SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Why no Index Scan?


Why no Index Scan?

Author
Message
diamondgm
diamondgm
SSC Veteran
SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)

Group: General Forum Members
Points: 239 Visits: 941
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.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)

Group: General Forum Members
Points: 89677 Visits: 45284
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, 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


diamondgm
diamondgm
SSC Veteran
SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)

Group: General Forum Members
Points: 239 Visits: 941
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 Smile

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.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)SSC Guru (89K reputation)

Group: General Forum Members
Points: 89677 Visits: 45284
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, 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


diamondgm
diamondgm
SSC Veteran
SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)SSC Veteran (239 reputation)

Group: General Forum Members
Points: 239 Visits: 941
Will digest.
Thanks Gail
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