TechNet
Export (0) Print
Expand All

sys.dm_db_missing_index_columns (Transact-SQL)

 

Updated: June 10, 2016

THIS TOPIC APPLIES TO:yesSQL Server (starting with 2008)yesAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Returns information about database table columns that are missing an index, excluding spatial indexes. sys.dm_db_missing_index_columns is a dynamic management function.

  
sys.dm_db_missing_index_columns(index_handle)  

index_handle
An integer that uniquely identifies a missing index. It can be obtained from the following dynamic management objects:

sys.dm_db_missing_index_details (Transact-SQL)

sys.dm_db_missing_index_groups (Transact-SQL)

Column nameData typeDescription
column_idintID of the column.
column_namesysnameName of the table column.
column_usagevarchar(20)How the column is used by the query. The possible values and their descriptions are:

EQUALITY: Column contributes to a predicate that expresses equality, of the form:
                        table.column = constant_value

INEQUALITY: Column contributes to a predicate that expresses inequality, for example, a predicate of the form: table.column > constant_value. Any comparison operator other than "=" expresses inequality.

INCLUDE: Column is not used to evaluate a predicate, but is used for another reason, for example, to cover a query.

Information returned by sys.dm_db_missing_index_columns is updated when a query is optimized by the query optimizer, and is not persisted. Missing index information is kept only until SQL Server is restarted. Database administrators should periodically make backup copies of the missing index information if they want to keep it after server recycling.

If a transaction creates or drops a table, the rows containing missing index information about the dropped objects are removed from this dynamic management object, preserving transaction consistency.

Users must be granted the VIEW SERVER STATE permission or any permission that implies the VIEW SERVER STATE permission to query this dynamic management function.

The following example runs a query against the Address table and then runs a query using the sys.dm_db_missing_index_columns dynamic management view to return the table columns that are missing an index.

USE AdventureWorks2012;  
GO  
SELECT City, StateProvinceID, PostalCode  
FROM Person.Address  
WHERE StateProvinceID = 9;  
GO  
SELECT mig.*, statement AS table_name,  
    column_id, column_name, column_usage  
FROM sys.dm_db_missing_index_details AS mid  
CROSS APPLY sys.dm_db_missing_index_columns (mid.index_handle)  
INNER JOIN sys.dm_db_missing_index_groups AS mig ON mig.index_handle = mid.index_handle  
ORDER BY mig.index_group_handle, mig.index_handle, column_id;  
GO  

sys.dm_db_missing_index_details (Transact-SQL)
sys.dm_db_missing_index_groups (Transact-SQL)
sys.dm_db_missing_index_group_stats (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft