1
0
mirror of https://github.com/MariaDB/server.git synced 2025-07-23 08:45:18 +03:00
Files
mariadb/mysql-test/main/replace_returning.test
Rucha Deodhar 5518c3209b 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.
2021-07-22 21:56:18 +05:30

193 lines
6.7 KiB
Plaintext

--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;
REPLACE INTO t1 (id1, val1) VALUES (1, 'g') RETURNING t1.*;
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;
REPLACE INTO t1 VALUES (1,'u'),(2,'v') RETURNING t1.*;
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;
REPLACE INTO t1 SET id1=1, val1 = 'o' RETURNING t1.*;
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);
REPLACE INTO t2 SELECT * FROM t1 WHERE id1=2 RETURNING t2.*;
SELECT * FROM t2;
DROP TABLE t1;
DROP TABLE t2;
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;