From 22731240bb7fd658dee176a894d5cf658080afd0 Mon Sep 17 00:00:00 2001 From: Deepakshi Mittal <78574784+deepakshi-mittal@users.noreply.github.com> Date: Wed, 3 Jan 2024 09:44:12 -0800 Subject: [PATCH 1/5] Support Instead of Trigger On Views (#2158) 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 | 61 ++ contrib/babelfishpg_tsql/src/pltsql.h | 2 + test/JDBC/expected/BABEL-2170-vu-cleanup.out | 39 + test/JDBC/expected/BABEL-2170-vu-prepare.out | 104 +++ test/JDBC/expected/BABEL-2170-vu-verify.out | 742 ++++++++++++++++++ test/JDBC/expected/BABEL-2170.out | 126 +++ .../input/triggers/BABEL-2170-vu-cleanup.sql | 39 + .../input/triggers/BABEL-2170-vu-prepare.sql | 92 +++ .../input/triggers/BABEL-2170-vu-verify.sql | 453 +++++++++++ test/JDBC/input/triggers/BABEL-2170.sql | 83 ++ test/JDBC/jdbc_schedule | 3 + 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 + test/JDBC/upgrade/latest/schedule | 1 + 31 files changed, 1764 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/expected/BABEL-2170.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 create mode 100644 test/JDBC/input/triggers/BABEL-2170.sql diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index ef53f3cfa8..600f4018a0 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -159,6 +159,7 @@ 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 plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo); static bool bbf_check_rowcount_hook(int es_processed); @@ -210,6 +211,7 @@ 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 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 +327,9 @@ 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_detect_numeric_overflow_hook = detect_numeric_overflow_hook; detect_numeric_overflow_hook = pltsql_detect_numeric_overflow; @@ -440,6 +445,7 @@ 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; 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 +725,61 @@ 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. + * 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) +{ + TriggerDesc *trigDesc = view->trigdesc; + if (trigDesc && triggerInvocationSequence) + { + 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(triggerInvocationSequence)); + if (prev_tgoid == current_tgoid) + { + return false; /** Loop trigger call by itself*/ + } + else if (list_length(triggerInvocationSequence) > TRIGGER_MAX_NEST_LEVEL || list_member_oid(triggerInvocationSequence, current_tgoid)) + { + /** Loop trigger call by another trigger */ + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit %d)", TRIGGER_MAX_NEST_LEVEL))); + } + } + } + + 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; +} + /* * Wrapper function that calls the initilization function. * Calls the pre function call hook on the procname 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 */ 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..c8b0f134a6 --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-cleanup.out @@ -0,0 +1,39 @@ +-- clean all objects in first database +USE babel_2170_db1; +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 babel_2170_db1; +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..614d1733a0 --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-prepare.out @@ -0,0 +1,104 @@ +CREATE DATABASE babel_2170_db1; +GO + +USE babel_2170_db1; +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..31a9cd8891 --- /dev/null +++ b/test/JDBC/expected/BABEL-2170-vu-verify.out @@ -0,0 +1,742 @@ +USE babel_2170_db1; +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 babel_2170_db1.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 babel_2170_db1.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 babel_2170_db1.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 babel_2170_db1.dbo.babel_2170_vu_employees_view_iot_update Invoked +~~END~~ + +~~ROW COUNT: 1~~ + + +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~~ + + +BEGIN TRANSACTION + UPDATE babel_2170_vu_employees_view SET MonthSalary = MonthSalary +1 WHERE EmployeeID IN (1, 2); +COMMIT TRANSACTION; +GO +~~START~~ +varchar +Trigger babel_2170_db1.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 babel_2170_db1.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 babel_2170_db1.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 babel_2170_db1.dbo.babel_2170_vu_employees_view_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 babel_2170_db1.dbo.babel_2170_vu_employees_view_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 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 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 babel_2170_db1.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 babel_2170_db1.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 babel_2170_db1.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 + +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 + +CREATE DATABASE babel_2170_db2; +GO + +USE babel_2170_db2; +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 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 babel_2170_db2', '3000'); +GO +~~START~~ +varchar +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; +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 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 new file mode 100644 index 0000000000..0357eda1df --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-cleanup.sql @@ -0,0 +1,39 @@ +-- clean all objects in first database +USE babel_2170_db1; +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 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 new file mode 100644 index 0000000000..a816837fe0 --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-prepare.sql @@ -0,0 +1,92 @@ +CREATE DATABASE babel_2170_db1; +GO + +USE babel_2170_db1; +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..261e0374c9 --- /dev/null +++ b/test/JDBC/input/triggers/BABEL-2170-vu-verify.sql @@ -0,0 +1,453 @@ +USE babel_2170_db1; +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 babel_2170_db1.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 babel_2170_db1.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 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 babel_2170_db1.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 babel_2170_db1.dbo.babel_2170_vu_employees_view_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 babel_2170_db1.dbo.babel_2170_vu_employees_view_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 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 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 + +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 + +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 + +CREATE DATABASE babel_2170_db2; +GO + +USE babel_2170_db2; +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 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 babel_2170_db2', '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 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 3c8f484869..8378df8b20 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 diff --git a/test/JDBC/upgrade/13_4/schedule b/test/JDBC/upgrade/13_4/schedule index 36d316f644..08c93ed9b5 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 e2ad92c143..aecee68d0b 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 aab2d61bc4..a17b9cf75f 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 08da73e6ca..cd0dfc594a 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 08da73e6ca..cd0dfc594a 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 bf25b07764..d639ba80d8 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 b3bf4a4165..daed233ad7 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 4db541349c..0ad4e9a9ca 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 a8a1de44bf..37bb96953e 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 69137c0d45..48b101e9f9 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 02b15a48f7..f6a6dde260 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 3c52af02ea..d9697243fc 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 6855828f71..f577b1dbed 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 9ee93de458..d6d51fe8f7 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 2768a8f562..0d596d6f21 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 0d73a0f77c..9a92667c45 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 72076b8c63..5475e807c4 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 04317518ea..c9017f7842 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 560251bd87..761943860d 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 diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 446c8d3348..77982f513a 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 dfe9a38ba2f496e9329b90eb64d59d9d9b3c4cfe Mon Sep 17 00:00:00 2001 From: Rob Verschoor <91290800+robverschoor@users.noreply.github.com> Date: Wed, 3 Jan 2024 23:24:19 +0100 Subject: [PATCH 2/5] Support floating-point notation without exponent (#2197) T-SQL supports floating-point without specifying an exponent, or specifying the exponent only as '+' or '-'. This defaults the exponent to 0. Some examples: 2.1E, -.2e+, -2.e- . This fix adds support by rewriting the exponent in ANTLR by appending a 0 in these cases. In addition, adding entry/exitEveryRule listeners in tsqlMutator for debugging infrastucture: these floating-points cases may occur also as parameters in stored proc calls meaning we have to handle them in tsqlMutator (as well as in tsqlBuilder where this debugging infrastructure is already present). Task: BABEL-4108 Signed-off-by: Rob Verschoor rcv@amazon.com --- contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 | 2 +- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 149 +++++++- .../expected/float_exponent-vu-cleanup.out | 14 + .../expected/float_exponent-vu-prepare.out | 15 + .../expected/float_exponent-vu-verify.out | 356 ++++++++++++++++++ test/JDBC/input/float_exponent-vu-cleanup.sql | 14 + test/JDBC/input/float_exponent-vu-prepare.sql | 15 + test/JDBC/input/float_exponent-vu-verify.sql | 161 ++++++++ test/JDBC/upgrade/latest/schedule | 1 + 9 files changed, 712 insertions(+), 15 deletions(-) create mode 100644 test/JDBC/expected/float_exponent-vu-cleanup.out create mode 100644 test/JDBC/expected/float_exponent-vu-prepare.out create mode 100644 test/JDBC/expected/float_exponent-vu-verify.out create mode 100644 test/JDBC/input/float_exponent-vu-cleanup.sql create mode 100644 test/JDBC/input/float_exponent-vu-prepare.sql create mode 100644 test/JDBC/input/float_exponent-vu-verify.sql diff --git a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 index de0d5b4c2b..266d3a9d34 100644 --- a/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 +++ b/contrib/babelfishpg_tsql/antlr/TSqlLexer.g4 @@ -1137,7 +1137,7 @@ DECIMAL: DEC_DIGIT+; ID: ( [_#] | LETTER) ( [_#$@0-9] | LETTER)*; BINARY: '0' [Xx] ( HEX_DIGIT | '\\' [\r]? [\n] )*; FLOAT: DEC_DOT_DEC; -REAL: (DECIMAL | DEC_DOT_DEC) ([Ee] ([+-]? DEC_DIGIT+)?); +REAL: (DECIMAL | DEC_DOT_DEC) ([Ee] ([+-]? DEC_DIGIT*)?); MONEY: CURRENCY_SYMBOL [ ]* ('+'|'-')? (DECIMAL | DEC_DOT_DEC); diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index d7bc3237af..93767966ca 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -185,6 +185,7 @@ static bool in_execute_body_batch_parameter = false; static const std::string fragment_SELECT_prefix = "SELECT "; // fragment prefix for expressions static const std::string fragment_EXEC_prefix = "EXEC "; // fragment prefix for execute_body_batch static PLtsql_stmt *makeChangeDbOwnerStatement(TSqlParser::Alter_authorizationContext *ctx); +static void handleFloatWithoutExponent(TSqlParser::ConstantContext *ctx); /* * Structure / Utility function for general purpose of query string modification @@ -2010,6 +2011,7 @@ class tsqlBuilder : public tsqlCommonMutator clear_rewritten_query_fragment(); } + // NB: similar code is in tsqlMutator void exitChar_string(TSqlParser::Char_stringContext *ctx) override { std::string str = getFullText(ctx); @@ -2121,6 +2123,13 @@ class tsqlBuilder : public tsqlCommonMutator // TO-DO } + // NB: this is copied in tsqlMutator + void exitConstant(TSqlParser::ConstantContext *ctx) override + { + // Check for floating-point number without exponent + handleFloatWithoutExponent(ctx); + } + ////////////////////////////////////////////////////////////////////////////// // Special handling of non-statement context ////////////////////////////////////////////////////////////////////////////// @@ -2419,18 +2428,19 @@ class tsqlBuilder : public tsqlCommonMutator class tsqlMutator : public TSqlParserBaseListener { -public: - MyInputStream &stream; +public: + const std::vector &ruleNames; + MyInputStream &stream; bool in_procedure_parameter = false; bool in_procedure_parameter_id = false; std::vector double_quota_places; - explicit tsqlMutator(MyInputStream &s) - : stream(s) + explicit tsqlMutator(const std::vector &rules, MyInputStream &s) + : ruleNames(rules), stream(s) { } - + public: void enterFunc_proc_name_schema(TSqlParser::Func_proc_name_schemaContext *ctx) override { @@ -2472,7 +2482,31 @@ class tsqlMutator : public TSqlParserBaseListener stream.setText(ctx->start->getStartIndex(), " chr"); } } + + std::string + getNodeDesc(ParseTree *t) + { + std::string result = Trees::getNodeText(t, this->ruleNames); + return result; + } + + // Tree listener overrides + void enterEveryRule(ParserRuleContext *ctx) override + { + std::string desc{getNodeDesc(ctx)}; + + if (pltsql_enable_antlr_detailed_log) + std::cout << "+entering (tsqlMutator)" << (void *) ctx << "[" << desc << "]" << std::endl; + } + + void exitEveryRule(ParserRuleContext *ctx) override + { + std::string desc{getNodeDesc(ctx)}; + if (pltsql_enable_antlr_detailed_log) + std::cout << "-leaving (tsqlMutator)" << (void *) ctx << "[" << desc << "]" << std::endl; + } + void enterFunc_proc_name_server_database_schema(TSqlParser::Func_proc_name_server_database_schemaContext *ctx) override { // We are looking at a function name; it may be a function call, or a @@ -2665,6 +2699,7 @@ class tsqlMutator : public TSqlParserBaseListener } } + // NB: similar code is in tsqlBuilder void exitChar_string(TSqlParser::Char_stringContext *ctx) override { if (in_procedure_parameter) @@ -2695,6 +2730,13 @@ class tsqlMutator : public TSqlParserBaseListener } } } + + // NB: this is copied in tsqlBuilder + void exitConstant(TSqlParser::ConstantContext *ctx) override + { + // Check for floating-point number without exponent + handleFloatWithoutExponent(ctx); + } }; //////////////////////////////////////////////////////////////////////////////// @@ -2989,7 +3031,7 @@ antlr_parse_query(const char *sourceText, bool useSLLParsing) { unsupportedFeatureHandler->visit(tree); } - std::unique_ptr mutator = std::make_unique(sourceStream); + std::unique_ptr mutator = std::make_unique(parser.getRuleNames(), sourceStream); antlr4::tree::ParseTreeWalker firstPass; firstPass.walk(mutator.get(), tree); @@ -4607,6 +4649,7 @@ makeDeclareStmt(TSqlParser::Declare_statementContext *ctx, std::mapdata_type()); PLtsql_type *type = parse_datatype(typeStr.c_str(), 0); // FIXME: the second arg should be 'location' + if (is_tsql_text_ntext_or_image_datatype(type->typoid)) { throw PGErrorWrapperException(ERROR, ERRCODE_DATATYPE_MISMATCH, "The text, ntext, and image data types are invalid for local variables.", getLineAndPos(local->data_type())); @@ -6013,7 +6056,7 @@ void process_execsql_destination_select(TSqlParser::Select_statement_standaloneC if (elem->EQUAL()) { - // in PG main parser, '@a=1' will be treaed as a boolean expression to compare @a and 1. This is different T-SQL expected. + // in PG main parser, '@a=1' will be treated as a boolean expression to compare @a and 1. This is different T-SQL expected. // We'll remove '@a=' from the query string so that main parser will return the expected result. removeTokenStringFromQuery(stmt->sqlstmt, elem->LOCAL_ID(), ctx); removeTokenStringFromQuery(stmt->sqlstmt, elem->EQUAL(), ctx); @@ -6126,7 +6169,7 @@ void process_execsql_destination_update(TSqlParser::Update_statementContext *uct removeCtxStringFromQuery(stmt->sqlstmt, elem->expression(), uctx); } - // Concetually we have to remove any nearest COMMA. + // Conceptually we have to remove any nearest COMMA. // But code is little bit dirty to handle some corner cases (the first few elems are removed or the last few elems are removed) if ((i==0 || comma_carry_over) && iCOMMA().size()) { @@ -6383,7 +6426,7 @@ static void post_process_column_definition(TSqlParser::Column_definitionContext *ctx, PLtsql_stmt_execsql *stmt, TSqlParser::Ddl_statementContext *baseCtx) { /* - * TSQL allows timestamp datatype without column name in create/alter table/type + * T-SQL allows TIMESTAMP datatype without column name in create/alter table/type * statement and internally assumes "timestamp" as column name. So here if * we find TIMESTAMP token then we will prepend "timestamp" as a column name * in the column definition. @@ -6757,7 +6800,7 @@ post_process_declare_table_statement(PLtsql_stmt_decl_table *stmt, TSqlParser::T for (auto cdtctx : ctx->column_def_table_constraints()->column_def_table_constraint()) { /* - * TSQL allows timestamp datatype without column name in declare table type + * T-SQL allows TIMESTAMP datatype without column name in declare table type * statement and internally assumes "timestamp" as column name. So here if * we find TIMESTAMP token then we will prepend "timestamp" as a column name * in the column definition. @@ -7305,10 +7348,10 @@ bool is_top_level_query_specification(TSqlParser::Query_specificationContext *ctx) { /* - * in ANTLR t-sql grammar, top-level select statement is represented as select_statement_standalone. - * subquery, derived table, cte can contain query specification via select statement but it is just a select_statement not via select_statement_standalone. - * To figure out the query-specification is corresponding to top-level select statement, - * iterate its ancestors and check if encoutering subquery, derived_table or common_table_expression. + * In ANTLR T-SQL grammar, top-level SELECT statement is represented as select_statement_standalone. + * subquery, derived table, CTE can contain query specification via SELECT statement but it is just a select_statement not via select_statement_standalone. + * To figure out the query-specification is corresponding to top-level SELECT statement, + * iterate its ancestors and check if encountering subquery, derived_table or common_table_expression. * if it is query specification in top-level statement, it will never meet those grammar element. */ Assert(ctx); @@ -7615,3 +7658,81 @@ makeChangeDbOwnerStatement(TSqlParser::Alter_authorizationContext *ctx) return (PLtsql_stmt *) result; } + +// Look for 'E' : T-SQL allows the exponent to be omitted (defaults to 0), but PG raises an error +// The REAL token is generated by the lexer; check the actual string to see if this is REAL notation +// Notes: +// * the mantissa may also start with a '.', i.e. '.5e' +// * the exponent may just be a + or - sign (means '0'; 1e+ ==> 1e0 ) +void +handleFloatWithoutExponent(TSqlParser::ConstantContext *ctx) +{ + std::string str = getFullText(ctx); + + // Check for case where exponent is only a sign: 2E+ , 2E- + if ((str.back() == '+') || (str.back() == '-')) + { + // remove terminating sign + str.pop_back(); + + if ((str.back() == 'E') || (str.back() == 'e')) + { + // ends in 'E+' or 'E-', continue below + } + else + { + // Whatever it is, it's not the notation we're looking for + return; + } + } + + if ((str.back() == 'E') || (str.back() == 'e')) + { + // remove terminating E + str.pop_back(); + + if ((str.front() == '+') || (str.front() == '-')) + { + // remove leading sign + str.erase(0,1); + } + + // Now check if this is a valid number. Note that it may start or end with '.' + // but in both cases it must have at least one digit as well. + size_t dot = str.find("."); + if (dot != std::string::npos) + { + // remove the dot + str.erase(dot,1); + } + + // What we have left now should be all digits + bool is_number = true; + if (str.length() == 0) + { + is_number = false; + } + else + { + for(size_t i = 0; i < str.length(); i++) + { + if (!isdigit(str[i])) + { + is_number = false; + break; + } + } + } + + if (is_number) + { + // Rewrite the exponent by adding a '0' + std::string str = getFullText(ctx); + size_t startPosition = ctx->start->getStartIndex(); + if (in_execute_body_batch_parameter) startPosition += fragment_EXEC_prefix.length(); // add length of prefix prepended internally for execute_body_batch + rewritten_query_fragment.emplace(std::make_pair(startPosition, std::make_pair(str, str+"0"))); + } + } + + return; +} diff --git a/test/JDBC/expected/float_exponent-vu-cleanup.out b/test/JDBC/expected/float_exponent-vu-cleanup.out new file mode 100644 index 0000000000..5bf3258f69 --- /dev/null +++ b/test/JDBC/expected/float_exponent-vu-cleanup.out @@ -0,0 +1,14 @@ +drop procedure p1_float_exponent +go + +drop procedure p2_float_exponent +go + +drop function f1_float_exponent +go + +drop view v1_float_exponent +go + +drop table t1_float_exponent +go diff --git a/test/JDBC/expected/float_exponent-vu-prepare.out b/test/JDBC/expected/float_exponent-vu-prepare.out new file mode 100644 index 0000000000..74674c6f61 --- /dev/null +++ b/test/JDBC/expected/float_exponent-vu-prepare.out @@ -0,0 +1,15 @@ +create table t1_float_exponent(a int, b real, c float, d decimal(10,2)) +go + +create view v1_float_exponent as select 2e as c +go + +create procedure p1_float_exponent @p float as select @p +go + +create procedure p2_float_exponent as +insert t1_float_exponent values (2e+, 3.1e, -.4e-, 5.e-) +go + +create function f1_float_exponent (@p float) returns float as begin return @p end +go diff --git a/test/JDBC/expected/float_exponent-vu-verify.out b/test/JDBC/expected/float_exponent-vu-verify.out new file mode 100644 index 0000000000..3b65c3f19a --- /dev/null +++ b/test/JDBC/expected/float_exponent-vu-verify.out @@ -0,0 +1,356 @@ +select 2E +go +~~START~~ +numeric +2 +~~END~~ + + +select -2E +go +~~START~~ +numeric +-2 +~~END~~ + + +select +2E +go +~~START~~ +numeric +2 +~~END~~ + + +select 2.1E +go +~~START~~ +numeric +2.1 +~~END~~ + + +select -2.1E +go +~~START~~ +numeric +-2.1 +~~END~~ + + +select +2.1E +go +~~START~~ +numeric +2.1 +~~END~~ + + +select 2.e +go +~~START~~ +numeric +2 +~~END~~ + + +select -2.e +go +~~START~~ +numeric +-2 +~~END~~ + + +select +2.e +go +~~START~~ +numeric +2 +~~END~~ + + +select .2e +go +~~START~~ +numeric +0.2 +~~END~~ + + +select -.2E +go +~~START~~ +numeric +-0.2 +~~END~~ + + +select +.2E +go +~~START~~ +numeric +0.2 +~~END~~ + + +select .2E+ +go +~~START~~ +numeric +0.2 +~~END~~ + + +select .2E- +go +~~START~~ +numeric +0.2 +~~END~~ + + +select 2E+ +go +~~START~~ +numeric +2 +~~END~~ + + +select 2E- +go +~~START~~ +numeric +2 +~~END~~ + + +select +.2E+ +go +~~START~~ +numeric +0.2 +~~END~~ + + +select -.2E- +go +~~START~~ +numeric +-0.2 +~~END~~ + + +select -.2E-1 +go +~~START~~ +numeric +-0.02 +~~END~~ + + +-- 2 + 1 = 3 +select 2E +1 +go +~~START~~ +numeric +3 +~~END~~ + + +-- 2 + 1 = 3 +select 2E+ +1 +go +~~START~~ +numeric +3 +~~END~~ + + +-- string constant, no change: +select '2E' +go +~~START~~ +varchar +2E +~~END~~ + + +-- hex constant: no change +select 0xe +go +~~START~~ +varbinary +0E +~~END~~ + + +-- invalid syntax in SQL Server +select 2E+ 1 +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error near '1' at line 2 and character position 11)~~ + + +-- invalid syntax in SQL Server +select 2 E+1 +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error near '+' at line 2 and character position 10)~~ + + +-- invalid syntax in SQL Server +select 2 E+ +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error near '+' at line 2 and character position 10)~~ + + +-- not a number but parsed as identifier +select .e +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error at or near ".")~~ + + +-- not a number +select 1.2.e +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: syntax error near '.' at line 2 and character position 10)~~ + + +insert t1_float_exponent values (2e+, 3.1e, -.4e-, 5.e-) +select * from t1_float_exponent +go +~~ROW COUNT: 1~~ + +~~START~~ +int#!#real#!#float#!#numeric +2#!#3.1#!#-0.4#!#5.00 +~~END~~ + +delete t1_float_exponent +go +~~ROW COUNT: 1~~ + + +exec p1_float_exponent 2E +go +~~START~~ +float +2.0 +~~END~~ + + +exec p1_float_exponent 2E+ +go +~~START~~ +float +2.0 +~~END~~ + + +exec p1_float_exponent -.2E+ +go +~~START~~ +float +-0.2 +~~END~~ + + +exec p1_float_exponent @p=-.2E+ +go +~~START~~ +float +-0.2 +~~END~~ + + +p1_float_exponent 2E +go +~~START~~ +float +2.0 +~~END~~ + + +p1_float_exponent 2E+ +go +~~START~~ +float +2.0 +~~END~~ + + +p1_float_exponent -.2E+ +go +~~START~~ +float +-0.2 +~~END~~ + + +p1_float_exponent @p=-.2E+ +go +~~START~~ +float +-0.2 +~~END~~ + + +exec p2_float_exponent +select * from t1_float_exponent +go +~~ROW COUNT: 1~~ + +~~START~~ +int#!#real#!#float#!#numeric +2#!#3.1#!#-0.4#!#5.00 +~~END~~ + + +select * from v1_float_exponent +go +~~START~~ +numeric +2 +~~END~~ + + +select dbo.f1_float_exponent(2e) +go +~~START~~ +float +2.0 +~~END~~ + + +select dbo.f1_float_exponent(-.2e-) +go +~~START~~ +float +-0.2 +~~END~~ + + +select dbo.f1_float_exponent(+2.e-) +go +~~START~~ +float +2.0 +~~END~~ + + + + + + + + diff --git a/test/JDBC/input/float_exponent-vu-cleanup.sql b/test/JDBC/input/float_exponent-vu-cleanup.sql new file mode 100644 index 0000000000..5bf3258f69 --- /dev/null +++ b/test/JDBC/input/float_exponent-vu-cleanup.sql @@ -0,0 +1,14 @@ +drop procedure p1_float_exponent +go + +drop procedure p2_float_exponent +go + +drop function f1_float_exponent +go + +drop view v1_float_exponent +go + +drop table t1_float_exponent +go diff --git a/test/JDBC/input/float_exponent-vu-prepare.sql b/test/JDBC/input/float_exponent-vu-prepare.sql new file mode 100644 index 0000000000..74674c6f61 --- /dev/null +++ b/test/JDBC/input/float_exponent-vu-prepare.sql @@ -0,0 +1,15 @@ +create table t1_float_exponent(a int, b real, c float, d decimal(10,2)) +go + +create view v1_float_exponent as select 2e as c +go + +create procedure p1_float_exponent @p float as select @p +go + +create procedure p2_float_exponent as +insert t1_float_exponent values (2e+, 3.1e, -.4e-, 5.e-) +go + +create function f1_float_exponent (@p float) returns float as begin return @p end +go diff --git a/test/JDBC/input/float_exponent-vu-verify.sql b/test/JDBC/input/float_exponent-vu-verify.sql new file mode 100644 index 0000000000..1f4af9ef3f --- /dev/null +++ b/test/JDBC/input/float_exponent-vu-verify.sql @@ -0,0 +1,161 @@ +select 2E +go + +select -2E +go + +select +2E +go + +select 2.1E +go + +select -2.1E +go + +select +2.1E +go + +select 2.e +go + +select -2.e +go + +select +2.e +go + +select .2e +go + +select -.2E +go + +select +.2E +go + +select .2E+ +go + +select .2E- +go + +select 2E+ +go + +select 2E- +go + +select +.2E+ +go + +select -.2E- +go + +select -.2E-1 +go + +-- 2 + 1 = 3 +select 2E +1 +go + +-- 2 + 1 = 3 +select 2E+ +1 +go + +-- string constant, no change: +select '2E' +go + +-- hex constant: no change +select 0xe +go + +-- invalid syntax in SQL Server +select 2E+ 1 +go + +-- invalid syntax in SQL Server +select 2 E+1 +go + +-- invalid syntax in SQL Server +select 2 E+ +go + +-- not a number but parsed as identifier +select .e +go + +-- not a number +select 1.2.e +go + +insert t1_float_exponent values (2e+, 3.1e, -.4e-, 5.e-) +select * from t1_float_exponent +go +delete t1_float_exponent +go + +exec p1_float_exponent 2E +go + +exec p1_float_exponent 2E+ +go + +exec p1_float_exponent -.2E+ +go + +exec p1_float_exponent @p=-.2E+ +go + +p1_float_exponent 2E +go + +p1_float_exponent 2E+ +go + +p1_float_exponent -.2E+ +go + +p1_float_exponent @p=-.2E+ +go + +exec p2_float_exponent +select * from t1_float_exponent +go + +select * from v1_float_exponent +go + +select dbo.f1_float_exponent(2e) +go + +select dbo.f1_float_exponent(-.2e-) +go + +select dbo.f1_float_exponent(+2.e-) +go + +-- JDBC test cases do not capture PRINT output, so the following tests have been commented out - but they work! + +-- print string '2e' (no change): +--print '2E' +--go + +-- print 2: +--print 2E +--go + +-- print -0.2: +--print -.2E +--go + +-- print -0.2: +--print -.2E+ +--go + +-- print 0.2: +--print +.2E- +--go + diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 77982f513a..57929c377e 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -466,6 +466,7 @@ unquoted_string doublequoted_string alter_authorization_change_db_owner sp_changedbowner +float_exponent datetimeoffset-timezone BABEL-4046 host_id From a2bc8ff656cba6aca75539df40f9ac70f38fd252 Mon Sep 17 00:00:00 2001 From: Rob Verschoor <91290800+robverschoor@users.noreply.github.com> Date: Thu, 4 Jan 2024 01:37:16 +0100 Subject: [PATCH 3/5] sp_executesql with NULL argument should not raise error (#2198) sp_executesql currently raises an error when called with a NULL argument for the SQL statement, but it should do nothing at all. Task: BABEL-4106 Signed-off-by: Rob Verschoor rcv@amazon.com --- contrib/babelfishpg_tsql/src/pl_exec-2.c | 10 ++++++---- test/JDBC/expected/BABEL-2748.out | 4 ---- test/JDBC/expected/BABEL-3092.out | 4 ---- 3 files changed, 6 insertions(+), 12 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/pl_exec-2.c b/contrib/babelfishpg_tsql/src/pl_exec-2.c index ded84a7c3a..950269b508 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec-2.c +++ b/contrib/babelfishpg_tsql/src/pl_exec-2.c @@ -928,7 +928,7 @@ exec_stmt_exec(PLtsql_execstate *estate, PLtsql_stmt_exec *stmt) stmt->is_scalar_func = is_scalar_func; - /* T-SQL doens't allow call prcedure in function */ + /* T-SQL doesn't allow call procedure in function */ if (estate->func && estate->func->fn_oid != InvalidOid && estate->func->fn_prokind == PROKIND_FUNCTION && estate->func->fn_is_trigger == PLTSQL_NOT_TRIGGER /* check EXEC is running * in the body of * function */ @@ -2127,11 +2127,13 @@ exec_stmt_exec_sp(PLtsql_execstate *estate, PLtsql_stmt_exec_sp *stmt) int save_nestlevel; int scope_level; InlineCodeBlockArgs *args = NULL; - + batch = exec_eval_expr(estate, stmt->query, &isnull, &restype, &restypmod); if (isnull) - ereport(ERROR, (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), - errmsg("batch string argument of sp_executesql is null"))); + { + // When called with a NULL argument, sp_executesql should take no action at all + break; + } batchstr = convert_value_to_string(estate, batch, restype); diff --git a/test/JDBC/expected/BABEL-2748.out b/test/JDBC/expected/BABEL-2748.out index 9e4daaac8f..ee27382cf3 100644 --- a/test/JDBC/expected/BABEL-2748.out +++ b/test/JDBC/expected/BABEL-2748.out @@ -229,10 +229,6 @@ declare @query_str varchar(100); declare @param_def varchar(100); exec sp_executesql @query_str, @param_def; go -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: batch string argument of sp_executesql is null)~~ - exec sp_prepexec; go diff --git a/test/JDBC/expected/BABEL-3092.out b/test/JDBC/expected/BABEL-3092.out index af641875fb..6f2073aab9 100644 --- a/test/JDBC/expected/BABEL-3092.out +++ b/test/JDBC/expected/BABEL-3092.out @@ -60,10 +60,6 @@ GO sp_executesql NULL; GO -~~ERROR (Code: 33557097)~~ - -~~ERROR (Message: batch string argument of sp_executesql is null)~~ - CREATE TABLE t_3092_fmtonly(a INT); GO From 0e1721ad86f65158b43cb6028c482cffa20526f5 Mon Sep 17 00:00:00 2001 From: Rob Verschoor <91290800+robverschoor@users.noreply.github.com> Date: Thu, 4 Jan 2024 04:50:07 +0100 Subject: [PATCH 4/5] Support PRINT NULL and PRINT (#2199) This PR introduces support for printing NULL and . When the argument to PRINT is NULL or an empty string, a single space should be printed. However Babelfish currently prints and an empty string, respectively. Signed-off-by: Rob Verschoor rcv@amazon.com --- contrib/babelfishpg_tsql/src/pl_exec-2.c | 13 +++++++- test/JDBC/expected/print_null-vu-cleanup.out | 2 ++ test/JDBC/expected/print_null-vu-prepare.out | 10 +++++++ test/JDBC/expected/print_null-vu-verify.out | 31 ++++++++++++++++++++ test/JDBC/input/print_null-vu-cleanup.sql | 2 ++ test/JDBC/input/print_null-vu-prepare.sql | 10 +++++++ test/JDBC/input/print_null-vu-verify.sql | 31 ++++++++++++++++++++ test/JDBC/upgrade/latest/schedule | 1 + 8 files changed, 99 insertions(+), 1 deletion(-) create mode 100644 test/JDBC/expected/print_null-vu-cleanup.out create mode 100644 test/JDBC/expected/print_null-vu-prepare.out create mode 100644 test/JDBC/expected/print_null-vu-verify.out create mode 100644 test/JDBC/input/print_null-vu-cleanup.sql create mode 100644 test/JDBC/input/print_null-vu-prepare.sql create mode 100644 test/JDBC/input/print_null-vu-verify.sql diff --git a/contrib/babelfishpg_tsql/src/pl_exec-2.c b/contrib/babelfishpg_tsql/src/pl_exec-2.c index 950269b508..d4a312669b 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec-2.c +++ b/contrib/babelfishpg_tsql/src/pl_exec-2.c @@ -409,11 +409,22 @@ exec_stmt_print(PLtsql_execstate *estate, PLtsql_stmt_print *stmt) &formattypmod); if (formatisnull) - extval = ""; + { + // Printing NULL prints a single space in T-SQL + extval = " "; + } else + { extval = convert_value_to_string(estate, formatdatum, formattypeid); + } + + if (strlen(extval) == 0) + { + // Printing an empty string prints a single space in T-SQL + extval = " "; + } ereport(INFO, errmsg_internal("%s", extval)); diff --git a/test/JDBC/expected/print_null-vu-cleanup.out b/test/JDBC/expected/print_null-vu-cleanup.out new file mode 100644 index 0000000000..dcdfb32d83 --- /dev/null +++ b/test/JDBC/expected/print_null-vu-cleanup.out @@ -0,0 +1,2 @@ +drop procedure p1_print_null +go diff --git a/test/JDBC/expected/print_null-vu-prepare.out b/test/JDBC/expected/print_null-vu-prepare.out new file mode 100644 index 0000000000..1c882b36a2 --- /dev/null +++ b/test/JDBC/expected/print_null-vu-prepare.out @@ -0,0 +1,10 @@ +create procedure p1_print_null as +declare @v varchar = null +print null +print @v +print '' +set @v = '' +print @v +print ' ' +print ' ' +go diff --git a/test/JDBC/expected/print_null-vu-verify.out b/test/JDBC/expected/print_null-vu-verify.out new file mode 100644 index 0000000000..d18f8de498 --- /dev/null +++ b/test/JDBC/expected/print_null-vu-verify.out @@ -0,0 +1,31 @@ + +-- Since the JDBC tests do not capture output from PRINT statements, these tests actually don't do anything +-- Keeping them for when then moment comes that PRINT tests are supported +-- prints a single space: +print null +go + +-- prints a single space: +declare @v varchar = null +print @v +go +-- prints a single space: +print '' +go + +-- prints a single space: +declare @v varchar = '' +print @v +go + +-- prints a single space: +print ' ' +go + +-- prints two spaces: +print ' ' +go + +-- same set of tests as above, but inside a stored proc: +exec p1_print_null +go diff --git a/test/JDBC/input/print_null-vu-cleanup.sql b/test/JDBC/input/print_null-vu-cleanup.sql new file mode 100644 index 0000000000..1ad3e02c5e --- /dev/null +++ b/test/JDBC/input/print_null-vu-cleanup.sql @@ -0,0 +1,2 @@ +drop procedure p1_print_null +go \ No newline at end of file diff --git a/test/JDBC/input/print_null-vu-prepare.sql b/test/JDBC/input/print_null-vu-prepare.sql new file mode 100644 index 0000000000..b3dcfd47e7 --- /dev/null +++ b/test/JDBC/input/print_null-vu-prepare.sql @@ -0,0 +1,10 @@ +create procedure p1_print_null as +declare @v varchar = null +print null +print @v +print '' +set @v = '' +print @v +print ' ' +print ' ' +go \ No newline at end of file diff --git a/test/JDBC/input/print_null-vu-verify.sql b/test/JDBC/input/print_null-vu-verify.sql new file mode 100644 index 0000000000..35283c46a4 --- /dev/null +++ b/test/JDBC/input/print_null-vu-verify.sql @@ -0,0 +1,31 @@ +-- Since the JDBC tests do not capture output from PRINT statements, these tests actually don't do anything +-- Keeping them for when then moment comes that PRINT tests are supported + +-- prints a single space: +print null +go + +-- prints a single space: +declare @v varchar = null +print @v +go +-- prints a single space: +print '' +go + +-- prints a single space: +declare @v varchar = '' +print @v +go + +-- prints a single space: +print ' ' +go + +-- prints two spaces: +print ' ' +go + +-- same set of tests as above, but inside a stored proc: +exec p1_print_null +go diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 57929c377e..dde3e9af4e 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -462,6 +462,7 @@ todatetimeoffset-dep triggers_with_transaction typeid-typename typeid-typename-dep +print_null unquoted_string doublequoted_string alter_authorization_change_db_owner From 1f0ffa7602b9711b4037c05db9ae1e2da3d1c0e0 Mon Sep 17 00:00:00 2001 From: Rob Verschoor <91290800+robverschoor@users.noreply.github.com> Date: Thu, 4 Jan 2024 04:55:15 +0100 Subject: [PATCH 5/5] Optional AS keyword in scalar CREATE FUNCTION (#2202) Description The AS keyword in a scalar CREATE FUNCTION is optional, but Babelfish currently requires it when the function result datatype is Babelfish-defined (like TINYINT). This fix inserts an AS keyword prior to the BEGIN keyword (which is mandatory) in ANTLR. While this fix is required only for Babelfish-defined function result datatypes, for simplicity it's done for all data types; there is no downside for those cases where it is not required. This issue only applies to scalar functions; for other function types, the optional AS keyword is already supported. Signed-off-by: Rob Verschoor rcv@amazon.com --- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 17 ++++++- .../expected/function_as_keywd-vu-cleanup.out | 10 ++++ .../expected/function_as_keywd-vu-prepare.out | 0 .../expected/function_as_keywd-vu-verify.out | 51 +++++++++++++++++++ .../input/function_as_keywd-vu-cleanup.sql | 10 ++++ .../input/function_as_keywd-vu-prepare.sql | 0 .../input/function_as_keywd-vu-verify.sql | 26 ++++++++++ test/JDBC/upgrade/latest/schedule | 1 + 8 files changed, 114 insertions(+), 1 deletion(-) create mode 100644 test/JDBC/expected/function_as_keywd-vu-cleanup.out create mode 100644 test/JDBC/expected/function_as_keywd-vu-prepare.out create mode 100644 test/JDBC/expected/function_as_keywd-vu-verify.out create mode 100644 test/JDBC/input/function_as_keywd-vu-cleanup.sql create mode 100644 test/JDBC/input/function_as_keywd-vu-prepare.sql create mode 100644 test/JDBC/input/function_as_keywd-vu-verify.sql diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 93767966ca..6a641cb16d 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -2654,7 +2654,22 @@ class tsqlMutator : public TSqlParserBaseListener in_procedure_parameter_id = true; } } - + + void exitFunc_body_returns_scalar(TSqlParser::Func_body_returns_scalarContext *ctx) override + { + // If no AS keyword is specified, insert it prior to the BEGIN keyword. + // This only applies to scalar functions; for other function types, the optional AS keyword + // is already supported. + // Formally, this fix is required only for all Babelfish-defined function result datatypes such as + // TINYINT, but for simplicity it's done for all data types. + if (!ctx->AS() && ctx->BEGIN()) + { + std::string b = getFullText(ctx->BEGIN()); + size_t startPosition = ctx->BEGIN()->getSymbol()->getStartIndex(); + rewritten_query_fragment.emplace(std::make_pair(startPosition, std::make_pair(b, "AS "+b))); + } + } + void exitProcedure_param(TSqlParser::Procedure_paramContext *ctx) override { in_procedure_parameter = false; diff --git a/test/JDBC/expected/function_as_keywd-vu-cleanup.out b/test/JDBC/expected/function_as_keywd-vu-cleanup.out new file mode 100644 index 0000000000..4ad823aa1e --- /dev/null +++ b/test/JDBC/expected/function_as_keywd-vu-cleanup.out @@ -0,0 +1,10 @@ +drop function f1_function_as_keywd +go +drop function f2_function_as_keywd +go +drop function f3_function_as_keywd +go +drop function f4_function_as_keywd +go +drop function f5_function_as_keywd +go diff --git a/test/JDBC/expected/function_as_keywd-vu-prepare.out b/test/JDBC/expected/function_as_keywd-vu-prepare.out new file mode 100644 index 0000000000..e69de29bb2 diff --git a/test/JDBC/expected/function_as_keywd-vu-verify.out b/test/JDBC/expected/function_as_keywd-vu-verify.out new file mode 100644 index 0000000000..5a4e04b205 --- /dev/null +++ b/test/JDBC/expected/function_as_keywd-vu-verify.out @@ -0,0 +1,51 @@ +create function f1_function_as_keywd () returns tinyint begin return 1 end +go +select dbo.f1_function_as_keywd() +go +~~START~~ +tinyint +1 +~~END~~ + + +create function f2_function_as_keywd () returns tinyint as begin return 2 end +go +select dbo.f2_function_as_keywd() +go +~~START~~ +tinyint +2 +~~END~~ + + +create function f3_function_as_keywd () returns int +begin return 3 end +go +select dbo.f3_function_as_keywd() +go +~~START~~ +int +3 +~~END~~ + + +create function f4_function_as_keywd () returns tinyint +as begin return 4 end +go +select dbo.f4_function_as_keywd() +go +~~START~~ +tinyint +4 +~~END~~ + + +execute('create function f5_function_as_keywd () returns tinyint begin return 5 end') +go +select dbo.f5_function_as_keywd() +go +~~START~~ +tinyint +5 +~~END~~ + diff --git a/test/JDBC/input/function_as_keywd-vu-cleanup.sql b/test/JDBC/input/function_as_keywd-vu-cleanup.sql new file mode 100644 index 0000000000..e1c2b4e8e7 --- /dev/null +++ b/test/JDBC/input/function_as_keywd-vu-cleanup.sql @@ -0,0 +1,10 @@ +drop function f1_function_as_keywd +go +drop function f2_function_as_keywd +go +drop function f3_function_as_keywd +go +drop function f4_function_as_keywd +go +drop function f5_function_as_keywd +go \ No newline at end of file diff --git a/test/JDBC/input/function_as_keywd-vu-prepare.sql b/test/JDBC/input/function_as_keywd-vu-prepare.sql new file mode 100644 index 0000000000..e69de29bb2 diff --git a/test/JDBC/input/function_as_keywd-vu-verify.sql b/test/JDBC/input/function_as_keywd-vu-verify.sql new file mode 100644 index 0000000000..0ccb6d8875 --- /dev/null +++ b/test/JDBC/input/function_as_keywd-vu-verify.sql @@ -0,0 +1,26 @@ +create function f1_function_as_keywd () returns tinyint begin return 1 end +go +select dbo.f1_function_as_keywd() +go + +create function f2_function_as_keywd () returns tinyint as begin return 2 end +go +select dbo.f2_function_as_keywd() +go + +create function f3_function_as_keywd () returns int +begin return 3 end +go +select dbo.f3_function_as_keywd() +go + +create function f4_function_as_keywd () returns tinyint +as begin return 4 end +go +select dbo.f4_function_as_keywd() +go + +execute('create function f5_function_as_keywd () returns tinyint begin return 5 end') +go +select dbo.f5_function_as_keywd() +go diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index dde3e9af4e..143a9648dd 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -481,6 +481,7 @@ Test_ISNULL BABEL-4270 BABEL-4410 BABEL-4231 +function_as_keywd typeproperty-dep sys_asymmetric_keys sys_certificates