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


Is it a duplicate Index?


Is it a duplicate Index?

Author
Message
Arsh
Arsh
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2341 Visits: 874
Dear Experts,
Have a question about duplicate indexes . Is an Index considered duplicate if the two column keys (Index A with col1+col2) it has are in reverse order of the same two columns used in another index (Index B with col2+col1) ? Thank you.
anthony.green
anthony.green
SSC Guru
SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)SSC Guru (67K reputation)

Group: General Forum Members
Points: 67024 Visits: 8605
No they are not duplicates as the key order is different.

Key order is important as its the way the optimizer searches the index

So IndexA (Col1,Col2), IndexB (Col2,Col1) are not considered duplicated

But IndexA (Col1, Col2), IndexB (Col1, Col2, Col3) then IndexA would be considered the duplicate



How to post data/code for the best help - Jeff Moden
Need a string splitter, try this - Jeff Moden
How to post performance problems - Gail Shaw
Managing Transaction Logs - Gail Shaw
Troubleshooting SQL Server: A Guide for the Accidental DBA - Jonathan Kehayias and Ted Krueger


Arsh
Arsh
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2341 Visits: 874
anthony.green - Thursday, November 9, 2017 1:36 AM
No they are not duplicates as the key order is different.

Key order is important as its the way the optimizer searches the index

So IndexA (Col1,Col2), IndexB (Col2,Col1) are not considered duplicated

But IndexA (Col1, Col2), IndexB (Col1, Col2, Col3) then IndexA would be considered the duplicate

Thank you so much Anthony. Very helpful.

Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)SSC Guru (236K reputation)

Group: General Forum Members
Points: 236244 Visits: 33634
anthony.green - Thursday, November 9, 2017 1:36 AM
No they are not duplicates as the key order is different.

Key order is important as its the way the optimizer searches the index

So IndexA (Col1,Col2), IndexB (Col2,Col1) are not considered duplicated

But IndexA (Col1, Col2), IndexB (Col1, Col2, Col3) then IndexA would be considered the duplicate

I'd say a potential duplicate. Everything say is 100% correct, but it's possible that, depending on the query, IndexB is more useful than IndexA in a given situation because we're filtering on Col1-Col3, not just on Col1 & Col2. That also goes the other way. The first index is smaller than the second, so may be more useful situationally. All that even though, within a pure definition, IndexA is duplicating what IndexB does in your second example. That's why this all gets so hard.

Another point on duplicates is that the first column is the one used to create the histogram for the index, which is one of the primary (but not the only) drivers for the optimizer to determine which index is useful. In that case, depending on your queries, one of those two indexes may never get used, even though it's the better index for a given situation.

Ain't SQL Server fun.


----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101501 Visits: 21396
Grant Fritchey - Thursday, November 9, 2017 6:43 AM
anthony.green - Thursday, November 9, 2017 1:36 AM
No they are not duplicates as the key order is different.

Key order is important as its the way the optimizer searches the index

So IndexA (Col1,Col2), IndexB (Col2,Col1) are not considered duplicated

But IndexA (Col1, Col2), IndexB (Col1, Col2, Col3) then IndexA would be considered the duplicate

I'd say a potential duplicate. Everything say is 100% correct, but it's possible that, depending on the query, IndexB is more useful than IndexA in a given situation because we're filtering on Col1-Col3, not just on Col1 & Col2. That also goes the other way. The first index is smaller than the second, so may be more useful situationally. All that even though, within a pure definition, IndexA is duplicating what IndexB does in your second example. That's why this all gets so hard.

Another point on duplicates is that the first column is the one used to create the histogram for the index, which is one of the primary (but not the only) drivers for the optimizer to determine which index is useful. In that case, depending on your queries, one of those two indexes may never get used, even though it's the better index for a given situation.

Ain't SQL Server fun.


Adding a little bit more.
The reversed order column indexed might be duplicates if you always query by both columns or just one of them but never the other by itself. Although, technically, they're not duplicates, one becomes redundant and might never be used.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)SSC Guru (539K reputation)

Group: General Forum Members
Points: 539209 Visits: 44575
By the same token, there is a type of duplicate index that can provide huge performance increases. They usually (but not always) are considered to be
"Covering Indexes". You can have the "perfect" Clustered Index for your query but, unless you're using a huge number of columns from a very wide table in your query, a much narrower Non-Clustered Index with the exact same key as the Clustered Index and the correct INCLUDES (think of it as being very similar to a much smaller Clustered Index) can make the queries that use the Non-Clustered Index absolutely fly compared to when the query uses the Clustered Index simply because of the greatly reduced page count thanks to more rows per page in the Non_Clustered Index.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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