sys.dm_db_missing_index_columns (Transact-SQL)
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.
Syntax
sys.dm_db_missing_index_columns(index_handle)
Arguments
index_handle
An integer that uniquely identifies a missing index. It can be obtained from the following dynamic management objects:
Table Returned
Column name |
Data type |
Description |
---|---|---|
column_id |
int |
ID of the column. |
column_name |
sysname |
Name of the table column. |
column_usage |
varchar(20) |
How the column is used by the query. Possible values are:
ValueDescription
EQUALITYColumn contributes to a predicate that expresses equality, of the form: table.column =constant_value
INEQUALITYColumn 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. For a complete list of comparison operators, see Comparison Operators (Database Engine).
INCLUDEColumn is not used to evaluate a predicate, but is used for another reason, for example, to cover a query.
|
Remarks
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.
For information about enabling and disabling missing index information collection, see About the Missing Indexes Feature.
The output from the sys.dm_db_missing_index_columns dynamic management function can be used by any tool that can read the missing index information that corresponds to an index_handle, process the information, and convert it into CREATE INDEX DDL statements that implement the missing index. For more information about creating DDL statements, see Using Missing Index Information to Write CREATE INDEX Statements.
For more information about limitations of this feature, see Limitations of the Missing Indexes Feature.
Transaction Consistency
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. For more information about transaction consistency in relation to the missing indexes dynamic management objects, see About the Missing Indexes Feature.
Permissions
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.
Examples
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 AdventureWorks;
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