May 5, 2014 at 8:25 am
These index came from the query that reported missing indexes, but I’m just trying to get a better understanding and I have following questions: I would appreciate if anyone can help and provide guidance.
On the AddressLink indexes – do we need two separate indexes for AddressID, DefaultAddress where one includes CustomerID and one includes VendorID? The index on CustomerID includes AddressID, but the one on VendorID doesn’t include it?
CREATE INDEX [IX_New_index_AddressLink1] ON [dbo].[AddressLink] ([AddressID], [DefaultAddress]) INCLUDE ([CustomerID])
CREATE INDEX [IX_New_index_AddressLink2] ON [dbo].[AddressLink] ([AddressID], [DefaultAddress]) INCLUDE ([VendorID])
CREATE INDEX [IX_New_index_AddressLink3] ON [dbo].[AddressLink] ([CustomerID]) INCLUDE ([AddressID])
CREATE INDEX [IX_New_index_AddressLink4] ON [dbo].[AddressLink] ([VendorID])
On the AddressTaxLink indexes – both indexes are on AddressID, but one includes TaxID and the other doesn’t. Do we need two indexes here?
CREATE INDEX [IX_New_index_AddressTaxLink1] ON [dbo].[AddressTaxLink] ([AddressID])
CREATE INDEX [IX_New_index_AddressTaxLink2] ON [dbo].[AddressTaxLink] ([AddressID]) INCLUDE ([TaxID])
Similar questions for the indexes on ContactAddressLink – both are on ContactID, but one includes AddressID and the other doesn’t – are both needed?
CREATE INDEX [IX_New_index_ContactAddressLink1] ON [dbo].[ContactAddressLink] ([ContactID])
CREATE INDEX [IX_New_index_ContactAddressLink2] ON [dbo].[ContactAddressLink] ([ContactID]) INCLUDE ([AddressID])
On the ContactPhoneLink indexes – one of the indexes includes ID, PhoneID, PhoneTypeID, and DefaultPhone and one of the indexes includes three of those four fields – do we need both indexes or can we just create the one that has all four fields?
CREATE INDEX [IX_New_index_ContactPhoneLink2] ON [dbo].[ContactPhoneLink] ([ContactID]) INCLUDE ([ID], [PhoneID], [PhoneTypeID], [DefaultPhone])
CREATE INDEX [IX_New_index_ContactPhoneLink3] ON [dbo].[ContactPhoneLink] ([ContactID]) INCLUDE ([PhoneID], [PhoneTypeID], [DefaultPhone])
On the OrderCommission indexes – do we need both or could we create just the first one?
CREATE INDEX [IX_New_index_OrderCommission2] ON [dbo].[OrderCommission] ([OrderID], [PrimarySalesperson]) INCLUDE ([SalespersonID])
CREATE INDEX [IX_New_index_OrderCommission3] ON [dbo].[OrderCommission] ([PrimarySalesperson]) INCLUDE ([OrderID], [SalespersonID])
On the Orders indexes – do we need all three of these or could we create one that included ID, CustomerPO, OrderDate, OrderNumber?
CREATE INDEX [IX_New_index_Orders7] ON [dbo].[Orders] ([OrderTypeID]) INCLUDE ([ID], [CustomerPO])
CREATE INDEX [IX_New_index_Orders8] ON [dbo].[Orders] ([OrderTypeID]) INCLUDE ([ID], [OrderDate])
CREATE INDEX [IX_New_index_Orders9] ON [dbo].[Orders] ([OrderTypeID]) INCLUDE ([ID], [OrderNumber])
May 5, 2014 at 8:35 am
The missing index DMV always recommends the exact best index for a single query. It takes makes no consideration as to whether the index is a near-duplicate with an existing or already recommended index. The list from the DMV will frequently include multiple redundant indexes.
In your example, the only set that can't be consolidated without any reduction in performance is the two on OrderCommission.
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
May 5, 2014 at 8:44 am
Some of the worst performance messes I have ever had to untangle at clients were due to the use of DTA by unqualified individuals. 2 clients made their systems essentially non-functional (and neither had the ability to unwind what they did).
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
May 5, 2014 at 8:54 am
So, other than just the size of the index, what's different about these two:
CREATE INDEX [IX_New_index_AddressLink1] ON [dbo].[AddressLink] ([AddressID], [DefaultAddress]) INCLUDE ([CustomerID])
CREATE INDEX [IX_New_index_AddressLink2] ON [dbo].[AddressLink] ([AddressID], [DefaultAddress]) INCLUDE ([VendorID])
And just doing this:
CREATE INDEX [IX_New_index_AddressLink1] ON [dbo].[AddressLink] ([AddressID], [DefaultAddress]) INCLUDE ([CustomerID],[VendorID])
The simple fact is, nothing. You'd be better off with that index than the two up above.
But, that doesn't address the fact that you don't have a clue which queries this index was suggested for. The missing index DMVs can be useful for suggestions, but if you really want to correlate queries to missing index suggestions, you need to query the procedure cache directly. And even then, you should test to validate that these index suggestions are actually helpful to the queries involved.
This is an introductory query [/url]I wrote for pulling information from the plan cache.
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
May 5, 2014 at 9:55 am
Thanks for the reply
"" you need to query the procedure cache directly.""
can you please clarify this as I am confuse about the about line.
May 5, 2014 at 10:39 am
Did you follow the link to the query I posted? It shows how to query the Dynamic Management Views that give you access to the plans in cache such as sys.dm_exec_query_stats and sys.dm_exec_query_plan. I introduced the query here[/url], describing a bit more about why I originally wrote it. There are also links to other people's versions of the same type of query in the comments.
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
May 5, 2014 at 10:43 am
As others have noted, never create indexes just because dta recommends them.
More importantly, though, the single most important performance factor is first getting the best clustered index. (Barring some emergency situation), Only after you get the best clustered index should you worry about nonclustered index(es).
SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply