init
This commit is contained in:
@@ -0,0 +1,5 @@
|
||||
IF EXISTS (SELECT 1 FROM sys.service_message_types WHERE name = 'AuditMessage') BEGIN
|
||||
ALTER MESSAGE TYPE [AuditMessage]
|
||||
VALIDATION = NONE;
|
||||
END
|
||||
GO
|
@@ -0,0 +1,96 @@
|
||||
DROP PROCEDURE IF EXISTS [auditlog].[usp_send]
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [auditlog].[usp_send]
|
||||
@fromService SYSNAME,
|
||||
@toService SYSNAME,
|
||||
@onContract SYSNAME,
|
||||
@messageType SYSNAME,
|
||||
@messageBody NVARCHAR(MAX)
|
||||
WITH EXECUTE AS 'Kreta_tech_user'
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE @dialogHandle UNIQUEIDENTIFIER;
|
||||
DECLARE @sendCount BIGINT;
|
||||
DECLARE @counter INT;
|
||||
DECLARE @error INT;
|
||||
|
||||
|
||||
SET @counter = 1;
|
||||
BEGIN TRANSACTION;
|
||||
|
||||
-- message validation check, preventing poison message at the target service validation
|
||||
-- target service validates WELL_FORMED_XML types, so it is best to prevent it at here
|
||||
|
||||
IF EXISTS (SELECT 1 FROM sys.[service_message_types] WHERE [name] = @messageType)
|
||||
AND ((TRY_CONVERT(xml, @messageBody) IS NOT NULL OR ISJSON(@messageBody) = 1))
|
||||
BEGIN
|
||||
IF ISJSON(@messageBody) = 0 BEGIN
|
||||
SET @messageBody = CAST(TRY_CONVERT(xml, @messageBody) AS nvarchar(max))
|
||||
END
|
||||
END
|
||||
ELSE BEGIN
|
||||
INSERT INTO [auditlog].[AuditServiceFailedItems] ([conversation_handle], [message_body])
|
||||
VALUES ('00000000-0000-0000-0000-000000000000', @messageBody)
|
||||
COMMIT TRANSACTION;
|
||||
RAISERROR('XML or JSON validation failure before sending. Check [auditlog].[AuditServiceFailedItems] for failed message.', 16,1) WITH LOG;
|
||||
END
|
||||
|
||||
-- Will need a loop to retry in case the dialog is
|
||||
-- in a state that does not allow transmission
|
||||
WHILE (1=1) BEGIN
|
||||
-- Claim a dialog from the dialog pool.
|
||||
-- A new one will be created if none are available.
|
||||
|
||||
EXEC [auditlog].[usp_get_dialog] @fromService, @toService, @onContract, @dialogHandle OUTPUT, @sendCount OUTPUT;
|
||||
|
||||
-- Attempt to SEND on the dialog
|
||||
IF (@messageBody IS NOT NULL) BEGIN
|
||||
-- If the @messageBody is not null it must be sent explicitly
|
||||
|
||||
SEND ON CONVERSATION @dialogHandle MESSAGE TYPE @messageType (@messageBody);
|
||||
END
|
||||
ELSE BEGIN
|
||||
-- Messages with no body must *not* specify the body,
|
||||
-- cannot send a NULL value argument
|
||||
SEND ON CONVERSATION @dialogHandle MESSAGE TYPE @messageType;
|
||||
END
|
||||
|
||||
SET @error = @@ERROR;
|
||||
IF @error = 0 BEGIN
|
||||
-- Successful send, increment count and exit the loop
|
||||
SET @sendCount = @sendCount + 1;
|
||||
BREAK;
|
||||
END
|
||||
|
||||
SET @counter = @counter + 1;
|
||||
IF @counter > 10 BEGIN
|
||||
-- We failed 10 times in a row, something must be broken
|
||||
RAISERROR('Failed to SEND on a conversation for more than 10 times. Error %i.', 16, 1, @error) WITH LOG;
|
||||
BREAK;
|
||||
END
|
||||
|
||||
-- Delete the associated dialog from the table and try again
|
||||
EXEC [auditlog].[usp_delete_dialog] @dialogHandle;
|
||||
SELECT @dialogHandle = NULL;
|
||||
END
|
||||
|
||||
-- "Criterion" for dialog pool removal is send count > 1000.
|
||||
-- Modify to suit application.
|
||||
-- When deleting also inform the target to end the dialog.
|
||||
IF @sendCount > 1000 BEGIN
|
||||
EXEC [auditlog].[usp_delete_dialog] @dialogHandle ;
|
||||
SEND ON CONVERSATION @dialogHandle MESSAGE TYPE [EndOfStream];
|
||||
END
|
||||
ELSE BEGIN
|
||||
-- Free the dialog.
|
||||
EXEC [auditlog].[usp_free_dialog] @dialogHandle, @sendCount;
|
||||
END
|
||||
|
||||
COMMIT TRANSACTION;
|
||||
END
|
||||
GO
|
||||
|
||||
|
@@ -0,0 +1,102 @@
|
||||
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
|
||||
@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''
|
||||
,C_' + IIF(@isAlIntezmenyId = 0, '', 'AL') + 'INTEZMENYID AS ''C_INTEZMENYID''
|
||||
,' + IIF(@tableName = 'T_TANEV', 'ID', IIF(@isAlIntezmenyId = 0, 'C_TANEVID', 'C_ALTANEVID')) + ' 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''
|
||||
,C_' + IIF(@isAlIntezmenyId = 0, '', 'AL') + 'INTEZMENYID AS ''C_INTEZMENYID''
|
||||
,' + IIF(@tableName = 'T_TANEV', 'ID', IIF(@isAlIntezmenyId = 0, 'C_TANEVID', 'C_ALTANEVID')) + ' 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
|
||||
BEGIN TRY
|
||||
EXEC [auditlog].[usp_send]
|
||||
@fromService = ''AuditService'',
|
||||
@toService = ''AuditService'',
|
||||
@onContract = ''AuditContract'',
|
||||
@messageType = ''AuditMessage'',
|
||||
@messageBody = @messageBody
|
||||
INSERT INTO auditlog.XmlAudit (MessageBody, InsertedAt)
|
||||
VALUES (@messageBody, ISNULL(@alterationTime, GETDATE()))
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
INSERT INTO auditlog.XmlAudit (MessageBody, InsertedAt)
|
||||
VALUES (@messageBody, ISNULL(@alterationTime, GETDATE()))
|
||||
END CATCH
|
||||
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
|
||||
|
@@ -0,0 +1,229 @@
|
||||
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
|
||||
)
|
||||
|
||||
|
||||
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
|
||||
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 val, NULL, 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
|
||||
END
|
||||
|
||||
IF @action = 'D' BEGIN -- DELETED
|
||||
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, val, 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
|
||||
END
|
||||
|
||||
IF @action = 'U' BEGIN -- UPDATE
|
||||
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
|
||||
|
||||
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
|
@@ -0,0 +1,54 @@
|
||||
IF OBJECT_ID('dev.sp_Global_GenerateAsyncAuditTriggerAll') IS NOT NULL BEGIN
|
||||
DROP PROCEDURE dev.sp_Global_GenerateAsyncAuditTriggerAll
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditTriggerAll
|
||||
@disabled bit = 0
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE tableCursor CURSOR LOCAL FOR
|
||||
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',
|
||||
'T_OLDALLATOGATOTTSAG',
|
||||
'T_FELHASZNALOBELEPESTORTENET',
|
||||
'T_EVFOLYAMTIPUS_OKTATASINEVELE',
|
||||
'T_TELEPULES',
|
||||
'T_TANTARGYNEVHEZKATEGORIA',
|
||||
'T_SERVERSTATISTICS',
|
||||
'T_MOBILDBINFO',
|
||||
'T_LOGLEVELTYPE',
|
||||
'T_GLOBALISBEALLITASOK',
|
||||
'T_INTEZMENY',
|
||||
'T_FENNTARTO',
|
||||
'T_LOGEVENTTYPE'
|
||||
)
|
||||
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'
|
||||
)
|
||||
|
||||
DECLARE @tableName nvarchar(50)
|
||||
|
||||
OPEN tableCursor
|
||||
FETCH NEXT FROM tableCursor INTO @tableName
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditTrigger @tableName, @disabled
|
||||
|
||||
FETCH NEXT FROM tableCursor INTO @tableName
|
||||
END
|
||||
CLOSE tableCursor
|
||||
DEALLOCATE tableCursor
|
||||
END
|
||||
GO
|
||||
|
@@ -0,0 +1,33 @@
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditTriggerAll
|
||||
GO
|
||||
|
||||
ALTER QUEUE auditLog.[AuditQueue]
|
||||
WITH ACTIVATION
|
||||
(
|
||||
STATUS = ON,
|
||||
PROCEDURE_NAME = auditLog.usp_AuditProcessing,
|
||||
MAX_QUEUE_READERS = 10,
|
||||
EXECUTE AS 'Kreta_tech_user'
|
||||
);
|
||||
|
||||
GO
|
||||
|
||||
ALTER QUEUE auditlog.AuditQueue WITH STATUS = ON;
|
||||
GO
|
||||
|
||||
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditAuditProcessing;
|
||||
GO
|
||||
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditAuditProcedure;
|
||||
GO
|
||||
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditAuditProcedureAll;
|
||||
GO
|
||||
|
||||
DECLARE @sql nvarchar(max) = '';
|
||||
|
||||
SELECT @sql += N'DROP PROCEDURE IF EXISTS auditlog.' + ROUTINE_NAME + ';' + char(13) + char(10)
|
||||
FROM INFORMATION_SCHEMA.ROUTINES r
|
||||
WHERE r.ROUTINE_SCHEMA = N'auditlog'
|
||||
AND r.ROUTINE_NAME like N'usp_AsyncAudit%';
|
||||
|
||||
EXEC sys.sp_executesql @sql
|
||||
GO
|
Reference in New Issue
Block a user