Commit 5518c320 authored by Rucha Deodhar's avatar Rucha Deodhar

MDEV-23178: Qualified asterisk not supported in INSERT .. RETURNING

Analysis: When we have INSERT/REPLACE returning with qualified asterisk in the
RETURNING clause, '*' is not resolved properly because of wrong context.
context->table_list is NULL or has incorrect table because context->table_list
has tables from the FROM clause. For INSERT/REPLACE...SELECT...RETURNING,
context->table_list has table we are inserting from. While in other
INSERT/REPLACE syntax, context->table_list is NULL because there is no FROM
clause.
Fix: If filling fields instead of '*' for qualified asterisk in RETURNING,
use first_name_resolution_table for correct resolution of item.
parent 091743c6
...@@ -89,6 +89,9 @@ total val1 id1 && id1 id1 UPPER(val1) f(id1) ...@@ -89,6 +89,9 @@ total val1 id1 && id1 id1 UPPER(val1) f(id1)
ANALYZE INSERT INTO t1(id1,val1) VALUES(13,'l') RETURNING *; ANALYZE INSERT INTO t1(id1,val1) VALUES(13,'l') RETURNING *;
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL 1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL
INSERT INTO t1(id1,val1) VALUES(14,'m') RETURNING t1.*;
id1 val1
14 m
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
# #
# Multiple values in one insert statement...RETURNING # Multiple values in one insert statement...RETURNING
...@@ -182,6 +185,9 @@ id val1 id1 && id1 id1|id1 UPPER(val1) f(id1) ...@@ -182,6 +185,9 @@ id val1 id1 && id1 id1|id1 UPPER(val1) f(id1)
ANALYZE INSERT INTO t1 VALUES(25,'a'),(26,'b') RETURNING *; ANALYZE INSERT INTO t1 VALUES(25,'a'),(26,'b') RETURNING *;
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL 1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL
ANALYZE INSERT INTO t1 VALUES(27,'c'),(28,'d') RETURNING t1.*;
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL
# #
# INSERT...ON DUPLICATE KEY UPDATE...RETURNING # INSERT...ON DUPLICATE KEY UPDATE...RETURNING
# #
...@@ -250,10 +256,14 @@ ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE ...@@ -250,10 +256,14 @@ ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE
val='k' RETURNING *; val='k' RETURNING *;
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
1 INSERT ins_duplicate ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL 1 INSERT ins_duplicate ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL
INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE
val='l' RETURNING ins_duplicate.*;
id val
2 l
SELECT * FROM ins_duplicate; SELECT * FROM ins_duplicate;
id val id val
1 a 1 a
2 k 2 l
3 c 3 c
4 d 4 d
# #
...@@ -327,6 +337,9 @@ total val1 id1 && id1 id1|id1 UPPER(val1) f(id1) ...@@ -327,6 +337,9 @@ total val1 id1 && id1 id1|id1 UPPER(val1) f(id1)
ANALYZE INSERT INTO t1 SET id1=12, val1='l' RETURNING *; ANALYZE INSERT INTO t1 SET id1=12, val1='l' RETURNING *;
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL 1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL
INSERT INTO t1 SET id1= 13, val1= 'm' RETURNING t1.*;
id1 val1
13 m
SELECT * FROM t1; SELECT * FROM t1;
id1 val1 id1 val1
1 a 1 a
...@@ -339,6 +352,7 @@ id1 val1 ...@@ -339,6 +352,7 @@ id1 val1
8 n 8 n
26 Z 26 Z
12 l 12 l
13 m
# #
# INSERT...SELECT...RETURNING # INSERT...SELECT...RETURNING
# #
...@@ -372,6 +386,7 @@ id1 val1 ...@@ -372,6 +386,7 @@ id1 val1
8 n 8 n
26 Z 26 Z
12 l 12 l
13 m
EXECUTE stmt; EXECUTE stmt;
(SELECT id1 FROM t1 WHERE val1='b') (SELECT id1 FROM t1 WHERE val1='b')
2 2
...@@ -407,6 +422,7 @@ id2 val2 ...@@ -407,6 +422,7 @@ id2 val2
5 e 5 e
26 Z 26 Z
12 l 12 l
13 m
Warnings: Warnings:
Warning 1062 Duplicate entry '1' for key 'PRIMARY' Warning 1062 Duplicate entry '1' for key 'PRIMARY'
Warning 1062 Duplicate entry '2' for key 'PRIMARY' Warning 1062 Duplicate entry '2' for key 'PRIMARY'
...@@ -430,6 +446,18 @@ id2 val2 ...@@ -430,6 +446,18 @@ id2 val2
5 e 5 e
26 Z 26 Z
12 l 12 l
13 m
TRUNCATE TABLE t2;
INSERT INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING t2.*;
id2 val2
1 a
INSERT INTO t2 SELECT t1.* FROM t1 WHERE id1=2 RETURNING t2.*;
id2 val2
2 b
SELECT * FROM t2;
id2 val2
1 a
2 b
DROP TABLE t1; DROP TABLE t1;
DROP TABLE t2; DROP TABLE t2;
DROP TABLE ins_duplicate; DROP TABLE ins_duplicate;
...@@ -460,6 +488,8 @@ t1 WHERE id1=1) ...@@ -460,6 +488,8 @@ t1 WHERE id1=1)
5 6 5 6
INSERT INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2); INSERT INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
INSERT INTO t2 (id2, val2) VALUES (6,'f') RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
# #
# Multiple rows in single insert statement # Multiple rows in single insert statement
# #
...@@ -481,6 +511,8 @@ t1 WHERE id1=1) ...@@ -481,6 +511,8 @@ t1 WHERE id1=1)
12 13 12 13
INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2); INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
# #
# INSERT ... SET # INSERT ... SET
# #
...@@ -501,6 +533,8 @@ WHERE id1=1) ...@@ -501,6 +533,8 @@ WHERE id1=1)
5 6 5 6
INSERT INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2); INSERT INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
INSERT INTO t2 SET id2=5, val2='f' RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
# #
# INSERT...ON DUPLICATE KEY UPDATE # INSERT...ON DUPLICATE KEY UPDATE
# #
...@@ -525,6 +559,9 @@ ERROR 42S22: Unknown column 'id2' in 'field list' ...@@ -525,6 +559,9 @@ ERROR 42S22: Unknown column 'id2' in 'field list'
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b'
RETURNING (SELECT id FROM ins_duplicate); RETURNING (SELECT id FROM ins_duplicate);
ERROR HY000: Table 'ins_duplicate' is specified twice, both as a target for 'INSERT' and as a separate source for data ERROR HY000: Table 'ins_duplicate' is specified twice, both as a target for 'INSERT' and as a separate source for data
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b'
RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
# #
# INSERT...SELECT # INSERT...SELECT
# #
...@@ -544,6 +581,8 @@ ERROR 21000: Operand should contain 1 column(s) ...@@ -544,6 +581,8 @@ ERROR 21000: Operand should contain 1 column(s)
INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id2 FROM t2); id2 FROM t2);
ERROR 21000: Subquery returns more than 1 row ERROR 21000: Subquery returns more than 1 row
INSERT INTO t2(id2,val2) SELECT t1.* FROM t1 WHERE id1=2 RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
# #
# TRIGGER # TRIGGER
# #
......
...@@ -41,6 +41,7 @@ SELECT * FROM t1; ...@@ -41,6 +41,7 @@ SELECT * FROM t1;
INSERT INTO v1(id1, val1) VALUES (12, 'a') RETURNING id1+id1 as total,val1, INSERT INTO v1(id1, val1) VALUES (12, 'a') RETURNING id1+id1 as total,val1,
id1 && id1, id1 id1, UPPER(val1),f(id1); id1 && id1, id1 id1, UPPER(val1),f(id1);
ANALYZE INSERT INTO t1(id1,val1) VALUES(13,'l') RETURNING *; ANALYZE INSERT INTO t1(id1,val1) VALUES(13,'l') RETURNING *;
INSERT INTO t1(id1,val1) VALUES(14,'m') RETURNING t1.*;
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
--echo # --echo #
...@@ -68,6 +69,7 @@ SELECT * FROM t1; ...@@ -68,6 +69,7 @@ SELECT * FROM t1;
INSERT INTO v1 VALUES(23,'y'),(24,'z') RETURNING id1 as id,val1, INSERT INTO v1 VALUES(23,'y'),(24,'z') RETURNING id1 as id,val1,
id1 && id1, id1|id1, UPPER(val1),f(id1); id1 && id1, id1|id1, UPPER(val1),f(id1);
ANALYZE INSERT INTO t1 VALUES(25,'a'),(26,'b') RETURNING *; ANALYZE INSERT INTO t1 VALUES(25,'a'),(26,'b') RETURNING *;
ANALYZE INSERT INTO t1 VALUES(27,'c'),(28,'d') RETURNING t1.*;
--echo # --echo #
--echo # INSERT...ON DUPLICATE KEY UPDATE...RETURNING --echo # INSERT...ON DUPLICATE KEY UPDATE...RETURNING
...@@ -101,6 +103,8 @@ val1='d' RETURNING id1+id1 AS total, val1, id1 && id1, id1|id1, UPPER(val1), ...@@ -101,6 +103,8 @@ val1='d' RETURNING id1+id1 AS total, val1, id1 && id1, id1|id1, UPPER(val1),
f(id1); f(id1);
ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE
val='k' RETURNING *; val='k' RETURNING *;
INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE
val='l' RETURNING ins_duplicate.*;
SELECT * FROM ins_duplicate; SELECT * FROM ins_duplicate;
--echo # --echo #
...@@ -130,6 +134,7 @@ EXPLAIN FORMAT="json" INSERT INTO t1 SET id1=11, val1='k' RETURNING val1; ...@@ -130,6 +134,7 @@ EXPLAIN FORMAT="json" INSERT INTO t1 SET id1=11, val1='k' RETURNING val1;
INSERT INTO v1 SET id1=26, val1='Z' RETURNING id1+id1 AS total,val1, INSERT INTO v1 SET id1=26, val1='Z' RETURNING id1+id1 AS total,val1,
id1 && id1, id1|id1, UPPER(val1),f(id1); id1 && id1, id1|id1, UPPER(val1),f(id1);
ANALYZE INSERT INTO t1 SET id1=12, val1='l' RETURNING *; ANALYZE INSERT INTO t1 SET id1=12, val1='l' RETURNING *;
INSERT INTO t1 SET id1= 13, val1= 'm' RETURNING t1.*;
SELECT * FROM t1; SELECT * FROM t1;
--echo # --echo #
...@@ -158,6 +163,10 @@ INSERT IGNORE INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING *; ...@@ -158,6 +163,10 @@ INSERT IGNORE INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING *;
INSERT IGNORE INTO v2 SELECT * FROM v1 RETURNING *; INSERT IGNORE INTO v2 SELECT * FROM v1 RETURNING *;
ANALYZE INSERT INTO t2 SELECT * FROM t1 WHERE id1=11 RETURNING *; ANALYZE INSERT INTO t2 SELECT * FROM t1 WHERE id1=11 RETURNING *;
SELECT * FROM t2; SELECT * FROM t2;
TRUNCATE TABLE t2;
INSERT INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING t2.*;
INSERT INTO t2 SELECT t1.* FROM t1 WHERE id1=2 RETURNING t2.*;
SELECT * FROM t2;
DROP TABLE t1; DROP TABLE t1;
DROP TABLE t2; DROP TABLE t2;
...@@ -190,6 +199,8 @@ INSERT INTO t2(id2,val2) VALUES(5,'e') RETURNING id2, (SELECT id1+id2 FROM ...@@ -190,6 +199,8 @@ INSERT INTO t2(id2,val2) VALUES(5,'e') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1); t1 WHERE id1=1);
--error ER_UPDATE_TABLE_USED --error ER_UPDATE_TABLE_USED
INSERT INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2); INSERT INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
INSERT INTO t2 (id2, val2) VALUES (6,'f') RETURNING t1.*;
--echo # --echo #
--echo # Multiple rows in single insert statement --echo # Multiple rows in single insert statement
...@@ -208,6 +219,8 @@ INSERT INTO t2 VALUES(11,'e'),(12,'f') RETURNING id2, (SELECT id1+id2 FROM ...@@ -208,6 +219,8 @@ INSERT INTO t2 VALUES(11,'e'),(12,'f') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1); t1 WHERE id1=1);
--error ER_UPDATE_TABLE_USED --error ER_UPDATE_TABLE_USED
INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2); INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING t1.*;
--echo # --echo #
--echo # INSERT ... SET --echo # INSERT ... SET
...@@ -226,6 +239,8 @@ INSERT INTO t2 SET id2=5, val2='e' RETURNING id2, (SELECT id1+id2 FROM t1 ...@@ -226,6 +239,8 @@ INSERT INTO t2 SET id2=5, val2='e' RETURNING id2, (SELECT id1+id2 FROM t1
WHERE id1=1); WHERE id1=1);
--error ER_UPDATE_TABLE_USED --error ER_UPDATE_TABLE_USED
INSERT INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2); INSERT INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
INSERT INTO t2 SET id2=5, val2='f' RETURNING t1.*;
--echo # --echo #
--echo # INSERT...ON DUPLICATE KEY UPDATE --echo # INSERT...ON DUPLICATE KEY UPDATE
...@@ -251,6 +266,9 @@ RETURNING id2, (SELECT id1+id FROM t1 WHERE id1=1); ...@@ -251,6 +266,9 @@ RETURNING id2, (SELECT id1+id FROM t1 WHERE id1=1);
--error ER_UPDATE_TABLE_USED --error ER_UPDATE_TABLE_USED
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b'
RETURNING (SELECT id FROM ins_duplicate); RETURNING (SELECT id FROM ins_duplicate);
--error ER_BAD_TABLE_ERROR
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b'
RETURNING t1.*;
--echo # --echo #
--echo # INSERT...SELECT --echo # INSERT...SELECT
...@@ -271,6 +289,8 @@ INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT ...@@ -271,6 +289,8 @@ INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT
--error ER_SUBQUERY_NO_1_ROW --error ER_SUBQUERY_NO_1_ROW
INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id2 FROM t2); id2 FROM t2);
--error ER_BAD_TABLE_ERROR
INSERT INTO t2(id2,val2) SELECT t1.* FROM t1 WHERE id1=2 RETURNING t1.*;
--echo # --echo #
--echo # TRIGGER --echo # TRIGGER
......
...@@ -33,9 +33,12 @@ EXECUTE stmt; ...@@ -33,9 +33,12 @@ EXECUTE stmt;
id1 (SELECT id2 FROM t2 WHERE val2='b') id1 (SELECT id2 FROM t2 WHERE val2='b')
1 2 1 2
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 (id1, val1) VALUES (1, 'g') RETURNING t1.*;
id1 val1
1 g
SELECT * FROM t1; SELECT * FROM t1;
id1 val1 id1 val1
1 f 1 g
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
# #
# Multiple values in one replace statement...RETURNING # Multiple values in one replace statement...RETURNING
...@@ -69,10 +72,14 @@ id1 (SELECT id2 FROM t2 WHERE val2='b') ...@@ -69,10 +72,14 @@ id1 (SELECT id2 FROM t2 WHERE val2='b')
1 2 1 2
2 2 2 2
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 VALUES (1,'u'),(2,'v') RETURNING t1.*;
id1 val1
1 u
2 v
SELECT * FROM t1; SELECT * FROM t1;
id1 val1 id1 val1
1 s 1 u
2 t 2 v
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
# #
# REPLACE...SET...RETURNING # REPLACE...SET...RETURNING
...@@ -101,9 +108,12 @@ EXECUTE stmt; ...@@ -101,9 +108,12 @@ EXECUTE stmt;
id1 (SELECT id2 FROM t2 WHERE val2='b') id1 (SELECT id2 FROM t2 WHERE val2='b')
3 2 3 2
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 SET id1=1, val1 = 'o' RETURNING t1.*;
id1 val1
1 o
SELECT * FROM t1; SELECT * FROM t1;
id1 val1 id1 val1
1 i 1 o
2 j 2 j
3 k 3 k
# #
...@@ -113,7 +123,7 @@ TRUNCATE TABLE t2; ...@@ -113,7 +123,7 @@ TRUNCATE TABLE t2;
REPLACE INTO t2(id2,val2) SELECT * FROM t1; REPLACE INTO t2(id2,val2) SELECT * FROM t1;
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING *; REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING *;
id2 val2 id2 val2
1 i 1 o
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING id2+id2 AS total, REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING id2+id2 AS total,
id2&&id2, id2|id2,UPPER(val2),f(id2); id2&&id2, id2|id2,UPPER(val2),f(id2);
total id2&&id2 id2|id2 UPPER(val2) f(id2) total id2&&id2 id2|id2 UPPER(val2) f(id2)
...@@ -122,7 +132,7 @@ REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT ...@@ -122,7 +132,7 @@ REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT
GROUP_CONCAT(val1) FROM t1 WHERE id1=1); GROUP_CONCAT(val1) FROM t1 WHERE id1=1);
(SELECT (SELECT
GROUP_CONCAT(val1) FROM t1 WHERE id1=1) GROUP_CONCAT(val1) FROM t1 WHERE id1=1)
i o
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT
GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1); GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1);
(SELECT (SELECT
...@@ -144,11 +154,109 @@ FROM t2 WHERE id2=0); ...@@ -144,11 +154,109 @@ FROM t2 WHERE id2=0);
(SELECT id1+id2 (SELECT id1+id2
FROM t2 WHERE id2=0) FROM t2 WHERE id2=0)
NULL NULL
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING t2.*;
id2 val2
2 j
SELECT * FROM t2; SELECT * FROM t2;
id2 val2 id2 val2
1 i 1 o
2 j 2 j
3 k 3 k
DROP TABLE t1; DROP TABLE t1;
DROP TABLE t2; DROP TABLE t2;
DROP FUNCTION f; DROP FUNCTION f;
#
# checking errors
#
CREATE TABLE t1(id1 INT,val1 VARCHAR(1));
CREATE TABLE t2(id2 INT,val2 VARCHAR(1));
REPLACE INTO t1 VALUES(1,'a'),(2,'b'),(3,'c');
#
# SIMLPE REPLACE STATEMENT
#
REPLACE INTO t2(id2,val2) VALUES(1,'a') RETURNING id1;
ERROR 42S22: Unknown column 'id1' in 'field list'
REPLACE INTO t2(id2,val2) values(2,'b') RETURNING SUM(id2);
ERROR HY000: Invalid use of group function
REPLACE INTO t2(id2,val2) VALUES(3,'c') RETURNING (SELECT id1 FROM t1);
ERROR 21000: Subquery returns more than 1 row
REPLACE INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t1);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t2);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2(id2,val2) VALUES(5,'e') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1);
id2 (SELECT id1+id2 FROM
t1 WHERE id1=1)
5 6
REPLACE INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
REPLACE INTO t2 (id2, val2) VALUES (6,'f') RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
#
# Multiple rows in single insert statement
#
REPLACE INTO t2 VALUES(1,'a'),(2,'b') RETURNING id1;
ERROR 42S22: Unknown column 'id1' in 'field list'
REPLACE INTO t2 VALUES(3,'c'),(4,'d') RETURNING MAX(id2);
ERROR HY000: Invalid use of group function
REPLACE INTO t2 VALUES(5,'c'),(6,'f') RETURNING (SELECT id1 FROM t1);
ERROR 21000: Subquery returns more than 1 row
REPLACE INTO t2 VALUES(7,'g'),(8,'h') RETURNING (SELECT * FROM t1);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2 VALUES(9,'g'),(10,'h') RETURNING (SELECT * FROM t2);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2 VALUES(11,'e'),(12,'f') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1);
id2 (SELECT id1+id2 FROM
t1 WHERE id1=1)
11 12
12 13
REPLACE INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
REPLACE INTO t2 VALUES(13,'f'),(14,'g') RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
#
# REPLACE ... SET
#
REPLACE INTO t2 SET id2=1, val2='a' RETURNING id1;
ERROR 42S22: Unknown column 'id1' in 'field list'
REPLACE INTO t2 SET id2=2, val2='b' RETURNING COUNT(id2);
ERROR HY000: Invalid use of group function
REPLACE INTO t2 SET id2=3, val2='c' RETURNING (SELECT id1 FROM t1);
ERROR 21000: Subquery returns more than 1 row
REPLACE INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t1);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t2);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2 SET id2=5, val2='e' RETURNING id2, (SELECT id1+id2 FROM t1
WHERE id1=1);
id2 (SELECT id1+id2 FROM t1
WHERE id1=1)
5 6
REPLACE INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2);
ERROR HY000: Table 't2' is specified twice, both as a target for 'INSERT' and as a separate source for data
REPLACE INTO t2 SET id2=5, val2='f' RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
#
# REPLACE...SELECT
#
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=1 RETURNING id1;
ERROR 42S22: Unknown column 'id1' in 'field list'
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING MAX(id2);
ERROR HY000: Invalid use of group function
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id1 FROM t1);
ERROR 21000: Subquery returns more than 1 row
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
* FROM t1);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT
* FROM t2);
ERROR 21000: Operand should contain 1 column(s)
REPLACE INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id2 FROM t2);
ERROR 21000: Subquery returns more than 1 row
REPLACE INTO t2(id2,val2) SELECT t1.* FROM t1 WHERE id1=2 RETURNING t1.*;
ERROR 42S02: Unknown table 'test.t1'
DROP TABLE t1,t2;
...@@ -28,6 +28,7 @@ PREPARE stmt FROM "REPLACE INTO t1 (id1,val1) VALUES (1,'f') RETURNING ...@@ -28,6 +28,7 @@ PREPARE stmt FROM "REPLACE INTO t1 (id1,val1) VALUES (1,'f') RETURNING
id1,(SELECT id2 FROM t2 WHERE val2='b')"; id1,(SELECT id2 FROM t2 WHERE val2='b')";
EXECUTE stmt; EXECUTE stmt;
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 (id1, val1) VALUES (1, 'g') RETURNING t1.*;
SELECT * FROM t1; SELECT * FROM t1;
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
...@@ -46,6 +47,7 @@ PREPARE stmt FROM "REPLACE INTO t1 VALUES (1,'s'),(2,'t') RETURNING id1, ...@@ -46,6 +47,7 @@ PREPARE stmt FROM "REPLACE INTO t1 VALUES (1,'s'),(2,'t') RETURNING id1,
(SELECT id2 FROM t2 WHERE val2='b')"; (SELECT id2 FROM t2 WHERE val2='b')";
EXECUTE stmt; EXECUTE stmt;
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 VALUES (1,'u'),(2,'v') RETURNING t1.*;
SELECT * FROM t1; SELECT * FROM t1;
TRUNCATE TABLE t1; TRUNCATE TABLE t1;
...@@ -64,6 +66,8 @@ PREPARE stmt FROM "REPLACE INTO t1 SET id1=3, val1='k' RETURNING id1, ...@@ -64,6 +66,8 @@ PREPARE stmt FROM "REPLACE INTO t1 SET id1=3, val1='k' RETURNING id1,
(SELECT id2 FROM t2 WHERE val2='b')"; (SELECT id2 FROM t2 WHERE val2='b')";
EXECUTE stmt; EXECUTE stmt;
DEALLOCATE PREPARE stmt; DEALLOCATE PREPARE stmt;
REPLACE INTO t1 SET id1=1, val1 = 'o' RETURNING t1.*;
SELECT * FROM t1; SELECT * FROM t1;
--echo # --echo #
...@@ -86,8 +90,103 @@ REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT id1+id2 ...@@ -86,8 +90,103 @@ REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT id1+id2
FROM t1 WHERE id1=1); FROM t1 WHERE id1=1);
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT id1+id2 REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT id1+id2
FROM t2 WHERE id2=0); FROM t2 WHERE id2=0);
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING t2.*;
SELECT * FROM t2; SELECT * FROM t2;
DROP TABLE t1; DROP TABLE t1;
DROP TABLE t2; DROP TABLE t2;
DROP FUNCTION f; DROP FUNCTION f;
--echo #
--echo # checking errors
--echo #
CREATE TABLE t1(id1 INT,val1 VARCHAR(1));
CREATE TABLE t2(id2 INT,val2 VARCHAR(1));
REPLACE INTO t1 VALUES(1,'a'),(2,'b'),(3,'c');
--echo #
--echo # SIMLPE REPLACE STATEMENT
--echo #
--error ER_BAD_FIELD_ERROR
REPLACE INTO t2(id2,val2) VALUES(1,'a') RETURNING id1;
--error ER_INVALID_GROUP_FUNC_USE
REPLACE INTO t2(id2,val2) values(2,'b') RETURNING SUM(id2);
--error ER_SUBQUERY_NO_1_ROW
REPLACE INTO t2(id2,val2) VALUES(3,'c') RETURNING (SELECT id1 FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t2);
REPLACE INTO t2(id2,val2) VALUES(5,'e') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1);
--error ER_UPDATE_TABLE_USED
REPLACE INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
REPLACE INTO t2 (id2, val2) VALUES (6,'f') RETURNING t1.*;
--echo #
--echo # Multiple rows in single insert statement
--echo #
--error ER_BAD_FIELD_ERROR
REPLACE INTO t2 VALUES(1,'a'),(2,'b') RETURNING id1;
--error ER_INVALID_GROUP_FUNC_USE
REPLACE INTO t2 VALUES(3,'c'),(4,'d') RETURNING MAX(id2);
--error ER_SUBQUERY_NO_1_ROW
REPLACE INTO t2 VALUES(5,'c'),(6,'f') RETURNING (SELECT id1 FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2 VALUES(7,'g'),(8,'h') RETURNING (SELECT * FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2 VALUES(9,'g'),(10,'h') RETURNING (SELECT * FROM t2);
REPLACE INTO t2 VALUES(11,'e'),(12,'f') RETURNING id2, (SELECT id1+id2 FROM
t1 WHERE id1=1);
--error ER_UPDATE_TABLE_USED
REPLACE INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
REPLACE INTO t2 VALUES(13,'f'),(14,'g') RETURNING t1.*;
--echo #
--echo # REPLACE ... SET
--echo #
--error ER_BAD_FIELD_ERROR
REPLACE INTO t2 SET id2=1, val2='a' RETURNING id1;
--error ER_INVALID_GROUP_FUNC_USE
REPLACE INTO t2 SET id2=2, val2='b' RETURNING COUNT(id2);
--error ER_SUBQUERY_NO_1_ROW
REPLACE INTO t2 SET id2=3, val2='c' RETURNING (SELECT id1 FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t2);
REPLACE INTO t2 SET id2=5, val2='e' RETURNING id2, (SELECT id1+id2 FROM t1
WHERE id1=1);
--error ER_UPDATE_TABLE_USED
REPLACE INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2);
--error ER_BAD_TABLE_ERROR
REPLACE INTO t2 SET id2=5, val2='f' RETURNING t1.*;
--echo #
--echo # REPLACE...SELECT
--echo #
--error ER_BAD_FIELD_ERROR
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=1 RETURNING id1;
--error ER_INVALID_GROUP_FUNC_USE
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING MAX(id2);
--error ER_SUBQUERY_NO_1_ROW
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id1 FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
* FROM t1);
--error ER_OPERAND_COLUMNS
REPLACE INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT
* FROM t2);
--error ER_SUBQUERY_NO_1_ROW
REPLACE INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT
id2 FROM t2);
--error ER_BAD_TABLE_ERROR
REPLACE INTO t2(id2,val2) SELECT t1.* FROM t1 WHERE id1=2 RETURNING t1.*;
DROP TABLE t1,t2;
...@@ -3366,7 +3366,7 @@ class Item_ident :public Item_result_field ...@@ -3366,7 +3366,7 @@ class Item_ident :public Item_result_field
friend bool insert_fields(THD *thd, Name_resolution_context *context, friend bool insert_fields(THD *thd, Name_resolution_context *context,
const char *db_name, const char *db_name,
const char *table_name, List_iterator<Item> *it, const char *table_name, List_iterator<Item> *it,
bool any_privileges); bool any_privileges, bool returning_field);
}; };
......
...@@ -7492,7 +7492,7 @@ static bool setup_natural_join_row_types(THD *thd, ...@@ -7492,7 +7492,7 @@ static bool setup_natural_join_row_types(THD *thd,
****************************************************************************/ ****************************************************************************/
int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields, int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields,
List<Item> *sum_func_list, SELECT_LEX *select_lex) List<Item> *sum_func_list, SELECT_LEX *select_lex, bool returning_field)
{ {
Item *item; Item *item;
List_iterator<Item> it(fields); List_iterator<Item> it(fields);
...@@ -7532,7 +7532,7 @@ int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields, ...@@ -7532,7 +7532,7 @@ int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields,
else if (insert_fields(thd, ((Item_field*) item)->context, else if (insert_fields(thd, ((Item_field*) item)->context,
((Item_field*) item)->db_name.str, ((Item_field*) item)->db_name.str,
((Item_field*) item)->table_name.str, &it, ((Item_field*) item)->table_name.str, &it,
any_privileges, &select_lex->hidden_bit_fields)) any_privileges, &select_lex->hidden_bit_fields, returning_field))
{ {
if (arena) if (arena)
thd->restore_active_arena(arena, &backup); thd->restore_active_arena(arena, &backup);
...@@ -7678,7 +7678,7 @@ int setup_returning_fields(THD* thd, TABLE_LIST* table_list) ...@@ -7678,7 +7678,7 @@ int setup_returning_fields(THD* thd, TABLE_LIST* table_list)
if (!thd->lex->has_returning()) if (!thd->lex->has_returning())
return 0; return 0;
return setup_wild(thd, table_list, thd->lex->returning()->item_list, NULL, return setup_wild(thd, table_list, thd->lex->returning()->item_list, NULL,
thd->lex->returning()) thd->lex->returning(), true)
|| setup_fields(thd, Ref_ptr_array(), thd->lex->returning()->item_list, || setup_fields(thd, Ref_ptr_array(), thd->lex->returning()->item_list,
MARK_COLUMNS_READ, NULL, NULL, false); MARK_COLUMNS_READ, NULL, NULL, false);
} }
...@@ -8005,7 +8005,7 @@ bool get_key_map_from_key_list(key_map *map, TABLE *table, ...@@ -8005,7 +8005,7 @@ bool get_key_map_from_key_list(key_map *map, TABLE *table,
bool bool
insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, insert_fields(THD *thd, Name_resolution_context *context, const char *db_name,
const char *table_name, List_iterator<Item> *it, const char *table_name, List_iterator<Item> *it,
bool any_privileges, uint *hidden_bit_fields) bool any_privileges, uint *hidden_bit_fields, bool returning_field)
{ {
Field_iterator_table_ref field_iterator; Field_iterator_table_ref field_iterator;
bool found; bool found;
...@@ -8034,7 +8034,7 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name, ...@@ -8034,7 +8034,7 @@ insert_fields(THD *thd, Name_resolution_context *context, const char *db_name,
*/ */
TABLE_LIST *first= context->first_name_resolution_table; TABLE_LIST *first= context->first_name_resolution_table;
TABLE_LIST *TABLE_LIST::* next= &TABLE_LIST::next_name_resolution_table; TABLE_LIST *TABLE_LIST::* next= &TABLE_LIST::next_name_resolution_table;
if (table_name) if (table_name && !returning_field)
{ {
first= context->table_list; first= context->table_list;
next= &TABLE_LIST::next_local; next= &TABLE_LIST::next_local;
......
...@@ -176,11 +176,11 @@ bool fill_record_n_invoke_before_triggers(THD *thd, TABLE *table, ...@@ -176,11 +176,11 @@ bool fill_record_n_invoke_before_triggers(THD *thd, TABLE *table,
bool insert_fields(THD *thd, Name_resolution_context *context, bool insert_fields(THD *thd, Name_resolution_context *context,
const char *db_name, const char *table_name, const char *db_name, const char *table_name,
List_iterator<Item> *it, bool any_privileges, List_iterator<Item> *it, bool any_privileges,
uint *hidden_bit_fields); uint *hidden_bit_fields, bool returning_field);
void make_leaves_list(THD *thd, List<TABLE_LIST> &list, TABLE_LIST *tables, void make_leaves_list(THD *thd, List<TABLE_LIST> &list, TABLE_LIST *tables,
bool full_table_list, TABLE_LIST *boundary); bool full_table_list, TABLE_LIST *boundary);
int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields, int setup_wild(THD *thd, TABLE_LIST *tables, List<Item> &fields,
List<Item> *sum_func_list, SELECT_LEX *sl); List<Item> *sum_func_list, SELECT_LEX *sl, bool returning_field);
int setup_returning_fields(THD* thd, TABLE_LIST* table_list); int setup_returning_fields(THD* thd, TABLE_LIST* table_list);
bool setup_fields(THD *thd, Ref_ptr_array ref_pointer_array, bool setup_fields(THD *thd, Ref_ptr_array ref_pointer_array,
List<Item> &item, enum_column_usage column_usage, List<Item> &item, enum_column_usage column_usage,
......
...@@ -1268,7 +1268,7 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, ...@@ -1268,7 +1268,7 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num,
real_og_num+= select_lex->order_list.elements; real_og_num+= select_lex->order_list.elements;
DBUG_ASSERT(select_lex->hidden_bit_fields == 0); DBUG_ASSERT(select_lex->hidden_bit_fields == 0);
if (setup_wild(thd, tables_list, fields_list, &all_fields, select_lex)) if (setup_wild(thd, tables_list, fields_list, &all_fields, select_lex, false))
DBUG_RETURN(-1); DBUG_RETURN(-1);
if (select_lex->setup_ref_array(thd, real_og_num)) if (select_lex->setup_ref_array(thd, real_og_num))
DBUG_RETURN(-1); DBUG_RETURN(-1);
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment