Background: I started in access from an inventory template found on the msft site. Tweaked to meet the needs of the organization. As reliance on the app became greater, IT suggested we move to MS SQL Server. Done. One of my tweaks was to use a vba triggered audit trail. It didn't exactly port over well to sql, creating duplicates, etc. What I need to do now is create a better audit solution. I read up, found some code and it works great on changes to records that already exist. It prevents new records from being inserted however and gives an ODBC cannot insert into a linked table and then spits out an error due to a syntax issue: (see image)
I need to know if this is some issue with regards to the autonumber that was set as the PK on the table that was part of access (as in, there is no primary key assigned on the new record yet so the trigger chokes) or if something else is at issue here. GO/****** Object: Trigger [dbo].[tr_audit] Script Date: 02/28/2012 08:02:05 ******/SET ANSI_NULLS ONGOSET QUOTED_IDENTIFIER ONGOALTER trigger [dbo].[tr_audit] on [dbo].[CaseDetails] for insert, update, deleteasdeclare @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) , @PKSelect varchar(1000) select @TableName = 'CaseDetails' -- date and user select @UserName = CURRENT_USER,-- 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 select for insert select @PKSelect = coalesce(@PKSelect+'+','') + '''<' + COLUMN_NAME + '=''+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, PK, FieldName, OldValue, NewValue, UpdateDate, UserName)' select @sql = @sql + ' select ''' + @Type + '''' select @sql = @sql + ',''' + @TableName + '''' select @sql = @sql + ',' + @PKSelect 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
Table[PK]ID int Unchecked[Case Number] nvarchar(11) UncheckedOwner int CheckedCategory nvarchar(255) CheckedPriority nvarchar(50) CheckedStatus nvarchar(50) Checked[Start Date] datetime Checked[End Date] datetime Checked[Admin Notes] nvarchar(255) CheckedFCR int CheckedAgency nvarchar(255) Checked[Patrol District] nvarchar(255) Checked[Request Origin] nvarchar(255) CheckedReason nvarchar(255) CheckedDupCase bit CheckedRequestOnly bit CheckedSSMA_TimeStamp timestamp UncheckedFraction nchar(10) CheckedSpPrj nvarchar(50) CheckedContents int Checked