mirror of
https://github.com/hasura/graphql-engine.git
synced 2024-12-14 17:02:49 +03:00
32a316aef7
## Description ✍️ This PR introduces a new feature to enable/disable event triggers during logical replication of table data for PostgreSQL and MS-SQL data sources. We introduce a new field `trigger_on_replication` in the `*_create_event_trigger` metadata API. By default the event triggers will not fire for logical data replication. ## Changelog ✍️ __Component__ : server __Type__: feature __Product__: community-edition ### Short Changelog Add option to enable/disable event triggers on logically replicated tables ### Related Issues ✍ https://github.com/hasura/graphql-engine/issues/8814 https://hasurahq.atlassian.net/browse/GS-252 ### Solution and Design - By default, triggers do **not** fire when the session mode is `replica` in Postgres, so if the `triggerOnReplication` is set to `true` for an event trigger we run the query `ALTER TABLE #{tableTxt} ENABLE ALWAYS TRIGGER #{triggerNameTxt};` so that the trigger fires always irrespective of the `session_replication_role` - By default, triggers do fire in case of replication in MS-SQL, so if the `triggerOnReplication` is set to `false` for an event trigger we add a clause `NOT FOR REPLICATION` to the the SQL when the trigger is created/altered, which sets the `is_not_for_replication` for the trigger as `true` and it does not fire during logical replication. ### Steps to test and verify ✍ - Run hspec integration tests for HGE ## Server checklist ✍ ### Metadata ✍ Does this PR add a new Metadata feature? - ✅ Yes - Does `export_metadata`/`replace_metadata` supports the new metadata added? - ✅ PR-URL: https://github.com/hasura/graphql-engine-mono/pull/6953 Co-authored-by: Puru Gupta <32328846+purugupta99@users.noreply.github.com> Co-authored-by: Sean Park-Ross <94021366+seanparkross@users.noreply.github.com> GitOrigin-RevId: 92731328a2bbdcad2302c829f26f9acb33c36135
29 lines
732 B
Plaintext
29 lines
732 B
Plaintext
CREATE OR ALTER TRIGGER #{qualifiedTriggerName}
|
|
ON #{qualifiedTableName}
|
|
AFTER DELETE
|
|
#{replicationClause}
|
|
AS
|
|
BEGIN
|
|
DECLARE @json NVARCHAR(MAX)
|
|
SET @json = (
|
|
SELECT
|
|
#{deliveryColsSQLExpression}, NULL as [payload.data.new],
|
|
'#{operation}' as [payload.op],
|
|
'#{schemaName}' as [schema_name],
|
|
'#{tableName}' as [table_name],
|
|
'#{triggerNameText}' as [trigger_name]
|
|
FROM DELETED
|
|
FOR JSON PATH, INCLUDE_NULL_VALUES
|
|
)
|
|
|
|
insert into hdb_catalog.event_log (schema_name,table_name,trigger_name,payload)
|
|
select * from OPENJSON (@json)
|
|
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;
|