From 8fc13e075b1722dced93af19ccd56710fb226e13 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Tue, 19 Dec 2023 16:18:10 +0000 Subject: [PATCH 1/7] Support Instead of Trigger On Views Currently Postgres does not support Instead of Trigger On Views for DML queries. On running such a query on VIEW, query rewriting substitutes view with underlying base table. Added a hook for skipping the substitution for DML query on the VIEW. This change will add support for Instead of Triggers for DML queries when using Babelfish. Task: BABEL-2170/BABEL-4532/BABEL-4514 Signed-off-by: Deepakshi Mittal --- contrib/babelfishpg_tsql/src/hooks.c | 90 +++ test/JDBC/expected/BABEL-2170-vu-cleanup.out | 39 ++ test/JDBC/expected/BABEL-2170-vu-prepare.out | 105 ++++ test/JDBC/expected/BABEL-2170-vu-verify.out | 578 ++++++++++++++++++ .../input/triggers/BABEL-2170-vu-cleanup.sql | 39 ++ .../input/triggers/BABEL-2170-vu-prepare.sql | 93 +++ .../input/triggers/BABEL-2170-vu-verify.sql | 321 ++++++++++ test/JDBC/upgrade/latest/schedule | 1 + 8 files changed, 1266 insertions(+) create mode 100644 test/JDBC/expected/BABEL-2170-vu-cleanup.out create mode 100644 test/JDBC/expected/BABEL-2170-vu-prepare.out create mode 100644 test/JDBC/expected/BABEL-2170-vu-verify.out create mode 100644 test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql create mode 100644 test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql create mode 100644 test/JDBC/input/triggers/BABEL-2170-vu-verify.sql diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index ef53f3cfa8..6069eb2219 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -159,6 +159,8 @@ static void pltsql_ExecutorStart(QueryDesc *queryDesc, int eflags); static void pltsql_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction, uint64 count, bool execute_once); static void pltsql_ExecutorFinish(QueryDesc *queryDesc); static void pltsql_ExecutorEnd(QueryDesc *queryDesc); +static bool pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event); +static bool pltsql_bbfCheckRecursionInTrigger(ResultRelInfo *resultRelInfo); static bool plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo); static bool bbf_check_rowcount_hook(int es_processed); @@ -210,6 +212,8 @@ static ExecutorFinish_hook_type prev_ExecutorFinish = NULL; static ExecutorEnd_hook_type prev_ExecutorEnd = NULL; static GetNewObjectId_hook_type prev_GetNewObjectId_hook = NULL; static inherit_view_constraints_from_table_hook_type prev_inherit_view_constraints_from_table = NULL; +static bbfViewHasInsteadofTrigger_hook_type prev_bbfViewHasInsteadofTrigger_hook = NULL; +static bbfCheckRecursionInTrigger_hook_type prev_bbfCheckRecursionInTrigger_hook = NULL; static detect_numeric_overflow_hook_type prev_detect_numeric_overflow_hook = NULL; static match_pltsql_func_call_hook_type prev_match_pltsql_func_call_hook = NULL; static insert_pltsql_function_defaults_hook_type prev_insert_pltsql_function_defaults_hook = NULL; @@ -325,6 +329,12 @@ InstallExtendedHooks(void) inherit_view_constraints_from_table_hook = preserve_view_constraints_from_base_table; TriggerRecuresiveCheck_hook = plsql_TriggerRecursiveCheck; + prev_bbfViewHasInsteadofTrigger_hook = bbfViewHasInsteadofTrigger_hook; + bbfViewHasInsteadofTrigger_hook = pltsql_bbfViewHasInsteadofTrigger; + + prev_bbfCheckRecursionInTrigger_hook = bbfCheckRecursionInTrigger_hook; + bbfCheckRecursionInTrigger_hook = pltsql_bbfCheckRecursionInTrigger; + prev_detect_numeric_overflow_hook = detect_numeric_overflow_hook; detect_numeric_overflow_hook = pltsql_detect_numeric_overflow; @@ -440,6 +450,8 @@ UninstallExtendedHooks(void) ExecutorEnd_hook = prev_ExecutorEnd; GetNewObjectId_hook = prev_GetNewObjectId_hook; inherit_view_constraints_from_table_hook = prev_inherit_view_constraints_from_table; + bbfViewHasInsteadofTrigger_hook = prev_bbfViewHasInsteadofTrigger_hook; + bbfCheckRecursionInTrigger_hook = prev_bbfCheckRecursionInTrigger_hook; detect_numeric_overflow_hook = prev_detect_numeric_overflow_hook; match_pltsql_func_call_hook = prev_match_pltsql_func_call_hook; insert_pltsql_function_defaults_hook = prev_insert_pltsql_function_defaults_hook; @@ -719,6 +731,84 @@ plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo) return false; } +/** + * Hook function to skip rewriting VIEW with base table if the VIEW has an instead of trigger + * Checks if view have an INSTEAD OF trigger at statement level + * If it does, we don't want to treat it as auto-updatable. + * Reference - src/backend/rewrite/rewriteHandler.c view_has_instead_trigger +*/ +static bool +pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) +{ + TriggerDesc *trigDesc = view->trigdesc; + if (trigDesc && triggerOids) + { + int i; + for (i = 0; i < trigDesc->numtriggers; i++) + { + Trigger *trigger = &trigDesc->triggers[i]; + Oid current_tgoid = trigger->tgoid; + Oid prev_tgoid = InvalidOid; + prev_tgoid = lfirst_oid(list_tail(triggerOids)); + if (prev_tgoid == current_tgoid) + { + return false; /** Direct recursive trigger case*/ + } + else if (list_member_oid(triggerOids, current_tgoid)) + { + /** Indirect recursive trigger case*/ + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); + } + } + } + + switch (event) + { + case CMD_INSERT: + if(trigDesc && trigDesc->trig_insert_instead_statement) + return true; + break; + case CMD_UPDATE: + if (trigDesc && trigDesc->trig_update_instead_statement) + return true; + break; + case CMD_DELETE: + if (trigDesc && trigDesc->trig_delete_instead_statement) + return true; + break; + default: + elog(ERROR, "unrecognized CmdType: %d", (int) event); + break; + } + return false; +} + +static bool pltsql_bbfCheckRecursionInTrigger(ResultRelInfo *relinfo) +{ + if (triggerOids && relinfo->ri_TrigDesc) + { + TriggerDesc *trigDesc; + int i; + trigDesc = relinfo->ri_TrigDesc; + for (i = 0; i < trigDesc->numtriggers; i++) + { + Trigger *trigger = &trigDesc->triggers[i]; + Oid current_tgoid = trigger->tgoid; + Oid prev_tgoid = lfirst_oid(list_tail(triggerOids)); + if (prev_tgoid != current_tgoid && list_member_oid(triggerOids, current_tgoid)) + { + /** Recursive trigger case*/ + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); + } + } + } + return true; +} + /* * Wrapper function that calls the initilization function. * Calls the pre function call hook on the procname diff --git a/test/JDBC/expected/BABEL-2170-vu-cleanup.out b/test/JDBC/expected/BABEL-2170-vu-cleanup.out new file mode 100644 index 0000000000..9fd916b30f --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-cleanup.out @@ -0,0 +1,39 @@ +-- clean all objects in first database +USE db1_BABEL2170; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_delete; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_bulkinsert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_bulkinsert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_2; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_txn; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_txn; +GO + +USE MASTER; +GO + +DROP DATABASE IF EXISTS db1_BABEL2170; +GO diff --git a/test/JDBC/expected/BABEL-2170-vu-prepare.out b/test/JDBC/expected/BABEL-2170-vu-prepare.out new file mode 100644 index 0000000000..dc6cd1a8cc --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-prepare.out @@ -0,0 +1,105 @@ +-- We will create two databases db1_BABEL2170, db2_BABEL2170 +CREATE DATABASE db1_BABEL2170; +GO + +USE db1_BABEL2170; +GO + +CREATE TABLE babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE VIEW babel_2170_vu_employees_view_bulkinsert AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'b%'; +GO + +CREATE VIEW babel_2170_vu_employees_view_2 AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE SCHEMA schema_2170; +GO + +CREATE TABLE schema_2170.babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO schema_2170.babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO schema_2170.babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW schema_2170.babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM schema_2170.babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE TABLE babel_2170_vu_employees_txn +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees_txn VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees_txn VALUES(2, 'angel', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW babel_2170_vu_employees_view_txn AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees_txn +WHERE EmployeeName LIKE 'a%'; +GO diff --git a/test/JDBC/expected/BABEL-2170-vu-verify.out b/test/JDBC/expected/BABEL-2170-vu-verify.out new file mode 100644 index 0000000000..94e3ee9a16 --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-verify.out @@ -0,0 +1,578 @@ +USE db1_BABEL2170; +GO + +-- Instead of Insert Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' +END +GO + +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street', '3000'); +GO +~~START~~ +varchar +Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees; +GO +~~START~~ +int +2 +~~END~~ + + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees_view; +GO +~~START~~ +int +2 +~~END~~ + + +-- Instead of Update Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID,EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID = 2 ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +BEGIN TRANSACTION + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 2~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID IN (1, 2) ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +-- Instead of Delete Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_delete ON babel_2170_vu_employees_view +INSTEAD OF DELETE +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked' +END +GO + +BEGIN TRANSACTION + DELETE FROM babel_2170_vu_employees_view WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked +~~END~~ + +~~ROW COUNT: 2~~ + + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees_view; +GO +~~START~~ +int +2 +~~END~~ + + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees; +GO +~~START~~ +int +2 +~~END~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +--- Tests multiple insert queries and check if inserted table can be accessed and trigger is working fine. +CREATE TRIGGER babel_2170_vu_employees_view_iot_bulkinsert ON babel_2170_vu_employees_view_bulkinsert +INSTEAD OF INSERT +AS + SELECT * FROM INSERTED; +GO + +BEGIN TRANSACTION +DECLARE @i int = 1 + WHILE @i <= 3 + BEGIN + INSERT INTO babel_2170_vu_employees_view_bulkinsert VALUES(@i, 'bob', '1st Street', '1000'); + SET @i = @i + 1 + END +COMMIT TRANSACTION +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#bob#!#1st Street#!#1000.00 +~~END~~ + +~~ROW COUNT: 1~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +2#!#bob#!#1st Street#!#1000.00 +~~END~~ + +~~ROW COUNT: 1~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +3#!#bob#!#1st Street#!#1000.00 +~~END~~ + +~~ROW COUNT: 1~~ + + +-- Same trigger name on different View created on Same table in same schema +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view_2 +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view2_iot_update Invoked' +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: trigger "babel_2170_vu_employees_view_iot_update" already exists in the database)~~ + + +-- Same trigger name on a Table in same schema +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees__table_iot_update Invoked' +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: trigger "babel_2170_vu_employees_view_iot_update" already exists in the database)~~ + + + +-- Test Instead of Update trigger in same db but cross schema +-- Cleanup default dbo schema IO Update trigger +DROP TRIGGER IF EXISTS [dbo].[babel_2170_vu_employees_view_iot_update]; +GO + +CREATE TRIGGER [schema_2170].[babel_2170_vu_employees_view_iot_update] ON [schema_2170].[babel_2170_vu_employees_view] +INSTEAD OF UPDATE +AS + SELECT 'Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' +GO + +CREATE TRIGGER [babel_2170_vu_employees_view_iot_update] ON [babel_2170_vu_employees_view] +INSTEAD OF UPDATE +AS + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' +GO + +UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM [schema_2170].[babel_2170_vu_employees_view] ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +UPDATE [dbo].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM [dbo].[babel_2170_vu_employees_view] ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +-- drop dbo schema trigger and test that schema_2170.update trigger is not dropped +DROP TRIGGER IF EXISTS [dbo].[babel_2170_vu_employees_view_iot_update]; +GO + +UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +varchar +Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +-- schema_2170 object cleanup +DROP TRIGGER IF EXISTS [schema_2170].babel_2170_vu_employees_view_iot_update; +GO + +DROP VIEW IF EXISTS [schema_2170].babel_2170_vu_employees_view; +GO + +DROP TABLE IF EXISTS [schema_2170].babel_2170_vu_employees; +GO + +DROP SCHEMA IF EXISTS schema_2170; +GO + +-- Test Transaction Commit and Rollback inside Instead of triggers +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn +INSTEAD OF UPDATE +AS + BEGIN + BEGIN TRAN; + INSERT INTO babel_2170_vu_employees_view_txn VALUES(3, 'adam', '1st Street', '3000'); + COMMIT tran; + END +GO + +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn +INSTEAD OF UPDATE +AS + BEGIN + BEGIN TRAN; + INSERT INTO babel_2170_vu_employees_view_txn VALUES(3, 'adam', '1st Street', '3000'); + ROLLBACK tran; + END +GO + +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~ROW COUNT: 1~~ + +~~ERROR (Code: 3609)~~ + +~~ERROR (Message: The transaction ended in the trigger. The batch has been aborted.)~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_insert ON babel_2170_vu_employees_view_txn INSTEAD OF INSERT AS +BEGIN TRAN; +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +COMMIT; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +SELECT * FROM inserted; +GO + +BEGIN TRAN; +GO +INSERT INTO babel_2170_vu_employees_view_txn VALUES(4, 'ana', '1st Street', '4000'); +GO +~~ROW COUNT: 1~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2001.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +4#!#ana#!#1st Street#!#4000.00 +~~END~~ + +~~ROW COUNT: 1~~ + +COMMIT; +GO + +BEGIN TRAN +GO +INSERT INTO babel_2170_vu_employees_view_txn VALUES(4, 'ana', '1st Street', '4000'); +GO +~~ROW COUNT: 1~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2002.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +4#!#ana#!#1st Street#!#4000.00 +~~END~~ + +~~ROW COUNT: 1~~ + +IF (@@trancount > 0) ROLLBACK; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2001.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_insert; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn INSTEAD OF UPDATE AS +SAVE TRAN sp1; +SAVE TRAN sp2; +DELETE FROM babel_2170_vu_employees_view_txn where EmployeeID =2; +ROLLBACK TRAN sp1; +GO + +BEGIN TRAN +GO +SELECT @@trancount; +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + +IF (@@trancount > 0) ROLLBACK; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2001.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_delete ON babel_2170_vu_employees_view_txn INSTEAD OF DELETE AS +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +INSERT INTO babel_2170_vu_employees_view_txn VALUES(5, 'ash', '1st Street', '5000'); +SELECT * FROM deleted; +GO + +DELETE FROM babel_2170_vu_employees_view_txn where EmployeeID =1; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2001.00 +3#!#adam#!#1st Street#!#3000.00 +~~END~~ + +~~ROW COUNT: 1~~ + +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2001.00 +3#!#adam#!#1st Street#!#3000.00 +5#!#ash#!#1st Street#!#5000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_delete; +GO + +-- test multi-db mode +SELECT set_config('role', 'jdbc_user', false); +GO +~~START~~ +text +jdbc_user +~~END~~ + + +SELECT set_config('babelfishpg_tsql.migration_mode', 'multi-db', false); +GO +~~START~~ +text +multi-db +~~END~~ + + +CREATE DATABASE db2_BABEL2170; +GO + +USE db2_BABEL2170; +GO + +CREATE TABLE babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +-- create same name Instead of Insert trigger in second db to test Cross db behavior +CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' +END +GO + +-- should fire IOT trigger of second db +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street db2_BABEL2170', '3000'); +GO +~~START~~ +varchar +Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#2000.00 +~~END~~ + + +-- clean all objects in second database +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees; +GO + +USE MASTER; +GO + +DROP DATABASE IF EXISTS db2_BABEL2170; +GO diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql b/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql new file mode 100644 index 0000000000..0f656cfde4 --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql @@ -0,0 +1,39 @@ +-- clean all objects in first database +USE db1_BABEL2170; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_delete; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_bulkinsert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_bulkinsert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_2; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_txn; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_txn; +GO + +USE MASTER; +GO + +DROP DATABASE IF EXISTS db1_BABEL2170; +GO \ No newline at end of file diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql b/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql new file mode 100644 index 0000000000..cb31bf570b --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql @@ -0,0 +1,93 @@ +-- We will create two databases db1_BABEL2170, db2_BABEL2170 +CREATE DATABASE db1_BABEL2170; +GO + +USE db1_BABEL2170; +GO + +CREATE TABLE babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO + +CREATE VIEW babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE VIEW babel_2170_vu_employees_view_bulkinsert AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'b%'; +GO + +CREATE VIEW babel_2170_vu_employees_view_2 AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE SCHEMA schema_2170; +GO + +CREATE TABLE schema_2170.babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO schema_2170.babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO schema_2170.babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO + +CREATE VIEW schema_2170.babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM schema_2170.babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE TABLE babel_2170_vu_employees_txn +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees_txn VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees_txn VALUES(2, 'angel', '1st Street', '2000'); +GO + +CREATE VIEW babel_2170_vu_employees_view_txn AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees_txn +WHERE EmployeeName LIKE 'a%'; +GO \ No newline at end of file diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql new file mode 100644 index 0000000000..c7802b6db5 --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql @@ -0,0 +1,321 @@ +USE db1_BABEL2170; +GO + +-- Instead of Insert Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' +END +GO + +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street', '3000'); +GO + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees; +GO + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees_view; +GO + +-- Instead of Update Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID,EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID = 2 ORDER BY EmployeeID; +GO + +BEGIN TRANSACTION + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID IN (1, 2) ORDER BY EmployeeID; +GO + +-- Instead of Delete Trigger on View +CREATE TRIGGER babel_2170_vu_employees_view_iot_delete ON babel_2170_vu_employees_view +INSTEAD OF DELETE +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked' +END +GO + +BEGIN TRANSACTION + DELETE FROM babel_2170_vu_employees_view WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees_view; +GO + +SELECT COUNT(EmployeeID) FROM babel_2170_vu_employees; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO + +--- Tests multiple insert queries and check if inserted table can be accessed and trigger is working fine. +CREATE TRIGGER babel_2170_vu_employees_view_iot_bulkinsert ON babel_2170_vu_employees_view_bulkinsert +INSTEAD OF INSERT +AS + SELECT * FROM INSERTED; +GO + +BEGIN TRANSACTION +DECLARE @i int = 1 + WHILE @i <= 3 + BEGIN + INSERT INTO babel_2170_vu_employees_view_bulkinsert VALUES(@i, 'bob', '1st Street', '1000'); + SET @i = @i + 1 + END +COMMIT TRANSACTION +GO + +-- Same trigger name on different View created on Same table in same schema +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view_2 +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view2_iot_update Invoked' +END +GO + +-- Same trigger name on a Table in same schema +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees__table_iot_update Invoked' +END +GO + +-- Test Instead of Update trigger in same db but cross schema + +-- Cleanup default dbo schema IO Update trigger +DROP TRIGGER IF EXISTS [dbo].[babel_2170_vu_employees_view_iot_update]; +GO + +CREATE TRIGGER [schema_2170].[babel_2170_vu_employees_view_iot_update] ON [schema_2170].[babel_2170_vu_employees_view] +INSTEAD OF UPDATE +AS + SELECT 'Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' +GO + +CREATE TRIGGER [babel_2170_vu_employees_view_iot_update] ON [babel_2170_vu_employees_view] +INSTEAD OF UPDATE +AS + SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' +GO + +UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM [schema_2170].[babel_2170_vu_employees_view] ORDER BY EmployeeID; +GO + +UPDATE [dbo].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM [dbo].[babel_2170_vu_employees_view] ORDER BY EmployeeID; +GO + +-- drop dbo schema trigger and test that schema_2170.update trigger is not dropped +DROP TRIGGER IF EXISTS [dbo].[babel_2170_vu_employees_view_iot_update]; +GO + +UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +-- schema_2170 object cleanup +DROP TRIGGER IF EXISTS [schema_2170].babel_2170_vu_employees_view_iot_update; +GO + +DROP VIEW IF EXISTS [schema_2170].babel_2170_vu_employees_view; +GO + +DROP TABLE IF EXISTS [schema_2170].babel_2170_vu_employees; +GO + +DROP SCHEMA IF EXISTS schema_2170; +GO + +-- Test Transaction Commit and Rollback inside Instead of triggers +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn +INSTEAD OF UPDATE +AS + BEGIN + BEGIN TRAN; + INSERT INTO babel_2170_vu_employees_view_txn VALUES(3, 'adam', '1st Street', '3000'); + COMMIT tran; + END +GO + +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn +INSTEAD OF UPDATE +AS + BEGIN + BEGIN TRAN; + INSERT INTO babel_2170_vu_employees_view_txn VALUES(3, 'adam', '1st Street', '3000'); + ROLLBACK tran; + END +GO + +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_insert ON babel_2170_vu_employees_view_txn INSTEAD OF INSERT AS +BEGIN TRAN; +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +COMMIT; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +SELECT * FROM inserted; +GO + +BEGIN TRAN; +GO +INSERT INTO babel_2170_vu_employees_view_txn VALUES(4, 'ana', '1st Street', '4000'); +GO +COMMIT; +GO + +BEGIN TRAN +GO +INSERT INTO babel_2170_vu_employees_view_txn VALUES(4, 'ana', '1st Street', '4000'); +GO +IF (@@trancount > 0) ROLLBACK; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_insert; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_update ON babel_2170_vu_employees_view_txn INSTEAD OF UPDATE AS +SAVE TRAN sp1; +SAVE TRAN sp2; +DELETE FROM babel_2170_vu_employees_view_txn where EmployeeID =2; +ROLLBACK TRAN sp1; +GO + +BEGIN TRAN +GO +SELECT @@trancount; +UPDATE babel_2170_vu_employees_view_txn SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +IF (@@trancount > 0) ROLLBACK; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_update; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_txn_delete ON babel_2170_vu_employees_view_txn INSTEAD OF DELETE AS +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +INSERT INTO babel_2170_vu_employees_view_txn VALUES(5, 'ash', '1st Street', '5000'); +SELECT * FROM deleted; +GO + +DELETE FROM babel_2170_vu_employees_view_txn where EmployeeID =1; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view_txn ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_delete; +GO + +-- test multi-db mode +SELECT set_config('role', 'jdbc_user', false); +GO + +SELECT set_config('babelfishpg_tsql.migration_mode', 'multi-db', false); +GO + +CREATE DATABASE db2_BABEL2170; +GO + +USE db2_BABEL2170; +GO + +CREATE TABLE babel_2170_vu_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000'); +GO + +CREATE VIEW babel_2170_vu_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees +WHERE EmployeeName LIKE 'a%'; +GO + +-- create same name Instead of Insert trigger in second db to test Cross db behavior +CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' +END +GO + +-- should fire IOT trigger of second db +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street db2_BABEL2170', '3000'); +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO + +-- clean all objects in second database +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees; +GO + +USE MASTER; +GO + +DROP DATABASE IF EXISTS db2_BABEL2170; +GO \ No newline at end of file diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 3c416c6cc5..791f282a0f 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -38,6 +38,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 From d7a527bc240621d87cabd99fc051141cc6223c68 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Wed, 20 Dec 2023 19:08:11 +0000 Subject: [PATCH 2/7] Added test cases from previously failing scripts Task: BABEL-2170 Signed-off-by: Deepakshi Mittal --- test/JDBC/expected/BABEL-2170-vu-verify.out | 183 +++++++++++++++++- .../input/triggers/BABEL-2170-vu-verify.sql | 141 +++++++++++++- 2 files changed, 322 insertions(+), 2 deletions(-) diff --git a/test/JDBC/expected/BABEL-2170-vu-verify.out b/test/JDBC/expected/BABEL-2170-vu-verify.out index 94e3ee9a16..d66fbd4142 100644 --- a/test/JDBC/expected/BABEL-2170-vu-verify.out +++ b/test/JDBC/expected/BABEL-2170-vu-verify.out @@ -55,10 +55,11 @@ Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked ~~ROW COUNT: 1~~ -SELECT EmployeeID,EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID = 2 ORDER BY EmployeeID; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees ORDER BY EmployeeID; GO ~~START~~ int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 2#!#angel#!#1st Street#!#2000.00 ~~END~~ @@ -483,6 +484,186 @@ int#!#varchar#!#varchar#!#numeric DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_delete; GO +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + +-- Transition table join test +CREATE TRIGGER babel_2170_vu_employees_view_transition ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE v set MonthSalary = 999 FROM inserted AS i + JOIN babel_2170_vu_employees_view AS v ON v.EmployeeID = i.EmployeeID +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = 5 WHERE EmployeeID = 2; +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#999.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_transition; +GO + +-- Recursive Trigger test Direct Recursion Trigger calling itself trigger 1 -> trigger 1 +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#amber#!#1st Street#!#1000.00 +2#!#angel#!#1st Street#!#1099.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + + + +-- Recursive Trigger test Indirect Recursion trigger 1 -> trigger 2 -> trigger 1 +CREATE TABLE babel_2170_vu_employees_rec +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees_rec VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees_rec VALUES(2, 'angel', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW babel_2170_vu_employees_view_rec AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees_rec +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_rec ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view_rec SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +END +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_rec2 ON babel_2170_vu_employees_view_rec +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32))~~ + + +UPDATE babel_2170_vu_employees_view_rec SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32))~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_rec; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_rec2; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_rec; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_rec; +GO + +-- Test when trigger on one view inserts into another view on the same table +CREATE TABLE babel_2170_vu_employees_t2 +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +CREATE VIEW babel_2170_vu_employees_t2_v1 AS SELECT * FROM babel_2170_vu_employees_t2 +GO + +CREATE VIEW babel_2170_vu_employees_t2_v2 AS SELECT * FROM babel_2170_vu_employees_t2 +GO + +CREATE TRIGGER babel_2170_vu_employees_iot_t2_v2 ON babel_2170_vu_employees_t2_v1 +INSTEAD OF INSERT +AS +INSERT INTO babel_2170_vu_employees_t2_v2 SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary+20 FROM INSERTED +GO + +INSERT INTO babel_2170_vu_employees_t2_v1 VALUES(5, 'ashley', '1st Street', '5000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_t2_v2 ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +5#!#ashley#!#1st Street#!#5020.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_iot_t2_v2; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_t2_v1; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_t2_v2; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_t2; +GO + -- test multi-db mode SELECT set_config('role', 'jdbc_user', false); GO diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql index c7802b6db5..7089e4d4ce 100644 --- a/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql +++ b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql @@ -31,7 +31,7 @@ GO UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; GO -SELECT EmployeeID,EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees WHERE EmployeeID = 2 ORDER BY EmployeeID; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees ORDER BY EmployeeID; GO BEGIN TRANSACTION @@ -253,6 +253,145 @@ GO DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_txn_delete; GO +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + +-- Transition table join test +CREATE TRIGGER babel_2170_vu_employees_view_transition ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE v set MonthSalary = 999 FROM inserted AS i + JOIN babel_2170_vu_employees_view AS v ON v.EmployeeID = i.EmployeeID +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = 5 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_transition; +GO + +-- Recursive Trigger test Direct Recursion Trigger calling itself trigger 1 -> trigger 1 +CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update; +GO + + +-- Recursive Trigger test Indirect Recursion trigger 1 -> trigger 2 -> trigger 1 + +CREATE TABLE babel_2170_vu_employees_rec +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_vu_employees_rec VALUES(1, 'amber', '1st Street', '1000'); +INSERT INTO babel_2170_vu_employees_rec VALUES(2, 'angel', '1st Street', '2000'); +GO + +CREATE VIEW babel_2170_vu_employees_view_rec AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_vu_employees_rec +WHERE EmployeeName LIKE 'a%'; +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_rec ON babel_2170_vu_employees_view +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view_rec SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +END +GO + +CREATE TRIGGER babel_2170_vu_employees_view_iot_rec2 ON babel_2170_vu_employees_view_rec +INSTEAD OF UPDATE +AS +BEGIN + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +END +GO + +UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +GO + +UPDATE babel_2170_vu_employees_view_rec SET MonthSalary = MonthSalary +100 WHERE EmployeeID = 2; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_rec; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_rec2; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_view_rec; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_rec; +GO + +-- Test when trigger on one view inserts into another view on the same table +CREATE TABLE babel_2170_vu_employees_t2 +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +CREATE VIEW babel_2170_vu_employees_t2_v1 AS SELECT * FROM babel_2170_vu_employees_t2 +GO + +CREATE VIEW babel_2170_vu_employees_t2_v2 AS SELECT * FROM babel_2170_vu_employees_t2 +GO + +CREATE TRIGGER babel_2170_vu_employees_iot_t2_v2 ON babel_2170_vu_employees_t2_v1 +INSTEAD OF INSERT +AS +INSERT INTO babel_2170_vu_employees_t2_v2 SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary+20 FROM INSERTED +GO + +INSERT INTO babel_2170_vu_employees_t2_v1 VALUES(5, 'ashley', '1st Street', '5000'); +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_t2_v2 ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_vu_employees_iot_t2_v2; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_t2_v1; +GO + +DROP VIEW IF EXISTS babel_2170_vu_employees_t2_v2; +GO + +DROP TABLE IF EXISTS babel_2170_vu_employees_t2; +GO + -- test multi-db mode SELECT set_config('role', 'jdbc_user', false); GO From 4576ce24001861f399316fe1bf4d7b7cdcaaf2eb Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Wed, 27 Dec 2023 21:10:15 +0000 Subject: [PATCH 3/7] Merged and removed extra hook and renamed oid variable Task: BABEL-2170 Signed-off-by: Deepakshi Mittal --- contrib/babelfishpg_tsql/src/hooks.c | 36 +++------------------------- 1 file changed, 3 insertions(+), 33 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 6069eb2219..19b9c3709c 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -160,7 +160,6 @@ static void pltsql_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction, ui static void pltsql_ExecutorFinish(QueryDesc *queryDesc); static void pltsql_ExecutorEnd(QueryDesc *queryDesc); static bool pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event); -static bool pltsql_bbfCheckRecursionInTrigger(ResultRelInfo *resultRelInfo); static bool plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo); static bool bbf_check_rowcount_hook(int es_processed); @@ -213,7 +212,6 @@ static ExecutorEnd_hook_type prev_ExecutorEnd = NULL; static GetNewObjectId_hook_type prev_GetNewObjectId_hook = NULL; static inherit_view_constraints_from_table_hook_type prev_inherit_view_constraints_from_table = NULL; static bbfViewHasInsteadofTrigger_hook_type prev_bbfViewHasInsteadofTrigger_hook = NULL; -static bbfCheckRecursionInTrigger_hook_type prev_bbfCheckRecursionInTrigger_hook = NULL; static detect_numeric_overflow_hook_type prev_detect_numeric_overflow_hook = NULL; static match_pltsql_func_call_hook_type prev_match_pltsql_func_call_hook = NULL; static insert_pltsql_function_defaults_hook_type prev_insert_pltsql_function_defaults_hook = NULL; @@ -332,9 +330,6 @@ InstallExtendedHooks(void) prev_bbfViewHasInsteadofTrigger_hook = bbfViewHasInsteadofTrigger_hook; bbfViewHasInsteadofTrigger_hook = pltsql_bbfViewHasInsteadofTrigger; - prev_bbfCheckRecursionInTrigger_hook = bbfCheckRecursionInTrigger_hook; - bbfCheckRecursionInTrigger_hook = pltsql_bbfCheckRecursionInTrigger; - prev_detect_numeric_overflow_hook = detect_numeric_overflow_hook; detect_numeric_overflow_hook = pltsql_detect_numeric_overflow; @@ -451,7 +446,6 @@ UninstallExtendedHooks(void) GetNewObjectId_hook = prev_GetNewObjectId_hook; inherit_view_constraints_from_table_hook = prev_inherit_view_constraints_from_table; bbfViewHasInsteadofTrigger_hook = prev_bbfViewHasInsteadofTrigger_hook; - bbfCheckRecursionInTrigger_hook = prev_bbfCheckRecursionInTrigger_hook; detect_numeric_overflow_hook = prev_detect_numeric_overflow_hook; match_pltsql_func_call_hook = prev_match_pltsql_func_call_hook; insert_pltsql_function_defaults_hook = prev_insert_pltsql_function_defaults_hook; @@ -741,7 +735,7 @@ static bool pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) { TriggerDesc *trigDesc = view->trigdesc; - if (trigDesc && triggerOids) + if (trigDesc && triggerInvocationSequence) { int i; for (i = 0; i < trigDesc->numtriggers; i++) @@ -749,12 +743,12 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) Trigger *trigger = &trigDesc->triggers[i]; Oid current_tgoid = trigger->tgoid; Oid prev_tgoid = InvalidOid; - prev_tgoid = lfirst_oid(list_tail(triggerOids)); + prev_tgoid = lfirst_oid(list_tail(triggerInvocationSequence)); if (prev_tgoid == current_tgoid) { return false; /** Direct recursive trigger case*/ } - else if (list_member_oid(triggerOids, current_tgoid)) + else if (list_member_oid(triggerInvocationSequence, current_tgoid)) { /** Indirect recursive trigger case*/ ereport(ERROR, @@ -785,30 +779,6 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) return false; } -static bool pltsql_bbfCheckRecursionInTrigger(ResultRelInfo *relinfo) -{ - if (triggerOids && relinfo->ri_TrigDesc) - { - TriggerDesc *trigDesc; - int i; - trigDesc = relinfo->ri_TrigDesc; - for (i = 0; i < trigDesc->numtriggers; i++) - { - Trigger *trigger = &trigDesc->triggers[i]; - Oid current_tgoid = trigger->tgoid; - Oid prev_tgoid = lfirst_oid(list_tail(triggerOids)); - if (prev_tgoid != current_tgoid && list_member_oid(triggerOids, current_tgoid)) - { - /** Recursive trigger case*/ - ereport(ERROR, - (errcode(ERRCODE_SYNTAX_ERROR), - errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); - } - } - } - return true; -} - /* * Wrapper function that calls the initilization function. * Calls the pre function call hook on the procname From ebc25506c26ecd6b8605f7e2734e8635324ffaa7 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Thu, 28 Dec 2023 16:39:09 +0000 Subject: [PATCH 4/7] Added test to all upgrade schedule files Task: BABEL-2170 Signed-off-by: Deepakshi Mittal --- contrib/babelfishpg_tsql/src/hooks.c | 7 ++++--- test/JDBC/upgrade/13_4/schedule | 1 + test/JDBC/upgrade/13_5/schedule | 1 + test/JDBC/upgrade/13_6/schedule | 1 + test/JDBC/upgrade/13_7/schedule | 1 + test/JDBC/upgrade/13_8/schedule | 1 + test/JDBC/upgrade/13_9/schedule | 1 + test/JDBC/upgrade/14_10/schedule | 1 + test/JDBC/upgrade/14_11/schedule | 1 + test/JDBC/upgrade/14_3/schedule | 1 + test/JDBC/upgrade/14_5/schedule | 1 + test/JDBC/upgrade/14_6/schedule | 1 + test/JDBC/upgrade/14_7/schedule | 1 + test/JDBC/upgrade/14_8/schedule | 1 + test/JDBC/upgrade/14_9/schedule | 1 + test/JDBC/upgrade/15_1/schedule | 1 + test/JDBC/upgrade/15_2/schedule | 1 + test/JDBC/upgrade/15_3/schedule | 1 + test/JDBC/upgrade/15_4/schedule | 1 + test/JDBC/upgrade/15_5/schedule | 1 + 20 files changed, 23 insertions(+), 3 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 19b9c3709c..d488f75faa 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -728,7 +728,8 @@ plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo) /** * Hook function to skip rewriting VIEW with base table if the VIEW has an instead of trigger * Checks if view have an INSTEAD OF trigger at statement level - * If it does, we don't want to treat it as auto-updatable. + * If it does, we don't want to treat it as auto-updatable. + * This function also does error checking for recursive triggers * Reference - src/backend/rewrite/rewriteHandler.c view_has_instead_trigger */ static bool @@ -746,11 +747,11 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) prev_tgoid = lfirst_oid(list_tail(triggerInvocationSequence)); if (prev_tgoid == current_tgoid) { - return false; /** Direct recursive trigger case*/ + return false; /** A trigger called recursively by itself*/ } else if (list_member_oid(triggerInvocationSequence, current_tgoid)) { - /** Indirect recursive trigger case*/ + /** A trigger called recursively by another trigger */ ereport(ERROR, (errcode(ERRCODE_SYNTAX_ERROR), errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); diff --git a/test/JDBC/upgrade/13_4/schedule b/test/JDBC/upgrade/13_4/schedule index e2751eb998..b470ca1269 100644 --- a/test/JDBC/upgrade/13_4/schedule +++ b/test/JDBC/upgrade/13_4/schedule @@ -27,6 +27,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/13_5/schedule b/test/JDBC/upgrade/13_5/schedule index f0437f31cb..f7606a5713 100644 --- a/test/JDBC/upgrade/13_5/schedule +++ b/test/JDBC/upgrade/13_5/schedule @@ -29,6 +29,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/13_6/schedule b/test/JDBC/upgrade/13_6/schedule index 218f5fb464..39962773a7 100644 --- a/test/JDBC/upgrade/13_6/schedule +++ b/test/JDBC/upgrade/13_6/schedule @@ -35,6 +35,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/13_7/schedule b/test/JDBC/upgrade/13_7/schedule index 40b1663a8c..0a4769f50c 100644 --- a/test/JDBC/upgrade/13_7/schedule +++ b/test/JDBC/upgrade/13_7/schedule @@ -33,6 +33,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/13_8/schedule b/test/JDBC/upgrade/13_8/schedule index 40b1663a8c..0a4769f50c 100644 --- a/test/JDBC/upgrade/13_8/schedule +++ b/test/JDBC/upgrade/13_8/schedule @@ -33,6 +33,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/13_9/schedule b/test/JDBC/upgrade/13_9/schedule index 6c629ce3af..c3d9547697 100644 --- a/test/JDBC/upgrade/13_9/schedule +++ b/test/JDBC/upgrade/13_9/schedule @@ -33,6 +33,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_10/schedule b/test/JDBC/upgrade/14_10/schedule index c733353ced..0a7f54be4b 100644 --- a/test/JDBC/upgrade/14_10/schedule +++ b/test/JDBC/upgrade/14_10/schedule @@ -117,6 +117,7 @@ BABEL-1062 BABEL-1243 BABEL-1493 BABEL-1963 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_11/schedule b/test/JDBC/upgrade/14_11/schedule index 205cf51a8c..02bdd76710 100644 --- a/test/JDBC/upgrade/14_11/schedule +++ b/test/JDBC/upgrade/14_11/schedule @@ -117,6 +117,7 @@ BABEL-1062 BABEL-1243 BABEL-1493 BABEL-1963 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_3/schedule b/test/JDBC/upgrade/14_3/schedule index 1d07c0e4c2..0de06f5d9c 100644 --- a/test/JDBC/upgrade/14_3/schedule +++ b/test/JDBC/upgrade/14_3/schedule @@ -35,6 +35,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_5/schedule b/test/JDBC/upgrade/14_5/schedule index 579f32fc54..7fcf121ebc 100644 --- a/test/JDBC/upgrade/14_5/schedule +++ b/test/JDBC/upgrade/14_5/schedule @@ -34,6 +34,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index 1808ee0bfc..ea3d54e7c7 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -35,6 +35,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_7/schedule b/test/JDBC/upgrade/14_7/schedule index 51bb3e81ab..5cf016fc9f 100644 --- a/test/JDBC/upgrade/14_7/schedule +++ b/test/JDBC/upgrade/14_7/schedule @@ -37,6 +37,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_8/schedule b/test/JDBC/upgrade/14_8/schedule index 14dd7a2b23..15dda02b24 100644 --- a/test/JDBC/upgrade/14_8/schedule +++ b/test/JDBC/upgrade/14_8/schedule @@ -37,6 +37,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/14_9/schedule b/test/JDBC/upgrade/14_9/schedule index bf32d16a6d..e42d9a3cc7 100644 --- a/test/JDBC/upgrade/14_9/schedule +++ b/test/JDBC/upgrade/14_9/schedule @@ -117,6 +117,7 @@ BABEL-1062 BABEL-1243 BABEL-1493 BABEL-1963 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/15_1/schedule b/test/JDBC/upgrade/15_1/schedule index 91603e7452..75dc656d4d 100644 --- a/test/JDBC/upgrade/15_1/schedule +++ b/test/JDBC/upgrade/15_1/schedule @@ -35,6 +35,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/15_2/schedule b/test/JDBC/upgrade/15_2/schedule index 34fb513cc1..b5ca7e8e35 100644 --- a/test/JDBC/upgrade/15_2/schedule +++ b/test/JDBC/upgrade/15_2/schedule @@ -37,6 +37,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/15_3/schedule b/test/JDBC/upgrade/15_3/schedule index 9512a97260..5b1460743f 100644 --- a/test/JDBC/upgrade/15_3/schedule +++ b/test/JDBC/upgrade/15_3/schedule @@ -37,6 +37,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/15_4/schedule b/test/JDBC/upgrade/15_4/schedule index 40976596c9..66c21ad2b3 100644 --- a/test/JDBC/upgrade/15_4/schedule +++ b/test/JDBC/upgrade/15_4/schedule @@ -37,6 +37,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 diff --git a/test/JDBC/upgrade/15_5/schedule b/test/JDBC/upgrade/15_5/schedule index b13a7608b4..d9fad93b11 100644 --- a/test/JDBC/upgrade/15_5/schedule +++ b/test/JDBC/upgrade/15_5/schedule @@ -38,6 +38,7 @@ BABEL-1963 BABEL-1994-CHAR BABEL-1994-VARCHAR BABEL-2086 +BABEL-2170 BABEL-2203 BABEL-2208 BABEL-2257 From 4d891abfc8cae2dca36aa93fa63101ada0c530da Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Thu, 28 Dec 2023 22:55:48 +0000 Subject: [PATCH 5/7] Added condition for recursive trigger reaching limit 32 Fixed indentation Task: BABEL-2170 Signed-off-by: Deepakshi Mittal --- contrib/babelfishpg_tsql/src/hooks.c | 26 ++++++++++++++++---------- 1 file changed, 16 insertions(+), 10 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index d488f75faa..ed8674f3ad 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -731,7 +731,7 @@ plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo) * If it does, we don't want to treat it as auto-updatable. * This function also does error checking for recursive triggers * Reference - src/backend/rewrite/rewriteHandler.c view_has_instead_trigger -*/ + */ static bool pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) { @@ -745,24 +745,30 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) Oid current_tgoid = trigger->tgoid; Oid prev_tgoid = InvalidOid; prev_tgoid = lfirst_oid(list_tail(triggerInvocationSequence)); - if (prev_tgoid == current_tgoid) + if (list_length(triggerInvocationSequence) > 32) + { + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); + } + else if (prev_tgoid == current_tgoid) { return false; /** A trigger called recursively by itself*/ } else if (list_member_oid(triggerInvocationSequence, current_tgoid)) - { - /** A trigger called recursively by another trigger */ - ereport(ERROR, - (errcode(ERRCODE_SYNTAX_ERROR), - errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); - } + { + /** A trigger called recursively by another trigger */ + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); + } } } switch (event) { case CMD_INSERT: - if(trigDesc && trigDesc->trig_insert_instead_statement) + if (trigDesc && trigDesc->trig_insert_instead_statement) return true; break; case CMD_UPDATE: @@ -774,7 +780,7 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) return true; break; default: - elog(ERROR, "unrecognized CmdType: %d", (int) event); + elog(ERROR, "unrecognized CmdType: %d", (int)event); break; } return false; From f1054956d52c1180fc12fb288530e8641960ca11 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Fri, 29 Dec 2023 19:15:41 +0000 Subject: [PATCH 6/7] Addressed Code review suggestion for muti-db test cases Ignored file containing multi-db test from jdbc schedule. Removed set config change for multi-db Added basic test cases seperately to verify IO Triggers. Task:BABEL-2170 Signed-off-by: Deepakshi Mittal --- test/JDBC/expected/BABEL-2170-vu-cleanup.out | 4 +- test/JDBC/expected/BABEL-2170-vu-prepare.out | 5 +- test/JDBC/expected/BABEL-2170-vu-verify.out | 61 +++------ test/JDBC/expected/BABEL-2170.out | 126 ++++++++++++++++++ .../input/triggers/BABEL-2170-vu-cleanup.sql | 4 +- .../input/triggers/BABEL-2170-vu-prepare.sql | 5 +- .../input/triggers/BABEL-2170-vu-verify.sql | 35 ++--- test/JDBC/input/triggers/BABEL-2170.sql | 83 ++++++++++++ test/JDBC/jdbc_schedule | 3 + 9 files changed, 256 insertions(+), 70 deletions(-) create mode 100644 test/JDBC/expected/BABEL-2170.out create mode 100644 test/JDBC/input/triggers/BABEL-2170.sql diff --git a/test/JDBC/expected/BABEL-2170-vu-cleanup.out b/test/JDBC/expected/BABEL-2170-vu-cleanup.out index 9fd916b30f..c8b0f134a6 100644 --- a/test/JDBC/expected/BABEL-2170-vu-cleanup.out +++ b/test/JDBC/expected/BABEL-2170-vu-cleanup.out @@ -1,5 +1,5 @@ -- clean all objects in first database -USE db1_BABEL2170; +USE babel_2170_db1; GO DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; @@ -35,5 +35,5 @@ GO USE MASTER; GO -DROP DATABASE IF EXISTS db1_BABEL2170; +DROP DATABASE IF EXISTS babel_2170_db1; GO diff --git a/test/JDBC/expected/BABEL-2170-vu-prepare.out b/test/JDBC/expected/BABEL-2170-vu-prepare.out index dc6cd1a8cc..614d1733a0 100644 --- a/test/JDBC/expected/BABEL-2170-vu-prepare.out +++ b/test/JDBC/expected/BABEL-2170-vu-prepare.out @@ -1,8 +1,7 @@ --- We will create two databases db1_BABEL2170, db2_BABEL2170 -CREATE DATABASE db1_BABEL2170; +CREATE DATABASE babel_2170_db1; GO -USE db1_BABEL2170; +USE babel_2170_db1; GO CREATE TABLE babel_2170_vu_employees diff --git a/test/JDBC/expected/BABEL-2170-vu-verify.out b/test/JDBC/expected/BABEL-2170-vu-verify.out index d66fbd4142..31a9cd8891 100644 --- a/test/JDBC/expected/BABEL-2170-vu-verify.out +++ b/test/JDBC/expected/BABEL-2170-vu-verify.out @@ -1,4 +1,4 @@ -USE db1_BABEL2170; +USE babel_2170_db1; GO -- Instead of Insert Trigger on View @@ -6,7 +6,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_insert Invoked' END GO @@ -14,7 +14,7 @@ INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street', '3000') GO ~~START~~ varchar -Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked +Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_insert Invoked ~~END~~ ~~ROW COUNT: 1~~ @@ -41,7 +41,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF UPDATE AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO @@ -49,7 +49,7 @@ UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE Emplo GO ~~START~~ varchar -Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked ~~END~~ ~~ROW COUNT: 1~~ @@ -70,7 +70,7 @@ COMMIT TRANSACTION; GO ~~START~~ varchar -Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked ~~END~~ ~~ROW COUNT: 2~~ @@ -90,7 +90,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_delete ON babel_2170_vu_employee INSTEAD OF DELETE AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_delete Invoked' END GO @@ -100,7 +100,7 @@ COMMIT TRANSACTION; GO ~~START~~ varchar -Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked +Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_delete Invoked ~~END~~ ~~ROW COUNT: 2~~ @@ -174,7 +174,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view2_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO ~~ERROR (Code: 33557097)~~ @@ -187,7 +187,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees__table_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO ~~ERROR (Code: 33557097)~~ @@ -204,20 +204,20 @@ GO CREATE TRIGGER [schema_2170].[babel_2170_vu_employees_view_iot_update] ON [schema_2170].[babel_2170_vu_employees_view] INSTEAD OF UPDATE AS - SELECT 'Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' GO CREATE TRIGGER [babel_2170_vu_employees_view_iot_update] ON [babel_2170_vu_employees_view] INSTEAD OF UPDATE AS - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' GO UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; GO ~~START~~ varchar -Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked +Trigger babel_2170_db1.schema_2170.babel_2170_vu_employees_view_iot_update Invoked ~~END~~ ~~ROW COUNT: 1~~ @@ -236,7 +236,7 @@ UPDATE [dbo].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHE GO ~~START~~ varchar -Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked +Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked ~~END~~ ~~ROW COUNT: 1~~ @@ -259,7 +259,7 @@ UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalar GO ~~START~~ varchar -Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked +Trigger babel_2170_db1.schema_2170.babel_2170_vu_employees_view_iot_update Invoked ~~END~~ ~~ROW COUNT: 1~~ @@ -664,27 +664,10 @@ GO DROP TABLE IF EXISTS babel_2170_vu_employees_t2; GO --- test multi-db mode -SELECT set_config('role', 'jdbc_user', false); +CREATE DATABASE babel_2170_db2; GO -~~START~~ -text -jdbc_user -~~END~~ - -SELECT set_config('babelfishpg_tsql.migration_mode', 'multi-db', false); -GO -~~START~~ -text -multi-db -~~END~~ - - -CREATE DATABASE db2_BABEL2170; -GO - -USE db2_BABEL2170; +USE babel_2170_db2; GO CREATE TABLE babel_2170_vu_employees @@ -718,22 +701,22 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' + SELECT 'Trigger babel_2170_db2.dbo.babel_2170_vu_employees_view_iot_insert Invoked' END GO -- should fire IOT trigger of second db -INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street db2_BABEL2170', '3000'); +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street babel_2170_db2', '3000'); GO ~~START~~ varchar -Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked +Trigger babel_2170_db2.dbo.babel_2170_vu_employees_view_iot_insert Invoked ~~END~~ ~~ROW COUNT: 1~~ -SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; GO ~~START~~ int#!#varchar#!#varchar#!#numeric @@ -755,5 +738,5 @@ GO USE MASTER; GO -DROP DATABASE IF EXISTS db2_BABEL2170; +DROP DATABASE IF EXISTS babel_2170_db2; GO diff --git a/test/JDBC/expected/BABEL-2170.out b/test/JDBC/expected/BABEL-2170.out new file mode 100644 index 0000000000..592a2798e2 --- /dev/null +++ b/test/JDBC/expected/BABEL-2170.out @@ -0,0 +1,126 @@ +CREATE TABLE babel_2170_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_employees VALUES(1, 'ash', '1st Street', '1000'); +INSERT INTO babel_2170_employees VALUES(2, 'bob', '1st Street', '2000'); +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE VIEW babel_2170_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_employees; +GO + +-- Instead of Insert Trigger on View +CREATE TRIGGER babel_2170_employees_view_iot_insert ON babel_2170_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_insert Invoked' +END +GO + +INSERT INTO babel_2170_employees_view VALUES(3, 'john', '1st Street', '3000'); +GO +~~START~~ +varchar +Trigger babel_2170_employees_view_iot_insert Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#ash#!#1st Street#!#1000.00 +2#!#bob#!#1st Street#!#2000.00 +~~END~~ + + +-- Instead of Update Trigger on View +CREATE TRIGGER babel_2170_employees_view_iot_update ON babel_2170_employees_view +INSTEAD OF UPDATE +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_update Invoked' +END +GO + +UPDATE babel_2170_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO +~~START~~ +varchar +Trigger babel_2170_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#ash#!#1st Street#!#1000.00 +2#!#bob#!#1st Street#!#2000.00 +~~END~~ + + + +-- Instead of Delete Trigger on View +CREATE TRIGGER babel_2170_employees_view_iot_delete ON babel_2170_employees_view +INSTEAD OF DELETE +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_delete Invoked' +END +GO + +BEGIN TRANSACTION + DELETE FROM babel_2170_employees_view WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO +~~START~~ +varchar +Trigger babel_2170_employees_view_iot_delete Invoked +~~END~~ + +~~ROW COUNT: 2~~ + + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO +~~START~~ +int#!#varchar#!#varchar#!#numeric +1#!#ash#!#1st Street#!#1000.00 +2#!#bob#!#1st Street#!#2000.00 +~~END~~ + + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_insert; +GO + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_update; +GO + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_delete; +GO + +DROP VIEW IF EXISTS babel_2170_employees_view; +GO + +DROP TABLE IF EXISTS babel_2170_employees; +GO diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql b/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql index 0f656cfde4..0357eda1df 100644 --- a/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql +++ b/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql @@ -1,5 +1,5 @@ -- clean all objects in first database -USE db1_BABEL2170; +USE babel_2170_db1; GO DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert; @@ -35,5 +35,5 @@ GO USE MASTER; GO -DROP DATABASE IF EXISTS db1_BABEL2170; +DROP DATABASE IF EXISTS babel_2170_db1; GO \ No newline at end of file diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql b/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql index cb31bf570b..a816837fe0 100644 --- a/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql +++ b/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql @@ -1,8 +1,7 @@ --- We will create two databases db1_BABEL2170, db2_BABEL2170 -CREATE DATABASE db1_BABEL2170; +CREATE DATABASE babel_2170_db1; GO -USE db1_BABEL2170; +USE babel_2170_db1; GO CREATE TABLE babel_2170_vu_employees diff --git a/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql index 7089e4d4ce..261e0374c9 100644 --- a/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql +++ b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql @@ -1,4 +1,4 @@ -USE db1_BABEL2170; +USE babel_2170_db1; GO -- Instead of Insert Trigger on View @@ -6,7 +6,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_insert Invoked' END GO @@ -24,7 +24,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF UPDATE AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO @@ -47,7 +47,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_delete ON babel_2170_vu_employee INSTEAD OF DELETE AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_delete Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_delete Invoked' END GO @@ -87,7 +87,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view2_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO @@ -96,7 +96,7 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_update ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees__table_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' END GO @@ -109,13 +109,13 @@ GO CREATE TRIGGER [schema_2170].[babel_2170_vu_employees_view_iot_update] ON [schema_2170].[babel_2170_vu_employees_view] INSTEAD OF UPDATE AS - SELECT 'Trigger db1_BABEL2170.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.schema_2170.babel_2170_vu_employees_view_iot_update Invoked' GO CREATE TRIGGER [babel_2170_vu_employees_view_iot_update] ON [babel_2170_vu_employees_view] INSTEAD OF UPDATE AS - SELECT 'Trigger db1_BABEL2170.dbo.babel_2170_vu_employees_view_iot_update Invoked' + SELECT 'Trigger babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked' GO UPDATE [schema_2170].[babel_2170_vu_employees_view] SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; @@ -392,17 +392,10 @@ GO DROP TABLE IF EXISTS babel_2170_vu_employees_t2; GO --- test multi-db mode -SELECT set_config('role', 'jdbc_user', false); +CREATE DATABASE babel_2170_db2; GO -SELECT set_config('babelfishpg_tsql.migration_mode', 'multi-db', false); -GO - -CREATE DATABASE db2_BABEL2170; -GO - -USE db2_BABEL2170; +USE babel_2170_db2; GO CREATE TABLE babel_2170_vu_employees @@ -432,15 +425,15 @@ CREATE TRIGGER babel_2170_vu_employees_view_iot_insert ON babel_2170_vu_employee INSTEAD OF INSERT AS BEGIN - SELECT 'Trigger db2_BABEL2170.dbo.babel_2170_vu_employees_view_iot_insert Invoked' + SELECT 'Trigger babel_2170_db2.dbo.babel_2170_vu_employees_view_iot_insert Invoked' END GO -- should fire IOT trigger of second db -INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street db2_BABEL2170', '3000'); +INSERT INTO babel_2170_vu_employees_view VALUES(3, 'adam', '1st Street babel_2170_db2', '3000'); GO -SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_vu_employees_view ORDER BY EmployeeID; GO -- clean all objects in second database @@ -456,5 +449,5 @@ GO USE MASTER; GO -DROP DATABASE IF EXISTS db2_BABEL2170; +DROP DATABASE IF EXISTS babel_2170_db2; GO \ No newline at end of file diff --git a/test/JDBC/input/triggers/BABEL-2170.sql b/test/JDBC/input/triggers/BABEL-2170.sql new file mode 100644 index 0000000000..bce08bc776 --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170.sql @@ -0,0 +1,83 @@ +CREATE TABLE babel_2170_employees +( + EmployeeID int NOT NULL, + EmployeeName VARCHAR(50), + EmployeeAddress VARCHAR(50), + MonthSalary NUMERIC(10, 2) +) +GO + +INSERT INTO babel_2170_employees VALUES(1, 'ash', '1st Street', '1000'); +INSERT INTO babel_2170_employees VALUES(2, 'bob', '1st Street', '2000'); +GO + +CREATE VIEW babel_2170_employees_view AS +SELECT EmployeeID, + EmployeeName, + EmployeeAddress, + MonthSalary +FROM babel_2170_employees; +GO + +-- Instead of Insert Trigger on View +CREATE TRIGGER babel_2170_employees_view_iot_insert ON babel_2170_employees_view +INSTEAD OF INSERT +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_insert Invoked' +END +GO + +INSERT INTO babel_2170_employees_view VALUES(3, 'john', '1st Street', '3000'); +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO + +-- Instead of Update Trigger on View +CREATE TRIGGER babel_2170_employees_view_iot_update ON babel_2170_employees_view +INSTEAD OF UPDATE +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_update Invoked' +END +GO + +UPDATE babel_2170_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID = 2; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO + +-- Instead of Delete Trigger on View + +CREATE TRIGGER babel_2170_employees_view_iot_delete ON babel_2170_employees_view +INSTEAD OF DELETE +AS +BEGIN + SELECT 'Trigger babel_2170_employees_view_iot_delete Invoked' +END +GO + +BEGIN TRANSACTION + DELETE FROM babel_2170_employees_view WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO + +SELECT EmployeeID, EmployeeName, EmployeeAddress, MonthSalary FROM babel_2170_employees_view ORDER BY EmployeeID; +GO + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_insert; +GO + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_update; +GO + +DROP TRIGGER IF EXISTS babel_2170_employees_view_iot_delete; +GO + +DROP VIEW IF EXISTS babel_2170_employees_view; +GO + +DROP TABLE IF EXISTS babel_2170_employees; +GO \ No newline at end of file diff --git a/test/JDBC/jdbc_schedule b/test/JDBC/jdbc_schedule index 0be0c2ac3f..fae21d9c71 100644 --- a/test/JDBC/jdbc_schedule +++ b/test/JDBC/jdbc_schedule @@ -128,6 +128,9 @@ ignore#!#case_insensitive_collation-before-13-5-vu-cleanup ignore#!#jira-BABEL-3504-upgrade-vu-prepare ignore#!#jira-BABEL-3504-upgrade-vu-verify ignore#!#jira-BABEL-3504-upgrade-vu-cleanup +ignore#!#BABEL-2170-vu-prepare +ignore#!#BABEL-2170-vu-verify +ignore#!#BABEL-2170-vu-cleanup ignore#!#AVG-Aggregate-Dep-before-15-2-or-14-7-vu-prepare ignore#!#AVG-Aggregate-Dep-before-15-2-or-14-7-vu-verify From d3fc730f65323707f686eae69c3f545c0f97c448 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal Date: Tue, 2 Jan 2024 16:14:05 +0000 Subject: [PATCH 7/7] Merged if condition into one, defined TRIGGER_MAX_NEST_LEVEL Task: BABEL-2170 Signed-off-by: Deepakshi Mittal --- contrib/babelfishpg_tsql/src/hooks.c | 18 ++++++------------ contrib/babelfishpg_tsql/src/pltsql.h | 2 ++ 2 files changed, 8 insertions(+), 12 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index ed8674f3ad..600f4018a0 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -745,22 +745,16 @@ pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event) Oid current_tgoid = trigger->tgoid; Oid prev_tgoid = InvalidOid; prev_tgoid = lfirst_oid(list_tail(triggerInvocationSequence)); - if (list_length(triggerInvocationSequence) > 32) + if (prev_tgoid == current_tgoid) { - ereport(ERROR, - (errcode(ERRCODE_SYNTAX_ERROR), - errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); - } - else if (prev_tgoid == current_tgoid) - { - return false; /** A trigger called recursively by itself*/ + return false; /** Loop trigger call by itself*/ } - else if (list_member_oid(triggerInvocationSequence, current_tgoid)) + else if (list_length(triggerInvocationSequence) > TRIGGER_MAX_NEST_LEVEL || list_member_oid(triggerInvocationSequence, current_tgoid)) { - /** A trigger called recursively by another trigger */ + /** Loop trigger call by another trigger */ ereport(ERROR, - (errcode(ERRCODE_SYNTAX_ERROR), - errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit 32)"))); + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit %d)", TRIGGER_MAX_NEST_LEVEL))); } } } diff --git a/contrib/babelfishpg_tsql/src/pltsql.h b/contrib/babelfishpg_tsql/src/pltsql.h index 12c83d807e..2b1dc9c39a 100644 --- a/contrib/babelfishpg_tsql/src/pltsql.h +++ b/contrib/babelfishpg_tsql/src/pltsql.h @@ -62,6 +62,8 @@ /* Max number of Args allowed for Prepared stmts. */ #define PREPARE_STMT_MAX_ARGS 2100 +#define TRIGGER_MAX_NEST_LEVEL 32 /* Maximum allowed trigger nesting level*/ + /* * Compiler's namespace item types */