1. For supporting event triggers, we need to generate new events on a mutation,
whether the mutation is done through Hasura or not. This can be done via an
DML SQL triggers which are supported by the [MS-SQL triggers](https://docs.microsoft.com/en-us/sql/t-sql/statements/create-trigger-transact-sql?view=sql-server-ver15.).
* MS-SQL maintains two logical tables, namely, [`inserted` and `deleted`](https://docs.microsoft.com/en-us/sql/relational-databases/triggers/use-the-inserted-and-deleted-tables?view=sql-server-ver15).
**NOTE**: Since we use the primary keys to co-relate DELETED and INSERTED table,
no trigger will fire when the primary key is updated. To fix this problem, we
update the UPDATE Trigger Spec as following.
1. When PK is not updated, then we send both `data.new` and `data.old`
2. When PK is updated, there are two cases:
* The updated PK value is already present in the table, then this case is
similar to CASE 1, where a single row is being updated. In such cases
send both `data.new` and `data.old`
* The updated PK value is not present in the table, then the updated value
will be sent as `data.new` and `data.old` will be made NULL
Thus, the `UPDATE` trigger will now look like following:
```sql
CREATE TRIGGER hasuraAuthorsAfterUpdate
ON books
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
DELETED.name as [payload.data.old.name], DELETED.id as [payload.data.old.id], INSERTED.name as [payload.data.new.name], INSERTED.id as [payload.data.new.id],
'UPDATE' as [payload.op],
'dbo' as [schema_name],
'books' as [table_name],
'insert_test_books' as [trigger_name]
FROM DELETED
JOIN INSERTED
ON INSERTED.id = DELETED.id
where INSERTED.name != DELETED.name OR INSERTED.id != DELETED.id
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 (1 = 1)
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
NULL as [payload.data.old], INSERTED.name as [payload.data.new.name], INSERTED.id as [payload.data.new.id],
'UPDATE' as [payload.op],
'dbo' as [schema_name],
'books' as [table_name],
'insert_test_books' as [trigger_name]
FROM INSERTED
WHERE NOT EXISTS (SELECT * FROM DELETED WHERE INSERTED.id = DELETED.id )
FOR JSON PATH, INCLUDE_NULL_VALUES
)
insert into hdb_catalog.event_log (schema_name,table_name,trigger_name,payload)
schema, then the trigger should also be in the `dbo` schema. Ref: [MSSQL Docs](https://docs.microsoft.com/en-us/sql/t-sql/statements/create-trigger-transact-sql?redirectedfrom=MSDN&view=sql-server-ver15)
6. In postgres, the session variables and trace context were set in runtime
configurations, `hasura.user` and `hasura.tracecontext` respectively, it's
done by setting these values via `SET LOCAL \"hasura.user\"={\"x-hasura-user-id\":\"1\"}`.
In MS-SQL, the same can be done using [SESSION_CONTEXT](https://docs.microsoft.com/en-us/sql/t-sql/functions/session-context-transact-sql?view=sql-server-ver15).
which can be used to check if a value is valid JSON.
2. As we know, there can be multiple instances of hasura running on the same
source/database. So, we need to make sure that the multiple instances do not
fetch the same rows, otherwise the same events will be processed more than
once. To solve this problem, postgres uses the `FOR UPDATE SKIP LOCKED` which
when used in a `SELECT` query will skip over the rows that are locked by
other transactions **without waiting**.
MS-SQL has a similar feature, [READPAST and UPDLOCK](https://docs.microsoft.com/en-us/sql/t-sql/queries/hints-transact-sql-table?view=sql-server-ver15)
which is more or less like `FOR UPDATE SKIP LOCKED`. From the docs,
> READPAST is primarily used to reduce locking contention when implementing a
> work queue that uses a SQL Server table. A queue reader that uses READPAST
> skips past queue entries locked by other transactions to the next available
> queue entry, without having to wait until the other transactions release
> their locks.
> When specified in transactions operating at the SNAPSHOT isolation level,
> READPAST must be combined with other table hints that require locks, such