view_IndexCreation.sql 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269
  1. --
  2. -- 2007-10-11 Pedro Lopes (Microsoft) [email protected]
  3. --
  4. -- 2008-01-17 Check for possibly redundant indexes in the output.
  5. -- 2009-05-21 Changed index scoring method; Disregards indexes with [Score] < 100000 and [User_Hits_on_Missing_Index] < 99;
  6. -- 2013-03-21 Changed database loop method;
  7. -- 2013-11-10 Added search for redundant indexes in missing indexes;
  8. -- 2022-11-22 Fixed issue with included column index generation
  9. SET NOCOUNT ON;
  10. SET QUOTED_IDENTIFIER ON;
  11. DECLARE @IC VARCHAR(4000), @ICWI VARCHAR(4000), @editionCheck bit
  12. /* Refer to http://docs.microsoft.com/sql/t-sql/functions/serverproperty-transact-sql */
  13. IF (SELECT SERVERPROPERTY('EditionID')) IN (1804890536, 1872460670, 610778273, -2117995310)
  14. SET @editionCheck = 1 -- supports enterprise only features
  15. ELSE
  16. SET @editionCheck = 0; -- does not support enterprise only features
  17. -- Create the helper functions
  18. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_allcols'')) DROP FUNCTION dbo.fn_createindex_allcols')
  19. EXEC ('USE tempdb; EXEC(''
  20. CREATE FUNCTION dbo.fn_createindex_allcols (@ix_handle int)
  21. RETURNS NVARCHAR(max)
  22. AS
  23. BEGIN
  24. DECLARE @ReturnCols NVARCHAR(max)
  25. ;WITH ColumnToPivot ([data()]) AS (
  26. SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''',''''
  27. FROM sys.dm_db_missing_index_details id
  28. CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
  29. WHERE id.index_handle = @ix_handle
  30. ORDER BY ic.column_id ASC
  31. FOR XML PATH(''''''''), TYPE
  32. ),
  33. XmlRawData (CSVString) AS (
  34. SELECT (SELECT [data()] AS InputData
  35. FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol
  36. )
  37. SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
  38. FROM XmlRawData
  39. RETURN (@ReturnCols)
  40. END'')
  41. ')
  42. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_keycols'')) DROP FUNCTION dbo.fn_createindex_keycols')
  43. EXEC ('USE tempdb; EXEC(''
  44. CREATE FUNCTION dbo.fn_createindex_keycols (@ix_handle int)
  45. RETURNS NVARCHAR(max)
  46. AS
  47. BEGIN
  48. DECLARE @ReturnCols NVARCHAR(max)
  49. ;WITH ColumnToPivot ([data()]) AS (
  50. SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''',''''
  51. FROM sys.dm_db_missing_index_details id
  52. CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
  53. WHERE id.index_handle = @ix_handle
  54. AND (ic.column_usage = ''''EQUALITY'''' OR ic.column_usage = ''''INEQUALITY'''')
  55. ORDER BY ic.column_id ASC
  56. FOR XML PATH(''''''''), TYPE
  57. ),
  58. XmlRawData (CSVString) AS (
  59. SELECT (SELECT [data()] AS InputData
  60. FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol
  61. )
  62. SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
  63. FROM XmlRawData
  64. RETURN (@ReturnCols)
  65. END'')
  66. ')
  67. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_includedcols'')) DROP FUNCTION dbo.fn_createindex_includedcols')
  68. EXEC ('USE tempdb; EXEC(''
  69. CREATE FUNCTION dbo.fn_createindex_includedcols (@ix_handle int)
  70. RETURNS NVARCHAR(max)
  71. AS
  72. BEGIN
  73. DECLARE @ReturnCols NVARCHAR(max)
  74. ;WITH ColumnToPivot ([data()]) AS (
  75. SELECT CONVERT(VARCHAR(3),ic.column_id) + N'''',''''
  76. FROM sys.dm_db_missing_index_details id
  77. CROSS APPLY sys.dm_db_missing_index_columns(id.index_handle) ic
  78. WHERE id.index_handle = @ix_handle
  79. AND ic.column_usage = ''''INCLUDE''''
  80. ORDER BY ic.column_id ASC
  81. FOR XML PATH(''''''''), TYPE
  82. ),
  83. XmlRawData (CSVString) AS (
  84. SELECT (SELECT [data()] AS InputData
  85. FROM ColumnToPivot AS d FOR XML RAW, TYPE).value(''''/row[1]/InputData[1]'''', ''''NVARCHAR(max)'''') AS CSVCol
  86. )
  87. SELECT @ReturnCols = CASE WHEN LEN(CSVString) <= 1 THEN NULL ELSE LEFT(CSVString, LEN(CSVString)-1) END
  88. FROM XmlRawData
  89. RETURN (@ReturnCols)
  90. END'')
  91. ')
  92. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexCreation'))
  93. DROP TABLE #IndexCreation
  94. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexCreation'))
  95. CREATE TABLE #IndexCreation (
  96. [database_id] int,
  97. DBName VARCHAR(255),
  98. [Table] VARCHAR(255),
  99. [ix_handle] int,
  100. [User_Hits_on_Missing_Index] int,
  101. [Estimated_Improvement_Percent] DECIMAL(5,2),
  102. [Avg_Total_User_Cost] int,
  103. [Unique_Compiles] int,
  104. [Score] NUMERIC(19,3),
  105. [KeyCols] VARCHAR(1000),
  106. [IncludedCols] VARCHAR(4000),
  107. [Ix_Name] VARCHAR(255),
  108. [AllCols] NVARCHAR(max),
  109. [KeyColsOrdered] NVARCHAR(max),
  110. [IncludedColsOrdered] NVARCHAR(max)
  111. )
  112. IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexRedundant'))
  113. DROP TABLE #IndexRedundant
  114. IF NOT EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID('tempdb.dbo.#IndexRedundant'))
  115. CREATE TABLE #IndexRedundant (
  116. DBName VARCHAR(255),
  117. [Table] VARCHAR(255),
  118. [Ix_Name] VARCHAR(255),
  119. [ix_handle] int,
  120. [KeyCols] VARCHAR(1000),
  121. [IncludedCols] VARCHAR(4000),
  122. [Redundant_With] VARCHAR(255)
  123. )
  124. INSERT INTO #IndexCreation
  125. SELECT i.database_id,
  126. m.[name],
  127. RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)) AS [Table],
  128. i.index_handle AS [ix_handle],
  129. [User_Hits_on_Missing_Index] = (s.user_seeks + s.user_scans),
  130. s.avg_user_impact, -- Query cost would reduce by this amount in percentage, on average.
  131. s.avg_total_user_cost, -- Average cost of the user queries that could be reduced by the index in the group.
  132. s.unique_compiles, -- Number of compilations and recompilations that would benefit from this missing index group.
  133. (CONVERT(NUMERIC(19,3), s.user_seeks) + CONVERT(NUMERIC(19,3), s.user_scans))
  134. * CONVERT(NUMERIC(19,3), s.avg_total_user_cost)
  135. * CONVERT(NUMERIC(19,3), s.avg_user_impact) AS Score, -- The higher the score, higher is the anticipated improvement for user queries.
  136. CASE WHEN (i.equality_columns IS NOT NULL AND i.inequality_columns IS NULL) THEN i.equality_columns
  137. WHEN (i.equality_columns IS NULL AND i.inequality_columns IS NOT NULL) THEN i.inequality_columns
  138. ELSE i.equality_columns + ',' + i.inequality_columns END AS [KeyCols],
  139. i.included_columns AS [IncludedCols],
  140. 'IX_' + LEFT(RIGHT(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), LEN(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3))) - (CHARINDEX('.', RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), 1)) - 1),
  141. LEN(RIGHT(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), LEN(RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3))) - (CHARINDEX('.', RIGHT(i.[statement], LEN(i.[statement]) - (LEN(m.[name]) + 3)), 1)) - 1)) - 1) + '_' + CAST(i.index_handle AS NVARCHAR) AS [Ix_Name],
  142. tempdb.dbo.fn_createindex_allcols(i.index_handle),
  143. tempdb.dbo.fn_createindex_keycols(i.index_handle),
  144. tempdb.dbo.fn_createindex_includedcols(i.index_handle)
  145. FROM sys.dm_db_missing_index_details i
  146. INNER JOIN master.sys.databases m ON i.database_id = m.database_id
  147. INNER JOIN sys.dm_db_missing_index_groups g ON i.index_handle = g.index_handle
  148. INNER JOIN sys.dm_db_missing_index_group_stats s ON s.group_handle = g.index_group_handle
  149. WHERE i.database_id > 4
  150. INSERT INTO #IndexRedundant
  151. SELECT I.DBName, I.[Table], I.[Ix_Name], I.[ix_handle], I.[KeyCols], I.[IncludedCols], I2.[Ix_Name]
  152. FROM #IndexCreation I
  153. INNER JOIN #IndexCreation I2 ON I.[database_id] = I2.[database_id] AND I.[Table] = I2.[Table] AND I.[Ix_Name] <> I2.[Ix_Name]
  154. AND (((I.KeyColsOrdered <> I2.KeyColsOrdered OR I.[IncludedColsOrdered] <> I2.[IncludedColsOrdered])
  155. AND ((CASE WHEN I.[IncludedColsOrdered] IS NULL THEN I.KeyColsOrdered ELSE I.KeyColsOrdered + ',' + I.[IncludedColsOrdered] END) = (CASE WHEN I2.[IncludedColsOrdered] IS NULL THEN I2.KeyColsOrdered ELSE I2.KeyColsOrdered + ',' + I2.[IncludedColsOrdered] END)
  156. OR I.[AllCols] = I2.[AllCols]))
  157. OR (I.KeyColsOrdered <> I2.KeyColsOrdered AND I.[IncludedColsOrdered] = I2.[IncludedColsOrdered])
  158. OR (I.KeyColsOrdered = I2.KeyColsOrdered AND I.[IncludedColsOrdered] <> I2.[IncludedColsOrdered]))
  159. WHERE I.[Score] >= 100000
  160. AND I2.[Score] >= 100000
  161. GROUP BY I.DBName, I.[Table], I.[Ix_Name], I.[ix_handle], I.[KeyCols], I.[IncludedCols], I2.[Ix_Name]
  162. ORDER BY I.DBName, I.[Table], I.[Ix_Name]
  163. IF (SELECT COUNT(*) FROM #IndexCreation WHERE [Score] >= 100000) > 0
  164. BEGIN
  165. SELECT 'Missing_Indexes' AS [Information], IC.DBName AS [Database_Name], IC.[Table] AS [Table_Name], CONVERT(bigint,[Score]) AS [Score], [User_Hits_on_Missing_Index],
  166. [Estimated_Improvement_Percent], [Avg_Total_User_Cost], [Unique_Compiles], IC.[KeyCols], IC.[IncludedCols], IC.[Ix_Name] AS [Index_Name],
  167. SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR
  168. WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
  169. ORDER BY IR.[Redundant_With]
  170. FOR XML PATH('')), 2, 8000) AS [Possibly_Redundant_With]
  171. FROM #IndexCreation IC
  172. WHERE [Score] >= 100000
  173. ORDER BY IC.DBName, IC.[Score] DESC, IC.[User_Hits_on_Missing_Index], IC.[Estimated_Improvement_Percent];
  174. SELECT DISTINCT 'Possibly_redundant_IXs_in_list' AS Comments, I.DBName AS [Database_Name], I.[Table] AS [Table_Name],
  175. I.[Ix_Name] AS [Index_Name], I.[KeyCols], I.[IncludedCols]
  176. FROM #IndexRedundant I
  177. ORDER BY I.DBName, I.[Table], I.[Ix_Name]
  178. END
  179. ELSE
  180. BEGIN
  181. SELECT 'Missing_Indexes' AS [Information], 'None' AS [Comment]
  182. END;
  183. IF (SELECT COUNT(*) FROM #IndexCreation IC WHERE IC.[IncludedCols] IS NULL AND IC.[Score] >= 100000) > 0
  184. BEGIN
  185. PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
  186. PRINT '--############# Indexes creation statements #############' + CHAR(10)
  187. DECLARE cIC CURSOR FAST_FORWARD FOR
  188. SELECT '-- User Hits on Missing Index ' + IC.[Ix_Name] + ': ' + CONVERT(VARCHAR(20),IC.[User_Hits_on_Missing_Index]) + CHAR(10) +
  189. '-- Estimated Improvement Percent: ' + CONVERT(VARCHAR(6),IC.[Estimated_Improvement_Percent]) + CHAR(10) +
  190. '-- Average Total User Cost: ' + CONVERT(VARCHAR(50),IC.[Avg_Total_User_Cost]) + CHAR(10) +
  191. '-- Unique Compiles: ' + CONVERT(VARCHAR(50),IC.[Unique_Compiles]) + CHAR(10) +
  192. '-- Score: ' + CONVERT(VARCHAR(20),CONVERT(bigint,IC.[Score])) +
  193. CASE WHEN (SELECT COUNT(IR.[Redundant_With]) FROM #IndexRedundant IR
  194. WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]) > 0
  195. THEN CHAR(10) + '-- Possibly Redundant with Missing Index(es): ' + SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR
  196. WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
  197. FOR XML PATH('')), 2, 8000)
  198. ELSE '' END +
  199. CHAR(10) + 'USE ' + QUOTENAME(IC.DBName) + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sysindexes WHERE name = N''' +
  200. IC.[Ix_Name] + ''') DROP INDEX ' + IC.[Table] + '.' +
  201. IC.[Ix_Name] + ';' + CHAR(10) + 'GO' + CHAR(10) + 'CREATE INDEX ' +
  202. IC.[Ix_Name] + ' ON ' + IC.[Table] + ' (' + IC.[KeyCols] + CASE WHEN @editionCheck = 1 THEN ') WITH (ONLINE = ON);' ELSE ');' END + CHAR(10) + 'GO' + CHAR(10)
  203. FROM #IndexCreation IC
  204. WHERE IC.[IncludedCols] IS NULL AND IC.[Score] >= 100000
  205. ORDER BY IC.DBName, IC.[Table], IC.[Ix_Name]
  206. OPEN cIC
  207. FETCH NEXT FROM cIC INTO @IC
  208. WHILE @@FETCH_STATUS = 0
  209. BEGIN
  210. PRINT @IC
  211. FETCH NEXT FROM cIC INTO @IC
  212. END
  213. CLOSE cIC
  214. DEALLOCATE cIC
  215. END;
  216. IF (SELECT COUNT(*) FROM #IndexCreation IC WHERE IC.[IncludedCols] IS NOT NULL AND IC.[Score] >= 100000) > 0
  217. BEGIN
  218. PRINT CHAR(10) + '/* Generated on ' + CONVERT (VARCHAR, GETDATE()) + ' in ' + @@SERVERNAME + ' */' + CHAR(10)
  219. PRINT '--############# Covering indexes creation statements #############' + CHAR(10)
  220. DECLARE cICWI CURSOR FAST_FORWARD FOR
  221. SELECT '-- User Hits on Missing Index ' + IC.[Ix_Name] + ': ' + CONVERT(VARCHAR(20),IC.[User_Hits_on_Missing_Index]) + CHAR(10) +
  222. '-- Estimated Improvement Percent: ' + CONVERT(VARCHAR(6),IC.[Estimated_Improvement_Percent]) + CHAR(10) +
  223. '-- Average Total User Cost: ' + CONVERT(VARCHAR(50),IC.[Avg_Total_User_Cost]) + CHAR(10) +
  224. '-- Unique Compiles: ' + CONVERT(VARCHAR(50),IC.[Unique_Compiles]) + CHAR(10) +
  225. '-- Score: ' + CONVERT(VARCHAR(20),CONVERT(bigint,IC.[Score])) +
  226. CASE WHEN (SELECT COUNT(IR.[Redundant_With]) FROM #IndexRedundant IR
  227. WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]) > 0
  228. THEN CHAR(10) + '-- Possibly Redundant with Missing Index(es): ' + SUBSTRING((SELECT ',' + IR.[Redundant_With] FROM #IndexRedundant IR
  229. WHERE IC.DBName = IR.DBName AND IC.[Table] = IR.[Table] AND IC.[ix_handle] = IR.[ix_handle]
  230. FOR XML PATH('')), 2, 8000)
  231. ELSE '' END +
  232. CHAR(10) + 'USE ' + QUOTENAME(IC.DBName) + CHAR(10) + 'GO' + CHAR(10) + 'IF EXISTS (SELECT name FROM sysindexes WHERE name = N''' +
  233. IC.[Ix_Name] + ''') DROP INDEX ' + IC.[Table] + '.' +
  234. IC.[Ix_Name] + ';' + CHAR(10) + 'GO' + CHAR(10) + 'CREATE INDEX ' +
  235. IC.[Ix_Name] + ' ON ' + IC.[Table] + ' (' + IC.[KeyCols] + ')' + CHAR(10) + 'INCLUDE (' + IC.[IncludedCols] + ')' +
  236. CASE WHEN @editionCheck = 1 THEN ' WITH (ONLINE = ON);' ELSE ';' END + CHAR(10) + 'GO' + CHAR(10)
  237. FROM #IndexCreation IC
  238. WHERE IC.[IncludedCols] IS NOT NULL AND IC.[Score] >= 100000
  239. ORDER BY IC.DBName, IC.[Table], IC.[Ix_Name]
  240. OPEN cICWI
  241. FETCH NEXT FROM cICWI INTO @ICWI
  242. WHILE @@FETCH_STATUS = 0
  243. BEGIN
  244. PRINT @ICWI
  245. FETCH NEXT FROM cICWI INTO @ICWI
  246. END
  247. CLOSE cICWI
  248. DEALLOCATE cICWI
  249. END;
  250. DROP TABLE #IndexCreation
  251. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_keycols'')) DROP FUNCTION dbo.fn_createindex_keycols')
  252. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_allcols'')) DROP FUNCTION dbo.fn_createindex_allcols')
  253. EXEC ('USE tempdb; IF EXISTS (SELECT [object_id] FROM tempdb.sys.objects (NOLOCK) WHERE [object_id] = OBJECT_ID(''tempdb.dbo.fn_createindex_includedcols'')) DROP FUNCTION dbo.fn_createindex_includedcols')
  254. GO