diff --git a/mysql-test/main/insert_update_alias.result b/mysql-test/main/insert_update_alias.result new file mode 100644 index 0000000000000..bd0705b999ba9 --- /dev/null +++ b/mysql-test/main/insert_update_alias.result @@ -0,0 +1,95 @@ +# +# MDEV-29919: Support INSERT ... VALUES AS alias ON DUPLICATE KEY UPDATE +# +# +# Test setup +# +CREATE TABLE t1 ( +a INT PRIMARY KEY, +b INT, +c INT +); +# +# Basic INSERT AS alias ON DUPLICATE KEY UPDATE +# +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200) AS new +ON DUPLICATE KEY UPDATE b = new.b, c = new.c; +SELECT * FROM t1; +a b c +1 20 200 +# +# Multiple rows with AS alias +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200), (2, 30, 300) AS new +ON DUPLICATE KEY UPDATE b = new.b; +SELECT * FROM t1 ORDER BY a; +a b c +1 20 100 +2 30 300 +# +# Expression using alias columns +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 5, 50) AS new +ON DUPLICATE KEY UPDATE b = new.b + new.c, c = new.a * 10; +SELECT * FROM t1; +a b c +1 55 10 +# +# Mix of alias and table column references +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200) AS new +ON DUPLICATE KEY UPDATE b = new.b, c = t1.c + new.c; +SELECT * FROM t1; +a b c +1 20 300 +# +# INSERT without ON DUPLICATE KEY (alias should be ignored) +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100) AS new; +SELECT * FROM t1; +a b c +1 10 100 +# +# Different alias names +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 99, 999) AS inserted_row +ON DUPLICATE KEY UPDATE b = inserted_row.b, c = inserted_row.c; +SELECT * FROM t1; +a b c +1 99 999 +# +# Alias cannot be the same as the target table name +# +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 50, 500) AS t1 +ON DUPLICATE KEY UPDATE b = t1.b; +ERROR 42000: Not unique table/alias: 't1' +# +# Verify that AS alias is NOT allowed in REPLACE +# +REPLACE INTO t1 VALUES (1, 50, 500) AS new; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use +# +# Verify that AS alias is NOT allowed in CREATE ... VALUES +# +CREATE TABLE t2 AS VALUES (1, 10, 100) AS new; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use +# +# Cleanup +# +DROP TABLE t1; +DROP TABLE IF EXISTS t2; +# +# End of tests +# diff --git a/mysql-test/main/insert_update_alias.test b/mysql-test/main/insert_update_alias.test new file mode 100644 index 0000000000000..b26f4fa2fdf17 --- /dev/null +++ b/mysql-test/main/insert_update_alias.test @@ -0,0 +1,101 @@ +--echo # +--echo # MDEV-29919: Support INSERT ... VALUES AS alias ON DUPLICATE KEY UPDATE +--echo # + +# +# This test validates the row alias syntax for INSERT ON DUPLICATE KEY UPDATE +# which allows referencing inserted values using alias.column instead of VALUES(column) +# + +--echo # +--echo # Test setup +--echo # +CREATE TABLE t1 ( + a INT PRIMARY KEY, + b INT, + c INT +); + +--echo # +--echo # Basic INSERT AS alias ON DUPLICATE KEY UPDATE +--echo # +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200) AS new + ON DUPLICATE KEY UPDATE b = new.b, c = new.c; +SELECT * FROM t1; + +--echo # +--echo # Multiple rows with AS alias +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200), (2, 30, 300) AS new + ON DUPLICATE KEY UPDATE b = new.b; +SELECT * FROM t1 ORDER BY a; + +--echo # +--echo # Expression using alias columns +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 5, 50) AS new + ON DUPLICATE KEY UPDATE b = new.b + new.c, c = new.a * 10; +SELECT * FROM t1; + +--echo # +--echo # Mix of alias and table column references +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 20, 200) AS new + ON DUPLICATE KEY UPDATE b = new.b, c = t1.c + new.c; +SELECT * FROM t1; + +--echo # +--echo # INSERT without ON DUPLICATE KEY (alias should be ignored) +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100) AS new; +SELECT * FROM t1; + +--echo # +--echo # Different alias names +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +INSERT INTO t1 VALUES (1, 99, 999) AS inserted_row + ON DUPLICATE KEY UPDATE b = inserted_row.b, c = inserted_row.c; +SELECT * FROM t1; + +--echo # +--echo # Alias cannot be the same as the target table name +--echo # +TRUNCATE TABLE t1; +INSERT INTO t1 VALUES (1, 10, 100); +--error ER_NONUNIQ_TABLE +INSERT INTO t1 VALUES (1, 50, 500) AS t1 + ON DUPLICATE KEY UPDATE b = t1.b; + +--echo # +--echo # Verify that AS alias is NOT allowed in REPLACE +--echo # +--error ER_SYNTAX_ERROR +REPLACE INTO t1 VALUES (1, 50, 500) AS new; + +--echo # +--echo # Verify that AS alias is NOT allowed in CREATE ... VALUES +--echo # +--error ER_SYNTAX_ERROR +CREATE TABLE t2 AS VALUES (1, 10, 100) AS new; + +--echo # +--echo # Cleanup +--echo # +DROP TABLE t1; +--disable_warnings +DROP TABLE IF EXISTS t2; +--enable_warnings + +--echo # +--echo # End of tests +--echo # diff --git a/sql/item.cc b/sql/item.cc index 3170f7bf27b4d..3249c828051c3 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -6433,6 +6433,23 @@ bool Item_field::fix_fields(THD *thd, Item **reference) if (!field) // If field is not checked { TABLE_LIST *table_list; + + /* Handle INSERT ... VALUES (...) AS alias ON DUPLICATE KEY UPDATE */ + if (table_name.str && + table_name.streq(thd->lex->insert_values_alias)) + { + DBUG_ASSERT(thd->lex->duplicates == DUP_UPDATE); + Item_field *field_ref= new (thd->mem_root) + Item_field(thd, context, db_name, Lex_cstring_strlen(NULL), field_name); + if (!field_ref) + return TRUE; + Item_insert_value *ins_val= new (thd->mem_root) + Item_insert_value(thd, context, field_ref); + if (!ins_val) + return TRUE; + thd->change_item_tree(reference, ins_val); + return ins_val->fix_fields(thd, reference); + } /* In case of view, find_field_in_tables() write pointer to view field expression to 'reference', i.e. it substitute that expression instead diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index d0aa138abd633..10914c56cb95a 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -1825,6 +1825,17 @@ int mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, if (duplic == DUP_UPDATE) { + /* + The row alias for INSERT ... AS alias cannot be the same as the + target table name, as this would make column references ambiguous. + */ + if (thd->lex->insert_values_alias.str && + table_list->table_name.streq(thd->lex->insert_values_alias)) + { + my_error(ER_NONUNIQ_TABLE, MYF(0), thd->lex->insert_values_alias.str); + DBUG_RETURN(1); + } + /* it should be allocated before Item::fix_fields() */ if (table_list->set_insert_values(thd->mem_root)) DBUG_RETURN(1); diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 73d97861325ef..bf5ebf630e8bf 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1277,6 +1277,7 @@ void LEX::start(THD *thd_arg) part_info= 0; m_sql_cmd= NULL; duplicates= DUP_ERROR; + insert_values_alias= Lex_ident_sys(); spname= NULL; spcont= NULL; proc_list.first= 0; diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 02dbc584204d6..376f846548886 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -3454,6 +3454,8 @@ struct LEX: public Query_tables_list const char *clause_that_disallows_subselect; enum enum_duplicates duplicates; + /* Represents INSERT...VALUES as */ + Lex_ident_sys_st insert_values_alias; enum enum_tx_isolation tx_isolation; enum enum_ha_read_modes ha_read_mode; union { diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 7207f28bd062a..ed1bb0708674f 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -9035,13 +9035,32 @@ table_value_constructor: if (Lex->parsed_TVC_start()) MYSQL_YYABORT; } - values_list + values_list opt_values_row_alias { if (!($$= Lex->parsed_TVC_end())) MYSQL_YYABORT; } ; +/* + Optional alias for the row(s) being inserted. + Syntax: INSERT ... VALUES (...) AS alias + Used to reference new values in ON DUPLICATE KEY UPDATE clause. +*/ +opt_values_row_alias: + { + Lex->insert_values_alias= Lex_ident_sys(); + } + | AS ident + { + if (Lex->sql_command == SQLCOM_REPLACE || Lex->sql_command == SQLCOM_CREATE_TABLE) + { + my_yyabort_error((ER_SYNTAX_ERROR, MYF(0))); + } + Lex->insert_values_alias= $2; + } + ; + opt_hint_comment: /*empty */ { $$.init(); } | HINT_COMMENT { $$= $1; }