Query Types and Indexes
When you are considering whether to create an index on a column, evaluate how the column is used in queries. The following tables describes the query types for which indexes are useful.
Note
The examples in the table are based on the AdventureWorks sample database. When you run the examples in SQL Server Management Studio, you can view the indexes that are selected by the query optimizer by displaying the actual execution plan. For more information, see How to: Display an Actual Execution Plan.
Query in which the column predicate is one of these | Query description and example | Index to consider |
---|---|---|
Exact match to a specific value |
Searches for an exact match in which the query uses the WHERE clause to specify a column entry with a specific value. For example:
|
Nonclustered or clustered index on the |
Exact match to a value in an IN (x,y,z) list |
Searches for an exact match to a value in a specified list of values. For example:
|
Nonclustered or clustered index on the |
Range of values |
Searches for a range of values in which the query specifies any entry that has a value between two values. For example:
Or
|
Clustered or nonclustered index on the |
Join between tables |
Searches for rows in a table that match a row in another table based on a join predicate. For example:
|
Nonclustered or clustered index on the |
LIKE comparison |
Searches for matching rows that start with a specific character string such as 'abc%'. For example:
|
Nonclustered or clustered index on the |
Sorted or aggregated |
Requires an implicit or explicit sort order or an aggregation (GROUP BY). For example:
|
Nonclustered or clustered index on the sorted or aggregated column. For sort columns, consider specifying the ASC or DESC order of the column. |
PRIMARY KEY or UNIQUE constraint |
Searches for duplicates of new index key values in insert and update operations, to enforce PRIMARY KEY and UNIQUE constraints. For example:
|
Clustered or nonclustered index on the column or columns defined in the constraint. |
UPDATE or DELETE operation in a PRIMARY KEY/FOREIGN KEY relationship |
Searches for rows in an update or delete operation in which the column participates in a PRIMARY KEY/FOREIGN KEY relationship, with or without the CASCADE option. |
Nonclustered or clustered index on the foreign key column. |
Column is in the select list but not in the predicate. |
Contains one or more columns in the select list that are not used for searching and lookups. For example:
|
Nonclustered index with |
See Also
Concepts
General Index Design Guidelines
Index with Included Columns