FIX: Filter Not Pushed Below Aggregate If Subquery Uses the DISTINCT Keyword (323721)



The information in this article applies to:

  • Microsoft SQL Server 2000 (all editions)

This article was previously published under Q323721
BUG #: 357417 (SHILOH_BUGS)

SYMPTOMS

SQL Server may select a query plan that applies a filter after an aggregate function. Although, applying the filter before the aggregate function would provide a faster plan. This may occur if all of the following criteria are met:
  • The query has a subquery that uses the DISTINCT keyword.

  • The outer query includes a predicate that references a string column that restricts the results.

  • The predicate (referenced in the previous bullet) passes the string column to:

    • A user-defined function.

      -or-

    • An intrinsic function (for example, a LIKE operator).

    -or-

    The comparison involves implicit or explicit data type conversion.

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.

The English version of this fix has the file attributes (or later) 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.
   Date          Time    Version     Size              File name
   -----------------------------------------------------------------

   29-May-2002   19:46   8.00.0634   7,454,801 bytes   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

For example, with this query:
SELECT * 
FROM (SELECT DISTINCT au_lname, au_fname FROM pubs.dbo.authors) AS t
WHERE au_lname LIKE 'White'
SQL Server 2000 Service Pack 2 may select a plan like this:
StmtText
--------------------------------------------------------------------------------------
  |--Filter(WHERE:(like([authors].[au_lname], 'White', NULL)))
       |--Stream Aggregate(GROUP BY:([authors].[au_lname]))
            |--Index Scan(OBJECT:([pubs].[dbo].[authors].[aunmind]), ORDERED FORWARD)
After you apply the fix, the plan changes to this:
StmtText
--------------------------------------------------------------------------------------
  |--Stream Aggregate(GROUP BY:([authors].[au_lname]))
       |--Index Seek(OBJECT:([pubs].[dbo].[authors].[aunmind]), 
          SEEK:([authors].[au_lname] >= 'White' AND [authors].[au_lname] <= 'White'), 
          WHERE:(like([authors].[au_lname], 'White', NULL)) ORDERED FORWARD)

Modification Type:MinorLast Reviewed:9/27/2005
Keywords:kbHotfixServer kbQFE kbbug kbfix kbSQLServ2000preSP3fix kbSQLServ2000sp3fix KB323721