Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Where clause on indexed column using a variable


Where clause on indexed column using a variable

Author
Message
angel.wong 72408
angel.wong 72408
SSC Rookie
SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)

Group: General Forum Members
Points: 27 Visits: 349
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
GilaMonster
GilaMonster
SSC-Forever
SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)

Group: General Forum Members
Points: 47374 Visits: 44395
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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


angel.wong 72408
angel.wong 72408
SSC Rookie
SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)

Group: General Forum Members
Points: 27 Visits: 349
Okay, this is because the engine simply ignores the local variable value and compiles a plan based on general statistics assumptions. :-)
GilaMonster
GilaMonster
SSC-Forever
SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)

Group: General Forum Members
Points: 47374 Visits: 44395
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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Want a cool Sig
Want a cool Sig
Old Hand
Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)Old Hand (318 reputation)

Group: General Forum Members
Points: 318 Visits: 705
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. :-P
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 Cool
I want to win the lotto :-D
I want a gf like Tiffa w00t Oh wait I'm married!:-D
angel.wong 72408
angel.wong 72408
SSC Rookie
SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)SSC Rookie (27 reputation)

Group: General Forum Members
Points: 27 Visits: 349
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
GilaMonster
GilaMonster
SSC-Forever
SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)SSC-Forever (47K reputation)

Group: General Forum Members
Points: 47374 Visits: 44395
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

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search