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


Covering Index vs Included Columns


Covering Index vs Included Columns

Author
Message
tfifield
tfifield
SSC Eights!
SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)

Group: General Forum Members
Points: 991 Visits: 2890
Hi Guys!

Can anyone tell me if there is any functional or performance difference between designing a covering index and an index that includes columns that will be queried.

Let's say I wanted to sum up the total quantity ordered by product in a date range.

SELECT ProductID, SUM(QtySold) AS MarchQty
FROM OrderDetail
WHERE OrderDate >= '3/1/08'
AND OrderDate < '4/1/08
GROUP BY ProductID

Would there by any performance difference between:
CREATE NONCLUSTERED INDEX IX_OrderDetailDateProdSold ON dbo.OrderDetail
( OrderDate ASC, ProductID ASC, QtySold ASC );

and

CREATE NONCLUSTERED INDEX IX_OrderDetailDateWithProdSold ON dbo.OrderDeail
(OrderDate) ASC
INCLUDE (ProductID, QtySold);
Matt Miller (#4)
Matt Miller (#4)
SSCertifiable
SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)SSCertifiable (7.6K reputation)

Group: General Forum Members
Points: 7639 Visits: 18060
There should be, although how much might be debatable. Ultimately - I think the "sweet spot" is the version you didn't include:

CREATE NONCLUSTERED INDEX IX_OrderDetailDateProdSold ON dbo.OrderDetail
( OrderDate ASC, ProductID ASC) INCLUDE (QtySold);



The short version as I understand it to make the "ideal" covering would be:
- columns appearing in the WHERE, FROM, GROUP BY and ORDER BY should appear in the "main part" of the index.
- columns not otherwise included that appear in the SELECT or HAVING go in the UNCLUDE clause.

Technically - since the "main part" is what the B-tree is based on - by keeping the main part as skinny as you can, you get better perf, while avoiding the bookmark lookup with the INCLUDE stuff.

----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
Jack Corbett
  Jack Corbett
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11014 Visits: 14858
I think Matt covered it very well. Another way to explain it that the included columns should be columns that you don't search on, but will return. I think a good example are middle_name and suffix columns. You probably return it but your searching, ordering, and grouping will usually be by last_name, first_name which would be your index with middle_name and suffix as the included columns.



Jack Corbett

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
tfifield
tfifield
SSC Eights!
SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)SSC Eights! (991 reputation)

Group: General Forum Members
Points: 991 Visits: 2890
Thanks guys. It makes sense I'll give it a whirl.
Todd Fifield
Hans Lindgren
Hans Lindgren
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1204 Visits: 366
Matt Miller (#4) (5/30/2008)

CREATE NONCLUSTERED INDEX IX_OrderDetailDateProdSold ON dbo.OrderDetail
( OrderDate ASC, ProductID ASC) INCLUDE (QtySold);



Matt,

Any specific reasons you wouldn't go for:
CREATE NONCLUSTERED INDEX IX_OrderDetailDateProdSold ON dbo.OrderDetail
( ProductID ASC, OrderDate ASC) INCLUDE (QtySold);


which (quite probably.Here I assume more products then dates in your solution) would have a much higher cardinality and would be far more effictive?

Regards,
Hans



Hans Lindgren
Hans Lindgren
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1204 Visits: 366
tfifield (5/30/2008)

Can anyone tell me if there is any functional or performance difference between designing a covering index and an index that includes columns that will be queried.

Hi,

I'd like to point out that a covered index contains all columns in every node of the index while a index with included columns only contains all columns on the leaf level.

I.e. a Covered index is wider in every node, hence takes more space and will be less performant for queries of the type
SELECT col1,col2,col3
FROM tab1
WHERE col1=... AND col2=...
(where col1 and col2 are in both types of indexes and col3 is in the covered index but Included in the 'Included Columns Index')

Regards,
Hanslindgren



SQLRNNR
SQLRNNR
SSC-Insane
SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)SSC-Insane (21K reputation)

Group: General Forum Members
Points: 21071 Visits: 18259
As for the covering index vs. include topic, I would recommend reading an article by Josef Richburg and the ensuing discussion on the topic. You can find the article here.

I would also recommend reading up on Gail Shaws articles on the topic. You can find her first article in the series [urlhttp://www.sqlservercentral.com/articles/Indexing/68439/]here[/url].

In the discussion on Josef's article, it is pointed out that the space saved is negligible between the covering index and the include. Also, Matt's answer pretty much nailed it otherwise.



Jason AKA CirqueDeSQLeil
I have given a name to my pain...
MCM SQL Server, MVP


SQL RNNR

Posting Performance Based Questions - Gail Shaw

manub22
manub22
SSC-Enthusiastic
SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)

Group: General Forum Members
Points: 137 Visits: 1859
+1 for Matt's response.

Theoretically Covering Index & Included Columns are same. The difference should be cited as: Covering Index/Included Columns vs Composite Index.


~manoj | LinkedIn | Facebook | YouTube
Blog: SQLwithManoj.com

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: 47187 Visits: 44356
Please note: 6 year old thread.

Edit:
Theoretically Covering Index & Included Columns are same.

No. Definitely not.


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


manub22
manub22
SSC-Enthusiastic
SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)SSC-Enthusiastic (137 reputation)

Group: General Forum Members
Points: 137 Visits: 1859
I was anticipating this kind of reply :-)

just stumbled on this thread, didn't realized its 6yrs old w00t

But the fact remains same right, then & now? Cool


~manoj | LinkedIn | Facebook | YouTube
Blog: SQLwithManoj.com

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