kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20170523102121_KC_170/sp_Global_GenerateAsyncAuditProcedure.sql
2024-03-13 00:33:46 +01:00

170 lines
No EOL
7.3 KiB
Transact-SQL

IF OBJECT_ID('dev.sp_Global_GenerateAsyncAuditProcedure') IS NOT NULL BEGIN
DROP PROCEDURE [dev].sp_Global_GenerateAsyncAuditProcedure
END
GO
CREATE PROCEDURE [dev].sp_Global_GenerateAsyncAuditProcedure
@tableName nvarchar(50)
AS BEGIN
DECLARE
@select nvarchar(max)
,@unpvt nvarchar(max)
,@sql nvarchar(max)
,@xmlList nvarchar(max)
,@tableCol nvarchar(max)
,@listCol nvarchar(max)
SELECT
@unpvt = ISNULL(@unpvt + ', ', '') + c.COLUMN_NAME
,@select = ISNULL(@select + ', ', '') + IIF(c.DATA_TYPE IN ('date', 'datetime'),'CONVERT(nvarchar(MAX), ' + c.COLUMN_NAME + ', 121)', 'CAST( ' + c.COLUMN_NAME + ' AS nvarchar(MAX))') + ' AS ' + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = @tableName
AND c.COLUMN_NAME NOT IN (N'ID', N'C_INTEZMENYID', N'C_ALINTEZMENYID', N'C_TANEVID', N'C_ALTANEVID', N'CREATED', N'LASTCHANGED', N'SERIAL', N'CREATOR', N'MODIFIER')
AND c.TABLE_SCHEMA = 'dbo'
AND c.DATA_TYPE NOT IN ('binary', 'varbinary');
SELECT
@listCol = ISNULL(@listCol + ', ', '') + c.COLUMN_NAME
,@xmlList = ISNULL(@xmlList + ',', ' ') + 't.c.value(''@' + c.COLUMN_NAME + ''', ''' + c.DATA_TYPE + ISNULL('(' + CASE WHEN c.CHARACTER_MAXIMUM_LENGTH IS NULL THEN NULL WHEN c.CHARACTER_MAXIMUM_LENGTH < 0 THEN 'max' ELSE CAST(c.CHARACTER_MAXIMUM_LENGTH AS nvarchar(30)) END + ')', '') + ''') AS ' + c.COLUMN_NAME + char(13) + char(10)
,@tableCol = ISNULL(@tableCol + ',', ' ') + c.COLUMN_NAME + ' ' + c.DATA_TYPE + ISNULL('(' + CASE WHEN c.CHARACTER_MAXIMUM_LENGTH IS NULL THEN NULL WHEN c.CHARACTER_MAXIMUM_LENGTH < 0 THEN 'max' ELSE CAST(c.CHARACTER_MAXIMUM_LENGTH AS nvarchar(30)) END + ')', '') + char(13) + char(10)
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = @tableName
AND c.TABLE_SCHEMA = 'dbo'
AND c.DATA_TYPE NOT IN ('binary', 'varbinary');
DECLARE @tanevCol nvarchar(30),
@intezmenyCol nvarchar(30)
SELECT @intezmenyCol = c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.COLUMN_NAME LIKE '%INTEZMENYID'
AND c.TABLE_NAME = @tableName
AND c.TABLE_SCHEMA = 'dbo'
SELECT @tanevCol = c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.COLUMN_NAME LIKE '%TANEVID'
AND c.TABLE_NAME = @tableName
AND c.TABLE_SCHEMA = 'dbo'
SET @sql = '
IF OBJECT_ID(''auditlog.usp_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + ''') IS NOT NULL BEGIN
DROP PROCEDURE auditlog.usp_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + '
END'
EXEC sp_executesql @sql;
SET @sql = '
CREATE PROCEDURE auditlog.usp_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + '
@message_body xml
AS
BEGIN
SET NOCOUNT ON
DECLARE @inserted TABLE (
' + @tableCol + '
)
DECLARE @deleted TABLE (
' + @tableCol + '
)
INSERT INTO @inserted ( ' + @listCol + ')
SELECT
' + @xmlList + '
FROM
@message_body.nodes(''//audit/row[@action="INSERTED"]'') AS t(c)
INSERT INTO @deleted ( ' + @listCol + ')
SELECT
' + @xmlList + '
FROM
@message_body.nodes(''//audit/row[@action="DELETED"]'') AS t(c)
DECLARE
@insTable TABLE (objectId int, intezmenyId int, tanevId int, creator int, modifier int, col nvarchar(30), val varchar(max))
DECLARE
@delTable TABLE (objectId int, intezmenyId int, tanevId int, creator int, modifier int, col nvarchar(30), val varchar(max))
DECLARE
@linkTable TABLE (id int, objectId int, intezmenyId int, tanevId int)
DECLARE
@action char(1),
@xml xml
SET @action =
CASE
WHEN NOT EXISTS (SELECT 1 FROM @deleted) THEN ''I''
WHEN NOT EXISTS (SELECT 1 FROM @inserted) THEN ''D''
ELSE ''U''
END
INSERT INTO @insTable (objectId, intezmenyId, tanevId, creator, modifier, col, val)
SELECT ID, C_INTEZMENYID, C_TANEVID, CREATOR, MODIFIER, col, val
FROM
(
SELECT ID, ' + @intezmenyCol + ' AS C_INTEZMENYID, ' + @tanevCol + ' AS C_TANEVID, CREATOR, MODIFIER, ' + @select + '
FROM @inserted) p
UNPIVOT (val FOR col IN (' + @unpvt +')) AS unpvt
INSERT INTO @delTable (objectId, intezmenyId, tanevId, creator, modifier, col, val)
SELECT ID, C_INTEZMENYID, C_TANEVID, CREATOR, MODIFIER, col, val
FROM
(
SELECT ID, ' + @intezmenyCol + ' AS C_INTEZMENYID, ' + @tanevCol + ' AS C_TANEVID, CREATOR, MODIFIER, ' + @select + '
FROM @deleted) p
UNPIVOT (val FOR col IN (' + @unpvt +')) AS unpvt
IF @action = ''I'' BEGIN
INSERT INTO dbo.T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
SELECT DISTINCT GETDATE(), objectId, ''' + @tableName + ''', ''New'', creator, intezmenyId, tanevId FROM @insTable
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT val, NULL, col, lk.id
FROM @insTable i
INNER JOIN @linkTable lk ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
END
IF @action = ''D'' BEGIN
INSERT INTO dbo.T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
SELECT DISTINCT GETDATE(), objectId, ''' + @tableName + ''', ''Removed'', modifier, intezmenyId, tanevId FROM @delTable
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT val, NULL, col, lk.id
FROM @delTable i
INNER JOIN @linkTable lk ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
END
IF @action = ''U'' BEGIN
INSERT INTO dbo.T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
SELECT DISTINCT GETDATE(), i.objectId, ''' + @tableName + ''',
CASE
WHEN i.val = ''T'' AND d.val = ''F'' THEN ''Logical Removed''
WHEN i.val = ''F'' AND d.val = ''T'' THEN ''Restored''
ELSE ''Modified''
END, i.modifier, i.intezmenyId, i.tanevId
FROM @insTable i
INNER JOIN @delTable d ON i.intezmenyId = d.intezmenyId AND i.objectId = d.objectId AND i.tanevId = d.tanevId AND i.col = d.col
-- WHERE i.col = ''TOROLT'' AND d.COL = ''TOROLT''
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT i.val, d.val, ISNULL(i.col, d.col), lk.id
FROM @delTable d
FULL JOIN @insTable i ON i.objectId = d.objectId AND i.intezmenyId = d.intezmenyId AND i.tanevId = d.tanevId AND i.col = d.col
INNER JOIN @linkTable lk ON ISNULL(i.objectId, d.objectId) = lk.objectId AND ISNULL(i.intezmenyId, d.intezmenyId) = lk.intezmenyId AND ISNULL(i.tanevId, d.tanevId) = lk.tanevId
WHERE (i.val <> d.val OR ((i.val IS NULL OR d.val IS NULL) AND (i.val IS NOT NULL OR d.val IS NOT NULL)))
END
END'
EXEC sp_executesql @sql;
END
GO