FIX: You receive an incorrect result when you query a column of the varchar(max) data type that contains only one character from a table in SQL Server 2005

Extended support for SQL Server 2005 ended on April 12, 2016

If you are still running SQL Server 2005, you will no longer receive security updates and technical support. We recommend upgrading to SQL Server 2014 and Azure SQL Database to achieve breakthrough performance, maintain security and compliance, and optimize your data platform infrastructure. Learn more about the options for upgrading from SQL Server 2005 to a supported version here.

SYMPTOMS
Consider the following scenario:
  • In Microsoft SQL Server 2005, you create a table that contains a column of the varchar(max) data type.
  • You insert a value that only has one character into the column.
  • You run a query against the table. The query returns the one character value.
  • The execution plan of the query uses a Hash Match operator.
In this scenario, when you run the query, the query may not return the one character value in the result.
CAUSE
This issue occurs because the implementation of the Hash Match operator does not handle the single-character scenario correctly for the varchar(max) data type.
RESOLUTION

Service pack information

To resolve this problem, obtain the latest service pack for SQL Server 2005. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
913089 How to obtain the latest service pack for SQL Server 2005
STATUS
Microsoft has confirmed that this is a problem in the Microsoft products that are listed in the "Applies to" section. This problem was first corrected in SQL Server 2005 Service Pack 3.
MORE INFORMATION

Steps to reproduce the issue

  1. Start SQL Server Management Studio, and then create a new query.
  2. Run the following statements to create tables for a test.
    create table #test1 (symbol varchar(64) not null)create table #test2 (symbol varchar(max) not null, id int not null)insert into #test1 values ('A')insert into #test1 values ('AB')insert into #test2 values ('A', 0)insert into #test2 values ('AB', 1)
  3. Run the following statements. You receive a correct result.
    select t0.symbol, t1.idfrom #test1 as t0inner loop join #test2 as t1on t0.symbol = t1.symbol collate Latin1_General_BIN
  4. Run the following statements. You receive an incorrect result.
    select t0.symbol, t1.idfrom #test1 as t0inner hash join #test2 as t1on t0.symbol = t1.symbol collate Latin1_General_BIN
For more information about software update terminology, click the following article number to view the article in the Microsoft Knowledge Base:
824684 Description of the standard terminology that is used to describe Microsoft software updates
Propiedades

Id. de artículo: 959017 - Última revisión: 12/16/2008 00:47:58 - Revisión: 1.0

Microsoft SQL Server 2005 Standard Edition, Microsoft SQL Server 2005 Developer Edition, Microsoft SQL Server 2005 Enterprise Edition, Microsoft SQL Server 2005 Standard X64 Edition, Microsoft SQL Server 2005 Standard Edition for Itanium-based Systems, Microsoft SQL Server 2005 Enterprise X64 Edition, Microsoft SQL Server 2005 Enterprise Edition for Itanium-based Systems, Microsoft SQL Server 2005 Workgroup Edition

  • kbbug KB959017
Comentarios