FIX: You may receive incorrect results when you run a Transact-SQL query in SQL Server 2000 (910392)



The information in this article applies to:

  • Microsoft SQL Server 2000 Standard Edition
  • Microsoft SQL Server 2000 Enterprise Edition
  • Microsoft SQL Server 2000 Developer Edition
  • Microsoft SQL Server 2000 Personal Edition

Bug #: 473290 (SQL Server 8.0)

SUMMARY

This article describes the following about this hotfix release:
  • The issues that are fixed by this hotfix package
  • The prerequisites for applying this hotfix package
  • Whether you must restart the computer after you apply this hotfix package
  • Whether this hotfix package is replaced by any other hotfix package
  • Whether you must make any registry changes after you apply this hotfix package
  • The files that are contained in this hotfix package

SYMPTOMS

When you run a Transact-SQL query in Microsoft SQL Server 2000, you may receive incorrect results. You experience this problem when all the following conditions are true:
  • The query contains an inner join that has a one-to-one key relationship.
  • The query contains an aggregate expression or a DISTINCT keyword.
  • The GROUP BY clause appears in the Showplan.
  • The query contains an outer join.
  • The outer join is simplified out of the query because no columns from the outer join table are referenced elsewhere in the query.

CAUSE

This problem occurs because the SQL Server query optimizer incorrectly simplifies the list of grouping columns. Therefore, the aggregate operator does not operate on the expected set of grouped columns.

RESOLUTION

Hotfix information

A supported hotfix is now available from Microsoft, but it is only intended to correct the problem that is described in this article. Only apply it to systems that are experiencing this specific problem. This hotfix may receive additional testing. Therefore, if you are not severely affected by this problem, we recommend that you wait for the next Microsoft SQL Server 2000 service pack that contains this hotfix.

To resolve this problem immediately, contact Microsoft Product Support Services to obtain the hotfix. For a complete list of Microsoft Product Support Services telephone numbers and information about support costs, visit the following Microsoft Web site:Note In special cases, charges that are ordinarily incurred for support calls may be canceled if a Microsoft Support Professional determines that a specific update will resolve your problem. The usual support costs will apply to additional support questions and issues that do not qualify for the specific update in question.

Prerequisites

Microsoft SQL Server 2000 Service Pack 4 (SP4)

To obtain SQL Server 2000 SP4, and for a list of previous hotfixes, see the "Microsoft SQL Server 2000 Service Pack 4" section in the following Microsoft Knowledge Base article:

290211 How to obtain the most recent SQL Server 2000 service pack

Restart information

You do not have to restart the computer after you apply this hotfix. However, the hotfix installation stops and then restarts the MSSQLSERVER service.

Hotfix file information

This hotfix contains only those files that are required to correct the problem that is described in this article. This hotfix may not contain all the files that you must have to fully update a product to the latest build.

