FIX: Reorder outer joins with filter criteria before non-selective joins and outer joins

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

On This Page

SYMPTOMS

If you submit a query that contains at least one outer join that has a filter condition in the WHERE clause on the inner table of the outer join (for example, a filter condition on the right table of a left outer join, or the left table of a right outer join), SQL Server may perform less selective joins first instead of performing the outer join early and applying the filter condition. If the filter condition from the outer join is one of the more selective criteria for the query, failing to process the criteria early in the plan may lead to:
  • Larger intermediate join sizes.
  • Higher resource utilization by the SQL Server process.
  • Slower response time for the query.

RESOLUTION

Resolution for SQL Server 2005

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
After you install the SQL Server 2005 service pack, you must turn on trace flag 4101 to resolve this problem.

Resolution for SQL Server 2000

To resolve this problem, obtain the latest service pack for Microsoft SQL Server 2000. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
290211 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.

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

   8.00.0584     Sqlservr.exe
				
NOTE: Because of file dependencies, the most recent hotfix or feature that contains the files may also contain additional files.

STATUS

Status for SQL Server 2005

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 Microsoft SQL Server 2005 Service Pack 1.

Status for SQL Server 2000

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 Microsoft SQL Server 2000 Service Pack 3.

MORE INFORMATION

The following contrived join scenario uses the pubs database to demonstrate the scenario:
set ansi_nulls off
go

use pubs
go

create procedure dbo.ansi_nulls_param @P1 varchar(11) as
select t.title_id, a.au_id, ta.title_id, s.stor_id from titles t 
   left outer join titleauthor ta on ta.title_id = t.title_id
   inner join authors a on a.au_id = t.title_id
   inner join sales s on s.title_id = t.title_id
where ta.title_id = @P1
go

exec dbo.ansi_nulls_param '123-45-6789'
go

drop proc dbo.ansi_nulls_param
go

--Slower Query Plan:
       |--Filter(WHERE:([ta].[title_id]=[@P1]))
            |--Nested Loops(Left Outer Join, OUTER REFERENCES:([t].[title_id]))
                 |--Nested Loops(Inner Join, OUTER REFERENCES:([s].[title_id]))
                 |    |--Nested Loops(Inner Join, OUTER REFERENCES:([s].[title_id]))
                 |    |    |--Index Scan(OBJECT:([pubs].[dbo].[sales].[titleidind] AS [s]))
                 |    |    |--Clustered Index Seek(OBJECT:([pubs].[dbo].[authors].[UPKCL_auidind] AS [a]), SEEK:([a].[au_id]=[s].[title_id]) ORDERED FORWARD)
                 |    |--Clustered Index Seek(OBJECT:([pubs].[dbo].[titles].[UPKCL_titleidind] AS [t]), SEEK:([t].[title_id]=[s].[title_id]) ORDERED FORWARD)
                 |--Index Seek(OBJECT:([pubs].[dbo].[titleauthor].[titleidind] AS [ta]), SEEK:([ta].[title_id]=[t].[title_id]) ORDERED FORWARD)

--Faster Query Plan:
       |--Nested Loops(Inner Join, OUTER REFERENCES:([a].[au_id]))
            |--Nested Loops(Inner Join, OUTER REFERENCES:([t].[title_id]))
            |    |--Filter(WHERE:([ta].[title_id]=[@P1]))
            |    |    |--Nested Loops(Left Outer Join, OUTER REFERENCES:([t].[title_id]))
            |    |         |--Index Scan(OBJECT:([pubs].[dbo].[titles].[titleind] AS [t]))
            |    |         |--Index Seek(OBJECT:([pubs].[dbo].[titleauthor].[titleidind] AS [ta]), SEEK:([ta].[title_id]=[t].[title_id]) ORDERED FORWARD)
            |    |--Clustered Index Seek(OBJECT:([pubs].[dbo].[authors].[UPKCL_auidind] AS [a]), SEEK:([a].[au_id]=[t].[title_id]) ORDERED FORWARD)
            |--Index Seek(OBJECT:([pubs].[dbo].[sales].[titleidind] AS [s]), SEEK:([s].[title_id]=[a].[au_id]) ORDERED FORWARD)
				
Note that the titleauthor table is the right table of a left outer join and the WHERE clause condition on titleauthor that is to be applied after the outer join. The output shows the original, slower query plan, where all the inner joins are performed first and the outer join and filter is performed last, even though it is the most selective condition for the query. The second query plan is a forced plan that demonstrates what the faster plan will look like, in which the outer join and filter is performed first, followed by the remaining inner joins.

For this particular scenario, the optimizer continues to choose the first plan even after you apply the hotfix. This is because these tables are so small and the estimated cost of the first plan is low enough that it is deemed better to just run with that plan than it is to continue searching for subsequent alternatives. As the data in the tables increases, the cost of the first plan becomes higher and the optimizer starts to choose the second plan.

Properties

Article ID: 318530 - Last Review: February 4, 2008 - Revision: 5.1
APPLIES TO
  • Microsoft SQL Server 2000 Standard Edition
  • Microsoft SQL Server 2005 Developer Edition
  • Microsoft SQL Server 2005 Enterprise Edition
  • Microsoft SQL Server 2005 Standard Edition
  • Microsoft SQL Server 2005 Workgroup Edition
Keywords: 
kbhotfixserver kbqfe kbsqlserv2000sp3fix kbbug kbfix kbsqlserv2000presp3fix KB318530

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