MDEV-36106 New-style hints: [NO_]DERIVED_CONDITION_PUSHDOWN, [NO_]MERGE

Implements and tests the optimizer hints DERIVED_CONDITION_PUSHDOWN
and NO_DERIVED_CONDITION_PUSHDOWN, table-level hints to enable and
disable, respectively, the condition pushdown for derived tables
which is typically controlled by the condition_pushdown_for_derived
optimizer switch.

Implements and tests the optimizer hints MERGE and NO_MERGE, table-level
hints to enable and disable, respectively, the derived_merge optimization
which is typically controlled by the derived_merge optimizer switch.

Sometimes hints need to be fixed before TABLE instances are available, but
after TABLE_LIST instances have been created (as in the cases of MERGE and
NO_MERGE).  This commit introduces a new function called
fix_hints_for_derived_table to allow early hint fixing for derived tables,
using only a TABLE_LIST instance (so long as such hints are not index-level).
This commit is contained in:
Dave Gosselin 2025-02-24 11:32:27 -05:00 committed by Sergei Golubchik
parent 60a64ab7c7
commit c43c88567f
10 changed files with 3367 additions and 41 deletions

File diff suppressed because it is too large Load Diff

View File

@ -0,0 +1,417 @@
--source include/have_sequence.inc
--disable_view_protocol
create table t1 (a int, b int, c int);
create table t2 (a int, b int, c int, d decimal);
insert into t1 values
(1,21,345), (1,33,7), (8,33,114), (1,21,500), (1,19,107), (5,14,787),
(8,33,123), (9,10,211), (5,16,207), (1,33,988), (5,27,132), (1,21,104),
(6,20,309), (6,20,315), (1,21,101), (8,33,404), (9,10,800), (1,21,123),
(7,11,708), (6,20,214);
create index t1_a on t1 (a);
insert into t2 values
(2,3,207,207.0000), (1,21,909,12.0000), (7,13,312,406.0000),
(8,64,248,107.0000), (6,20,315,279.3333), (1,19,203,107.0000),
(8,80,800,314.0000), (3,12,231,190.0000), (6,23,303,909.0000);
create view v1 as select a, b, max(c) as max_c, avg(c) as avg_c from t1
group by a,b having max_c < 707;
create table t3 select 2*seq as a, 2*seq+1 as b from seq_0_to_1000;
CREATE TABLE t4 (a INT, b INT);
INSERT INTO t4 VALUES (1,2),(2,3),(3,4);
create table t5 select seq as i, 10*seq as j from seq_1_to_10;
create view v2 as select * from t5;
create table t6 (a int primary key);
insert into t6 select * from seq_1_to_50;
create view v6 as select a from t6 where a mod 2 = 1;
set @save_optimizer_switch=@@optimizer_switch;
set session optimizer_switch='condition_pushdown_for_derived=on';
--source include/explain-no-costs.inc
explain format=json select /*+ NO_DERIVED_CONDITION_PUSHDOWN(v1) */ * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(v1) */ * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
select * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
--source include/explain-no-costs.inc
explain format=json with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(v1@qb1) */ * from cte;
with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(v1@qb1) */ * from cte;
with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select * from cte;
--source include/explain-no-costs.inc
explain format=json with recursive cte as (
select max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select * from cte where max_c < 100
) select /*+ NO_DERIVED_CONDITION_PUSHDOWN(cte) */ * from cte;
with recursive cte as (
select max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select * from cte where max_c < 100
) select /*+ NO_DERIVED_CONDITION_PUSHDOWN(cte) */ * from cte;
with recursive cte as (
select max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select * from cte where max_c < 100
) select * from cte;
--source include/explain-no-costs.inc
explain format=json select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt)*/ * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt)*/ * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
select * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
--echo "This explain and query shows the result when no hints are specified, for comparison to hint cases in the next three explain and select pairs"
--source include/explain-no-costs.inc
explain format=json select * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ NO_DERIVED_CONDITION_PUSHDOWN(du)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(du)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt,du)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt,du)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json SELECT /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
SELECT /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
SELECT * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
--source include/explain-no-costs.inc
explain format=json SELECT /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
SELECT /*+ NO_DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
SELECT * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
--source include/explain-no-costs.inc
explain format=json
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(@qb1 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(@qb2 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(@qb3 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ NO_DERIVED_CONDITION_PUSHDOWN(@qb4 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
set session optimizer_switch='condition_pushdown_for_derived=off';
--source include/explain-no-costs.inc
explain format=json select /*+ DERIVED_CONDITION_PUSHDOWN(v1) */ * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
select /*+ DERIVED_CONDITION_PUSHDOWN(v1) */ * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
select * from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a));
--source include/explain-no-costs.inc
explain format=json with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select /*+ DERIVED_CONDITION_PUSHDOWN(v1@qb1) */ * from cte;
with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select /*+ DERIVED_CONDITION_PUSHDOWN(v1@qb1) */ * from cte;
with cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a)))
select * from cte;
--source include/explain-no-costs.inc
explain format=json with recursive cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select /*+ QB_NAME(qb2) */ * from cte where max_c < 100
) select /*+ DERIVED_CONDITION_PUSHDOWN(v1@qb1) DERIVED_CONDITION_PUSHDOWN(cte) */ * from cte;
with recursive cte as (
select /*+ QB_NAME(qb1) */ max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select /*+ QB_NAME(qb2) */ * from cte where max_c < 100
) select /*+ DERIVED_CONDITION_PUSHDOWN(v1@qb1) DERIVED_CONDITION_PUSHDOWN(cte) */ * from cte;
with recursive cte as (
select max_c, avg_c from v1,t2 where
((v1.max_c>300) and (v1.avg_c>t2.d) and (v1.b=t2.b)) or
((v1.max_c<135) and (v1.max_c<t2.c) and (v1.a=t2.a))
union
select * from cte where max_c < 100
) select * from cte;
--source include/explain-no-costs.inc
explain format=json select /*+ DERIVED_CONDITION_PUSHDOWN(dt)*/ * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
select /*+ DERIVED_CONDITION_PUSHDOWN(dt)*/ * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
select * from
(select t3.b as a from t3 group by t3.a) dt where (dt.a=3 or dt.a=5);
--source include/explain-no-costs.inc
explain format=json SELECT /*+ DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
SELECT /*+ DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
SELECT * FROM (
SELECT t4.b AS a
FROM t4
GROUP BY t4.a
) dt WHERE (dt.a=2);
--source include/explain-no-costs.inc
explain format=json SELECT /*+ DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
SELECT /*+ DERIVED_CONDITION_PUSHDOWN(dt) */ * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
SELECT * FROM (
SELECT qb.b AS a
FROM (
select 1*t4.b as b, 1*t4.a as a from t4
) qb
GROUP BY qb.a
) dt WHERE (dt.a=2);
--echo "This explain and query shows the result when no hints are specified, for comparison to hint cases in the next three explain and select pairs"
--source include/explain-no-costs.inc
explain format=json select * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ DERIVED_CONDITION_PUSHDOWN(dt)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ DERIVED_CONDITION_PUSHDOWN(dt)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ DERIVED_CONDITION_PUSHDOWN(du)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ DERIVED_CONDITION_PUSHDOWN(du)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json select /*+ DERIVED_CONDITION_PUSHDOWN(dt,du)*/ * from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
select /*+ DERIVED_CONDITION_PUSHDOWN(dt,du)*/ count(*) from (
select t3.b as a from t3 group by t3.a
) dt join (
select t3.a as a, t3.b as b from t3 where t3.a % 2 = 0 group by t3.b
) du where (dt.a=3 or dt.a=5) and (du.a % 10 <> 0 or du.a % 5 <> 0);
--source include/explain-no-costs.inc
explain format=json
select /*+ DERIVED_CONDITION_PUSHDOWN(@qb1 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ DERIVED_CONDITION_PUSHDOWN(@qb2 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ DERIVED_CONDITION_PUSHDOWN(@qb3 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
--source include/explain-no-costs.inc
explain format=json
select /*+ DERIVED_CONDITION_PUSHDOWN(@qb4 dv6) */ * from
(select /*+ QB_NAME(qb4) */ * from
(select /*+ QB_NAME(qb3) */ * from
(select /*+ QB_NAME(qb2) */ * from
(select /*+ QB_NAME(qb1) */ avg_a from
(select avg(a) as avg_a from v6) dv6
) dv6) dv6) dv6) dv6 where avg_a <> 0;
set optimizer_switch=@save_optimizer_switch;
create table t7(a int);
insert into t7 values (1),(2),(3);
explain extended select /*+ NO_MERGE(t) NO_ICP(t key1) */ * from (select * from t7) t;
explain extended select /*+ NO_MERGE(t) NO_ICP(t) */ * from (select * from t7) t;
drop view v1, v2, v6;
drop table t1, t2, t3, t4, t5, t6, t7;
--enable_view_protocol

View File

@ -0,0 +1,469 @@
create table t1 select seq as i, 10*seq as j from seq_1_to_10;
create view v1 as select * from t1 where i % 2 = 0;
set @save_optimizer_switch=@@optimizer_switch;
set session optimizer_switch='derived_merge=on';
explain format=json SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i < 3 and t1.j > 8"
}
}
]
}
}
SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
explain format=json SELECT /*+ NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "dt.a < 3 and dt.b > 8",
"materialized": {
"query_block": {
"select_id": 2,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i < 3 and t1.j > 8"
}
}
]
}
}
}
}
]
}
}
SELECT /*+ NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
explain format=json select * from (select i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.j MOD 5 = 0 and t1.i MOD 2 = 0"
}
}
]
}
}
select * from (select i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain format=json select /*+ NO_MERGE(dt) */ * from (select /*+ NO_MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "dt.j MOD 5 = 0",
"materialized": {
"query_block": {
"select_id": 2,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i MOD 2 = 0 and t1.j MOD 5 = 0"
}
}
]
}
}
}
}
]
}
}
select /*+ NO_MERGE(dt) */ * from (select /*+ NO_MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain format=json select /*+ NO_MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "dt.j MOD 5 = 0",
"materialized": {
"query_block": {
"select_id": 2,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i MOD 2 = 0 and t1.j MOD 5 = 0"
}
}
]
}
}
}
}
]
}
}
select /*+ NO_MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain extended SELECT /*+ NO_MERGE(dt2) NO_MERGE(dt)*/ * FROM
(SELECT i as a, j as b FROM t1) AS dt, (SELECT i as a, j as b FROM t1) AS dt2
WHERE dt.a = dt2.a and dt.b = dt2.b AND dt.a < 3 AND dt.b > 8;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10 100.00 Using where
1 PRIMARY <derived3> ref key0 key0 16 dt.a,dt.b 1 100.00
3 DERIVED t1 ALL NULL NULL NULL NULL 10 100.00 Using where
2 DERIVED t1 ALL NULL NULL NULL NULL 10 100.00 Using where
Warnings:
Note 1003 /* select#1 */ select /*+ NO_MERGE(`dt2`@`select#1`) NO_MERGE(`dt`@`select#1`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt2`.`a` AS `a`,`dt2`.`b` AS `b` from (/* select#2 */ select `test`.`t1`.`i` AS `a`,`test`.`t1`.`j` AS `b` from `test`.`t1` where `test`.`t1`.`i` < 3 and `test`.`t1`.`j` > 8) `dt` join (/* select#3 */ select `test`.`t1`.`i` AS `a`,`test`.`t1`.`j` AS `b` from `test`.`t1` where `test`.`t1`.`i` < 3 and `test`.`t1`.`j` > 8) `dt2` where `dt2`.`a` = `dt`.`a` and `dt2`.`b` = `dt`.`b` and `dt`.`a` < 3 and `dt`.`b` > 8
set session optimizer_switch='derived_merge=off';
explain format=json SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "dt.a < 3 and dt.b > 8",
"materialized": {
"query_block": {
"select_id": 2,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i < 3 and t1.j > 8"
}
}
]
}
}
}
}
]
}
}
SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
explain format=json select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.j MOD 5 = 0 and t1.i MOD 2 = 0"
}
}
]
}
}
select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain format=json select * from (select i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "dt.j MOD 5 = 0",
"materialized": {
"query_block": {
"select_id": 2,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.i MOD 2 = 0 and t1.j MOD 5 = 0"
}
}
]
}
}
}
}
]
}
}
select * from (select i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain format=json select /*+ MERGE(dt) */ * from (select /*+ MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.j MOD 5 = 0 and t1.i MOD 2 = 0"
}
}
]
}
}
select /*+ MERGE(dt) */ * from (select /*+ MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain format=json select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": "COST_REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"loops": 1,
"rows": 10,
"cost": "COST_REPLACED",
"filtered": 100,
"attached_condition": "t1.j MOD 5 = 0 and t1.i MOD 2 = 0"
}
}
]
}
}
select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
i j
2 20
4 40
6 60
8 80
10 100
explain extended SELECT /*+ MERGE(dt2) MERGE(dt)*/ * FROM
(SELECT i as a, j as b FROM t1) AS dt, (SELECT i as a, j as b FROM t1) AS dt2
WHERE dt.a = dt2.a and dt.b = dt2.b AND dt.a < 3 AND dt.b > 8;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 100.00 Using where
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 select /*+ MERGE(`dt2`@`select#1`) MERGE(`dt`@`select#1`) */ `test`.`t1`.`i` AS `a`,`test`.`t1`.`j` AS `b`,`test`.`t1`.`i` AS `a`,`test`.`t1`.`j` AS `b` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`i` = `test`.`t1`.`i` and `test`.`t1`.`j` = `test`.`t1`.`j` and `test`.`t1`.`i` < 3 and `test`.`t1`.`j` > 8
set optimizer_switch=@save_optimizer_switch;
explain extended select /*+ NO_MERGE(t) */ * from (select * from t1) t;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10 100.00
2 DERIVED t1 ALL NULL NULL NULL NULL 10 100.00
Warnings:
Note 1003 /* select#1 */ select /*+ NO_MERGE(`t`@`select#1`) */ `t`.`i` AS `i`,`t`.`j` AS `j` from (/* select#2 */ select `test`.`t1`.`i` AS `i`,`test`.`t1`.`j` AS `j` from `test`.`t1`) `t`
explain extended select /*+ MERGE(t) */ * from (select * from t1) t;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 100.00
Warnings:
Note 1003 select /*+ MERGE(`t`@`select#1`) */ `test`.`t1`.`i` AS `i`,`test`.`t1`.`j` AS `j` from `test`.`t1`
create table t2 select seq as i, 10*seq as j from seq_1_to_10;
create view v2 as select * from t2;
set session optimizer_switch='derived_merge=off';
explain extended
SELECT /*+ merge(wrong_name) */a, b FROM
(SELECT /*+ merge(wrong_name) */ i as a, j as b FROM
(select i*10 as i, j*5 as j from v2) dt_in) AS dt_out
WHERE a < 3 AND b > 8;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 10 100.00 Using where
2 DERIVED <derived3> ALL NULL NULL NULL NULL 10 100.00 Using where
3 DERIVED t2 ALL NULL NULL NULL NULL 10 100.00 Using where
Warnings:
Warning 4221 Unresolved table name `wrong_name`@`select#2` for MERGE hint
Warning 4221 Unresolved table name `wrong_name`@`select#1` for MERGE hint
Note 1003 /* select#1 */ select `dt_out`.`a` AS `a`,`dt_out`.`b` AS `b` from (/* select#2 */ select `dt_in`.`i` AS `a`,`dt_in`.`j` AS `b` from (/* select#3 */ select `test`.`t2`.`i` * 10 AS `i`,`test`.`t2`.`j` * 5 AS `j` from `test`.`t2` where `test`.`t2`.`i` * 10 < 3 and `test`.`t2`.`j` * 5 > 8) `dt_in` where `dt_in`.`i` < 3 and `dt_in`.`j` > 8) `dt_out` where `dt_out`.`a` < 3 and `dt_out`.`b` > 8
SELECT /*+ MERGE(dt) MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `foo`@`select#1` for MERGE hint
SELECT /*+ MERGE(dt) MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4219 Hint MERGE(`dt`) is ignored as conflicting/duplicated
SELECT /*+ MERGE(bar) MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `bar`@`select#1` for MERGE hint
SELECT /*+ MERGE(bar) MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `bar`@`select#1` for MERGE hint
Warning 4221 Unresolved table name `foo`@`select#1` for MERGE hint
SELECT /*+ NO_MERGE(dt) NO_MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `foo`@`select#1` for NO_MERGE hint
SELECT /*+ NO_MERGE(dt) NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4219 Hint NO_MERGE(`dt`) is ignored as conflicting/duplicated
SELECT /*+ NO_MERGE(bar) NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `bar`@`select#1` for NO_MERGE hint
SELECT /*+ NO_MERGE(bar) NO_MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
a b
1 10
2 20
Warnings:
Warning 4221 Unresolved table name `bar`@`select#1` for NO_MERGE hint
Warning 4221 Unresolved table name `foo`@`select#1` for NO_MERGE hint
drop table t1, t2;
drop view v1, v2;

View File

@ -0,0 +1,95 @@
--source include/have_sequence.inc
--disable_view_protocol
create table t1 select seq as i, 10*seq as j from seq_1_to_10;
create view v1 as select * from t1 where i % 2 = 0;
set @save_optimizer_switch=@@optimizer_switch;
set session optimizer_switch='derived_merge=on';
--source include/explain-no-costs.inc
explain format=json SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--source include/explain-no-costs.inc
explain format=json SELECT /*+ NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT /*+ NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--source include/explain-no-costs.inc
explain format=json select * from (select i, j from v1) dt where dt.j % 5 = 0;
select * from (select i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain format=json select /*+ NO_MERGE(dt) */ * from (select /*+ NO_MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
select /*+ NO_MERGE(dt) */ * from (select /*+ NO_MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain format=json select /*+ NO_MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
select /*+ NO_MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain extended SELECT /*+ NO_MERGE(dt2) NO_MERGE(dt)*/ * FROM
(SELECT i as a, j as b FROM t1) AS dt, (SELECT i as a, j as b FROM t1) AS dt2
WHERE dt.a = dt2.a and dt.b = dt2.b AND dt.a < 3 AND dt.b > 8;
set session optimizer_switch='derived_merge=off';
--source include/explain-no-costs.inc
explain format=json SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--source include/explain-no-costs.inc
explain format=json select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain format=json select * from (select i, j from v1) dt where dt.j % 5 = 0;
select * from (select i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain format=json select /*+ MERGE(dt) */ * from (select /*+ MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
select /*+ MERGE(dt) */ * from (select /*+ MERGE(v1) */ i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain format=json select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
select /*+ MERGE(dt) */ * from (select i, j from v1) dt where dt.j % 5 = 0;
--source include/explain-no-costs.inc
explain extended SELECT /*+ MERGE(dt2) MERGE(dt)*/ * FROM
(SELECT i as a, j as b FROM t1) AS dt, (SELECT i as a, j as b FROM t1) AS dt2
WHERE dt.a = dt2.a and dt.b = dt2.b AND dt.a < 3 AND dt.b > 8;
set optimizer_switch=@save_optimizer_switch;
# Test warnings
explain extended select /*+ NO_MERGE(t) */ * from (select * from t1) t;
explain extended select /*+ MERGE(t) */ * from (select * from t1) t;
create table t2 select seq as i, 10*seq as j from seq_1_to_10;
create view v2 as select * from t2;
set session optimizer_switch='derived_merge=off';
explain extended
SELECT /*+ merge(wrong_name) */a, b FROM
(SELECT /*+ merge(wrong_name) */ i as a, j as b FROM
(select i*10 as i, j*5 as j from v2) dt_in) AS dt_out
WHERE a < 3 AND b > 8;
SELECT /*+ MERGE(dt) MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--disable_ps_protocol
SELECT /*+ MERGE(dt) MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--enable_ps_protocol
SELECT /*+ MERGE(bar) MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT /*+ MERGE(bar) MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT /*+ NO_MERGE(dt) NO_MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--disable_ps_protocol
SELECT /*+ NO_MERGE(dt) NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
--enable_ps_protocol
SELECT /*+ NO_MERGE(bar) NO_MERGE(dt) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
SELECT /*+ NO_MERGE(bar) NO_MERGE(foo) */ a, b FROM (SELECT i as a, j as b FROM t1) AS dt WHERE a < 3 AND b > 8;
drop table t1, t2;
drop view v1, v2;
--enable_view_protocol

View File

@ -45,6 +45,8 @@ struct st_opt_hint_info opt_hint_info[]=
{{STRING_WITH_LEN("JOIN_SUFFIX")}, false, true, true},
{{STRING_WITH_LEN("JOIN_ORDER")}, false, true, true},
{{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},
{null_clex_str, 0, 0, 0}
};
@ -199,6 +201,7 @@ Opt_hints_qb *get_qb_hints(Parse_context *pc)
/*
Mark the query block as resolved as we know which SELECT_LEX it is
attached to.
Note that children (indexes, tables) are probably not resolved, yet.
*/
qb->set_fixed();
@ -398,10 +401,52 @@ Opt_hints_qb::Opt_hints_qb(Opt_hints *opt_hints_arg,
}
/**
fix_hints_for_derived_table allows early hint fixing for
derived tables by linking both *this and the Opt_hints_table
object to the passed TABLE_LIST instance.
@param table_list Pointer to TABLE_LIST object
*/
void Opt_hints_qb::fix_hints_for_derived_table(TABLE_LIST *table_list)
{
Opt_hints_table *tab=
static_cast<Opt_hints_table *>(find_by_name(table_list->alias));
/*
If this is fixed and the corresponding Opt_hints_table doesn't exist (or it
exists and is fixed) then there's nothing to do, so return early.
*/
if (is_fixed() && (!tab || tab->is_fixed()))
return;
/*
This instance will have been marked as fixed on the basis of its
attachment to a SELECT_LEX (during get_qb_hints) but that is
insufficient to consider it fixed for the case where a TABLE
instance is required but not yet available. If the associated
table isn't yet fixed, then fix this hint as though it were unfixed.
We mark the Opt_hints_table as 'fixed' here and this means we
won't try to fix the child hints again later. They will remain
unfixed and will eventually produce "Unresolved index name" error
in opt_hints_qb->check_unfixed(). This is acceptable because
no child hints apply to derived tables.
*/
DBUG_ASSERT(!table_list->opt_hints_table);
DBUG_ASSERT(tab);
table_list->opt_hints_qb= this;
table_list->opt_hints_table= tab;
tab->set_fixed();
}
Opt_hints_table *Opt_hints_qb::fix_hints_for_table(TABLE *table,
const Lex_ident_table &alias)
{
Opt_hints_table *tab= static_cast<Opt_hints_table *>(find_by_name(alias));
Opt_hints_table *tab=
static_cast<Opt_hints_table *>(find_by_name(alias));
table->pos_in_table_list->opt_hints_qb= this;
@ -591,11 +636,9 @@ bool hint_key_state(const THD *thd, const TABLE *table,
}
bool hint_table_state(const THD *thd, const TABLE *table,
opt_hints_enum type_arg,
bool fallback_value)
bool hint_table_state(const THD *thd, const TABLE_LIST *table_list,
opt_hints_enum type_arg, bool fallback_value)
{
TABLE_LIST *table_list= table->pos_in_table_list;
if (table_list->opt_hints_qb)
{
bool ret_val= false;
@ -609,6 +652,15 @@ bool hint_table_state(const THD *thd, const TABLE *table,
}
bool hint_table_state(const THD *thd, const TABLE *table,
opt_hints_enum type_arg,
bool fallback_value)
{
return hint_table_state(thd, table->pos_in_table_list, type_arg,
fallback_value);
}
void append_table_name(THD *thd, String *str, const LEX_CSTRING &table_name,
const LEX_CSTRING &qb_name)
{

View File

@ -51,6 +51,11 @@
each table, as a result TABLE_LIST::opt_hints_table points to the table's
hints.
Non-index hints may be fixed before TABLE instances are available, by
calling fix_hints_for_derived_table and using a TABLE_LIST instance; as
the name implies, this is the case for derived tables (and such tables
are the only use case at this point).
== Hint hierarchy ==
Hints have this hierarchy, less specific to more specific:
@ -178,6 +183,13 @@ protected:
for key level.
*/
Lex_ident_sys name;
/*
Hints by default are NOT_FIXED.
When hints are fixed, during hint resolution, they
transition from NOT_FIXED to FIXED.
*/
enum class Fixed_state { NOT_FIXED, FIXED };
private:
/*
Parent object. There is no parent for global level,
@ -193,8 +205,8 @@ private:
/* Array of child objects. i.e. array of the lower level objects */
Mem_root_array<Opt_hints*, true> child_array;
/* true if hint is connected to the real object */
bool fixed;
/* FIXED if hint is connected to the real object (see above) */
Fixed_state fixed;
/*
Number of child hints that are fully fixed, that is, fixed and
@ -208,7 +220,7 @@ public:
Opt_hints *parent_arg,
MEM_ROOT *mem_root_arg)
: name(name_arg), parent(parent_arg), child_array(mem_root_arg),
fixed(false), n_fully_fixed_children(0)
fixed(Fixed_state::NOT_FIXED), n_fully_fixed_children(0)
{ }
bool is_specified(opt_hints_enum type_arg) const
@ -260,8 +272,8 @@ public:
}
void set_name(const Lex_ident_sys &name_arg) { name= name_arg; }
Opt_hints *get_parent() const { return parent; }
void set_fixed() { fixed= true; }
bool is_fixed() const { return fixed; }
void set_fixed() { fixed= Fixed_state::FIXED; }
bool is_fixed() const { return fixed == Fixed_state::FIXED; }
void incr_fully_fixed_children() { n_fully_fixed_children++; }
Mem_root_array<Opt_hints*, true> *child_array_ptr() { return &child_array; }
@ -450,6 +462,8 @@ public:
void append_hint_arguments(THD *thd, opt_hints_enum hint,
String *str) override;
void fix_hints_for_derived_table(TABLE_LIST *table_list);
/**
Function finds Opt_hints_table object corresponding to
table alias in the query block and attaches corresponding
@ -662,6 +676,20 @@ bool hint_key_state(const THD *thd, const TABLE *table,
uint keyno, opt_hints_enum type_arg,
uint optimizer_switch);
/**
Returns table hint value if hint is specified, returns
fallback value if hint is not specified.
@param thd Pointer to THD object
@param table_lsit Pointer to TABLE_LIST object
@param type_arg Hint type
@param fallback_value Value to be returned if the hint is not set
@return table hint value if hint is specified,
otherwise fallback value.
*/
bool hint_table_state(const THD *thd, const TABLE_LIST *table_list,
opt_hints_enum type_arg, bool fallback_value);
/**
Returns table hint value if hint is specified, returns

View File

@ -71,6 +71,10 @@ Optimizer_hint_tokenizer::find_keyword(const LEX_CSTRING &str)
if ("MRR"_Lex_ident_column.streq(str)) return TokenID::keyword_MRR;
break;
case 5:
if ("MERGE"_Lex_ident_column.streq(str)) return TokenID::keyword_MERGE;
break;
case 6:
if ("NO_BKA"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_BKA;
if ("NO_BNL"_Lex_ident_column.streq(str)) return TokenID::keyword_NO_BNL;
@ -88,6 +92,8 @@ Optimizer_hint_tokenizer::find_keyword(const LEX_CSTRING &str)
return TokenID::keyword_SEMIJOIN;
else if ("SUBQUERY"_Lex_ident_column.streq(str))
return TokenID::keyword_SUBQUERY;
else if ("NO_MERGE"_Lex_ident_column.streq(str))
return TokenID::keyword_NO_MERGE;
break;
case 9:
@ -134,6 +140,16 @@ Optimizer_hint_tokenizer::find_keyword(const LEX_CSTRING &str)
if ("NO_RANGE_OPTIMIZATION"_Lex_ident_column.streq(str))
return TokenID::keyword_NO_RANGE_OPTIMIZATION;
break;
case 26:
if ("DERIVED_CONDITION_PUSHDOWN"_Lex_ident_column.streq(str))
return TokenID::keyword_DERIVED_CONDITION_PUSHDOWN;
break;
case 29:
if ("NO_DERIVED_CONDITION_PUSHDOWN"_Lex_ident_column.streq(str))
return TokenID::keyword_NO_DERIVED_CONDITION_PUSHDOWN;
break;
}
if (str.length > 0 && (str.str[0] >= '0' && str.str[0] <= '9'))
@ -325,6 +341,22 @@ bool Parser::Table_level_hint::resolve(Parse_context *pc) const
hint_type= BKA_HINT_ENUM;
hint_state= false;
break;
case TokenID::keyword_DERIVED_CONDITION_PUSHDOWN:
hint_type= DERIVED_CONDITION_PUSHDOWN_HINT_ENUM;
hint_state= true;
break;
case TokenID::keyword_NO_DERIVED_CONDITION_PUSHDOWN:
hint_type= DERIVED_CONDITION_PUSHDOWN_HINT_ENUM;
hint_state= false;
break;
case TokenID::keyword_MERGE:
hint_type= MERGE_HINT_ENUM;
hint_state= true;
break;
case TokenID::keyword_NO_MERGE:
hint_type= MERGE_HINT_ENUM;
hint_state= false;
break;
default:
DBUG_ASSERT(0);
return true;

View File

@ -48,6 +48,8 @@ enum opt_hints_enum
JOIN_SUFFIX_HINT_ENUM,
JOIN_ORDER_HINT_ENUM,
JOIN_FIXED_ORDER_HINT_ENUM,
DERIVED_CONDITION_PUSHDOWN_HINT_ENUM,
MERGE_HINT_ENUM,
MAX_HINT_ENUM // This one must be the last in the list
};
@ -112,7 +114,11 @@ public:
keyword_JOIN_PREFIX,
keyword_JOIN_SUFFIX,
keyword_JOIN_ORDER,
keyword_JOIN_FIXED_ORDER
keyword_JOIN_FIXED_ORDER,
keyword_DERIVED_CONDITION_PUSHDOWN,
keyword_NO_DERIVED_CONDITION_PUSHDOWN,
keyword_MERGE,
keyword_NO_MERGE
};
class Token: public Lex_cstring
@ -363,7 +369,11 @@ private:
return id == TokenID::keyword_BKA ||
id == TokenID::keyword_BNL ||
id == TokenID::keyword_NO_BKA ||
id == TokenID::keyword_NO_BNL;
id == TokenID::keyword_NO_BNL ||
id == TokenID::keyword_DERIVED_CONDITION_PUSHDOWN ||
id == TokenID::keyword_NO_DERIVED_CONDITION_PUSHDOWN ||
id == TokenID::keyword_MERGE ||
id == TokenID::keyword_NO_MERGE;
}
};
class Table_level_hint_type: public TokenChoice<Parser,

View File

@ -2514,43 +2514,42 @@ JOIN::optimize_inner()
DBUG_RETURN(TRUE);
}
if (optimizer_flag(thd, OPTIMIZER_SWITCH_COND_PUSHDOWN_FOR_DERIVED))
TABLE_LIST *tbl;
List_iterator_fast<TABLE_LIST> li(select_lex->leaf_tables);
while ((tbl= li++))
{
TABLE_LIST *tbl;
List_iterator_fast<TABLE_LIST> li(select_lex->leaf_tables);
while ((tbl= li++))
const bool is_derived_pushdown_allowed= hint_table_state(
thd, tbl->table, DERIVED_CONDITION_PUSHDOWN_HINT_ENUM,
optimizer_flag(thd, OPTIMIZER_SWITCH_COND_PUSHDOWN_FOR_DERIVED));
if (!is_derived_pushdown_allowed)
{
/*
/* Run optimize phase on this derived table/view. */
if (tbl->is_view_or_derived() &&
tbl->handle_derived(thd->lex, DT_OPTIMIZE))
DBUG_RETURN(1);
continue;
}
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.
*/
if (tbl->is_materialized_derived())
if (!tbl->is_inner_table_of_outer_join())
{
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.
*/
if (!tbl->is_inner_table_of_outer_join())
{
if (pushdown_cond_for_derived(thd, conds, tbl))
DBUG_RETURN(1);
}
if (mysql_handle_single_derived(thd->lex, tbl, DT_OPTIMIZE))
DBUG_RETURN(1);
if (pushdown_cond_for_derived(thd, conds, tbl))
DBUG_RETURN(1);
}
if (mysql_handle_single_derived(thd->lex, tbl, DT_OPTIMIZE))
DBUG_RETURN(1);
}
}
else
{
/* Run optimize phase for all derived tables/views used in this SELECT. */
if (select_lex->handle_derived(thd->lex, DT_OPTIMIZE))
DBUG_RETURN(1);
}
{
if (select_lex->where)
{

View File

@ -57,6 +57,7 @@
#endif
#include "log_event.h" // MAX_TABLE_MAP_ID
#include "sql_class.h"
#include "opt_hints.h"
/* For MySQL 5.7 virtual fields */
#define MYSQL57_GENERATED_FIELD 128
@ -10146,6 +10147,19 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view)
bool forced_no_merge_for_update_delete=
belong_to_view ? belong_to_view->updating :
!unit->outer_select()->outer_select();
/*
In the case where a table merge operation moves a derived table from
one select to another, table hints may be adjusted already.
*/
if (select_lex->opt_hints_qb && // QB hints initialized
!this->opt_hints_table) // Table hints are not adjusted yet
select_lex->opt_hints_qb->fix_hints_for_derived_table(this);
bool is_derived_merge_allowed=
hint_table_state(thd, this, MERGE_HINT_ENUM,
optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_MERGE));
if (!is_materialized_derived() && unit->can_be_merged() &&
/*
Following is special case of
@ -10162,7 +10176,7 @@ bool TABLE_LIST::init_derived(THD *thd, bool init_view)
(!first_select->group_list.elements &&
!first_select->order_list.elements)) &&
(is_view() ||
optimizer_flag(thd, OPTIMIZER_SWITCH_DERIVED_MERGE)) &&
is_derived_merge_allowed) &&
!thd->lex->can_not_use_merged() &&
!(!is_view() && forced_no_merge_for_update_delete &&
(thd->lex->sql_command == SQLCOM_UPDATE_MULTI ||