diff options
author | halfspawn <j.brauge@qualiac.com> | 2017-07-07 17:50:09 +0200 |
---|---|---|
committer | Sergei Golubchik <serg@mariadb.org> | 2017-07-07 22:38:15 +0200 |
commit | abf95afa2a1c23f3c7aa42f44fc665450ebeeea1 (patch) | |
tree | 103be88238fab60dd5e84f0d7729f14f3a0f47b4 | |
parent | 30fee6150a7b3afc0b7d371aac1a9eb7e3de554f (diff) | |
download | mariadb-git-abf95afa2a1c23f3c7aa42f44fc665450ebeeea1.tar.gz |
MDEV-12137 DELETE statement with the same source and target
single-table deletes only
-rw-r--r-- | mysql-test/r/delete_use_source.result | 178 | ||||
-rw-r--r-- | mysql-test/r/lowercase_view.result | 3 | ||||
-rw-r--r-- | mysql-test/r/merge.result | 42 | ||||
-rw-r--r-- | mysql-test/r/subselect.result | 5 | ||||
-rw-r--r-- | mysql-test/r/subselect_no_exists_to_in.result | 5 | ||||
-rw-r--r-- | mysql-test/r/subselect_no_mat.result | 5 | ||||
-rw-r--r-- | mysql-test/r/subselect_no_opts.result | 5 | ||||
-rw-r--r-- | mysql-test/r/subselect_no_scache.result | 5 | ||||
-rw-r--r-- | mysql-test/r/subselect_no_semijoin.result | 5 | ||||
-rw-r--r-- | mysql-test/r/view.result | 3 | ||||
-rw-r--r-- | mysql-test/t/delete_use_source.test | 172 | ||||
-rw-r--r-- | mysql-test/t/lowercase_view.test | 4 | ||||
-rw-r--r-- | mysql-test/t/merge.test | 61 | ||||
-rw-r--r-- | mysql-test/t/subselect.test | 8 | ||||
-rw-r--r-- | mysql-test/t/view.test | 7 | ||||
-rw-r--r-- | sql/sql_delete.cc | 86 | ||||
-rw-r--r-- | sql/sql_delete.h | 3 | ||||
-rw-r--r-- | sql/sql_prepare.cc | 4 |
18 files changed, 528 insertions, 73 deletions
diff --git a/mysql-test/r/delete_use_source.result b/mysql-test/r/delete_use_source.result new file mode 100644 index 00000000000..c7ca43083cf --- /dev/null +++ b/mysql-test/r/delete_use_source.result @@ -0,0 +1,178 @@ +set sql_mode=oracle; +use test; +create or replace table tab_delete(c1 integer not null,c2 integer not null) engine=InnoDb; +create index tab_delete_c1 on tab_delete(c1); +create or replace view view_delete as select * from tab_delete where c1 in (0,1); +CREATE or replace PROCEDURE gendata(a int, count int ) AS +i INT:=0; +BEGIN +FOR i IN 1 .. count +LOOP +insert into tab_delete values (a,i); +END LOOP; +END; +/ +create or replace trigger trg after delete on tab_delete for each row +begin +declare c int; +begin +if old.c1 = 1 then +select count(*) into c from tab_delete where c1!=old.c1; +SIGNAL SQLSTATE '45000' set table_name=c; +end if; +end; +end; +/ +set @count=500; +call gendata(0,@count); +call gendata(1,50); +call gendata(2,20); +call gendata(3,20); +commit; +# +# Delete with limit (quick select - range acces) +# +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 limit 1; +affected rows: 1 +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 limit 1; +affected rows: 0 +select count(*) from view_delete where c1=0; +count(*) +499 +rollback; +# +# Delete +# +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 ; +affected rows: 500 +rollback; +# +# Delete with exists +# +start transaction; +select count(*) from view_delete where c1=2; +count(*) +0 +delete from tab_delete where c1=2 and exists(select 'x' from tab_delete b where b.c2<10); +affected rows: 20 +delete from tab_delete where c1=2 and exists(select 'x' from tab_delete b where b.c2<10); +affected rows: 0 +select count(*) from view_delete where c1=2; +count(*) +0 +rollback; +# +# Delete throw a view with limit (range access) +# +start transaction; +# Acces by range (quick_select), initied = INDEX +# +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +# | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +# +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +# | 1 | PRIMARY | tab_delete | range | tab_delete_c1 | tab_delete_c1 | 4 | NULL | 550 | Using where | +# | 2 | DEPENDENT SUBQUERY | b | ref | tab_delete_c1 | tab_delete_c1 | 4 | test.tab_delete.c1 | 73 | Using index | +# +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 limit 1; +affected rows: 1 +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 limit 1; +affected rows: 0 +select count(*) from view_delete where c1=0; +count(*) +499 +rollback; +# +# Delete throw a view (ALL access) +# +start transaction; +# Acces by pointer, initied = RND +# +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +# | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +# +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +# | 1 | PRIMARY | tab_delete | ALL | tab_delete_c1 | NULL | NULL | NULL | 589 | Using where | +# | 2 | DEPENDENT SUBQUERY | b | ref | tab_delete_c1 | tab_delete_c1 | 4 | test.tab_delete.c1 | 295 | Using index | +# +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 ; +affected rows: 500 +select count(*) from view_delete where c1=0; +count(*) +0 +rollback; +# +# Delete failed due to trigger +# +start transaction; +delete from tab_delete where c1=1 and (select count(*) from tab_delete b where b.c1=tab_delete.c1) > 0 order by c2 asc limit 10; +ERROR 45000: Unhandled user-defined exception condition +rollback; +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) > 0 order by c1 desc limit 100; +ERROR 45000: Unhandled user-defined exception condition +select c1,count(*) from tab_delete group by c1; +c1 count(*) +0 500 +1 50 +2 20 +3 20 +rollback; +# +# Delete throw a view with returning +# +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 order by c2 asc limit 10 returning c1,c2; +c1 c2 +0 1 +0 2 +0 3 +0 4 +0 5 +0 6 +0 7 +0 8 +0 9 +0 10 +rollback; +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 order by c2 desc limit 10 returning c1,c2; +c1 c2 +0 491 +0 492 +0 493 +0 494 +0 495 +0 496 +0 497 +0 498 +0 499 +0 500 +rollback; +# +# Delete from table with more than 150000 rows +# +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +select count(*) from tab_delete; +count(*) +151040 +with high memory for sort_buffer_size +SET SESSION sort_buffer_size = 1024000; +start transaction; +delete from tab_delete where c1=0 and exists(select 'x' from tab_delete b where b.c1<10); +affected rows: 128000 +rollback; +with few memory for sort_buffer_size +SET SESSION sort_buffer_size = 1024; +start transaction; +delete from tab_delete where c1=0 and exists(select 'x' from tab_delete b where b.c1<10); +affected rows: 128000 +rollback; +drop procedure if exists gendata; +drop view if exists view_delete; +drop table if exists tab_delete; diff --git a/mysql-test/r/lowercase_view.result b/mysql-test/r/lowercase_view.result index df303807407..3b6aeb9548b 100644 --- a/mysql-test/r/lowercase_view.result +++ b/mysql-test/r/lowercase_view.result @@ -66,11 +66,8 @@ ERROR HY000: The definition of table 'v2aA' prevents operation UPDATE on table ' update v3aA set v3Aa.col1 = (select max(col1) from v3aA); ERROR HY000: Table 'v3aA' is specified twice, both as a target for 'UPDATE' and as a separate source for data delete from v2Aa where col1 = (select max(col1) from v1Aa); -ERROR HY000: The definition of table 'v1Aa' prevents operation DELETE on table 'v2Aa' delete from v2aA where col1 = (select max(col1) from t1Aa); -ERROR HY000: The definition of table 'v2aA' prevents operation DELETE on table 'v2aA' delete from v2Aa where col1 = (select max(col1) from v2aA); -ERROR HY000: Table 'v2Aa' is specified twice, both as a target for 'DELETE' and as a separate source for data delete v2Aa from v2aA,t2Aa where (select max(col1) from v1aA) > 0 and v2Aa.col1 = t2aA.col1; ERROR HY000: The definition of table 'v1aA' prevents operation DELETE on table 'v2aA' delete t1aA from t1Aa,t2Aa where (select max(col1) from v1Aa) > 0 and t1aA.col1 = t2aA.col1; diff --git a/mysql-test/r/merge.result b/mysql-test/r/merge.result index f468f47c4c9..6da7eb38655 100644 --- a/mysql-test/r/merge.result +++ b/mysql-test/r/merge.result @@ -3743,33 +3743,47 @@ ERROR HY000: The definition of table 'v1' prevents operation UPDATE on table 'm1 update m1 set a = ((select max(a) from tmp, v1)); ERROR HY000: The definition of table 'v1' prevents operation UPDATE on table 'm1' delete from m1 where a = (select max(a) from m1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from m2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t3, m1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t3, m2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t3, t1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from t3, t2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from tmp, m1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from tmp, m2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from tmp, t1); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from tmp, t2); -ERROR HY000: Table 'm1' is specified twice, both as a target for 'DELETE' and as a separate source for data +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from v1); -ERROR HY000: The definition of table 'v1' prevents operation DELETE on table 'm1' +insert into t1 (a) values (1); +insert into t2 (a) values (1); delete from m1 where a = (select max(a) from tmp, v1); -ERROR HY000: The definition of table 'v1' prevents operation DELETE on table 'm1' +insert into t1 (a) values (1); +insert into t2 (a) values (1); drop view v1; drop temporary table tmp; drop table t1, t2, t3, m1, m2; diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 95a872f1498..98a279c28e9 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -607,11 +607,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/subselect_no_exists_to_in.result b/mysql-test/r/subselect_no_exists_to_in.result index 7f07b974bb2..5cee4076ed8 100644 --- a/mysql-test/r/subselect_no_exists_to_in.result +++ b/mysql-test/r/subselect_no_exists_to_in.result @@ -611,11 +611,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/subselect_no_mat.result b/mysql-test/r/subselect_no_mat.result index 57c7a979d61..e7409b0b09c 100644 --- a/mysql-test/r/subselect_no_mat.result +++ b/mysql-test/r/subselect_no_mat.result @@ -614,11 +614,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/subselect_no_opts.result b/mysql-test/r/subselect_no_opts.result index 6e8be4a02a7..3bdc91686d7 100644 --- a/mysql-test/r/subselect_no_opts.result +++ b/mysql-test/r/subselect_no_opts.result @@ -610,11 +610,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/subselect_no_scache.result b/mysql-test/r/subselect_no_scache.result index 1b437f6919d..3beba7c338d 100644 --- a/mysql-test/r/subselect_no_scache.result +++ b/mysql-test/r/subselect_no_scache.result @@ -613,11 +613,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/subselect_no_semijoin.result b/mysql-test/r/subselect_no_semijoin.result index 6094c7e029d..f2d97078772 100644 --- a/mysql-test/r/subselect_no_semijoin.result +++ b/mysql-test/r/subselect_no_semijoin.result @@ -610,11 +610,12 @@ select * from t1 where b = (select b from t2 where t1.a = t2.a); a b 2 12 delete from t1 where b in (select b from t1); -ERROR HY000: Table 't1' is specified twice, both as a target for 'DELETE' and as a separate source for data +affected rows: 3 +insert into t1 values (0, 10),(1, 11),(2, 12); delete from t1 where b = (select b from t2); ERROR 21000: Subquery returns more than 1 row delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; a b 0 10 1 11 diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 77794ac1c82..50a48ade3bd 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -994,11 +994,8 @@ ERROR HY000: The definition of table 'v2' prevents operation UPDATE on table 'v3 update v3 set v3.col1 = (select max(col1) from v3); ERROR HY000: Table 'v3' is specified twice, both as a target for 'UPDATE' and as a separate source for data delete from v2 where col1 = (select max(col1) from v1); -ERROR HY000: The definition of table 'v1' prevents operation DELETE on table 'v2' delete from v2 where col1 = (select max(col1) from t1); -ERROR HY000: The definition of table 'v2' prevents operation DELETE on table 'v2' delete from v2 where col1 = (select max(col1) from v2); -ERROR HY000: Table 'v2' is specified twice, both as a target for 'DELETE' and as a separate source for data delete v2 from v2,t2 where (select max(col1) from v1) > 0 and v2.col1 = t2.col1; ERROR HY000: The definition of table 'v1' prevents operation DELETE on table 'v2' delete t1 from t1,t2 where (select max(col1) from v1) > 0 and t1.col1 = t2.col1; diff --git a/mysql-test/t/delete_use_source.test b/mysql-test/t/delete_use_source.test new file mode 100644 index 00000000000..ddd7858ee77 --- /dev/null +++ b/mysql-test/t/delete_use_source.test @@ -0,0 +1,172 @@ +-- source include/have_innodb.inc +set sql_mode=oracle; +use test; +create or replace table tab_delete(c1 integer not null,c2 integer not null) engine=InnoDb; +create index tab_delete_c1 on tab_delete(c1); +create or replace view view_delete as select * from tab_delete where c1 in (0,1); +delimiter /; +CREATE or replace PROCEDURE gendata(a int, count int ) AS + i INT:=0; +BEGIN + FOR i IN 1 .. count + LOOP + insert into tab_delete values (a,i); + END LOOP; +END; +/ +create or replace trigger trg after delete on tab_delete for each row +begin + declare c int; + begin + if old.c1 = 1 then + select count(*) into c from tab_delete where c1!=old.c1; + SIGNAL SQLSTATE '45000' set table_name=c; + end if; + end; +end; +/ +delimiter ;/ +set @count=500; +call gendata(0,@count); +call gendata(1,50); +call gendata(2,20); +call gendata(3,20); +commit; + +--echo # +--echo # Delete with limit (quick select - range acces) +--echo # + +start transaction; +--enable_info +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 limit 1; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 limit 1; +--disable_info +select count(*) from view_delete where c1=0; +rollback; + +--echo # +--echo # Delete +--echo # + +start transaction; +--enable_info +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 ; +--disable_info +rollback; + +--echo # +--echo # Delete with exists +--echo # + +start transaction; +select count(*) from view_delete where c1=2; +--enable_info +delete from tab_delete where c1=2 and exists(select 'x' from tab_delete b where b.c2<10); +delete from tab_delete where c1=2 and exists(select 'x' from tab_delete b where b.c2<10); +--disable_info +select count(*) from view_delete where c1=2; +rollback; + +--echo # +--echo # Delete throw a view with limit (range access) +--echo # + +start transaction; +--echo # Acces by range (quick_select), initied = INDEX +--echo # +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +--echo # | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +--echo # +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +--echo # | 1 | PRIMARY | tab_delete | range | tab_delete_c1 | tab_delete_c1 | 4 | NULL | 550 | Using where | +--echo # | 2 | DEPENDENT SUBQUERY | b | ref | tab_delete_c1 | tab_delete_c1 | 4 | test.tab_delete.c1 | 73 | Using index | +--echo # +------+--------------------+------------+-------+---------------+---------------+---------+--------------------+------+-------------+ +# explain delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 limit 1; +--enable_info +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 limit 1; +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 limit 1; +--disable_info +select count(*) from view_delete where c1=0; +rollback; + +--echo # +--echo # Delete throw a view (ALL access) +--echo # + +start transaction; +--echo # Acces by pointer, initied = RND +--echo # +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +--echo # | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +--echo # +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +--echo # | 1 | PRIMARY | tab_delete | ALL | tab_delete_c1 | NULL | NULL | NULL | 589 | Using where | +--echo # | 2 | DEPENDENT SUBQUERY | b | ref | tab_delete_c1 | tab_delete_c1 | 4 | test.tab_delete.c1 | 295 | Using index | +--echo # +------+--------------------+------------+------+---------------+---------------+---------+--------------------+------+-------------+ +# explain delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500; +--enable_info +delete from view_delete where (select count(*) from tab_delete b where b.c1=view_delete.c1) = 500 ; +--disable_info +select count(*) from view_delete where c1=0; +rollback; + + +--echo # +--echo # Delete failed due to trigger +--echo # + +start transaction; +--enable_info +--error ER_SIGNAL_EXCEPTION +delete from tab_delete where c1=1 and (select count(*) from tab_delete b where b.c1=tab_delete.c1) > 0 order by c2 asc limit 10; +--disable_info +rollback; +start transaction; +--enable_info +--error ER_SIGNAL_EXCEPTION +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) > 0 order by c1 desc limit 100; +--disable_info +select c1,count(*) from tab_delete group by c1; +rollback; + +--echo # +--echo # Delete throw a view with returning +--echo # + +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 order by c2 asc limit 10 returning c1,c2; +rollback; +start transaction; +delete from tab_delete where (select count(*) from tab_delete b where b.c1=tab_delete.c1) = 500 order by c2 desc limit 10 returning c1,c2; +rollback; + + +--echo # +--echo # Delete from table with more than 150000 rows +--echo # +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +insert into tab_delete select * from tab_delete; +select count(*) from tab_delete; + +--echo with high memory for sort_buffer_size +SET SESSION sort_buffer_size = 1024000; +start transaction; +--enable_info +delete from tab_delete where c1=0 and exists(select 'x' from tab_delete b where b.c1<10); +--disable_info +rollback; + +--echo with few memory for sort_buffer_size +SET SESSION sort_buffer_size = 1024; +start transaction; +--enable_info +delete from tab_delete where c1=0 and exists(select 'x' from tab_delete b where b.c1<10); +--disable_info +rollback; + +drop procedure if exists gendata; +drop view if exists view_delete; +drop table if exists tab_delete; diff --git a/mysql-test/t/lowercase_view.test b/mysql-test/t/lowercase_view.test index 52be911cde0..6d53e6d9130 100644 --- a/mysql-test/t/lowercase_view.test +++ b/mysql-test/t/lowercase_view.test @@ -73,11 +73,9 @@ update v3aA set v3Aa.col1 = (select max(col1) from t1aA); update v3aA set v3Aa.col1 = (select max(col1) from v2aA); -- error 1093 update v3aA set v3Aa.col1 = (select max(col1) from v3aA); --- error 1443 +# Works since MDEV-12137 (no more error 1093) delete from v2Aa where col1 = (select max(col1) from v1Aa); --- error 1443 delete from v2aA where col1 = (select max(col1) from t1Aa); --- error 1093 delete from v2Aa where col1 = (select max(col1) from v2aA); -- error 1443 delete v2Aa from v2aA,t2Aa where (select max(col1) from v1aA) > 0 and v2Aa.col1 = t2aA.col1; diff --git a/mysql-test/t/merge.test b/mysql-test/t/merge.test index 09f313616f1..c35dd39170b 100644 --- a/mysql-test/t/merge.test +++ b/mysql-test/t/merge.test @@ -2763,39 +2763,66 @@ update m1 set a = ((select max(a) from tmp, t2)); update m1 set a = ((select max(a) from v1)); --error ER_VIEW_PREVENT_UPDATE update m1 set a = ((select max(a) from tmp, v1)); - - ---error ER_UPDATE_TABLE_USED +# Works since MDEV-12137 +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from m1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from m2); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t2); +insert into t1 (a) values (1); +insert into t2 (a) values (1); ---error ER_UPDATE_TABLE_USED +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t3, m1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t3, m2); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t3, t1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from t3, t2); +insert into t1 (a) values (1); +insert into t2 (a) values (1); ---error ER_UPDATE_TABLE_USED +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from tmp, m1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from tmp, m2); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from tmp, t1); ---error ER_UPDATE_TABLE_USED +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously :ER_UPDATE_TABLE_USED delete from m1 where a = (select max(a) from tmp, t2); - ---error ER_VIEW_PREVENT_UPDATE +insert into t1 (a) values (1); +insert into t2 (a) values (1); + +# previously : ER_VIEW_PREVENT_UPDATE delete from m1 where a = (select max(a) from v1); ---error ER_VIEW_PREVENT_UPDATE +insert into t1 (a) values (1); +insert into t2 (a) values (1); +# previously : ER_VIEW_PREVENT_UPDATE delete from m1 where a = (select max(a) from tmp, v1); +insert into t1 (a) values (1); +insert into t2 (a) values (1); drop view v1; drop temporary table tmp; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 282013222de..59694635c70 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -340,12 +340,16 @@ insert into t1 values (0, 10),(1, 11),(2, 12); insert into t2 values (1, 21),(2, 12),(3, 23); select * from t1; select * from t1 where b = (select b from t2 where t1.a = t2.a); --- error ER_UPDATE_TABLE_USED +# Works since MDEV-12137 +# previously : ER_UPDATE_TABLE_USED +--enable_info delete from t1 where b in (select b from t1); +--disable_info +insert into t1 values (0, 10),(1, 11),(2, 12); -- error ER_SUBQUERY_NO_1_ROW delete from t1 where b = (select b from t2); delete from t1 where b = (select b from t2 where t1.a = t2.a); -select * from t1; +select * from t1 order by b; drop table t1, t2; #multi-delete with subselects diff --git a/mysql-test/t/view.test b/mysql-test/t/view.test index fa130afc84b..9ed37a2bf65 100644 --- a/mysql-test/t/view.test +++ b/mysql-test/t/view.test @@ -914,11 +914,12 @@ update v3 set v3.col1 = (select max(col1) from t1); update v3 set v3.col1 = (select max(col1) from v2); -- error ER_UPDATE_TABLE_USED update v3 set v3.col1 = (select max(col1) from v3); --- error ER_VIEW_PREVENT_UPDATE +# Works since MDEV-12137 +# Previously error ER_VIEW_PREVENT_UPDATE delete from v2 where col1 = (select max(col1) from v1); --- error ER_VIEW_PREVENT_UPDATE +# Previously error ER_VIEW_PREVENT_UPDATE delete from v2 where col1 = (select max(col1) from t1); --- error ER_UPDATE_TABLE_USED +# Previously error ER_UPDATE_TABLE_USED delete from v2 where col1 = (select max(col1) from v2); -- error ER_VIEW_PREVENT_UPDATE delete v2 from v2,t2 where (select max(col1) from v1) > 0 and v2.col1 = t2.col1; diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index eb5f0d7a477..8d4757e6d31 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -45,6 +45,8 @@ // end_read_record #include "sql_partition.h" // make_used_partitions_str +#define MEM_STRIP_BUF_SIZE current_thd->variables.sortbuff_size + /* @brief Print query plan of a single-table DELETE command @@ -246,6 +248,9 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, Delete_plan query_plan(thd->mem_root); query_plan.index= MAX_KEY; query_plan.using_filesort= FALSE; + Unique * deltempfile= NULL; + uint delete_while_scanning= 1; + uint delete_record= 0; DBUG_ENTER("mysql_delete"); create_explain_query(thd->lex, thd->mem_root); @@ -275,7 +280,8 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, query_plan.updating_a_view= MY_TEST(table_list->view); if (mysql_prepare_delete(thd, table_list, select_lex->with_wild, - select_lex->item_list, &conds)) + select_lex->item_list, &conds, + delete_while_scanning)) DBUG_RETURN(TRUE); if (with_select) @@ -556,16 +562,68 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, explain= (Explain_delete*)thd->lex->explain->get_upd_del_plan(); explain->tracker.on_scan_init(); + if (delete_while_scanning == 0) + { + /* + The table we are going to delete appears in join. + Instead of deleting the rows, first mark them deleted. + */ + ha_rows tmplimit=limit; + deltempfile= new Unique (refpos_order_cmp, + (void *) table->file, + table->file->ref_length, + MEM_STRIP_BUF_SIZE); + while (!(error=info.read_record(&info)) && !thd->killed && + ! thd->is_error()) + { + explain->tracker.on_record_read(); + thd->inc_examined_row_count(1); + if (table->vfield) + (void) table->update_virtual_fields(table->file, + VCOL_UPDATE_FOR_DELETE); + if (!select || select->skip_record(thd) > 0) + { + explain->tracker.on_record_after_where(); + table->file->position(table->record[0]); + if ((error= deltempfile->unique_add((char*) table->file->ref))) + { + error= 1; + goto terminate_delete; + } + if (!--tmplimit && using_limit) + { + break; + } + } + } + end_read_record(&info); + if (deltempfile->get(table) || + table->file->ha_index_or_rnd_end() || + init_read_record(&info, thd, table, NULL , &deltempfile->sort, 0, 1, + FALSE)) + { + error= 1; + goto terminate_delete; + } + delete_record= 1; + } + while (!(error=info.read_record(&info)) && !thd->killed && - ! thd->is_error()) + ! thd->is_error()) { - explain->tracker.on_record_read(); - thd->inc_examined_row_count(1); - if (table->vfield) - (void) table->update_virtual_fields(table->file, VCOL_UPDATE_FOR_DELETE); - if (!select || select->skip_record(thd) > 0) + if (delete_while_scanning == 1) + { + explain->tracker.on_record_read(); + thd->inc_examined_row_count(1); + if (table->vfield) + (void) table->update_virtual_fields(table->file, + VCOL_UPDATE_FOR_DELETE); + delete_record=(!select || select->skip_record(thd) > 0) ? 1 : 0; + if (delete_record) + explain->tracker.on_record_after_where(); + } + if (delete_record == 1) { - explain->tracker.on_record_after_where(); if (table->triggers && table->triggers->process_triggers(thd, TRG_EVENT_DELETE, TRG_ACTION_BEFORE, FALSE)) @@ -616,6 +674,7 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, else break; } +terminate_delete: killed_status= thd->killed; if (killed_status != NOT_KILLED || thd->is_error()) error= 1; // Aborted @@ -647,6 +706,8 @@ cleanup: thd->lex->current_select->first_cond_optimization= 0; } + delete deltempfile; + deltempfile=NULL; delete select; select= NULL; transactional_table= table->file->has_transactions(); @@ -746,7 +807,8 @@ l TRUE error */ int mysql_prepare_delete(THD *thd, TABLE_LIST *table_list, - uint wild_num, List<Item> &field_list, Item **conds) + uint wild_num, List<Item> &field_list, Item **conds, + uint &delete_while_scanning) { Item *fake_conds= 0; SELECT_LEX *select_lex= &thd->lex->select_lex; @@ -775,10 +837,7 @@ l { TABLE_LIST *duplicate; if ((duplicate= unique_table(thd, table_list, table_list->next_global, 0))) - { - update_non_unique_table_error(table_list, "DELETE", duplicate); - DBUG_RETURN(TRUE); - } + delete_while_scanning= 0; } if (select_lex->inner_refs_list.elements && @@ -794,7 +853,6 @@ l Delete multiple tables from join ***************************************************************************/ -#define MEM_STRIP_BUF_SIZE current_thd->variables.sortbuff_size extern "C" int refpos_order_cmp(void* arg, const void *a,const void *b) { diff --git a/sql/sql_delete.h b/sql/sql_delete.h index 9cd09dc5722..d49b0114c52 100644 --- a/sql/sql_delete.h +++ b/sql/sql_delete.h @@ -27,7 +27,8 @@ typedef class Item COND; template <typename T> class SQL_I_List; int mysql_prepare_delete(THD *thd, TABLE_LIST *table_list, - uint wild_num, List<Item> &field_list, Item **conds); + uint wild_num, List<Item> &field_list, Item **conds, + uint &delete_while_scanning); bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, SQL_I_List<ORDER> *order, ha_rows rows, ulonglong options, select_result *result); diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index 37d70bdc7ba..dc0dcbac43f 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1496,6 +1496,7 @@ static bool mysql_test_delete(Prepared_statement *stmt, uint table_count= 0; THD *thd= stmt->thd; LEX *lex= stmt->lex; + uint delete_while_scanning=1; DBUG_ENTER("mysql_test_delete"); if (delete_precheck(thd, table_list) || @@ -1524,7 +1525,8 @@ static bool mysql_test_delete(Prepared_statement *stmt, DBUG_RETURN(mysql_prepare_delete(thd, table_list, lex->select_lex.with_wild, lex->select_lex.item_list, - &lex->select_lex.where)); + &lex->select_lex.where, + delete_while_scanning)); error: DBUG_RETURN(TRUE); } |