From 0ddc981034ee3c9335591825e2fd1ff6a3f06fd3 Mon Sep 17 00:00:00 2001 From: Dave Gosselin Date: Thu, 24 Apr 2025 15:03:05 -0400 Subject: [PATCH] MDEV-36092 New-style hint: [NO_]SPLIT_MATERIALIZED Support for optimizer hints NO_SPLIT_MATERIALIZED and SPLIT_MATERIALIZED. These hints allow fine-grained control of the "lateral derived" optimization within a query. --- .../main/opt_hints_split_materialized.result | 417 ++++++++++++++++++ .../main/opt_hints_split_materialized.test | 337 ++++++++++++++ sql/opt_hints.cc | 1 + sql/opt_hints_parser.cc | 12 + sql/opt_hints_parser.h | 9 +- sql/opt_split.cc | 12 +- 6 files changed, 784 insertions(+), 4 deletions(-) create mode 100644 mysql-test/main/opt_hints_split_materialized.result create mode 100644 mysql-test/main/opt_hints_split_materialized.test diff --git a/mysql-test/main/opt_hints_split_materialized.result b/mysql-test/main/opt_hints_split_materialized.result new file mode 100644 index 0000000000000..163d29d468898 --- /dev/null +++ b/mysql-test/main/opt_hints_split_materialized.result @@ -0,0 +1,417 @@ +# +# MDEV-36092 New-style hint: [NO_]SPLIT_MATERIALIZED +# +set @save_optimizer_switch=@@optimizer_switch; +create table t1 ( +n1 int(10) not null, +n2 int(10) not null, +c1 char(1) not null, +key c1 (c1), +key n1_c1_n2 (n1,c1,n2) +) engine=innodb charset=latin1; +insert into t1 values (0, 2, 'a'), (1, 3, 'a'); +insert into t1 select seq+1,seq+2,'c' from seq_1_to_1000; +analyze table t1; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +explain select t1.n1 from t1, (select n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 LATERAL DERIVED t1 ref c1,n1_c1_n2 n1_c1_n2 4 test.t1.n1 1 Using where; Using index +explain select /*+ no_split_materialized(@qb1 t1) */ t1.n1 from t1, +(select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 DERIVED t1 ref c1 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +explain select /*+ no_split_materialized(t1@qb1) */ t1.n1 from t1, +(select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 DERIVED t1 ref c1 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +explain select t1.n1 from t1, +(select /*+ no_split_materialized(t1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 DERIVED t1 ref c1 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +set optimizer_switch='split_materialized=off'; +explain select t1.n1 from t1, (select n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 DERIVED t1 ref c1 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +explain select /*+ split_materialized(@qb1 t1) */ t1.n1 from t1, +(select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 LATERAL DERIVED t1 ref c1,n1_c1_n2 n1_c1_n2 4 test.t1.n1 1 Using where; Using index +explain select /*+ split_materialized(t1@qb1) */ t1.n1 from t1, +(select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 LATERAL DERIVED t1 ref c1,n1_c1_n2 n1_c1_n2 4 test.t1.n1 1 Using where; Using index +explain select t1.n1 from t1, +(select /*+ split_materialized(t1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t +where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref c1,n1_c1_n2 c1 1 const 2 Using index condition; Using where; Using temporary; Using filesort +1 PRIMARY ref key0 key0 8 test.t1.n1,test.t1.n2 1 +2 LATERAL DERIVED t1 ref c1,n1_c1_n2 n1_c1_n2 4 test.t1.n1 1 Using where; Using index +set optimizer_switch=@save_optimizer_switch; +drop table t1; +set @save_optimizer_switch=@@optimizer_switch; +create table t1(a int, b int); +insert into t1 select seq,seq from seq_1_to_5; +create table t2(a int, b int, key(a)); +insert into t2 +select a.seq,b.seq from seq_1_to_25 a, seq_1_to_2 b; +create table t3(a int, b int, key(a)); +insert into t3 +select a.seq,b.seq from seq_1_to_5 a, seq_1_to_3 b; +analyze table t1,t2,t3 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status OK +test.t2 analyze status Engine-independent statistics collected +test.t2 analyze status Table is already up to date +test.t3 analyze status Engine-independent statistics collected +test.t3 analyze status Table is already up to date +create table t10 ( +grp_id int, +col1 int, +key(grp_id) +); +insert into t10 +select +a.seq, +b.seq +from +seq_1_to_100 a, +seq_1_to_100 b; +create table t11 ( +col1 int, +col2 int +); +insert into t11 +select a.seq, a.seq from seq_1_to_10 a; +analyze table t10,t11 persistent for all; +Table Op Msg_type Msg_text +test.t10 analyze status Engine-independent statistics collected +test.t10 analyze status Table is already up to date +test.t11 analyze status Engine-independent statistics collected +test.t11 analyze status OK +create table t21 (pk int primary key); +insert into t21 values (1),(2),(3); +create table t22 (pk int primary key); +insert into t22 values (1),(2),(3); +explain +select * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 LATERAL DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index +2 LATERAL DERIVED t10 ref grp_id grp_id 5 test.t1.b 100 +2 LATERAL DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ no_split_materialized(t10) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index; Using temporary; Using filesort +2 DERIVED t10 ALL NULL NULL NULL NULL 10000 +2 DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select /*+ no_split_materialized(t10@qb1) */ * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ qb_name(qb1) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index; Using temporary; Using filesort +2 DERIVED t10 ALL NULL NULL NULL NULL 10000 +2 DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select /*+ no_split_materialized(@qb1 t10) */ * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ qb_name(qb1) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index; Using temporary; Using filesort +2 DERIVED t10 ALL NULL NULL NULL NULL 10000 +2 DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +set optimizer_switch='split_materialized=off'; +explain +select * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index; Using temporary; Using filesort +2 DERIVED t10 ALL NULL NULL NULL NULL 10000 +2 DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ split_materialized(t10) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 LATERAL DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index +2 LATERAL DERIVED t10 ref grp_id grp_id 5 test.t1.b 100 +2 LATERAL DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select /*+ split_materialized(t10@qb1) */ * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ qb_name(qb1) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 LATERAL DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index +2 LATERAL DERIVED t10 ref grp_id grp_id 5 test.t1.b 100 +2 LATERAL DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +explain +select /*+ split_materialized(@qb1 t10) */ * from +t21, +( +(t1 left join t2 on t2.a=t1.b) +left join t3 on t3.a=t1.b +) left join (select /*+ qb_name(qb1) */ grp_id, count(*) +from +t22 join t10 left join t11 on t11.col1=t10.col1 +where +t22.pk=1 +group by grp_id) t on t.grp_id=t1.b +where +t21.pk=1; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t21 const PRIMARY PRIMARY 4 const 1 Using index +1 PRIMARY t1 ALL NULL NULL NULL NULL 5 +1 PRIMARY t2 ref a a 5 test.t1.b 2 Using where +1 PRIMARY t3 ref a a 5 test.t1.b 3 Using where +1 PRIMARY ref key0 key0 5 test.t1.b 10 Using where +2 LATERAL DERIVED t22 const PRIMARY PRIMARY 4 const 1 Using index +2 LATERAL DERIVED t10 ref grp_id grp_id 5 test.t1.b 100 +2 LATERAL DERIVED t11 ALL NULL NULL NULL NULL 10 Using where; Using join buffer (flat, BNL join) +set optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3, t10, t11, t21, t22; +set @save_optimizer_switch=@@optimizer_switch; +create table t1 (a char(1)) engine=myisam; +insert into t1 values ('1'),('2'); +create table t2 (b int, key(b)) engine=myisam; +alter table t2 disable keys; +insert into t2 values (1),(2),(3); +alter table t2 enable keys; +create table t3 (c int) engine=myisam; +insert into t3 (c) select seq from seq_1_to_101; +explain select * from t1 where t1.a in ( +select b from ( +select t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 LATERAL DERIVED t2 ref b b 5 test.t1.a 1 Using where; Using index; Using temporary; Using filesort +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select /*+ no_split_materialized(@qb2 t2) */ * from t1 where t1.a in ( +select /*+ qb_name(qb1) */ b from ( +select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 DERIVED t2 range NULL b 5 NULL 3 Using where; Using index for group-by +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select /*+ no_split_materialized(t2@qb2) */ * from t1 where t1.a in ( +select /*+ qb_name(qb1) */ b from ( +select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 DERIVED t2 range NULL b 5 NULL 3 Using where; Using index for group-by +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select * from t1 where t1.a in ( +select b from ( +select /*+ no_split_materialized(t2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 DERIVED t2 range NULL b 5 NULL 3 Using where; Using index for group-by +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +set optimizer_switch='split_materialized=off'; +explain select * from t1 where t1.a in ( +select b from ( +select t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 DERIVED t2 range NULL b 5 NULL 3 Using where; Using index for group-by +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select /*+ split_materialized(@qb2 t2) */ * from t1 where t1.a in ( +select /*+ qb_name(qb1) */ b from ( +select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 LATERAL DERIVED t2 ref b b 5 test.t1.a 1 Using where; Using index; Using temporary; Using filesort +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select /*+ split_materialized(t2@qb2) */ * from t1 where t1.a in ( +select /*+ qb_name(qb1) */ b from ( +select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 LATERAL DERIVED t2 ref b b 5 test.t1.a 1 Using where; Using index; Using temporary; Using filesort +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +explain select * from t1 where t1.a in ( +select b from ( +select /*+ split_materialized(t2) */ t2.b from t2 where not exists ( +select 1 from t3 +) group by b +) sq +); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where +1 PRIMARY eq_ref distinct_key distinct_key 5 test.t1.a 1 Using where +3 LATERAL DERIVED t2 ref b b 5 test.t1.a 1 Using where; Using index; Using temporary; Using filesort +4 SUBQUERY t3 ALL NULL NULL NULL NULL 101 +set optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3; +# +# End 12.1 tests +# diff --git a/mysql-test/main/opt_hints_split_materialized.test b/mysql-test/main/opt_hints_split_materialized.test new file mode 100644 index 0000000000000..1aa4c3fc84791 --- /dev/null +++ b/mysql-test/main/opt_hints_split_materialized.test @@ -0,0 +1,337 @@ +--echo # +--echo # MDEV-36092 New-style hint: [NO_]SPLIT_MATERIALIZED +--echo # + +--source include/have_innodb.inc +--source include/have_sequence.inc + +set @save_optimizer_switch=@@optimizer_switch; + +### case 1 +create table t1 ( + n1 int(10) not null, + n2 int(10) not null, + c1 char(1) not null, + key c1 (c1), + key n1_c1_n2 (n1,c1,n2) +) engine=innodb charset=latin1; +insert into t1 values (0, 2, 'a'), (1, 3, 'a'); +insert into t1 select seq+1,seq+2,'c' from seq_1_to_1000; + +analyze table t1; + +## default showing lateral derived optimization in use. +explain select t1.n1 from t1, (select n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +## cases where hint disables lateral derived optimization. +explain select /*+ no_split_materialized(@qb1 t1) */ t1.n1 from t1, + (select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +explain select /*+ no_split_materialized(t1@qb1) */ t1.n1 from t1, + (select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +explain select t1.n1 from t1, + (select /*+ no_split_materialized(t1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +## test opposite way, where hint enables the optimization instead of disabling it. +set optimizer_switch='split_materialized=off'; + +## default showing lateral derived optimization not used. +explain select t1.n1 from t1, (select n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +## cases where hint enables lateral derived optimization. +explain select /*+ split_materialized(@qb1 t1) */ t1.n1 from t1, + (select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +explain select /*+ split_materialized(t1@qb1) */ t1.n1 from t1, + (select /*+ qb_name(qb1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +explain select t1.n1 from t1, + (select /*+ split_materialized(t1) */ n1, n2 from t1 where c1 = 'a' group by n1) as t + where t.n1 = t1.n1 and t.n2 = t1.n2 and c1 = 'a' group by n1; + +set optimizer_switch=@save_optimizer_switch; +drop table t1; +### end case 1 + + +### case 2 +# 5 values +set @save_optimizer_switch=@@optimizer_switch; + +create table t1(a int, b int); +insert into t1 select seq,seq from seq_1_to_5; + +# 5 value groups of size 2 each +create table t2(a int, b int, key(a)); +insert into t2 +select a.seq,b.seq from seq_1_to_25 a, seq_1_to_2 b; + +# 5 value groups of size 3 each +create table t3(a int, b int, key(a)); +insert into t3 +select a.seq,b.seq from seq_1_to_5 a, seq_1_to_3 b; + +analyze table t1,t2,t3 persistent for all; + +create table t10 ( + grp_id int, + col1 int, + key(grp_id) +); + +# 100 groups of 100 values each +insert into t10 +select + a.seq, + b.seq +from + seq_1_to_100 a, + seq_1_to_100 b; + +# and x10 multiplier + +create table t11 ( + col1 int, + col2 int +); +insert into t11 +select a.seq, a.seq from seq_1_to_10 a; + +analyze table t10,t11 persistent for all; + +create table t21 (pk int primary key); +insert into t21 values (1),(2),(3); + +create table t22 (pk int primary key); +insert into t22 values (1),(2),(3); + +## default showing lateral derived optimization in use. +explain +select * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +## cases where hint disables lateral derived optimization. +explain +select * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ no_split_materialized(t10) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +explain +select /*+ no_split_materialized(t10@qb1) */ * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ qb_name(qb1) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +explain +select /*+ no_split_materialized(@qb1 t10) */ * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ qb_name(qb1) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +## test opposite way, where hint enables the optimization instead of disabling it. +set optimizer_switch='split_materialized=off'; + +## default showing lateral derived optimization not used. +explain +select * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +## cases where hint enables lateral derived optimization. +explain +select * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ split_materialized(t10) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +explain +select /*+ split_materialized(t10@qb1) */ * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ qb_name(qb1) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +explain +select /*+ split_materialized(@qb1 t10) */ * from + t21, + ( + (t1 left join t2 on t2.a=t1.b) + left join t3 on t3.a=t1.b + ) left join (select /*+ qb_name(qb1) */ grp_id, count(*) + from + t22 join t10 left join t11 on t11.col1=t10.col1 + where + t22.pk=1 + group by grp_id) t on t.grp_id=t1.b +where + t21.pk=1; + +set optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3, t10, t11, t21, t22; +### end case 2 + +### case 3 +set @save_optimizer_switch=@@optimizer_switch; + +create table t1 (a char(1)) engine=myisam; +insert into t1 values ('1'),('2'); +create table t2 (b int, key(b)) engine=myisam; +alter table t2 disable keys; +insert into t2 values (1),(2),(3); +alter table t2 enable keys; +create table t3 (c int) engine=myisam; +insert into t3 (c) select seq from seq_1_to_101; + +## default showing lateral derived optimization in use. +explain select * from t1 where t1.a in ( + select b from ( + select t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +## cases where hint enables lateral derived optimization. +explain select /*+ no_split_materialized(@qb2 t2) */ * from t1 where t1.a in ( + select /*+ qb_name(qb1) */ b from ( + select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +explain select /*+ no_split_materialized(t2@qb2) */ * from t1 where t1.a in ( + select /*+ qb_name(qb1) */ b from ( + select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +explain select * from t1 where t1.a in ( + select b from ( + select /*+ no_split_materialized(t2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +## test opposite way, where hint enables the optimization instead of disabling it. +set optimizer_switch='split_materialized=off'; + +## default showing lateral derived optimization not used. +explain select * from t1 where t1.a in ( + select b from ( + select t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +## cases where hint enables lateral derived optimization. +explain select /*+ split_materialized(@qb2 t2) */ * from t1 where t1.a in ( + select /*+ qb_name(qb1) */ b from ( + select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +explain select /*+ split_materialized(t2@qb2) */ * from t1 where t1.a in ( + select /*+ qb_name(qb1) */ b from ( + select /*+ qb_name(qb2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + +explain select * from t1 where t1.a in ( + select b from ( + select /*+ split_materialized(t2) */ t2.b from t2 where not exists ( + select 1 from t3 + ) group by b + ) sq +); + + +set optimizer_switch=@save_optimizer_switch; +drop table t1, t2, t3; +### end case 3 + +--echo # +--echo # End 12.1 tests +--echo # diff --git a/sql/opt_hints.cc b/sql/opt_hints.cc index 9b8ec60f543eb..c93107359ef54 100644 --- a/sql/opt_hints.cc +++ b/sql/opt_hints.cc @@ -47,6 +47,7 @@ struct st_opt_hint_info opt_hint_info[]= {{STRING_WITH_LEN("JOIN_FIXED_ORDER")}, false, true, false}, {{STRING_WITH_LEN("DERIVED_CONDITION_PUSHDOWN")}, false, false, false}, {{STRING_WITH_LEN("MERGE")}, false, false, false}, + {{STRING_WITH_LEN("SPLIT_MATERIALIZED")}, false, false, false}, {null_clex_str, 0, 0, 0} }; diff --git a/sql/opt_hints_parser.cc b/sql/opt_hints_parser.cc index 0ff5bf20ad2d4..f2c031054f6ba 100644 --- a/sql/opt_hints_parser.cc +++ b/sql/opt_hints_parser.cc @@ -134,11 +134,15 @@ Optimizer_hint_tokenizer::find_keyword(const LEX_CSTRING &str) case 18: if ("MAX_EXECUTION_TIME"_Lex_ident_column.streq(str)) return TokenID::keyword_MAX_EXECUTION_TIME; + if ("SPLIT_MATERIALIZED"_Lex_ident_column.streq(str)) + return TokenID::keyword_SPLIT_MATERIALIZED; break; case 21: if ("NO_RANGE_OPTIMIZATION"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_RANGE_OPTIMIZATION; + if ("NO_SPLIT_MATERIALIZED"_Lex_ident_column.streq(str)) + return TokenID::keyword_NO_SPLIT_MATERIALIZED; break; case 26: @@ -357,6 +361,14 @@ bool Parser::Table_level_hint::resolve(Parse_context *pc) const hint_type= MERGE_HINT_ENUM; hint_state= false; break; + case TokenID::keyword_SPLIT_MATERIALIZED: + hint_type= SPLIT_MATERIALIZED_HINT_ENUM; + hint_state= true; + break; + case TokenID::keyword_NO_SPLIT_MATERIALIZED: + hint_type= SPLIT_MATERIALIZED_HINT_ENUM; + hint_state= false; + break; default: DBUG_ASSERT(0); return true; diff --git a/sql/opt_hints_parser.h b/sql/opt_hints_parser.h index 7cf22c45a38fb..c63cd3f94ea7a 100644 --- a/sql/opt_hints_parser.h +++ b/sql/opt_hints_parser.h @@ -50,6 +50,7 @@ enum opt_hints_enum JOIN_FIXED_ORDER_HINT_ENUM, DERIVED_CONDITION_PUSHDOWN_HINT_ENUM, MERGE_HINT_ENUM, + SPLIT_MATERIALIZED_HINT_ENUM, MAX_HINT_ENUM // This one must be the last in the list }; @@ -118,7 +119,9 @@ class Optimizer_hint_tokenizer: public Extended_string_tokenizer keyword_DERIVED_CONDITION_PUSHDOWN, keyword_NO_DERIVED_CONDITION_PUSHDOWN, keyword_MERGE, - keyword_NO_MERGE + keyword_NO_MERGE, + keyword_SPLIT_MATERIALIZED, + keyword_NO_SPLIT_MATERIALIZED }; class Token: public Lex_cstring @@ -373,7 +376,9 @@ class Optimizer_hint_parser: public Optimizer_hint_tokenizer, id == TokenID::keyword_DERIVED_CONDITION_PUSHDOWN || id == TokenID::keyword_NO_DERIVED_CONDITION_PUSHDOWN || id == TokenID::keyword_MERGE || - id == TokenID::keyword_NO_MERGE; + id == TokenID::keyword_NO_MERGE || + id == TokenID::keyword_SPLIT_MATERIALIZED || + id == TokenID::keyword_NO_SPLIT_MATERIALIZED; } }; class Table_level_hint_type: public TokenChoicemaster_unit(); TABLE_LIST *derived= unit->derived; - if (!(optimizer_flag(thd, OPTIMIZER_SWITCH_SPLIT_MATERIALIZED)) || // !(1) - !(derived && derived->is_materialized_derived()) || // !(2) + + if (!(derived && derived->is_materialized_derived()) || // !(2) (unit->first_select()->next_select()) || // !(3) (derived->prohibit_cond_pushdown) || // !(4) (derived->is_recursive_with_table()) || // !(5) @@ -416,6 +417,13 @@ bool JOIN::check_for_splittable_materialized() if (tbl->is_inner_table_of_outer_join()) continue; + /* If a hint disables split materialization for this table, then skip it. */ + const bool is_split_materialized_allowed= hint_table_state( + thd, tbl->table, SPLIT_MATERIALIZED_HINT_ENUM, + optimizer_flag(thd, OPTIMIZER_SWITCH_SPLIT_MATERIALIZED)); + if (!is_split_materialized_allowed) + continue; + List_iterator li(fields_list); Item *item; uint item_no= 0;