Commit bef20b5f authored by Igor Babaev's avatar Igor Babaev

MDEV-30538 Plans for SELECT and multi-table UPDATE/DELETE unexpectedly differ

This patch allowed transformation of EXISTS subqueries into equivalent
IN predicands at the top level of WHERE conditions for multi-table UPDATE
and DELETE statements. There was no reason to prohibit the transformation
for such statements. The transformation provides more opportunities of
using semi-join optimizations.

Approved by Oleksandr Byelkin <sanja@mariadb.com>
parent 0845bce0
......@@ -1251,3 +1251,123 @@ EXPLAIN
}
}
DROP TABLES t1, t2;
# End of 10.3 tests
#
# MDEV-28538: multi-table UPDATE/DELETE with possible exists-to-in
#
create table t1 (c1 int, c2 int, c3 int, index idx(c2));
insert into t1 values
(1,1,1),(3,2,2),(1,3,3),
(2,1,4),(2,2,5),(4,3,6),
(2,4,7),(2,5,8);
create table t2 (c1 int, c2 int, c3 int, index idx(c2));
insert into t2 values
(1,7,1),(1,8,2),(1,3,3),
(2,1,4),(2,2,5),(2,3,6),
(2,4,7),(2,5,8);
create table t3 (c1 int, c2 int, c3 int, index idx(c2));
insert into t3 values
(1,1,1),(1,2,2),(1,3,3),
(2,1,4),(2,2,5),(2,3,6),
(2,4,7),(2,5,8);
insert into t3 select c1+1, c2+2, c3 from t3;
insert into t3 select c1, c2+2, c3 from t3;
analyze table t1,t2,t3 persistent for all;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
test.t2 analyze status Engine-independent statistics collected
test.t2 analyze status OK
test.t3 analyze status Engine-independent statistics collected
test.t3 analyze status OK
explain select * from t1,t3
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL idx NULL NULL NULL 8 Using where
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t3 ref idx idx 5 test.t1.c2 3
2 MATERIALIZED t2 range idx idx 5 NULL 3 Using index condition; Using where
explain delete from t1 using t1,t3
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL idx NULL NULL NULL 8 Using where
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t3 ref idx idx 5 test.t1.c2 3 Using index
2 MATERIALIZED t2 range idx idx 5 NULL 3 Using where
explain update t1,t3 set t1.c1 = t1.c1+10
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL idx NULL NULL NULL 8 Using where
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
1 PRIMARY t3 ref idx idx 5 test.t1.c2 3 Using index
2 MATERIALIZED t2 range idx idx 5 NULL 3 Using where
create table t as select * from t1;
select * from t1,t3
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
c1 c2 c3 c1 c2 c3
2 1 4 1 1 1
2 1 4 2 1 4
2 2 5 1 2 2
2 2 5 2 2 5
2 4 7 2 4 7
2 4 7 2 4 2
2 4 7 3 4 5
2 4 7 1 4 2
2 4 7 2 4 5
2 5 8 2 5 8
2 5 8 2 5 3
2 5 8 3 5 6
2 5 8 1 5 3
2 5 8 2 5 6
2 5 8 2 5 1
2 5 8 3 5 4
select * from t1;
c1 c2 c3
1 1 1
3 2 2
1 3 3
2 1 4
2 2 5
4 3 6
2 4 7
2 5 8
delete from t1 using t1,t3
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
select * from t1;
c1 c2 c3
1 1 1
3 2 2
1 3 3
4 3 6
truncate table t1;
insert into t1 select * from t;
analyze table t1 persistent for all;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status Table is already up to date
update t1,t3 set t1.c1 = t1.c1+10
where t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
select * from t1;
c1 c2 c3
1 1 1
3 2 2
1 3 3
12 1 4
12 2 5
4 3 6
12 4 7
12 5 8
drop table t1,t2,t3,t;
# End of 10.4 tests
......@@ -1130,3 +1130,73 @@ EXPLAIN FORMAT=JSON UPDATE t2 JOIN t1 USING(a) SET t2.part=2 WHERE t2.part=1 AND
EXPLAIN FORMAT=JSON UPDATE t2 JOIN t1 USING(a) SET t2.part=3 WHERE t2.part=2 AND t1.part=2;
DROP TABLES t1, t2;
--echo # End of 10.3 tests
--echo #
--echo # MDEV-28538: multi-table UPDATE/DELETE with possible exists-to-in
--echo #
create table t1 (c1 int, c2 int, c3 int, index idx(c2));
insert into t1 values
(1,1,1),(3,2,2),(1,3,3),
(2,1,4),(2,2,5),(4,3,6),
(2,4,7),(2,5,8);
create table t2 (c1 int, c2 int, c3 int, index idx(c2));
insert into t2 values
(1,7,1),(1,8,2),(1,3,3),
(2,1,4),(2,2,5),(2,3,6),
(2,4,7),(2,5,8);
create table t3 (c1 int, c2 int, c3 int, index idx(c2));
insert into t3 values
(1,1,1),(1,2,2),(1,3,3),
(2,1,4),(2,2,5),(2,3,6),
(2,4,7),(2,5,8);
insert into t3 select c1+1, c2+2, c3 from t3;
insert into t3 select c1, c2+2, c3 from t3;
analyze table t1,t2,t3 persistent for all;
let $c=
t1.c2 = t3.c2 and
t1.c1 > 1 and
exists (select 'X' from t2 where t2.c1 = t1.c1 and t2.c2 > 4);
let $q1=
select * from t1,t3
where $c;
eval explain $q1;
let $q2=
delete from t1 using t1,t3
where $c;
eval explain $q2;
let $q3=
update t1,t3 set t1.c1 = t1.c1+10
where $c;
eval explain $q3;
create table t as select * from t1;
eval $q1;
select * from t1;
eval $q2;
select * from t1;
truncate table t1;
insert into t1 select * from t;
analyze table t1 persistent for all;
eval $q3;
select * from t1;
drop table t1,t2,t3,t;
--echo # End of 10.4 tests
......@@ -76,7 +76,8 @@ rollback;
explain update t1 set c1=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 > 3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 Using where
2 DEPENDENT SUBQUERY a ALL NULL NULL NULL NULL 8 Using where
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED a ALL NULL NULL NULL NULL 8
start transaction;
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
affected rows: 4
......@@ -317,7 +318,8 @@ rollback;
explain update t1 set c1=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 > 3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 range t1_c2 t1_c2 5 NULL 2 Using where
2 DEPENDENT SUBQUERY a ref t1_c2 t1_c2 5 test.t1.c2 4 Using index
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED a range t1_c2 t1_c2 5 NULL 2 Using where; Using index
start transaction;
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
affected rows: 4
......@@ -558,7 +560,8 @@ rollback;
explain update t1 set c1=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 > 3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 range t1_c2 t1_c2 5 NULL 2 Using where
2 DEPENDENT SUBQUERY a ref t1_c2 t1_c2 5 test.t1.c2 1 Using index
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED a range t1_c2 t1_c2 5 NULL 2 Using where; Using index
start transaction;
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
affected rows: 4
......@@ -800,7 +803,8 @@ rollback;
explain update t1 set c1=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 > 3;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 range t1_c2 t1_c2 5 NULL 2 Using where
2 DEPENDENT SUBQUERY a ref t1_c2 t1_c2 5 test.t1.c2 1 Using index
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED a range t1_c2 t1_c2 5 NULL 2 Using where; Using index
start transaction;
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
affected rows: 4
......
......@@ -2825,7 +2825,9 @@ bool Item_exists_subselect::select_prepare_to_be_in()
bool trans_res= FALSE;
DBUG_ENTER("Item_exists_subselect::select_prepare_to_be_in");
if (!optimizer &&
thd->lex->sql_command == SQLCOM_SELECT &&
(thd->lex->sql_command == SQLCOM_SELECT ||
thd->lex->sql_command == SQLCOM_UPDATE_MULTI ||
thd->lex->sql_command == SQLCOM_DELETE_MULTI) &&
!unit->first_select()->is_part_of_union() &&
optimizer_flag(thd, OPTIMIZER_SWITCH_EXISTS_TO_IN) &&
(is_top_level_item() ||
......
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