IF OBJECT_ID('dev.sp_Global_GenerateAsyncAuditAuditPocessing') IS NOT NULL BEGIN DROP PROCEDURE dev.sp_Global_GenerateAsyncAuditAuditPocessing END GO CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditAuditPocessing AS BEGIN DECLARE @sql nvarchar(max), @if nvarchar(max) = '' SELECT @if += ' IF @tableName = ''' + TABLE_NAME + ''' BEGIN EXEC auditlog.usp_AsyncAudit' + UPPER(SUBSTRING(TABLE_NAME, 3, 100)) + ' @message_body; END' FROM ( SELECT DISTINCT TABLE_NAME FROM INFORMATION_SCHEMA.COLUMNS WHERE COLUMN_NAME IN ('CREATOR', 'MODIFIER') AND TABLE_NAME NOT IN ('T_ENTITYHISTORY', 'T_ENTITYATTRIBUTEHISTORY', 'T_LOG', 'T_GLOBALLOCK') AND TABLE_NAME IN ( SELECT t.name FROM sys.tables t INNER JOIN sys.schemas s ON s.schema_id = t.schema_id WHERE s.name ='dbo' ) ) x -- DROP PROCEDURE audit.usp_AuditProcessing SET @sql = N' IF OBJECT_ID(''auditlog.usp_AuditProcessing'') IS NOT NULL BEGIN DROP PROCEDURE auditlog.usp_AuditProcessing END ' EXEC sys.sp_executesql @sql SET @sql = N' CREATE PROCEDURE auditlog.usp_AuditProcessing AS BEGIN DECLARE @message_type varchar(100) ,@dialog uniqueidentifier ,@message_body XML ,@tableName nvarchar(50) WHILE (1 = 1) BEGIN -- Receive the next available message from the queue WAITFOR ( RECEIVE TOP(1) @message_type = message_type_name ,@message_body = CAST(message_body AS XML) ,@dialog = conversation_handle FROM auditlog.AuditQueue ), TIMEOUT 500 IF (@@ROWCOUNT = 0 OR @message_body IS NULL) BEGIN BREAK END ELSE BEGIN SELECT @tableName = t.c.value(''@name'', ''nvarchar(50)'') FROM @message_body.nodes(''/audit'') t(c) ' + @if + ' END END CONVERSATION @dialog END END ' EXEC sys.sp_executesql @sql END GO