Technical Article

Unused Indexes

,

This script will provide a list of indexes that are not used in a database. Indexes are overhead and any indexes not being used but are being updated cause additional load on a database. This looks at the following  items: User seeks, scans and lookups. If all three of these are zero and the User Updates column is above zero this means we are using resources to keep these indexes up todate but we are not getting benefit from them. One thing to remember is index information comes from DM's and they are cleared whenever SQL is restarted. Make sure your SQL server has been running for at least a month to ensure you capture enough data. Always keep the drop and create index code in case you do need to create an index you dropped. Always test in a Dev environment whenever possible.

-- Unused Index Script
-- Original Author: David Waller 
-- Date: 4/2020
SELECT TOP 25
o.name AS ObjectName
, i.name AS IndexName
, i.index_id AS IndexID
, dm_ius.user_seeks AS UserSeek
, dm_ius.user_scans AS UserScans
, dm_ius.user_lookups AS UserLookups
, dm_ius.user_updates AS UserUpdates
, p.TableRows
, 'DROP INDEX ' + QUOTENAME(i.name)
+ ' ON ' + QUOTENAME(s.name) + '.'
+ QUOTENAME(OBJECT_NAME(dm_ius.OBJECT_ID)) AS 'drop statement'
FROM sys.dm_db_index_usage_stats dm_ius
INNER JOIN sys.indexes i ON i.index_id = dm_ius.index_id 
AND dm_ius.OBJECT_ID = i.OBJECT_ID
INNER JOIN sys.objects o ON dm_ius.OBJECT_ID = o.OBJECT_ID
INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
INNER JOIN (SELECT SUM(p.rows) TableRows, p.index_id, p.OBJECT_ID
FROM sys.partitions p GROUP BY p.index_id, p.OBJECT_ID) p
ON p.index_id = dm_ius.index_id AND dm_ius.OBJECT_ID = p.OBJECT_ID
WHERE OBJECTPROPERTY(dm_ius.OBJECT_ID,'IsUserTable') = 1
AND dm_ius.database_id = DB_ID()
AND i.type_desc = 'nonclustered'
AND i.is_primary_key = 0
AND i.is_unique_constraint = 0
and dm_ius.user_seeks = 0
and dm_ius.user_scans = 0
and dm_ius.user_lookups = 0
ORDER BY dm_ius.user_updates desc
GO

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating