This commit is contained in:
skidoodle 2024-03-13 00:33:46 +01:00
commit e124a47765
19374 changed files with 9806149 additions and 0 deletions

View file

@ -0,0 +1,32 @@
IF EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditServiceTarget') BEGIN
DROP SERVICE AuditServiceTarget
END
GO
IF EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditServiceInit') BEGIN
DROP SERVICE AuditServiceInit
END
GO
IF EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditService') BEGIN
DROP SERVICE [AuditService]
END
GO
IF EXISTS (SELECT 1 FROM sys.service_queues WHERE name = 'AuditQueue') BEGIN
DROP QUEUE auditlog.AuditQueue
END
GO
IF EXISTS (SELECT 1 FROM sys.service_contracts WHERE name = 'AuditContract') BEGIN
DROP CONTRACT AuditContract
END
GO
IF EXISTS (SELECT 1 FROM sys.service_message_types WHERE name = 'AuditMessage') BEGIN
DROP MESSAGE TYPE AuditMessage
END
GO

View file

@ -0,0 +1,24 @@
DECLARE @sql nvarchar(max)
EXEC sp_changedbowner 'sa';
IF (SELECT is_broker_enabled FROM sys.databases WHERE database_id = DB_ID()) = 0 BEGIN
SET @sql = N'ALTER DATABASE ' + DB_NAME() + ' SET SINGLE_USER WITH ROLLBACK IMMEDIATE '
EXEC master.sys.sp_executesql @sql
-- Ha a Service Broker IDja nem egyedi
IF EXISTS (SELECT 1 FROM sys.databases x WHERE x.service_broker_guid = (SELECT service_broker_guid FROM sys.databases d WHERE d.database_id = DB_ID()) AND x.database_id <> DB_ID()) BEGIN
SET @sql = N'ALTER DATABASE ' + DB_NAME() + ' SET NEW_BROKER'
EXEC master.sys.sp_executesql @sql
END
ELSE BEGIN
SET @sql = N'ALTER DATABASE ' + DB_NAME() + ' SET ENABLE_BROKER'
EXEC master.sys.sp_executesql @sql
END
SET @sql = N'ALTER DATABASE ' + DB_NAME() + ' SET MULTI_USER'
EXEC master.sys.sp_executesql @sql
END;
GO

View file

@ -0,0 +1,39 @@
IF NOT EXISTS (SELECT 1 FROM sys.service_message_types WHERE name = 'AuditMessage') BEGIN
CREATE MESSAGE TYPE [AuditMessage]
VALIDATION = WELL_FORMED_XML;
END
GO
IF NOT EXISTS (SELECT 1 FROM sys.service_message_types WHERE name = 'EndOfStream') BEGIN
CREATE MESSAGE TYPE EndOfStream;
END
GO
IF NOT EXISTS (SELECT 1 FROM sys.service_contracts WHERE name = 'AuditContract') BEGIN
CREATE CONTRACT [AuditContract] (
[AuditMessage] SENT BY INITIATOR,
[EndOfStream] SENT BY INITIATOR
);
END
GO
IF OBJECT_ID('auditlog.usp_AuditProcessing') IS NULL BEGIN
EXEC('CREATE PROCEDURE auditlog.usp_AuditProcessing AS SELECT 1')
END
IF NOT EXISTS (SELECT 1 FROM sys.service_queues WHERE name = 'AuditQueue') BEGIN
CREATE QUEUE auditlog.AuditQueue WITH STATUS=ON, ACTIVATION (
STATUS = ON
,MAX_QUEUE_READERS = 1
,PROCEDURE_NAME = auditlog.usp_AuditProcessing
,EXECUTE AS 'kreta_tech_user'
);
END
GO
IF NOT EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditService') BEGIN
CREATE SERVICE [AuditService]
ON QUEUE auditlog.AuditQueue ([AuditContract]);
END
GO

View file

@ -0,0 +1,93 @@
IF OBJECT_ID('auditlog.ErrorLog') IS NOT NULL
DROP TABLE [auditlog].[ErrorLog];
GO
CREATE TABLE [auditlog].[ErrorLog](
[ErrorLogID] [int] IDENTITY(1,1) NOT NULL,
[ErrorTime] [datetime] NOT NULL,
[UserName] [sysname] NOT NULL,
[ErrorNumber] [int] NOT NULL,
[ErrorSeverity] [int] NULL,
[ErrorState] [int] NULL,
[ErrorProcedure] [nvarchar](126) NULL,
[ErrorLine] [int] NULL,
[ErrorMessage] [nvarchar](4000) NOT NULL,
CONSTRAINT [PK_ErrorLog_ErrorLogID] PRIMARY KEY CLUSTERED ([ErrorLogID] ASC)
)
GO
ALTER TABLE [auditlog].[ErrorLog]
ADD CONSTRAINT [DF_ErrorLog_ErrorTime]
DEFAULT (getdate()) FOR [ErrorTime]
GO
IF OBJECT_ID('auditlog.uspLogError') IS NOT NULL
DROP PROCEDURE [auditlog].[uspLogError];
GO
CREATE PROCEDURE [auditlog].[uspLogError]
@ErrorLogID int = 0 OUTPUT -- contains the ErrorLogID of the row inserted
AS -- by uspLogError in the ErrorLog table
BEGIN
SET NOCOUNT ON;
-- Output parameter value of 0 indicates that error
-- information was not logged
SET @ErrorLogID = 0;
BEGIN TRY
-- Return if there is no error information to log
IF ERROR_NUMBER() IS NULL
RETURN;
-- Return if inside an uncommittable transaction.
-- Data insertion/modification is not allowed when
-- a transaction is in an uncommittable state.
IF XACT_STATE() = -1 BEGIN
PRINT 'Cannot log error since the current transaction is in an uncommittable state. '
+ 'Rollback the transaction before executing uspLogError in order to successfully log error information.';
RETURN;
END
INSERT [auditlog].[ErrorLog] (
[UserName],
[ErrorNumber],
[ErrorSeverity],
[ErrorState],
[ErrorProcedure],
[ErrorLine],
[ErrorMessage]
) VALUES (
CONVERT(sysname, CURRENT_USER),
ERROR_NUMBER(),
ERROR_SEVERITY(),
ERROR_STATE(),
ERROR_PROCEDURE(),
ERROR_LINE(),
ERROR_MESSAGE()
);
-- Pass back the ErrorLogID of the row inserted
SET @ErrorLogID = @@IDENTITY;
END TRY
BEGIN CATCH
PRINT 'An error occurred in stored procedure uspLogError: ';
RAISERROR('Error during logging an error by uspLogError', 16, 1) WITH LOG;
RETURN -1;
END CATCH
END;
GO
IF OBJECT_ID('auditlog.AuditServiceFailedItems') IS NOT NULL
DROP TABLE [auditlog].[AuditServiceFailedItems];
GO
CREATE TABLE [auditlog].[AuditServiceFailedItems] (
[conversation_handle] uniqueidentifier,
[message_body] nvarchar(max),
[EventDate] datetime DEFAULT CURRENT_TIMESTAMP
);
GO

View file

@ -0,0 +1,238 @@
IF OBJECT_ID('auditlog.DialogPool') IS NOT NULL
DROP TABLE [auditlog].[DialogPool];
GO
CREATE TABLE [auditlog].[DialogPool] (
[FromService] SYSNAME NOT NULL,
[ToService] SYSNAME NOT NULL,
[OnContract] SYSNAME NOT NULL,
[Handle] UNIQUEIDENTIFIER NOT NULL,
[OwnerSPID] INT NOT NULL,
[CreationTime] DATETIME NOT NULL,
[SendCount] BIGINT NOT NULL,
CONSTRAINT [UQ_DialogPool_Handle] UNIQUE (Handle)
);
GO
IF OBJECT_ID('auditlog.usp_get_dialog') IS NOT NULL
DROP PROCEDURE [auditlog].[usp_get_dialog];
GO
CREATE PROCEDURE [auditlog].[usp_get_dialog]
@fromService SYSNAME,
@toService SYSNAME,
@onContract SYSNAME,
@dialogHandle UNIQUEIDENTIFIER OUTPUT,
@sendCount BIGINT OUTPUT
AS
BEGIN
SET NOCOUNT ON;
DECLARE @dialog TABLE (
[FromService] SYSNAME NOT NULL,
[ToService] SYSNAME NOT NULL,
[OnContract] SYSNAME NOT NULL,
[Handle] UNIQUEIDENTIFIER NOT NULL,
[OwnerSPID] INT NOT NULL,
[CreationTime] DATETIME NOT NULL,
[SendCount] BIGINT NOT NULL
);
-- Try to claim an unused dialog in DialogPool
-- READPAST option avoids blocking on locked dialogs.
BEGIN TRANSACTION;
DELETE FROM @dialog;
UPDATE TOP(1) [auditlog].[DialogPool] WITH(READPAST)
SET [OwnerSPID] = @@SPID
OUTPUT INSERTED.* INTO @dialog
WHERE [FromService] = @fromService
AND [ToService] = @toService
AND [OnContract] = @OnContract
AND [OwnerSPID] = -1;
IF @@ROWCOUNT > 0 BEGIN
SET @dialogHandle = (SELECT [Handle] FROM @dialog);
SET @sendCount = (SELECT [SendCount] FROM @dialog);
END
ELSE BEGIN
-- No free dialogs: need to create a new one
BEGIN DIALOG CONVERSATION @dialogHandle
FROM SERVICE @fromService
TO SERVICE @toService
ON CONTRACT @onContract
WITH ENCRYPTION = OFF;
INSERT INTO [auditlog].[DialogPool]
([FromService], [ToService], [OnContract], [Handle], [OwnerSPID], [CreationTime], [SendCount])
VALUES
(@fromService, @toService, @onContract, @dialogHandle, @@SPID, GETDATE(), 0);
SET @sendCount = 0;
END
COMMIT TRANSACTION;
END
GO
--------------------------------------------------------------------------
-- Free dialog procedure.
-- Return the dialog to the pool.
-- Inputs are dialog handle and updated send count.
--------------------------------------------------------------------------
IF OBJECT_ID('auditlog.usp_free_dialog') IS NOT NULL
DROP PROCEDURE [auditlog].[usp_free_dialog];
GO
CREATE PROCEDURE [auditlog].[usp_free_dialog]
@dialogHandle UNIQUEIDENTIFIER,
@sendCount BIGINT
AS
BEGIN
SET NOCOUNT ON;
DECLARE @rowcount INT;
DECLARE @string VARCHAR(50);
BEGIN TRANSACTION;
-- Release dialog by setting OwnerSPID to -1.
UPDATE [auditlog].[DialogPool] SET [OwnerSPID] = -1, [SendCount] = @sendCount
WHERE [Handle] = @dialogHandle;
SET @rowcount = @@ROWCOUNT;
IF @rowcount = 0 BEGIN
SET @string = (SELECT CAST( @dialogHandle AS VARCHAR(50)));
RAISERROR('usp_free_dialog: dialog %s not found in dialog pool', 16, 1, @string) WITH LOG;
END
ELSE IF @rowcount > 1 BEGIN
SET @string = (SELECT CAST( @dialogHandle AS VARCHAR(50)));
RAISERROR('usp_free_dialog: duplicate dialog %s found in dialog pool', 16, 1, @string) WITH LOG;
END
COMMIT TRANSACTION;
END
GO
IF OBJECT_ID('auditlog.usp_delete_dialog') IS NOT NULL
DROP PROCEDURE [auditlog].[usp_delete_dialog];
GO
CREATE PROCEDURE [auditlog].[usp_delete_dialog]
@dialogHandle UNIQUEIDENTIFIER
AS
BEGIN
SET NOCOUNT ON;
BEGIN TRY
BEGIN TRANSACTION;
DELETE [DialogPool] WHERE Handle = @dialogHandle;
COMMIT TRANSACTION;
END TRY
BEGIN CATCH
-- Rollback any active or uncommittable transactions before
-- inserting information in the ErrorLog
IF @@TRANCOUNT > 0 BEGIN
ROLLBACK TRANSACTION;
END
EXECUTE [auditlog].[uspLogError];
END CATCH;
END
GO
IF OBJECT_ID('auditlog.usp_send') IS NOT NULL
DROP PROCEDURE [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 [validation] = 'X')
AND (TRY_CONVERT(xml, @messageBody) IS NOT NULL)
BEGIN
SET @messageBody = CAST(TRY_CONVERT(xml, @messageBody) AS nvarchar(max))
END
ELSE BEGIN
INSERT INTO [auditlog].[AuditServiceFailedItems] ([conversation_handle], [message_body])
VALUES ('00000000-0000-0000-0000-000000000000', @messageBody)
COMMIT TRANSACTION;
RAISERROR('XML 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

View file

@ -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 + '
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", (
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

View file

@ -0,0 +1,143 @@
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
-- DROP PROCEDURE adt.usp_AuditProcessing
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

View file

@ -0,0 +1,171 @@
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
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;
--select @sql
END
GO

View file

@ -0,0 +1,42 @@
EXEC dev.sp_Global_GenerateAsyncAuditTriggerAll
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
DECLARE trCursor CURSOR FOR
SELECT OBJECT_NAME(parent_id) AS tableName, name as triggerName
FROM sys.triggers
WHERE name like 'tr%Log'
DECLARE
@tableName nvarchar(100),
@triggerName nvarchar(100),
@sql nvarchar(max)
OPEN trCursor
FETCH NEXT FROM trCursor INTO @tableName, @triggerName
WHILE @@FETCH_STATUS = 0 BEGIN
SET @sql = 'DROP TRIGGER ' + @triggerName + ';'
EXEC sys.sp_executesql @sql
FETCH NEXT FROM trCursor INTO @tableName, @triggerName
END
CLOSE trCursor
DEALLOCATE trCursor
GO