Commit 6b97fe06 authored by Igor Babaev's avatar Igor Babaev

Fixed the bugs mdev-12670 and mdev-12675.

The code that blocked conversion of a IN subselect pedicate to a semi-join
if it occurred in the ON expression of an outer join did not do it correctly.
As a result, the conversion was blocked for IN subselect predicates
encountered in ON expressions of INNER joins or in WHERE conditions
of mergeable views / derived tables. This patch fixes this problem.
parent 15f9931f
......@@ -2579,5 +2579,43 @@ Handler_read_rnd_deleted 0
Handler_read_rnd_next 27
deallocate prepare stmt1;
drop table t1,t2;
#
# Bug mdev-12670: mergeable derived / view with subqueries
# subject to semi-join optimizations
# (actually this is a 5.3 bug.)
#
create table t1 (a int) engine=myisam;
insert into t1 values (5),(3),(2),(7),(2),(5),(1);
create table t2 (b int, index idx(b)) engine=myisam;
insert into t2 values (2),(3),(2),(1),(3),(4);
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
analyze table t1,t2;
Table Op Msg_type Msg_text
test.t1 analyze status OK
test.t2 analyze status OK
explain select a from t1 where a in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7 Using where
1 PRIMARY t2 ref idx idx 5 test.t1.a 140 Using index; FirstMatch(t1)
explain select * from (select a from t1 where a in (select b from t2)) t;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
1 SIMPLE t2 ref idx idx 5 test.t1.a 140 Using index; FirstMatch(t1)
create view v1 as select a from t1 where a in (select b from t2);
explain select * from v1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where
1 SIMPLE t2 ref idx idx 5 test.t1.a 140 Using index; FirstMatch(t1)
drop view v1;
drop table t1,t2;
set optimizer_switch=@exit_optimizer_switch;
set join_cache_level=@exit_join_cache_level;
......@@ -426,7 +426,7 @@ c1
bb
cc
Warnings:
Warning 1931 Query execution was interrupted. The query examined at least 18 rows, which exceeds LIMIT ROWS EXAMINED (16). The query result may be incomplete.
Warning 1931 Query execution was interrupted. The query examined at least 17 rows, which exceeds LIMIT ROWS EXAMINED (16). The query result may be incomplete.
select * from v1 LIMIT ROWS EXAMINED 11;
c1
bb
......@@ -439,7 +439,8 @@ from (select * from t1
where c1 IN (select * from t2 where c2 > ' ' LIMIT ROWS EXAMINED 0)) as tmp
LIMIT ROWS EXAMINED 11;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using where
1 SIMPLE t1 ALL NULL NULL NULL NULL 4
1 SIMPLE <subquery3> eq_ref distinct_key distinct_key 2 func 1
3 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 Using where
select *
from (select * from t1
......
......@@ -1650,9 +1650,9 @@ CREATE VIEW v1 AS SELECT 1;
EXPLAIN
SELECT * FROM t1 INNER JOIN t2 ON t2.a != 0 AND t2.a IN (SELECT * FROM v1);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived3> system NULL NULL NULL NULL 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 2
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
2 MATERIALIZED <derived3> system NULL NULL NULL NULL 1
3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used
SELECT * FROM t1 INNER JOIN t2 ON t2.a != 0 AND t2.a IN (SELECT * FROM v1);
a a
......@@ -3060,4 +3060,43 @@ project_number
aaa
drop table t1, t2, t3;
set optimizer_switch= @tmp_mdev6859;
#
# MDEV-12675: subquery subject to semi-join optimizations
# in ON expression of INNER JOIN
#
set @tmp_mdev12675=@@optimizer_switch;
set optimizer_switch=default;
create table t1 (a int) engine=myisam;
insert into t1 values (5),(3),(2),(7),(2),(5),(1);
create table t2 (b int, index idx(b)) engine=myisam;
insert into t2 values (2),(3),(2),(1),(3),(4);
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
analyze table t1,t2;
Table Op Msg_type Msg_text
test.t1 analyze status OK
test.t2 analyze status OK
explain
select a from t1, t2 where b between 1 and 2 and a in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7 Using where
1 PRIMARY t2 ref idx idx 5 test.t1.a 256 Using index; FirstMatch(t1)
1 PRIMARY t2 range idx idx 5 NULL 2 Using where; Using index; Using join buffer (flat, BNL join)
explain
select a from t1 join t2 on b between 1 and 2 and a in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7 Using where
1 PRIMARY t2 ref idx idx 5 test.t1.a 256 Using index; FirstMatch(t1)
1 PRIMARY t2 range idx idx 5 NULL 2 Using where; Using index; Using join buffer (flat, BNL join)
drop table t1,t2;
set optimizer_switch= @tmp_mdev12675;
set optimizer_switch=@subselect_sj_tmp;
......@@ -1663,9 +1663,9 @@ CREATE VIEW v1 AS SELECT 1;
EXPLAIN
SELECT * FROM t1 INNER JOIN t2 ON t2.a != 0 AND t2.a IN (SELECT * FROM v1);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived3> system NULL NULL NULL NULL 1
1 PRIMARY t1 ALL NULL NULL NULL NULL 2
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
2 MATERIALIZED <derived3> system NULL NULL NULL NULL 1
3 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used
SELECT * FROM t1 INNER JOIN t2 ON t2.a != 0 AND t2.a IN (SELECT * FROM v1);
a a
......@@ -3074,6 +3074,45 @@ project_number
aaa
drop table t1, t2, t3;
set optimizer_switch= @tmp_mdev6859;
#
# MDEV-12675: subquery subject to semi-join optimizations
# in ON expression of INNER JOIN
#
set @tmp_mdev12675=@@optimizer_switch;
set optimizer_switch=default;
create table t1 (a int) engine=myisam;
insert into t1 values (5),(3),(2),(7),(2),(5),(1);
create table t2 (b int, index idx(b)) engine=myisam;
insert into t2 values (2),(3),(2),(1),(3),(4);
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
analyze table t1,t2;
Table Op Msg_type Msg_text
test.t1 analyze status OK
test.t2 analyze status OK
explain
select a from t1, t2 where b between 1 and 2 and a in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7 Using where
1 PRIMARY t2 ref idx idx 5 test.t1.a 256 Using index; FirstMatch(t1)
1 PRIMARY t2 range idx idx 5 NULL 2 Using where; Using index; Using join buffer (flat, BNL join)
explain
select a from t1 join t2 on b between 1 and 2 and a in (select b from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 7 Using where
1 PRIMARY t2 ref idx idx 5 test.t1.a 256 Using index; FirstMatch(t1)
1 PRIMARY t2 range idx idx 5 NULL 2 Using where; Using index; Using join buffer (flat, BNL join)
drop table t1,t2;
set optimizer_switch= @tmp_mdev12675;
set optimizer_switch=@subselect_sj_tmp;
#
# BUG#49129: Wrong result with IN-subquery with join_cache_level=6 and firstmatch=off
......
......@@ -1881,6 +1881,36 @@ deallocate prepare stmt1;
drop table t1,t2;
--echo #
--echo # Bug mdev-12670: mergeable derived / view with subqueries
--echo # subject to semi-join optimizations
--echo # (actually this is a 5.3 bug.)
--echo #
create table t1 (a int) engine=myisam;
insert into t1 values (5),(3),(2),(7),(2),(5),(1);
create table t2 (b int, index idx(b)) engine=myisam;
insert into t2 values (2),(3),(2),(1),(3),(4);
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
analyze table t1,t2;
explain select a from t1 where a in (select b from t2);
explain select * from (select a from t1 where a in (select b from t2)) t;
create view v1 as select a from t1 where a in (select b from t2);
explain select * from v1;
drop view v1;
drop table t1,t2;
# The following command must be the last one the file
set optimizer_switch=@exit_optimizer_switch;
set join_cache_level=@exit_join_cache_level;
......@@ -2769,5 +2769,37 @@ WHERE ( SELECT z.country
drop table t1, t2, t3;
set optimizer_switch= @tmp_mdev6859;
--echo #
--echo # MDEV-12675: subquery subject to semi-join optimizations
--echo # in ON expression of INNER JOIN
--echo #
set @tmp_mdev12675=@@optimizer_switch;
set optimizer_switch=default;
create table t1 (a int) engine=myisam;
insert into t1 values (5),(3),(2),(7),(2),(5),(1);
create table t2 (b int, index idx(b)) engine=myisam;
insert into t2 values (2),(3),(2),(1),(3),(4);
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
insert into t2 select b+10 from t2;
analyze table t1,t2;
explain
select a from t1, t2 where b between 1 and 2 and a in (select b from t2);
explain
select a from t1 join t2 on b between 1 and 2 and a in (select b from t2);
drop table t1,t2;
set optimizer_switch= @tmp_mdev12675;
# The following command must be the last one the file
set optimizer_switch=@subselect_sj_tmp;
......@@ -1366,7 +1366,7 @@ Item_in_subselect::Item_in_subselect(Item * left_exp,
Item_exists_subselect(),
left_expr_cache(0), first_execution(TRUE), in_strategy(SUBS_NOT_TRANSFORMED),
optimizer(0), pushed_cond_guards(NULL), emb_on_expr_nest(NULL),
is_jtbm_merged(FALSE), is_jtbm_const_tab(FALSE),
do_not_convert_to_sj(FALSE), is_jtbm_merged(FALSE), is_jtbm_const_tab(FALSE),
is_flattenable_semijoin(FALSE),
is_registered_semijoin(FALSE),
upper_item(0)
......
......@@ -466,6 +466,8 @@ class Item_in_subselect :public Item_exists_subselect
NULL - for all other locations
*/
TABLE_LIST *emb_on_expr_nest;
/* May be TRUE only for the candidates to semi-join conversion */
bool do_not_convert_to_sj;
/*
Types of left_expr and subquery's select list allow to perform subquery
materialization. Currently, we set this to FALSE when it as well could
......@@ -555,8 +557,8 @@ class Item_in_subselect :public Item_exists_subselect
:Item_exists_subselect(), left_expr_cache(0), first_execution(TRUE),
abort_on_null(0), in_strategy(SUBS_NOT_TRANSFORMED), optimizer(0),
pushed_cond_guards(NULL), func(NULL), emb_on_expr_nest(NULL),
is_jtbm_merged(FALSE), is_jtbm_const_tab(FALSE),
upper_item(0)
do_not_convert_to_sj(FALSE), is_jtbm_merged(FALSE),
is_jtbm_const_tab(FALSE), upper_item(0)
{}
void cleanup();
subs_type substype() { return IN_SUBS; }
......@@ -617,6 +619,8 @@ class Item_in_subselect :public Item_exists_subselect
emb_on_expr_nest= embedding;
}
void block_conversion_to_sj () { do_not_convert_to_sj= TRUE; }
bool test_strategy(uchar strategy)
{ return test(in_strategy & strategy); }
......
......@@ -678,6 +678,7 @@ int check_and_do_in_subquery_rewrites(JOIN *join)
!((join->select_options | // 10
select_lex->outer_select()->join->select_options) // 10
& SELECT_STRAIGHT_JOIN)) // 10
{
DBUG_PRINT("info", ("Subquery is semi-join conversion candidate"));
......@@ -1000,6 +1001,25 @@ bool check_for_outer_joins(List<TABLE_LIST> *join_list)
}
void find_and_block_conversion_to_sj(Item *to_find,
List_iterator_fast<Item_in_subselect> &li)
{
if (to_find->type() != Item::SUBSELECT_ITEM ||
((Item_subselect *) to_find)->substype() != Item_subselect::IN_SUBS)
return;
Item_in_subselect *in_subq;
li.rewind();
while ((in_subq= li++))
{
if (in_subq == to_find)
{
in_subq->block_conversion_to_sj();
return;
}
}
}
/*
Convert semi-join subquery predicates into semi-join join nests
......@@ -1052,7 +1072,6 @@ bool convert_join_subqueries_to_semijoins(JOIN *join)
Query_arena *arena, backup;
Item_in_subselect *in_subq;
THD *thd= join->thd;
List_iterator<TABLE_LIST> ti(join->select_lex->leaf_tables);
DBUG_ENTER("convert_join_subqueries_to_semijoins");
if (join->select_lex->sj_subselects.is_empty())
......@@ -1070,6 +1089,60 @@ bool convert_join_subqueries_to_semijoins(JOIN *join)
subq_sel->update_used_tables();
}
/*
Check all candidates to semi-join conversion that occur
in ON expressions of outer join. Set the flag blocking
this conversion for them.
*/
TABLE_LIST *tbl;
List_iterator<TABLE_LIST> ti(join->select_lex->leaf_tables);
while ((tbl= ti++))
{
TABLE_LIST *embedded;
TABLE_LIST *embedding= tbl;
do
{
embedded= embedding;
if (test(embedded->outer_join))
{
Item *cond= embedded->on_expr;
if (!cond)
;
else if (cond->type() != Item::COND_ITEM)
find_and_block_conversion_to_sj(cond, li);
else if (((Item_cond*) cond)->functype() ==
Item_func::COND_AND_FUNC)
{
Item *item;
List_iterator<Item> it(*(((Item_cond*) cond)->argument_list()));
while ((item= it++))
{
find_and_block_conversion_to_sj(item, li);
}
}
}
embedding= embedded->embedding;
}
while (embedding &&
embedding->nested_join->join_list.head() == embedded);
}
/*
Block conversion to semi-joins for those candidates that
are encountered in the WHERE condition of the multi-table view
with CHECK OPTION if this view is used in UPDATE/DELETE.
(This limitation can be, probably, easily lifted.)
*/
li.rewind();
while ((in_subq= li++))
{
if (in_subq->emb_on_expr_nest != NO_JOIN_NEST &&
in_subq->emb_on_expr_nest->effective_with_check)
{
in_subq->block_conversion_to_sj();
}
}
li.rewind();
/* First, convert child join's subqueries. We proceed bottom-up here */
while ((in_subq= li++))
......@@ -1088,8 +1161,10 @@ bool convert_join_subqueries_to_semijoins(JOIN *join)
if (convert_join_subqueries_to_semijoins(child_join))
DBUG_RETURN(TRUE);
in_subq->sj_convert_priority=
test(in_subq->emb_on_expr_nest != NO_JOIN_NEST) * MAX_TABLES * 2 +
test(in_subq->do_not_convert_to_sj) * MAX_TABLES * 2 +
in_subq->is_correlated * MAX_TABLES + child_join->outer_tables;
}
......@@ -1122,7 +1197,7 @@ bool convert_join_subqueries_to_semijoins(JOIN *join)
bool remove_item= TRUE;
/* Stop processing if we've reached a subquery that's attached to the ON clause */
if (in_subq->emb_on_expr_nest != NO_JOIN_NEST)
if (in_subq->do_not_convert_to_sj)
break;
if (in_subq->is_flattenable_semijoin)
......
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