1
0
mirror of https://github.com/MariaDB/server.git synced 2025-08-01 03:47:19 +03:00

This first patch prepared for the task MDEV-13369:

"Optimization for equi-joins of derived tables with GROUP BY"
should be considered rather as a 'proof of concept'.

The task itself is targeted at an optimization that employs re-writing
equi-joins with grouping derived tables / views into lateral
derived tables. Here's an example of such transformation:
  select t1.a,t.max,t.min
  from t1 [left] join
       (select a, max(t2.b) max, min(t2.b) min from t2
       group by t2.a) as t
       on t1.a=t.a;
=>
  select t1.a,tl.max,tl.min
  from t1 [left] join
       lateral (select a, max(t2.b) max, min(t2.b) min from t2
                where  t1.a=t2.a) as t
       on 1=1;
The transformation pushes the equi-join condition t1.a=t.a into the
derived table making it dependent on table t1. It means that for
every row from t1 a new derived table must be filled out. However
the size of any of these derived tables is just a fraction of the
original derived table t. One could say that transformation 'splits'
the rows used for the GROUP BY operation into separate groups
performing aggregation for a group only in the case when there is
a match for the current row of t1.
Apparently the transformation may produce a query with a better
performance only in the case when
 - the GROUP BY list refers only to fields returned by the derived table
 - there is an index I on one of the tables T used in FROM list of
   the specification of the derived table whose prefix covers the
   the fields from the proper beginning of the GROUP BY list or
   fields that are equal to those fields.
Whether the result of the re-writing can be executed faster depends
on many factors:
  - the size of the original derived table
  - the size of the table T
  - whether the index I is clustering for table T
  - whether the index I fully covers the GROUP BY list.

This patch only tries to improve the chosen execution plan using
this transformation. It tries to do it only when the chosen
plan reaches the derived table by a key whose prefix covers
all the fields of the derived table produced by the fields of
the table T from the GROUP BY list.
The code of the patch does not evaluates the cost of the improved
plan. If certain conditions are met the transformation is applied.
This commit is contained in:
Igor Babaev
2017-08-03 21:19:19 -07:00
parent 6685cdc250
commit b14e2b044b
13 changed files with 948 additions and 51 deletions

View File

