Technical Article

Script Generates Audit Triggers

,

As a DBA , I had to determine if a large number of Databases were actually being used. I wrote this script to create triggers that write to an audit table if any table in the Database was updated.

It first creates an audit table to write to whenever any table is updated.

It then loops thru each table and generates an Insert,Update and Delete trigger for each table.

Whenever a row in any table is updated,inserted, or deleted it inserts a row to the audit table with the date of the update.

It will only log the update once, since the purpose of this was to determine if the Database was being used.

I checked the audit table after about 3 months, and removed any Databases that showed no update activity.

Of course if the Database is not being updated, this will not work. However most tables in a Database will eventually be updated, then the trigger will capture the date of the update.

-- create table to hold updated message and date
if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[dba_audit_table]') and OBJECTPROPERTY(id, N'IsUserTable') = 1)
      drop table [dbo].[dba_audit_table]GO
CREATE TABLE [dbo].[dba_audit_table] 
       ([PKID] [int] IDENTITY (1, 1) NOT NULL ,
       [Tablename] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
       [Message] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
       [UpdDate] [datetime] NULL ) ON [PRIMARY]
GO
ALTER TABLE [dbo].[dba_audit_table] WITH NOCHECK ADD CONSTRAINT [PK_dba_audit_table] PRIMARY KEY CLUSTERED ([PKID]) ON [PRIMARY] 
GO
-- for each table in database generate audit trigger-- except dba_audit_table, dtproperties 
DECLARE @TABLENAME VARCHAR(50)DECLARE @SQLCMD VARCHAR(2000)
DECLARE TABLES_CURSOR CURSOR FOR 
     SELECT Name from dbo.sysobjects 
        where xtype = 'U'  
        AND NAME <> 'dtproperties' 
        AND NAME <> 'dba_audit_table'
OPEN TABLES_CURSOR

FETCH NEXT FROM TABLES_CURSOR INTO @TABLENAME
WHILE (@@FETCH_STATUS = 0)
BEGIN
 -- BUILD CREATE TRIGGER STATEMENT
 SET @SQLCMD = (SELECT 'CREATE TRIGGER [TLOGUPDATE_') 
 SET @SQLCMD = @SQLCMD + @TABLENAME + '] ON [DBO].[' + @TABLENAME + ']'  
 SET @SQLCMD = @SQLCMD + ' FOR INSERT, UPDATE, DELETE AS IF NOT EXISTS ' 
 SET @SQLCMD = @SQLCMD + ' (SELECT DBA.TABLENAME FROM DBO.DBA_AUDIT_TABLE DBA WHERE TABLENAME = ' 
 SET @SQLCMD = @SQLCMD + '''' + @TABLENAME + '''' + ') BEGIN INSERT INTO DBA_AUDIT_TABLE (Tablename,Message,UpdDate) VALUES ' 
 SET @SQLCMD = @SQLCMD + '(' + '''' + @TABLENAME + '''' + ',' + '''' + 'Table was updated.' + '''' + ',Getdate()) END' 
 -- EXECUTE CREATE TRIGGER STATEMENT 
EXEC (@SQLCMD) FETCH NEXT FROM TABLES_CURSOR INTO @TABLENAME
END 
CLOSE TABLES_CURSOR  
DEALLOCATE TABLES_CURSOR

Rate

3.67 (6)

You rated this post out of 5. Change rating

Share

Share

Rate

3.67 (6)

You rated this post out of 5. Change rating