The English version of this hotfix has the file attributes (or later file attributes) that are listed in the following table. The dates and times for these files are listed in Coordinated Universal Time (UTC). When you view the file information, it is converted to local time. To find the difference between UTC and local time, use the Time Zone tab in the Date and Time tool in Control Panel.SQL Server 2000, 32-bit versions
File nameFile versionFile sizeDateTimePlatform
Dtsui.dll2000.80.2171.01,593,34404-Nov-200507:10x86
Impprov.dll2000.80.2171.0102,40004-Nov-200507:10x86
Mssdi98.dll8.11.50523.0239,10406-Jun-200522:46x86
Ntwdblib.dll2000.80.2171.0290,81604-Nov-200507:10x86
Odsole70.dll2000.80.2171.069,63204-Nov-200507:10x86
Pfclnt80.dll2000.80.2171.0430,08004-Nov-200507:10x86
Replprov.dll2000.80.2171.0237,56804-Nov-200507:10x86
Semexec.dll2000.80.2171.0856,06404-Nov-200507:10x86
Sqlagent.exe2000.80.2171.0323,58404-Nov-200505:27x86
Sqldiag.exe2000.80.2171.0118,78404-Nov-200506:09x86
Sqldmo.dll2000.80.2171.04,362,24004-Nov-200507:10x86
Sqlfth75.dll2000.80.2171.0102,40004-Nov-200505:33x86
Sqlservr.exe2000.80.2171.09,158,65604-Nov-200507:10x86
Sqlsort.dll2000.80.2171.0589,82404-Nov-200507:10x86
Stardds.dll2000.80.2171.0176,12804-Nov-200507:10x86
Svrnetcn.dll2000.80.2171.0110,59204-Nov-200507:10x86
Ums.dll2000.80.2171.035,32804-Nov-200507:10x86
Sqlevn70.rll2000.80.2171.045,05604-Nov-200507:10Not Applicable
SQL Server 2000, Itanium architecture version
File nameFile versionFile sizeDateTimePlatform
Impprov.dll2000.80.2171.0244,73604-Nov-200507:13IA-64
Mssdi98.dll8.11.50523.0758,78406-Jun-200522:46IA-64
Odsole70.dll2000.80.2171.0150,52804-Nov-200507:12IA-64
Pfclnt80.dll2000.80.2171.01,187,84004-Nov-200507:30IA-64
Replprov.dll2000.80.2171.0538,62404-Nov-200507:19IA-64
Sqlagent.exe2000.80.2171.01,061,37604-Nov-200507:37IA-64
Sqldiag.exe2000.80.2171.0334,33604-Nov-200507:32IA-64
Sqldmo.dll2000.80.2171.013,860,35204-Nov-200507:41IA-64
Sqlfth75.dll2000.80.2171.0246,78404-Nov-200507:15IA-64
Sqlservr.exe2000.80.2171.024,921,60004-Nov-200513:24IA-64
Sqlsort.dll2000.80.2171.0617,47204-Nov-200505:23IA-64
Svrnetcn.dll2000.80.2171.0427,52004-Nov-200507:27IA-64
Sqlevn70.rll2000.80.2171.035,32804-Nov-200513:24Not Applicable
Note Because of file dependencies, the most recent hotfix that contains these files may contain additional files.

STATUS

Microsoft has confirmed that this is a bug in the Microsoft products that are listed in the "Applies to" section.

MORE INFORMATION

Steps to reproduce the problem

Create the test environment

Run the following code in SQL Query Analyzer.
USE Northwind
GO

