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,230 @@
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditTrigger
GO
CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditTrigger
@tableName nvarchar(50)
,@disabled bit = 0
AS
DECLARE
@newColumnList nvarchar(max)
,@oldColumnList nvarchar(max)
,@SQL nvarchar(max)
,@ColumnIntezmenyId nvarchar(1000) = '0'
,@ColumnTanevId nvarchar(1000) = '0'
,@JoinKeys nvarchar(4000);
SELECT @newColumnList = ISNULL(@newColumnList + ', ', '') + 'i.' + COLUMN_NAME + N' AS ''new.' + COLUMN_NAME + '''',
@oldColumnList = ISNULL(@oldColumnList + ', ', '') + 'd.' + COLUMN_NAME + N' AS ''old.' + 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');
SELECT @ColumnIntezmenyId = CASE WHEN TABLE_NAME = 'T_INTEZMENY' THEN 'i.ID' ELSE 'i.' + COLUMN_NAME END
FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = @tableName AND TABLE_SCHEMA = 'dbo' AND COLUMN_NAME IN ('C_INTEZMENYID', 'C_ALINTEZMENYID');
SELECT @ColumnTanevId = CASE WHEN TABLE_NAME = 'T_TANEV' THEN 'i.ID' ELSE 'i.' + COLUMN_NAME END
FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME = @tableName AND TABLE_SCHEMA = 'dbo' AND COLUMN_NAME IN ('C_TANEVID', 'C_ALTANEVID');
SELECT @JoinKeys = COALESCE(@JoinKeys + ' AND ', '') + 'i.' + c.name + ' = d.' + c.name
FROM sys.key_constraints kc
INNER JOIN sys.index_columns ic ON ic.index_id = kc.unique_index_id AND ic.object_id = kc.parent_object_id
INNER JOIN sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
WHERE kc.parent_object_id = object_id('dbo.' + @tableName)
and kc.type = 'PK'
ORDER BY ic.index_column_id ASC;
SET @SQL = '
CREATE OR ALTER TRIGGER [tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + '] ON [' + @tableName + ']
WITH EXECUTE AS ''kreta_tech_user''
FOR INSERT, UPDATE, DELETE
AS
DECLARE @rowcount INT = @@ROWCOUNT;
DECLARE @json NVARCHAR(MAX);
DECLARE @key INT = 0;
DECLARE @limit INT = 1000;
DECLARE @action TINYINT = 0;
DECLARE @now NVARCHAR(20) = CONVERT(NVARCHAR(20), GETDATE(), 120);
DECLARE @handle UNIQUEIDENTIFIER;
DECLARE @userid INT;
SET NOCOUNT ON;
SET @action += CASE WHEN EXISTS(SELECT * FROM inserted) THEN 1 ELSE 0 END;
SET @action += CASE WHEN EXISTS(SELECT * FROM deleted) THEN 2 ELSE 0 END;
IF @rowcount = 0 SET @rowcount = (SELECT COUNT(*) FROM inserted);
IF @rowcount = 0 SET @rowcount = (SELECT COUNT(*) FROM deleted);
IF @rowcount = 0 RETURN;
SET @userid = TRY_CAST(SESSION_CONTEXT(N''USERID'') AS INT);
' + IIF(EXISTS(SELECT * FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_NAME = @tableName AND COLUMN_NAME = 'MODIFIER'), 'IF ISNULL(@userid, 0) = 0 AND (UPDATE(MODIFIER) OR UPDATE(CREATOR)) SET @userid = (SELECT TOP 1 NULLIF(ISNULL(MODIFIER, CREATOR), 0) FROM inserted);', '') + '
IF @rowcount > @limit
BEGIN
SELECT TOP 0 * INTO #audit_trigger_inserted FROM inserted UNION ALL SELECT TOP 0 * FROM inserted;
SELECT TOP 0 * INTO #audit_trigger_deleted FROM deleted UNION ALL SELECT TOP 0 * FROM deleted;
ALTER TABLE #audit_trigger_inserted ADD TRIGGER_ADDED_KEY INT NOT NULL IDENTITY(1, 1);
ALTER TABLE #audit_trigger_deleted ADD TRIGGER_ADDED_KEY INT NOT NULL IDENTITY(1, 1);
INSERT INTO #audit_trigger_inserted SELECT * FROM inserted;
INSERT INTO #audit_trigger_deleted SELECT * FROM deleted;
ALTER TABLE #audit_trigger_inserted ADD PRIMARY KEY CLUSTERED(TRIGGER_ADDED_KEY);
ALTER TABLE #audit_trigger_deleted ADD PRIMARY KEY CLUSTERED(TRIGGER_ADDED_KEY);
-- ALTER TABLE #audit_trigger_inserted ADD UNIQUE NONCLUSTERED (TRIGGER_ADDED_KEY);
-- ALTER TABLE #audit_trigger_deleted ADD UNIQUE NONCLUSTERED (TRIGGER_ADDED_KEY);
END
BEGIN DIALOG CONVERSATION @handle
FROM SERVICE AuditService
TO SERVICE ''AuditService''
ON CONTRACT AuditContract
WITH ENCRYPTION = OFF, LIFETIME = 10000;
WHILE (1 = 1)
BEGIN
IF @action = 1 -- INSERT
IF @rowcount > @limit
BEGIN
SET @json = (
SELECT TOP (@limit)
i.ID AS ID,
' + @ColumnTanevId + ' AS TID,
' + @ColumnIntezmenyId + ' AS IID,
ISNULL(i.MODIFIER, i.CREATOR) AS [UID],
' + @newColumnList + '
FROM #audit_trigger_inserted i
WHERE i.TRIGGER_ADDED_KEY > @key
ORDER BY i.TRIGGER_ADDED_KEY ASC
FOR JSON PATH, INCLUDE_NULL_VALUES
)
SELECT TOP (@limit) @key = TRIGGER_ADDED_KEY FROM #audit_trigger_inserted WHERE TRIGGER_ADDED_KEY > @key ORDER BY TRIGGER_ADDED_KEY;
END
ELSE
SET @json = (
SELECT
i.ID AS ID,
' + @ColumnTanevId + ' AS TID,
' + @ColumnIntezmenyId + ' AS IID,
ISNULL(i.MODIFIER, i.CREATOR) AS [UID],
' + @newColumnList + '
FROM inserted i
FOR JSON PATH, INCLUDE_NULL_VALUES
)
IF @action = 2 -- DELETE
IF @rowcount > @limit
BEGIN
SET @json = (
SELECT TOP (@limit)
d.ID AS ID,
' + replace(@ColumnTanevId, 'i.', 'd.') + ' AS TID,
' + replace(@ColumnIntezmenyId, 'i.', 'd.') + ' AS IID,
ISNULL(d.MODIFIER, d.CREATOR) AS [UID],
' + @oldColumnList + '
FROM #audit_trigger_deleted d
WHERE d.TRIGGER_ADDED_KEY > @key
ORDER BY d.TRIGGER_ADDED_KEY ASC
FOR JSON PATH, INCLUDE_NULL_VALUES
)
SELECT TOP (@limit) @key = TRIGGER_ADDED_KEY FROM #audit_trigger_deleted WHERE TRIGGER_ADDED_KEY > @key ORDER BY TRIGGER_ADDED_KEY;
END
ELSE
SET @json = (
SELECT
d.ID AS ID,
' + replace(@ColumnTanevId, 'i.', 'd.') + ' AS TID,
' + replace(@ColumnIntezmenyId, 'i.', 'd.') + ' AS IID,
ISNULL(d.MODIFIER, d.CREATOR) AS [UID],
' + @oldColumnList + '
FROM deleted d
FOR JSON PATH, INCLUDE_NULL_VALUES
)
IF @action = 3 --UPDATE
IF @rowcount > @limit
BEGIN
SET @json = (
SELECT TOP (@limit)
i.ID AS ID,
' + @ColumnTanevId + ' AS TID,
' + @ColumnIntezmenyId + ' AS IID,
ISNULL(i.MODIFIER, i.CREATOR) AS [UID],
' + @oldColumnList + ',
' + @newColumnList + '
FROM #audit_trigger_inserted i
INNER JOIN #audit_trigger_deleted d ON i.TRIGGER_ADDED_KEY = d.TRIGGER_ADDED_KEY
WHERE i.TRIGGER_ADDED_KEY > @key
ORDER BY i.TRIGGER_ADDED_KEY ASC
FOR JSON PATH, INCLUDE_NULL_VALUES
)
SELECT TOP (@limit) @key = TRIGGER_ADDED_KEY FROM #audit_trigger_inserted WHERE TRIGGER_ADDED_KEY > @key ORDER BY TRIGGER_ADDED_KEY;
END
ELSE
SET @json = (
SELECT
i.ID AS ID,
' + @ColumnTanevId + ' AS TID,
' + @ColumnIntezmenyId + ' AS IID,
ISNULL(i.MODIFIER, i.CREATOR) AS [UID],
' + @oldColumnList + ',
' + @newColumnList + '
FROM inserted i
INNER JOIN deleted d ON ' + @JoinKeys + '
FOR JSON PATH, INCLUDE_NULL_VALUES
)
IF @json IS NULL BREAK;
SET @json = CONCAT(
''{'',
''"ENTITY":"' + @tableName + '",'',
''"REASON":"'', CHOOSE(@action, ''New'', ''Removed'', ''Modified''), ''",'',
''"DATETIME":"'', @now, ''",'',
''"ACTION":'', @action, '','',
''"HOST":"'', HOST_NAME(), ''",'',
''"LOGIN":"'', REPLACE(ORIGINAL_LOGIN(), ''\'', ''\\''), ''",'',
''"USERID":'', COALESCE(CAST(@userid AS VARCHAR(10)), ''null''), '','',
''"ROWCOUNT":'', @rowcount, '', '',
''"ROWS": '', @json,
''}'');
SEND ON CONVERSATION @handle MESSAGE TYPE AuditMessage (@json);
IF @rowcount <= @limit BREAK;
END
END CONVERSATION @handle;
'
-- SELECT @SQL
EXEC sys.sp_executesql @SQL;
IF @disabled = 1
BEGIN
SET @SQL = 'DISABLE TRIGGER [tr_AsyncAudit' + UPPER(SUBSTRING(@tableName, 3, 100)) + '] ON [' + @tableName + ']';
EXEC(@SQL);
END
GO

View file

@ -0,0 +1,65 @@
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditTriggerAll
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_ENTITYATTRIBUTEHISTORY_ARCHIVE'
,'T_ENTITYBLOBVALUES'
,'T_ENTITYBLOBVALUES_ARCHIVE'
,'T_LOG'
,'T_GLOBALLOCK'
,'T_OLDALLATOGATOTTSAG'
,'T_FELHASZNALOBELEPESTORTENET'
,'T_EVFOLYAMTIPUS_OKTATASINEVELE'
,'T_TELEPULES'
,'T_TANTARGYNEVHEZKATEGORIA'
,'T_MOBILDBINFO'
,'T_LOGLEVELTYPE'
,'T_FENNTARTO'
,'T_LOGEVENTTYPE'
,'T_DASHBOARDUZENET'
,'T_DASHBOARDUZENETKATEGORIA'
,'T_AMITANTARGYSABLON'
,'T_AMITTFSABLON'
,'T_ADATTISZTITASINDIKATOR'
,'T_DASHBOARDUZENETINTEZMENY'
,'T_ORAREND'
,'T_TANULOTANTARGYATLAG'
,'T_CONFIGTIPUS'
,'T_INTEZMENYCONFIG'
,'T_SZIRSTATKONYVTARKATEGORIA'
,'T_ORARENDTELJES'
,'T_OSZTONDIJHISTORY'
)
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

View file

@ -0,0 +1,351 @@
CREATE OR ALTER PROCEDURE auditlog.usp_AuditProcessing
AS
SET NOCOUNT ON;
DECLARE @messagetype sysname
,@handle uniqueidentifier
,@message_body nvarchar(max)
,@json_part nvarchar(2000)
,@entity varchar(100)
,@reason varchar(100)
,@datetime datetime
,@action tinyint = 0
,@userid int
,@login nvarchar(1000)
,@hostname nvarchar(1000)
,@rowcount int
,@limit int = 100;
-- table for inserted rows
CREATE TABLE #ins(
C_ENTITYID INT NOT NULL,
C_PROPERTYNAME VARCHAR(100) NOT NULL,
C_INTEZMENYID INT NOT NULL,
C_TANEVID INT NOT NULL,
C_VALUE NVARCHAR(MAX) NULL,
PRIMARY KEY CLUSTERED (C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME)
)
-- table for deleted rows
CREATE TABLE #del(
C_ENTITYID INT NOT NULL,
C_PROPERTYNAME VARCHAR(100) NOT NULL,
C_INTEZMENYID INT NOT NULL,
C_TANEVID INT NOT NULL,
C_VALUE NVARCHAR(MAX) NULL,
PRIMARY KEY CLUSTERED (C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME)
)
-- table for audit rows
CREATE TABLE #audit(
C_ENTITYID INT NOT NULL,
C_INTEZMENYID INT NOT NULL,
C_TANEVID INT NOT NULL,
C_FELHASZNALOID INT NULL,
C_PROPERTYNAME VARCHAR(1000) NULL,
C_ORIGINALVALUE NVARCHAR(MAX) NULL,
C_CURRENTVALUE NVARCHAR(MAX) NULL
);
-- table for ids inserted into ENTITYHISTORY
CREATE TABLE #entity(
ENTITYID INT NOT NULL,
INTEZMENYID INT NOT NULL,
TANEVID INT NOT NULL,
ENTITYHISTORYID INT NOT NULL,
PRIMARY KEY CLUSTERED (ENTITYID, INTEZMENYID, TANEVID)
);
WHILE (1 = 1)
BEGIN
BEGIN TRY
TRUNCATE TABLE #ins;
TRUNCATE TABLE #del;
TRUNCATE TABLE #audit;
TRUNCATE TABLE #entity;
BEGIN TRANSACTION;
-- take 1 message from queue
WAITFOR (
RECEIVE TOP(1)
@handle = conversation_handle,
@message_body = message_body,
@messagetype = message_type_name
FROM auditlog.AuditQueue
), TIMEOUT 1000;
-- if there are no more rows in the queue then exit
IF @@ROWCOUNT = 0 BREAK;
IF @messagetype <> 'AuditMessage'
GOTO CONTINUE_PROCESS;
-- take the beginning of the message and search for "ROWS" node
SET @json_part = LEFT(@message_body, 2000);
IF @json_part LIKE '%"ROWS"%'
BEGIN
SET @json_part = LEFT(@json_part, PATINDEX('%"ROWS"%', @json_part) - 1);
SET @json_part = @json_part + '"ROWS":null}';
END
ELSE
BEGIN
INSERT INTO auditlog.AuditServiceFailedItems([conversation_handle], [message_body], [error_message])
VALUES (@handle, @message_body, 'No "ROWS" in first 2000 chars');
GOTO CONTINUE_PROCESS;
END
-- lightweight parsing of the message for headers
SELECT
@entity = CASE WHEN j.[key] = 'ENTITY' THEN j.[value] ELSE @entity END,
@reason = CASE WHEN j.[key] = 'REASON' THEN j.[value] ELSE @reason END,
@datetime = CASE WHEN j.[key] = 'DATETIME' THEN CONVERT(datetime, j.[value], 121) ELSE @datetime END,
@action = CASE WHEN j.[key] = 'ACTION' THEN j.[value] ELSE @action END,
@hostname = CASE WHEN j.[key] = 'HOST' THEN j.[value] ELSE @hostname END,
@login = CASE WHEN j.[key] = 'LOGIN' THEN j.[value] ELSE @login END,
@userid = CASE WHEN j.[key] = 'USERID' THEN j.[value] ELSE @userid END,
@rowcount = CASE WHEN j.[key] = 'ROWCOUNT' THEN j.[value] ELSE @rowcount END
FROM OPENJSON(@json_part) j
WHERE j.[key] in ('ENTITY', 'REASON', 'DATETIME', 'ACTION', 'HOST', 'LOGIN', 'USERID', 'ROWCOUNT');
-- user parsing
IF NOT EXISTS(SELECT * FROM dbo.T_FELHASZNALO WHERE ID = @userid)
BEGIN
INSERT INTO auditlog.Users(USERNAME)
SELECT @login AS USERNAME
WHERE NOT EXISTS(SELECT * FROM auditlog.Users WHERE USERNAME = @login);
SET @userid = null;
END
IF @rowcount > @limit
INSERT INTO #ins(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_VALUE)
SELECT
JSON_VALUE(j.value, '$.ID') AS C_ENTITYID,
JSON_VALUE(j.value, '$.IID') AS C_INTEZMENYID,
JSON_VALUE(j.value, '$.TID') AS C_TANEVID,
i.[key] AS C_PROPERTYNAME,
i.[value] AS C_VALUE
FROM OPENJSON(@message_body, '$.ROWS') j
CROSS APPLY OPENJSON(j.value, '$.new') i
OPTION (MAXDOP 1);
IF @rowcount > @limit
INSERT INTO #del(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_VALUE)
SELECT
JSON_VALUE(j.value, '$.ID') AS C_ENTITYID,
JSON_VALUE(j.value, '$.IID') AS C_INTEZMENYID,
JSON_VALUE(j.value, '$.TID') AS C_TANEVID,
d.[key] AS C_PROPERTYNAME,
d.[value] AS C_VALUE
FROM OPENJSON(@message_body, '$.ROWS') j
CROSS APPLY OPENJSON(j.value, '$.old') d
OPTION (MAXDOP 1);
-- extract audit rows from message
IF @action = 1 -- INSERT
IF @rowcount > @limit
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
i.C_ENTITYID,
i.C_INTEZMENYID,
i.C_TANEVID,
i.C_PROPERTYNAME AS C_PROPERTYNAME,
NULL AS C_ORIGINALVALUE,
i.C_VALUE AS C_CURRENTVALUE
FROM #ins i
OPTION (MAXDOP 1);
ELSE
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
JSON_VALUE(j.value, '$.ID') AS C_ENTITYID,
JSON_VALUE(j.value, '$.IID') AS C_INTEZMENYID,
JSON_VALUE(j.value, '$.TID') AS C_TANEVID,
i.[key] AS C_PROPERTYNAME,
NULL AS C_ORIGINALVALUE,
i.[value] AS C_CURRENTVALUE
FROM OPENJSON(@message_body, '$.ROWS') j
OUTER APPLY OPENJSON(j.value, '$.new') i
OPTION (MAXDOP 1);
IF @action = 2 -- DELETE
IF @rowcount > @limit
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
d.C_ENTITYID,
d.C_INTEZMENYID,
d.C_TANEVID,
d.C_PROPERTYNAME AS C_PROPERTYNAME,
d.C_VALUE AS C_ORIGINALVALUE,
NULL AS C_CURRENTVALUE
FROM #del d
OPTION (MAXDOP 1);
ELSE
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
JSON_VALUE(j.value, '$.ID') AS C_ENTITYID,
JSON_VALUE(j.value, '$.IID') AS C_INTEZMENYID,
JSON_VALUE(j.value, '$.TID') AS C_TANEVID,
d.[key] AS C_PROPERTYNAME,
d.[value] AS C_ORIGINALVALUE,
NULL AS C_CURRENTVALUE
FROM OPENJSON(@message_body, '$.ROWS') j
OUTER APPLY OPENJSON(j.value, '$.old') d
OPTION (MAXDOP 1);
IF @action = 3 -- UPDATE
IF @rowcount > @limit
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
ISNULL(i.C_ENTITYID, d.C_ENTITYID) AS C_ENTITYID,
ISNULL(i.C_INTEZMENYID, d.C_INTEZMENYID) AS C_INTEZMENYID,
ISNULL(i.C_TANEVID, d.C_TANEVID) AS C_TANEVID,
ISNULL(i.C_PROPERTYNAME, d.C_PROPERTYNAME) AS C_PROPERTYNAME,
d.C_VALUE AS C_ORIGINALVALUE,
i.C_VALUE AS C_CURRENTVALUE
FROM #ins i
INNER MERGE JOIN #del d ON i.C_ENTITYID = d.C_ENTITYID
AND i.C_INTEZMENYID = d.C_INTEZMENYID
AND i.C_TANEVID = d.C_TANEVID
AND i.C_PROPERTYNAME = d.C_PROPERTYNAME
OPTION (MAXDOP 1);
ELSE
INSERT INTO #audit(C_ENTITYID, C_INTEZMENYID, C_TANEVID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
JSON_VALUE(j.value, '$.ID') AS C_ENTITYID,
JSON_VALUE(j.value, '$.IID') AS C_INTEZMENYID,
JSON_VALUE(j.value, '$.TID') AS C_TANEVID,
ISNULL(i.[key], d.[key]) AS C_PROPERTYNAME,
d.[value] AS C_ORIGINALVALUE,
i.[value] AS C_CURRENTVALUE
FROM OPENJSON(@message_body, '$.ROWS') j
OUTER APPLY OPENJSON(j.value, '$.new') i
OUTER APPLY OPENJSON(j.value, '$.old') d
WHERE i.[key] = d.[key]
OPTION (MAXDOP 1);
BEGIN TRANSACTION T1;
-- fill entityhistory and save generated ids
INSERT INTO dbo.T_ENTITYHISTORY(C_ENTITYNAME, C_ENTITYID, C_REASON, C_INTEZMENYID, C_TANEVID, C_FELHASZNALOID, C_ALTERATIONDATE, CREATED, HOSTNAME)
OUTPUT inserted.C_ENTITYID, inserted.C_INTEZMENYID, inserted.C_TANEVID, inserted.ID INTO #entity(ENTITYID, INTEZMENYID, TANEVID, ENTITYHISTORYID)
SELECT DISTINCT
@entity AS C_ENTITYNAME,
C_ENTITYID,
@reason AS C_REASON,
C_INTEZMENYID,
C_TANEVID,
COALESCE(@userid, (SELECT USERID FROM auditlog.Users WHERE USERNAME = @login)) AS C_FELHASZNALOID,
@datetime AS C_ALTERATIONDATE,
GETDATE() AS CREATED,
@hostname AS HOSTNAME
FROM #audit
OPTION (MAXDOP 1);
-- fill attributehistory for small values
INSERT INTO dbo.T_ENTITYATTRIBUTEHISTORY(C_ENTITYHISTORYID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
e.ENTITYHISTORYID AS C_ENTITYHISTORYID,
a.C_PROPERTYNAME,
a.C_ORIGINALVALUE,
a.C_CURRENTVALUE
FROM #audit a
INNER JOIN #entity e ON e.ENTITYID = a.C_ENTITYID and e.INTEZMENYID = a.C_INTEZMENYID and e.TANEVID = a.C_TANEVID
WHERE (
(@action IN (1, 2))
OR
(@action = 3 AND ISNULL(a.C_ORIGINALVALUE, '') <> ISNULL(a.C_CURRENTVALUE, ''))
OR
(@action = 3 AND a.C_ORIGINALVALUE IS NULL AND a.C_CURRENTVALUE IS NOT NULL)
OR
(@action = 3 AND a.C_ORIGINALVALUE IS NOT NULL AND a.C_CURRENTVALUE IS NULL)
)
AND (ISNULL(DATALENGTH(a.C_ORIGINALVALUE), 0) <= 2000 AND ISNULL(DATALENGTH(a.C_CURRENTVALUE), 0) <= 2000)
OPTION (MAXDOP 1);
-- fill attributehistory for big values
INSERT INTO dbo.T_ENTITYBLOBVALUES(C_ENTITYHISTORYID, C_PROPERTYNAME, C_ORIGINALVALUE, C_CURRENTVALUE)
SELECT
e.ENTITYHISTORYID AS C_ENTITYHISTORYID,
a.C_PROPERTYNAME,
a.C_ORIGINALVALUE,
a.C_CURRENTVALUE
FROM #audit a
INNER JOIN #entity e ON e.ENTITYID = a.C_ENTITYID and e.INTEZMENYID = a.C_INTEZMENYID and e.TANEVID = a.C_TANEVID
WHERE (
(@action IN (1, 2))
OR
(@action = 3 AND ISNULL(a.C_ORIGINALVALUE, '') <> ISNULL(a.C_CURRENTVALUE, ''))
OR
(@action = 3 AND a.C_ORIGINALVALUE IS NULL AND a.C_CURRENTVALUE IS NOT NULL)
OR
(@action = 3 AND a.C_ORIGINALVALUE IS NOT NULL AND a.C_CURRENTVALUE IS NULL)
)
AND (ISNULL(DATALENGTH(a.C_ORIGINALVALUE), 0) > 2000 OR ISNULL(DATALENGTH(a.C_CURRENTVALUE), 0) > 2000)
OPTION (MAXDOP 1);
COMMIT TRANSACTION T1; -- commit changes in ENTITYHISTORY
CONTINUE_PROCESS:
IF @@TRANCOUNT > 0 COMMIT TRANSACTION; -- commit changes in the Queue
END TRY
BEGIN CATCH
DECLARE @E NVARCHAR(MAX) = dbo.fn_get_error_info();
IF @@TRANCOUNT > 1 ROLLBACK TRANSACTION T1; -- rollback changes in ENTITYHISTORY
INSERT auditlog.ErrorLog(UserName, ErrorNumber, ErrorSeverity, ErrorState, ErrorProcedure, ErrorLine, ErrorMessage)
VALUES(SUSER_NAME(), JSON_VALUE(@E, '$.ERROR_NUMBER'), JSON_VALUE(@E, '$.ERROR_SEVERITY'), JSON_VALUE(@E, '$.ERROR_STATE'), JSON_VALUE(@E, '$.ERROR_PROCEDURE'), JSON_VALUE(@E, '$.ERROR_LINE'), JSON_VALUE(@E, '$.ERROR_MESSAGE'));
INSERT INTO auditlog.AuditServiceFailedItems([conversation_handle], [message_body], [error_message])
VALUES(@handle, @message_body, JSON_VALUE(@E, '$.ERROR_MESSAGE'));
IF @@TRANCOUNT > 0 COMMIT TRANSACTION; -- commit changes in the Queue
END CATCH
END -- end of while
IF @@TRANCOUNT > 0 COMMIT TRANSACTION; -- commit any changes
-- close orphaned conversations
DECLARE @conversations TABLE([conversation_handle] uniqueidentifier NOT NULL PRIMARY KEY CLUSTERED);
INSERT INTO @conversations([conversation_handle])
SELECT e.[conversation_handle]
FROM sys.conversation_endpoints e WITH (NOLOCK)
WHERE e.[state] IN ('ER', 'DI', 'DO', 'CD')
AND e.far_service = 'AuditService'
AND NOT EXISTS(SELECT * FROM auditlog.AuditQueue a WITH (NOLOCK) WHERE a.[conversation_handle] = e.[conversation_handle])
OPTION (HASH JOIN);
SET @handle = 0x0;
WHILE (1 = 1)
BEGIN
SELECT TOP 1 @handle = [conversation_handle]
FROM @conversations
WHERE [conversation_handle] > @handle
ORDER BY [conversation_handle];
IF @@ROWCOUNT = 0 BREAK;
BEGIN TRY
END CONVERSATION @handle WITH CLEANUP;
END TRY
BEGIN CATCH
END CATCH
END
GO

View file

@ -0,0 +1,229 @@
USE msdb
GO
CREATE OR ALTER PROCEDURE dbo.usp_CheckAudit
@recipient_address NVARCHAR(1000) = null
AS
SET NOCOUNT ON;
DECLARE @result nvarchar(max) = ''
,@sql nvarchar(max)
,@remote_sql nvarchar(max)
,@db_cursor cursor
,@db_name nvarchar(100)
,@table_exists bit;
CREATE TABLE #AsyncActivity (
ServerName nvarchar(100)
,DatabaseName nvarchar(100)
,Broker bit null
,LastPageVisit datetime null
,LastEntityHistory datetime null
,FirstQueueItem datetime null
,QueueLength int null
,QueueEnabled bit null
,ProcessActivated bit null
,LastHourErrors int null
,LastHourFailedItems int null
,OpenConversations int null
,DisabledTriggers int null
,ErrorMessage nvarchar(4000) null,
Errors as (
case when (ErrorMessage > '') then 1 else 0 end +
case when (Broker = 0) then 2 else 0 end +
case when (QueueLength > 1 AND ISNULL(LastEntityHistory, GETDATE()) < ISNULL(DATEADD(hour, -3, LastPageVisit), GETDATE())) then 4 else 0 end +
case when (QueueEnabled = 0) then 8 else 0 end +
case when (QueueLength > 100000) then 16 else 0 end +
case when (ProcessActivated = 0) then 32 else 0 end +
case when (LastHourErrors > 0) then 64 else 0 end +
case when (LastHourFailedItems > 0) then 128 else 0 end +
case when (DisabledTriggers > 0) then 256 else 0 end +
case when (OpenConversations > 1000) then 512 else 0 end
)
);
SET @sql = '
SELECT
--@@SERVERNAME AS ServerName,
DB_NAME() AS DatabaseName,
(SELECT TOP 1 is_broker_enabled FROM sys.databases WHERE database_id = db_id()) AS Broker,
(SELECT TOP 1 CREATED FROM dbo.T_OLDALLATOGATOTTSAG (NOLOCK) ORDER BY ID DESC) AS LastPageVisit,
(SELECT TOP 1 CREATED FROM dbo.T_ENTITYHISTORY (NOLOCK) ORDER BY ID DESC) AS LastEntityHistory,
(SELECT TOP 1 message_enqueue_time FROM auditlog.AuditQueue WITH (NOLOCK) ORDER BY message_enqueue_time) AS FirstQueueItem,
(SELECT COUNT(*) FROM auditlog.AuditQueue WITH (NOLOCK)) AS QueueLength,
(SELECT TOP 1 is_enqueue_enabled FROM sys.service_queues WHERE name = ''AuditQueue'') AS QueueEnabled,
(SELECT TOP 1 is_activation_enabled FROM sys.service_queues WHERE name = ''AuditQueue'') AS ProcessActivated,
(SELECT COUNT(*) FROM auditlog.ErrorLog (NOLOCK) WHERE ErrorTime > DATEADD(minute, -61, GETDATE())) AS LastHourErrors,
(SELECT COUNT(*) FROM auditlog.AuditServiceFailedItems (NOLOCK) WHERE EventDate > DATEADD(minute, -61, GETDATE())) AS LastHourFailedItems,
(SELECT COUNT(*) FROM sys.triggers WHERE parent_class = 1 AND name LIKE ''tr_AsyncAudit%'' and is_disabled = 1) AS DisabledTriggers,
(SELECT COUNT(*) FROM sys.conversation_endpoints (NOLOCK) WHERE far_service = ''AuditService'') AS OpenConversations
';
SET @db_cursor = CURSOR STATIC FOR
SELECT DISTINCT name
FROM sys.databases d
LEFT JOIN sys.dm_hadr_database_replica_states rs on rs.database_id = d.database_id
WHERE d.state = 0
AND d.is_read_only = 0
AND d.database_id > 4
AND d.name NOT LIKE '%GINOP%'
AND d.source_database_id IS NULL
AND (
NOT EXISTS(SELECT * FROM sys.dm_hadr_database_replica_states r WHERE r.database_id = d.database_id)
OR
(rs.is_local = 1 AND rs.is_primary_replica = 1)
);
SET LOCK_TIMEOUT 5000;
OPEN @db_cursor;
FETCH NEXT FROM @db_cursor INTO @db_name;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @remote_sql = 'SELECT @table_exists = SIGN(COUNT(*)) FROM [' + @db_name + '].INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = ''T_ENTITYHISTORY'' and TABLE_SCHEMA = ''dbo''';
EXEC sp_executesql @remote_sql, N'@table_exists BIT OUTPUT', @table_exists = @table_exists OUTPUT;
IF @table_exists = 0 GOTO FETCH_NEXT;
SET @remote_sql = 'EXEC [' + @db_name + '].sys.sp_executesql @SQL';
BEGIN TRY
INSERT INTO #AsyncActivity(DatabaseName, Broker, LastPageVisit, LastEntityHistory, FirstQueueItem, QueueLength, QueueEnabled, ProcessActivated, LastHourErrors, LastHourFailedItems, DisabledTriggers, OpenConversations)
EXEC sp_executesql @remote_sql, N'@SQL NVARCHAR(max)', @SQL = @sql;
END TRY
BEGIN CATCH
INSERT INTO #AsyncActivity(ServerName, DatabaseName, ErrorMessage)
VALUES(@@SERVERNAME, @db_name, ERROR_MESSAGE());
END CATCH
FETCH_NEXT:
FETCH NEXT FROM @db_cursor INTO @db_name;
END
CLOSE @db_cursor
IF @recipient_address IS NULL
BEGIN
SELECT * FROM #AsyncActivity;
RETURN;
END
SELECT @result += '<tr>' +
'<td>' + DatabaseName + '</td>' +
CASE WHEN ErrorMessage IS NOT NULL THEN
'<td colspan=11' + IIF(Errors & 1 = 1, ' class="error"', '') + '>Error:' + ErrorMessage + '</td>'
ELSE
'<td' + IIF(Errors & 2 = 2, ' class="error"', '') + '>' + ISNULL(CAST(Broker AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td>' + ISNULL(CONVERT(VARCHAR(19), LastPageVisit, 120), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 4 = 4, ' class="error"', '') + '>' + ISNULL(CONVERT(VARCHAR(19), LastEntityHistory, 120), '&nbsp;') + '</td>' +
'<td>' + ISNULL(CONVERT(VARCHAR(19), FirstQueueItem, 120), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 16 = 16, ' class="error"', '') + '>' + ISNULL(CAST(QueueLength AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 8 = 8, ' class="error"', '') + '>' + ISNULL(CAST(QueueEnabled AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 32 = 32, ' class="error"', '') + '>' + ISNULL(CAST(ProcessActivated AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 64 = 64, ' class="error"', '') + '>' + ISNULL(CAST(LastHourErrors AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 128 = 128, ' class="error"', '') + '>' + ISNULL(CAST(LastHourFailedItems AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 256 = 256, ' class="error"', '') + '>' + ISNULL(CAST(DisabledTriggers AS VARCHAR(10)), '&nbsp;') + '</td>' +
'<td' + IIF(Errors & 512 = 512, ' class="error"', '') + '>' + ISNULL(CAST(OpenConversations AS VARCHAR(10)), '&nbsp;') + '</td>'
END +
'</tr>'
FROM #AsyncActivity
WHERE Errors > 0;
IF @@ROWCOUNT = 0 RETURN;
SET @result = '
<style>
p {
font-size: 10pt;
font-family: Calibri;
}
th {
border:1px solid #EEEEEE;
padding: 4px;
font-weight: bold;
font-size: 10pt;
font-family: Calibri;
background-color: #EEEEEE;
}
td {
border:1px solid #EEEEEE;
padding:4px;
text-align: right;
font-size: 10pt;
font-family: Calibri;
nowrap;
}
td.error {
border:1px solid #EEEEEE;
padding:4px;
text-align: right;
font-size: 10pt;
font-family: Calibri;
color: #FFFFFF;
background-color: #FF0000;
font-weight: bold;
nowrap;
}
</style>
<p>Figyelem! Hiba az AUDIT rendszerben a <b>' + @@SERVERNAME + '</b> szerveren:</p>
<table style="border-collapse:collapse">
<thead>
<th>DatabaseName</th>
<th>Broker On</th>
<th>Last Visit</th>
<th>Last History</th>
<th>First Queue</th>
<th>Queue Items</th>
<th>Queue On</th>
<th>Process Active</th>
<th>Latest Errors</th>
<th>Latest Fails</th>
<th>Disabled Triggers</th>
<th>Open Conversations</th>
</thead>
' + @result + '
</table>
<p>További információk és teendők: <a href= "https://ekretapedia.ekreta.hu/main/_layouts/15/WopiFrame.aspx?sourcedoc={9934831a-3b80-4c13-abc1-9274cceed8bb}&action=edit&wd=target%28Checklistek.one%7C2b67a257-f2e8-4e0e-9977-42134b49d577%2FAudit%20kezel%C3%A9se%20%28Audit%202.0%5C%29%7Cc1f02bcc-4bd9-485b-8deb-d98f310d946e%2F%29&wdorigin=703">OneNote|Checklistek\Audit kezelése (Audit 2.0)</a></p>
'
IF EXISTS(SELECT * FROM #AsyncActivity WHERE Errors & 32 = 32)
SET @result += '
<p><b>Process Active:</b> Újraindítás a következő paranccsal:</p>
<pre style="background-color: #EEEEEE">
ALTER QUEUE auditlog.AuditQueue
WITH
STATUS = ON,
ACTIVATION (
STATUS = ON,
PROCEDURE_NAME = auditlog.usp_AuditProcessing,
MAX_QUEUE_READERS = 1,
EXECUTE AS ''kreta_tech_user''
),
POISON_MESSAGE_HANDLING (STATUS = ON);
</pre>'
IF EXISTS(SELECT * FROM #AsyncActivity WHERE Errors & 512 = 512)
SET @result += '
<p><b>Open Conversations:</b>Javítás:</p>
<pre style="background-color: #EEEEEE">
SELECT * FROM sys.dm_broker_activated_tasks WHERE database_id = DB_ID();
SELECT * FROM sys.sysprocesses WHERE spid = $spid;
KILL $spid;
</pre>'
EXEC msdb.dbo.sp_send_dbmail
--@profile_name = 'SQL Server Alert Mail Profile',
@recipients = @recipient_address
,@body = @result
,@subject = N'KRÉTA - Audit TRIGGER/QUEUE/PROCESS hiba'
,@importance = 'High'
,@body_format = 'HTML'

View file

@ -0,0 +1,35 @@
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE OR ALTER PROCEDURE auditlog.uspLogError
@ErrorLogID int = 0 OUTPUT -- contains the ErrorLogID of the row inserted
AS -- by uspLogError in the ErrorLog table
DECLARE
@error_number INT = ERROR_NUMBER(),
@error_severity INT = ERROR_SEVERITY(),
@error_state INT = ERROR_STATE(),
@error_procedure SYSNAME = ERROR_PROCEDURE(),
@error_line INT = ERROR_LINE(),
@error_message NVARCHAR(4000) = ERROR_MESSAGE();
SET NOCOUNT ON;
INSERT auditlog.ErrorLog (
UserName,
ErrorNumber,
ErrorSeverity,
ErrorState,
ErrorProcedure,
ErrorLine,
ErrorMessage
) VALUES (
CURRENT_USER,
@error_number,
@error_severity,
@error_state,
@error_procedure,
@error_line,
@error_message
);
SET @ErrorLogID = SCOPE_IDENTITY();
GO