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

View File

@@ -0,0 +1,63 @@
-- Enable Service Broker
DECLARE @sql nvarchar(max)
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
GO
-- Creating message
IF NOT EXISTS (SELECT 1 FROM sys.service_message_types WHERE name = 'AuditMessage') BEGIN
CREATE MESSAGE TYPE AuditMessage
AUTHORIZATION kreta_tech_user
--VALIDATION = WELL_FORMED_XML
END
GO
-- Creating contract
IF NOT EXISTS (SELECT 1 FROM sys.service_contracts WHERE name = 'AuditContract') BEGIN
CREATE CONTRACT AuditContract
AUTHORIZATION kreta_tech_user (AuditMessage SENT BY INITIATOR);
END
GO
-- Creating queue
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
-- Creating init Service
IF NOT EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditServiceInit') BEGIN
CREATE SERVICE AuditServiceInit
AUTHORIZATION kreta_tech_user
ON QUEUE auditlog.AuditQueue (AuditContract);
END
GO
-- Creating target Service
IF NOT EXISTS (SELECT 1 FROM sys.services WHERE name = 'AuditServiceTarget') BEGIN
CREATE SERVICE AuditServiceTarget
AUTHORIZATION kreta_tech_user
ON QUEUE auditlog.AuditQueue (AuditContract);
END
GO

View File

@@ -0,0 +1,15 @@
IF SCHEMA_ID('dev') IS NULL BEGIN
EXEC sp_executesql N'CREATE SCHEMA dev'
END
GO
IF SCHEMA_ID('auditlog') IS NULL BEGIN
EXEC sp_executesql N'CREATE SCHEMA auditlog'
END
GO
IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE [name] = 'kreta_tech_user') BEGIN
CREATE USER kreta_tech_user WITHOUT LOGIN
EXEC sp_addrolemember N'db_owner', N'kreta_tech_user';
END

View File

@@ -0,0 +1,8 @@
EXEC dev.sp_Global_GenerateAsyncAuditTriggerAll 1
GO
EXEC dev.sp_Global_GenerateAsyncAuditProcedureAll
GO
EXEC dev.sp_Global_GenerateAsyncAuditAuditPocessing
GO

View File

@@ -0,0 +1,73 @@
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 ('CREATOR', 'MODIFIER')
AND TABLE_NAME NOT IN ('T_ENTITYHISTORY', 'T_ENTITYATTRIBUTEHISTORY', 'T_LOG', 'T_GLOBALLOCK')
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 audit.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 XML
,@tableName nvarchar(50)
WHILE (1 = 1) BEGIN -- Receive the next available message from the queue
WAITFOR (
RECEIVE TOP(1)
@message_type = message_type_name
,@message_body = CAST(message_body AS XML)
,@dialog = conversation_handle
FROM auditlog.AuditQueue
), TIMEOUT 500
IF (@@ROWCOUNT = 0 OR @message_body IS NULL) BEGIN
BREAK
END
ELSE BEGIN
SELECT @tableName = t.c.value(''@name'', ''nvarchar(50)'')
FROM @message_body.nodes(''/audit'') t(c)
' + @if + '
END
END CONVERSATION @dialog
END
END
'
EXEC sys.sp_executesql @sql
END
GO

View File

@@ -0,0 +1,170 @@
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

View File

@@ -0,0 +1,35 @@
IF OBJECT_ID('dev.sp_Global_GenerateAsyncAuditProcedureAll') IS NOT NULL BEGIN
DROP PROCEDURE dev.sp_Global_GenerateAsyncAuditProcedureAll
END
GO
CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditProcedureAll AS
BEGIN
DECLARE @tableName nvarchar(50)
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')
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'
)
OPEN tableCursor
FETCH NEXT FROM tableCursor INTO @tableName
WHILE @@FETCH_STATUS = 0 BEGIN
EXEC dev.sp_Global_GenerateAsyncAuditProcedure @tableName
FETCH NEXT FROM tableCursor INTO @tableName
END
CLOSE tableCursor
DEALLOCATE tableCursor
END
GO

View File

@@ -0,0 +1,73 @@
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 XML
DECLARE @TableId int
--get relevant information from inserted/deleted and convert to xml message
SET @MessageBody = (
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
)
IF @MessageBody IS NOT NULL BEGIN
DECLARE @Handle UNIQUEIDENTIFIER;
BEGIN DIALOG CONVERSATION @Handle
FROM SERVICE AuditServiceInit
TO SERVICE ''AuditServiceTarget''
ON CONTRACT AuditContract
WITH ENCRYPTION = OFF;
SEND ON CONVERSATION @Handle
MESSAGE TYPE AuditMessage(@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,37 @@
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')
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