Skip to content

Commit

Permalink
Feature/55184 update school audit trigger (#2339)
Browse files Browse the repository at this point in the history
* Update assets version

* Update trigger

* Update ms-sql version

Attempt to fix the issue that triggers cannot be ALTERed without error.

* Update migrations - scope

* Make azure-sql-edge the default for local dev

* Drop FK constraint from schoolAudit table

* Handle DELETE ops in school audit trigger

* Fix: remove FK from pupilAudit

* Update pupil audit trigger  - now handles deletes
  • Loading branch information
jon-shipley authored Nov 25, 2022
1 parent e7c61ae commit fe31436
Show file tree
Hide file tree
Showing 10 changed files with 293 additions and 3 deletions.
2 changes: 1 addition & 1 deletion admin/package.json
Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@
"watch:integration": "yarn jest --watch --coverage=no --config ./tests-integration/jest.integration.config.js"
},
"mtc": {
"assets-version": "35403e1d6d0f5f675c028f29d5629ce0"
"assets-version": "e3cf7309a51a6a6af117a4d5f04dedec"
},
"engines": {
"node": ">= 14"
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
CREATE OR ALTER TRIGGER [mtc_admin].[schoolInsertUpdateAuditTrigger] ON [mtc_admin].[school]
AFTER INSERT, UPDATE, DELETE
AS
BEGIN
DECLARE @auditOperationTypeLookupId int;
DECLARE @newDataJson NVARCHAR(MAX);
DECLARE @updatedTimestamp DATETIMEOFFSET(3) = GETUTCDATE();
DECLARE @schoolId INT;
-- infer audit type, populate var
IF EXISTS (SELECT 1 FROM inserted)
BEGIN
IF EXISTS (SELECT 1 FROM deleted)
BEGIN
-- I am an update
SELECT @auditOperationTypeLookupId=2
SELECT @schoolId = id FROM inserted
-- incorporate updatedAt trigger logic, to avoid duplicate audit entries
UPDATE [mtc_admin].[school] SET updatedAt = @updatedTimestamp
WHERE id = @schoolId
END
ELSE
BEGIN
-- I am an insert
SELECT @auditOperationTypeLookupId=1
END
END
ELSE
BEGIN
-- Delete operation
SELECT @auditOperationTypeLookupId=3
END

DECLARE @lastModifiedBy_userId int
DECLARE db_cursor CURSOR FOR
SELECT i.id, i.lastModifiedBy_userId
FROM inserted i;
DECLARE db_deleted_cursor CURSOR FOR
SELECT d.id, d.lastModifiedBy_userId
FROM deleted d;

IF @auditOperationTypeLookupId IN (1,2)
BEGIN
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @schoolId, @lastModifiedBy_userId
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @newDataJson = (SELECT TOP 1 * FROM inserted i WHERE i.id = @schoolId FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER);
-- incorporate updatedAt trigger logic, to avoid duplicate audit entries
IF @auditOperationTypeLookupId = 2
BEGIN
UPDATE [mtc_admin].[school] SET updatedAt = @updatedTimestamp WHERE id = @schoolId;
SET @newDataJson = JSON_MODIFY(@newDataJson, '$.updatedAt', CAST(@updatedTimestamp AS NVARCHAR));
END
-- do insert into school audit
INSERT INTO [mtc_admin].[schoolAudit]
(auditOperationTypeLookup_id, newData, school_id, operationBy_userId, sqlUserIdentifier)
VALUES (@auditOperationTypeLookupId, @newDataJson, @schoolId, @lastModifiedBy_userId, SUSER_SNAME());

FETCH NEXT FROM db_cursor INTO @schoolId, @lastModifiedBy_userId
END

CLOSE db_cursor
DEALLOCATE db_cursor
END

IF @auditOperationTypeLookupId = 3
BEGIN
OPEN db_deleted_cursor
FETCH NEXT FROM db_deleted_cursor INTO @schoolId, @lastModifiedBy_userId
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @newDataJson = (SELECT TOP 1 * FROM deleted d WHERE d.id = @schoolId FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER);
-- do insert into school audit
INSERT INTO [mtc_admin].[schoolAudit]
(auditOperationTypeLookup_id, newData, school_id, operationBy_userId, sqlUserIdentifier)
VALUES (@auditOperationTypeLookupId, @newDataJson, @schoolId, @lastModifiedBy_userId, SUSER_SNAME());

FETCH NEXT FROM db_deleted_cursor INTO @schoolId, @lastModifiedBy_userId
END

CLOSE db_deleted_cursor
DEALLOCATE db_deleted_cursor
END
END
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
CREATE OR ALTER TRIGGER [mtc_admin].[schoolInsertUpdateAuditTrigger] ON [mtc_admin].[school]
AFTER INSERT, UPDATE
AS
BEGIN
DECLARE @auditOperationTypeLookupId int
DECLARE @newDataJson NVARCHAR(MAX)
DECLARE @updatedTimestamp DATETIMEOFFSET(3) = GETUTCDATE()
-- infer audit type, populate var
IF EXISTS (SELECT 1 FROM inserted)
BEGIN
IF EXISTS (SELECT 1 FROM deleted)
BEGIN
-- I am an update
SELECT @auditOperationTypeLookupId=2
DECLARE @schoolId INT
SELECT @schoolId = id FROM inserted
-- incorporate updatedAt trigger logic, to avoid duplicate audit entries
UPDATE [mtc_admin].[school] SET updatedAt = @updatedTimestamp
WHERE id = @schoolId
END
ELSE
BEGIN
-- I am an insert
SELECT @auditOperationTypeLookupId=1
END
END
ELSE
BEGIN
-- I am a delete (not currently supported)
SELECT @auditOperationTypeLookupId=3
END
-- grab incoming data as JSON
SELECT @newDataJson = (SELECT * FROM inserted FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER)

SET @newDataJson = JSON_MODIFY(@newDataJson, '$.updatedAt', CAST(@updatedTimestamp AS NVARCHAR))

INSERT INTO [mtc_admin].[schoolAudit]
(auditOperationTypeLookup_id, newData, school_id, operationBy_userId, sqlUserIdentifier)

SELECT @auditOperationTypeLookupId, @newDataJson, i.id, i.lastModifiedBy_userId, SUSER_SNAME()
FROM mtc_admin.school s
INNER JOIN inserted i ON s.id = i.id
END
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
ALTER TABLE [mtc_admin].[schoolAudit]
DROP CONSTRAINT IF EXISTS [FK_school_id];
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
IF NOT EXISTS(SELECT *
FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE
WHERE CONSTRAINT_COLUMN_USAGE.TABLE_SCHEMA = 'mtc_admin'
AND CONSTRAINT_COLUMN_USAGE.TABLE_NAME = 'schoolAudit'
AND CONSTRAINT_COLUMN_USAGE.COLUMN_NAME = 'school_id'
AND CONSTRAINT_NAME = 'FK_school_id')
BEGIN
ALTER TABLE [mtc_admin].[schoolAudit]
ADD CONSTRAINT [FK_school_id]
FOREIGN KEY (school_id) REFERENCES [mtc_admin].[school] (id);
END
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
ALTER TABLE [mtc_admin].[pupilAudit]
DROP CONSTRAINT IF EXISTS [FK_pupilAudit_pupil_id];
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
IF NOT EXISTS(SELECT *
FROM INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE
WHERE CONSTRAINT_COLUMN_USAGE.TABLE_SCHEMA = 'mtc_admin'
AND CONSTRAINT_COLUMN_USAGE.TABLE_NAME = 'pupilAudit'
AND CONSTRAINT_COLUMN_USAGE.COLUMN_NAME = 'pupil_id'
AND CONSTRAINT_NAME = 'FK_pupilAudit_pupil_id')
BEGIN
ALTER TABLE [mtc_admin].[pupilAudit]
ADD CONSTRAINT [FK_pupilAudit_pupil_id]
FOREIGN KEY (pupil_id) REFERENCES [mtc_admin].[pupil] (id);
END
Original file line number Diff line number Diff line change
@@ -0,0 +1,82 @@
CREATE OR ALTER TRIGGER [mtc_admin].[pupilInsertUpdateAuditTrigger] ON [mtc_admin].[pupil]
AFTER INSERT, UPDATE, DELETE
AS
BEGIN
DECLARE @auditOperationTypeLookupId int
DECLARE @newDataJson NVARCHAR(MAX)
DECLARE @updatedTimestamp DATETIMEOFFSET(3) = GETUTCDATE()
-- infer audit type, populate var
IF EXISTS (SELECT 1 FROM inserted)
BEGIN
IF EXISTS (SELECT 1 FROM deleted)
BEGIN
-- I am an update
SELECT @auditOperationTypeLookupId=2
END
ELSE
BEGIN
-- I am an insert
SELECT @auditOperationTypeLookupId=1
END
END
ELSE
BEGIN
-- i am a delete
SELECT @auditOperationTypeLookupId=3
END

DECLARE @pupilId int
DECLARE @lastModifiedBy_userId int
DECLARE db_cursor CURSOR FOR
SELECT i.id, i.lastModifiedBy_userId
FROM inserted i;
DECLARE db_deleted_cursor CURSOR FOR
SELECT d.id, d.lastModifiedBy_userId
FROM deleted d;

IF @auditOperationTypeLookupId IN (1,2)
BEGIN
OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @pupilId, @lastModifiedBy_userId
WHILE @@FETCH_STATUS = 0
BEGIN
-- grab the inserted/updated data
SELECT @newDataJson = (SELECT TOP 1 * FROM inserted i WHERE i.id = @pupilId FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER)
-- incorporate updatedAt trigger logic, to avoid duplicate audit entries
IF @auditOperationTypeLookupId = 2
BEGIN
UPDATE [mtc_admin].[pupil] SET updatedAt = @updatedTimestamp WHERE id = @pupilId
SET @newDataJson = JSON_MODIFY(@newDataJson, '$.updatedAt', CAST(@updatedTimestamp AS NVARCHAR))
END

-- do insert into pupil audit
INSERT INTO [mtc_admin].[pupilAudit]
(auditOperationTypeLookup_id, newData, pupil_id, operationBy_userId, sqlUserIdentifier)
VALUES (@auditOperationTypeLookupId, @newDataJson, @pupilId, @lastModifiedBy_userId, SUSER_SNAME())

FETCH NEXT FROM db_cursor INTO @pupilId, @lastModifiedBy_userId
END

CLOSE db_cursor
DEALLOCATE db_cursor
END

IF @auditOperationTypeLookupId = 3
BEGIN
OPEN db_deleted_cursor
FETCH NEXT FROM db_deleted_cursor INTO @pupilId, @lastModifiedBy_userId
WHILE @@FETCH_STATUS = 0
BEGIN
SELECT @newDataJson = (SELECT TOP 1 * FROM deleted d WHERE d.id = @pupilId FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER);
-- do insert into pupil audit
INSERT INTO [mtc_admin].[pupilAudit]
(auditOperationTypeLookup_id, newData, pupil_id, operationBy_userId, sqlUserIdentifier)
VALUES (@auditOperationTypeLookupId, @newDataJson, @pupilId, @lastModifiedBy_userId, SUSER_SNAME());

FETCH NEXT FROM db_deleted_cursor INTO @pupilId, @lastModifiedBy_userId
END

CLOSE db_deleted_cursor
DEALLOCATE db_deleted_cursor
END
END
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
CREATE OR ALTER TRIGGER [mtc_admin].[pupilInsertUpdateAuditTrigger] ON [mtc_admin].[pupil]
AFTER INSERT, UPDATE
AS
BEGIN
DECLARE @auditOperationTypeLookupId int
DECLARE @newDataJson NVARCHAR(MAX)
DECLARE @updatedTimestamp DATETIMEOFFSET(3) = GETUTCDATE()
-- infer audit type, populate var
IF EXISTS (SELECT 1 FROM inserted)
BEGIN
IF EXISTS (SELECT 1 FROM deleted)
BEGIN
-- I am an update
SELECT @auditOperationTypeLookupId=2
END
ELSE
BEGIN
-- I am an insert
SELECT @auditOperationTypeLookupId=1
END
END
ELSE
BEGIN
-- i am a delete
SELECT @auditOperationTypeLookupId=3
END

DECLARE @pupilId int
DECLARE @lastModifiedBy_userId int
DECLARE db_cursor CURSOR FOR
SELECT i.id, i.lastModifiedBy_userId
FROM inserted i

OPEN db_cursor
FETCH NEXT FROM db_cursor INTO @pupilId, @lastModifiedBy_userId
WHILE @@FETCH_STATUS = 0
BEGIN
-- incorporate updatedAt trigger logic, to avoid duplicate audit entries
IF @auditOperationTypeLookupId = 2
BEGIN
UPDATE [mtc_admin].[pupil] SET updatedAt = @updatedTimestamp WHERE id = @pupilId
END
SELECT @newDataJson = (SELECT TOP 1 * FROM inserted i WHERE i.id = @pupilId FOR JSON AUTO, WITHOUT_ARRAY_WRAPPER)
SET @newDataJson = JSON_MODIFY(@newDataJson, '$.updatedAt', CAST(@updatedTimestamp AS NVARCHAR))
-- do insert into pupil audit
INSERT INTO [mtc_admin].[pupilAudit]
(auditOperationTypeLookup_id, newData, pupil_id, operationBy_userId, sqlUserIdentifier)
VALUES (@auditOperationTypeLookupId, @newDataJson, @pupilId, @lastModifiedBy_userId, SUSER_SNAME())

FETCH NEXT FROM db_cursor INTO @pupilId, @lastModifiedBy_userId
END

CLOSE db_cursor
DEALLOCATE db_cursor
END
4 changes: 2 additions & 2 deletions docker-compose.yml
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
version: '3'
services:
sqldb:
image: "mcr.microsoft.com/mssql/server:2019-CU16-GDR1-ubuntu-20.04"
#image: "mcr.microsoft.com/azure-sql-edge"
#image: "mcr.microsoft.com/mssql/server:2022-latest"
image: "mcr.microsoft.com/azure-sql-edge"
container_name: mtc_mssql
ports:
- "1433:1433"
Expand Down

0 comments on commit fe31436

Please sign in to comment.