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

Why no Index Scan? Expand / Collapse
Author
Message
Posted Tuesday, January 8, 2013 4:17 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 12:10 AM
Points: 141, Visits: 860
Hi All!
Hoping someone can help us understand this.

Given;
USE tempdb
GO

IF OBJECT_ID('tempdb.dbo.Covered') IS NOT NULL DROP TABLE Covered
IF OBJECT_ID('tempdb.dbo.Included') IS NOT NULL DROP TABLE Included
SET NOCOUNT ON;
CREATE TABLE Covered
(
RowID INT IDENTITY(1,1)
,Col1 INT NOT NULL
,Col2 INT NOT NULL
)

CREATE TABLE Included
(
RowID INT IDENTITY(1,1)
,Col1 INT NOT NULL
,Col2 INT NOT NULL
)
GO

INSERT INTO Covered
SELECT TOP 100000
ABS(CHECKSUM(NEWID()) % 100)
,ABS(CHECKSUM(NEWID()) % 10000)
FROM sys.syscolumns T1, sys.syscolumns T2, sys.syscolumns T3
GO 10

INSERT INTO Included
SELECT TOP 100000
ABS(CHECKSUM(NEWID()) % 100)
,ABS(CHECKSUM(NEWID()) % 10000)
FROM sys.syscolumns T1, sys.syscolumns T2, sys.syscolumns T3
GO 10


CREATE INDEX c_Covered ON Covered (RowID)
CREATE INDEX c_Included ON Included (RowID)

CREATE INDEX nc_Covered ON Covered (Col1, Col2)
CREATE INDEX nc_Included ON Included (Col1) INCLUDE (Col2)

And queries;
SELECT COUNT(*)
FROM Covered
WHERE Col1 > 60
AND Col2 > 9998

SELECT COUNT(*)
FROM Included
WHERE Col1 > 60
AND Col2 > 9998

We were expecting the second query to perform an Index Scan because included column (Col2) is not sorted.
Is it regarded as a Scan only when multiple levels of the B-Tree are traversed?
...the non clustered index (Col1) would get us to the leaf level and then find qualifying values for Col2 (unsorted).

Please let me know if my question is not clear.

Thanking you in advance.
Post #1404131
Posted Tuesday, January 8, 2013 4:22 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: Today @ 2:25 AM
Points: 40,390, Visits: 36,832
It's a seek because you have a SARGable predicate (Col1 > 60 ) on a column that is the leading column of the index.

Scan is when you have nothing to seek on and SQL has to read the entire index or table. In this case, there is something to seek on.



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 #1404133
Posted Tuesday, January 8, 2013 4:40 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 12:10 AM
Points: 141, Visits: 860
GilaMonster (1/8/2013)
It's a seek because you have a SARGable predicate (Col1 > 60 ) on a column that is the leading column of the index.

Scan is when you have nothing to seek on and SQL has to read the entire index or table. In this case, there is something to seek on.


Thanks for your response Gail :)

I think where we are stuck is;
At the leaf level of the NCI(no include), Col2 is sorted and the evaluation of whether or not the value meets the predicate could be/should be optimised?

In the case of the INCLUDE;
for Col1 = 61, Col2 = {random order}
In the case of the 'COVER';
for Col1 = 61, Col2 = {ordered numbers}

Perhaps we lack a fundamental understanding of what's going on.
Post #1404152
Posted Tuesday, January 8, 2013 5:06 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: Today @ 2:25 AM
Points: 40,390, Visits: 36,832
There's actually no difference in this case because of the inequality
http://sqlinthewild.co.za/index.php/2009/02/06/index-columns-selectivity-and-inequality-predicates/



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 #1404164
Posted Tuesday, January 8, 2013 5:10 AM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, November 19, 2014 12:10 AM
Points: 141, Visits: 860
Will digest.
Thanks Gail
Post #1404167
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse