FIX: Optimizer May Choose Inefficient Query Plan When Using NOT LIKE with an Empty String

Article translations Article translations
Article ID: 247125 - View products that this article applies to.
This article was previously published under Q247125
This article has been archived. It is offered "as is" and will no longer be updated.
BUG #: 56552 (SQLBUG_70)
Expand all | Collapse all

SYMPTOMS

SQL Server may incorrectly estimate the number of rows returned by a query or subquery using the NOT LIKE comparison operator with the Empty String. This behavior can subsequently cause poor performance on SELECT statements due to inefficient query plans being chosen.

Instead of using the NOT LIKE comparison operator for selecting rows that do not have Empty String values for a column, use the following query:
SELECT * 
FROM orders 
WHERE shipaddress LIKE '_%'
				
Note that '_' matches any single character, and '%' matches any string of zero or more characters.

STATUS

Microsoft has confirmed this to be a problem in SQL Server 7.0. This problem has been corrected in U.S. Service Pack 2 for Microsoft SQL Server 7.0. For more information, click the following article number to view the article in the Microsoft Knowledge Base:
254561 INF: How to Obtain Service Pack 2 for Microsoft SQL Server 7.0 and Microsoft Data Engine (MSDE) 1.0
For more information, contact your primary support provider.

MORE INFORMATION

The behavior reported can be observed by running the following query with the Northwind database:
SELECT * 
FROM orders 
WHERE shipaddress NOT LIKE ''
				
This query returns 830 rows; however, the generated Estimated Execution Plan only estimates a single row returned for the NOT LIKE filter. To display the Estimated Execution Plan for a query, you can select the Display Estimated Execution Plan (CTRL+L) option from the Query Analyzer's toolbar.

Properties

Article ID: 247125 - Last Review: October 22, 2013 - Revision: 2.1
APPLIES TO
  • Microsoft SQL Server 7.0 Standard Edition
Keywords: 
kbnosurvey kbarchive kbbug kbfix KB247125

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