@ -8782,3 +8782,441 @@ EXPLAIN
}
DROP VIEW v2;
DROP TABLE t1,t2;
#
# MDEV-13369: Optimization for equi-joins of grouping derived tables
# (Splitting derived tables / views with GROUP BY)
#
create table t1 (a int);
insert into t1 values
(8), (5), (1), (2), (9), (7), (2), (7);
create table t2 (a int, b int, index idx(a));
insert into t2 values
(7,10), (1,20), (2,23), (7,18), (1,30),
(4,71), (3,15), (7,82), (8,12), (4,15),
(11,33), (10,42), (4,53), (10,17), (2,90);
set statement optimizer_switch='split_grouping_derived=off' for select t1.a,t.max,t.min
from t1 join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
a max min
8 12 12
1 30 20
2 90 23
7 82 10
2 90 23
7 82 10
select t1.a,t.max,t.min
from t1 join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
a max min
8 12 12
1 30 20
2 90 23
7 82 10
2 90 23
7 82 10
explain extended select t1.a,t.max,t.min
from t1 join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 100.00 Using where
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 100.00
2 LATERAL DERIVED t2 ref idx idx 5 test.t1.a 2 100.00
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t1` join (/* select#2 */ select `test`.`t2`.`a` AS `a`,max(`test`.`t2`.`b`) AS `max`,min(`test`.`t2`.`b`) AS `min` from `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` group by `test`.`t2`.`a`) `t` where `t`.`a` = `test`.`t1`.`a`
explain format=json select t1.a,t.max,t.min
from t1 join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t1.a is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
"outer_ref_condition": "t1.a is not null",
"table": {
"table_name": "t2",
"access_type": "ref",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100
}
}
}
}
}
}
set statement optimizer_switch='split_grouping_derived=off' for select t1.a,t.max,t.min
from t1 left join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
a max min
8 12 12
5 NULL NULL
1 30 20
2 90 23
9 NULL NULL
7 82 10
2 90 23
7 82 10
select t1.a,t.max,t.min
from t1 left join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
a max min
8 12 12
5 NULL NULL
1 30 20
2 90 23
9 NULL NULL
7 82 10
2 90 23
7 82 10
explain extended select t1.a,t.max,t.min
from t1 left join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 8 100.00
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2 100.00 Using where
2 LATERAL DERIVED t2 ref idx idx 5 test.t1.a 2 100.00
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t1` left join (/* select#2 */ select `test`.`t2`.`a` AS `a`,max(`test`.`t2`.`b`) AS `max`,min(`test`.`t2`.`b`) AS `min` from `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` group by `test`.`t2`.`a`) `t` on(`t`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` is not null) where 1
explain format=json select t1.a,t.max,t.min
from t1 left join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
EXPLAIN
{
"query_block": {
"select_id": 1,
"const_condition": "1",
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 8,
"filtered": 100
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100,
"attached_condition": "trigcond(trigcond(t1.a is not null))",
"materialized": {
"query_block": {
"select_id": 2,
"outer_ref_condition": "t1.a is not null",
"table": {
"table_name": "t2",
"access_type": "ref",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t1.a"],
"rows": 2,
"filtered": 100
}
}
}
}
}
}
create table t3 (a int, c varchar(16));
insert into t3 values
(8,'aa'), (5,'cc'), (1,'bb'), (2,'aa'), (9,'cc'),
(7,'aa'), (2,'aa'), (7,'bb');
create table t4 (a int, b int, c varchar(16), index idx(a,c));
insert into t4 values
(7,10,'cc'), (1,20,'aa'), (2,23,'bb'), (7,18,'cc'), (1,30,'bb'),
(4,71,'xx'), (3,15,'aa'), (7,82,'bb'), (8,12,'dd'), (4,15,'aa'),
(11,33,'yy'), (10,42,'zz'), (4,53,'xx'), (10,17,'yy'), (7,12,'bb'),
(8,20,'dd'), (7,32,'bb'), (1,50,'aa'), (3,40,'bb'), (3,77,'aa');
set statement optimizer_switch='split_grouping_derived=off' for select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
on t3.a=t.a and t3.c=t.c;
a c max min
1 bb 30 30
7 bb 82 12
select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
on t3.a=t.a and t3.c=t.c;
a c max min
1 bb 30 30
7 bb 82 12
explain extended select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
on t3.a=t.a and t3.c=t.c;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t3 ALL NULL NULL NULL NULL 8 100.00 Using where
1 PRIMARY <derived2> ref key0 key0 24 test.t3.a,test.t3.c 2 100.00
2 LATERAL DERIVED t4 ref idx idx 24 test.t3.a,test.t3.c 2 100.00
Warnings:
Note 1003 /* select#1 */ select `test`.`t3`.`a` AS `a`,`test`.`t3`.`c` AS `c`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t3` join (/* select#2 */ select `test`.`t4`.`a` AS `a`,`test`.`t4`.`c` AS `c`,max(`test`.`t4`.`b`) AS `max`,min(`test`.`t4`.`b`) AS `min` from `test`.`t4` where `test`.`t4`.`a` = `test`.`t3`.`a` and `test`.`t4`.`c` = `test`.`t3`.`c` group by `test`.`t4`.`a`,`test`.`t4`.`c`) `t` where `t`.`a` = `test`.`t3`.`a` and `t`.`c` = `test`.`t3`.`c`
explain format=json select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
on t3.a=t.a and t3.c=t.c;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t3",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t3.a is not null and t3.c is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "24",
"used_key_parts": ["a", "c"],
"ref": ["test.t3.a", "test.t3.c"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
"outer_ref_condition": "t3.a is not null and t3.c is not null",
"table": {
"table_name": "t4",
"access_type": "ref",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "24",
"used_key_parts": ["a", "c"],
"ref": ["test.t3.a", "test.t3.c"],
"rows": 2,
"filtered": 100
}
}
}
}
}
}
set statement optimizer_switch='split_grouping_derived=off' for select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by c,a) t
on t3.a=t.a and t3.c=t.c;
a c max min
1 bb 30 30
7 bb 82 12
select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by c,a) t
on t3.a=t.a and t3.c=t.c;
a c max min
1 bb 30 30
7 bb 82 12
explain extended select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by c,a) t
on t3.a=t.a and t3.c=t.c;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t3 ALL NULL NULL NULL NULL 8 100.00 Using where
1 PRIMARY <derived2> ref key0 key0 24 test.t3.a,test.t3.c 2 100.00
2 LATERAL DERIVED t4 ref idx idx 24 test.t3.a,test.t3.c 2 100.00
Warnings:
Note 1003 /* select#1 */ select `test`.`t3`.`a` AS `a`,`test`.`t3`.`c` AS `c`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t3` join (/* select#2 */ select `test`.`t4`.`a` AS `a`,`test`.`t4`.`c` AS `c`,max(`test`.`t4`.`b`) AS `max`,min(`test`.`t4`.`b`) AS `min` from `test`.`t4` where `test`.`t4`.`c` = `test`.`t3`.`c` and `test`.`t4`.`a` = `test`.`t3`.`a` group by `test`.`t4`.`c`,`test`.`t4`.`a`) `t` where `t`.`a` = `test`.`t3`.`a` and `t`.`c` = `test`.`t3`.`c`
explain format=json select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by c,a) t
on t3.a=t.a and t3.c=t.c;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t3",
"access_type": "ALL",
"rows": 8,
"filtered": 100,
"attached_condition": "t3.a is not null and t3.c is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "24",
"used_key_parts": ["a", "c"],
"ref": ["test.t3.a", "test.t3.c"],
"rows": 2,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
"outer_ref_condition": "t3.a is not null and t3.c is not null",
"table": {
"table_name": "t4",
"access_type": "ref",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "24",
"used_key_parts": ["a", "c"],
"ref": ["test.t3.a", "test.t3.c"],
"rows": 2,
"filtered": 100
}
}
}
}
}
}
drop index idx on t2;
create index idx on t2(b);
create index idx on t3(a);
create index idx2 on t4(c);
insert into t3 select * from t3;
insert into t3 select * from t3;
insert into t4 select * from t4;
set statement optimizer_switch='split_grouping_derived=off' for select t2.a,t2.b,t3.c,t.max,t.min
from t2, t3, (select c, max(b) max, min(b) min from t4 group by c) t
where t2.b > 50 and t2.a=t3.a and t3.c=t.c;
a b c max min
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
select t2.a,t2.b,t3.c,t.max,t.min
from t2, t3, (select c, max(b) max, min(b) min from t4 group by c) t
where t2.b > 50 and t2.a=t3.a and t3.c=t.c;
a b c max min
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
7 82 aa 77 15
7 82 bb 82 12
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
2 90 aa 77 15
explain extended select t2.a,t2.b,t3.c,t.max,t.min
from t2, t3, (select c, max(b) max, min(b) min from t4 group by c) t
where t2.b > 50 and t2.a=t3.a and t3.c=t.c;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 range idx idx 5 NULL 5 100.00 Using index condition; Using where
1 PRIMARY t3 ref idx idx 5 test.t2.a 3 100.00 Using where
1 PRIMARY <derived2> ref key0 key0 19 test.t3.c 4 100.00
2 LATERAL DERIVED t4 ref idx2 idx2 19 test.t3.c 5 100.00
Warnings:
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t3`.`c` AS `c`,`t`.`max` AS `max`,`t`.`min` AS `min` from `test`.`t2` join `test`.`t3` join (/* select#2 */ select `test`.`t4`.`c` AS `c`,max(`test`.`t4`.`b`) AS `max`,min(`test`.`t4`.`b`) AS `min` from `test`.`t4` where `test`.`t4`.`c` = `test`.`t3`.`c` group by `test`.`t4`.`c`) `t` where `test`.`t3`.`a` = `test`.`t2`.`a` and `t`.`c` = `test`.`t3`.`c` and `test`.`t2`.`b` > 50
explain format=json select t2.a,t2.b,t3.c,t.max,t.min
from t2, t3, (select c, max(b) max, min(b) min from t4 group by c) t
where t2.b > 50 and t2.a=t3.a and t3.c=t.c;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "t2",
"access_type": "range",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "5",
"used_key_parts": ["b"],
"rows": 5,
"filtered": 100,
"index_condition": "t2.b > 50",
"attached_condition": "t2.a is not null"
},
"table": {
"table_name": "t3",
"access_type": "ref",
"possible_keys": ["idx"],
"key": "idx",
"key_length": "5",
"used_key_parts": ["a"],
"ref": ["test.t2.a"],
"rows": 3,
"filtered": 100,
"attached_condition": "t3.c is not null"
},
"table": {
"table_name": "<derived2>",
"access_type": "ref",
"possible_keys": ["key0"],
"key": "key0",
"key_length": "19",
"used_key_parts": ["c"],
"ref": ["test.t3.c"],
"rows": 4,
"filtered": 100,
"materialized": {
"query_block": {
"select_id": 2,
"outer_ref_condition": "t3.c is not null",
"table": {
"table_name": "t4",
"access_type": "ref",
"possible_keys": ["idx2"],
"key": "idx2",
"key_length": "19",
"used_key_parts": ["c"],
"ref": ["test.t3.c"],
"rows": 5,
"filtered": 100
}
}
}
}
}
}
drop table t1,t2,t3,t4;

View File

@ -593,7 +593,7 @@ The following options may be given as the first argument:
join_cache_hashed, join_cache_bka,
optimize_join_buffer_size, table_elimination,
extended_keys, exists_to_in, orderby_uses_equalities,
condition_pushdown_for_derived
condition_pushdown_for_derived, split_grouping_derived
--optimizer-use-condition-selectivity=#
Controls selectivity of which conditions the optimizer
takes into account to calculate cardinality of a partial
@ -1367,7 +1367,7 @@ old-style-user-limits FALSE
optimizer-prune-level 1
optimizer-search-depth 62
optimizer-selectivity-sampling-limit 100
optimizer-switch index_merge=on,index_merge_union=on,index_merge_sort_union=on,index_merge_intersection=on,index_merge_sort_intersection=off,engine_condition_pushdown=off,index_condition_pushdown=on,derived_merge=on,derived_with_keys=on,firstmatch=on,loosescan=on,materialization=on,in_to_exists=on,semijoin=on,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=on,mrr=off,mrr_cost_based=off,mrr_sort_keys=off,outer_join_with_cache=on,semijoin_with_cache=on,join_cache_incremental=on,join_cache_hashed=on,join_cache_bka=on,optimize_join_buffer_size=off,table_elimination=on,extended_keys=on,exists_to_in=on,orderby_uses_equalities=on,condition_pushdown_for_derived=on
optimizer-switch index_merge=on,index_merge_union=on,index_merge_sort_union=on,index_merge_intersection=on,index_merge_sort_intersection=off,engine_condition_pushdown=off,index_condition_pushdown=on,derived_merge=on,derived_with_keys=on,firstmatch=on,loosescan=on,materialization=on,in_to_exists=on,semijoin=on,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=on,mrr=off,mrr_cost_based=off,mrr_sort_keys=off,outer_join_with_cache=on,semijoin_with_cache=on,join_cache_incremental=on,join_cache_hashed=on,join_cache_bka=on,optimize_join_buffer_size=off,table_elimination=on,extended_keys=on,exists_to_in=on,orderby_uses_equalities=on,condition_pushdown_for_derived=on,split_grouping_derived=on
optimizer-use-condition-selectivity 1
performance-schema FALSE
performance-schema-accounts-size -1

View File

@ -1548,3 +1548,100 @@ eval explain format=json $q;
DROP VIEW v2;
DROP TABLE t1,t2;
--echo #
--echo # MDEV-13369: Optimization for equi-joins of grouping derived tables
--echo # (Splitting derived tables / views with GROUP BY)
--echo #
let
$no_splitting= set statement optimizer_switch='split_grouping_derived=off' for;
create table t1 (a int);
insert into t1 values
(8), (5), (1), (2), (9), (7), (2), (7);
create table t2 (a int, b int, index idx(a));
insert into t2 values
(7,10), (1,20), (2,23), (7,18), (1,30),
(4,71), (3,15), (7,82), (8,12), (4,15),
(11,33), (10,42), (4,53), (10,17), (2,90);
let $q1=
select t1.a,t.max,t.min
from t1 join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
eval $no_splitting $q1;
eval $q1;
eval explain extended $q1;
eval explain format=json $q1;
let $q2=
select t1.a,t.max,t.min
from t1 left join
(select a, max(t2.b) max, min(t2.b) min from t2 group by t2.a) t
on t1.a=t.a;
eval $no_splitting $q2;
eval $q2;
eval explain extended $q2;
eval explain format=json $q2;
create table t3 (a int, c varchar(16));
insert into t3 values
(8,'aa'), (5,'cc'), (1,'bb'), (2,'aa'), (9,'cc'),
(7,'aa'), (2,'aa'), (7,'bb');
create table t4 (a int, b int, c varchar(16), index idx(a,c));
insert into t4 values
(7,10,'cc'), (1,20,'aa'), (2,23,'bb'), (7,18,'cc'), (1,30,'bb'),
(4,71,'xx'), (3,15,'aa'), (7,82,'bb'), (8,12,'dd'), (4,15,'aa'),
(11,33,'yy'), (10,42,'zz'), (4,53,'xx'), (10,17,'yy'), (7,12,'bb'),
(8,20,'dd'), (7,32,'bb'), (1,50,'aa'), (3,40,'bb'), (3,77,'aa');
let $q3=
select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by a,c) t
on t3.a=t.a and t3.c=t.c;
eval $no_splitting $q3;
eval $q3;
eval explain extended $q3;
eval explain format=json $q3;
let $q4=
select t3.a,t3.c,t.max,t.min
from t3 join
(select a, c, max(b) max, min(b) min from t4 group by c,a) t
on t3.a=t.a and t3.c=t.c;
eval $no_splitting $q4;
eval $q4;
eval explain extended $q4;
eval explain format=json $q4;
drop index idx on t2;
create index idx on t2(b);
create index idx on t3(a);
create index idx2 on t4(c);
insert into t3 select * from t3;
insert into t3 select * from t3;
insert into t4 select * from t4;
let $q5=
select t2.a,t2.b,t3.c,t.max,t.min
from t2, t3, (select c, max(b) max, min(b) min from t4 group by c) t
where t2.b > 50 and t2.a=t3.a and t3.c=t.c;
eval $no_splitting $q5;
eval $q5;
eval explain extended $q5;
eval explain format=json $q5;
drop table t1,t2,t3,t4;

View File

@ -1605,6 +1605,7 @@ public:
*/
virtual bool check_valid_arguments_processor(void *arg) { return 0; }
virtual bool update_vcol_processor(void *arg) { return 0; }
virtual bool set_fields_as_dependent_processor(void *arg) { return 0; }
/*============== End of Item processor list ======================*/
virtual Item *get_copy(THD *thd, MEM_ROOT *mem_root)=0;
@ -2828,6 +2829,15 @@ public:
}
return mark_unsupported_function(field_name.str, arg, VCOL_FIELD_REF);
}
bool set_fields_as_dependent_processor(void *arg)
{
if (!(used_tables() & OUTER_REF_TABLE_BIT))
{
depended_from= (st_select_lex *) arg;
item_equal= NULL;
}
return 0;
}
void cleanup();
Item_equal *get_item_equal() { return item_equal; }
void set_item_equal(Item_equal *item_eq) { item_equal= item_eq; }

View File

