October 24, 2012 at 10:18 pm
I have a SQL 2008 R2 table with a few composite indexes and a few single column indexes. I've narrowed my problem down to this; if I run a query such as the following:
select * from tbl
where col > getdate()
the execution plan shows that index built on col is used. However if I run the query this way:
declare @todaydate datetime
set @todaydate = getdate()
select * from tbl
where col > @todaydate
then the execution plan shows that the index wasn't used.
I would like to know if this is how sql works or is the sql optimizer just recognizing that it doesn't need to use the index.
Thanks in advance for your help
October 25, 2012 at 1:45 am
It's a combination of this http://sqlinthewild.co.za/index.php/2008/02/25/parameter-sniffing-pt-2/ and the fact that the index is not covering
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
October 25, 2012 at 4:33 am
Okay, this is because the engine simply ignores the local variable value and compiles a plan based on general statistics assumptions. 🙂
October 25, 2012 at 4:58 am
Not ignores. At compile time (before any of the batch is executed), the variable doesn't have a value and hence any value it gets during execution can't be sniffed and used.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
October 25, 2012 at 8:11 am
I found this to be very helpful. Funny thing is I just watched it last night. 🙂
It's a readiness video for the MCM Prorgram. I'm hoping to get an MCM in about 100 years. 😛
http://technet.microsoft.com/en-us/sqlserver/gg545010.aspx
---------------------------------------------------------------
Mike Hahn - MCSomething someday:-)
Right way to ask for help!!
http://www.sqlservercentral.com/articles/Best+Practices/61537/
I post so I can see my avatar :hehe:
I want a personal webpage 😎
I want to win the lotto 😀
I want a gf like Tiffa :w00t: Oh wait I'm married!:-D
October 29, 2012 at 9:35 pm
Eh, just wonder why the equal operator can make the execution plan shows that the index was used.
declare @todaydate datetime
set @todaydate = getdate()
select * from tbl
where col = @todaydate
However the execution plan shows that the index wasn't used in <, <>, >, >=, <=?
declare @todaydate datetime
set @todaydate = getdate()
select * from tbl
where col > @todaydate
October 30, 2012 at 2:19 am
The estimations from an equality where there's no parameter sniffing is based on the average density of the column. The estimations for an inequality where there's no parameter sniffing is, if I recall, 30% of the table. The latter is far too high for seek + key lookup to be efficient, the former may be small enough.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply