FIX: Incorrect Results with Join of Column Converted to Binary (282243)



The information in this article applies to:

  • Microsoft SQL Server 7.0
  • Microsoft SQL Server 2000 (all editions)

This article was previously published under Q282243
BUG #: 351225 (SHILOH_bugs)
BUG #: 100900 (SQLBUG_70)

SYMPTOMS

When you use a case insensitive collation, if a correlated subquery or join is performed on a character-based column that has been converted to binary or varbinary, and if the optimizer chooses a plan that uses a table spool or hash match with cache, incorrect results may be returned. The rows that are returned are the matches based on a case insensitive comparison of the column, rather than a binary comparison.

CAUSE

On a case insensitive server, the lookups from the table spool or hash cache are performed in a case insensitive fashion instead of a binary lookup. Because the column was cast to a binary type, a binary lookup should be performed.

RESOLUTION

SQL Server 2000

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 2000. For additional information, click the following article number to view the article in the Microsoft Knowledge Base:

290211 INF: How to Obtain the Latest SQL Server 2000 Service Pack

SQL Server 7.0

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 7.0. For additional information, click the following article number to view the article in the Microsoft Knowledge Base:

301511 INF: How to Obtain the Latest SQL Server 7.0 Service Pack

NOTE: The following hotfix was created prior to Microsoft SQL Server 7.0 Service Pack 4.

The English version of this fix should have the following file attributes or later:
   Version      File name      Platform
   ----------------------------------------------------

   7.00.0919    s70919i.exe    x86        SP2-based fix
   7.00.0919    s70919a.exe    Alpha      SP2-based fix

   7.00.0970    s70970i.exe    x86        SP3-based fix
   7.00.0970    s70970a.exe    Alpha      SP3-based fix
				
NOTE: Because of file dependencies, the most recent hotfix or feature that contains the preceding files may also contain additional files.

STATUS

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.

SQL Server 2000
This problem was first corrected in SQL Server 2000 Service Pack 1.

SQL Server 7.0
This problem was first corrected in Microsoft SQL Server 7.0 Service Pack 4.

MORE INFORMATION

The following script demonstrates the problem. Before you apply the fix, the script returns two rows with a TestCode of 'a', rather than one row with value 'a' and a second with value 'A'.
CREATE TABLE #tblIDs(TestID int, Code varchar(1))
CREATE TABLE #tblValues(Code varchar(1))

INSERT INTO #tblIDs(TestID, Code) VALUES(1,'a')
INSERT INTO #tblIDs(TestID, Code) VALUES(2,'A')

INSERT INTO #tblValues(Code) VALUES('a')
INSERT INTO #tblValues(Code) VALUES('A')

SELECT #tblValues.Code AS TestCode, 
   (SELECT #tblIDs.TestID FROM #tblIDs 
      WHERE CAST(#tblIDs.Code AS varbinary) = 
            CAST(#tblValues.Code AS varbinary)
    ) AS TestID 
FROM #tblValues

DROP TABLE #tblIDs
DROP TABLE #tblValues
GO
				

Modification Type:MajorLast Reviewed:10/29/2003
Keywords:kbBug kbfix kbSQLServ2000sp1fix KB282243