Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
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.
  • Loading branch information
igorbabaev committed Aug 10, 2017
1 parent 6685cdc commit b14e2b0
Show file tree
Hide file tree
Showing 13 changed files with 948 additions and 51 deletions.
438 changes: 438 additions & 0 deletions mysql-test/r/derived_cond_pushdown.result

Large diffs are not rendered by default.

4 changes: 2 additions & 2 deletions mysql-test/r/mysqld--help.result
Expand Up @@ -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
Expand Down Expand Up @@ -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
Expand Down
97 changes: 97 additions & 0 deletions mysql-test/t/derived_cond_pushdown.test
Expand Up @@ -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;

10 changes: 10 additions & 0 deletions sql/item.h
Expand Up @@ -1605,6 +1605,7 @@ class Item: public Value_source,
*/
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;
Expand Down Expand Up @@ -2828,6 +2829,15 @@ class Item_field :public Item_ident
}
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; }
Expand Down
29 changes: 25 additions & 4 deletions sql/sql_derived.cc
Expand Up @@ -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();
}
Expand All @@ -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());
unit->optimized= TRUE;
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)
Expand Down Expand Up @@ -1041,6 +1054,13 @@ bool mysql_derived_fill(THD *thd, LEX *lex, TABLE_LIST *derived)
DBUG_ASSERT(derived->table && derived->table->is_created());
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)
{
Expand Down Expand Up @@ -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;

Expand Down
9 changes: 7 additions & 2 deletions sql/sql_lex.cc
Expand Up @@ -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;
Expand Down Expand Up @@ -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)
type= "DERIVED";
{
if (is_uncacheable & UNCACHEABLE_DEPENDENT)
type= "LATERAL DERIVED";
else
type= "DERIVED";
}
else if (using_materialization)
type= "MATERIALIZED";
else
Expand Down
1 change: 1 addition & 0 deletions sql/sql_lex.h
Expand Up @@ -690,6 +690,7 @@ class st_select_lex_unit: public st_select_lex_node {
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;

Expand Down
5 changes: 4 additions & 1 deletion sql/sql_priv.h
Expand Up @@ -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 | \
Expand All @@ -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
Expand Down

0 comments on commit b14e2b0

Please sign in to comment.