Commit 5e4aa1a2 authored by Igor Babaev's avatar Igor Babaev

Fixed the bug mdev-13709.

Currently condition pushdown into materialized views / derived tables
is not implemented yet (see mdev-12387) and grouping views are
optimized early when subqueries are converted to semi-joins in
convert_join_subqueries_to_semijoins(). If a subquery that is converted
to a semi-join uses a grouping view this view is optimized in two phases.
For such a view V only the first phase of optimization is done after
the conversion of subqueries of the outer join into semi-joins.
At the same time the reference of the view V appears in the join
expression of the outer join. In fixed code there was an attempt to push
conditions into this view and to optimize it after this. This triggered
the second phase of the optimization of the view and it was done
prematurely. The second phase of the optimization for the materialized
view is supposed to be called after the splitting condition is pushed
into the view in the call of JOIN::improve_chosen_plan for the outer
join.

The fix blocks the attempt to push conditions into splittable views
if they have been already partly optimized and the following
optimization for them.

The test case of the patch shows that the code for mdev-13369
basically supported the splitting technique for materialized views /
derived tables.

The patch also replaces the name of the state JOIN::OPTIMIZATION_IN_STAGE_2
for JOIN::OPTIMIZATION_PHASE_1_DONE and fixes a bug in
TABLE_LIST::fetch_number_of_rows()
parent fb14761d
......@@ -10041,3 +10041,111 @@ EXPLAIN
}
}
drop table t1,t2,t3,t4;
#
# MDEV-13709: Optimization for semi-joins of grouping derived tables
# (Splitting derived tables / views with GROUP BY)
#
CREATE TABLE t1 (i int);
INSERT INTO t1 VALUES (1),(9),(3);
CREATE TABLE t2 (a int, i int);
INSERT INTO t2 VALUES (1,9),(2,3),(3,7),(4,1);
CREATE TABLE t3 (a int, c varchar(8), index(c));
INSERT INTO t3 VALUES (1,'foo'),(3,'bar'),(4,'foo'),(2,'bar');
CREATE TABLE t4 (c varchar(8));
INSERT INTO t4 VALUES ('abc'),('foo'),('def');
CREATE VIEW v1 AS
SELECT c FROM t3
WHERE a IN ( SELECT t2.a FROM t1 JOIN t2 WHERE t1.i = t2.i ) GROUP BY c ;
set statement optimizer_switch='split_grouping_derived=off' for SELECT * FROM t4 WHERE c IN ( SELECT c FROM v1 );
c
foo
SELECT * FROM t4 WHERE c IN ( SELECT c FROM v1 );
c
foo
explain extended SELECT * FROM t4 WHERE c IN ( SELECT c FROM v1 );
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t4 ALL NULL NULL NULL NULL 3 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 11 test.t4.c 4 100.00 FirstMatch(t4)
3 LATERAL DERIVED t3 ALL c NULL NULL NULL 4 75.00 Using where
3 LATERAL DERIVED <subquery4> eq_ref distinct_key distinct_key 4 func 1 100.00
4 MATERIALIZED t1 ALL NULL NULL NULL NULL 3 100.00
4 MATERIALIZED t2 ALL NULL NULL NULL NULL 4 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 /* select#1 */ select `test`.`t4`.`c` AS `c` from `test`.`t4` semi join (`test`.`v1`) where `v1`.`c` = `test`.`t4`.`c`
explain format=json SELECT * FROM t4 WHERE c IN ( SELECT c FROM v1 );
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t4",
"access_type": "ALL",
"rows": 3,
"filtered": 100,
"attached_condition": "t4.c is not null"
},
"table": {
"table_name": "<derived3>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "11",
"used_key_parts": ["c"],
"ref": ["test.t4.c"],
"rows": 4,
"filtered": 100,
"first_match": "t4",
"materialized": {
"query_block": {
"select_id": 3,
"const_condition": "1",
"table": {
"table_name": "t3",
"access_type": "ALL",
"possible_keys": ["c"],
"rows": 4,
"filtered": 75,
"attached_condition": "t3.c = t4.c"
},
"table": {
"table_name": "<subquery4>",
"access_type": "eq_ref",
"possible_keys": ["distinct_key"],
"key": "distinct_key",
"key_length": "4",
"used_key_parts": ["a"],
"ref": ["func"],
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 4,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 3,
"filtered": 100
},
"block-nl-join": {
"table": {
"table_name": "t2",
"access_type": "ALL",
"rows": 4,
"filtered": 100
},
"buffer_type": "flat",
"buffer_size": "256Kb",
"join_type": "BNL",
"attached_condition": "t2.i = t1.i and t2.i = t1.i"
}
}
}
}
}
}
}
}
}
DROP VIEW v1;
DROP TABLE t1,t2,t3,t4;
......@@ -1762,3 +1762,35 @@ eval explain extended $q6;
eval explain format=json $q6;
drop table t1,t2,t3,t4;
--echo #
--echo # MDEV-13709: Optimization for semi-joins of grouping derived tables
--echo # (Splitting derived tables / views with GROUP BY)
--echo #
CREATE TABLE t1 (i int);
INSERT INTO t1 VALUES (1),(9),(3);
CREATE TABLE t2 (a int, i int);
INSERT INTO t2 VALUES (1,9),(2,3),(3,7),(4,1);
CREATE TABLE t3 (a int, c varchar(8), index(c));
INSERT INTO t3 VALUES (1,'foo'),(3,'bar'),(4,'foo'),(2,'bar');
CREATE TABLE t4 (c varchar(8));
INSERT INTO t4 VALUES ('abc'),('foo'),('def');
CREATE VIEW v1 AS
SELECT c FROM t3
WHERE a IN ( SELECT t2.a FROM t1 JOIN t2 WHERE t1.i = t2.i ) GROUP BY c ;
let $q1=
SELECT * FROM t4 WHERE c IN ( SELECT c FROM v1 );
eval $no_splitting $q1;
eval $q1;
eval explain extended $q1;
eval explain format=json $q1;
DROP VIEW v1;
DROP TABLE t1,t2,t3,t4;
......@@ -891,7 +891,7 @@ bool mysql_derived_optimize(THD *thd, LEX *lex, TABLE_LIST *derived)
JOIN *join= first_select->join;
unit->set_limit(unit->global_parameters());
if (join &&
join->optimization_state == JOIN::OPTIMIZATION_IN_STAGE_2 &&
join->optimization_state == JOIN::OPTIMIZATION_PHASE_1_DONE &&
join->with_two_phase_optimization)
{
if (unit->optimized_2)
......
......@@ -1109,7 +1109,7 @@ int JOIN::optimize()
{
int res= 0;
join_optimization_state init_state= optimization_state;
if (optimization_state == JOIN::OPTIMIZATION_IN_STAGE_2)
if (optimization_state == JOIN::OPTIMIZATION_PHASE_1_DONE)
res= optimize_stage2();
else
{
......@@ -1121,7 +1121,7 @@ int JOIN::optimize()
res= optimize_inner();
}
if (!with_two_phase_optimization ||
init_state == JOIN::OPTIMIZATION_IN_STAGE_2)
init_state == JOIN::OPTIMIZATION_PHASE_1_DONE)
{
if (!res && have_query_plan != QEP_DELETED)
build_explain();
......@@ -1339,6 +1339,11 @@ JOIN::optimize_inner()
*/
if (tbl->is_materialized_derived())
{
JOIN *join= tbl->get_unit()->first_select()->join;
if (join &&
join->optimization_state == JOIN::OPTIMIZATION_PHASE_1_DONE &&
join->with_two_phase_optimization)
continue;
/*
Do not push conditions from where into materialized inner tables
of outer joins: this is not valid.
......@@ -1533,7 +1538,7 @@ JOIN::optimize_inner()
setup_subq_exit:
with_two_phase_optimization= check_two_phase_optimization(thd);
if (with_two_phase_optimization)
optimization_state= JOIN::OPTIMIZATION_IN_STAGE_2;
optimization_state= JOIN::OPTIMIZATION_PHASE_1_DONE;
else
{
if (optimize_stage2())
......@@ -1554,7 +1559,7 @@ int JOIN::optimize_stage2()
goto setup_subq_exit;
if (select_lex->handle_derived(thd->lex, DT_OPTIMIZE))
DBUG_RETURN(1);
DBUG_RETURN(1);
if (thd->check_killed())
DBUG_RETURN(1);
......
......@@ -1383,7 +1383,7 @@ class JOIN :public Sql_alloc
enum join_optimization_state { NOT_OPTIMIZED=0,
OPTIMIZATION_IN_PROGRESS=1,
OPTIMIZATION_IN_STAGE_2=2,
OPTIMIZATION_PHASE_1_DONE=2,
OPTIMIZATION_DONE=3};
// state of JOIN optimization
enum join_optimization_state optimization_state;
......
......@@ -7954,9 +7954,8 @@ int TABLE_LIST::fetch_number_of_rows()
if (jtbm_subselect)
return 0;
if (is_materialized_derived() && !fill_me)
{
table->file->stats.records= ((select_unit*)derived->result)->records;
table->file->stats.records= ((select_unit*)(get_unit()->result))->records;
set_if_bigger(table->file->stats.records, 2);
table->used_stat_records= table->file->stats.records;
}
......
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