Using Covering Index
A Non Clustered Index which contains all columns which are referred by a Query (in Select, Where or Join) is called Covering Index.
In other words
When all columns which are required to satisfy the query are included in a non-clustered Index to avoid extra key lookup that index is known as Covering index.
This type of index can effectively improve the query performance. To understand the reason why Covering index helps in gaining extra performance let’s do some testing.
In this example, I’ll be creating two identical tables Stock & Stock1 with exactly same data and number of rows. To test the performance benefits, we’ve to create different type of indexes on both tables. On first table we’ll create an Index with all key columns and on Second table we’ll create a Covering index which will also include the non-key column. Let’s see whether it impacted the performance or not.
This is the query which we need to test: (Queries are given below)
select PID, Qty, calories, PName from Stock where Qty>=11 and calories< 200
On Table Stock we created a Clustered Index on PID and a non clustered index on Qty and Calories whereas on Table Stock1 we created a clustered Index on PID and a NON Clustered Index on Qty and Calories along with these two columns we also included a non-key column PName to convert this index into a covering index.
In First table, the Query uses the non-clustered index to get PID,Qty and calories and once all these values are available SQL Engine will search the PName column at the leaf node of the clustered Index (Basically it will be a lookup against the Clustering key which is PID) . Now if we could avoid traversing Clustered index to get relevant PName values we can easily improve the query performance; to do so We created another table Stock1 where the non-clustered index was created on Qty and calories but PName (a non-key column) was included in the index; Since the non clustered index already has the PName values now there is no need to traverse the Clustered index and we can save those resources.
When we executed both these queries after enabling Statistics IO ON; we saw a decrease in Logical Reads from 43 to 39. I know the numbers are not too much and theres not a major difference but there is definitely a improvement which depends heavily on Number of records & selection criterion.
Then we compared the Execution plans and saw that the first query on Stock table where we don’t have non-key column in the index that is taking 93% resources compared to second table query which is just 7%.
Moreover, if you compare the IO and CPU Cost there is a drastic improvement. Hence we can conclude by saying that performance wise Covering indexes are much better then any other normal Non Clustered Index.
In-case, you want to test this you can use the below mentioned query. (Don’t execute queries on your production box, these queries are provided as is without any warranty)
create database Test_Sarab
go
use test_sarab
go
create table Stock
(
PID int Identity primary key,
Qty int,
calories int,
PName varchar(30)
)
create table Stock1
(
PID int Identity primary key,
Qty int,
calories int,
PName varchar(30)
)
insert into Stock values
(10, 267, ‘Doughnut Custard’),
(11, 410, ‘Doughnut Iced Glazed’),
(11, 256, ‘Doughnut Jam’),
(11, 266, ‘Muffin Blueberry’),
(11, 149, ‘Breakfast Muffin’),
(13, 401, ‘Muffin Chocolate Chip’),
(9, 141, ‘Wholemeal Muffin’),
(13, 78, ‘Brown Bread’)
go 1001
insert into Stock1 values
(10, 267, ‘Doughnut Custard’),
(11, 410, ‘Doughnut Iced Glazed’),
(11, 256, ‘Doughnut Jam’),
(11, 266, ‘Muffin Blueberry’),
(11, 149, ‘Breakfast Muffin’),
(13, 401, ‘Muffin Chocolate Chip’),
(9, 141, ‘Wholemeal Muffin’),
(13, 78, ‘Brown Bread’)
go 1001
create index Id2 on Stock (Qty, calories)
create index FinalIDx on Stock1 (Qty, calories) include (PName)
–dbcc dropcleanbuffers
SET STATISTICS IO ON;
select PID, Qty, calories, PName from Stock where Qty>=11 and calories< 200
select PID, Qty, calories, PName from Stock1 where Qty>=11 and calories< 200
Thanks,
Sarabpreet Singh Anand
Pingback: SQL Tip-6 | Use Covering Index to solve key lookup issues » Sarabpreet Singh Anand