CREATE TABLE [dbo].[Participant] (
	[ProgramUserId] [int] NOT NULL ,
	[ProjectId] [int] NOT NULL 
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[Project] (
	[ProjectId] [int] NOT NULL ,
	[ProjectHdrId] [int] NOT NULL ,
	[CustomerId] [int] NOT NULL 
) ON [PRIMARY]
GO
CREATE TABLE [dbo].[ProjectHdr] (
	[ProjectHdrId] [int] NOT NULL
) ON [PRIMARY]
GO
ALTER TABLE [dbo].[Participant] WITH NOCHECK ADD 
	CONSTRAINT [pkParticipant_ParticipantId] PRIMARY KEY  CLUSTERED 
	(
		[ProgramUserId],
		[ProjectId]
	)  ON [PRIMARY] 
GO
ALTER TABLE [dbo].[Project] WITH NOCHECK ADD 
	CONSTRAINT [pkProject_ProjectId] PRIMARY KEY  CLUSTERED 
	(
		[ProjectId]
	)  ON [PRIMARY] 
GO
ALTER TABLE [dbo].[ProjectHdr] WITH NOCHECK ADD 
	CONSTRAINT [pkProjectHdr_ProjectHdrId] PRIMARY KEY  CLUSTERED 
	(
		[ProjectHdrId]
	)  ON [PRIMARY] 
GO
 CREATE  UNIQUE  INDEX [ixProject_CustomerId_Unique] ON [dbo].[Project]([CustomerId], [ProjectHdrId]) ON [PRIMARY]
GO
insert into Participant(ProgramUserId,ProjectId) values('3','8');
insert into Participant(ProgramUserId,ProjectId) values('3','74');
insert into Participant(ProgramUserId,ProjectId) values('3','1004');
insert into Participant(ProgramUserId,ProjectId) values('5','1003');
insert into Participant(ProgramUserId,ProjectId) values('7','8');
insert into Participant(ProgramUserId,ProjectId) values('7','74');
insert into Participant(ProgramUserId,ProjectId) values('7','1004');
insert into Participant(ProgramUserId,ProjectId) values('8','1003');
insert into Participant(ProgramUserId,ProjectId) values('8','1004');
GO

insert into Project (ProjectId,ProjectHdrId,CustomerId) values('1','1','1');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('2','2','2');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('7','15','5');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('8','26','5');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('71','27','52');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('72','3','52');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('73','3','51');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('74','15','51');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('1003','1002','5');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('1004','1001','5');
insert into Project (ProjectId,ProjectHdrId,CustomerId) values('1014','1001','51');
GO

insert into ProjectHdr(ProjectHdrId) values('1');
insert into ProjectHdr(ProjectHdrId) values('2');
insert into ProjectHdr(ProjectHdrId) values('3');
insert into ProjectHdr(ProjectHdrId) values('15');
insert into ProjectHdr(ProjectHdrId) values('26');
insert into ProjectHdr(ProjectHdrId) values('27');
insert into ProjectHdr(ProjectHdrId) values('1001');
insert into ProjectHdr(ProjectHdrId) values('1002');
GO

Analyze the problem

  1. Run the following SQL query.
    SELECT PH.ProjectHdrId, P.ProjectId
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5
    As expected, the query returns eight rows. Some rows are duplicates. Therefore, there are four distinct rows.
  2. Add the DISTINCT keyword, and then run the query again.
    dbcc freeproccache
    
    SELECT DISTINCT PH.ProjectHdrId, P.ProjectId
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5
    
    The result of this query should be four rows. However, only one row is returned.

Work around the problem

  1. The following workaround returns the correct result set for the JOIN query. This query uses a temporary table and selected distinct values from the query.
    dbcc freeproccache
    
    SELECT PH.ProjectHdrId, P.ProjectId
    INTO #temp
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5
    SELECT * from #temp
    SELECT DISTINCT * from #temp
    DROP TABLE #temp
    
    If the SELECT statement in this query does not have the DISTINCT keyword, the query returns eight rows. If the SELECT statement in this query has the DISTINCT keyword, this query returns four rows.
  2. The following query adds a "dummy condition" on the Participant table. Run this query.
    dbcc freeproccache
    
    SELECT DISTINCT PH.ProjectHdrId, P.ProjectId
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5 AND (PP.ProjectId IS NOT NULL OR PP.ProjectId IS NULL)
    
    Notice that the query returns four rows.
  3. The following query changes the order of the equi-join and enforces this order. Run this query.
    dbcc freeproccache
    
    SELECT DISTINCT PH.ProjectHdrId, P.ProjectId
    FROM Project AS P JOIN ProjectHdr AS PH ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5 OPTION (FORCE ORDER)
    
    Notice that the query returns four rows.
  4. The following query drops the index Project.ixProject_CustomerId_Unique. Run this query.
    drop index project.ixProject_CustomerId_Unique
    
    dbcc freeproccache
    
    SELECT DISTINCT PH.ProjectHdrId, P.ProjectId
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5
    Notice that the query returns four rows.

Reproduce the problem

  1. If you re-create the index Project.ixProject_CustomerId_Unique, the problem occurs again. Run the following code to re-create the index.
    create unique index ixProject_CustomerId_Unique on project (CustomerId, ProjectHdrId)
  2. Run the following query.
    dbcc freeproccache
    
    SELECT DISTINCT PH.ProjectHdrId,  P.ProjectId
    FROM ProjectHdr AS PH JOIN Project AS P ON P.ProjectHdrId = PH.ProjectHdrId
    LEFT OUTER JOIN Participant AS PP ON PP.ProjectId = P.ProjectId
    WHERE P.CustomerId = 5
    Notice that only one record is returned. However, if you run the query without the DISTINCT keyword in the SELECT statement, the query returns eight rows.
For more information about the naming schema for Microsoft SQL Server updates, click the following article number to view the article in the Microsoft Knowledge Base:

822499 New naming schema for Microsoft SQL Server software update packages

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


Modification Type:MinorLast Reviewed:7/26/2006
Keywords:kbprb kbtshoot kbbug kbfix kbHotfixServer kbQFE kbpubtypekc KB910392 kbAudITPRO kbAudDeveloper