init
This commit is contained in:
@@ -0,0 +1,18 @@
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditTriggerAll @disabled = 0
|
||||
GO
|
||||
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditProcedureAll
|
||||
GO
|
||||
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditAuditPocessing
|
||||
GO
|
||||
|
||||
ALTER QUEUE auditLog.[AuditQueue]
|
||||
WITH ACTIVATION
|
||||
(
|
||||
STATUS = ON,
|
||||
PROCEDURE_NAME = auditLog.usp_AuditProcessing,
|
||||
MAX_QUEUE_READERS = 10,
|
||||
EXECUTE AS 'Kreta_tech_user'
|
||||
);
|
||||
GO
|
@@ -0,0 +1,141 @@
|
||||
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 ('C_TANEVID', 'C_ALTANEVID')
|
||||
AND TABLE_NAME NOT IN ('T_ENTITYHISTORY', 'T_ENTITYATTRIBUTEHISTORY', 'T_LOG', 'T_GLOBALLOCK', 'T_EVFOLYAMTIPUS_OKTATASINEVELE')
|
||||
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
|
||||
|
||||
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 nvarchar(max)
|
||||
,@tableName nvarchar(80)
|
||||
,@conversation_handle UNIQUEIDENTIFIER
|
||||
,@message_type_name sysname;
|
||||
|
||||
WHILE (1 = 1) BEGIN
|
||||
BEGIN TRANSACTION;
|
||||
WAITFOR
|
||||
(RECEIVE TOP(1)
|
||||
@conversation_handle = conversation_handle,
|
||||
@message_body = message_body,
|
||||
@message_type_name = message_type_name
|
||||
FROM auditlog.AuditQueue
|
||||
), TIMEOUT 1000;
|
||||
--INSERT INTO auditlog.Test (xmlData) VALUES (@message_body)
|
||||
IF (@@ROWCOUNT = 0)
|
||||
BEGIN
|
||||
ROLLBACK TRANSACTION;
|
||||
BREAK;
|
||||
END
|
||||
BEGIN TRY
|
||||
-- Handle the Message
|
||||
IF @message_type_name = N''AuditMessage'' BEGIN
|
||||
SELECT @tableName = CAST(@message_body AS xml).value(''/audit[1]/@name'', ''nvarchar(80)'')
|
||||
|
||||
' + @if + '
|
||||
END
|
||||
|
||||
ELSE IF @message_type_name = ''EndOfStream''
|
||||
BEGIN
|
||||
-- initiator is signaling end of message stream: end the dialog
|
||||
END CONVERSATION @conversation_handle;
|
||||
END
|
||||
|
||||
-- If end dialog message, end the dialog
|
||||
ELSE IF @message_type_name = N''http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog''
|
||||
BEGIN
|
||||
END CONVERSATION @conversation_handle;
|
||||
END
|
||||
|
||||
ELSE IF @message_type_name = N''DEFAULT''
|
||||
BEGIN
|
||||
END CONVERSATION @conversation_handle;
|
||||
END
|
||||
|
||||
-- If error message, log and end conversation
|
||||
ELSE IF @message_type_name = N''http://schemas.microsoft.com/SQL/ServiceBroker/Error'' BEGIN
|
||||
DECLARE @error INT;
|
||||
DECLARE @description NVARCHAR(4000);
|
||||
-- Pull the error code and description from the doc
|
||||
WITH XMLNAMESPACES (''http://schemas.microsoft.com/SQL/ServiceBroker/Error'' AS ssb)
|
||||
SELECT
|
||||
@error = CAST(@message_body AS xml).value(''(//ssb:Error/ssb:Code)[1]'', ''INT''),
|
||||
@description = CAST(@message_body AS xml).value(''(//ssb:Error/ssb:Description)[1]'', ''NVARCHAR(4000)'');
|
||||
|
||||
|
||||
--INSERT INTO [dbo].[ErrorLog] (ConversationHandle, message_body, message_type_name)
|
||||
--SELECT @conversation_handle, CAST(@message_body AS nvarchar(max)), @message_type_name;
|
||||
|
||||
RAISERROR(N''Received error Code:%i Description:"%s"'', 16, 1, @error, @description) WITH LOG;
|
||||
|
||||
-- Now that we handled the error logging cleanup
|
||||
END CONVERSATION @conversation_handle;
|
||||
END
|
||||
|
||||
-- If everything succeeded correctly commit the transaction
|
||||
COMMIT TRANSACTION;
|
||||
|
||||
END TRY
|
||||
|
||||
-- If we have any error get caught we want to throw the error
|
||||
-- and then rollback the transaction to put the message on the queue
|
||||
BEGIN CATCH
|
||||
IF (ERROR_NUMBER() = 1205)
|
||||
BEGIN
|
||||
ROLLBACK TRANSACTION;
|
||||
EXEC [auditlog].[uspLogError];
|
||||
CONTINUE;
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
ROLLBACK TRANSACTION --ReceiveSavePoint;
|
||||
|
||||
EXEC [auditlog].[uspLogError];
|
||||
|
||||
INSERT INTO [auditlog].[AuditServiceFailedItems]
|
||||
([conversation_handle], [message_body])
|
||||
VALUES (@conversation_handle, @message_body);
|
||||
|
||||
THROW;
|
||||
END
|
||||
END CATCH
|
||||
END
|
||||
END
|
||||
'
|
||||
EXEC sys.sp_executesql @sql
|
||||
|
||||
END
|
||||
GO
|
@@ -0,0 +1,174 @@
|
||||
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
|
||||
,@alterationTime datetime
|
||||
|
||||
SELECT @alterationTime = @message_body.value(''/audit[1]/@alterationTime'', ''datetime'')
|
||||
|
||||
|
||||
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 @alterationTime, 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 @alterationTime, 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 @alterationTime, 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
|
||||
INNER 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
|
||||
|
||||
|
@@ -0,0 +1,72 @@
|
||||
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
|
||||
|
||||
--get relevant information from inserted/deleted and convert to xml message
|
||||
SET @MessageBody = CAST((
|
||||
SELECT ''' + @tableName + ''' AS "name", GETDATE() 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
|
||||
EXEC [auditlog].[usp_send]
|
||||
@fromService = ''AuditService'',
|
||||
@toService = ''AuditService'',
|
||||
@onContract = ''AuditContract'',
|
||||
@messageType = ''AuditMessage'',
|
||||
@messageBody = @MessageBody
|
||||
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
|
||||
|
Reference in New Issue
Block a user