FIX: SQL Server Might Return Incorrect Results When You Use an Outer Join and a View

Article translations Article translations
Article ID: 321541 - View products that this article applies to.
This article was previously published under Q321541
BUG #: 357109 (SHILOH_BUGS)
Expand all | Collapse all

SYMPTOMS

SQL Server returns incorrect results in a particular scenario that involves a query with an outer join and a view.

You can reproduce the behavior when all the following conditions exist:
  • You use a query that contains an outer join, and you use a view (directly or indirectly) on the inner side of the outer join.
  • The view contains an expression in its SELECT list that references one or more base table columns. Also, if all base table column values are NULL, the expression returns non-NULL results.
  • The view is a simple view that does not contain a DISTINCT, TOP, or GROUP BY aggregate.

CAUSE

An incorrect view resolution is causing the problem.

When the condition in the first bullet item of the "Symptoms" section is true, the inlining process will involve pulling all result expressions of the view from under the outer join to be computed above the outer join.

When the condition in the second bullet item of the "Symptoms" section is true, this pulling is semantically incorrect and will lead to incorrect results.

When the condition in the third bullet item of the "Symptoms" section is true, the view resolution code will inline the view tree in the query.

RESOLUTION

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
NOTE: The following hotfix was created before the release of Microsoft SQL Server 2000 Service Pack 3.

A supported hotfix is available from Microsoft. However, this hotfix is intended to correct only the problem that is described in this article. Apply this hotfix only to systems that are experiencing this specific problem.

If the hotfix is available for download, there is a "Hotfix download available" section at the top of this Knowledge Base article. If this section does not appear, submit a request to Microsoft Customer Service and Support to obtain the hotfix.

Note If additional issues occur or if any troubleshooting is required, you might have to create a separate service request. The usual support costs will apply to additional support questions and issues that do not qualify for this specific hotfix. For a complete list of Microsoft Customer Service and Support telephone numbers or to create a separate service request, visit the following Microsoft Web site:
http://support.microsoft.com/contactus/?ws=support
Note The "Hotfix download available" form displays the languages for which the hotfix is available. If you do not see your language, it is because a hotfix is not available for that language. The English version of this fix should have the following file attributes or later:
   Date         Version    Size       File name
   ------------------------------------------------

   04/20/2002   8.00.613   7,281 KB   Sqlservr.exe 
				
NOTE: Because of file dependencies, the most recent hotfix or feature that contains the 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.

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

MORE INFORMATION

To reproduce the problem, use the following script:

create table t1 (pk1 int not null,primary key (pk1))
create table t2 (pk1 int not null,label1 varchar(10) not null,primary key (pk1))
go
insert into t1 values (1)
insert into t2 values (2, 'XXXXX')
go
create view V as
select pk1,
       case  when label1 is null then  'b2 mapped 1' else label1 end as label1 from t2
go
select A.pk1 as A_pk1, B.pk1 as B_pk1, B.label1 as B_label1
from t1 as A left outer join V as B on A.pk1 = B.pk1
go
				

The script returns this result:

A_pk1       B_pk1       B_label1    
----------- ----------- -----------
1           NULL        b2 mapped 1
				


This is the result the SELECT statement is supposed to return:

A_pk1       B_pk1       B_label1    
----------- ----------- -----------
1           NULL        NULL
				


Properties

Article ID: 321541 - Last Review: October 11, 2005 - Revision: 3.5
APPLIES TO
  • Microsoft SQL Server 2000 Standard Edition
Keywords: 
kbautohotfix kbhotfixserver kbqfe kbbug kbfix kbsqlserv2000sp3fix KB321541

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com