Take your indexed columns out of functions to really boost SQL Server performance!

by Sep 23, 2010

In a future article I will show how to quantify and rank your “heaviest” SQL Server queries according to the overall load they place on your system. That discussion will show that at most sites it’s often NOT the infrequent long-running queries which are placing the greatest load on SQL Server but rather the short-fast running TSQL statements which run hundreds of thousands of times per hour which are producing the greatest load on SQL Server. One way to ensure that queries run with peak performance is to make certain that all indexable columns are not buried within functions in the query’s “WHERE” clause. It’s all too easy to write a query like this:

USE [AdventureWorks]
GO
SELECT SalesOrderID
 FROM Sales.SalesOrderHeader
 WHERE DATEDIFF(d, OrderDate, GETDATE()) = 104
GO
 

However let’s create an index on the OrderDatecolumn of that table and then see what the query plan shows us.

USE [AdventureWorks]
GO
CREATE NONCLUSTERED INDEX [IX_SalesOrderHeader_OrderDate]
ON [Sales].[SalesOrderHeader] ([OrderDate])
GO
USE [AdventureWorks]
GO
SELECT SalesOrderID
 FROM Sales.SalesOrderHeader
 WHERE DATEDIFF(d, OrderDate, GETDATE()) = 104
GO
 

The SQL Server generates a query plan which performs a sub-optimal index scan. With just a little thought we can place the indexed column OrderDate outside of theDATEDIFF function like this:

 

USE [AdventureWorks]
GO
SELECT SalesOrderID
 FROM Sales.SalesOrderHeader�
 WHERE OrderDate = DATEADD(d, -104, GETDATE())
GO
 

Now let’s compare the query plans produced by SQL Server on the 2 queries, one where the indexed column is inside the DATEDIFF function and one where it is outside the function:

 

USE [AdventureWorks]
GO
SELECT SalesOrderID
 FROM Sales.SalesOrderHeader
 WHERE DATEDIFF(d, OrderDate, GETDATE()) = 104 -- indexed column inside the DATEDIFF function
SELECT SalesOrderID
 FROM Sales.SalesOrderHeader
 WHERE OrderDate = DATEADD(d, -104, GETDATE()) -- indexed column outside the DATEDIFF function
GO
 

The query plan where we moved the indexed column outside of theDATEDIFF function was able to perform an index seek instead of an index scan making it 25 times faster! That’s an awesome performance improvement achieved with just the smallest of tweaks and if it’s on a query which runs thousands of times every hour then the impact of making such a change cannot be overemphasized. In order to be sure that the benefits the query plan indicates we should get are real let’s run the 2 queries in a loop many times over and compare their run times:

 

USE [AdventureWorks]
GO
SET NOCOUNT ON
DECLARE @StartTime1 datetime, @StartTime2 datetime, @EndTime1 datetime, @EndTime2 datetime, @Counter int, @V int
SELECT @StartTime1 = GETDATE(), @Counter = 0
WHILE @Counter < 2000 -- Run indexed column inside the DATEDIFF function 2,000 times
 BEGIN
 SELECT @V = SalesOrderID FROM Sales.SalesOrderHeader WHERE DATEDIFF(d, OrderDate, GETDATE()) = 104 -- indexed column inside the DATEDIFF function
 SET @Counter = @Counter + 1
 END
SELECT @EndTime1 = GETDATE()
SELECT @StartTime2 = GETDATE(), @Counter = 0
WHILE @Counter < 2000 -- Run indexed column outside the DATEDIFF function 2,000 times
 BEGIN
 SELECT @V = SalesOrderID FROM Sales.SalesOrderHeader WHERE OrderDate = DATEADD(d, -104, GETDATE()) -- indexed column outside the DATEDIFF function
 SET @Counter = @Counter + 1�
 END
SELECT @EndTime2 = GETDATE()
SELECT 'Run time of indexed column inside the DATEDIFF' = DATEDIFF(ms, @StartTime1, @EndTime1),
       'Run time of indexed column outside the DATEDIFF' = DATEDIFF(ms, @StartTime2, @EndTime2),
       'Improvement when moving indexed column outside the DATEDIFF' = CONVERT(varchar(9), (CONVERT(DEC(6,2), ((DATEDIFF(ms, @StartTime1, @EndTime1) * 1.00) / DATEDIFF(ms, @StartTime2, @EndTime2))))) + ' X improvement'
GO

 

As you can see the improvement in performance in moving the indexed column to outside the DATEDIFF function is astounding 300 TIMES faster! Far more than even the 25X faster which the SQL Server query plans had predicted! The fun doesn’t end there though as the performance improvements are not only when one moves an indexed column out of the DATEDIFF function but moving it out of almost any function. Here are a few other examples of how one can move an indexed column out of a function to derive the same significant performance gains:

 
WHERE LEFT (AccountNumber, 11) = ’10-4001-13A’

 

Should be changed to

WHERE AccountNumber LIKE ’10-4001-13A%’

 

AND

WHERE YEAR(OrderDate) = 2010

 

Should be changed to

WHERE OrderDate BETWEEN ‘1 Jan 2010’ AND ‘31 Dec 2010’

 

AND

WHERE CHARINDEX(’10-400’, AccountNumber) = 0

 

Should be changed to

WHERE AccountNumber LIKE ’10-400%’
 

 

There are hundreds of other situations where one can extract the indexed column from within the function and “expose” it outside the function to derive the performance benefit in SQL Server in switching from an index scan to an index seek… All it takes is a little thought. Note: These tests were run on SQL Server 2008 SP1.