@ -872,12 +872,12 @@ bool mysql_derived_optimize(THD *thd, LEX *lex, TABLE_LIST *derived)
bool res= FALSE;
DBUG_ENTER("mysql_derived_optimize");
if (unit->optimized)
DBUG_RETURN(FALSE);
lex->current_select= first_select;
if (unit->is_unit_op())
{
if (unit->optimized)
DBUG_RETURN(FALSE);
// optimize union without execution
res= unit->optimize();
}
@ -887,7 +887,20 @@ 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->with_two_phase_optimization)
{
if (unit->optimized_2)
DBUG_RETURN(FALSE);
unit->optimized_2= TRUE;
}
else
{
if (unit->optimized)
DBUG_RETURN(FALSE);
unit->optimized= TRUE;
}
if ((res= join->optimize()))
goto err;
if (join->table_count == join->const_tables)
@ -1042,6 +1055,13 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived)
select_unit *derived_result= derived->derived_result;
SELECT_LEX *save_current_select= lex->current_select;
if (!derived_is_recursive && (unit->uncacheable & UNCACHEABLE_DEPENDENT))
{
if ((res= derived->table->file->ha_delete_all_rows()))
goto err;
unit->first_select()->join->first_record= false;
}
if (derived_is_recursive)
{
if (derived->is_with_table_recursive_reference())
@ -1088,7 +1108,8 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived)
res= TRUE;
unit->executed= TRUE;
}
if (res || (!lex->describe && !derived_is_recursive))
err:
if (res || (!lex->describe && !derived_is_recursive && !unit->uncacheable))
unit->cleanup();
lex->current_select= save_current_select;

View File

