Skip to content

Commit

Permalink
WL#6312: Referencing new row in INSERT ... VALUES ... ODKU statements
Browse files Browse the repository at this point in the history
Extend the INSERT .. VALUES/SET .. ON DUPLICATE KEY UPDATE syntax to
make it possible to declare an alias for the new row and columns in that
row, and refer to those aliases in the UPDATE expression.

The intention with this new feature is to be able to replace
VALUES(<expression>) clauses with row and column alias names.

INSERT .. SELECT .. ON DUPLICATE KEY UPDATE is not affected. Named
references to the old and new row are already possible in these
statements.

A derived table is created as the VALUES alias to resolve references to
the new rows from within update expressions. The field_translations of
the derived table are initialized with Item_insert_values, which resolve
directly to the insert_values buffer of the insert table.

The name of the table being updated is now a valid reference to the old
row in the scope of an ODKU clause. func_misc-bug19601730.test is thus
changed to allow such references.

Change-Id: I979b72f76e5fcf9f3af88acf1c8d06674179bd44
  • Loading branch information
Thomas Aven committed Aug 8, 2019
1 parent 7b9e3af commit c39355e
Show file tree
Hide file tree
Showing 11 changed files with 888 additions and 16 deletions.
299 changes: 299 additions & 0 deletions mysql-test/r/insert_update.result
Original file line number Diff line number Diff line change
Expand Up @@ -732,3 +732,302 @@ pk col
1 Carmen
2 Martin
DROP TABLE t1;
# WL#6312: Referencing new row in INSERT .. VALUES .. ON DUPLICATE KEY UPDATE.
CREATE TABLE t0(a INT PRIMARY KEY, b INT);
CREATE TABLE t1(x INT PRIMARY KEY, y INT);
# Allowed: Referencing VALUES from the update list.
INSERT INTO t0 VALUES (1, 3), (2, 3) AS n(a, b)
ON DUPLICATE KEY UPDATE b= t0.b + n.b;
SELECT * FROM t0;
a b
1 3
2 3
INSERT INTO t0 VALUES (1, 3), (2, 3) AS n(a, b)
ON DUPLICATE KEY UPDATE b= t0.b + n.b;
SELECT * FROM t0;
a b
1 6
2 6
# Allowed: Not naming columns for VALUES table.
INSERT INTO t0 VALUES (1, 5), (2, 7) AS n
ON DUPLICATE KEY UPDATE b= t0.b + n.b;
SELECT * FROM t0;
a b
1 11
2 13
# Not allowed: Naming the VALUES table the same as the table inserted into.
INSERT INTO t0 VALUES (1, 5), (2, 7) AS t0
ON DUPLICATE KEY UPDATE b= t0.a;
ERROR 42000: Not unique table/alias: 't0'
# Not allowed: Naming multiple VALUES columns the same.
INSERT INTO t0 VALUES (1, 5), (2, 7) AS n(a, a)
ON DUPLICATE KEY UPDATE b= t0.a;
ERROR 42S21: Duplicate column name 'a'
# Not allowed: Unequal number of columns in VALUES table and inserted rows.
INSERT INTO t0 VALUES (1, 5), (2, 7) AS n(a)
ON DUPLICATE KEY UPDATE b= t0.a;
ERROR HY000: In definition of view, derived table or common table expression, SELECT list and column names list have different column counts
# Allowed: Referencing VALUES table from within a subquery.
INSERT INTO t1 VALUES (1, 50), (2, 100);
INSERT INTO t0 VALUES (1, 10), (2, 20) AS n
ON DUPLICATE KEY UPDATE b= (SELECT y FROM t1 WHERE x = n.a);
SELECT * FROM t0;
a b
1 50
2 100
# Allowed: Overriding the VALUES table name from within a subquery.
INSERT INTO t0 VALUES (1, 10) AS n(a, b)
ON DUPLICATE KEY UPDATE b= 20 + (SELECT n.y FROM t1 AS n WHERE n.x = t0.a);
SELECT * FROM t0;
a b
1 70
2 100
# Allowed: VALUES table name overriding table names.
CREATE TABLE n(a INT, b INT);
INSERT INTO t0 VALUES (1, 10) AS n(a, b)
ON DUPLICATE KEY UPDATE b= n.b;
SELECT * FROM t0;
a b
1 10
2 100
# Allowed: FROM clause in subquery overriding VALUES table name.
INSERT INTO n VALUES (1, 50);
INSERT INTO t0 VALUES (1, 20) AS n(a, b)
ON DUPLICATE KEY UPDATE b= (SELECT n.b FROM n);
SELECT * FROM t0;
a b
1 50
2 100
# Allowed: Discrepancy between specified insert columns and column names of VALUES table.
CREATE TABLE t2(a INT, b INT PRIMARY KEY, c INT);
INSERT INTO t2 VALUES (1, 10, 100);
INSERT INTO t2(b, c) VALUES (10, 20) AS n(a, b)
ON DUPLICATE KEY UPDATE c= n.b;
SELECT * FROM t2;
a b c
1 10 20
# Allowed: Using the «INSERT .. SET» syntax.
DROP TABLE t0;
CREATE TABLE t0(a INT PRIMARY KEY, b INT);
INSERT INTO t0 VALUES (1, 10);
INSERT INTO t0 SET a=1, b=20 AS n
ON DUPLICATE KEY UPDATE b= n.b;
SELECT * FROM t0;
a b
1 20
# Allowed: Referring to the VALUES table from inside functions.
DROP TABLE t1;
CREATE TABLE t1(a BIGINT UNSIGNED PRIMARY KEY, b BIGINT UNSIGNED);
INSERT INTO t1 VALUES (45, 1) AS n
ON DUPLICATE KEY UPDATE b= IF(n.b > t1.b, n.b, t1.b);
SELECT * FROM t1;
a b
45 1
INSERT INTO t1 VALUES (45, 2) AS n
ON DUPLICATE KEY UPDATE b= IF(n.b > t1.b, n.b, t1.b);
SELECT * FROM t1;
a b
45 2
INSERT INTO t1 VALUES (45, 1) AS n
ON DUPLICATE KEY UPDATE b= IF(n.b > t1.b, n.b, t1.b);
SELECT * FROM t1;
a b
45 2
# Allowed: Using ODKU when inserting into a view.
DROP TABLE t1;
CREATE TABLE t1(a INT PRIMARY KEY DEFAULT 3, b INT);
CREATE VIEW v AS SELECT b FROM t1;
INSERT INTO t1 VALUES(3, 2);
INSERT INTO v VALUES(3) AS n
ON DUPLICATE KEY UPDATE b= n.b;
SELECT * FROM t1;
a b
3 3
SELECT * FROM v;
b
3
# Allowed: Creating a VALUES alias with no ODKU statement.
DROP TABLE t1;
CREATE TABLE t1(a INT PRIMARY KEY, b INT);
INSERT INTO t1 VALUES(1, 10) as n;
SELECT * FROM t1;
a b
1 10
# Not allowed: Referencing the VALUES table inside the VALUES clause.
INSERT INTO t1 VALUES(n.a, 10) as n
ON DUPLICATE KEY UPDATE b= n.b;
ERROR 42S22: Unknown column 'n.a' in 'field list'
# If a table reference within an update expression does not find the
# column in the VALUES table, it should look further in outer contexts.
DROP TABLE n;
CREATE TABLE n(x INT, y INT);
DROP TABLE t0;
CREATE TABLE t0(a INT PRIMARY KEY, b INT);
DELETE FROM t0;
INSERT INTO t0 VALUES(1, 10);
INSERT INTO n VALUES(1, 11);
INSERT INTO t0 VALUES(1, 19) as n(a, b)
ON DUPLICATE KEY UPDATE b= (SELECT n.y FROM n);
SELECT * FROM t0;
a b
1 11
# Allowed: Referring to the old row of the insert table from within an
# ODKU update expression.
DELETE FROM t0;
INSERT INTO t0 VALUES(1, 10);
INSERT INTO t0 VALUES(2, 20);
INSERT INTO t0 VALUES(2, 29) as n
ON DUPLICATE KEY UPDATE b= t0.b+1;
SELECT * FROM t0;
a b
1 10
2 21
DROP TABLE t0;
DROP TABLE t1;
DROP TABLE t2;
DROP TABLE n;
DROP VIEW v;
# WL#6312: Referencing new row in INSERT .. VALUES .. ON DUPLICATE KEY UPDATE.
# Compare old and new syntax (VALUES() vs. AS new) for regressions.
# binlog_unsafe.test. More than one unique key.
# Old syntax.
CREATE TABLE insert_2_keys (a INT UNIQUE KEY, b INT UNIQUE KEY);
INSERT INTO insert_2_keys values (1, 1);
INSERT INTO insert_2_keys VALUES (1, 2)
ON DUPLICATE KEY UPDATE a= VALUES(a) + 10, b= VALUES(b) + 10;
SELECT * FROM insert_2_keys;
a b
11 12
DROP TABLE insert_2_keys;
# New syntax.
CREATE TABLE insert_2_keys (a INT UNIQUE KEY, b INT UNIQUE KEY);
INSERT INTO insert_2_keys values (1, 1);
INSERT INTO insert_2_keys VALUES (1, 2) AS n
ON DUPLICATE KEY UPDATE a= n.a + 10, b= n.b + 10;
SELECT * FROM insert_2_keys;
a b
11 12
DROP TABLE insert_2_keys;
# json_functions.inc. JSON should work with INSERT .. ON DUPLICATE KEY UPDATE.
# Old syntax.
CREATE TABLE t(id INT PRIMARY KEY, j JSON);
INSERT INTO t VALUES (1, '[1]')
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("a", VALUES(j));
SELECT * FROM t;
id j
1 [1]
INSERT INTO t VALUES (1, '[1,2]')
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("ab", VALUES(j));
SELECT * FROM t;
id j
1 {"ab": [1, 2]}
INSERT INTO t VALUES (1, '[1,2,3]')
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("abc", VALUES(j));
SELECT * FROM t;
id j
1 {"abc": [1, 2, 3]}
DROP TABLE t;
# New syntax.
CREATE TABLE t(id INT PRIMARY KEY, j JSON);
INSERT INTO t VALUES (1, '[1]') AS n
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("a", n.j);
SELECT * FROM t;
id j
1 [1]
INSERT INTO t VALUES (1, '[1,2]') AS n
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("ab", n.j);
SELECT * FROM t;
id j
1 {"ab": [1, 2]}
INSERT INTO t VALUES (1, '[1,2,3]') AS n
ON DUPLICATE KEY UPDATE j = JSON_OBJECT("abc", n.j);
SELECT * FROM t;
id j
1 {"abc": [1, 2, 3]}
DROP TABLE t;
# errors.test. Subquery with VALUES table reference.
# Old syntax.
CREATE TABLE t1(a INT);
CREATE TABLE t2(a INT PRIMARY KEY, b INT);
INSERT INTO t1 VALUES (10);
INSERT INTO t2(a, b) VALUES (1, 0);
INSERT INTO t2(a, b) VALUES (1, 0)
ON DUPLICATE KEY UPDATE b= (SELECT VALUES(a) + 2 FROM t1);
SELECT * FROM t2;
a b
1 NULL
DROP TABLE t1;
DROP TABLE t2;
# New syntax.
CREATE TABLE t1 (a INT);
CREATE TABLE t2(a INT PRIMARY KEY, b INT);
INSERT INTO t1 VALUES (10);
INSERT INTO t2(a, b) VALUES (1, 0);
INSERT INTO t2(a, b) VALUES (1, 0) AS n
ON DUPLICATE KEY UPDATE b= (SELECT n.a + 2 FROM t1);
SELECT * FROM t2;
a b
1 3
DROP TABLE t1;
DROP TABLE t2;
# func_test.test. New syntax should work inside functions.
# Old syntax.
CREATE TABLE t1(a INT PRIMARY KEY, b INT);
INSERT INTO t1 VALUES (1, 2);
INSERT INTO t1 VALUES (1, 3)
ON DUPLICATE KEY UPDATE b= GREATEST(b, VALUES(b));
SELECT * FROM t1;
a b
1 3
DROP TABLE t1;
# New syntax.
CREATE TABLE t1(a INT PRIMARY KEY, b INT);
INSERT INTO t1 VALUES (1, 2);
INSERT INTO t1 VALUES (1, 3) AS n
ON DUPLICATE KEY UPDATE b= GREATEST(t1.b, n.b);
SELECT * FROM t1;
a b
1 3
DROP TABLE t1;
# type_blob-bug13901905_myisam.test. INSERT .. SET syntax should work with blobs.
# Old syntax.
CREATE TABLE t1 (a INT, b BLOB, UNIQUE KEY(a));
INSERT INTO t1 SET b='11', a=0
ON DUPLICATE KEY UPDATE b= VALUES(a), a= values(b);
INSERT INTO t1 SET b='11', a=0
ON DUPLICATE KEY UPDATE b= VALUES(a), a= values(b);
SELECT * FROM t1;
a b
11 0
DROP TABLE t1;
# New syntax
CREATE TABLE t1 (a INT, b BLOB, UNIQUE KEY(a));
INSERT INTO t1 SET b='11', a=0 AS n
ON DUPLICATE KEY UPDATE b= n.a, a= n.b;
INSERT INTO t1 SET b='11', a=0 AS n
ON DUPLICATE KEY UPDATE b= n.a, a= n.b;
SELECT * FROM t1;
a b
11 0
DROP TABLE t1;
# insert-bug25361251.test. Text fields should work.
# Old syntax.
CREATE TABLE t1(id INT NOT NULL, text1 TEXT, text2 TEXT, PRIMARY KEY (id));
INSERT INTO t1 VALUES (0, "x", "x"), (1, "y", "y");
INSERT INTO t1 (id, text1, text2) VALUES (0, "x", "y")
ON DUPLICATE KEY UPDATE text1 = VALUES(text1), text2 = VALUES(text2);
SELECT * FROM t1;
id text1 text2
0 x y
1 y y
DROP TABLE t1;
# New syntax.
CREATE TABLE t1(id INT NOT NULL, text1 TEXT, text2 TEXT, PRIMARY KEY (id));
INSERT INTO t1 VALUES (0, "x", "x"), (1, "y", "y");
INSERT INTO t1 (id, text1, text2) VALUES (0, "x", "y") AS n
ON DUPLICATE KEY UPDATE text1 = n.text1, text2 = n.text2;
SELECT * FROM t1;
id text1 text2
0 x y
1 y y
DROP TABLE t1;

0 comments on commit c39355e

Please sign in to comment.