From c17fd7f5432c612552da0bd60137152028903f1e Mon Sep 17 00:00:00 2001 From: Tanzeel Khan <140405735+tanscorpio7@users.noreply.github.com> Date: Fri, 26 Jul 2024 20:37:01 +0530 Subject: [PATCH] Fix error when OUTPUT INTO table variable statement fires trigger (#2639) (#2796) Fix error portal snapshots (1) did not account for all active snapshots (2) when OUTPUT INTO table variable statement fires triggers. pltsql statements that could fire trigger must always run inside a transaction block. If a txn block is not active, we create one. We exclude some types of statements from this, one of them being DML on table variables since they can never fire a trigger. We detect this using the variable mod_stmt_tablevar. Now an edge case here is OUTPUT into table variable stmt. Which we internally transform into two DML nodes. TOP INSERT NODE (signifies the output into clause) Another DELETE / UPDATE / INSERT node inside the top insert node -> with clause (specifies the first part of the output into clause ) As a fix we simply skip transaction commands inside pltsql UDFs and not rely on mod_stmt_tablevar on anymore. Also blocked certain cases of OUTPUT clause which should not be allowed inside pltsql UDFs. OUTPUT clause flushes results to client (INTO clause is missing) OUTPUT INTO clause has a non local object as its target. (UDFs only allow DML on local objects) Issues Resolved: BABEL-4859 Signed-off-by: Tanzeel Khan tzlkhan@amazon.com --- contrib/babelfishpg_tsql/src/pl_exec.c | 10 +- contrib/babelfishpg_tsql/src/tsqlIface.cpp | 17 + .../expected/output_into_fires_trigger.out | 418 ++++++++++++++++++ test/JDBC/input/output_into_fires_trigger.sql | 295 ++++++++++++ 4 files changed, 735 insertions(+), 5 deletions(-) create mode 100644 test/JDBC/expected/output_into_fires_trigger.out create mode 100644 test/JDBC/input/output_into_fires_trigger.sql diff --git a/contrib/babelfishpg_tsql/src/pl_exec.c b/contrib/babelfishpg_tsql/src/pl_exec.c index 69a179c7e5a..c11f179e597 100644 --- a/contrib/babelfishpg_tsql/src/pl_exec.c +++ b/contrib/babelfishpg_tsql/src/pl_exec.c @@ -4608,6 +4608,9 @@ exec_stmt_execsql(PLtsql_execstate *estate, /* fetch current search_path */ char *old_search_path = NULL; + bool ro_func = (estate->func->fn_prokind == PROKIND_FUNCTION) && + (estate->func->fn_is_trigger == PLTSQL_NOT_TRIGGER) && + (strcmp(estate->func->fn_signature, "inline_code_block") != 0); if (stmt->original_query) original_query_string = stmt->original_query; @@ -4762,7 +4765,7 @@ exec_stmt_execsql(PLtsql_execstate *estate, * tsql_select_assign_stmt (select @a=1). with ANTLR=off, it is * handled in PLtsql_stmt_query_set. */ - if (stmt->need_to_push_result || stmt->is_tsql_select_assign_stmt || stmt->mod_stmt_tablevar) + if (stmt->need_to_push_result || stmt->is_tsql_select_assign_stmt || ro_func) enable_txn_in_triggers = false; if (enable_txn_in_triggers) @@ -5031,10 +5034,7 @@ exec_stmt_execsql(PLtsql_execstate *estate, if ((!pltsql_disable_batch_auto_commit || (stmt->txn_data != NULL)) && pltsql_support_tsql_transactions() && (enable_txn_in_triggers || estate->trigdata == NULL) && - !(estate->func->fn_prokind == PROKIND_FUNCTION && - estate->func->fn_is_trigger == PLTSQL_NOT_TRIGGER && - strcmp(estate->func->fn_signature, "inline_code_block") != 0) && - !estate->insert_exec) + !ro_func && !estate->insert_exec) { commit_stmt(estate, (estate->tsql_trigger_flags & TSQL_TRAN_STARTED)); diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 487f19fff73..99b3caeb635 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -1420,6 +1420,23 @@ class tsqlBuilder : public tsqlCommonMutator else if (ctx->delete_statement() && ctx->delete_statement()->delete_statement_from()->ddl_object() && !ctx->delete_statement()->delete_statement_from()->ddl_object()->local_id() && (ctx->delete_statement()->table_sources() ? ::getFullText(ctx->delete_statement()->table_sources()).c_str()[0] != '@' : true)) /* delete non-local object, table variables are allowed */ throw PGErrorWrapperException(ERROR, ERRCODE_INVALID_FUNCTION_DEFINITION, "'DELETE' cannot be used within a function", getLineAndPos(ctx->delete_statement()->delete_statement_from()->ddl_object())); + + /* + * Reject if OUTPUT clause is missing INTO (returning to client) or OUTPUT INTO non local object + */ + + if (ctx->insert_statement() && ctx->insert_statement()->output_clause() && (!ctx->insert_statement()->output_clause()->INTO() || !ctx->insert_statement()->output_clause()->LOCAL_ID())) + { + throw PGErrorWrapperException(ERROR, ERRCODE_INVALID_FUNCTION_DEFINITION, "Invalid use of a side-effecting operator 'INSERT' within a function.", getLineAndPos(ctx->insert_statement()->output_clause())); + } + else if (ctx->update_statement() && ctx->update_statement()->output_clause() && (!ctx->update_statement()->output_clause()->INTO() || !ctx->update_statement()->output_clause()->LOCAL_ID())) + { + throw PGErrorWrapperException(ERROR, ERRCODE_INVALID_FUNCTION_DEFINITION, "Invalid use of a side-effecting operator 'UPDATE' within a function.", getLineAndPos(ctx->update_statement()->output_clause())); + } + else if (ctx->delete_statement() && ctx->delete_statement()->output_clause() && (!ctx->delete_statement()->output_clause()->INTO() || !ctx->delete_statement()->output_clause()->LOCAL_ID())) + { + throw PGErrorWrapperException(ERROR, ERRCODE_INVALID_FUNCTION_DEFINITION, "Invalid use of a side-effecting operator 'DELETE' within a function.", getLineAndPos(ctx->delete_statement()->output_clause())); + } } /* we must add previous rewrite at first. */ diff --git a/test/JDBC/expected/output_into_fires_trigger.out b/test/JDBC/expected/output_into_fires_trigger.out new file mode 100644 index 00000000000..d3700778b02 --- /dev/null +++ b/test/JDBC/expected/output_into_fires_trigger.out @@ -0,0 +1,418 @@ + + + + + +-- Below statements will fire an after trigger +-- INSERT non local table OUTPUT ... INTO local table +-- UPDATE non local table OUTPUT ... INTO local table +-- DELETE non local table OUTPUT ... INTO local table +-- REPEAT THE ABOVE INSIDE + -- PROCEDURE + -- TRIGGER + -- FUNCTION (functions should not be allowed to create for output to client or non local object) +-- SOME MORE CASES OF OUTPUT CLAUSE WHICH SHOULD NOT BE ALLOWED INSIDE PLTSQL FUNCTIONS +-- OUTPUT TO CLIENT & OUTPUT INTO NON LOCAL OBJECT +CREATE TABLE babel_4859_t (id INT) +GO + + +-- INSERT table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_insert] + ON [dbo].[babel_4859_t] +AFTER INSERT +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +-- UPDATE table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_update] + ON [dbo].[babel_4859_t] +AFTER UPDATE +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +-- DELETE table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_delete] + ON [dbo].[babel_4859_t] +AFTER delete +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +-- INSERT table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +GO + +EXEC babel_4859_p +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +DROP PROC babel_4859_p +GO + +-- UPDATE table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +GO + +EXEC babel_4859_p +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +DROP PROC babel_4859_p +GO + +-- DELETE table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +GO + +EXEC babel_4859_p +GO +~~START~~ +int +1 +~~END~~ + +~~ROW COUNT: 4~~ + + +DROP PROC babel_4859_p +GO + +CREATE TABLE babel_4859_t2 (id INT) +GO + +-- INSERT table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +4859 +9584 +2 +3 +~~END~~ + +~~ROW COUNT: 1~~ + + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + +-- UPDATE table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int#!#int +77#!#4859 +77#!#9584 +77#!#2 +77#!#3 +~~END~~ + +~~ROW COUNT: 1~~ + + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + +-- DELETE table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +77 +77 +77 +77 +~~END~~ + +~~ROW COUNT: 1~~ + + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + + +-- INSERT table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because inserting into non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'INSERT' cannot be used within a function)~~ + + +-- UPDATE table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because updating non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); + UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'UPDATE' cannot be used within a function)~~ + + +-- DELETE table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because deleting from non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id_old INT); + DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 'DELETE' cannot be used within a function)~~ + + + + +-- OUTPUT TO CLIENT SHOUD BE BLOCKED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'INSERT' within a function.)~~ + + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id, DELETED.id + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'UPDATE' within a function.)~~ + + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'DELETE' within a function.)~~ + + + +-- OUTPUT INTO NON LOCAL OBJECTS SHOULD NOT BE ALLOWED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id INTO babel_4859_t2 VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'INSERT' within a function.)~~ + + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id INTO babel_4859_t2 + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'UPDATE' within a function.)~~ + + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id INTO babel_4859_t2 + RETURN 1 +END +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Invalid use of a side-effecting operator 'DELETE' within a function.)~~ + + +-- OUTPUT INTO LOCAL OBJECTS SHOULD BE ALLOWED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id INTO @babel_4859_tabvar_2 VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id INTO @babel_4859_tabvar_2 + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id INTO @babel_4859_tabvar_2 + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +DROP TABLE babel_4859_t, babel_4859_t2 +GO diff --git a/test/JDBC/input/output_into_fires_trigger.sql b/test/JDBC/input/output_into_fires_trigger.sql new file mode 100644 index 00000000000..181aedb9863 --- /dev/null +++ b/test/JDBC/input/output_into_fires_trigger.sql @@ -0,0 +1,295 @@ +-- Below statements will fire an after trigger +-- INSERT non local table OUTPUT ... INTO local table +-- UPDATE non local table OUTPUT ... INTO local table +-- DELETE non local table OUTPUT ... INTO local table + +-- REPEAT THE ABOVE INSIDE + -- PROCEDURE + -- TRIGGER + -- FUNCTION (functions should not be allowed to create for output to client or non local object) + +-- SOME MORE CASES OF OUTPUT CLAUSE WHICH SHOULD NOT BE ALLOWED INSIDE PLTSQL FUNCTIONS +-- OUTPUT TO CLIENT & OUTPUT INTO NON LOCAL OBJECT + + + +CREATE TABLE babel_4859_t (id INT) +GO + + +-- INSERT table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_insert] + ON [dbo].[babel_4859_t] +AFTER INSERT +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +GO + +-- UPDATE table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_update] + ON [dbo].[babel_4859_t] +AFTER UPDATE +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +GO + +-- DELETE table OUTPUT ... INTO table variable +CREATE TRIGGER [dbo].[babel_4859_trigger_delete] + ON [dbo].[babel_4859_t] +AFTER delete +AS +SET NOCOUNT ON +SELECT 1; +GO + +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +GO + +-- INSERT table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +GO + +EXEC babel_4859_p +GO + +DROP PROC babel_4859_p +GO + +-- UPDATE table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +GO + +EXEC babel_4859_p +GO + +DROP PROC babel_4859_p +GO + +-- DELETE table OUTPUT ... INTO table variable INSIDE PROCEDURE +CREATE PROCEDURE babel_4859_p +AS +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +GO + +EXEC babel_4859_p +GO + +DROP PROC babel_4859_p +GO + +CREATE TABLE babel_4859_t2 (id INT) +GO + +-- INSERT table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id INT); +INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + +-- UPDATE table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); +UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + +-- DELETE table OUTPUT ... INTO table variable INSIDE TRIGGER which will in turn fire another trigger +CREATE TRIGGER [dbo].[babel_4859_t2_trigger_insert] + ON [dbo].[babel_4859_t2] +AFTER INSERT +AS +SET NOCOUNT ON +DECLARE @babel_4859_tabvar TABLE (id_old INT); +DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar +SELECT * FROM @babel_4859_tabvar +GO + +INSERT INTO babel_4859_t2 VALUES (1) +GO + +DROP TRIGGER [dbo].[babel_4859_t2_trigger_insert] +GO + + +-- INSERT table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because inserting into non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO babel_4859_t OUTPUT INSERTED.id INTO @babel_4859_tabvar VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO + +-- UPDATE table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because updating non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT, id_old INT); + UPDATE babel_4859_t SET id = 77 OUTPUT INSERTED.id, DELETED.id INTO @babel_4859_tabvar + RETURN 1 +END +GO + +-- DELETE table OUTPUT ... INTO table variable INSIDE FUNCTION +-- Should fail because deleting from non local object +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id_old INT); + DELETE babel_4859_t OUTPUT DELETED.id INTO @babel_4859_tabvar + RETURN 1 +END +GO + + + +-- OUTPUT TO CLIENT SHOUD BE BLOCKED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id, DELETED.id + RETURN 1 +END +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id + RETURN 1 +END +GO + + +-- OUTPUT INTO NON LOCAL OBJECTS SHOULD NOT BE ALLOWED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id INTO babel_4859_t2 VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id INTO babel_4859_t2 + RETURN 1 +END +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id INTO babel_4859_t2 + RETURN 1 +END +GO + +-- OUTPUT INTO LOCAL OBJECTS SHOULD BE ALLOWED INSIDE FUNCTIONS +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + INSERT INTO @babel_4859_tabvar OUTPUT INSERTED.id INTO @babel_4859_tabvar_2 VALUES (4859), (9584), (2), (3) + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + UPDATE @babel_4859_tabvar SET id = 77 OUTPUT INSERTED.id INTO @babel_4859_tabvar_2 + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +CREATE FUNCTION babel_4859_f1() +RETURNS INT +AS +BEGIN + DECLARE @babel_4859_tabvar TABLE (id INT); + DECLARE @babel_4859_tabvar_2 TABLE (id INT); + DELETE @babel_4859_tabvar OUTPUT DELETED.id INTO @babel_4859_tabvar_2 + RETURN 1 +END +GO +DROP FUNCTION babel_4859_f1 +GO + +DROP TABLE babel_4859_t, babel_4859_t2 +GO \ No newline at end of file