diff --git a/.github/composite-actions/install-dependencies/action.yml b/.github/composite-actions/install-dependencies/action.yml index c63c54e031..e531d9f8db 100644 --- a/.github/composite-actions/install-dependencies/action.yml +++ b/.github/composite-actions/install-dependencies/action.yml @@ -9,7 +9,7 @@ runs: curl https://packages.microsoft.com/keys/microsoft.asc | sudo apt-key add - curl https://packages.microsoft.com/config/ubuntu/20.04/prod.list | sudo tee /etc/apt/sources.list.d/msprod.list sudo apt-get update --fix-missing -y - sudo apt-get install uuid-dev openjdk-8-jre libicu-dev libxml2-dev openssl libssl-dev python3-dev libossp-uuid-dev libpq-dev cmake pkg-config g++ build-essential bison mssql-tools unixodbc-dev libsybdb5 freetds-dev freetds-common gdal-bin libgdal-dev libgeos-dev gdb + sudo apt-get install uuid-dev openjdk-8-jre libicu-dev libxml2-dev openssl libssl-dev python3-dev libossp-uuid-dev libpq-dev cmake pkg-config g++ build-essential bison mssql-tools unixodbc-dev libsybdb5 freetds-dev freetds-common gdal-bin libgdal-dev libgeos-dev gdb libkrb5-dev sudo apt install -y ccache sudo apt-get install lcov sudo /usr/sbin/update-ccache-symlinks diff --git a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql index b0e2299745..91bfb6f9d7 100644 --- a/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql +++ b/contrib/babelfishpg_tsql/sql/upgrades/babelfishpg_tsql--4.4.0--4.5.0.sql @@ -54,6 +54,7 @@ BEGIN END; $$; + /* Helper function to update local variables dynamically during execution */ CREATE OR REPLACE FUNCTION sys.pltsql_assign_var(dno INT, val ANYELEMENT) RETURNS ANYELEMENT diff --git a/contrib/babelfishpg_tsql/src/tsqlIface.cpp b/contrib/babelfishpg_tsql/src/tsqlIface.cpp index 0135e7dd1a..579cacb91a 100644 --- a/contrib/babelfishpg_tsql/src/tsqlIface.cpp +++ b/contrib/babelfishpg_tsql/src/tsqlIface.cpp @@ -7289,29 +7289,70 @@ void process_execsql_destination_update(TSqlParser::Update_statementContext *uct appendStringInfo(&ds, ", "); ++returning_col_cnt; - if (elem->full_column_name()) + if (elem->EQUAL(0) && elem->full_column_name()) { /* "SET @a=col=expr" => "SET col=expr ... RETURNING sys.pltsql_assign_var(dno, cast(expr as type))" */ - appendStringInfo(&ds, "sys.pltsql_assign_var(%d, cast(%s as %s))", + appendStringInfo(&ds, "sys.pltsql_assign_var(%d, %s)", nse->itemno, - ::getFullText(elem->full_column_name()).c_str(), - tsql_format_type_extended(var->datatype->typoid, var->datatype->atttypmod, FORMAT_TYPE_TYPEMOD_GIVEN)); + rewrite_assignment_expression(var, elem->expression())); removeTokenStringFromQuery(stmt->sqlstmt, elem->LOCAL_ID(), uctx); removeTokenStringFromQuery(stmt->sqlstmt, elem->EQUAL(0), uctx); } - else + else if(elem->EQUAL(0) && elem->expression()) { /* "SET @a=expr, col=expr2" => "SET col=expr2 ... RETURNING sys.pltsql_assign_var(dno, cast(expr as type))" */ - appendStringInfo(&ds, "sys.pltsql_assign_var(%d, cast(%s as %s))", + appendStringInfo(&ds, "sys.pltsql_assign_var(%d, %s)", nse->itemno, - ::getFullText(elem->expression()).c_str(), - tsql_format_type_extended(var->datatype->typoid, var->datatype->atttypmod, FORMAT_TYPE_TYPEMOD_GIVEN)); + rewrite_assignment_expression(var, elem->expression())); + handle_local_ids_for_expression(elem->expression()); removeTokenStringFromQuery(stmt->sqlstmt, elem->LOCAL_ID(), uctx); removeTokenStringFromQuery(stmt->sqlstmt, elem->EQUAL(0), uctx); removeCtxStringFromQuery(stmt->sqlstmt, elem->expression(), uctx); } + else if(elem->assignment_operator() && elem->expression()) + { + /* "SET @a+=expr, col=expr2" => "SET col=expr2 ... RETURNING sys.pltsql_assign_var(dno, "@var" + cast((expr) as type))" */ + tree::TerminalNode *anode = nullptr; + + if (elem->assignment_operator()) + { + if (elem->assignment_operator()->PLUS_ASSIGN()) + anode = elem->assignment_operator()->PLUS_ASSIGN(); + else if (elem->assignment_operator()->MINUS_ASSIGN()) + anode = elem->assignment_operator()->MINUS_ASSIGN(); + else if (elem->assignment_operator()->MULT_ASSIGN()) + anode = elem->assignment_operator()->MULT_ASSIGN(); + else if (elem->assignment_operator()->DIV_ASSIGN()) + anode = elem->assignment_operator()->DIV_ASSIGN(); + else if (elem->assignment_operator()->MOD_ASSIGN()) + anode = elem->assignment_operator()->MOD_ASSIGN(); + else if (elem->assignment_operator()->AND_ASSIGN()) + anode = elem->assignment_operator()->AND_ASSIGN(); + else if (elem->assignment_operator()->XOR_ASSIGN()) + anode = elem->assignment_operator()->XOR_ASSIGN(); + else if (elem->assignment_operator()->OR_ASSIGN()) + anode = elem->assignment_operator()->OR_ASSIGN(); + else + Assert(0); + } + appendStringInfo(&ds, "sys.pltsql_assign_var(%d, %s %s %s)", + nse->itemno, + delimitIfAtAtUserVarName(::getFullText(elem->LOCAL_ID())).c_str(), + rewrite_assign_operator(anode), + rewrite_assignment_expression(var, elem->expression())); + + handle_local_ids_for_expression(elem->expression()); + removeTokenStringFromQuery(stmt->sqlstmt, elem->LOCAL_ID(), uctx); + removeCtxStringFromQuery(stmt->sqlstmt, elem->assignment_operator(), uctx); + removeCtxStringFromQuery(stmt->sqlstmt, elem->expression(), uctx); + } + else + { + /* Syntax error should already be handled. */ + Assert(0); + } // 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) @@ -7326,11 +7367,21 @@ void process_execsql_destination_update(TSqlParser::Update_statementContext *uct /* remove prev COMMA by default */ removeTokenStringFromQuery(stmt->sqlstmt, uctx->COMMA(i-1), uctx); } + } else comma_carry_over = false; } + /* + * Should remove semi colon before appending RETURNING clause. Otherwise syntax + * error will be thrown. + */ + if (uctx->SEMI()) + { + removeTokenStringFromQuery(stmt->sqlstmt, uctx->SEMI(), uctx); + } + pltsql_adddatum((PLtsql_datum *) target); stmt->target = (PLtsql_variable *)target; diff --git a/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out b/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out index 52c77265b4..1c3c7a78ab 100644 --- a/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out +++ b/test/JDBC/expected/parallel_query/test_dynamic_local_vars.out @@ -1309,7 +1309,6 @@ int ~~END~~ - select set_config('babelfishpg_tsql.explain_timing', 'off', false); GO ~~START~~ @@ -1562,5 +1561,907 @@ on ~~END~~ +drop table local_var_tst +GO + +create table ident_tst(id_num INT IDENTITY(1, 1), b varchar(10)) +GO + +insert into ident_tst values ('test') +GO +~~ROW COUNT: 1~~ + + +declare @a int = 1 +select @a = @@IDENTITY +select @a +select 1 where @a = @@IDENTITY +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +-- additional testing for update with dynamic variables +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +set QUOTED_IDENTIFIER on +GO + +declare @i varchar(100) +update local_var_tst set id = id + 10, @i = cast("xmax" as varchar(100)) +select 1 where @i IS NOT NULL +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +set QUOTED_IDENTIFIER off +GO + +select * from local_var_tst order by id; +GO +~~START~~ +int +11 +12 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- long identifier with update +declare @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx int +update local_var_tst set id =10, @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx = id +select @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +10 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- @@ variables +declare @@incnjkdnc int +update local_var_tst set id =10, @@incnjkdnc = id +select @@incnjkdnc +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +10 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int +update local_var_tst set id = id + 2, @i = id * 5; +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +20 +~~END~~ + + +select * from local_var_tst order by id; +GO +~~START~~ +int +3 +4 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int; +update local_var_tst set id =10, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +0#!# +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +0#!#10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j) +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j); +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = @j * 2 +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +20#!#10 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +2 +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +1 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1 +update local_var_tst set id = @i, @i += id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +3 +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +1 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i VARCHAR(200) = '' +update local_var_tst set id = id * 2, @i = @i + cast(id as varchar(20)) +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +24 +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +2 +4 +~~END~~ + + +-- @i should be NULL as no row passes the qual condition +declare @i int +update local_var_tst set id =10, @i = id * 5 where id = 1 +select @i +GO +~~START~~ +int + +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +2 +4 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 5 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +5 +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +1 +2 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int +set @i = 0 +update local_var_tst set id = @i, @i = id * 5 +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +0 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +0 +0 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- trim is re-written by antlr +declare @i varchar(200) +select @i = '' +update local_var_tst set id = @i, @i = TRIM(@i + cast(id as varchar(10))); +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +00 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +0 +0 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +-- variables in the where clause should be treated as const +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +200 +~~END~~ + + +select * from local_var_tst order by id; +GO +~~START~~ +int +2 +100 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = @@IDENTITY +select @i +select 1 where @i = @@IDENTITY +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +100 +100 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE PARTITION FUNCTION RangePF1 ( INT ) +AS RANGE RIGHT FOR VALUES (10, 100, 1000) ; +GO + +declare @i int = -1; +SELECT @i = $PARTITION.RangePF1 (10); +select @i +update local_var_tst set id = @i, @i = $PARTITION.RangePF1 (10); +select @i +GO +~~START~~ +int +2 +~~END~~ + +~~ROW COUNT: 2~~ + +~~START~~ +int +2 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +2 +2 +~~END~~ + + +DROP PARTITION FUNCTION RangePF1 +GO + +CREATE PROCEDURE var_with_procedure (@i int, @a numeric(10,4) OUTPUT) AS +BEGIN + update local_var_tst set id = @i * 2, @a = id * 5 where id = @i + select @a +END; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @input int = 1, @res int; +exec var_with_procedure @input, @res +select @res +GO +~~ROW COUNT: 1~~ + +~~START~~ +numeric +10.0000 +~~END~~ + +~~START~~ +int + +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +2 +~~END~~ + + +declare @input int = 2, @a int; +exec var_with_procedure @input, @a +select @a +GO +~~ROW COUNT: 2~~ + +~~START~~ +numeric +20.0000 +~~END~~ + +~~START~~ +int + +~~END~~ + + +DROP PROCEDURE var_with_procedure; +GO + +DROP TABLE local_var_tst +GO + +create table local_var_tst_1 (id int) +GO + +insert into local_var_tst_1 values (1) +insert into local_var_tst_1 values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +create unique index idx_local_var_tst_1 on local_var_tst_1(id) +GO + + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '0', false); +SELECT set_config('enable_seqscan', '0', false); +GO +~~START~~ +text +on +~~END~~ + +~~START~~ +text +off +~~END~~ + +~~START~~ +text +off +~~END~~ + + +declare @i int = 1 +update local_var_tst_1 set id = @i, @i = id * 5 where id = 1 +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +5 +~~END~~ + + +declare @i int = 1 +update local_var_tst_1 set id = 10 output deleted.id where id = 1 +select @i +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '1', false); +SELECT set_config('enable_seqscan', '1', false); +GO +~~START~~ +text +on +~~END~~ + +~~START~~ +text +on +~~END~~ + +~~START~~ +text +on +~~END~~ + + +DROP TABLE local_var_tst_1 +GO + +CREATE TABLE update_test_tbl ( + age int, + fname char(10), + lname char(10), + city nchar(20) +) +GO + +TRUNCATE TABLE update_test_tbl +GO + +INSERT INTO update_test_tbl(age, fname, lname, city) +VALUES (50, 'fname1', 'lname1', 'london'), + (34, 'fname2', 'lname2', 'paris'), + (35, 'fname3', 'lname3', 'brussels'), + (90, 'fname4', 'lname4', 'new york'), + (26, 'fname5', 'lname5', 'los angeles'), + (74, 'fname6', 'lname6', 'tokyo'), + (44, 'fname7', 'lname7', 'oslo'), + (19, 'fname8', 'lname8', 'hong kong'), + (61, 'fname9', 'lname9', 'shanghai'), + (29, 'fname10', 'lname10', 'mumbai') +GO +~~ROW COUNT: 10~~ + + +CREATE TABLE update_test_tbl2 ( + year int, + lname char(10), +) +GO + +TRUNCATE TABLE update_test_tbl2 +GO + +INSERT INTO update_test_tbl2(year, lname) +VALUES (51, 'lname1'), + (34, 'lname3'), + (25, 'lname8'), + (95, 'lname9'), + (36, 'lname10') +GO +~~ROW COUNT: 5~~ + + +UPDATE update_test_tbl SET fname = 'fname13' +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +GO +~~ROW COUNT: 2~~ + + +declare @a varchar(4000) = ''; +UPDATE update_test_tbl SET fname = 'fname13', @a = @a + fname +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +select @a +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +fname13 fname13 +~~END~~ + + +DROP TABLE update_test_tbl2; +GO + +DROP TABLE update_test_tbl +GO + +drop table ident_tst +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i = id, @j = @i * 2, @i = @j +select @i, @j +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Babelfish does not support assignment to the same variable in SELECT. variable name: "@i")~~ + + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i += id, @j = @i * 2 +select @i, @j +GO +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +7#!#14 +~~END~~ + + +select * from local_var_tst order by id +GO +~~START~~ +int +3 +4 +~~END~~ + + drop table local_var_tst GO diff --git a/test/JDBC/expected/test_dynamic_local_vars.out b/test/JDBC/expected/test_dynamic_local_vars.out index de01fca282..82da9b4fd6 100644 --- a/test/JDBC/expected/test_dynamic_local_vars.out +++ b/test/JDBC/expected/test_dynamic_local_vars.out @@ -1309,7 +1309,6 @@ int ~~END~~ - select set_config('babelfishpg_tsql.explain_timing', 'off', false); GO ~~START~~ @@ -1551,5 +1550,907 @@ on ~~END~~ +drop table local_var_tst +GO + +create table ident_tst(id_num INT IDENTITY(1, 1), b varchar(10)) +GO + +insert into ident_tst values ('test') +GO +~~ROW COUNT: 1~~ + + +declare @a int = 1 +select @a = @@IDENTITY +select @a +select 1 where @a = @@IDENTITY +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +-- additional testing for update with dynamic variables +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +set QUOTED_IDENTIFIER on +GO + +declare @i varchar(100) +update local_var_tst set id = id + 10, @i = cast("xmax" as varchar(100)) +select 1 where @i IS NOT NULL +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +set QUOTED_IDENTIFIER off +GO + +select * from local_var_tst order by id; +GO +~~START~~ +int +11 +12 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- long identifier with update +declare @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx int +update local_var_tst set id =10, @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx = id +select @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +10 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- @@ variables +declare @@incnjkdnc int +update local_var_tst set id =10, @@incnjkdnc = id +select @@incnjkdnc +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +10 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int +update local_var_tst set id = id + 2, @i = id * 5; +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +20 +~~END~~ + + +select * from local_var_tst order by id; +GO +~~START~~ +int +3 +4 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int; +update local_var_tst set id =10, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +0#!# +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +0#!#10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j) +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j); +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = @j * 2 +select @i, @j +go +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +20#!#10 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +10 +10 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +2 +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +1 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1 +update local_var_tst set id = @i, @i += id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +3 +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +1 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i VARCHAR(200) = '' +update local_var_tst set id = id * 2, @i = @i + cast(id as varchar(20)) +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +24 +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +2 +4 +~~END~~ + + +-- @i should be NULL as no row passes the qual condition +declare @i int +update local_var_tst set id =10, @i = id * 5 where id = 1 +select @i +GO +~~START~~ +int + +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +2 +4 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 5 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +5 +~~END~~ + + +select * from local_var_tst order by id +go +~~START~~ +int +1 +2 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int +set @i = 0 +update local_var_tst set id = @i, @i = id * 5 +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +0 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +0 +0 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +-- trim is re-written by antlr +declare @i varchar(200) +select @i = '' +update local_var_tst set id = @i, @i = TRIM(@i + cast(id as varchar(10))); +select @i +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +00 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +0 +0 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + + +-- variables in the where clause should be treated as const +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = id * 2 where id = @i +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +200 +~~END~~ + + +select * from local_var_tst order by id; +GO +~~START~~ +int +2 +100 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = @@IDENTITY +select @i +select 1 where @i = @@IDENTITY +GO +~~ROW COUNT: 2~~ + +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +select * from local_var_tst +GO +~~START~~ +int +100 +100 +~~END~~ + + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +CREATE PARTITION FUNCTION RangePF1 ( INT ) +AS RANGE RIGHT FOR VALUES (10, 100, 1000) ; +GO + +declare @i int = -1; +SELECT @i = $PARTITION.RangePF1 (10); +select @i +update local_var_tst set id = @i, @i = $PARTITION.RangePF1 (10); +select @i +GO +~~START~~ +int +2 +~~END~~ + +~~ROW COUNT: 2~~ + +~~START~~ +int +2 +~~END~~ + + +select * from local_var_tst; +GO +~~START~~ +int +2 +2 +~~END~~ + + +DROP PARTITION FUNCTION RangePF1 +GO + +CREATE PROCEDURE var_with_procedure (@i int, @a numeric(10,4) OUTPUT) AS +BEGIN + update local_var_tst set id = @i * 2, @a = id * 5 where id = @i + select @a +END; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @input int = 1, @res int; +exec var_with_procedure @input, @res +select @res +GO +~~ROW COUNT: 1~~ + +~~START~~ +numeric +10.0000 +~~END~~ + +~~START~~ +int + +~~END~~ + + +select * from local_var_tst +go +~~START~~ +int +2 +2 +~~END~~ + + +declare @input int = 2, @a int; +exec var_with_procedure @input, @a +select @a +GO +~~ROW COUNT: 2~~ + +~~START~~ +numeric +20.0000 +~~END~~ + +~~START~~ +int + +~~END~~ + + +DROP PROCEDURE var_with_procedure; +GO + +DROP TABLE local_var_tst +GO + +create table local_var_tst_1 (id int) +GO + +insert into local_var_tst_1 values (1) +insert into local_var_tst_1 values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +create unique index idx_local_var_tst_1 on local_var_tst_1(id) +GO + + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '0', false); +SELECT set_config('enable_seqscan', '0', false); +GO +~~START~~ +text +on +~~END~~ + +~~START~~ +text +off +~~END~~ + +~~START~~ +text +off +~~END~~ + + +declare @i int = 1 +update local_var_tst_1 set id = @i, @i = id * 5 where id = 1 +select @i +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +5 +~~END~~ + + +declare @i int = 1 +update local_var_tst_1 set id = 10 output deleted.id where id = 1 +select @i +GO +~~START~~ +int +1 +~~END~~ + +~~START~~ +int +1 +~~END~~ + + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '1', false); +SELECT set_config('enable_seqscan', '1', false); +GO +~~START~~ +text +on +~~END~~ + +~~START~~ +text +on +~~END~~ + +~~START~~ +text +on +~~END~~ + + +DROP TABLE local_var_tst_1 +GO + +CREATE TABLE update_test_tbl ( + age int, + fname char(10), + lname char(10), + city nchar(20) +) +GO + +TRUNCATE TABLE update_test_tbl +GO + +INSERT INTO update_test_tbl(age, fname, lname, city) +VALUES (50, 'fname1', 'lname1', 'london'), + (34, 'fname2', 'lname2', 'paris'), + (35, 'fname3', 'lname3', 'brussels'), + (90, 'fname4', 'lname4', 'new york'), + (26, 'fname5', 'lname5', 'los angeles'), + (74, 'fname6', 'lname6', 'tokyo'), + (44, 'fname7', 'lname7', 'oslo'), + (19, 'fname8', 'lname8', 'hong kong'), + (61, 'fname9', 'lname9', 'shanghai'), + (29, 'fname10', 'lname10', 'mumbai') +GO +~~ROW COUNT: 10~~ + + +CREATE TABLE update_test_tbl2 ( + year int, + lname char(10), +) +GO + +TRUNCATE TABLE update_test_tbl2 +GO + +INSERT INTO update_test_tbl2(year, lname) +VALUES (51, 'lname1'), + (34, 'lname3'), + (25, 'lname8'), + (95, 'lname9'), + (36, 'lname10') +GO +~~ROW COUNT: 5~~ + + +UPDATE update_test_tbl SET fname = 'fname13' +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +GO +~~ROW COUNT: 2~~ + + +declare @a varchar(4000) = ''; +UPDATE update_test_tbl SET fname = 'fname13', @a = @a + fname +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +select @a +GO +~~ROW COUNT: 2~~ + +~~START~~ +varchar +fname13 fname13 +~~END~~ + + +DROP TABLE update_test_tbl2; +GO + +DROP TABLE update_test_tbl +GO + +drop table ident_tst +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO +~~ROW COUNT: 1~~ + +~~ROW COUNT: 1~~ + + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i = id, @j = @i * 2, @i = @j +select @i, @j +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Babelfish does not support assignment to the same variable in SELECT. variable name: "@i")~~ + + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i += id, @j = @i * 2 +select @i, @j +GO +~~ROW COUNT: 2~~ + +~~START~~ +int#!#int +7#!#14 +~~END~~ + + +select * from local_var_tst order by id +GO +~~START~~ +int +3 +4 +~~END~~ + + drop table local_var_tst GO diff --git a/test/JDBC/input/test_dynamic_local_vars.sql b/test/JDBC/input/test_dynamic_local_vars.sql index be95f21e41..3253d2d84c 100644 --- a/test/JDBC/input/test_dynamic_local_vars.sql +++ b/test/JDBC/input/test_dynamic_local_vars.sql @@ -712,7 +712,6 @@ select @i = id * 2 from local_var_tst where id = @i select @i GO - select set_config('babelfishpg_tsql.explain_timing', 'off', false); GO @@ -819,3 +818,461 @@ GO drop table local_var_tst GO + +create table ident_tst(id_num INT IDENTITY(1, 1), b varchar(10)) +GO + +insert into ident_tst values ('test') +GO + +declare @a int = 1 +select @a = @@IDENTITY +select @a +select 1 where @a = @@IDENTITY +GO + +-- additional testing for update with dynamic variables +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + + +set QUOTED_IDENTIFIER on +GO + +declare @i varchar(100) +update local_var_tst set id = id + 10, @i = cast("xmax" as varchar(100)) +select 1 where @i IS NOT NULL +GO + +set QUOTED_IDENTIFIER off +GO + +select * from local_var_tst order by id; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +-- long identifier with update +declare @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx int +update local_var_tst set id =10, @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx = id +select @incnjkdncjknxdjnkxnknvjkdfjvbdfbvjbdfhjbvjdbfvkjbdnjnlkanjfnvjnjfdlsahdnuejncdiebnjcnjksndjnjxndjcx +GO + +select * from local_var_tst +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +-- @@ variables +declare @@incnjkdnc int +update local_var_tst set id =10, @@incnjkdnc = id +select @@incnjkdnc +GO + +select * from local_var_tst +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int +update local_var_tst set id = id + 2, @i = id * 5; +select @i +GO + +select * from local_var_tst order by id; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int, @j int; +update local_var_tst set id =10, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go + +select * from local_var_tst; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = case when @j =0 then 1 else 0 end; +select @i, @j +go + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j) +select @i +GO + +select * from local_var_tst; +GO + +declare @i int, @j int = 0 +update local_var_tst set id =10, @i = charindex('a','a',@j); +select @i +GO + +select * from local_var_tst; +GO + +declare @i int, @j int; +update local_var_tst set id = 10, @j = id, @i = @j * 2 +select @i, @j +go + +select * from local_var_tst; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 2 where id = @i +select @i +GO + +select * from local_var_tst +go + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int = 1 +update local_var_tst set id = @i, @i += id * 2 where id = @i +select @i +GO + +select * from local_var_tst +go + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i VARCHAR(200) = '' +update local_var_tst set id = id * 2, @i = @i + cast(id as varchar(20)) +select @i +GO + +select * from local_var_tst order by id +go + +-- @i should be NULL as no row passes the qual condition +declare @i int +update local_var_tst set id =10, @i = id * 5 where id = 1 +select @i +GO + +select * from local_var_tst order by id +go + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + + +declare @i int = 1 +update local_var_tst set id = @i, @i = id * 5 where id = @i +select @i +GO + +select * from local_var_tst order by id +go + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int +set @i = 0 +update local_var_tst set id = @i, @i = id * 5 +select @i +GO + +select * from local_var_tst; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +-- trim is re-written by antlr +declare @i varchar(200) +select @i = '' +update local_var_tst set id = @i, @i = TRIM(@i + cast(id as varchar(10))); +select @i +GO + +select * from local_var_tst; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +-- variables in the where clause should be treated as const + +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = id * 2 where id = @i +select @i +GO + +select * from local_var_tst order by id; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int = 1; +update local_var_tst set id = @i * 100, @i = @@IDENTITY +select @i +select 1 where @i = @@IDENTITY +GO + +select * from local_var_tst +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +CREATE PARTITION FUNCTION RangePF1 ( INT ) +AS RANGE RIGHT FOR VALUES (10, 100, 1000) ; +GO + +declare @i int = -1; +SELECT @i = $PARTITION.RangePF1 (10); +select @i +update local_var_tst set id = @i, @i = $PARTITION.RangePF1 (10); +select @i +GO + +select * from local_var_tst; +GO + +DROP PARTITION FUNCTION RangePF1 +GO + +CREATE PROCEDURE var_with_procedure (@i int, @a numeric(10,4) OUTPUT) AS +BEGIN + update local_var_tst set id = @i * 2, @a = id * 5 where id = @i + select @a +END; +GO + +TRUNCATE table local_var_tst +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @input int = 1, @res int; +exec var_with_procedure @input, @res +select @res +GO + +select * from local_var_tst +go + +declare @input int = 2, @a int; +exec var_with_procedure @input, @a +select @a +GO + +DROP PROCEDURE var_with_procedure; +GO + +DROP TABLE local_var_tst +GO + +create table local_var_tst_1 (id int) +GO + +insert into local_var_tst_1 values (1) +insert into local_var_tst_1 values (2) +GO + +create unique index idx_local_var_tst_1 on local_var_tst_1(id) +GO + + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '0', false); +SELECT set_config('enable_seqscan', '0', false); +GO + +declare @i int = 1 +update local_var_tst_1 set id = @i, @i = id * 5 where id = 1 +select @i +GO + +declare @i int = 1 +update local_var_tst_1 set id = 10 output deleted.id where id = 1 +select @i +GO + +SELECT set_config('enable_indexscan', '1', false); +SELECT set_config('enable_indexonlyscan', '1', false); +SELECT set_config('enable_seqscan', '1', false); +GO + +DROP TABLE local_var_tst_1 +GO + +CREATE TABLE update_test_tbl ( + age int, + fname char(10), + lname char(10), + city nchar(20) +) +GO + +TRUNCATE TABLE update_test_tbl +GO + +INSERT INTO update_test_tbl(age, fname, lname, city) +VALUES (50, 'fname1', 'lname1', 'london'), + (34, 'fname2', 'lname2', 'paris'), + (35, 'fname3', 'lname3', 'brussels'), + (90, 'fname4', 'lname4', 'new york'), + (26, 'fname5', 'lname5', 'los angeles'), + (74, 'fname6', 'lname6', 'tokyo'), + (44, 'fname7', 'lname7', 'oslo'), + (19, 'fname8', 'lname8', 'hong kong'), + (61, 'fname9', 'lname9', 'shanghai'), + (29, 'fname10', 'lname10', 'mumbai') +GO + +CREATE TABLE update_test_tbl2 ( + year int, + lname char(10), +) +GO + +TRUNCATE TABLE update_test_tbl2 +GO + +INSERT INTO update_test_tbl2(year, lname) +VALUES (51, 'lname1'), + (34, 'lname3'), + (25, 'lname8'), + (95, 'lname9'), + (36, 'lname10') +GO + +UPDATE update_test_tbl SET fname = 'fname13' +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +GO + +declare @a varchar(4000) = ''; +UPDATE update_test_tbl SET fname = 'fname13', @a = @a + fname +FROM update_test_tbl t1 +INNER JOIN update_test_tbl2 t2 +ON t1.lname = t2.lname +WHERE year > 50 +select @a +GO + +DROP TABLE update_test_tbl2; +GO + +DROP TABLE update_test_tbl +GO + +drop table ident_tst +GO + +create table local_var_tst (id int) +GO + +insert into local_var_tst values (1) +insert into local_var_tst values (2) +GO + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i = id, @j = @i * 2, @i = @j +select @i, @j +GO + +declare @i int = 0, @j int +update local_var_tst set id = id + 2, @i += id, @j = @i * 2 +select @i, @j +GO + +select * from local_var_tst order by id +GO + +drop table local_var_tst +GO