committed by
Sergei Golubchik
26 changed files with 1846 additions and 108 deletions
-
16mysql-test/main/features.result
-
14mysql-test/main/features.test
-
560mysql-test/main/insert_returning.result
-
280mysql-test/main/insert_returning.test
-
72mysql-test/main/insert_returning_datatypes.result
-
74mysql-test/main/insert_returning_datatypes.test
-
154mysql-test/main/replace_returning.result
-
93mysql-test/main/replace_returning.test
-
61mysql-test/main/replace_returning_datatypes.result
-
66mysql-test/main/replace_returning_datatypes.test
-
69mysql-test/main/replace_returning_err.result
-
86mysql-test/main/replace_returning_err.test
-
1sql/mysqld.cc
-
20sql/sql_base.cc
-
1sql/sql_base.h
-
12sql/sql_class.h
-
48sql/sql_delete.cc
-
3sql/sql_delete.h
-
131sql/sql_insert.cc
-
2sql/sql_insert.h
-
21sql/sql_lex.h
-
94sql/sql_parse.cc
-
2sql/sql_parse.h
-
4sql/sql_prepare.cc
-
35sql/sql_yacc.yy
-
35sql/sql_yacc_ora.yy
@ -0,0 +1,560 @@ |
|||
# Test for INSERT...RETURNING |
|||
CREATE TABLE t1(id1 INT PRIMARY KEY AUTO_INCREMENT, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY AUTO_INCREMENT, val2 VARCHAR(1)); |
|||
CREATE VIEW v1 AS SELECT id1, val1 FROM t1; |
|||
CREATE VIEW v2 AS SELECT id2,val2 FROM t2; |
|||
INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); |
|||
CREATE FUNCTION f(arg INT) RETURNS TEXT |
|||
BEGIN |
|||
RETURN (SELECT arg+arg); |
|||
END| |
|||
# |
|||
# Simple insert statement...RETURNING |
|||
# |
|||
INSERT INTO t1 (id1, val1) VALUES (1, 'a'); |
|||
INSERT INTO t1 (id1, val1) VALUES (2, 'b') RETURNING *; |
|||
id1 val1 |
|||
2 b |
|||
INSERT INTO t1 (id1, val1) VALUES (3, 'c') RETURNING id1+id1 as total,val1, |
|||
id1 && id1, id1 | id1, UPPER(val1),f(id1); |
|||
total val1 id1 && id1 id1 | id1 UPPER(val1) f(id1) |
|||
6 c 1 3 C 6 |
|||
INSERT INTO t1(id1,val1) VALUES (4,'d') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
INSERT INTO t1(id1,val1) VALUES(5,'e') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
PREPARE stmt FROM "INSERT INTO t1 (id1,val1) VALUES (6,'f') RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
DELETE FROM t1 WHERE id1=6; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO t1(id1,val1) VALUES (7,'h') RETURNING *; |
|||
id1 val1 |
|||
7 h |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 h |
|||
EXPLAIN INSERT INTO t1(id1,val1) VALUES (8,'i') RETURNING *; |
|||
id select_type table type possible_keys key key_len ref rows Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL |
|||
EXPLAIN EXTENDED INSERT INTO t1(id1,val1) VALUES(9,'j') RETURNING id1; |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL 100.00 NULL |
|||
EXPLAIN FORMAT="json" INSERT INTO t1(id1,val1) VALUES (10,'k') RETURNING id1; |
|||
EXPLAIN |
|||
{ |
|||
"query_block": { |
|||
"select_id": 1, |
|||
"table": { |
|||
"table_name": "t1" |
|||
} |
|||
} |
|||
} |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 h |
|||
INSERT INTO v1(id1, val1) VALUES (12, 'a') RETURNING id1+id1 as total,val1, |
|||
id1 && id1, id1 id1, UPPER(val1),f(id1); |
|||
total val1 id1 && id1 id1 UPPER(val1) f(id1) |
|||
24 a 1 12 A 24 |
|||
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 |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL |
|||
TRUNCATE TABLE t1; |
|||
# |
|||
# Multiple values in one insert statement...RETURNING |
|||
# |
|||
INSERT INTO t1 VALUES (1,'a'),(2,'b'); |
|||
INSERT INTO t1 VALUES (3,'c'),(4,'d') RETURNING *; |
|||
id1 val1 |
|||
3 c |
|||
4 d |
|||
INSERT INTO t1 VALUES (5,'e'),(6,'f') RETURNING id1 as id,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
id val1 id1 && id1 id1|id1 UPPER(val1) f(id1) |
|||
5 e 1 5 E 10 |
|||
6 f 1 6 F 12 |
|||
INSERT INTO t1 VALUES (7,'g'),(8,'h') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
a |
|||
INSERT INTO t1 VALUES (9,'i'),(10,'j') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
NULL |
|||
PREPARE stmt FROM "INSERT INTO t1 VALUES (11,'k'),(12,'l') RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
2 |
|||
DELETE FROM t1 WHERE val1 IN ('k','l'); |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 g |
|||
8 h |
|||
9 i |
|||
10 j |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
2 |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO t1 VALUES(13,'o'),(14,'p') RETURNING *; |
|||
id1 val1 |
|||
13 o |
|||
14 p |
|||
EXPLAIN INSERT INTO t1 VALUES(15,'q'),(16,'r') RETURNING *; |
|||
id select_type table type possible_keys key key_len ref rows Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL |
|||
EXPLAIN EXTENDED INSERT INTO t1 VALUES (17,'s'),(18,'t') RETURNING *; |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL 100.00 NULL |
|||
EXPLAIN FORMAT="json" INSERT INTO t1 VALUES(19,'u'),(20,'v') RETURNING id1; |
|||
EXPLAIN |
|||
{ |
|||
"query_block": { |
|||
"select_id": 1, |
|||
"table": { |
|||
"table_name": "t1" |
|||
} |
|||
} |
|||
} |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 g |
|||
8 h |
|||
9 i |
|||
10 j |
|||
12 l |
|||
11 k |
|||
13 o |
|||
14 p |
|||
INSERT INTO v1 VALUES(23,'y'),(24,'z') RETURNING id1 as id,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
id val1 id1 && id1 id1|id1 UPPER(val1) f(id1) |
|||
23 y 1 23 Y 46 |
|||
24 z 1 24 Z 48 |
|||
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 |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL |
|||
# |
|||
# INSERT...ON DUPLICATE KEY UPDATE...RETURNING |
|||
# |
|||
CREATE TABLE ins_duplicate (id INT PRIMARY KEY AUTO_INCREMENT, val VARCHAR(1)); |
|||
INSERT INTO ins_duplicate VALUES (1,'a'); |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING *; |
|||
id val |
|||
2 b |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='c' |
|||
RETURNING id+id AS total, val, id && id, id|id, UPPER(val),f(id); |
|||
total val id && id id|id UPPER(val) f(id) |
|||
4 c 1 2 C 4 |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='d' |
|||
RETURNING (SELECT GROUP_CONCAT(val2) FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) FROM t2 WHERE id2=1) |
|||
a |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='e' |
|||
RETURNING (SELECT GROUP_CONCAT(val2) FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
PREPARE stmt FROM "INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE |
|||
KEY UPDATE val='f' RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
SELECT * FROM t2; |
|||
id2 val2 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO ins_duplicate(id,val) VALUES (3,'c'),(4,'d') ON DUPLICATE |
|||
KEY UPDATE val='g' RETURNING id; |
|||
id |
|||
3 |
|||
4 |
|||
EXPLAIN INSERT INTO ins_duplicate(id,val) VALUES (2,'b') ON DUPLICATE KEY |
|||
UPDATE val='h' RETURNING val; |
|||
id select_type table type possible_keys key key_len ref rows Extra |
|||
1 INSERT ins_duplicate ALL NULL NULL NULL NULL NULL NULL |
|||
EXPLAIN EXTENDED INSERT INTO ins_duplicate(id,val) VALUES (2,'b') |
|||
ON DUPLICATE KEY UPDATE val='i' RETURNING val; |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 INSERT ins_duplicate ALL NULL NULL NULL NULL NULL 100.00 NULL |
|||
EXPLAIN FORMAT="json" INSERT INTO ins_duplicate(id,val) VALUES (2,'b') |
|||
ON DUPLICATE KEY UPDATE val='j' RETURNING val; |
|||
EXPLAIN |
|||
{ |
|||
"query_block": { |
|||
"select_id": 1, |
|||
"table": { |
|||
"table_name": "ins_duplicate" |
|||
} |
|||
} |
|||
} |
|||
INSERT INTO v1(id1, val1) VALUES (2,'d') ON DUPLICATE KEY UPDATE |
|||
val1='d' RETURNING id1+id1 AS total, val1, id1 && id1, id1|id1, UPPER(val1), |
|||
f(id1); |
|||
total val1 id1 && id1 id1|id1 UPPER(val1) f(id1) |
|||
4 d 1 2 D 4 |
|||
ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE |
|||
val='k' RETURNING *; |
|||
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 |
|||
SELECT * FROM ins_duplicate; |
|||
id val |
|||
1 a |
|||
2 k |
|||
3 c |
|||
4 d |
|||
# |
|||
# INSERT...SET...RETURNING |
|||
# |
|||
TRUNCATE TABLE t1; |
|||
INSERT INTO t1 SET id1= 1, val1= 'a'; |
|||
INSERT INTO t1 SET id1= 2, val1= 'b' RETURNING *; |
|||
id1 val1 |
|||
2 b |
|||
INSERT INTO t1 SET id1= 3, val1= 'c' RETURNING id1+id1 AS total,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
total val1 id1 && id1 id1|id1 UPPER(val1) f(id1) |
|||
6 c 1 3 C 6 |
|||
INSERT INTO t1 SET id1= 4, val1= 'd' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
INSERT INTO t1 SET id1= 5, val1='e' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
PREPARE stmt FROM "INSERT INTO t1 SET id1= 6, val1='f' RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
DELETE FROM t1 WHERE val1='f'; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
EXECUTE stmt; |
|||
(SELECT id2 FROM t2 WHERE val2='b') |
|||
2 |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT INTO t1 SET id1= 7, val1= 'g' RETURNING f(id1); |
|||
f(id1) |
|||
14 |
|||
INSERT INTO t1 SET val1= 'n' RETURNING *; |
|||
id1 val1 |
|||
8 n |
|||
INSERT IGNORE INTO t1 SET id1= 8, val1= 'h' RETURNING *; |
|||
id1 val1 |
|||
8 h |
|||
Warnings: |
|||
Warning 1062 Duplicate entry '8' for key 'PRIMARY' |
|||
EXPLAIN INSERT INTO t1 SET id1=9, val1='i' RETURNING id1; |
|||
id select_type table type possible_keys key key_len ref rows Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL |
|||
EXPLAIN EXTENDED INSERT INTO t1 SET id1=10, val1='j' RETURNING val1; |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL 100.00 NULL |
|||
EXPLAIN FORMAT="json" INSERT INTO t1 SET id1=11, val1='k' RETURNING val1; |
|||
EXPLAIN |
|||
{ |
|||
"query_block": { |
|||
"select_id": 1, |
|||
"table": { |
|||
"table_name": "t1" |
|||
} |
|||
} |
|||
} |
|||
INSERT INTO v1 SET id1=26, val1='Z' RETURNING id1+id1 AS total,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
total val1 id1 && id1 id1|id1 UPPER(val1) f(id1) |
|||
52 Z 1 26 Z 52 |
|||
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 |
|||
1 INSERT t1 ALL NULL NULL NULL NULL NULL NULL 100.00 100.00 NULL |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 g |
|||
8 n |
|||
26 Z |
|||
12 l |
|||
# |
|||
# INSERT...SELECT...RETURNING |
|||
# |
|||
TRUNCATE TABLE t2; |
|||
INSERT INTO t2(id2,val2) SELECT * FROM t1; |
|||
TRUNCATE TABLE t2; |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING *; |
|||
id2 val2 |
|||
1 a |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING id2+id2 AS total, |
|||
val2,id2 && id2, id2|id2, UPPER(val2),f(id2); |
|||
total val2 id2 && id2 id2|id2 UPPER(val2) f(id2) |
|||
4 b 1 2 B 4 |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1); |
|||
(SELECT GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1) |
|||
NULL |
|||
PREPARE stmt FROM "INSERT INTO t2 SELECT * FROM t1 WHERE id1=4 RETURNING (SELECT id1 FROM t1 WHERE val1='b')"; |
|||
EXECUTE stmt; |
|||
(SELECT id1 FROM t1 WHERE val1='b') |
|||
2 |
|||
DELETE FROM t2 WHERE id2=4; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 g |
|||
8 n |
|||
26 Z |
|||
12 l |
|||
EXECUTE stmt; |
|||
(SELECT id1 FROM t1 WHERE val1='b') |
|||
2 |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=6 RETURNING |
|||
(SELECT id1+id2 FROM t1 WHERE id1=1); |
|||
(SELECT id1+id2 FROM t1 WHERE id1=1) |
|||
7 |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=7 RETURNING f(id2); |
|||
f(id2) |
|||
14 |
|||
EXPLAIN INSERT INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING id2; |
|||
id select_type table type possible_keys key key_len ref rows Extra |
|||
1 PRIMARY t1 const PRIMARY PRIMARY 4 const 1 |
|||
EXPLAIN EXTENDED INSERT INTO t1 SELECT * FROM t1 WHERE id1=9 RETURNING val1; |
|||
id select_type table type possible_keys key key_len ref rows filtered Extra |
|||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables |
|||
EXPLAIN FORMAT="json" INSERT INTO t1 SELECT * FROM t1 WHERE id1=10 RETURNING val1; |
|||
EXPLAIN |
|||
{ |
|||
"query_block": { |
|||
"select_id": 1, |
|||
"table": { |
|||
"message": "Impossible WHERE noticed after reading const tables" |
|||
} |
|||
} |
|||
} |
|||
INSERT IGNORE INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING *; |
|||
id2 val2 |
|||
8 n |
|||
INSERT IGNORE INTO v2 SELECT * FROM v1 RETURNING *; |
|||
id2 val2 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
5 e |
|||
6 f |
|||
7 g |
|||
8 n |
|||
26 Z |
|||
12 l |
|||
Warnings: |
|||
Warning 1062 Duplicate entry '1' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '2' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '3' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '4' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '6' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '7' for key 'PRIMARY' |
|||
Warning 1062 Duplicate entry '8' for key 'PRIMARY' |
|||
ANALYZE INSERT INTO t2 SELECT * FROM t1 WHERE id1=11 RETURNING *; |
|||
id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra |
|||
1 PRIMARY NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL no matching row in const table |
|||
SELECT * FROM t2; |
|||
id2 val2 |
|||
1 a |
|||
2 b |
|||
3 c |
|||
4 d |
|||
6 f |
|||
7 g |
|||
8 n |
|||
5 e |
|||
26 Z |
|||
12 l |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP TABLE ins_duplicate; |
|||
# |
|||
# Error message test |
|||
# |
|||
CREATE TABLE t1(id1 INT,val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT,val2 VARCHAR(1)); |
|||
CREATE TABLE ins_duplicate (id INT PRIMARY KEY, val VARCHAR(1)); |
|||
INSERT INTO t1 VALUES(1,'a'),(2,'b'),(3,'c'); |
|||
# |
|||
# SIMLPE INSERT STATEMENT |
|||
# |
|||
INSERT INTO t2(id2,val2) VALUES(1,'a') RETURNING id1; |
|||
ERROR 42S22: Unknown column 'id1' in 'field list' |
|||
INSERT INTO t2(id2,val2) values(2,'b') RETURNING SUM(id2); |
|||
ERROR HY000: Invalid use of group function |
|||
INSERT INTO t2(id2,val2) VALUES(3,'c') RETURNING (SELECT id1 FROM t1); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
INSERT INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t1); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t2); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT 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 |
|||
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 |
|||
# |
|||
# Multiple rows in single insert statement |
|||
# |
|||
INSERT INTO t2 VALUES(1,'a'),(2,'b') RETURNING id1; |
|||
ERROR 42S22: Unknown column 'id1' in 'field list' |
|||
INSERT INTO t2 VALUES(3,'c'),(4,'d') RETURNING MAX(id2); |
|||
ERROR HY000: Invalid use of group function |
|||
INSERT INTO t2 VALUES(5,'c'),(6,'f') RETURNING (SELECT id1 FROM t1); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
INSERT INTO t2 VALUES(7,'g'),(8,'h') RETURNING (SELECT * FROM t1); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO t2 VALUES(9,'g'),(10,'h') RETURNING (SELECT * FROM t2); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT 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 |
|||
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 |
|||
# |
|||
# INSERT ... SET |
|||
# |
|||
INSERT INTO t2 SET id2=1, val2='a' RETURNING id1; |
|||
ERROR 42S22: Unknown column 'id1' in 'field list' |
|||
INSERT INTO t2 SET id2=2, val2='b' RETURNING COUNT(id2); |
|||
ERROR HY000: Invalid use of group function |
|||
INSERT INTO t2 SET id2=3, val2='c' RETURNING (SELECT id1 FROM t1); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
INSERT INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t1); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t2); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT 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 |
|||
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 |
|||
# |
|||
# INSERT...ON DUPLICATE KEY UPDATE |
|||
# |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING id1; |
|||
ERROR 42S22: Unknown column 'id1' in 'field list' |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING MAX(id); |
|||
ERROR HY000: Invalid use of group function |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT id1 FROM t1); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT * FROM t1); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT * FROM ins_duplicate); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING id2, (SELECT id1+id FROM t1 WHERE id1=1); |
|||
ERROR 42S22: Unknown column 'id2' in 'field list' |
|||
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
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 |
|||
# |
|||
# INSERT...SELECT |
|||
# |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=1 RETURNING id1; |
|||
ERROR 42S22: Unknown column 'id1' in 'field list' |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING MAX(id2); |
|||
ERROR HY000: Invalid use of group function |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
id1 FROM t1); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
* FROM t1); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT |
|||
* FROM t2); |
|||
ERROR 21000: Operand should contain 1 column(s) |
|||
INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
id2 FROM t2); |
|||
ERROR 21000: Subquery returns more than 1 row |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP TABLE ins_duplicate; |
|||
DROP VIEW v1; |
|||
DROP VIEW v2; |
|||
DROP FUNCTION f; |
@ -0,0 +1,280 @@ |
|||
--echo # Test for INSERT...RETURNING |
|||
|
|||
CREATE TABLE t1(id1 INT PRIMARY KEY AUTO_INCREMENT, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY AUTO_INCREMENT, val2 VARCHAR(1)); |
|||
CREATE VIEW v1 AS SELECT id1, val1 FROM t1; |
|||
CREATE VIEW v2 AS SELECT id2,val2 FROM t2; |
|||
INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); |
|||
|
|||
DELIMITER |; |
|||
|
|||
CREATE FUNCTION f(arg INT) RETURNS TEXT |
|||
BEGIN |
|||
RETURN (SELECT arg+arg); |
|||
END| |
|||
|
|||
DELIMITER ;| |
|||
|
|||
--echo # |
|||
--echo # Simple insert statement...RETURNING |
|||
--echo # |
|||
INSERT INTO t1 (id1, val1) VALUES (1, 'a'); |
|||
INSERT INTO t1 (id1, val1) VALUES (2, 'b') RETURNING *; |
|||
INSERT INTO t1 (id1, val1) VALUES (3, 'c') RETURNING id1+id1 as total,val1, |
|||
id1 && id1, id1 | id1, UPPER(val1),f(id1); |
|||
INSERT INTO t1(id1,val1) VALUES (4,'d') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
INSERT INTO t1(id1,val1) VALUES(5,'e') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "INSERT INTO t1 (id1,val1) VALUES (6,'f') RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DELETE FROM t1 WHERE id1=6; |
|||
SELECT * FROM t1; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO t1(id1,val1) VALUES (7,'h') RETURNING *; |
|||
SELECT * FROM t1; |
|||
EXPLAIN INSERT INTO t1(id1,val1) VALUES (8,'i') RETURNING *; |
|||
EXPLAIN EXTENDED INSERT INTO t1(id1,val1) VALUES(9,'j') RETURNING id1; |
|||
EXPLAIN FORMAT="json" INSERT INTO t1(id1,val1) VALUES (10,'k') RETURNING id1; |
|||
SELECT * FROM t1; |
|||
INSERT INTO v1(id1, val1) VALUES (12, 'a') RETURNING id1+id1 as total,val1, |
|||
id1 && id1, id1 id1, UPPER(val1),f(id1); |
|||
ANALYZE INSERT INTO t1(id1,val1) VALUES(13,'l') RETURNING *; |
|||
TRUNCATE TABLE t1; |
|||
|
|||
--echo # |
|||
--echo # Multiple values in one insert statement...RETURNING |
|||
--echo # |
|||
INSERT INTO t1 VALUES (1,'a'),(2,'b'); |
|||
INSERT INTO t1 VALUES (3,'c'),(4,'d') RETURNING *; |
|||
INSERT INTO t1 VALUES (5,'e'),(6,'f') RETURNING id1 as id,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
INSERT INTO t1 VALUES (7,'g'),(8,'h') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
INSERT INTO t1 VALUES (9,'i'),(10,'j') RETURNING(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "INSERT INTO t1 VALUES (11,'k'),(12,'l') RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DELETE FROM t1 WHERE val1 IN ('k','l'); |
|||
SELECT * FROM t1; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO t1 VALUES(13,'o'),(14,'p') RETURNING *; |
|||
EXPLAIN INSERT INTO t1 VALUES(15,'q'),(16,'r') RETURNING *; |
|||
EXPLAIN EXTENDED INSERT INTO t1 VALUES (17,'s'),(18,'t') RETURNING *; |
|||
EXPLAIN FORMAT="json" INSERT INTO t1 VALUES(19,'u'),(20,'v') RETURNING id1; |
|||
SELECT * FROM t1; |
|||
INSERT INTO v1 VALUES(23,'y'),(24,'z') RETURNING id1 as id,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
ANALYZE INSERT INTO t1 VALUES(25,'a'),(26,'b') RETURNING *; |
|||
|
|||
--echo # |
|||
--echo # INSERT...ON DUPLICATE KEY UPDATE...RETURNING |
|||
--echo # |
|||
CREATE TABLE ins_duplicate (id INT PRIMARY KEY AUTO_INCREMENT, val VARCHAR(1)); |
|||
INSERT INTO ins_duplicate VALUES (1,'a'); |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING *; |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='c' |
|||
RETURNING id+id AS total, val, id && id, id|id, UPPER(val),f(id); |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='d' |
|||
RETURNING (SELECT GROUP_CONCAT(val2) FROM t2 WHERE id2=1); |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='e' |
|||
RETURNING (SELECT GROUP_CONCAT(val2) FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE |
|||
KEY UPDATE val='f' RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
SELECT * FROM t2; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT IGNORE INTO ins_duplicate(id,val) VALUES (3,'c'),(4,'d') ON DUPLICATE |
|||
KEY UPDATE val='g' RETURNING id; |
|||
EXPLAIN INSERT INTO ins_duplicate(id,val) VALUES (2,'b') ON DUPLICATE KEY |
|||
UPDATE val='h' RETURNING val; |
|||
EXPLAIN EXTENDED INSERT INTO ins_duplicate(id,val) VALUES (2,'b') |
|||
ON DUPLICATE KEY UPDATE val='i' RETURNING val; |
|||
EXPLAIN FORMAT="json" INSERT INTO ins_duplicate(id,val) VALUES (2,'b') |
|||
ON DUPLICATE KEY UPDATE val='j' RETURNING val; |
|||
INSERT INTO v1(id1, val1) VALUES (2,'d') ON DUPLICATE KEY UPDATE |
|||
val1='d' RETURNING id1+id1 AS total, val1, id1 && id1, id1|id1, UPPER(val1), |
|||
f(id1); |
|||
ANALYZE INSERT INTO ins_duplicate(id,val) VALUES(2,'b') ON DUPLICATE KEY UPDATE |
|||
val='k' RETURNING *; |
|||
SELECT * FROM ins_duplicate; |
|||
|
|||
--echo # |
|||
--echo # INSERT...SET...RETURNING |
|||
--echo # |
|||
TRUNCATE TABLE t1; |
|||
INSERT INTO t1 SET id1= 1, val1= 'a'; |
|||
INSERT INTO t1 SET id1= 2, val1= 'b' RETURNING *; |
|||
INSERT INTO t1 SET id1= 3, val1= 'c' RETURNING id1+id1 AS total,val1, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
INSERT INTO t1 SET id1= 4, val1= 'd' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
INSERT INTO t1 SET id1= 5, val1='e' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "INSERT INTO t1 SET id1= 6, val1='f' RETURNING (SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DELETE FROM t1 WHERE val1='f'; |
|||
SELECT * FROM t1; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT INTO t1 SET id1= 7, val1= 'g' RETURNING f(id1); |
|||
INSERT INTO t1 SET val1= 'n' RETURNING *; |
|||
INSERT IGNORE INTO t1 SET id1= 8, val1= 'h' RETURNING *; |
|||
EXPLAIN INSERT INTO t1 SET id1=9, val1='i' RETURNING id1; |
|||
EXPLAIN EXTENDED INSERT INTO t1 SET id1=10, val1='j' RETURNING val1; |
|||
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, |
|||
id1 && id1, id1|id1, UPPER(val1),f(id1); |
|||
ANALYZE INSERT INTO t1 SET id1=12, val1='l' RETURNING *; |
|||
SELECT * FROM t1; |
|||
|
|||
--echo # |
|||
--echo # INSERT...SELECT...RETURNING |
|||
--echo # |
|||
TRUNCATE TABLE t2; |
|||
INSERT INTO t2(id2,val2) SELECT * FROM t1; |
|||
TRUNCATE TABLE t2; |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING *; |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING id2+id2 AS total, |
|||
val2,id2 && id2, id2|id2, UPPER(val2),f(id2); |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1); |
|||
PREPARE stmt FROM "INSERT INTO t2 SELECT * FROM t1 WHERE id1=4 RETURNING (SELECT id1 FROM t1 WHERE val1='b')"; |
|||
EXECUTE stmt; |
|||
DELETE FROM t2 WHERE id2=4; |
|||
SELECT * FROM t1; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=6 RETURNING |
|||
(SELECT id1+id2 FROM t1 WHERE id1=1); |
|||
INSERT INTO t2 SELECT * FROM t1 WHERE id1=7 RETURNING f(id2); |
|||
EXPLAIN INSERT INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING id2; |
|||
EXPLAIN EXTENDED INSERT INTO t1 SELECT * FROM t1 WHERE id1=9 RETURNING val1; |
|||
EXPLAIN FORMAT="json" INSERT INTO t1 SELECT * FROM t1 WHERE id1=10 RETURNING val1; |
|||
INSERT IGNORE INTO t2 SELECT * FROM t1 WHERE id1=8 RETURNING *; |
|||
INSERT IGNORE INTO v2 SELECT * FROM v1 RETURNING *; |
|||
ANALYZE INSERT INTO t2 SELECT * FROM t1 WHERE id1=11 RETURNING *; |
|||
SELECT * FROM t2; |
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP TABLE ins_duplicate; |
|||
|
|||
--echo # |
|||
--echo # Error message test |
|||
--echo # |
|||
|
|||
CREATE TABLE t1(id1 INT,val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT,val2 VARCHAR(1)); |
|||
CREATE TABLE ins_duplicate (id INT PRIMARY KEY, val VARCHAR(1)); |
|||
|
|||
INSERT INTO t1 VALUES(1,'a'),(2,'b'),(3,'c'); |
|||
|
|||
--echo # |
|||
--echo # SIMLPE INSERT STATEMENT |
|||
--echo # |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO t2(id2,val2) VALUES(1,'a') RETURNING id1; |
|||
--error ER_INVALID_GROUP_FUNC_USE |
|||
INSERT INTO t2(id2,val2) values(2,'b') RETURNING SUM(id2); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO t2(id2,val2) VALUES(3,'c') RETURNING (SELECT id1 FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2(id2,val2) VALUES(4,'d') RETURNING (SELECT * FROM t2); |
|||
INSERT INTO t2(id2,val2) VALUES(5,'e') RETURNING id2, (SELECT id1+id2 FROM |
|||
t1 WHERE id1=1); |
|||
--error ER_UPDATE_TABLE_USED |
|||
INSERT INTO t2(id2,val2) VALUES(5,'f') RETURNING (SELECT id2 FROM t2); |
|||
|
|||
--echo # |
|||
--echo # Multiple rows in single insert statement |
|||
--echo # |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO t2 VALUES(1,'a'),(2,'b') RETURNING id1; |
|||
--error ER_INVALID_GROUP_FUNC_USE |
|||
INSERT INTO t2 VALUES(3,'c'),(4,'d') RETURNING MAX(id2); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO t2 VALUES(5,'c'),(6,'f') RETURNING (SELECT id1 FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2 VALUES(7,'g'),(8,'h') RETURNING (SELECT * FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2 VALUES(9,'g'),(10,'h') RETURNING (SELECT * FROM t2); |
|||
INSERT INTO t2 VALUES(11,'e'),(12,'f') RETURNING id2, (SELECT id1+id2 FROM |
|||
t1 WHERE id1=1); |
|||
--error ER_UPDATE_TABLE_USED |
|||
INSERT INTO t2 VALUES(13,'f'),(14,'g') RETURNING (SELECT id2 FROM t2); |
|||
|
|||
--echo # |
|||
--echo # INSERT ... SET |
|||
--echo # |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO t2 SET id2=1, val2='a' RETURNING id1; |
|||
--error ER_INVALID_GROUP_FUNC_USE |
|||
INSERT INTO t2 SET id2=2, val2='b' RETURNING COUNT(id2); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO t2 SET id2=3, val2='c' RETURNING (SELECT id1 FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2 SET id2=4, val2='d' RETURNING (SELECT * FROM t2); |
|||
INSERT INTO t2 SET id2=5, val2='e' RETURNING id2, (SELECT id1+id2 FROM t1 |
|||
WHERE id1=1); |
|||
--error ER_UPDATE_TABLE_USED |
|||
INSERT INTO t2 SET id2=5, val2='f' RETURNING (SELECT id2 FROM t2); |
|||
|
|||
--echo # |
|||
--echo # INSERT...ON DUPLICATE KEY UPDATE |
|||
--echo # |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING id1; |
|||
--error ER_INVALID_GROUP_FUNC_USE |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING MAX(id); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT id1 FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT * FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO ins_duplicate VALUES (2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT * FROM ins_duplicate); |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING id2, (SELECT id1+id FROM t1 WHERE id1=1); |
|||
--error ER_UPDATE_TABLE_USED |
|||
INSERT INTO ins_duplicate VALUES(2,'b') ON DUPLICATE KEY UPDATE val='b' |
|||
RETURNING (SELECT id FROM ins_duplicate); |
|||
|
|||
--echo # |
|||
--echo # INSERT...SELECT |
|||
--echo # |
|||
--error ER_BAD_FIELD_ERROR |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=1 RETURNING id1; |
|||
--error ER_INVALID_GROUP_FUNC_USE |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING MAX(id2); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
id1 FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
* FROM t1); |
|||
--error ER_OPERAND_COLUMNS |
|||
INSERT INTO t2(id2, val2) SELECT * FROM t1 WHERE id1=2 RETURNING(SELECT |
|||
* FROM t2); |
|||
--error ER_SUBQUERY_NO_1_ROW |
|||
INSERT INTO t2(id2,val2) SELECT * FROM t1 WHERE id1=2 RETURNING (SELECT |
|||
id2 FROM t2); |
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP TABLE ins_duplicate; |
|||
DROP VIEW v1; |
|||
DROP VIEW v2; |
|||
DROP FUNCTION f; |
@ -0,0 +1,72 @@ |
|||
CREATE TABLE t1(num_int1 INT(2) PRIMARY KEY, |
|||
num_bit1 BIT(8), |
|||
num_float1 FLOAT(5,2), |
|||
num_double1 DOUBLE(5,2), |
|||
char_enum1 ENUM('A','B','C','D'), |
|||
char_set1 SET('a','b','c','d','e'), |
|||
str_varchar1 VARCHAR(2), |
|||
d1 DATE, |
|||
dt1 DATETIME, |
|||
ts1 TIMESTAMP, |
|||
y1 YEAR, |
|||
b1 BOOL); |
|||
CREATE TABLE t2(num_int2 INT(2) PRIMARY KEY, |
|||
num_bit2 BIT(8), |
|||
num_float2 FLOAT(5,2), |
|||
num_double2 DOUBLE(5,2), |
|||
char_enum2 ENUM('A','B','C','D'), |
|||
char_set2 SET('a','b','c','d','e'), |
|||
str_varchar2 VARCHAR(2), |
|||
d2 DATE, |
|||
dt2 DATETIME, |
|||
ts2 TIMESTAMP, |
|||
y2 YEAR, |
|||
b2 BOOL); |
|||
# |
|||
# SIMLPE INSERT STATEMENT |
|||
# |
|||
INSERT INTO t1(num_int1,num_bit1,num_float1,num_double1,char_enum1,char_set1, |
|||
str_varchar1, d1,dt1,ts1,y1,b1) VALUES(1,b'1000011', 123.45, 123.55, |
|||
'A','b,e', 'V','120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12', |
|||
2012,0) RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
1 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
# |
|||
# MULTIPLE ROWS IN SINGLE STATEMENT |
|||
# |
|||
INSERT INTO t1 VALUES(2,b'1000011', 123.45, 123.55, 'A','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0),(3,b'1000011', |
|||
123.45, 123.55, 'A','b,e', 'V','120314',"2012-04-19 13:08:22", |
|||
'2001-07-22 12:12:12',2012,1) RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
2 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
3 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 1 |
|||
# |
|||
# INSERT...SET...RETURNING |
|||
# |
|||
INSERT INTO t1 SET num_int1=4,num_bit1=b'1000011',num_float1=124.67, |
|||
num_double1=231.12,char_enum1='B',char_set1='a,d,e', |
|||
str_varchar1='AB',d1='120314',dt1="2012-04-19 13:08:22", |
|||
ts1='2001-07-22 12:12:1',y1=2014,b1=1 RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
4 C 124.67 231.12 B a,d,e AB 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:01 2014 1 |
|||
# |
|||
# INSERT...ON DUPLICATE KEY UPDATE |
|||
# |
|||
INSERT INTO t1 VALUES (5,b'1000011', 123.45, 123.55,'C','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0) |
|||
ON DUPLICATE KEY UPDATE num_float1=111.111 RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
5 C 123.45 123.55 C b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
# |
|||
# INSERT...SELECT...RETURNING |
|||
# |
|||
INSERT INTO t2 SELECT * FROM t1 RETURNING *; |
|||
num_int2 num_bit2 num_float2 num_double2 char_enum2 char_set2 str_varchar2 d2 dt2 ts2 y2 b2 |
|||
1 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
2 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
3 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 1 |
|||
4 C 124.67 231.12 B a,d,e AB 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:01 2014 1 |
|||
5 C 123.45 123.55 C b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
@ -0,0 +1,74 @@ |
|||
#Test for checking all dataypes are returned |
|||
|
|||
CREATE TABLE t1(num_int1 INT(2) PRIMARY KEY, |
|||
num_bit1 BIT(8), |
|||
num_float1 FLOAT(5,2), |
|||
num_double1 DOUBLE(5,2), |
|||
char_enum1 ENUM('A','B','C','D'), |
|||
char_set1 SET('a','b','c','d','e'), |
|||
str_varchar1 VARCHAR(2), |
|||
d1 DATE, |
|||
dt1 DATETIME, |
|||
ts1 TIMESTAMP, |
|||
y1 YEAR, |
|||
b1 BOOL); |
|||
|
|||
CREATE TABLE t2(num_int2 INT(2) PRIMARY KEY, |
|||
num_bit2 BIT(8), |
|||
num_float2 FLOAT(5,2), |
|||
num_double2 DOUBLE(5,2), |
|||
char_enum2 ENUM('A','B','C','D'), |
|||
char_set2 SET('a','b','c','d','e'), |
|||
str_varchar2 VARCHAR(2), |
|||
d2 DATE, |
|||
dt2 DATETIME, |
|||
ts2 TIMESTAMP, |
|||
y2 YEAR, |
|||
b2 BOOL); |
|||
|
|||
|
|||
--echo # |
|||
--echo # SIMLPE INSERT STATEMENT |
|||
--echo # |
|||
INSERT INTO t1(num_int1,num_bit1,num_float1,num_double1,char_enum1,char_set1, |
|||
str_varchar1, d1,dt1,ts1,y1,b1) VALUES(1,b'1000011', 123.45, 123.55, |
|||
'A','b,e', 'V','120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12', |
|||
2012,0) RETURNING *; |
|||
|
|||
|
|||
--echo # |
|||
--echo # MULTIPLE ROWS IN SINGLE STATEMENT |
|||
--echo # |
|||
INSERT INTO t1 VALUES(2,b'1000011', 123.45, 123.55, 'A','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0),(3,b'1000011', |
|||
123.45, 123.55, 'A','b,e', 'V','120314',"2012-04-19 13:08:22", |
|||
'2001-07-22 12:12:12',2012,1) RETURNING *; |
|||
|
|||
|
|||
|
|||
--echo # |
|||
--echo # INSERT...SET...RETURNING |
|||
--echo # |
|||
INSERT INTO t1 SET num_int1=4,num_bit1=b'1000011',num_float1=124.67, |
|||
num_double1=231.12,char_enum1='B',char_set1='a,d,e', |
|||
str_varchar1='AB',d1='120314',dt1="2012-04-19 13:08:22", |
|||
ts1='2001-07-22 12:12:1',y1=2014,b1=1 RETURNING *; |
|||
|
|||
|
|||
|
|||
--echo # |
|||
--echo # INSERT...ON DUPLICATE KEY UPDATE |
|||
--echo # |
|||
INSERT INTO t1 VALUES (5,b'1000011', 123.45, 123.55,'C','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0) |
|||
ON DUPLICATE KEY UPDATE num_float1=111.111 RETURNING *; |
|||
|
|||
|
|||
--echo # |
|||
--echo # INSERT...SELECT...RETURNING |
|||
--echo # |
|||
INSERT INTO t2 SELECT * FROM t1 RETURNING *; |
|||
|
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
@ -0,0 +1,154 @@ |
|||
# Test for REPLACE...RETURNING |
|||
CREATE TABLE t1(id1 INT PRIMARY KEY, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY, val2 VARCHAR(1)); |
|||
INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); |
|||
CREATE FUNCTION f(arg INT) RETURNS INT |
|||
BEGIN |
|||
RETURN (SELECT arg+arg); |
|||
END| |
|||
# |
|||
# Simple replace statement...RETURNING |
|||
# |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'a'); |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'b') RETURNING *; |
|||
id1 val1 |
|||
1 b |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'c') RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
total id1&&id1 id1|id1 UPPER(val1) f(id1) |
|||
2 1 1 C 2 |
|||
REPLACE INTO t1(id1,val1) VALUES (1,'d') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
REPLACE INTO t1(id1,val1) VALUES(1,'e') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
PREPARE stmt FROM "REPLACE INTO t1 (id1,val1) VALUES (1,'f') RETURNING |
|||
id1,(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
id1 (SELECT id2 FROM t2 WHERE val2='b') |
|||
1 2 |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 f |
|||
TRUNCATE TABLE t1; |
|||
# |
|||
# Multiple values in one replace statement...RETURNING |
|||
# |
|||
REPLACE INTO t1 VALUES (1,'a'),(2,'b'); |
|||
REPLACE INTO t1 VALUES (1,'c'),(2,'d') RETURNING *; |
|||
id1 val1 |
|||
1 c |
|||
2 d |
|||
REPLACE INTO t1 VALUES (1,'e'),(2,'f') RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
total id1&&id1 id1|id1 UPPER(val1) f(id1) |
|||
2 1 1 E 2 |
|||
4 1 2 F 4 |
|||
REPLACE INTO t1 VALUES (1,'o'),(2,'p') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
a |
|||
REPLACE INTO t1 VALUES (1,'q'),(2,'r') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
NULL |
|||
PREPARE stmt FROM "REPLACE INTO t1 VALUES (1,'s'),(2,'t') RETURNING id1, |
|||
(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
id1 (SELECT id2 FROM t2 WHERE val2='b') |
|||
1 2 |
|||
2 2 |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 s |
|||
2 t |
|||
TRUNCATE TABLE t1; |
|||
# |
|||
# REPLACE...SET...RETURNING |
|||
# |
|||
REPLACE INTO t1 SET id1=1, val1 = 'a'; |
|||
REPLACE INTO t1 SET id1=2, val1 = 'b' RETURNING *; |
|||
id1 val1 |
|||
2 b |
|||
REPLACE INTO t1 SET id1=3, val1 = 'c' RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
total id1&&id1 id1|id1 UPPER(val1) f(id1) |
|||
6 1 3 C 6 |
|||
REPLACE INTO t1 SET id1=1, val1 = 'i' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1) |
|||
a |
|||
REPLACE INTO t1 SET id1=2, val1='j' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
(SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1) |
|||
NULL |
|||
PREPARE stmt FROM "REPLACE INTO t1 SET id1=3, val1='k' RETURNING id1, |
|||
(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
id1 (SELECT id2 FROM t2 WHERE val2='b') |
|||
3 2 |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
id1 val1 |
|||
1 i |
|||
2 j |
|||
3 k |
|||
# |
|||
# REPLACE...SELECT...RETURNING |
|||
# |
|||
TRUNCATE TABLE t2; |
|||
REPLACE INTO t2(id2,val2) SELECT * FROM t1; |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING *; |
|||
id2 val2 |
|||
1 i |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING id2+id2 AS total, |
|||
id2&&id2, id2|id2,UPPER(val2),f(id2); |
|||
total id2&&id2 id2|id2 UPPER(val2) f(id2) |
|||
4 1 2 J 4 |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT |
|||
GROUP_CONCAT(val1) FROM t1 WHERE id1=1); |
|||
(SELECT |
|||
GROUP_CONCAT(val1) FROM t1 WHERE id1=1) |
|||
i |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT |
|||
GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1); |
|||
(SELECT |
|||
GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1) |
|||
NULL |
|||
PREPARE stmt FROM "REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING |
|||
id2,(SELECT id1 FROM t1 WHERE val1='b')"; |
|||
EXECUTE stmt; |
|||
id2 (SELECT id1 FROM t1 WHERE val1='b') |
|||
2 NULL |
|||
DEALLOCATE PREPARE stmt; |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT id1+id2 |
|||
FROM t1 WHERE id1=1); |
|||
(SELECT id1+id2 |
|||
FROM t1 WHERE id1=1) |
|||
4 |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT id1+id2 |
|||
FROM t2 WHERE id2=0); |
|||
(SELECT id1+id2 |
|||
FROM t2 WHERE id2=0) |
|||
NULL |
|||
SELECT * FROM t2; |
|||
id2 val2 |
|||
1 i |
|||
2 j |
|||
3 k |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP FUNCTION f; |
@ -0,0 +1,93 @@ |
|||
--echo # Test for REPLACE...RETURNING |
|||
|
|||
CREATE TABLE t1(id1 INT PRIMARY KEY, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY, val2 VARCHAR(1)); |
|||
INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); |
|||
|
|||
DELIMITER |; |
|||
|
|||
CREATE FUNCTION f(arg INT) RETURNS INT |
|||
BEGIN |
|||
RETURN (SELECT arg+arg); |
|||
END| |
|||
|
|||
DELIMITER ;| |
|||
|
|||
--echo # |
|||
--echo # Simple replace statement...RETURNING |
|||
--echo # |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'a'); |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'b') RETURNING *; |
|||
REPLACE INTO t1 (id1, val1) VALUES (1, 'c') RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
REPLACE INTO t1(id1,val1) VALUES (1,'d') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
REPLACE INTO t1(id1,val1) VALUES(1,'e') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "REPLACE INTO t1 (id1,val1) VALUES (1,'f') RETURNING |
|||
id1,(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
TRUNCATE TABLE t1; |
|||
|
|||
--echo # |
|||
--echo # Multiple values in one replace statement...RETURNING |
|||
--echo # |
|||
REPLACE INTO t1 VALUES (1,'a'),(2,'b'); |
|||
REPLACE INTO t1 VALUES (1,'c'),(2,'d') RETURNING *; |
|||
REPLACE INTO t1 VALUES (1,'e'),(2,'f') RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
REPLACE INTO t1 VALUES (1,'o'),(2,'p') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
REPLACE INTO t1 VALUES (1,'q'),(2,'r') RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "REPLACE INTO t1 VALUES (1,'s'),(2,'t') RETURNING id1, |
|||
(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
TRUNCATE TABLE t1; |
|||
|
|||
--echo # |
|||
--echo # REPLACE...SET...RETURNING |
|||
--echo # |
|||
REPLACE INTO t1 SET id1=1, val1 = 'a'; |
|||
REPLACE INTO t1 SET id1=2, val1 = 'b' RETURNING *; |
|||
REPLACE INTO t1 SET id1=3, val1 = 'c' RETURNING id1+id1 AS total, |
|||
id1&&id1, id1|id1,UPPER(val1),f(id1); |
|||
REPLACE INTO t1 SET id1=1, val1 = 'i' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 WHERE id2=1); |
|||
REPLACE INTO t1 SET id1=2, val1='j' RETURNING (SELECT GROUP_CONCAT(val2) |
|||
FROM t2 GROUP BY id2 HAVING id2=id2+1); |
|||
PREPARE stmt FROM "REPLACE INTO t1 SET id1=3, val1='k' RETURNING id1, |
|||
(SELECT id2 FROM t2 WHERE val2='b')"; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
SELECT * FROM t1; |
|||
|
|||
--echo # |
|||
--echo # REPLACE...SELECT...RETURNING |
|||
--echo # |
|||
TRUNCATE TABLE t2; |
|||
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=2 RETURNING id2+id2 AS total, |
|||
id2&&id2, id2|id2,UPPER(val2),f(id2); |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT |
|||
GROUP_CONCAT(val1) FROM t1 WHERE id1=1); |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT |
|||
GROUP_CONCAT(val1) FROM t1 GROUP BY id1 HAVING id1=id1+1); |
|||
PREPARE stmt FROM "REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING |
|||
id2,(SELECT id1 FROM t1 WHERE val1='b')"; |
|||
EXECUTE stmt; |
|||
DEALLOCATE PREPARE stmt; |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=3 RETURNING (SELECT id1+id2 |
|||
FROM t1 WHERE id1=1); |
|||
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=1 RETURNING (SELECT id1+id2 |
|||
FROM t2 WHERE id2=0); |
|||
SELECT * FROM t2; |
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
|||
DROP FUNCTION f; |
@ -0,0 +1,61 @@ |
|||
CREATE TABLE t1(num_int1 INT(2) PRIMARY KEY, |
|||
num_bit1 BIT(8), |
|||
num_float1 FLOAT(5,2), |
|||
num_double1 DOUBLE(5,2), |
|||
char_enum1 ENUM('A','B','C','D'), |
|||
char_set1 SET('a','b','c','d','e'), |
|||
str_varchar1 VARCHAR(2), |
|||
d1 DATE, |
|||
dt1 DATETIME, |
|||
ts1 TIMESTAMP, |
|||
y1 YEAR, |
|||
b1 BOOL); |
|||
CREATE TABLE t2(num_int2 INT(2) PRIMARY KEY, |
|||
num_bit2 BIT(8), |
|||
num_float2 FLOAT(5,2), |
|||
num_double2 DOUBLE(5,2), |
|||
char_enum2 ENUM('A','B','C','D'), |
|||
char_set2 SET('a','b','c','d','e'), |
|||
str_varchar2 VARCHAR(2), |
|||
d2 DATE, |
|||
dt2 DATETIME, |
|||
ts2 TIMESTAMP, |
|||
y2 YEAR, |
|||
b2 BOOL); |
|||
# |
|||
# SIMLPE REPLACE STATEMENT |
|||
# |
|||
REPLACE INTO t1(num_int1,num_bit1,num_float1,num_double1,char_enum1,char_set1, |
|||
str_varchar1, d1,dt1,ts1,y1,b1) VALUES(1,b'1000011', 123.45, 123.55, |
|||
'A','b,e', 'V','120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12', |
|||
2012,0) RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
1 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
# |
|||
# MULTIPLE ROWS IN SINGLE STATEMENT |
|||
# |
|||
REPLACE INTO t1 VALUES(1,b'1000011', 123.45, 123.55, 'A','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0),(3,b'1000011', |
|||
123.45, 123.55, 'A','b,e', 'V','120314',"2012-04-19 13:08:22", |
|||
'2001-07-22 12:12:12',2012,1) RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
1 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 0 |
|||
3 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 1 |
|||
# |
|||
# REPLACE...SET...RETURNING |
|||
# |
|||
REPLACE INTO t1 SET num_int1=1,num_bit1=b'1000011',num_float1=124.67, |
|||
num_double1=231.12,char_enum1='B',char_set1='a,d,e', |
|||
str_varchar1='AB',d1='120314',dt1="2012-04-19 13:08:22", |
|||
ts1='2001-07-22 12:12:1',y1=2014,b1=1 RETURNING *; |
|||
num_int1 num_bit1 num_float1 num_double1 char_enum1 char_set1 str_varchar1 d1 dt1 ts1 y1 b1 |
|||
1 C 124.67 231.12 B a,d,e AB 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:01 2014 1 |
|||
# |
|||
# REPLACE...SELECT...RETURNING |
|||
# |
|||
REPLACE INTO t2 SELECT * FROM t1 RETURNING *; |
|||
num_int2 num_bit2 num_float2 num_double2 char_enum2 char_set2 str_varchar2 d2 dt2 ts2 y2 b2 |
|||
1 C 124.67 231.12 B a,d,e AB 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:01 2014 1 |
|||
3 C 123.45 123.55 A b,e V 2012-03-14 2012-04-19 13:08:22 2001-07-22 12:12:12 2012 1 |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
@ -0,0 +1,66 @@ |
|||
#Test for checking all dataypes are returned |
|||
|
|||
CREATE TABLE t1(num_int1 INT(2) PRIMARY KEY, |
|||
num_bit1 BIT(8), |
|||
num_float1 FLOAT(5,2), |
|||
num_double1 DOUBLE(5,2), |
|||
char_enum1 ENUM('A','B','C','D'), |
|||
char_set1 SET('a','b','c','d','e'), |
|||
str_varchar1 VARCHAR(2), |
|||
d1 DATE, |
|||
dt1 DATETIME, |
|||
ts1 TIMESTAMP, |
|||
y1 YEAR, |
|||
b1 BOOL); |
|||
|
|||
CREATE TABLE t2(num_int2 INT(2) PRIMARY KEY, |
|||
num_bit2 BIT(8), |
|||
num_float2 FLOAT(5,2), |
|||
num_double2 DOUBLE(5,2), |
|||
char_enum2 ENUM('A','B','C','D'), |
|||
char_set2 SET('a','b','c','d','e'), |
|||
str_varchar2 VARCHAR(2), |
|||
d2 DATE, |
|||
dt2 DATETIME, |
|||
ts2 TIMESTAMP, |
|||
y2 YEAR, |
|||
b2 BOOL); |
|||
|
|||
|
|||
--echo # |
|||
--echo # SIMLPE REPLACE STATEMENT |
|||
--echo # |
|||
REPLACE INTO t1(num_int1,num_bit1,num_float1,num_double1,char_enum1,char_set1, |
|||
str_varchar1, d1,dt1,ts1,y1,b1) VALUES(1,b'1000011', 123.45, 123.55, |
|||
'A','b,e', 'V','120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12', |
|||
2012,0) RETURNING *; |
|||
|
|||
|
|||
--echo # |
|||
--echo # MULTIPLE ROWS IN SINGLE STATEMENT |
|||
--echo # |
|||
REPLACE INTO t1 VALUES(1,b'1000011', 123.45, 123.55, 'A','b,e', 'V', |
|||
'120314',"2012-04-19 13:08:22", '2001-07-22 12:12:12',2012,0),(3,b'1000011', |
|||
123.45, 123.55, 'A','b,e', 'V','120314',"2012-04-19 13:08:22", |
|||
'2001-07-22 12:12:12',2012,1) RETURNING *; |
|||
|
|||
|
|||
|
|||
--echo # |
|||
--echo # REPLACE...SET...RETURNING |
|||
--echo # |
|||
REPLACE INTO t1 SET num_int1=1,num_bit1=b'1000011',num_float1=124.67, |
|||
num_double1=231.12,char_enum1='B',char_set1='a,d,e', |
|||
str_varchar1='AB',d1='120314',dt1="2012-04-19 13:08:22", |
|||
ts1='2001-07-22 12:12:1',y1=2014,b1=1 RETURNING *; |
|||
|
|||
|
|||
|
|||
--echo # |
|||
--echo # REPLACE...SELECT...RETURNING |
|||
--echo # |
|||
REPLACE INTO t2 SELECT * FROM t1 RETURNING *; |
|||
|
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
@ -0,0 +1,69 @@ |
|||
CREATE TABLE t1(id1 INT PRIMARY KEY, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY, val2 VARCHAR(1)); |
|||
INSERT 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, '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 |
|||
# |
|||
# Multiple rows in single replace 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(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 ... 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 = '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...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 |
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
@ -0,0 +1,86 @@ |
|||
# |
|||
# Test for checking error message for REPLACE...RETURNING |
|||
# |
|||
|
|||
#REPLACE INTO <table> ... RETURNING <not existing col> |
|||
#REPLACE INTO <table> ... RETURNING <expr with aggr function> |
|||
#REPLACE INTO ... RETURNING subquery with more than 1 row |
|||
#REPLACE INTO ... RETURNING operand should contain 1 colunm(s) |
|||
#REPLACE INTO ... RETURNING operand should contain 1 colunm(s) |
|||
#REPLACE INTO ... SELECT...RETURNING < SELECT <colname> FROM <REPLACE TABLE> |
|||
|
|||
CREATE TABLE t1(id1 INT PRIMARY KEY, val1 VARCHAR(1)); |
|||
CREATE TABLE t2(id2 INT PRIMARY KEY, val2 VARCHAR(1)); |
|||
|
|||
INSERT 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); |
|||
--error ER_UPDATE_TABLE_USED |
|||
REPLACE INTO t2(id2, val2) VALUES(5, 'f') RETURNING(SELECT id2 FROM t2); |
|||
|
|||
--echo # |
|||
--echo # Multiple rows in single replace 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); |
|||
--error ER_UPDATE_TABLE_USED |
|||
REPLACE INTO t2 VALUES(13, 'f'), (14, 'g') RETURNING(SELECT id2 FROM t2); |
|||
|
|||
--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); |
|||
--error ER_UPDATE_TABLE_USED |
|||
REPLACE INTO t2 SET id2 = 5, val2 = 'f' RETURNING(SELECT id2 FROM t2); |
|||
|
|||
--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); |
|||
|
|||
DROP TABLE t1; |
|||
DROP TABLE t2; |
Write
Preview
Loading…
Cancel
Save
Reference in new issue