Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Where clause on indexed column using a variable Expand / Collapse
Author
Message
Posted Wednesday, October 24, 2012 10:18 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, July 18, 2014 7:48 PM
Points: 21, Visits: 235
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
Post #1376762
Posted Thursday, October 25, 2012 1:45 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 3:46 PM
Points: 42,462, Visits: 35,525
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 2008, MVP
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

Post #1376824
Posted Thursday, October 25, 2012 4:33 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, July 18, 2014 7:48 PM
Points: 21, Visits: 235
Okay, this is because the engine simply ignores the local variable value and compiles a plan based on general statistics assumptions.
Post #1376895
Posted Thursday, October 25, 2012 4:58 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 3:46 PM
Points: 42,462, Visits: 35,525
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 2008, MVP
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

Post #1376913
Posted Thursday, October 25, 2012 8:11 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, April 24, 2014 9:12 AM
Points: 285, Visits: 504
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 - Future MCM 2025
Right way to ask for help!!
http://www.sqlservercentral.com/articles/Best+Practices/61537/
I post so I can see my avatar
I want a personal webpage
I want to win the lotto
I want a gf like Tiffa
Post #1377006
Posted Monday, October 29, 2012 9:35 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, July 18, 2014 7:48 PM
Points: 21, Visits: 235
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
Post #1378551
Posted Tuesday, October 30, 2012 2:19 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Yesterday @ 3:46 PM
Points: 42,462, Visits: 35,525
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 2008, MVP
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

Post #1378607
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse