graphql-engine/server/src-rsr/mssql/mssql_update_trigger.sql.shakespeare
Naveen Naidu abb57e58c8 server/MSSQL: Event Delivery System (Incremental PR - 3)
</details>

PR-URL: https://github.com/hasura/graphql-engine-mono/pull/3392
Co-authored-by: Divi <32202683+imperfect-fourth@users.noreply.github.com>
GitOrigin-RevId: 9df6b0aa7d91f22571b72d3e467da23b916c9140
2022-04-21 07:20:34 +00:00

65 lines
2.3 KiB
Plaintext

CREATE OR ALTER TRIGGER #{qualifiedTriggerName}
ON #{qualifiedTableName}
AFTER UPDATE
AS
BEGIN
DECLARE @json_pk_not_updated NVARCHAR(MAX)
DECLARE @json_pk_updated NVARCHAR(MAX)
-- When primary key is not updated during a UPDATE transaction then construct both
-- 'data.old' and 'data.new'.
SET @json_pk_not_updated =
(SELECT
#{oldDeliveryColsSQLExp}, #{newDeliveryColsSQLExp},
'#{operation}' as [payload.op],
'#{schemaName}' as [schema_name],
'#{tableName}' as [table_name],
'#{triggerNameText}' as [trigger_name]
FROM DELETED
JOIN INSERTED
ON #{primaryKeyJoinExp}
#{listenColumnExp}
FOR JSON PATH
)
insert into hdb_catalog.event_log (schema_name,table_name,trigger_name,payload)
select * from OPENJSON (@json_pk_not_updated)
WITH(
schema_name NVARCHAR(MAX) '$.schema_name',
table_name NVARCHAR(MAX) '$.table_name',
trigger_name NVARCHAR(MAX) '$.trigger_name',
[payload] NVARCHAR(MAX) AS JSON
)
-- When primary key is updated during a UPDATE transaction then construct only 'data.new'
-- since according to the UPDATE Event trigger spec for MSSQL, the 'data.old' would be NULL
IF (#{isPrimaryKeyInListenColumnsExp})
BEGIN
SET @json_pk_updated =
-- The following SQL statement checks, if there are any rows in INSERTED
-- table whose primary key does not match to any rows present in DELETED
-- table. When such an situation occurs during a UPDATE transaction, then
-- this means that the primary key of the row was updated.
(SELECT
#{oldDeliveryColsSQLExpWhenPrimaryKeyUpdated}, #{newDeliveryColsSQLExpWhenPrimaryKeyUpdated},
'#{operation}' as [payload.op],
'#{schemaName}' as [schema_name],
'#{tableName}' as [table_name],
'#{triggerNameText}' as [trigger_name]
FROM INSERTED
WHERE NOT EXISTS (SELECT * FROM DELETED WHERE #{primaryKeyJoinExp})
FOR JSON PATH, INCLUDE_NULL_VALUES
)
insert into hdb_catalog.event_log (schema_name,table_name,trigger_name,payload)
select * from OPENJSON (@json_pk_updated)
WITH(
schema_name NVARCHAR(MAX) '$.schema_name',
table_name NVARCHAR(MAX) '$.table_name',
trigger_name NVARCHAR(MAX) '$.trigger_name',
[payload] NVARCHAR(MAX) AS JSON
)
END
END;