Commit 8d7462ec authored by Igor Babaev's avatar Igor Babaev

MDEV-21614 Wrong query results with optimizer_switch="split_materialized=on"

Do not materialize a semi-join nest if it contains a materialized derived
table /view that potentially can be subject to the split optimization.
Splitting of materialization of such nest would help, but currently there
is no code to support this technique.
parent fafb35ee
...@@ -16829,4 +16829,93 @@ id username id userid logindate ...@@ -16829,4 +16829,93 @@ id username id userid logindate
2 user2 3 2 2017-06-19 12:17:02 2 user2 3 2 2017-06-19 12:17:02
set join_cache_level=default; set join_cache_level=default;
DROP TABLE t1,t2; DROP TABLE t1,t2;
#
# MDEV-21614: potentially splittable materialized derived/view
# within materialized semi-join
#
create table t1 (
id int not null auto_increment primary key,
a int not null
) engine=myisam;
create table t2 (
id int not null auto_increment primary key,
ro_id int not null,
flag int not null, key (ro_id)
) engine=myisam;
insert into t1(a) select seq+100 from seq_1_to_20;
insert into t2(ro_id,flag) select seq, 1 from seq_1_to_20;
insert into t2(ro_id,flag) select seq, 0 from seq_1_to_20;
create view v1 as
select t1.* from t1 left join t2 on (t1.id = t2.ro_id AND t2.flag = 1)
group by t1.id;
select id, a from t1 where id in (select id from v1);
id a
1 101
2 102
3 103
4 104
5 105
6 106
7 107
8 108
9 109
10 110
11 111
12 112
13 113
14 114
15 115
16 116
17 117
18 118
19 119
20 120
explain extended select id, a from t1 where id in (select id from v1);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 20 100.00
1 PRIMARY <derived3> ref key0 key0 4 test.t1.id 2 100.00 FirstMatch(t1)
3 LATERAL DERIVED t1 eq_ref PRIMARY PRIMARY 4 test.t1.id 1 100.00
3 LATERAL DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` semi join (`test`.`v1`) where `v1`.`id` = `test`.`t1`.`id`
select id, a from t1
where id in (select id
from (select t1.* from t1 left join t2
on (t1.id = t2.ro_id AND t2.flag = 1)
group by t1.id) dt);
id a
1 101
2 102
3 103
4 104
5 105
6 106
7 107
8 108
9 109
10 110
11 111
12 112
13 113
14 114
15 115
16 116
17 117
18 118
19 119
20 120
explain extended select id, a from t1
where id in (select id
from (select t1.* from t1 left join t2
on (t1.id = t2.ro_id AND t2.flag = 1)
group by t1.id) dt);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL PRIMARY NULL NULL NULL 20 100.00
1 PRIMARY <derived3> ref key0 key0 4 test.t1.id 2 100.00 FirstMatch(t1)
3 LATERAL DERIVED t1 eq_ref PRIMARY PRIMARY 4 test.t1.id 1 100.00
3 LATERAL DERIVED t2 ref ro_id ro_id 4 test.t1.id 1 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` semi join ((/* select#3 */ select `test`.`t1`.`id` AS `id`,`test`.`t1`.`a` AS `a` from `test`.`t1` left join `test`.`t2` on(`test`.`t2`.`ro_id` = `test`.`t1`.`id` and `test`.`t2`.`flag` = 1) where `test`.`t1`.`id` = `test`.`t1`.`id` group by `test`.`t1`.`id`) `dt`) where `dt`.`id` = `test`.`t1`.`id`
drop view v1;
drop table t1,t2;
# End of 10.3 tests # End of 10.3 tests
--source include/have_sequence.inc
--source include/default_optimizer_switch.inc --source include/default_optimizer_switch.inc
let $no_pushdown= set statement optimizer_switch='condition_pushdown_for_derived=off' for; let $no_pushdown= set statement optimizer_switch='condition_pushdown_for_derived=off' for;
set @@join_buffer_size=256*1024; set @@join_buffer_size=256*1024;
...@@ -3328,4 +3329,46 @@ set join_cache_level=default; ...@@ -3328,4 +3329,46 @@ set join_cache_level=default;
DROP TABLE t1,t2; DROP TABLE t1,t2;
--echo #
--echo # MDEV-21614: potentially splittable materialized derived/view
--echo # within materialized semi-join
--echo #
create table t1 (
id int not null auto_increment primary key,
a int not null
) engine=myisam;
create table t2 (
id int not null auto_increment primary key,
ro_id int not null,
flag int not null, key (ro_id)
) engine=myisam;
insert into t1(a) select seq+100 from seq_1_to_20;
insert into t2(ro_id,flag) select seq, 1 from seq_1_to_20;
insert into t2(ro_id,flag) select seq, 0 from seq_1_to_20;
create view v1 as
select t1.* from t1 left join t2 on (t1.id = t2.ro_id AND t2.flag = 1)
group by t1.id;
let $q1=
select id, a from t1 where id in (select id from v1);
eval $q1;
eval explain extended $q1;
let $q2=
select id, a from t1
where id in (select id
from (select t1.* from t1 left join t2
on (t1.id = t2.ro_id AND t2.flag = 1)
group by t1.id) dt);
eval $q2;
eval explain extended $q2;
drop view v1;
drop table t1,t2;
--echo # End of 10.3 tests --echo # End of 10.3 tests
...@@ -477,6 +477,15 @@ bool JOIN::check_for_splittable_materialized() ...@@ -477,6 +477,15 @@ bool JOIN::check_for_splittable_materialized()
/* Attach this info to the table T */ /* Attach this info to the table T */
derived->table->set_spl_opt_info(spl_opt_info); derived->table->set_spl_opt_info(spl_opt_info);
/*
If this is specification of a materialized derived table T that is
potentially splittable and is used in the from list of the right operand
of an IN predicand transformed to a semi-join then the embedding semi-join
nest is not allowed to be materialized.
*/
if (derived && derived->is_materialized_derived() &&
derived->embedding && derived->embedding->sj_subq_pred)
derived->embedding->sj_subq_pred->types_allow_materialization= FALSE;
return true; return true;
} }
......
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