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

Covering Index vs Included Columns Expand / Collapse
Author
Message
Posted Friday, May 30, 2008 12:39 PM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Monday, January 27, 2014 7:07 PM
Points: 959, Visits: 2,879
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);
Post #509318
Posted Friday, May 30, 2008 12:53 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:41 PM
Points: 7,090, Visits: 14,715
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?
Post #509326
Posted Friday, May 30, 2008 1:06 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Yesterday @ 6:12 AM
Points: 10,910, Visits: 12,553
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

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
Post #509334
Posted Saturday, May 31, 2008 11:01 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Monday, January 27, 2014 7:07 PM
Points: 959, Visits: 2,879
Thanks guys. It makes sense I'll give it a whirl.
Todd Fifield
Post #509487
Posted Tuesday, April 13, 2010 3:03 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, September 05, 2013 7:04 AM
Points: 1,197, Visits: 294
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



Post #902213
Posted Tuesday, April 13, 2010 3:12 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, September 05, 2013 7:04 AM
Points: 1,197, Visits: 294
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



Post #902217
Posted Tuesday, April 13, 2010 5:50 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Yesterday @ 5:28 PM
Points: 20,483, Visits: 14,136
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


SQL RNNR

Posting Performance Based Questions - Gail Shaw
Posting Data Etiquette - Jeff Moden
Hidden RBAR - Jeff Moden
VLFs and the Tran Log - Kimberly Tripp
Post #902815
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse