init
This commit is contained in:
commit
e124a47765
19374 changed files with 9806149 additions and 0 deletions
|
@ -0,0 +1,385 @@
|
|||
DROP PROCEDURE IF EXISTS auditLog.usp_AuditProcessing
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE auditLog.usp_AuditProcessing
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @messageType varchar(100)
|
||||
,@dialog uniqueidentifier
|
||||
,@messageBody nvarchar(max)
|
||||
,@tableName nvarchar(80)
|
||||
,@conversationHandle UNIQUEIDENTIFIER
|
||||
,@messageTypeName sysname;
|
||||
|
||||
CREATE TABLE #linkTable (
|
||||
id int
|
||||
,objectId int
|
||||
,intezmenyId int
|
||||
,tanevId int
|
||||
)
|
||||
|
||||
CREATE TABLE #attributeTable (
|
||||
entity_history_id int
|
||||
,entity_property nvarchar(100) collate Hungarian_CI_AI
|
||||
,entity_attribute_history_id int
|
||||
)
|
||||
|
||||
|
||||
|
||||
WHILE (1 = 1) BEGIN
|
||||
BEGIN TRANSACTION;
|
||||
WAITFOR
|
||||
(RECEIVE TOP(1)
|
||||
@conversationHandle = conversation_handle,
|
||||
@messageBody = message_body,
|
||||
@messageTypeName = message_type_name
|
||||
FROM auditlog.AuditQueue
|
||||
), TIMEOUT 1000;
|
||||
|
||||
IF (@@ROWCOUNT = 0)
|
||||
BEGIN
|
||||
ROLLBACK TRANSACTION;
|
||||
BREAK;
|
||||
END
|
||||
|
||||
BEGIN TRY
|
||||
|
||||
DECLARE
|
||||
@action char(1)
|
||||
,@alterationTime datetime
|
||||
|
||||
-- Handle the Message
|
||||
IF @messageTypeName = N'AuditMessage' BEGIN
|
||||
IF ISJSON(@messageBody) = 1 BEGIN
|
||||
|
||||
TRUNCATE TABLE #linkTable
|
||||
|
||||
SELECT
|
||||
@tableName = name
|
||||
,@alterationTime = alterationTime
|
||||
FROM OPENJSON (@messageBody) WITH (
|
||||
name nvarchar(50) '$.name'
|
||||
,alterationTime datetime '$.alterationTime'
|
||||
)
|
||||
|
||||
SET @action =
|
||||
CASE
|
||||
WHEN NOT EXISTS (SELECT 1 FROM OPENJSON (@messageBody, '$.deleted')) THEN 'I'
|
||||
WHEN NOT EXISTS (SELECT 1 FROM OPENJSON (@messageBody, '$.inserted')) THEN 'D'
|
||||
ELSE 'U'
|
||||
END
|
||||
|
||||
IF @action = 'I' BEGIN -- INSERT
|
||||
|
||||
TRUNCATE TABLE #attributeTable
|
||||
|
||||
|
||||
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
|
||||
@alterationTime AS C_ALTERATIONDATE
|
||||
,JSON_Value (c.value, '$.ID') AS C_ENTITYID
|
||||
,@tableName AS C_ENTITYNAME
|
||||
,'New' AS C_REASON
|
||||
,JSON_Value (c.value, '$.CREATOR') as C_FELHASZNALOID
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as C_INTEZMENYID
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as C_TANEVID
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
SELECT i.val, NULL, i.col, lk.id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) <= 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
OUTPUT INSERTED.ID, INSERTED.C_PROPERTYNAME, INSERTED.C_ENTITYHISTORYID INTO #attributeTable(entity_attribute_history_id, entity_property, entity_history_id)
|
||||
SELECT NULL, NULL, i.col, lk.id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) > 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYBLOBVALUES(C_CURRENTVALUE, C_ORIGINALVALUE, C_ENTITYATTRIBUTEHISTORYID)
|
||||
SELECT i.val, NULL, av.entity_attribute_history_id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
|
||||
LEFT JOIN #attributeTable av on av.entity_history_id = lk.id and av.entity_property = i.col collate Hungarian_CI_AI
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) > 2000
|
||||
END
|
||||
|
||||
|
||||
|
||||
IF @action = 'D' BEGIN -- DELETED
|
||||
|
||||
TRUNCATE TABLE #attributeTable
|
||||
|
||||
|
||||
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
|
||||
@alterationTime AS C_ALTERATIONDATE
|
||||
,JSON_Value (c.value, '$.ID') AS C_ENTITYID
|
||||
,@tableName AS C_ENTITYNAME
|
||||
,'Removed' AS C_REASON
|
||||
,JSON_Value (c.value, '$.CREATOR') as C_FELHASZNALOID
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as C_INTEZMENYID
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as C_TANEVID
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
SELECT NULL, d.val, d.col, lk.id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
WHERE ISNULL(DATALENGTH(d.val), 0) <= 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
OUTPUT INSERTED.ID, INSERTED.C_PROPERTYNAME, INSERTED.C_ENTITYHISTORYID INTO #attributeTable(entity_attribute_history_id, entity_property, entity_history_id)
|
||||
SELECT NULL, NULL, d.col, lk.id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
WHERE ISNULL(DATALENGTH(d.val), 0) > 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYBLOBVALUES (C_CURRENTVALUE, C_ORIGINALVALUE, C_ENTITYATTRIBUTEHISTORYID)
|
||||
SELECT NULL, d.val, av.entity_attribute_history_id
|
||||
FROM #linkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,p.[key] AS col
|
||||
,p.[Value] AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
LEFT JOIN #attributeTable av on av.entity_history_id = lk.id and av.entity_property = d.col collate Hungarian_CI_AI
|
||||
WHERE ISNULL(DATALENGTH(d.val), 0) > 2000
|
||||
|
||||
END
|
||||
|
||||
IF @action = 'U' BEGIN -- UPDATE
|
||||
|
||||
TRUNCATE TABLE #attributeTable
|
||||
|
||||
|
||||
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
|
||||
@alterationTime AS C_ALTERATIONDATE
|
||||
,JSON_Value (c.value, '$.ID') AS C_ENTITYID
|
||||
,@tableName AS C_ENTITYNAME
|
||||
,'Modified' AS C_REASON
|
||||
,JSON_Value (c.value, '$.MODIFIER') as C_FELHASZNALOID
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as C_INTEZMENYID
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as C_TANEVID
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
SELECT NULLIF(i.val, N'#NULL#'), NULLIF(d.val, N'#NULL#'), d.col, lk.id
|
||||
FROM #LinkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON d.objectId = i.objectId AND d.intezmenyId = i.intezmenyId AND d.tanevId = i.tanevId AND d.col = i.col AND i.val <> d.val
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) <= 2000 AND ISNULL(DATALENGTH(d.val), 0) <= 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
||||
OUTPUT INSERTED.ID, INSERTED.C_PROPERTYNAME, INSERTED.C_ENTITYHISTORYID INTO #attributeTable(entity_attribute_history_id, entity_property, entity_history_id)
|
||||
SELECT NULL, NULL, d.col, lk.id
|
||||
FROM #LinkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON d.objectId = i.objectId AND d.intezmenyId = i.intezmenyId AND d.tanevId = i.tanevId AND d.col = i.col AND i.val <> d.val
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) > 2000 OR ISNULL(DATALENGTH(d.val), 0) > 2000
|
||||
|
||||
|
||||
INSERT INTO dbo.T_ENTITYBLOBVALUES (C_CURRENTVALUE, C_ORIGINALVALUE, C_ENTITYATTRIBUTEHISTORYID)
|
||||
SELECT NULLIF(i.val, N'#NULL#'), NULLIF(d.val, N'#NULL#'), av.entity_attribute_history_id
|
||||
FROM #LinkTable lk
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.deleted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) d ON d.objectId = lk.objectId AND d.intezmenyId = lk.intezmenyId AND d.tanevId = lk.tanevId
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
JSON_Value (c.value, '$.ID') as objectId
|
||||
,JSON_Value (c.value, '$.C_INTEZMENYID') as intezmenyId
|
||||
,JSON_Value (c.value, '$.C_TANEVID') as tanevId
|
||||
,JSON_Value (c.value, '$.CREATOR') as creator
|
||||
,JSON_Value (c.value, '$.MODIFIER') as modifier
|
||||
,p.[key] AS col
|
||||
,ISNULL(p.[Value], N'#NULL#') AS val
|
||||
FROM OPENJSON (@messageBody, '$.inserted') as c
|
||||
CROSS APPLY OPENJSON (c.value, '$.col') as p
|
||||
) i ON d.objectId = i.objectId AND d.intezmenyId = i.intezmenyId AND d.tanevId = i.tanevId AND d.col = i.col AND i.val <> d.val
|
||||
LEFT JOIN #attributeTable av on av.entity_history_id = lk.id and av.entity_property = ISNULL(d.col, i.col) collate Hungarian_CI_AI
|
||||
WHERE ISNULL(DATALENGTH(i.val), 0) > 2000 OR ISNULL(DATALENGTH(d.val), 0) > 2000
|
||||
|
||||
END
|
||||
END
|
||||
END
|
||||
ELSE IF @messageTypeName = 'EndOfStream' BEGIN
|
||||
-- initiator is signaling end of message stream: end the dialog
|
||||
END CONVERSATION @conversationHandle;
|
||||
END
|
||||
|
||||
-- If end dialog message, end the dialog
|
||||
ELSE IF @messageTypeName = N'http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog' BEGIN
|
||||
END CONVERSATION @conversationHandle;
|
||||
END
|
||||
|
||||
ELSE IF @messageTypeName = N'DEFAULT' BEGIN
|
||||
END CONVERSATION @conversationHandle;
|
||||
END
|
||||
|
||||
-- If error message, log and end conversation
|
||||
ELSE IF @messageTypeName = 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(@messageBody AS xml).value('(//ssb:Error/ssb:Code)[1]', 'INT'),
|
||||
@description = CAST(@messageBody AS xml).value('(//ssb:Error/ssb:Description)[1]', 'NVARCHAR(4000)');
|
||||
|
||||
|
||||
--INSERT INTO [dbo].[ErrorLog] (ConversationHandle, message_body, message_type_name)
|
||||
--SELECT @conversationHandle, CAST(@messageBody AS nvarchar(max)), @messageTypeName;
|
||||
|
||||
RAISERROR(N'Received error Code:%i Description:"%s"', 16, 1, @error, @description) WITH LOG;
|
||||
|
||||
-- Now that we handled the error logging cleanup
|
||||
END CONVERSATION @conversationHandle;
|
||||
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 (@conversationHandle, @messageBody);
|
||||
THROW;
|
||||
END
|
||||
END CATCH
|
||||
END
|
||||
END
|
||||
GO
|
Loading…
Add table
Add a link
Reference in a new issue