102 lines
3.5 KiB
Transact-SQL
102 lines
3.5 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditTrigger
|
|
GO
|
|
|
|
CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditTrigger
|
|
@tableName nvarchar(50)
|
|
,@disabled bit = 0
|
|
AS
|
|
BEGIN
|
|
|
|
DECLARE
|
|
@columnList nvarchar(max)
|
|
,@sql nvarchar(max)
|
|
,@isAlIntezmenyId bit = 0
|
|
|
|
SELECT @columnList = ISNULL(@columnList + ', ', '') + COLUMN_NAME + N' AS ''col.' + COLUMN_NAME + ''''
|
|
FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_NAME = @tableName
|
|
AND TABLE_SCHEMA = 'dbo'
|
|
AND DATA_TYPE NOT IN ('varbinary', 'binary')
|
|
AND COLUMN_NAME NOT IN ('SERIAL', 'LASTCHANGED', 'CREATED', 'ID', 'C_INTEZMENYID', 'C_ALINTEZMENYID', 'C_TANEVID', 'C_ALTANEVID', 'NNID', 'CREATED')
|
|
|
|
IF EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = @tableName AND TABLE_SCHEMA = 'dbo' AND COLUMN_NAME = 'C_ALINTEZMENYID') BEGIN
|
|
SET @isAlIntezmenyId = 1
|
|
END
|
|
|
|
SET @sql = '
|
|
DROP TRIGGER IF EXISTS tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100))
|
|
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 = (
|
|
SELECT ''' + @tableName + ''' AS ''name'', GETDATE() AS ''alterationTime'',
|
|
JSON_QUERY (
|
|
(SELECT
|
|
ID AS ''ID''
|
|
,' + IIF(@tableName = 'T_INTEZMENY','ID','C_' + IIF(@isAlIntezmenyId = 0, '', 'AL') + 'INTEZMENYID')+ ' AS ''C_INTEZMENYID''
|
|
,' + CASE
|
|
WHEN @tableName = 'T_INTEZMENY' THEN '0'
|
|
WHEN @tableName = 'T_TANEV' THEN 'ID'
|
|
WHEN @isAlIntezmenyId = 1 THEN 'C_ALTANEVID'
|
|
ELSE 'C_TANEVID' END
|
|
+' AS ''C_TANEVID''
|
|
,CREATOR AS ''CREATOR''
|
|
,MODIFIER AS ''MODIFIER''
|
|
,' + @columnList + '
|
|
FROM inserted
|
|
FOR JSON PATH, ROOT(''audit''), INCLUDE_NULL_VALUES), ''$.audit''
|
|
) AS ''inserted'',
|
|
JSON_QUERY (
|
|
(SELECT
|
|
ID AS ''ID''
|
|
,' + IIF(@tableName = 'T_INTEZMENY','ID','C_' + IIF(@isAlIntezmenyId = 0, '', 'AL') + 'INTEZMENYID')+ ' AS ''C_INTEZMENYID''
|
|
,' + CASE
|
|
WHEN @tableName = 'T_INTEZMENY' THEN '0'
|
|
WHEN @tableName = 'T_TANEV' THEN 'ID'
|
|
WHEN @isAlIntezmenyId = 1 THEN 'C_ALTANEVID'
|
|
ELSE 'C_TANEVID' END
|
|
+' AS ''C_TANEVID''
|
|
,CREATOR AS ''CREATOR''
|
|
,MODIFIER AS ''MODIFIER''
|
|
,' + @columnList + '
|
|
FROM deleted
|
|
FOR JSON PATH, ROOT(''audit''), INCLUDE_NULL_VALUES), ''$.audit''
|
|
) AS ''deleted''
|
|
FOR JSON PATH, WITHOUT_ARRAY_WRAPPER, INCLUDE_NULL_VALUES
|
|
)
|
|
|
|
IF (@messageBody IS NOT NULL) BEGIN
|
|
EXEC [auditlog].[usp_send]
|
|
@fromService = ''AuditService'',
|
|
@toService = ''AuditService'',
|
|
@onContract = ''AuditContract'',
|
|
@messageType = ''AuditMessage'',
|
|
@messageBody = @messageBody
|
|
END
|
|
END
|
|
'
|
|
|
|
EXEC sys.sp_executesql @sql
|
|
|
|
--select @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
|