Thumb Rule is as much as possible avoid using FUNCTIONS within WHERE Clause of your SQL Query.
Let me show you some very basic examples to substantiate this theory.
--Table schema
Create table tblDateExample (dtStartDate datetime)
Go
-- Populate dummy records into the table
INSERT tblDateExample VALUES ('2009-04-15 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-14 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-13 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-12 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-11 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-11 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-11 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-11 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-10 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-09 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-08 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-07 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-10 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-10 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-10 12:00:00.000')
INSERT tblDateExample VALUES ('2009-04-10 12:00:00.000')
-- Create an Index
Create index IXStartDate on tblDateExample ( dtStartDate )
Go
Using Functions within WHERE Clause
SET SHOWPLAN_TEXT ON
Go
Select dtStartDate from tblDateExample where Convert(Varchar(8), dtStartDate, 112) = '20090411'
SET SHOWPLAN_TEXT OFF
Go
Checkout its execution plan, as expected it doesn’t make use of the Index fully
|—Index Scan (OBJECT:([Testbed].[dbo].[tblDateExample].[IXStartDate]), WHERE:(CONVERT(varchar(8),[Testbed].[dbo].[tblDateExample].[dtStartDate],112)=[@1]))
Rewrite the same query without a function in the WHERE Clause
SET SHOWPLAN_TEXT ON
Go
Select dtStartDate from tblDateExample where dtStartDate >= '20090411' AND dtStartDate < '20090412'
SET SHOWPLAN_TEXT OFF
Go
The execution plan shows us that it uses Index Seek.
|—Index Seek (OBJECT:([Testbed].[dbo].[tblDateExample].[IXStartDate]), SEEK:([Testbed].[dbo].[tblDateExample].[dtStartDate] >= CONVERT_IMPLICIT(datetime,[@1],0) AND [Testbed].[dbo].[tblDateExample].[dtStartDate] < CONVERT_IMPLICIT(datetime,[@2],0)) ORDERED FORWARD)
That said, there are instances where we can still make use of Index Seek in spite of using Functions within the WHERE Clause. Check out the below query for an example.
Select dtStartDate from tblDateExample
where
Convert(datetime,dtStartDate,101) > Convert(datetime,'2009-04-11',101) and
Convert(datetime,dtStartDate,101) < Convert(datetime,'2009-04-12',101)
The execution plan for the above query:
|—Index Seek (OBJECT:([Testbed].[dbo].[tblDateExample].[IXStartDate]), SEEK:([Testbed].[dbo].[tblDateExample].[dtStartDate] > CONVERT(datetime,[@1],101) AND [Testbed].[dbo].[tblDateExample].[dtStartDate] < CONVERT(datetime,[@2],101)) ORDERED FORWARD)
On trying to understand the reason for this behavior i noticed there is no real conversion happening in the above query. i.e., Both the Converted type and the original column type are the same :)
Comments