Click here to Skip to main content
Click here to Skip to main content

Quick SQL Server Auditing Setup

, 16 Aug 2012 CPOL
Rate this:
Please Sign up or sign in to vote.
Setting up a lightweight audit function for a SQL Server db.

Introduction

There is an obvious need to implement an audit function in database applications. Having devised this solution I could not see a similar approach taken by anyone else, hence I am presenting here.

My audit tool implements the following features:

  • an Audit table storing details of all insert, update and delete operations
  • only data changes are captured, i.e. tool does not capture the details of the entire row on every data change
  • data change operations are grouped in the Audit table, e.g. if 10 rows are updated each Audit row will have an identical Operation Ref
  • an Audit Config table allows control over which tables and columns to apply the audit tool.

Using the code

The audit tool is implemented like so:

Any table implementing the audit tool will have three triggers. Each trigger will:

  1. store the inserted and deleted tables to a local temporary table;
  2. get some dynamic SQL from a GetAuditSQL function; 
  3. execute the SQL code (this generates the Audit data); 
  4. delete the temporary tables. 
The trigger SQL code is below:
ALTER TRIGGER [dbo].[Customer_DELETE_Audit] ON [dbo].[Customer] AFTER DELETE
AS
BEGIN
SET NOCOUNT ON
select * into #tmpDeleted from deleted;
declare @sql nvarchar(max);
select @sql = [audit].[GetAuditSQL]('dbo','Customer','delete','','#tmpDeleted');
if isnull(@sql,'') <> '' exec sp_executesql @sql;
drop table #tmpDeleted;
END
GO
 

ALTER TRIGGER [dbo].[Customer_INSERT_Audit] ON [dbo].[Customer] AFTER INSERT
AS
BEGIN
SET NOCOUNT ON
select * into #tmpInserted from inserted;
declare @sql nvarchar(max);
select @sql = [audit].[GetAuditSQL]('dbo','Customer','insert','#tmpInserted','');
if isnull(@sql,'') <> '' exec sp_executesql @sql;
drop table #tmpInserted;
END
GO
 
ALTER TRIGGER [dbo].[Customer_UPDATE_Audit] ON [dbo].[Customer] AFTER UPDATE AS
BEGIN
SET NOCOUNT ON
select * into #tmpInserted from inserted;
select * into #tmpDeleted from deleted;
declare @sql nvarchar(max);
select @sql = [audit].[GetAuditSQL]('dbo','Customer','update','#tmpInserted','#tmpDeleted');
if isnull(@sql,'') <> '' exec sp_executesql @sql;
drop table #tmpInserted;
drop table #tmpDeleted;
END
GO

The GetAuditSQL code will iterate over the columns for the given table in AuditConfig and generate code that:

  1. compares the deleted and inserted data (from the trigger) to see where changes exist; 
  2. derive old and new values from the deleted and inserted data;
  3. insert rows into the Audit table. 

The GetAuditSQL code is below:

ALTER function [audit].[GetAuditSQL](
@Schemaname varchar(100),
@Tablename varchar(100),
@OperationType varchar(100),
@InsertedTableName varchar(100),
@DeletedTableName varchar(100)) returns nvarchar(max)
as
begin
    declare @OpRef varchar(100) = isnull((select max(OperationRef)+1 FROM audit),1)
    declare @retval nvarchar(max) = N''
    if not exists (select 0 from AuditConfig where Tablename = @Tablename and EnableAudit = 1)
        return @retval
    set @retval = N'
            insert into [audit].[Audit] ([Login],OperationRef,Schemaname,
            Tablename,OperationType,ColumnName,RowID,OldValue,NewValue) 
            select SYSTEM_USER, ''' + @OpRef + ''',''' + @Schemaname + ''',''' + 
            @Tablename + ''',''' + @OperationType+ ''', * from 
            ('
    declare @AddUnion bit = 0;
    declare @ColumnName varchar(100) = ''
    declare ac cursor for select ColumnName from AuditConfig 
            where Tablename = @Tablename and EnableAudit = 1
    open ac
    fetch next from ac into @ColumnName
    while @@FETCH_STATUS = 0 
    begin
        if @AddUnion = 1 SET @retval = @retval + N' union '
        if @OperationType = 'insert'
        begin
            SET @retval = @retval + N'
                select ''' + @ColumnName + ''' ColName, i.ID, NULL OldValue, 
                convert(nvarchar(max),i.['+ @ColumnName + 
                ']) NewValue from [' + @InsertedTableName + '] i'
        end
        if @OperationType = 'update'
        begin
            SET @retval = @retval + N'
                select ''' + @ColumnName + ''' ColName, i.ID, convert(nvarchar(max),d.['+ @ColumnName + ']) OldValue, 
                   convert(nvarchar(max),i.['+ @ColumnName + ']) NewValue from [' + @InsertedTableName + '] i JOIN [' + 
                   @DeletedTableName + '] d ON i.ID = d.ID AND (i.['+ @ColumnName + 
                   '] <> d.['+ @ColumnName + '] OR i.['+ @ColumnName + 
                   '] IS NOT NULL AND d.['+ @ColumnName + '] IS NULL)'
        end
        if @OperationType = 'delete'
        begin
            SET @retval = @retval + N'
                select ''' + @ColumnName + ''' ColName, i.ID, 
                convert(nvarchar(max),i.['+ @ColumnName + ']) OldValue, 
                NULL NewValue from [' + @DeletedTableName + '] i'
        end
        SET @AddUnion = 1
        fetch next from ac into @ColumnName
    end
    close ac
    deallocate ac
    SET @retval = @retval + N') d'
    return @retval
end  

The script file attached to this article will set up the audit tool in it's entirety:

  1. Set up the Audit and AuditConfig tables
  2. Set up the GetAuditSQL function 
  3. Set up two SPs (these can be called when new tables or columns are introduced to the database):
    1. to auto-populate the AuditConfig table with all table and column names; 
    2. set up all triggers.
  4. Execute the two SPs, applied to a specific schema (dbo by default) 
There are notes in the header that should be read before executing the script. Hope this is helpful!

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)

Share

About the Author

Andy Taw
Software Developer
United Kingdom United Kingdom
No Biography provided

Comments and Discussions

 
QuestionQuick SQL Server Auditing PinmemberDenial Parl6-Nov-14 23:47 
QuestionA Little help PinmemberMember 103846087-Nov-13 5:34 
AnswerRe: A Little help PinmemberAndy Taw7-Nov-13 7:01 
GeneralRe: A Little help PinmemberAndrew Lierman13-Nov-13 8:28 
GeneralMy vote of 5 PinmemberJohnWaller22-Aug-13 5:33 
GeneralRe: My vote of 5 PinmemberAndy Taw22-Aug-13 6:09 
GeneralRe: My vote of 5 PinmemberJohnWaller22-Aug-13 6:41 
GeneralMy vote of 4 [modified] PinmemberKanwal Shehzad2-Sep-12 10:23 
QuestionSome errors [modified] PinmemberKanwal Shehzad29-Aug-12 22:34 
First of all I appreciate the efforts for such a demanding utility.
I tried to utilize this utility but I got following errors:
 
1) Triggers can't be generated if a table have columns of following data types:
i) Text
ii) NText
iii) Image
 
The error message is like this:
Msg 311, Level 16, State 1, Procedure InTblMUnit_UPDATE_Audit, Line 1
Cannot use text, ntext, or image columns in the 'inserted' and 'deleted' tables.
2) The audit log is created only if table contains a column named [ID], otherwise audit log is not created. Therefore I got primary key column like this:
 
SELECT @PrimaryKey = cu.COLUMN_NAME 
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE cu 
WHERE EXISTS 
	(SELECT tc.* FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc 
		WHERE tc.TABLE_NAME = @Tablename 
			AND tc.CONSTRAINT_TYPE = 'PRIMARY KEY' 
			AND tc.CONSTRAINT_NAME = cu.CONSTRAINT_NAME)
 
So GetAuditSQL procedure becomes like this:
 
CREATE function [audit].[GetAuditSQL](
@Schemaname varchar(100),
@Tablename varchar(100),
@OperationType varchar(100),
@InsertedTableName varchar(100),
@DeletedTableName varchar(100)) returns nvarchar(max)
as
begin
	DECLARE @PrimaryKey VARCHAR(50)
	declare @OpRef varchar(100) = isnull((select max(OperationRef)+1 FROM audit),1)
	declare @retval nvarchar(max) = N''
	if not exists (select 0 from AuditConfig where Tablename = @Tablename and EnableAudit = 1)
		return @retval
	set @retval = N'
			insert into [audit].[Audit] ([Login],OperationRef,Schemaname,Tablename,OperationType,ColumnName,RowID,OldValue,NewValue) 
			select SYSTEM_USER, ''' + @OpRef + ''',''' + @Schemaname + ''',''' + @Tablename + ''',''' + @OperationType+ ''', * from 
			('
	declare @AddUnion bit = 0;
	declare @ColumnName varchar(100) = ''
	declare ac cursor for select ColumnName from AuditConfig where Tablename = @Tablename and EnableAudit = 1
	open ac
	fetch next from ac into @ColumnName
	while @@FETCH_STATUS = 0 
	begin
		if @AddUnion = 1 SET @retval = @retval + N' union '
		SET @PrimaryKey = ''
		SELECT @PrimaryKey = cu.COLUMN_NAME 
		FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE cu 
		WHERE EXISTS 
			( SELECT tc.* 
				FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS tc 
				WHERE tc.TABLE_NAME = @Tablename 
					AND tc.CONSTRAINT_TYPE = 'PRIMARY KEY' 
					AND tc.CONSTRAINT_NAME = cu.CONSTRAINT_NAME )
		if @OperationType = 'insert'
		begin
			SET @retval = @retval + N'
				select ''' + @ColumnName + ''' ColName, i.[' + @PrimaryKey + '], NULL OldValue, convert(nvarchar(max),i.['+ @ColumnName + ']) NewValue from [' + @InsertedTableName + '] i'
		end
		if @OperationType = 'update'
		begin
			SET @retval = @retval + N'
				select ''' + @ColumnName + ''' ColName, i.[' + @PrimaryKey + '], convert(nvarchar(max),d.['+ @ColumnName + ']) OldValue, convert(nvarchar(max),i.['+ @ColumnName + ']) NewValue from [' + @InsertedTableName + '] i JOIN [' + @DeletedTableName + '] d ON i.[' + @PrimaryKey + '] = d.[' + @PrimaryKey + '] AND (i.['+ @ColumnName + '] <> d.['+ @ColumnName + '] OR i.['+ @ColumnName + '] IS NOT NULL AND d.['+ @ColumnName + '] IS NULL)'
		end
		if @OperationType = 'delete'
		begin
			SET @retval = @retval + N'
				select ''' + @ColumnName + ''' ColName, i.[' + @PrimaryKey + '], convert(nvarchar(max),i.['+ @ColumnName + ']) OldValue, NULL NewValue from [' + @DeletedTableName + '] i'
		end
		SET @AddUnion = 1
		fetch next from ac into @ColumnName
	end
	close ac
	deallocate ac
	SET @retval = @retval + N') d'
	return @retval
end
GO
 

I executed the code as it is downloaded. Please let me know if the code have some prerequisite...
 
Regards,
Kanwal Shehzad


modified 30-Aug-12 6:16am.

AnswerRe: Some errors PinmemberHitendra Jadav28-Feb-13 9:44 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.

| Advertise | Privacy | Terms of Use | Mobile
Web04 | 2.8.141223.1 | Last Updated 16 Aug 2012
Article Copyright 2012 by Andy Taw
Everything else Copyright © CodeProject, 1999-2014
Layout: fixed | fluid