Suggesting MS SQL Index Creations Using sys.dm_db_missing_index_details

Within SQL Server, sys.dm_db_missing_index_details returns indexes which it believes are required by the Query Optimiser. Basically as queries are run in the background, the Query Optimiser makes a record of any optimisations it feels are necessary. Restarting the SQL server resets all these stats.

Using some SQL it is possible to identify potentially missing indexes, create sample SQL to build these indexes. I’ve found the following SQL useful:

SELECT mid.statement
	,migs.avg_total_user_cost * (migs.avg_user_impact / 100.0) * (migs.user_seeks + migs.user_scans) AS improvement_measure
	,'CREATE INDEX [missing_index_' + CONVERT(VARCHAR, mig.index_group_handle) + '_' + CONVERT(VARCHAR, mid.index_handle) + '_' + LEFT(PARSENAME(mid.statement, 1), 32) + ']' + ' ON ' + mid.statement + ' (' + ISNULL(mid.equality_columns, '') + CASE 
		WHEN mid.equality_columns IS NOT NULL
			AND mid.inequality_columns IS NOT NULL
			THEN ','
		ELSE ''
		END + ISNULL(mid.inequality_columns, '') + ')' + ISNULL(' INCLUDE (' + mid.included_columns + ')', '') AS create_index_statement
	,migs.*
	,mid.database_id
	,mid.[object_id]
FROM sys.dm_db_missing_index_groups mig
INNER JOIN sys.dm_db_missing_index_group_stats migs ON migs.group_handle = mig.index_group_handle
INNER JOIN sys.dm_db_missing_index_details mid ON mig.index_handle = mid.index_handle
WHERE migs.avg_total_user_cost * (migs.avg_user_impact / 100.0) * (migs.user_seeks + migs.user_scans) > 10
ORDER BY migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans) DESC

This produces results as follows:

Columns include:

  • statement – The table affected
  • improvement_measure – A generated measure of improvement (based on user cost, impact, seeks etc)
  • create_index_statement – A cut and paste friendly statement to add the index
  • group_handle – Identifies a group of missing indexes. This identifier is unique across the server.
  • unique_compiles – Number of compilations and recompilations that would benefit from this missing index group
  • user_seeks – Number of seeks caused by user queries that the recommended index in the group could have been used for
  • user_scans – Number of scans caused by user queries that the recommended index in the group could have been used for.
  • last_user_seek – Date and time of last seek caused by user queries that the recommended index in the group could have been used for.
  • last_user_scan – Date and time of last scan caused by user queries that the recommended index in the group could have been used for.
  • avg_total_user_cost – Average cost of the user queries that could be reduced by the index in the group.
  • avg_user_impact – Average percentage benefit that user queries could experience if this missing index group was implemented.
  • system_seeks – Number of seeks caused by system queries, such as auto stats queries, that the recommended index in the group could have been used for.
  • last_system_seek – Date and time of last system seek caused by system queries that the recommended index in the group could have been used for.
  • last_system_scan – Date and time of last system scan caused by system queries that the recommended index in the group could have been used for.
  • avg_total_system_cost – Average cost of the system queries that could be reduced by the index in the group.
  • avg_system_impact – Average percentage benefit that system queries could experience if this missing index group was implemented.
  • database_id – The ID number of the database
  • object_id – The ID number of the object

Leave a Reply

This site uses Akismet to reduce spam. Learn how your comment data is processed.