About Me

My photo
Mumbai, Maharastra, India
He has more than 7.6 years of experience in the software development. He has spent most of the times in web/desktop application development. He has sound knowledge in various database concepts. You can reach him at viki.keshari@gmail.com https://www.linkedin.com/in/vikrammahapatra/ https://twitter.com/VikramMahapatra http://www.facebook.com/viki.keshari

Search This Blog

Friday, June 7, 2013

Consequence of Redundant Index on your table.


If have multiple queries where your searching criteria varies from col1 in first query, col1 and col2 in second query, col1 and col3 in third query, how you will be proceeding with index creation.

Let’s stimulate the whole situation by taking an example; we are creating a table employee with some columns.

set nocount on
go

create table dbo.Employee
(emp_id int identity primary key,
first_name varchar(10),
last_name varchar(10),
address varchar(20),
city varchar(10),
state varchar(10),
active bit)
Command(s) completed successfully.

Our table is ready, now lets insert some data into it.

declare @cnt int, @id varchar(4)
select @cnt = 1

while (@cnt <= 10000)
begin
      select @id = cast(@cnt as varchar)
      insert into Employee(first_name, last_name, address, city, active)
      select 'f'+@id, 'l'+@id, 'a'+@id, 'c'+@id, 1
      select @cnt = @cnt + 1
end
Command(s) completed successfully.

Now since we have table Employee in position lets create indexes on the basis of predicate used in the select queries.

create index ix_emp_lastname on dbo.Employee(last_name)
create index ix_emp_lastname_firstname on dbo.Employee(last_name, first_name)
create index ix_emp_lastname_active on dbo.Employee(last_name, active)
go

Now here we have created three indexes on Employee, first on last_name column, second on last_name and first_name, third on last_name and active column.

Lets check out the space used by the index by executing sp_spaceused

exec sp_spaceused Employee
name      rows  reserved  data    index_size unused
--------------- --------- ------- ---------- -------
Employee  10000 1376 KB   432 KB  712 KB     232 KB

So the index is using 712Kb of space. Now lets fire each query and check out the execution plan to see how and which index it is using,

select emp_id from dbo.Employee
where last_name = 'l34'










The first query used index ix_emp_lastname_active, now lets run the second query and see the execution plan

select emp_id from dbo.Employee
where last_name = 'l34' and active = 1









The second query used index ix_emp_lastname_active, now lets run the third query and see the execution plan

select emp_id from dbo.Employee
where first_name = 'f34' and last_name = 'l34'









The third query used index ix_emp_lastname_firstname, now lets run the fourth query and see the execution plan

select emp_id from dbo.Employee
where first_name = 'f34' and last_name = 'l34' and active = 1












Now these are interesting. The first and second queries used index ix_emp_lastname_active. The third query used index ix_emp_lastname_firstname. For the last query, the optimizer decided to use ix_emp_lastname_firstname as well and decided to do a lookup to get the actives value.

NOTE (Intresting Look) : If you haven't noticed yet, index ix_emp_lastname was not used to satisfy any of these queries. It's just sitting around, literally taking up space.

Now let's drop these indexes and add a single index to satisfy the same four queries

drop index dbo.Employee.ix_emp_lastname
drop index dbo.Employee.ix_emp_lastname_firstname
drop index dbo.Employee.ix_emp_lastname_activesw

Lets create a single index which will satisfy the all the query

create index ix_emp_lastname on dbo.Employee(lastname, firstname, active)

If we now re-run sp_spaceused, we'll see that the index space used by the table has been reduced by over 100%

exec sp_spaceused Employee
name     rows        reserved           data    index_size  unused
-------------------- ------------------ ------  ----------  ---------
Employee 10000       846 KB             432 KB  304 KB       112 KB

Lets again execute those queries and see the new execution plan.

select emp_id from dbo.Employee where last_name = 'l34'














Now the first query used index ix_emp_lastname, now lets run the second query and see the execution plan

select emp_id from dbo.Employee where last_name = 'l34' and active = 1











The second query is also using the same index ix_emp_lastname, now lets run the third query and see the execution plan

select emp_id from dbo.Employee where first_name = 'f34' and last_name = 'l34'











Again we can see the third query is also using the same index ix_emp_lastname, now lets run the fourth query and see the execution plan

select emp_id from dbo.Employee where first_name = 'f34' and last_name = 'l34' and active = 1









The fourth query is also using the same index.

Conclusion: the single index satisfies all four queries. In addition, the last query that performed a lookup for the actives now reads it directly from the index and does not resort to searching the clustered table for the value.

If you desire to kill, kill me through code;honor me HEAVEN.


Post Reference: Vikram Aristocratic Elfin Share

No comments:

Post a Comment