IF OBJECT_ID('dev.sp_Global_GenerateAsyncAuditTrigger') IS NOT NULL BEGIN DROP PROCEDURE dev.sp_Global_GenerateAsyncAuditTrigger END GO CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditTrigger @tableName nvarchar(50) ,@disabled bit = 0 AS BEGIN DECLARE @col nvarchar(MAX) ,@sql nvarchar(MAX) SELECT @col = ISNULL(@col + ', ', '') + COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = @tableName AND TABLE_SCHEMA = 'dbo' AND DATA_TYPE NOT IN ('varbinary', 'binary') SET @sql = ' IF OBJECT_ID(''tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + ''') IS NOT NULL BEGIN DROP TRIGGER tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + ' END' EXEC sys.sp_executesql @sql SET @sql = ' CREATE TRIGGER tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + ' ON ' + @tableName + ' WITH EXECUTE AS ''Kreta_tech_user'' FOR INSERT, UPDATE, DELETE AS BEGIN SET NOCOUNT ON; DECLARE @MessageBody nvarchar(max) DECLARE @TableId int DECLARE @alterationTime datetime = GETDATE() --get relevant information from inserted/deleted and convert to xml message SET @MessageBody = CAST(( SELECT ''' + @tableName + ''' AS "name", @alterationTime AS "alterationTime", ( SELECT * FROM ( SELECT ''INSERTED'' AS [action], ' + @col + ' from inserted as inserted UNION ALL SELECT ''DELETED'' AS [action], ' + @col + ' from deleted as deleted ) x FOR XML RAW, TYPE) FOR XML RAW (''audit''), TYPE ) AS nvarchar(max)) IF (@MessageBody IS NOT NULL) BEGIN BEGIN TRY EXEC [auditlog].[usp_send] @fromService = ''AuditService'', @toService = ''AuditService'', @onContract = ''AuditContract'', @messageType = ''AuditMessage'', @messageBody = @MessageBody INSERT INTO auditlog.XmlAudit (MessageBody, InsertedAt) VALUES (@MessageBody, ISNULL(@alterationTime, GETDATE())) END TRY BEGIN CATCH INSERT INTO auditlog.XmlAudit (MessageBody, InsertedAt) VALUES (@MessageBody, ISNULL(@alterationTime, GETDATE())) END CATCH END END ' EXEC sys.sp_executesql @sql IF @disabled = 1 BEGIN SET @sql = 'DISABLE TRIGGER tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + ' ON ' + @tableName EXEC sys.sp_executesql @sql END END GO