Commit 75d354a2 authored by Daniel Black's avatar Daniel Black

MDEV-33988 DELETE single table to support table aliases

Gain MySQL compatibility by allowing table aliases in a single
table statement.

This now supports the syntax of:

DELETE [delete_opts] FROM tbl_name [[AS] tbl_alias] [PARTITION (partition_name [, partition_name] ...)] ....

The delete.test is from MySQL commit 1a72b69778a9791be44525501960b08856833b8d
/ Change-Id: Iac3a2b5ed993f65b7f91acdfd60013c2344db5c0.

Co-Author: Gleb Shchepa <gleb.shchepa@oracle.com> (for delete.test)

Reviewed by Igor Babaev (igor@mariadb.com)
parent 0cd20e3a
......@@ -259,13 +259,13 @@ a INT
);
INSERT INTO db2.t1 (a) SELECT * FROM t2;
DELETE FROM t1 alias USING t1, t2 alias WHERE t1.a = alias.a;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'alias USING t1, t2 alias WHERE t1.a = alias.a' at line 1
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1, t2 alias WHERE t1.a = alias.a' at line 1
DELETE FROM alias USING t1, t2 alias WHERE t1.a = alias.a;
DELETE FROM t1, alias USING t1, t2 alias WHERE t1.a = alias.a;
DELETE FROM t1, t2 USING t1, t2 alias WHERE t1.a = alias.a;
ERROR 42S02: Unknown table 't2' in MULTI DELETE
DELETE FROM db1.t1 alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a' at line 1
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a' at line 1
DELETE FROM alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
DELETE FROM db2.alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
ERROR 42S02: Unknown table 'alias' in MULTI DELETE
......@@ -273,7 +273,7 @@ DELETE FROM t1 USING t1 WHERE a = 1;
SELECT * FROM t1;
a
DELETE FROM t1 alias USING t1 alias WHERE a = 2;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'alias USING t1 alias WHERE a = 2' at line 1
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 alias WHERE a = 2' at line 1
SELECT * FROM t1;
a
DROP TABLE t1, t2;
......@@ -611,3 +611,28 @@ c1 c2 c3
2 2 5
drop table t1;
End of 11.1 tests
#
# MDEV-33988 DELETE to support table aliases
#
CREATE TABLE t1 (c1 INT);
INSERT INTO t1 VALUES (1), (2);
SELECT * FROM t1;
c1
1
2
DELETE FROM t1 AS a1 WHERE a1.c1 = 2;
SELECT * FROM t1;
c1
1
CREATE TABLE t2 (c2 INT);
INSERT INTO t2 VALUES (1), (2);
SELECT * FROM t2;
c2
1
2
DELETE FROM t2 a2 WHERE NOT EXISTS (SELECT * FROM t1 WHERE t1.c1 = a2.c2);
SELECT * FROM t2;
c2
1
DROP TABLE t1, t2;
End of 11.6 tests
......@@ -668,3 +668,26 @@ select *from t1;
drop table t1;
--echo End of 11.1 tests
--echo #
--echo # MDEV-33988 DELETE to support table aliases
--echo #
# Test from MySQL Bug#27455809; DELETE FROM ...WHERE NOT EXISTS WITH TABLE ALIAS CREATES AN ERROR 1064 (42000
CREATE TABLE t1 (c1 INT);
INSERT INTO t1 VALUES (1), (2);
SELECT * FROM t1;
DELETE FROM t1 AS a1 WHERE a1.c1 = 2;
SELECT * FROM t1;
CREATE TABLE t2 (c2 INT);
INSERT INTO t2 VALUES (1), (2);
SELECT * FROM t2;
DELETE FROM t2 a2 WHERE NOT EXISTS (SELECT * FROM t1 WHERE t1.c1 = a2.c2);
SELECT * FROM t2;
DROP TABLE t1, t2;
--echo End of 11.6 tests
......@@ -334,3 +334,74 @@ c1 c2 c3
2 1 4
deallocate prepare stmt;
drop table t1,t2;
# End of 11.1
#
# MDEV-33988 DELETE (single table) to support table aliases
#
create table t1 (c1 int, c2 int, c3 int);
insert into t1 values
(1,1,1), (1,2,2), (1,3,3), (2,1,4), (2,2,5), (2,3,6), (2,5,7), (3,5,8);
create table t2 (id int auto_increment primary key, a int, key(a));
insert into t2(a) values (3), (5), (-1);
# 1. The alias in delete coincides with the table name in IN subquery.
explain extended
delete from t1 t2 where t2.c1 in (select a from t2);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 8 100.00 Using where
1 PRIMARY t2 ref a a 5 test.t2.c1 1 100.00 Using index; FirstMatch(t2)
Warnings:
Note 1003 delete from `test`.`t1` `t2` using (`test`.`t2`) where `test`.`t2`.`a` = `test`.`t2`.`c1`
delete from t1 t2 where t2.c1 in (select a from t2);
select * from t1;
c1 c2 c3
1 1 1
1 2 2
1 3 3
2 1 4
2 2 5
2 3 6
2 5 7
# 2. The alias in delete is different from the alias in IN subquery
explain extended
delete from t1 t_x where t_x.c2 IN (select a from t2 as t_y);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t_x ALL NULL NULL NULL NULL 7 100.00 Using where
1 PRIMARY t_y ref a a 5 test.t_x.c2 1 100.00 Using index; FirstMatch(t_x)
Warnings:
Note 1003 delete from `test`.`t1` `t_x` using (`test`.`t2` `t_y`) where `test`.`t_y`.`a` = `test`.`t_x`.`c2`
delete from t1 t_x where t_x.c2 IN (select a from t2 as t_y);
select * from t1;
c1 c2 c3
1 1 1
1 2 2
2 1 4
2 2 5
# 3. The alias in delete is the same as the alias in IN subquery.
explain extended
delete from t1 as t_x where t_x.c3 IN (select a from t2 t_x);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t_x ALL NULL NULL NULL NULL 4 100.00 Using where
1 PRIMARY t_x ref a a 5 test.t_x.c3 1 100.00 Using index; FirstMatch(t_x)
Warnings:
Note 1003 delete from `test`.`t1` `t_x` using (`test`.`t2` `t_x`) where `test`.`t_x`.`a` = `test`.`t_x`.`c3`
delete from t1 as t_x where t_x.c3 IN (select a from t2 t_x);
select * from t1;
c1 c2 c3
1 1 1
1 2 2
2 1 4
# 4. The table in delete is the alias in IN subquery
explain extended
delete from t1 t2 where t2.c1 IN (select a -1 from t2 as t1);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 3 100.00
1 PRIMARY t1 index NULL a 5 NULL 3 33.33 Using where; Using index; FirstMatch(t2)
Warnings:
Note 1003 delete from `test`.`t1` `t2` using (`test`.`t2` `t1`) where `test`.`t2`.`c1` = `test`.`t1`.`a` - 1
delete from t1 t2 where t2.c1 IN (select a -1 from t2 as t1);
select * from t1;
c1 c2 c3
1 1 1
1 2 2
drop table t1, t2;
# End of 11.6
......@@ -257,3 +257,50 @@ select * from t2;
deallocate prepare stmt;
drop table t1,t2;
--echo # End of 11.1
--echo #
--echo # MDEV-33988 DELETE (single table) to support table aliases
--echo #
create table t1 (c1 int, c2 int, c3 int);
insert into t1 values
(1,1,1), (1,2,2), (1,3,3), (2,1,4), (2,2,5), (2,3,6), (2,5,7), (3,5,8);
create table t2 (id int auto_increment primary key, a int, key(a));
insert into t2(a) values (3), (5), (-1);
--echo # 1. The alias in delete coincides with the table name in IN subquery.
explain extended
delete from t1 t2 where t2.c1 in (select a from t2);
delete from t1 t2 where t2.c1 in (select a from t2);
select * from t1;
--echo # 2. The alias in delete is different from the alias in IN subquery
explain extended
delete from t1 t_x where t_x.c2 IN (select a from t2 as t_y);
delete from t1 t_x where t_x.c2 IN (select a from t2 as t_y);
select * from t1;
--echo # 3. The alias in delete is the same as the alias in IN subquery.
explain extended
delete from t1 as t_x where t_x.c3 IN (select a from t2 t_x);
delete from t1 as t_x where t_x.c3 IN (select a from t2 t_x);
select * from t1;
--echo # 4. The table in delete is the alias in IN subquery
explain extended
delete from t1 t2 where t2.c1 IN (select a -1 from t2 as t1);
delete from t1 t2 where t2.c1 IN (select a -1 from t2 as t1);
select * from t1;
drop table t1, t2;
--echo # End of 11.6
......@@ -2006,3 +2006,41 @@ drop table t1;
#
# End of 10.4 tests
#
#
# MDEV-33988 DELETE (single table) to support table aliases
#
CREATE TABLE `t1` (
`id` int(11) default NULL
)
PARTITION BY RANGE (id) (
PARTITION p0 VALUES LESS THAN (6),
PARTITION p1 VALUES LESS THAN (11),
PARTITION p2 VALUES LESS THAN (16),
PARTITION p3 VALUES LESS THAN (21));
INSERT INTO `t1` VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10),
(11), (12), (13), (14), (15), (16), (17), (18), (19), (20);
DELETE FROM t1 AS a PARTITION(p0) WHERE a.id % 2 = 0;
SELECT * FROM t1 ORDER BY id;
id
1
3
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
DROP TABLE t1;
#
# End of 11.6 tests
#
......@@ -940,3 +940,28 @@ drop table t1;
--echo # End of 10.4 tests
--echo #
--echo #
--echo # MDEV-33988 DELETE (single table) to support table aliases
--echo #
CREATE TABLE `t1` (
`id` int(11) default NULL
)
PARTITION BY RANGE (id) (
PARTITION p0 VALUES LESS THAN (6),
PARTITION p1 VALUES LESS THAN (11),
PARTITION p2 VALUES LESS THAN (16),
PARTITION p3 VALUES LESS THAN (21));
INSERT INTO `t1` VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10),
(11), (12), (13), (14), (15), (16), (17), (18), (19), (20);
DELETE FROM t1 AS a PARTITION(p0) WHERE a.id % 2 = 0;
SELECT * FROM t1 ORDER BY id;
DROP TABLE t1;
--echo #
--echo # End of 11.6 tests
--echo #
......@@ -69,7 +69,7 @@ FLUSH TABLE t2;
# has broken triggers. The parse error refers to the first broken
# trigger.
CREATE TRIGGER tr16 AFTER UPDATE ON t1 FOR EACH ROW INSERT INTO t1 VALUES (1);
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'a USING t1 a' at line 1'
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 a' at line 1'
CREATE TRIGGER tr22 BEFORE INSERT ON t2 FOR EACH ROW DELETE FROM non_existing_table;
ERROR 42000: Unknown trigger has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'Not allowed syntax here, and trigger name cant be extracted either.' at line 1'
SHOW TRIGGERS;
......@@ -80,20 +80,20 @@ tr15 UPDATE t1 CREATE DEFINER=`root`@`localhost` TRIGGER tr15 BEFORE UPDATE ON t
tr13 DELETE t1 CREATE DEFINER=`root`@`localhost` TRIGGER tr13 BEFORE DELETE ON t1 FOR EACH ROW DELETE FROM t1 a USING t1 a BEFORE # latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
tr14 DELETE t1 DELETE FROM non_existing_table AFTER # root@localhost latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
INSERT INTO t1 VALUES (1);
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'a USING t1 a' at line 1'
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 a' at line 1'
INSERT INTO t2 VALUES (1);
ERROR 42000: Unknown trigger has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'Not allowed syntax here, and trigger name cant be extracted either.' at line 1'
DELETE FROM t1;
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'a USING t1 a' at line 1'
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 a' at line 1'
UPDATE t1 SET a = 1 WHERE a = 1;
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'a USING t1 a' at line 1'
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 a' at line 1'
SELECT * FROM t1;
a
1
2
3
RENAME TABLE t1 TO t1_2;
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'a USING t1 a' at line 1'
ERROR 42000: Trigger 'tr13' has an error in its body: 'You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'USING t1 a' at line 1'
SHOW TRIGGERS;
Trigger Event Table Statement Timing Created sql_mode Definer character_set_client collation_connection Database Collation
tr11 INSERT t1 DELETE FROM t3 BEFORE # root@localhost latin1 latin1_swedish_ci utf8mb4_uca1400_ai_ci
......
......@@ -13734,10 +13734,10 @@ delete_part2:
;
delete_single_table:
FROM table_ident opt_use_partition
FROM table_ident opt_table_alias_clause opt_use_partition
{
if (unlikely(!Select->
add_table_to_list(thd, $2, NULL, TL_OPTION_UPDATING,
add_table_to_list(thd, $2, $3, TL_OPTION_UPDATING,
YYPS->m_lock_type,
YYPS->m_mdl_type,
NULL,
......@@ -13750,11 +13750,11 @@ delete_single_table:
Lex->query_tables= 0;
Lex->query_tables_last= &Lex->query_tables;
if (unlikely(!Select->
add_table_to_list(thd, $2, NULL, TL_OPTION_UPDATING,
add_table_to_list(thd, $2, $3, TL_OPTION_UPDATING,
YYPS->m_lock_type,
YYPS->m_mdl_type,
NULL,
$3)))
$4)))
MYSQL_YYABORT;
Lex->auxiliary_table_list.first->correspondent_table=
Lex->query_tables;
......
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