Created
August 11, 2020 10:09
-
-
Save ebicoglu/ebe2d8649f61c7e64bd724243f7d7237 to your computer and use it in GitHub Desktop.
Finds missing indexes for SQL
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
SELECT | |
OBJECT_NAME(id.[object_id], db.[database_id]) AS [Table] | |
,id.[equality_columns] AS [EqualityColumns] | |
,id.[inequality_columns] AS [InEqualityColumns] | |
,id.[included_columns] AS [IncludedColumns] | |
,gs.[avg_total_user_cost] AS [UserCost] -- Average cost of the user queries that could be reduced by the index in the group. | |
,gs.[avg_user_impact] AS [QueryBoostImpact] -- The value means that the query cost would on average drop by this percentage if this missing index group was implemented. | |
,gs.[user_seeks] * gs.[avg_total_user_cost] * (gs.[avg_user_impact] * 0.01) AS [IndexAdvantage] | |
,'CREATE INDEX [IX_' + OBJECT_NAME(id.[object_id], db.[database_id]) + '_' + REPLACE(REPLACE(REPLACE(ISNULL(id.[equality_columns], ''), ', ', '_'), '[', ''), ']', '') + CASE | |
WHEN id.[equality_columns] IS NOT NULL | |
AND id.[inequality_columns] IS NOT NULL | |
THEN '_' | |
ELSE '' | |
END + REPLACE(REPLACE(REPLACE(ISNULL(id.[inequality_columns], ''), ', ', '_'), '[', ''), ']', '') + '_' + LEFT(CAST(NEWID() AS [nvarchar](64)), 5) + ']' + ' ON ' + id.[statement] + ' (' + ISNULL(id.[equality_columns], '') + CASE | |
WHEN id.[equality_columns] IS NOT NULL | |
AND id.[inequality_columns] IS NOT NULL | |
THEN ',' | |
ELSE '' | |
END + ISNULL(id.[inequality_columns], '') + ')' + ISNULL(' INCLUDE (' + id.[included_columns] + ')', '') AS [Index Create Script] | |
FROM [sys].[dm_db_missing_index_group_stats] gs WITH (NOLOCK) | |
INNER JOIN [sys].[dm_db_missing_index_groups] ig WITH (NOLOCK) ON gs.[group_handle] = ig.[index_group_handle] | |
INNER JOIN [sys].[dm_db_missing_index_details] id WITH (NOLOCK) ON ig.[index_handle] = id.[index_handle] | |
INNER JOIN [sys].[databases] db WITH (NOLOCK) ON db.[database_id] = id.[database_id] | |
WHERE db.[database_id] = DB_ID() | |
ORDER BY [IndexAdvantage] DESC | |
OPTION (RECOMPILE); |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
This worked great, thanks