@ -2157,7 +2157,7 @@ void st_select_lex_unit::init_query()
select_limit_cnt= HA_POS_ERROR;
offset_limit_cnt= 0;
union_distinct= 0;
prepared= optimized= executed= 0;
prepared= optimized= optimized_2= executed= 0;
optimize_started= 0;
item= 0;
union_result= 0;
@ -4464,7 +4464,12 @@ void st_select_lex::set_explain_type(bool on_the_fly)
{
/* If we're a direct child of a UNION, we're the first sibling there */
if (linkage == DERIVED_TABLE_TYPE)
{
if (is_uncacheable & UNCACHEABLE_DEPENDENT)
type= "LATERAL DERIVED";
else
type= "DERIVED";
}
else if (using_materialization)
type= "MATERIALIZED";
else

View File

@ -690,6 +690,7 @@ public:
select_result *result;
bool prepared, // prepare phase already performed for UNION (unit)
optimized, // optimize phase already performed for UNION (unit)
optimized_2,
executed, // already executed
cleaned;

View File

@ -227,6 +227,7 @@
#define OPTIMIZER_SWITCH_EXISTS_TO_IN (1ULL << 28)
#define OPTIMIZER_SWITCH_ORDERBY_EQ_PROP (1ULL << 29)
#define OPTIMIZER_SWITCH_COND_PUSHDOWN_FOR_DERIVED (1ULL << 30)
#define OPTIMIZER_SWITCH_SPLIT_GROUPING_DERIVED (1ULL << 31)
#define OPTIMIZER_SWITCH_DEFAULT (OPTIMIZER_SWITCH_INDEX_MERGE | \
OPTIMIZER_SWITCH_INDEX_MERGE_UNION | \
@ -252,7 +253,9 @@
OPTIMIZER_SWITCH_LOOSE_SCAN | \
OPTIMIZER_SWITCH_EXISTS_TO_IN | \
OPTIMIZER_SWITCH_ORDERBY_EQ_PROP | \
OPTIMIZER_SWITCH_COND_PUSHDOWN_FOR_DERIVED)
OPTIMIZER_SWITCH_COND_PUSHDOWN_FOR_DERIVED | \
OPTIMIZER_SWITCH_SPLIT_GROUPING_DERIVED)
/*
Replication uses 8 bytes to store SQL_MODE in the binary log. The day you
use strictly more than 64 bits by adding one more define above, you should

View File

@ -223,6 +223,9 @@ static bool test_if_cheaper_ordering(const JOIN_TAB *tab,
ha_rows *new_select_limit,
uint *new_used_key_parts= NULL,
uint *saved_best_key_parts= NULL);
static int test_if_order_by_key(JOIN *join,
ORDER *order, TABLE *table, uint idx,
uint *used_key_parts= NULL);
static bool test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,
ha_rows select_limit, bool no_changes,
const key_map *map);
@ -1075,15 +1078,7 @@ err:
DBUG_RETURN(res); /* purecov: inspected */
}
int JOIN::optimize()
{
// to prevent double initialization on EXPLAIN
if (optimization_state != JOIN::NOT_OPTIMIZED)
return FALSE;
optimization_state= JOIN::OPTIMIZATION_IN_PROGRESS;
int res= optimize_inner();
if (!res && have_query_plan != QEP_DELETED)
void JOIN::build_explain()
{
create_explain_query_if_not_exists(thd->lex, thd->mem_root);
have_query_plan= QEP_AVAILABLE;
@ -1108,9 +1103,30 @@ int JOIN::optimize()
get_using_temporary_read_tracker();
}
}
}
int JOIN::optimize()
{
int res= 0;
join_optimization_state init_state= optimization_state;
if (optimization_state == JOIN::OPTIMIZATION_IN_STAGE_2)
res= optimize_stage2();
else
{
// to prevent double initialization on EXPLAIN
if (optimization_state != JOIN::NOT_OPTIMIZED)
return FALSE;
optimization_state= JOIN::OPTIMIZATION_IN_PROGRESS;
is_for_splittable_grouping_derived= false;
res= optimize_inner();
}
if (!with_two_phase_optimization ||
init_state == JOIN::OPTIMIZATION_IN_STAGE_2)
{
if (!res && have_query_plan != QEP_DELETED)
build_explain();
optimization_state= JOIN::OPTIMIZATION_DONE;
}
return res;
}
@ -1160,10 +1176,8 @@ int JOIN::init_join_caches()
int
JOIN::optimize_inner()
{
ulonglong select_opts_for_readinfo;
uint no_jbuf_after;
JOIN_TAB *tab;
DBUG_ENTER("JOIN::optimize");
subq_exit_fl= false;
do_send_rows = (unit->select_limit_cnt) ? 1 : 0;
DEBUG_SYNC(thd, "before_join_optimize");
@ -1384,6 +1398,7 @@ JOIN::optimize_inner()
"Impossible HAVING" : "Impossible WHERE";
table_count= top_join_tab_count= 0;
error= 0;
subq_exit_fl= true;
goto setup_subq_exit;
}
}
@ -1438,6 +1453,7 @@ JOIN::optimize_inner()
zero_result_cause= "No matching min/max row";
table_count= top_join_tab_count= 0;
error=0;
subq_exit_fl= true;
goto setup_subq_exit;
}
if (res > 1)
@ -1480,6 +1496,7 @@ JOIN::optimize_inner()
{
DBUG_PRINT("info",("No tables"));
error= 0;
subq_exit_fl= true;
goto setup_subq_exit;
}
error= -1; // Error is sent to client
@ -1513,6 +1530,39 @@ JOIN::optimize_inner()
DBUG_RETURN(1);
}
setup_subq_exit:
with_two_phase_optimization= check_two_phase_optimization(thd);
if (with_two_phase_optimization)
optimization_state= JOIN::OPTIMIZATION_IN_STAGE_2;
else
{
if (optimize_stage2())
DBUG_RETURN(1);
}
DBUG_RETURN(0);
}
int JOIN::optimize_stage2()
{
ulonglong select_opts_for_readinfo;
uint no_jbuf_after;
JOIN_TAB *tab;
DBUG_ENTER("JOIN::optimize_stage2");
if (subq_exit_fl)
goto setup_subq_exit;
if (select_lex->handle_derived(thd->lex, DT_OPTIMIZE))
DBUG_RETURN(1);
if (thd->check_killed())
DBUG_RETURN(1);
/* Generate an execution plan from the found optimal join order. */
if (get_best_combination())
DBUG_RETURN(1);
if (optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_WITH_KEYS))
drop_unused_derived_keys();
@ -4461,10 +4511,12 @@ make_join_statistics(JOIN *join, List<TABLE_LIST> &tables_list,
if (join->choose_subquery_plan(all_table_map & ~join->const_table_map))
goto error;
if (join->improve_chosen_plan(join->thd))
goto error;
DEBUG_SYNC(join->thd, "inside_make_join_statistics");
/* Generate an execution plan from the found optimal join order. */
DBUG_RETURN(join->thd->check_killed() || join->get_best_combination());
DBUG_RETURN(0);
error:
/*
@ -8792,6 +8844,257 @@ JOIN_TAB *next_depth_first_tab(JOIN* join, JOIN_TAB* tab)
return tab;
}
static
bool key_can_be_used_to_split_by_fields(KEY *key_info, uint used_key_parts,
List<Field> &fields)
{
if (used_key_parts < fields.elements)
return false;
List_iterator_fast<Field> li(fields);
Field *fld;
KEY_PART_INFO *start= key_info->key_part;
KEY_PART_INFO *end= start + fields.elements;
while ((fld= li++))
{
KEY_PART_INFO *key_part;
for (key_part= start; key_part < end; key_part++)
{
if (key_part->fieldnr == fld->field_index + 1)
break;
}
if (key_part == end)
return false;
}
return true;
}
bool JOIN::check_for_splittable_grouping_derived(THD *thd)
{
st_select_lex_unit *unit= select_lex->master_unit();
TABLE_LIST *derived= unit->derived;
if (!optimizer_flag(thd, OPTIMIZER_SWITCH_SPLIT_GROUPING_DERIVED))
return false;
if (!(derived && derived->is_materialized_derived()))
return false;
if (unit->first_select()->next_select())
return false;
if (derived->prohibit_cond_pushdown)
return false;
if (derived->is_recursive_with_table())
return false;
if (!group_list)
return false;
ORDER *ord;
TABLE *table= 0;
key_map ref_keys;
uint group_fields= 0;
ref_keys.set_all();
for (ord= group_list; ord; ord= ord->next, group_fields++)
{
Item *ord_item= *ord->item;
if (ord_item->real_item()->type() != Item::FIELD_ITEM)
return false;
Field *ord_field= ((Item_field *) (ord_item->real_item()))->field;
if (!table)
table= ord_field->table;
else if (table != ord_field->table)
return false;
ref_keys.intersect(ord_field->part_of_key);
}
if (ref_keys.is_clear_all())
return false;
uint i;
List<Field> grouping_fields;
List<Field> splitting_fields;
List_iterator<Item> li(fields_list);
for (ord= group_list; ord; ord= ord->next)
{
Item *item;
i= 0;
while ((item= li++))
{
if ((*ord->item)->eq(item, 0))
break;
i++;
}
if (!item)
return false;
if (splitting_fields.push_back(derived->table->field[i], thd->mem_root))
return false;
Item_field *ord_field= (Item_field *)(item->real_item());
if (grouping_fields.push_back(ord_field->field, thd->mem_root))
return false;
li.rewind();
}
for (i= 0; i < table->s->keys; i++)
{
if (!(ref_keys.is_set(i)))
continue;
KEY *key_info= table->key_info + i;
if (key_can_be_used_to_split_by_fields(key_info,
table->actual_n_key_parts(key_info),
grouping_fields))
break;
}
if (i == table->s->keys)
return false;
derived->table->splitting_fields= splitting_fields;
is_for_splittable_grouping_derived= true;
return true;
}
bool JOIN::check_two_phase_optimization(THD *thd)
{
if (!check_for_splittable_grouping_derived(thd))
return false;
return true;
}
Item *JOIN_TAB::get_splitting_cond_for_grouping_derived(THD *thd)
{
/* this is a stub */
TABLE_LIST *derived= table->pos_in_table_list;
st_select_lex *sel= derived->get_unit()->first_select();
Item *cond= 0;
table_map used_tables= OUTER_REF_TABLE_BIT;
POSITION *pos= join->best_positions;
for (; pos->table != this; pos++)
{
used_tables|= pos->table->table->map;
}
if (!pos->key)
return 0;
KEY *key_info= table->key_info + pos->key->key;
if (!key_can_be_used_to_split_by_fields(key_info,
key_info->user_defined_key_parts,
table->splitting_fields))
return 0;
create_ref_for_key(join, this, pos->key,
false, used_tables);
List<Item> cond_list;
KEY_PART_INFO *start= key_info->key_part;
KEY_PART_INFO *end= start + table->splitting_fields.elements;
List_iterator_fast<Field> li(table->splitting_fields);
Field *fld= li++;
for (ORDER *ord= sel->join->group_list; ord; ord= ord->next, fld= li++)
{
Item *left_item= (*ord->item)->build_clone(thd, thd->mem_root);
uint i= 0;
for (KEY_PART_INFO *key_part= start; key_part < end; key_part++, i++)
{
if (key_part->fieldnr == fld->field_index + 1)
break;
}
Item *right_item= ref.items[i]->build_clone(thd, thd->mem_root);
Item_func_eq *eq_item= 0;
right_item= right_item->build_clone(thd, thd->mem_root);
if (left_item && right_item)
{
right_item->walk(&Item::set_fields_as_dependent_processor,
false, join->select_lex);
right_item->update_used_tables();
eq_item= new (thd->mem_root) Item_func_eq(thd, left_item, right_item);
}
if (!eq_item || cond_list.push_back(eq_item, thd->mem_root))
return 0;
}
switch (cond_list.elements) {
case 0: break;
case 1: cond= cond_list.head(); break;
default: cond= new (thd->mem_root) Item_cond_and(thd, cond_list);
}
if (cond)
cond->fix_fields(thd,0);
return cond;
}
bool JOIN::inject_cond_into_where(Item *injected_cond)
{
Item *where_item= injected_cond;
List<Item> *and_args= NULL;
if (conds && conds->type() == Item::COND_ITEM &&
((Item_cond*) conds)->functype() == Item_func::COND_AND_FUNC)
{
and_args= ((Item_cond*) conds)->argument_list();
if (cond_equal)
and_args->disjoin((List<Item> *) &cond_equal->current_level);
}
where_item= and_items(thd, conds, where_item);
if (!where_item->fixed && where_item->fix_fields(thd, 0))
return true;
thd->change_item_tree(&select_lex->where, where_item);
select_lex->where->top_level_item();
conds= select_lex->where;
if (and_args && cond_equal)
{
and_args= ((Item_cond*) conds)->argument_list();
List_iterator<Item_equal> li(cond_equal->current_level);
Item_equal *elem;
while ((elem= li++))
{
and_args->push_back(elem, thd->mem_root);
}
}
return false;
}
bool JOIN::push_splitting_cond_into_derived(THD *thd, Item *cond)
{
enum_reopt_result reopt_result= REOPT_NONE;
table_map all_table_map= 0;
for (JOIN_TAB *tab= join_tab + const_tables;
tab < join_tab + top_join_tab_count; tab++)
{
all_table_map|= tab->table->map;
}
reopt_result= reoptimize(cond, all_table_map, NULL);
if (reopt_result == REOPT_ERROR)
return true;
if (inject_cond_into_where(cond))
return true;
if (cond->used_tables() & OUTER_REF_TABLE_BIT)
{
select_lex->uncacheable|= UNCACHEABLE_DEPENDENT_INJECTED;
st_select_lex_unit *unit= select_lex->master_unit();
unit->uncacheable|= UNCACHEABLE_DEPENDENT_INJECTED;
}
return false;
}
bool JOIN::improve_chosen_plan(THD *thd)
{
for (JOIN_TAB *tab= join_tab + const_tables;
tab < join_tab + table_count; tab++)
{
TABLE_LIST *tbl= tab->table->pos_in_table_list;
if (tbl->is_materialized_derived())
{
st_select_lex *sel= tbl->get_unit()->first_select();
JOIN *derived_join= sel->join;
if (derived_join && derived_join->is_for_splittable_grouping_derived)
{
Item *cond= tab->get_splitting_cond_for_grouping_derived(thd);
if (cond && derived_join->push_splitting_cond_into_derived(thd, cond))
return true;
}
}
}
return false;
}
static Item * const null_ptr= NULL;
@ -11860,11 +12163,13 @@ bool JOIN_TAB::preread_init()
/* Materialize derived table/view. */
if ((!derived->get_unit()->executed ||
derived->is_recursive_with_table()) &&
derived->is_recursive_with_table() ||
derived->get_unit()->uncacheable) &&
mysql_handle_single_derived(join->thd->lex,
derived, DT_CREATE | DT_FILL))
return TRUE;
if (!(derived->get_unit()->uncacheable & UNCACHEABLE_DEPENDENT))
preread_init_done= TRUE;
if (select && select->quick)
select->quick->replace_handler(table->file);
@ -20671,7 +20976,7 @@ part_of_refkey(TABLE *table,Field *field)
static int test_if_order_by_key(JOIN *join,
ORDER *order, TABLE *table, uint idx,
uint *used_key_parts= NULL)
uint *used_key_parts)
{
KEY_PART_INFO *key_part,*key_part_end;
key_part=table->key_info[idx].key_part;

View File

@ -614,6 +614,7 @@ typedef struct st_join_table {
bool use_order() const; ///< Use ordering provided by chosen index?
bool sort_table();
bool remove_duplicates();
Item *get_splitting_cond_for_grouping_derived(THD *thd);
} JOIN_TAB;
@ -1275,6 +1276,8 @@ public:
*/
bool filesort_found_rows;
bool subq_exit_fl;
ROLLUP rollup; ///< Used with rollup
bool mixed_implicit_grouping;
@ -1380,7 +1383,8 @@ public:
enum join_optimization_state { NOT_OPTIMIZED=0,
OPTIMIZATION_IN_PROGRESS=1,
OPTIMIZATION_DONE=2};
OPTIMIZATION_IN_STAGE_2=2,
OPTIMIZATION_DONE=3};
// state of JOIN optimization
enum join_optimization_state optimization_state;
bool initialized; ///< flag to avoid double init_execution calls
@ -1406,6 +1410,9 @@ public:
/** Exec time only: TRUE <=> current group has been sent */
bool group_sent;
bool is_for_splittable_grouping_derived;
bool with_two_phase_optimization;
JOIN_TAB *sort_and_group_aggr_tab;
JOIN(THD *thd_arg, List<Item> &fields_arg, ulonglong select_options_arg,
@ -1510,6 +1517,8 @@ public:
bool prepare_stage2();
int optimize();
int optimize_inner();
int optimize_stage2();
void build_explain();
int reinit();
int init_execution();
void exec();
@ -1656,6 +1665,11 @@ public:
bool need_order, bool distinct,
const char *message);
JOIN_TAB *first_breadth_first_tab() { return join_tab; }
bool check_two_phase_optimization(THD *thd);
bool check_for_splittable_grouping_derived(THD *thd);
bool inject_cond_into_where(Item *injected_cond);
bool push_splitting_cond_into_derived(THD *thd, Item *cond);
bool improve_chosen_plan(THD *thd);
private:
/**
Create a temporary table to be used for processing DISTINCT/ORDER
@ -1693,6 +1707,7 @@ private:
bool implicit_grouping;
void cleanup_item_list(List<Item> &items) const;
bool make_aggr_tables_info();
};
enum enum_with_bush_roots { WITH_BUSH_ROOTS, WITHOUT_BUSH_ROOTS};

View File

@ -1770,7 +1770,7 @@ bool st_select_lex_unit::cleanup()
void st_select_lex_unit::reinit_exec_mechanism()
{
prepared= optimized= executed= 0;
prepared= optimized= optimized_2= executed= 0;
optimize_started= 0;
#ifndef DBUG_OFF
if (is_unit_op())

View File

@ -2385,6 +2385,7 @@ export const char *optimizer_switch_names[]=
"exists_to_in",
"orderby_uses_equalities",
"condition_pushdown_for_derived",
"split_grouping_derived",
"default",
NullS
};

View File

@ -1305,6 +1305,7 @@ public:
bool stats_is_read; /* Persistent statistics is read for the table */
bool histograms_are_read;
MDL_ticket *mdl_ticket;
List<Field> splitting_fields;
void init(THD *thd, TABLE_LIST *tl);
bool fill_item_list(List<Item> *item_list) const;