January 8, 2013 at 4:17 am
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
(
RowIDINT IDENTITY(1,1)
,Col1INT NOT NULL
,Col2INT NOT NULL
)
CREATE TABLE Included
(
RowIDINT IDENTITY(1,1)
,Col1INT NOT NULL
,Col2INT 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_CoveredON Covered (RowID)
CREATE INDEX c_IncludedON Included (RowID)
CREATE INDEX nc_CoveredON Covered (Col1, Col2)
CREATE INDEX nc_IncludedON 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.
January 8, 2013 at 4:22 am
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
January 8, 2013 at 4:40 am
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.
January 8, 2013 at 5:06 am
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
January 8, 2013 at 5:10 am
Will digest.
Thanks Gail
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply