Audit trigger inside of stored procedure.

  • Hi all -

    Im needing to tap into some of you TSQL gurus. This is for a trigger that will audit dml on tables that are dynamically built, therefore needs to be able to take the table's name as an arguement. This is really the only way to do what im looking for due to business requirements, before anyone starts asking (or telling me) about Profiler, CDC, or 2008's auditing feature. I have already explored those as options and they don't completely conform to my biz needs.

    Here is what i am shooting for:

    1. The application creates a form (which creates a table dynamically).

    2. The new table has to be audited for change on the columns in my audit database (newvalue, oldvalue, date, OSuser, etc.) THIS WORKS.

    3. The way the table trigger is created is once the 'save form' button is pressed in the app, the table is created and this stored procedure will run. This creates the trigger automatically on the new table and begins the audit process.

    WHat i have:

    1. I have a working audit trigger. Any table i create, any column i add or drop, regardless the trigger adds the change to my "audit" table.

    What im asking help on:

    1. I can't seem to get the trigger 'wrapped' in my sp correctly to pass in my table name.

    ------------------------------------------------------------------------------------------

    Wrapper for SP:

    ALTER PROC spReplaceAuditTrigger( @PassedTableName as NVarchar(255) ) AS

    BEGIN

    DECLARE @ActualTableName AS NVarchar(255)

    SELECT @ActualTableName = QUOTENAME( TABLE_NAME )

    FROM INFORMATION_SCHEMA.TABLES

    WHERE TABLE_NAME = @PassedTableName

    DECLARE @sql AS NVARCHAR(MAX)

    SELECT @sql = ' .....Trigger code goes here.... '

    EXEC(@SQL)

    END

    GO

    ---------------------------------------------------------------

    TRIGGER CODE:

    alter trigger [dbo].Audit_test_ChangeTracking] on [dbo].[Audit_test] for insert, update, delete

    as

    declare @bit int ,

    @field int ,

    @maxfield int ,

    @char int ,

    @fieldname varchar(128) ,

    @TableName varchar(128) ,

    @PKCols varchar(1000) ,

    @sql varchar(2000),

    @UpdateDate varchar(21) ,

    @UserName varchar(128) ,

    @Type char(1) ,

    @PKFieldSelect varchar(1000),

    @PKValueSelect varchar(1000)

    select @TableName = 'Audit_test'

    -- date and user

    select @UserName = system_user ,

    @UpdateDate = convert(varchar(8), getdate(), 112) + ' ' + convert(varchar(12), getdate(), 114)

    -- Action

    if exists (select * from inserted)

    if exists (select * from deleted)

    select @Type = 'U'

    else

    select @Type = 'I'

    else

    select @Type = 'D'

    -- get list of columns

    select * into #ins from inserted

    select * into #del from deleted

    -- Get primary key columns for full outer join

    select @PKCols = coalesce(@PKCols + ' and', ' on') + ' i.' + c.COLUMN_NAME + ' = d.' + c.COLUMN_NAME

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = 'PRIMARY KEY'

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    -- Get primary key fields select for insert

    select @PKFieldSelect = coalesce(@PKFieldSelect+'+','') + '''' + COLUMN_NAME + ''''

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = 'PRIMARY KEY'

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    select @PKValueSelect = coalesce(@PKValueSelect+'+','') + 'convert(varchar(100), coalesce(i.' + COLUMN_NAME + ',d.' + COLUMN_NAME + '))'

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = 'PRIMARY KEY'

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    if @PKCols is null

    begin

    raiserror('no PK on table %s', 16, -1, @TableName)

    return

    end

    select @field = 0, @maxfield = max(ORDINAL_POSITION) from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName

    while @field < @maxfield

    begin

    select @field = min(ORDINAL_POSITION) from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName and ORDINAL_POSITION > @field

    select @bit = (@field - 1 )% 8 + 1

    select @bit = power(2,@bit - 1)

    select @char = ((@field - 1) / 8) + 1

    if substring(COLUMNS_UPDATED(),@char, 1) & @bit > 0 or @Type in ('I','D')

    begin

    select @fieldname = COLUMN_NAME from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName and ORDINAL_POSITION = @field

    select @sql = 'insert Audit (Type, TableName, PrimaryKeyField, PrimaryKeyValue, FieldName, OldValue, NewValue, UpdateDate, UserName)'

    select @sql = @sql + ' select ''' + @Type + ''''

    select @sql = @sql + ',''' + @TableName + ''''

    select @sql = @sql + ',' + @PKFieldSelect

    select @sql = @sql + ',' + @PKValueSelect

    select @sql = @sql + ',''' + @fieldname + ''''

    select @sql = @sql + ',convert(varchar(1000),d.' + @fieldname + ')'

    select @sql = @sql + ',convert(varchar(1000),i.' + @fieldname + ')'

    select @sql = @sql + ',''' + @UpdateDate + ''''

    select @sql = @sql + ',''' + @UserName + ''''

    select @sql = @sql + ' from #ins i full outer join #del d'

    select @sql = @sql + @PKCols

    select @sql = @sql + ' where i.' + @fieldname + ' <> d.' + @fieldname

    select @sql = @sql + ' or (i.' + @fieldname + ' is null and d.' + @fieldname + ' is not null)'

    select @sql = @sql + ' or (i.' + @fieldname + ' is not null and d.' + @fieldname + ' is null)'

    exec (@sql)

    end

    end

    GO

    ------------------------------

    Thanks all!!

    D

  • Looks like you just need to double the quotes on the trigger code except for where you use the variable. Try this:

    alter PROC spReplaceAuditTrigger( @PassedTableName as NVarchar(255) ) AS

    BEGIN

    DECLARE @ActualTableName AS NVarchar(255)

    SELECT @ActualTableName = QUOTENAME( TABLE_NAME )

    FROM INFORMATION_SCHEMA.TABLES

    WHERE TABLE_NAME = @PassedTableName

    DECLARE @sql AS NVARCHAR(MAX)

    SELECT @sql = '

    create trigger [dbo][.Audit_test_ChangeTracking] on [dbo].[Audit_test] for insert, update, delete

    as

    declare @bit int ,

    @field int ,

    @maxfield int ,

    @char int ,

    @fieldname varchar(128) ,

    @TableName varchar(128) ,

    @PKCols varchar(1000) ,

    @sql varchar(2000),

    @UpdateDate varchar(21) ,

    @UserName varchar(128) ,

    @Type char(1) ,

    @PKFieldSelect varchar(1000),

    @PKValueSelect varchar(1000)

    select @TableName = '+ @ActualTableName +'

    -- date and user

    select @UserName = system_user ,

    @UpdateDate = convert(varchar(8), getdate(), 112) + '' '' + convert(varchar(12), getdate(), 114)

    -- Action

    if exists (select * from inserted)

    if exists (select * from deleted)

    select @Type = ''U''

    else

    select @Type = ''I''

    else

    select @Type = ''D''

    -- get list of columns

    select * into #ins from inserted

    select * into #del from deleted

    -- Get primary key columns for full outer join

    select @PKCols = coalesce(@PKCols + '' and'', '' on'') + '' i.'' + c.COLUMN_NAME + '' = d.'' + c.COLUMN_NAME

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = ''PRIMARY KEY''

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    -- Get primary key fields select for insert

    select @PKFieldSelect = coalesce(@PKFieldSelect+''+'','''') + '''''''' + COLUMN_NAME + ''''''''

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = ''PRIMARY KEY''

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    select @PKValueSelect = coalesce(@PKValueSelect+''+'','''') + ''convert(varchar(100), coalesce(i.'' + COLUMN_NAME + '',d.'' + COLUMN_NAME + ''))''

    from INFORMATION_SCHEMA.TABLE_CONSTRAINTS pk ,

    INFORMATION_SCHEMA.KEY_COLUMN_USAGE c

    where pk.TABLE_NAME = @TableName

    and CONSTRAINT_TYPE = ''PRIMARY KEY''

    and c.TABLE_NAME = pk.TABLE_NAME

    and c.CONSTRAINT_NAME = pk.CONSTRAINT_NAME

    if @PKCols is null

    begin

    raiserror(''no PK on table %s'', 16, -1, @TableName)

    return

    end

    select @field = 0, @maxfield = max(ORDINAL_POSITION) from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName

    while @field < @maxfield

    begin

    select @field = min(ORDINAL_POSITION) from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName and ORDINAL_POSITION > @field

    select @bit = (@field - 1 )% 8 + 1

    select @bit = power(2,@bit - 1)

    select @char = ((@field - 1) / 8) + 1

    if substring(COLUMNS_UPDATED(),@char, 1) & @bit > 0 or @Type in (''I'',''D'')

    begin

    select @fieldname = COLUMN_NAME from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = @TableName and ORDINAL_POSITION = @field

    select @sql = ''insert Audit (Type, TableName, PrimaryKeyField, PrimaryKeyValue, FieldName, OldValue, NewValue, UpdateDate, UserName)''

    select @sql = @sql + '' select '''''' + @Type + ''''''''

    select @sql = @sql + '','''''' + @TableName + ''''''''

    select @sql = @sql + '','' + @PKFieldSelect

    select @sql = @sql + '','' + @PKValueSelect

    select @sql = @sql + '','''''' + @fieldname + ''''''''

    select @sql = @sql + '',convert(varchar(1000),d.'' + @fieldname + '')''

    select @sql = @sql + '',convert(varchar(1000),i.'' + @fieldname + '')''

    select @sql = @sql + '','''''' + @UpdateDate + ''''''''

    select @sql = @sql + '','''''' + @UserName + ''''''''

    select @sql = @sql + '' from #ins i full outer join #del d''

    select @sql = @sql + @PKCols

    select @sql = @sql + '' where i.'' + @fieldname + '' <> d.'' + @fieldname

    select @sql = @sql + '' or (i.'' + @fieldname + '' is null and d.'' + @fieldname + '' is not null)''

    select @sql = @sql + '' or (i.'' + @fieldname + '' is not null and d.'' + @fieldname + '' is null)''

    exec (@sql)

    end

    end

    '

    EXEC(@SQL)

    END

    GO

    ______________________________________________________________________________
    How I want a drink, alcoholic of course, after the heavy lectures involving quantum mechanics.

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply