In the previous article, I showed a quick and dirty method to try and capture the indexes that may have been just created. We all know that in the hectic life of the DBA, it is easy enough to forget the indexes created more than just a few hours in the past.
In that article, I mentioned that the solution provided was far from a complete solution to the entire problem. A bigger part of the picture involves audits to know when and by whom indexes were created, altered or dropped.
Auditing
On many an occasion I have had clients request help with tracking the changes that have occurred to their indexes. The reasons vary slightly but generally boil down to two large categories: 1) to better understand who is making changes and 2) to help ensure proper indexes are not removed due to code promotions (various apps like to wipe out custom indexes which causes performance issues).
With that in mind, the following provides a solution that will help track indexes that have changed (index definition) or that have been added or removed during the audit interval. The interval can be set per your specific requirements. For this specific solution, I have historically just set this to run once a day. The solution is shown below.
USE DBA; GO CREATE TABLE [dbo].[dba_IndexDefChange] ( [IdxChangeID] [INT] IDENTITY(1, 1) NOT NULL , [DBName] [sysname] NOT NULL , [SchemaName] [VARCHAR](25) NULL , [ObjectName] [sysname] NOT NULL , [IndexName] [sysname] NOT NULL , [PollDate] [DATE] NULL , [ChangeType] [VARCHAR](25) NULL , CONSTRAINT [PK__dba_IndexDefChan__2E984B70] PRIMARY KEY CLUSTERED ( [IdxChangeID] ASC ) WITH ( PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF , IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON ) ON [PRIMARY] ) ON [PRIMARY]; GO CREATE TABLE [dbo].[dba_IndexDefs] ( [IndexDefID] [INT] IDENTITY(1, 1) NOT NULL , [DBName] [NVARCHAR](128) NOT NULL , [ObjectID] [INT] NOT NULL , [IndexID] [INT] NOT NULL , [SchemaName] [NVARCHAR](128) NULL , [ObjectName] [NVARCHAR](128) NULL , [IndexName] [sysname] NULL , [ObjectType] [VARCHAR](5) NOT NULL , [IndexColumns] [NVARCHAR](MAX) NULL , [IncludeColumns] [NVARCHAR](MAX) NULL , [IsClustered] [VARCHAR](3) NOT NULL , [IsUnique] [VARCHAR](3) NOT NULL , [AllowRowLocks] [VARCHAR](3) NOT NULL , [AllowPageLocks] [VARCHAR](3) NOT NULL , [LastUpdatedDate] [DATETIME] NULL , [IndexFillFactor] [TINYINT] NOT NULL , [data_compression_desc] [NVARCHAR](60) NULL , [filter_definition] [NVARCHAR](MAX) NULL , [CreateStatement] [NVARCHAR](MAX) NULL , [PollDate] [DATE] NOT NULL , [IndexRev] [INT] NOT NULL , CONSTRAINT [PK_dba_IndexDefs] PRIMARY KEY CLUSTERED ( [IndexDefID] ASC , [DBName] ASC , [ObjectID] ASC , [IndexID] ASC ) WITH ( PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF , IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON ) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; GO CREATE TABLE [dbo].[dba_IndexDefsStage] ( [DBName] [NVARCHAR](128) NOT NULL , [ObjectID] [INT] NOT NULL , [IndexID] [INT] NOT NULL , [SchemaName] [NVARCHAR](128) NULL , [ObjectName] [NVARCHAR](128) NULL , [IndexName] [sysname] NULL , [ObjectType] [VARCHAR](5) NOT NULL , [IndexColumns] [NVARCHAR](MAX) NULL , [IncludeColumns] [NVARCHAR](MAX) NULL , [IsClustered] [VARCHAR](3) NOT NULL , [IsUnique] [VARCHAR](3) NOT NULL , [AllowRowLocks] [VARCHAR](3) NOT NULL , [AllowPageLocks] [VARCHAR](3) NOT NULL , [LastUpdatedDate] [DATETIME] NULL , [IndexFillFactor] [TINYINT] NOT NULL , [data_compression_desc] [NVARCHAR](60) NULL , [filter_definition] [NVARCHAR](MAX) NULL , [CreateStatement] [NVARCHAR](MAX) NULL , [IndexRev] [INT] NOT NULL , CONSTRAINT [PK_dba_IndexDefsStage] PRIMARY KEY CLUSTERED ( [DBName] ASC , [ObjectID] ASC , [IndexID] ASC ) WITH ( PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF , IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON ) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; GO ALTER TABLE [dbo].[dba_IndexDefs] ADD CONSTRAINT [DF_dba_IndexDefs_PollDate] DEFAULT ( GETDATE()) FOR [PollDate]; GO ALTER TABLE [dbo].[dba_IndexDefs] ADD CONSTRAINT [DF_dba_IndexDefs_IndexRev] DEFAULT (( 1 )) FOR [IndexRev]; GO ALTER TABLE [dbo].[dba_IndexDefsStage] ADD CONSTRAINT [DF_dba_IndexDefsStage_IndexRev] DEFAULT (( 1 )) FOR [IndexRev]; GO CREATE PROCEDURE [dbo].[GetIdxDefinitions] AS SET NOCOUNT ON; BEGIN TRUNCATE TABLE dba_IndexDefsStage; DECLARE @DBName VARCHAR(256); DECLARE @SQL VARCHAR(MAX); DECLARE indexes CURSOR LOCAL STATIC FORWARD_ONLY READ_ONLY FOR SELECTname FROMsys.databases WHERE source_database_id IS NULL AND state_desc <> 'offline' AND DATABASEPROPERTY(NAME, 'IsReadOnly') = 0 AND name <> 'tempdb'; OPEN indexes; FETCH NEXT FROM indexes INTO @DBName; WHILE @@FETCH_STATUS = 0 BEGIN SET @SQL = 'Use [' + @DBName + ']; With IndexStuff as ( SELECT icol.object_id ,i.name ,icol.index_id ,REPLACE(REPLACE(STUFF( ( SELECT '', ['' + c.name + '']'' AS [text()] FROM sys.index_columns ic Inner Join sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id WHERE ic.object_id = icol.object_id AND ic.index_id = icol.index_id And ic.is_included_column = 0 ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''VARCHAR(MAX)'') , 1, 2, ''''),''['',''''),'']'','''') AS ColList ,REPLACE(REPLACE(STUFF( ( SELECT '', ['' + c.name + '']'' AS [text()] FROM sys.index_columns ic Inner Join sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id WHERE ic.object_id = icol.object_id AND ic.index_id = icol.index_id And ic.is_included_column = 1 ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''VARCHAR(MAX)'') , 1, 2, ''''),''['',''''),'']'','''') AS IncludeColList FROM ['+ @DBName + '].sys.index_columns icol INNER JOIN [' + @DBName + '].sys.indexes i ON icol.object_id = i.object_id AND icol.index_id = i.index_id GROUP BY icol.object_id, i.name, icol.index_id ),tmp_indexes as ( SELECT SchemaName= SCHEMA_NAME(o.schema_id) ,ObjectID = i.object_id, ObjectName = OBJECT_NAME(i.object_id), ObjectType = CASE OBJECTPROPERTY(i.object_id, ''IsTable'') WHEN 1 THEN ''Table'' ELSE ''View'' END, IndexID = i.index_id, IndexName = i.name, IndexColumns = dt.ColList, IncludeColumns= dt.IncludeColList, IsClustered = CASE i.type WHEN 1 THEN ''YES'' ELSE ''NO'' END, IsUnique = CASE i.is_unique WHEN 1 THEN ''YES'' ELSE ''NO'' END, AllowRowLocks = CASE i.ALLOW_ROW_LOCKS WHEN 1 THEN ''YES'' ELSE ''NO'' END, AllowPageLocks = CASE i.ALLOW_PAGE_LOCKS WHEN 1 THEN ''YES'' ELSE ''NO'' END, LastUpdatedDate = STATS_DATE(i.object_id, i.index_id), IndexFillFactor= i.fill_factor ,p.data_compression_desc ,i.filter_definition FROM sys.indexes AS i INNER JOIN IndexStuff dt ON dt.object_id = i.object_id AND dt.index_id = i.index_id INNER JOIN sys.partitions p ON i.object_id = p.object_id AND i.index_id = p.index_id INNER JOIN sys.objects o ON o.object_id = i.object_id WHERE OBJECTPROPERTY(i.object_id, ''IsMSShipped'') = 0 AND INDEXPROPERTY(i.object_id, i.name, ''IsAutoStatistics'') = 0 AND i.index_id BETWEEN 1 And 250 ) Insert Into [DBA].[dbo].[dba_IndexDefsStage] ([DBName],[ObjectID],[IndexID],[SchemaName] ,[ObjectName],[IndexName],[ObjectType],[IndexColumns],[IncludeColumns],[IsClustered] ,[IsUnique],[AllowRowLocks],[AllowPageLocks],[LastUpdatedDate],[IndexFillFactor] ,[data_compression_desc],[filter_definition],[CreateStatement]) SELECT DB_NAME() AS DBName ,ti.[ObjectID] ,ti.[IndexID] ,ti.[SchemaName] ,ti.[ObjectName] ,ti.[IndexName] ,ti.[ObjectType] ,ti.[IndexColumns] ,ti.[IncludeColumns] ,ti.[IsClustered] ,ti.[IsUnique] ,ti.[AllowRowLocks] ,ti.[AllowPageLocks] ,ti.[LastUpdatedDate] ,ti.[IndexFillFactor] ,ti.[data_compression_desc] ,ti.[filter_definition] , CreateStatement = ''CREATE '' + CASE WHEN IsUnique = ''YES'' THEN ''UNIQUE '' ELSE '''' END + CASE WHEN IsClustered = ''YES'' THEN ''CLUSTERED '' ELSE ''NONCLUSTERED '' END + ''INDEX ['' + IndexName + '']'' +'' ON ['' + SchemaName + ''].['' + ObjectName + ''] '' + ''('' + IndexColumns + '')'' + CASE ISNULL(filter_definition,'' '') WHEN '' '' THEN '''' ELSE '' WHERE '' + filter_definition +'''' END + CASE WHEN ISNULL(IncludeColumns,'' '') = '' '' THEN '''' ELSE '' INCLUDE('' + IncludeColumns + '')'' END + CASE WHEN IndexFillFactor <> 0 THEN '' WITH (ONLINE = ON, FILLFACTOR = '' + CONVERT(VARCHAR(10),IndexFillFactor) + '','' WHEN IndexFillFactor = 0 THEN '' WITH (ONLINE = ON,'' END + CASE AllowPageLocks WHEN ''YES'' THEN '''' ELSE '' ALLOW_ROW_LOCKS = OFF,'' END + CASE AllowPageLocks WHEN ''YES'' THEN '''' ELSE '' ALLOW_PAGE_LOCKS = OFF,'' END + '' Data_Compression = ''+ data_compression_desc COLLATE SQL_Latin1_General_CP1_CI_AS+'')'' FROM tmp_indexes ti'; EXEC ( @SQL ); FETCH NEXT FROM indexes INTO @DBName; END; CLOSE indexes; DEALLOCATE indexes; /* New Indexes v. Old Indexes no longer present Index Definition has changed */INSERT INTO dba_IndexDefChange ( [DBName] , [SchemaName] , [ObjectName] , [IndexName] , [PollDate] , [ChangeType] ) SELECTds.[DBName] , ds.[SchemaName] , ds.[ObjectName] , ds.[IndexName] , GETDATE() , 'New Index' FROMdba_IndexDefsStage ds LEFT OUTER JOIN dba_IndexDefs D ON D.DBName = ds.DBName AND D.ObjectName = ds.ObjectName AND D.IndexName = ds.IndexName WHERE D.IndexName IS NULL; INSERT INTO dba_IndexDefChange ( [DBName] , [SchemaName] , [ObjectName] , [IndexName] , [PollDate] , [ChangeType] ) SELECTD.[DBName] , D.[SchemaName] , D.[ObjectName] , D.[IndexName] , GETDATE() , 'INDEX Removed' FROMdba_IndexDefs D LEFT OUTER JOIN dba_IndexDefsStage ds ON D.DBName = ds.DBName AND D.ObjectName = ds.ObjectName AND D.IndexName = ds.IndexName WHERE ds.IndexName IS NULL; INSERT INTO dba_IndexDefChange ( [DBName] , [SchemaName] , [ObjectName] , [IndexName] , [PollDate] , [ChangeType] ) SELECTD.[DBName] , D.[SchemaName] , D.[ObjectName] , D.[IndexName] , GETDATE() , 'INDEX DEFINITION Changed' FROMdba_IndexDefs D INNER JOIN dba_IndexDefsStage ds ON D.DBName = ds.DBName AND D.ObjectName = ds.ObjectName AND D.IndexName = ds.IndexName WHERE ( ds.IndexColumns <> D.IndexColumns OR ds.IncludeColumns <> D.IncludeColumns OR ds.IndexFillFactor <> D.IndexFillFactor OR ds.data_compression_desc <> D.data_compression_desc OR ds.filter_definition <> D.filter_definition ); /* Index Not currently registered */INSERT INTO dba_IndexDefs ( [DBName] , [ObjectID] , [IndexID] , [SchemaName] , [ObjectName] , [IndexName] , [ObjectType] , [IndexColumns] , [IncludeColumns] , [IsClustered] , [IsUnique] , [AllowRowLocks] , [AllowPageLocks] , [LastUpdatedDate] , [IndexFillFactor] , [data_compression_desc] , [filter_definition] , [CreateStatement] , [PollDate] ) SELECTds.[DBName] , ds.[ObjectID] , ds.[IndexID] , ds.[SchemaName] , ds.[ObjectName] , ds.[IndexName] , ds.[ObjectType] , ds.[IndexColumns] , ds.[IncludeColumns] , ds.[IsClustered] , ds.[IsUnique] , ds.[AllowRowLocks] , ds.[AllowPageLocks] , ds.[LastUpdatedDate] , ds.[IndexFillFactor] , ds.[data_compression_desc] , ds.[filter_definition] , ds.[CreateStatement] , GETDATE() FROMdba_IndexDefsStage ds LEFT OUTER JOIN dba_IndexDefs D ON D.DBName = ds.DBName AND D.ObjectName = ds.ObjectName AND D.IndexName = ds.IndexName WHERE D.IndexName IS NULL; /* Index Def has Changed */INSERT INTO dba_IndexDefs ( [DBName] , [ObjectID] , [IndexID] , [SchemaName] , [ObjectName] , [IndexName] , [ObjectType] , [IndexColumns] , [IncludeColumns] , [IsClustered] , [IsUnique] , [AllowRowLocks] , [AllowPageLocks] , [LastUpdatedDate] , [IndexFillFactor] , [data_compression_desc] , [filter_definition] , [CreateStatement] , [PollDate] , IndexRev ) SELECTds.[DBName] , ds.[ObjectID] , ds.[IndexID] , ds.[SchemaName] , ds.[ObjectName] , ds.[IndexName] , ds.[ObjectType] , ds.[IndexColumns] , ds.[IncludeColumns] , ds.[IsClustered] , ds.[IsUnique] , ds.[AllowRowLocks] , ds.[AllowPageLocks] , ds.[LastUpdatedDate] , ds.[IndexFillFactor] , ds.[data_compression_desc] , ds.[filter_definition] , ds.[CreateStatement] , GETDATE() , d.IndexRev + ds.IndexRev FROMdba_IndexDefsStage ds INNER JOIN dba_IndexDefs d ON d.DBName = ds.DBName AND d.ObjectName = ds.ObjectName AND d.IndexName = ds.IndexName CROSS APPLY ( SELECTMAX(IndexRev) AS IndexRev FROMdba_IndexDefs id WHERE d.DBName = id.DBName AND d.ObjectName = id.ObjectName AND d.IndexName = id.IndexName ) ca WHERE ( ds.IndexColumns <> d.IndexColumns OR ds.IncludeColumns <> d.IncludeColumns OR ds.IndexFillFactor <> d.IndexFillFactor OR ds.data_compression_desc <> d.data_compression_desc OR ds.filter_definition <> d.filter_definition ) AND d.IndexRev = ca.IndexRev; END; GO
To make this solution work, I use several tables and a stored procedure. The stored procedure is scheduled via an agent job and scheduled to your requirements. The tables will stage all of the indexes for all of the databases, then log which have changed or have been added or removed. From there, a simple query to the IndexDefChange table will help me learn of which indexes may deserve some attention.
Put a bow on it
This article showed a method to audit for index changes. The weak link in a solution such as this really boils down to the requirement that the solution needs to be in place before the index change occurs. Otherwise, it would all be for naught.
Interested in more back to basics articles? Check these out!
Want to learn more about your indexes? Try this index maintenance article or this index size article.
This is the second article in the 2019 “12 Days of Christmas” series. For the full list of articles, please visit this page.