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

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:

Value

Description

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.

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.

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.

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 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

See Also

Reference

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)