From c1f388248fec314be49dc775757e1012c61d3015 Mon Sep 17 00:00:00 2001 From: Oleg Smirnov Date: Sun, 9 Nov 2025 02:01:07 +0700 Subject: [PATCH 1/2] MDEV-38045: Implement implicit query block names for optimizer hints This patch implements support for implicit query block (QB) names in optimizer hints, allowing hints to reference query blocks and tables within derived tables, views and CTEs without requiring explicit QB_NAME hints. Examples. -- Addressing a table inside a derived table using implicit QB name select /*+ no_index(t1@dt) */ * from (select * from t1 where a > 10) as DT; -- this is an equivalent to: select /*+ no_index(t1@dt) */ * from (select /*+ qb_name(dt)*/ * from t1 where a > 10) as DT; -- Addressing a query block corresponding to the derived table select /*+ no_bnl(@dt) */ * from (select * from t1, t2 where t.1.a > t2.a) as DT; -- View create view v1 as select * from t1 where a > 10 and b > 100; -- referencing a table inside a view by implicit QB name: select /*+ index_merge(t1@v1 idx_a, idx_b) */ * from v1, t2 where v1.a = t2.a; -- equivalent to: create view v1 as select /*+ qb_name(qb_v1) */ * from t1 where a > 10 and b > 100; select /*+ index_merge(t1@qb_v1 idx_a, idx_b) */ * from v1, t2 where v1.a = t2.a; -- CTE with aless100 as (select a from t1 where b <100) select /*+ index(t1@aless100) */ * from aless100; -- equivalent to: with aless100 as (select /*+ qb_name(aless100) */ a from t1 where b <100) select /*+ index(t1@aless100) */ * from aless100; Key changes: 1. Two-stage hint resolution - Introduced hint_resolution_stage enum (EARLY/LATE) to control when different hint types are resolved: - EARLY stage: before opening tables (QB_NAME, MERGE hints) - LATE stage: after opening tables (all other hints) 2. Implicit QB name support - Derived table/view/CTE aliases can now be used as implicit query block names in hint syntax: @alias, table@alias - Derived tables inside views can be addressed from outer queries using their aliases --- mysql-test/main/opt_hints.result | 48 +- mysql-test/main/opt_hints.test | 26 +- mysql-test/main/opt_hints_impl_qb_name.inc | 177 +++++ mysql-test/main/opt_hints_impl_qb_name.result | 695 ++++++++++++++++++ mysql-test/main/opt_hints_impl_qb_name.test | 22 + sql/opt_hints.cc | 238 +++++- sql/opt_hints.h | 4 + sql/opt_hints_parser.cc | 70 +- sql/opt_hints_parser.h | 45 +- sql/opt_hints_structs.h | 59 ++ sql/share/errmsg-utf8.txt | 4 + sql/sql_lex.h | 6 + sql/sql_parse.cc | 4 +- sql/sql_prepare.cc | 3 +- sql/sql_select.cc | 2 +- sql/sql_show.cc | 1 + sql/sql_view.cc | 2 +- 17 files changed, 1313 insertions(+), 93 deletions(-) create mode 100644 mysql-test/main/opt_hints_impl_qb_name.inc create mode 100644 mysql-test/main/opt_hints_impl_qb_name.result create mode 100644 mysql-test/main/opt_hints_impl_qb_name.test create mode 100644 sql/opt_hints_structs.h diff --git a/mysql-test/main/opt_hints.result b/mysql-test/main/opt_hints.result index fe305997302ac..53848c4e00339 100644 --- a/mysql-test/main/opt_hints.result +++ b/mysql-test/main/opt_hints.result @@ -439,6 +439,18 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t2 ref f1 f1 8 test.t3.f1,test.t3.f2 2 50.00 Using where; FirstMatch(t3) Warnings: Note 1003 update /*+ BKA(`t2`@`select#2`) NO_BNL(`t1`@`select#2`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) */ `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f2` = `test`.`t3`.`f2` and `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 and `test`.`t3`.`f2` between `test`.`t3`.`f1` and `test`.`t1`.`f2` and `test`.`t3`.`f2` + 1 >= `test`.`t3`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Same as above but addressing tables with QB name +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) BKA(t2@QB1) NO_BNL(t1@QB1)*/ t3 +SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN +(SELECT /*+ QB_NAME(QB1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND +t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 range PRIMARY,f2_idx,f3_idx f2_idx 4 NULL 2 100.00 Using index condition; Using where +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 3.33 Using where +1 PRIMARY t2 ref f1 f1 8 test.t3.f1,test.t3.f2 2 50.00 Using where; FirstMatch(t3) +Warnings: +Note 1003 update /*+ BKA(`t2`@`QB1`) NO_BNL(`t1`@`QB1`) NO_RANGE_OPTIMIZATION(`t3`@`select#1` `PRIMARY`) */ `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f1` = `test`.`t3`.`f1` and `test`.`t2`.`f2` = `test`.`t3`.`f2` and `test`.`t3`.`f1` > 30 and `test`.`t3`.`f1` < 33 and `test`.`t3`.`f2` between `test`.`t3`.`f1` and `test`.`t1`.`f2` and `test`.`t3`.`f2` + 1 >= `test`.`t3`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` # Turn off range access for all keys. EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3) */ t3 SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN @@ -450,6 +462,31 @@ id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY t3 eq_ref PRIMARY,f2_idx,f3_idx PRIMARY 4 test.t2.f1 1 100.00 Using where; End temporary Warnings: Note 1003 update /*+ NO_RANGE_OPTIMIZATION(`t3`@`select#1`) */ `test`.`t3` semi join (`test`.`t1` join `test`.`t2`) set `test`.`t3`.`f3` = 'mnbv' where `test`.`t1`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f1` = `test`.`t2`.`f1` and `test`.`t3`.`f2` = `test`.`t2`.`f2` and `test`.`t2`.`f1` > 30 and `test`.`t2`.`f1` < 33 and `test`.`t2`.`f2` between `test`.`t2`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t2`.`f1` + 1 and `test`.`t3`.`f3` = `test`.`t2`.`f3` +# Multi-table UPDATE with a derived table +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t2@dt)*/ t3, +(SELECT /*+ qb_name(dt)*/ t1.* FROM t1, t2 WHERE t1.f1 > t2.f1) AS dt +SET t3.f3 = 'mnbv' WHERE t3.f1 = dt.f1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 ALL PRIMARY,f2_idx NULL NULL NULL 56 100.00 +1 PRIMARY ref key0 key0 5 test.t3.f1 8 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 +2 DERIVED t2 index f1 f1 8 NULL 28 100.00 Using where; Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ update /*+ NO_RANGE_OPTIMIZATION(`t2`@`dt`) */ `test`.`t3` join (/* select#2 */ select /*+ QB_NAME(`dt`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`f1` > `test`.`t2`.`f1`) `dt` set `test`.`t3`.`f3` = 'mnbv' where `dt`.`f1` = `test`.`t3`.`f1` +# Multi-table UPDATE with a derived table and both table-level and +# query block-level hints +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t2@dt) NO_BNL(@dt)*/ t3, +(SELECT /*+ qb_name(dt)*/ t1.* FROM t1, t2 WHERE t1.f1 > t2.f1) AS dt +SET t3.f3 = 'mnbv' WHERE t3.f1 = dt.f1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t3 ALL PRIMARY,f2_idx NULL NULL NULL 56 100.00 +1 PRIMARY ref key0 key0 5 test.t3.f1 8 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 3 100.00 +2 DERIVED t2 index f1 f1 8 NULL 28 100.00 Using where; Using index +Warnings: +Note 1003 /* select#1 */ update /*+ NO_BNL(@`dt`) NO_RANGE_OPTIMIZATION(`t2`@`dt`) */ `test`.`t3` join (/* select#2 */ select /*+ QB_NAME(`dt`) */ `test`.`t1`.`f1` AS `f1`,`test`.`t1`.`f2` AS `f2` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`f1` > `test`.`t2`.`f1`) `dt` set `test`.`t3`.`f3` = 'mnbv' where `dt`.`f1` = `test`.`t3`.`f1` EXPLAIN EXTENDED DELETE FROM t3 WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN (SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND @@ -500,7 +537,7 @@ Warnings: Note 1003 (insert into `test`.`t3`(f1,f2,f3) select /*+ NO_ICP(`t5`@`select#1`) */ `test`.`t4`.`x` AS `x`,`test`.`t5`.`y` AS `y`,'filler' AS `filler` from `test`.`t4` join `test`.`t4` `t5` where `test`.`t4`.`y` = 8 and `test`.`t5`.`x` between 7 and (8 + 0)) # Turn off ICP for a particular table and a key EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) -(SELECT /*+ QB_NAME(qb1) NO_ICP(t5@QB1 x_idx)*/ t4.x, t5.y, 'filler' FROM t4, t4 t5 +(SELECT /*+ NO_ICP(t5@QB1 x_idx) QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t4 ref y_idx y_idx 5 const 1 100.00 @@ -550,15 +587,14 @@ id select_type table type possible_keys key key_len ref rows filtered Extra Warnings: Warning 4219 Hint QB_NAME(`qb1`) is ignored as conflicting/duplicated Note 1003 select /*+ QB_NAME(`qb1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t2` -# Should issue warning -EXPLAIN EXTENDED SELECT /*+ BKA(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +# QB_NAME may appear after the hint, but the hint is still resolved +EXPLAIN EXTENDED SELECT /*+ NO_BNL(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 -1 SIMPLE t2 ALL f1 NULL NULL NULL 28 25.00 Using where; Using join buffer (flat, BNL join) +1 SIMPLE t2 ALL f1 NULL NULL NULL 28 25.00 Using where Warnings: -Warning 4220 Query block name `qb1` is not found for BKA hint -Note 1003 select /*+ QB_NAME(`qb1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`f1` = `test`.`t1`.`f1` and `test`.`t2`.`f2` between `test`.`t1`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t1`.`f1` + 1 +Note 1003 select /*+ QB_NAME(`qb1`) NO_BNL(@`qb1`) */ `test`.`t2`.`f1` AS `f1`,`test`.`t2`.`f2` AS `f2`,`test`.`t2`.`f3` AS `f3` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`f1` = `test`.`t1`.`f1` and `test`.`t2`.`f2` between `test`.`t1`.`f1` and `test`.`t1`.`f2` and `test`.`t2`.`f2` + 1 >= `test`.`t1`.`f1` + 1 # Should not crash PREPARE stmt1 FROM "SELECT /*+ BKA(t2) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1"; diff --git a/mysql-test/main/opt_hints.test b/mysql-test/main/opt_hints.test index c3d1b3660ef7d..35282287bae86 100644 --- a/mysql-test/main/opt_hints.test +++ b/mysql-test/main/opt_hints.test @@ -248,12 +248,32 @@ SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN (SELECT /*+ BKA(t2) NO_BNL(t1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +--echo # Same as above but addressing tables with QB name +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t3 PRIMARY) BKA(t2@QB1) NO_BNL(t1@QB1)*/ t3 + SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN + (SELECT /*+ QB_NAME(QB1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND + t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); + --echo # Turn off range access for all keys. EXPLAIN EXTENDED UPDATE /*+ NO_RANGE_OPTIMIZATION(t3) */ t3 SET f3 = 'mnbv' WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN (SELECT t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 AND t1.f2 AND t2.f2 + 1 >= t1.f1 + 1); +--echo # Multi-table UPDATE with a derived table +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t2@dt)*/ t3, + (SELECT /*+ qb_name(dt)*/ t1.* FROM t1, t2 WHERE t1.f1 > t2.f1) AS dt +SET t3.f3 = 'mnbv' WHERE t3.f1 = dt.f1; + +--echo # Multi-table UPDATE with a derived table and both table-level and +--echo # query block-level hints +EXPLAIN EXTENDED +UPDATE /*+ NO_RANGE_OPTIMIZATION(t2@dt) NO_BNL(@dt)*/ t3, + (SELECT /*+ qb_name(dt)*/ t1.* FROM t1, t2 WHERE t1.f1 > t2.f1) AS dt +SET t3.f3 = 'mnbv' WHERE t3.f1 = dt.f1; + EXPLAIN EXTENDED DELETE FROM t3 WHERE f1 > 30 AND f1 < 33 AND (t3.f1, t3.f2, t3.f3) IN (SELECT /*+ QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND @@ -282,7 +302,7 @@ EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) --echo # Turn off ICP for a particular table and a key EXPLAIN EXTENDED INSERT INTO t3(f1, f2, f3) - (SELECT /*+ QB_NAME(qb1) NO_ICP(t5@QB1 x_idx)*/ t4.x, t5.y, 'filler' FROM t4, t4 t5 + (SELECT /*+ NO_ICP(t5@QB1 x_idx) QB_NAME(qb1) */ t4.x, t5.y, 'filler' FROM t4, t4 t5 WHERE t4.y = 8 AND t5.x BETWEEN 7 AND t4.y+0); --echo # Make sure ICP is expected to be used when there are no hints @@ -308,8 +328,8 @@ EXPLAIN EXTENDED REPLACE INTO t3(f1, f2, f3) --echo # Should issue warning EXPLAIN EXTENDED SELECT /*+ QB_NAME(qb1) QB_NAME(qb1 ) */ * FROM t2; ---echo # Should issue warning -EXPLAIN EXTENDED SELECT /*+ BKA(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 +--echo # QB_NAME may appear after the hint, but the hint is still resolved +EXPLAIN EXTENDED SELECT /*+ NO_BNL(@qb1) QB_NAME(qb1) */ t2.f1, t2.f2, t2.f3 FROM t1,t2 WHERE t1.f1=t2.f1 AND t2.f2 BETWEEN t1.f1 and t1.f2 and t2.f2 + 1 >= t1.f1 + 1; --echo # Should not crash diff --git a/mysql-test/main/opt_hints_impl_qb_name.inc b/mysql-test/main/opt_hints_impl_qb_name.inc new file mode 100644 index 0000000000000..f6269e908f824 --- /dev/null +++ b/mysql-test/main/opt_hints_impl_qb_name.inc @@ -0,0 +1,177 @@ +--echo # Table-level hint +explain extended select /*+ no_bnl(t2@dt)*/ * from + (select t1.* from t1, t2 where t1.a > t2.a) as dt; + +--echo # QB-level hint +explain extended select /*+ no_bnl(@dt)*/ * from + (select t1.* from t1, t2 where t1.a > t2.a) as dt; + +--echo # Index-level hints +--echo # Without the hint 'range' index access would be chosen +explain extended select /*+ no_index(t1@`T`)*/ * from + (select * from t1 where a < 3) T; + +--echo # Without the hint 'range' index access would be chosen +explain extended select /*+ no_range_optimization(t1@t1)*/ * from + (select * from t1 where a > 100 and a < 120) as t1; + +--echo # Regular and derived tables share same name but the hint is applied correctly +explain extended select /*+ index(t1@t1 idx_ab)*/ * from + (select * from t1 where a < 3) as t1; + +explain extended select /*+ no_index(t1@t2 idx_a) index(t1@t1 idx_ab)*/ * from + (select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; + +explain extended select /*+ no_index(t1@t1 idx_a, idx_ab)*/ * from + (select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; + +--echo # Nested derived tables +explain extended select /*+ no_bnl(t1@dt2)*/ * from + (select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; + +explain extended select /*+ no_index(t1@DT2)*/ * from + (select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; + +--echo # Explicit QB name overrides the implicit one +explain extended select /*+ no_index(t1@dt2)*/ * from + (select count(*) from t1, (select /*+ qb_name(dt2)*/ * from t1 where a < 5) dt1) as dt2; + +--echo # Both hints are applied +explain extended select /*+ no_index(t1@dt1) no_bnl(t1@dt2)*/ * from + (select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; + +--echo # Nested derived tables with ambiguous names +explain extended select * from + (select count(*) from t1, (select * from t1 where a < 5) t1) as t1; + +--echo # Warning on ambiguous query block name, hint is ignored + +--disable_ps_protocol +# PS protocol is disabled because the warning is genererated only during +# PREPARE step of a statement. When the QB name cannot be resolved the hint +# is discarded, so it is not present during EXECUTE step. The same applies +# not only to implicit but also to explicit QB names. + +explain extended select /*+ no_index(t1@t1)*/* from + (select count(*) from t1, (select * from t1 where a < 5) t1) as t1; + +--echo # The hint cannot be applied to a derived table with UNION +explain extended select /*+ no_index(t2@t1)*/* from + (select * from t1 where a < 3 union select * from t2 where a < 9) as t1; + +explain extended select /*+ no_index(t1@t1)*/* from + (select * from t1 where a < 3 union select * from t2 where a < 9) as t1; + +--echo # Test INSERT..SELECT +explain extended insert into t2 select /*+ no_bnl(t2@dt)*/ * from + (select t1.* from t1, t2 where t1.a > t2.a) as dt; + +--echo # MERGE/NO_MERGE hints are resolved early and so do not support +--echo # implicit QB names. Warning is expected +explain extended select /*+ no_merge(@dt)*/ * from + (select * from (select t1.* from t1, t2 where t1.a > t2.a) as dt1) as dt; + +--enable_ps_protocol + +--echo # ====================================== +--echo # Test CTEs +--echo # By default BNL and index access to t1 is used. +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; + +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(t1@cte)*/ * from cte; + +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte; + +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte)*/ * from cte; + +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte) no_index(t1@dt1)*/ * from cte; + +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@dt1 idx_a) no_bnl(@cte)*/ * from cte; + +--echo # Ambiguity: multiple occurencies of `cte`, the hint is ignored + +--disable_ps_protocol +# See the comment above for why PS protocol is disabled + +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte where cnt > 10 +union +select * from cte where cnt < 100; + +--echo # However, if CTE occurencies have different aliases, the hint can be applied +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte1)*/ * from cte as cte1 where cnt > 10 +union +select * from cte where cnt < 100; + +--enable_ps_protocol + +--echo # ====================================== +--echo # Test views +create view v1 as select * from t1 where a < 100; + +--echo # Default execution plan +explain extended select * + from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; + +explain extended + select /*+ index(t1@`v1` idx_ab) no_index(t1@`v2`)*/ * + from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; + +--echo # Nested views +create view v2 as select * from v1 where a < 300; + +--echo # Default execution plan +explain extended select * from v2; + +--echo # Addressing an object inside a nested view +explain extended select /*+ index(t1@`v1` idx_ab)*/ * from v2; + +create view v3 as select * from t1 union select * from t2; + +--echo # Unable to apply the hint to a table with UNION + +--disable_ps_protocol +# See the comment above for why PS protocol is disabled + +explain extended select /*+ no_index(t1@v3) */ * from v3; + +--echo # Ambiguity: view `v1` appears two times - should warn and ignore hint +explain extended select /*+ index(t2@v1) */ * from v1, + (select a from v1 where b > 5) dt; + +--enable_ps_protocol + +--echo # Implicit QB names are not supported inside views +create view v4 as select /*+ no_bnl(t2@dt)*/ * from + (select t1.* from t1, t2 where t1.a > t2.a) as dt; + +show create view v4; + +--echo # However, a derived table inside a view can be addressed from outer query +create view v5 as select dt.a from + t1, (select t1.* from t1, t2 where t1.a > t2.a) as dt where t1.a=dt.a; + +--echo # Addressing a single table +explain extended select /*+ no_bnl(t2@dt) */* from v5; +--echo # Addressing the whole derived table +explain extended select /*+ no_bnl(@dt) */* from v5; + +--echo # Derived tables inside views can be addressed by their aliases +explain extended select /*+ no_bnl(t2@dt) */ * from v4; + +drop view v1, v2, v3, v4, v5; \ No newline at end of file diff --git a/mysql-test/main/opt_hints_impl_qb_name.result b/mysql-test/main/opt_hints_impl_qb_name.result new file mode 100644 index 0000000000000..7198578586b5b --- /dev/null +++ b/mysql-test/main/opt_hints_impl_qb_name.result @@ -0,0 +1,695 @@ +create table t1 (a int, b int, c char(20), key idx_a(a), key idx_ab(a, b)); +insert into t1 select seq, seq, 'filler' from seq_1_to_100; +create table t2 as select * from t1; +analyze table t1,t2 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status Table is already up to date +test.t2 analyze status Engine-independent statistics collected +test.t2 analyze status OK + +================================================================ +set optimizer_switch= 'derived_merge=on'; +# Table-level hint +explain extended select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 select /*+ NO_BNL(`t2`@`select#2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a` +# QB-level hint +explain extended select /*+ no_bnl(@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 select /*+ NO_BNL(@`select#2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a` +# Index-level hints +# Without the hint 'range' index access would be chosen +explain extended select /*+ no_index(t1@`T`)*/ * from +(select * from t1 where a < 3) T; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 2.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`select#2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 +# Without the hint 'range' index access would be chosen +explain extended select /*+ no_range_optimization(t1@t1)*/ * from +(select * from t1 where a > 100 and a < 120) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 1.00 Using where +Warnings: +Note 1003 select /*+ NO_RANGE_OPTIMIZATION(`t1`@`select#2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 100 and `test`.`t1`.`a` < 120 +# Regular and derived tables share same name but the hint is applied correctly +explain extended select /*+ index(t1@t1 idx_ab)*/ * from +(select * from t1 where a < 3) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 select /*+ INDEX(`t1`@`select#2` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 +explain extended select /*+ no_index(t1@t2 idx_a) index(t1@t1 idx_ab)*/ * from +(select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 3 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`select#3` `idx_a`) INDEX(`t1`@`select#2` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5 and `test`.`t1`.`a` < 3 +explain extended select /*+ no_index(t1@t1 idx_a, idx_ab)*/ * from +(select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 2.00 Using where +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`select#2` `idx_a`,`idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5 and `test`.`t1`.`a` < 3 +# Nested derived tables +explain extended select /*+ no_bnl(t1@dt2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `dt2` +explain extended select /*+ no_index(t1@DT2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `dt2` +# Explicit QB name overrides the implicit one +explain extended select /*+ no_index(t1@dt2)*/ * from +(select count(*) from t1, (select /*+ qb_name(dt2)*/ * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `dt2` +# Both hints are applied +explain extended select /*+ no_index(t1@dt1) no_bnl(t1@dt2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#3`) NO_BNL(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `dt2` +# Nested derived tables with ambiguous names +explain extended select * from +(select count(*) from t1, (select * from t1 where a < 5) t1) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select `t1`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `t1` +# Warning on ambiguous query block name, hint is ignored +explain extended select /*+ no_index(t1@t1)*/* from +(select count(*) from t1, (select * from t1 where a < 5) t1) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Warning 4243 Query block name `t1` is ambiguous for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5) `t1` +# The hint cannot be applied to a derived table with UNION +explain extended select /*+ no_index(t2@t1)*/* from +(select * from t1 where a < 3 union select * from t2 where a < 9) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +3 UNION t2 ALL NULL NULL NULL NULL 100 8.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `t1` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 union /* select#3 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where `test`.`t2`.`a` < 9) `t1` +explain extended select /*+ no_index(t1@t1)*/* from +(select * from t1 where a < 3 union select * from t2 where a < 9) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +3 UNION t2 ALL NULL NULL NULL NULL 100 8.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `t1` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 union /* select#3 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where `test`.`t2`.`a` < 9) `t1` +# Test INSERT..SELECT +explain extended insert into t2 select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 Using temporary +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 insert into `test`.`t2` select /*+ NO_BNL(`t2`@`select#2`) */ sql_buffer_result `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a` +# MERGE/NO_MERGE hints are resolved early and so do not support +# implicit QB names. Warning is expected +explain extended select /*+ no_merge(@dt)*/ * from +(select * from (select t1.* from t1, t2 where t1.a > t2.a) as dt1) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4220 Query block name `dt` is not found for NO_MERGE hint +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a` +# ====================================== +# Test CTEs +# By default BNL and index access to t1 is used. +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(t1@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_BNL(`t1`@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_BNL(@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte) no_index(t1@dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) NO_INDEX(`t1`@`select#3`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@dt1 idx_a) no_bnl(@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 300 100.00 +2 DERIVED t1 range idx_ab idx_ab 5 NULL 3 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#3` `idx_a`) NO_BNL(@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Ambiguity: multiple occurencies of `cte`, the hint is ignored +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte where cnt > 10 +union +select * from cte where cnt < 100; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using where +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +4 UNION ALL NULL NULL NULL NULL 200 100.00 Using where +5 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +5 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4243 Query block name `cte` is ambiguous for NO_BNL hint +Note 1003 with cte as (/* select#2 */ select count(0) AS `cnt` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5 having `cnt` > 10)/* select#1 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` > 10 union /* select#4 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` < 100 +# However, if CTE occurencies have different aliases, the hint can be applied +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte1)*/ * from cte as cte1 where cnt > 10 +union +select * from cte where cnt < 100; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using where +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +4 UNION ALL NULL NULL NULL NULL 200 100.00 Using where +5 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +5 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `cnt` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5 having `cnt` > 10)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `cte1`.`cnt` AS `cnt` from `cte` `cte1` where `cte1`.`cnt` > 10 union /* select#4 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` < 100 +# ====================================== +# Test views +create view v1 as select * from t1 where a < 100; +# Default execution plan +explain extended select * +from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +1 SIMPLE t1 ref idx_a,idx_ab idx_a 5 test.t1.a 1 100.00 +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` < 3 and `test`.`t1`.`a` < 100 and `test`.`t1`.`a` < 100 +explain extended +select /*+ index(t1@`v1` idx_ab) no_index(t1@`v2`)*/ * +from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 99.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ INDEX(`t1` `idx_ab`) NO_INDEX(`t1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` < 3 and `test`.`t1`.`a` < 100 and `test`.`t1`.`a` < 100 +# Nested views +create view v2 as select * from v1 where a < 300; +# Default execution plan +explain extended select * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 94.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 300 and `test`.`t1`.`a` < 100 +# Addressing an object inside a nested view +explain extended select /*+ index(t1@`v1` idx_ab)*/ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 99 100.00 Using index condition +Warnings: +Note 1003 select /*+ INDEX(`t1` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 300 and `test`.`t1`.`a` < 100 +create view v3 as select * from t1 union select * from t2; +# Unable to apply the hint to a table with UNION +explain extended select /*+ no_index(t1@v3) */ * from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 +3 UNION t2 ALL NULL NULL NULL NULL 100 100.00 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `v3` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Ambiguity: view `v1` appears two times - should warn and ignore hint +explain extended select /*+ index(t2@v1) */ * from v1, +(select a from v1 where b > 5) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_ab 5 NULL 99 90.20 Using where; Using index +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 94.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4243 Query block name `v1` is ambiguous for INDEX hint +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`b` > 5 and `test`.`t1`.`a` < 100 and `test`.`t1`.`a` < 100 +# Implicit QB names are not supported inside views +create view v4 as select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +Warnings: +Warning 4242 Implicit query block names are ignored for hints specified within VIEWs +show create view v4; +View Create View character_set_client collation_connection +v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (`t1` join `t2`) where `t1`.`a` > `t2`.`a`) `dt` latin1 latin1_swedish_ci +# However, a derived table inside a view can be addressed from outer query +create view v5 as select dt.a from +t1, (select t1.* from t1, t2 where t1.a > t2.a) as dt where t1.a=dt.a; +# Addressing a single table +explain extended select /*+ no_bnl(t2@dt) */* from v5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 index idx_a,idx_ab idx_a 5 NULL 100 100.00 Using where; Using index +1 SIMPLE t1 ref idx_a,idx_ab idx_a 5 test.t1.a 1 100.00 Using index +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 select /*+ NO_BNL(`t2`) */ `test`.`t1`.`a` AS `a` from `test`.`t1` join `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` > `test`.`t2`.`a` +# Addressing the whole derived table +explain extended select /*+ no_bnl(@dt) */* from v5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 index idx_a,idx_ab idx_a 5 NULL 100 100.00 Using where; Using index +1 SIMPLE t1 ref idx_a,idx_ab idx_a 5 test.t1.a 1 100.00 Using index +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 select /*+ NO_BNL() */ `test`.`t1`.`a` AS `a` from `test`.`t1` join `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` > `test`.`t2`.`a` +# Derived tables inside views can be addressed by their aliases +explain extended select /*+ no_bnl(t2@dt) */ * from v4; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +1 SIMPLE t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 select /*+ NO_BNL(`t2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a` +drop view v1, v2, v3, v4, v5; + +================================================================ +set optimizer_switch= 'derived_merge=off'; +# Table-level hint +explain extended select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 10000 100.00 +2 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +2 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(`t2`@`select#2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` +# QB-level hint +explain extended select /*+ no_bnl(@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 10000 100.00 +2 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +2 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(@`select#2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` +# Index-level hints +# Without the hint 'range' index access would be chosen +explain extended select /*+ no_index(t1@`T`)*/ * from +(select * from t1 where a < 3) T; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 2.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `T`.`a` AS `a`,`T`.`b` AS `b`,`T`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `T` +# Without the hint 'range' index access would be chosen +explain extended select /*+ no_range_optimization(t1@t1)*/ * from +(select * from t1 where a > 100 and a < 120) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 1.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_RANGE_OPTIMIZATION(`t1`@`select#2`) */ `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 100 and `test`.`t1`.`a` < 120) `t1` +# Regular and derived tables share same name but the hint is applied correctly +explain extended select /*+ index(t1@t1 idx_ab)*/ * from +(select * from t1 where a < 3) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select /*+ INDEX(`t1`@`select#2` `idx_ab`) */ `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `t1` +explain extended select /*+ no_index(t1@t2 idx_a) index(t1@t1 idx_ab)*/ * from +(select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 3 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_ab idx_ab 5 NULL 3 100.00 Using index condition +2 DERIVED t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#3` `idx_a`) INDEX(`t1`@`select#2` `idx_ab`) */ `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c`,`t2`.`a` AS `a`,`t2`.`b` AS `b`,`t2`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `t2` +explain extended select /*+ no_index(t1@t1 idx_a, idx_ab)*/ * from +(select * from t1 where a < 3) as t1, (select * from t1 where a < 5) as t2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +2 DERIVED t1 ALL NULL NULL NULL NULL 100 2.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2` `idx_a`,`idx_ab`) */ `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c`,`t2`.`a` AS `a`,`t2`.`b` AS `b`,`t2`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `t2` +# Nested derived tables +explain extended select /*+ no_bnl(t1@dt2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`) `dt2` +explain extended select /*+ no_index(t1@DT2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`) `dt2` +# Explicit QB name overrides the implicit one +explain extended select /*+ no_index(t1@dt2)*/ * from +(select count(*) from t1, (select /*+ qb_name(dt2)*/ * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED ALL NULL NULL NULL NULL 4 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`dt2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`) `dt2` +# Both hints are applied +explain extended select /*+ no_index(t1@dt1) no_bnl(t1@dt2)*/ * from +(select count(*) from t1, (select * from t1 where a < 5) dt1) as dt2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED ALL NULL NULL NULL NULL 4 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +3 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#3`) NO_BNL(`t1`@`select#2`) */ `dt2`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`) `dt2` +# Nested derived tables with ambiguous names +explain extended select * from +(select count(*) from t1, (select * from t1 where a < 5) t1) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select `t1`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `t1`) `t1` +# Warning on ambiguous query block name, hint is ignored +explain extended select /*+ no_index(t1@t1)*/* from +(select count(*) from t1, (select * from t1 where a < 5) t1) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Warning 4243 Query block name `t1` is ambiguous for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`count(*)` AS `count(*)` from (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `t1`) `t1` +# The hint cannot be applied to a derived table with UNION +explain extended select /*+ no_index(t2@t1)*/* from +(select * from t1 where a < 3 union select * from t2 where a < 9) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +3 UNION t2 ALL NULL NULL NULL NULL 100 8.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `t1` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 union /* select#3 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where `test`.`t2`.`a` < 9) `t1` +explain extended select /*+ no_index(t1@t1)*/* from +(select * from t1 where a < 3 union select * from t2 where a < 9) as t1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +3 UNION t2 ALL NULL NULL NULL NULL 100 8.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `t1` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3 union /* select#3 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where `test`.`t2`.`a` < 9) `t1` +# Test INSERT..SELECT +explain extended insert into t2 select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 10000 100.00 +2 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +2 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 insert into `test`.`t2` /* select#1 */ select /*+ NO_BNL(`t2`@`select#2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` +# MERGE/NO_MERGE hints are resolved early and so do not support +# implicit QB names. Warning is expected +explain extended select /*+ no_merge(@dt)*/ * from +(select * from (select t1.* from t1, t2 where t1.a > t2.a) as dt1) as dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 10000 100.00 +2 DERIVED ALL NULL NULL NULL NULL 10000 100.00 +3 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +3 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Warning 4220 Query block name `dt` is not found for NO_MERGE hint +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `dt1`.`a` AS `a`,`dt1`.`b` AS `b`,`dt1`.`c` AS `c` from (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt1`) `dt` +# ====================================== +# Test CTEs +# By default BNL and index access to t1 is used. +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(t1@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_BNL(`t1`@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_BNL(@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte) no_index(t1@dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED ALL NULL NULL NULL NULL 4 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) NO_INDEX(`t1`@`select#3`) */ `cte`.`count(*)` AS `count(*)` from `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@dt1 idx_a) no_bnl(@cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 300 100.00 +2 DERIVED ALL NULL NULL NULL NULL 3 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index +3 DERIVED t1 range idx_ab idx_ab 5 NULL 3 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#3` `idx_a`) NO_BNL(@`select#2`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Ambiguity: multiple occurencies of `cte`, the hint is ignored +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_bnl(@cte)*/ * from cte where cnt > 10 +union +select * from cte where cnt < 100; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using where +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +4 UNION ALL NULL NULL NULL NULL 200 100.00 Using where +5 DERIVED ALL NULL NULL NULL NULL 2 100.00 +5 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +6 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4243 Query block name `cte` is ambiguous for NO_BNL hint +Note 1003 with cte as (/* select#2 */ select count(0) AS `cnt` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1` having `cnt` > 10)/* select#1 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` > 10 union /* select#4 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` < 100 +# However, if CTE occurencies have different aliases, the hint can be applied +explain extended +with cte as (select count(*) as cnt from t1, (select * from t1 where a < 5) dt1) +select /*+ no_index(t1@cte1)*/ * from cte as cte1 where cnt > 10 +union +select * from cte where cnt < 100; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using where +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +4 UNION ALL NULL NULL NULL NULL 200 100.00 Using where +5 DERIVED ALL NULL NULL NULL NULL 2 100.00 +5 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +6 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `cnt` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1` having `cnt` > 10)/* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `cte1`.`cnt` AS `cnt` from `cte` `cte1` where `cte1`.`cnt` > 10 union /* select#4 */ select `cte`.`cnt` AS `cnt` from `cte` where `cte`.`cnt` < 100 +# ====================================== +# Test views +create view v1 as select * from t1 where a < 100; +# Default execution plan +explain extended select * +from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 1 100.00 Using index condition +1 SIMPLE t1 ref idx_a,idx_ab idx_a 5 test.t1.a 1 100.00 +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` < 3 and `test`.`t1`.`a` < 100 and `test`.`t1`.`a` < 100 +explain extended +select /*+ index(t1@`v1` idx_ab) no_index(t1@`v2`)*/ * +from v1, v1 as v2 where v1.a = v2.a and v1.a < 3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 2 100.00 Using index condition +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 99.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ INDEX(`t1` `idx_ab`) NO_INDEX(`t1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` = `test`.`t1`.`a` and `test`.`t1`.`a` < 3 and `test`.`t1`.`a` < 100 and `test`.`t1`.`a` < 100 +# Nested views +create view v2 as select * from v1 where a < 300; +# Default execution plan +explain extended select * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL idx_a,idx_ab NULL NULL NULL 100 94.00 Using where +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 300 and `test`.`t1`.`a` < 100 +# Addressing an object inside a nested view +explain extended select /*+ index(t1@`v1` idx_ab)*/ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 99 100.00 Using index condition +Warnings: +Note 1003 select /*+ INDEX(`t1` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 300 and `test`.`t1`.`a` < 100 +create view v3 as select * from t1 union select * from t2; +# Unable to apply the hint to a table with UNION +explain extended select /*+ no_index(t1@v3) */ * from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 +3 UNION t2 ALL NULL NULL NULL NULL 100 100.00 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Warning 4244 Implicit query block name `v3` is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for NO_INDEX hint +Note 1003 /* select#1 */ select `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Ambiguity: view `v1` appears two times - should warn and ignore hint +explain extended select /*+ index(t2@v1) */ * from v1, +(select a from v1 where b > 5) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL idx_a,idx_ab NULL NULL NULL 100 94.00 Using where +1 PRIMARY ALL NULL NULL NULL NULL 99 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_ab 5 NULL 99 90.20 Using where; Using index +Warnings: +Warning 4243 Query block name `v1` is ambiguous for INDEX hint +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`dt`.`a` AS `a` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`b` > 5 and `test`.`t1`.`a` < 100) `dt` where `test`.`t1`.`a` < 100 +# Implicit QB names are not supported inside views +create view v4 as select /*+ no_bnl(t2@dt)*/ * from +(select t1.* from t1, t2 where t1.a > t2.a) as dt; +Warnings: +Warning 4242 Implicit query block names are ignored for hints specified within VIEWs +show create view v4; +View Create View character_set_client collation_connection +v4 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v4` AS select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (select `t1`.`a` AS `a`,`t1`.`b` AS `b`,`t1`.`c` AS `c` from (`t1` join `t2`) where `t1`.`a` > `t2`.`a`) `dt` latin1 latin1_swedish_ci +# However, a derived table inside a view can be addressed from outer query +create view v5 as select dt.a from +t1, (select t1.* from t1, t2 where t1.a > t2.a) as dt where t1.a=dt.a; +# Addressing a single table +explain extended select /*+ no_bnl(t2@dt) */* from v5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 index idx_a,idx_ab idx_a 5 NULL 100 100.00 Using where; Using index +1 PRIMARY ref key0 key0 5 test.t1.a 100 100.00 +3 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +3 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(`t2`) */ `dt`.`a` AS `a` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` where `dt`.`a` = `test`.`t1`.`a` +# Addressing the whole derived table +explain extended select /*+ no_bnl(@dt) */* from v5; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 index idx_a,idx_ab idx_a 5 NULL 100 100.00 Using where; Using index +1 PRIMARY ref key0 key0 5 test.t1.a 100 100.00 +3 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +3 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL() */ `dt`.`a` AS `a` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` where `dt`.`a` = `test`.`t1`.`a` +# Derived tables inside views can be addressed by their aliases +explain extended select /*+ no_bnl(t2@dt) */ * from v4; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 10000 100.00 +3 DERIVED t1 ALL idx_a,idx_ab NULL NULL NULL 100 100.00 +3 DERIVED t2 ALL NULL NULL NULL NULL 100 100.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_BNL(`t2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` > `test`.`t2`.`a`) `dt` +drop view v1, v2, v3, v4, v5; +set optimizer_switch= default; +drop table t1, t2; diff --git a/mysql-test/main/opt_hints_impl_qb_name.test b/mysql-test/main/opt_hints_impl_qb_name.test new file mode 100644 index 0000000000000..8a2fdf88ef4bd --- /dev/null +++ b/mysql-test/main/opt_hints_impl_qb_name.test @@ -0,0 +1,22 @@ +--source include/have_sequence.inc + +create table t1 (a int, b int, c char(20), key idx_a(a), key idx_ab(a, b)); + +insert into t1 select seq, seq, 'filler' from seq_1_to_100; + +create table t2 as select * from t1; + +analyze table t1,t2 persistent for all; + +--echo +--echo ================================================================ +set optimizer_switch= 'derived_merge=on'; +--source opt_hints_impl_qb_name.inc + +--echo +--echo ================================================================ +set optimizer_switch= 'derived_merge=off'; +--source opt_hints_impl_qb_name.inc + +set optimizer_switch= default; +drop table t1, t2; \ No newline at end of file diff --git a/sql/opt_hints.cc b/sql/opt_hints.cc index f2cae70f0ee63..1d2aa496caa6d 100644 --- a/sql/opt_hints.cc +++ b/sql/opt_hints.cc @@ -15,10 +15,12 @@ Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA */ #include "my_global.h" +#include "opt_hints_structs.h" #include "sql_class.h" #include "sql_lex.h" #include "sql_select.h" #include "opt_hints.h" +#include "opt_trace.h" /** Information about hints. Must be in sync with opt_hints_enum. @@ -30,32 +32,34 @@ can control wishful form of the hint name. */ +using hrs= hint_resolution_stage; + struct st_opt_hint_info opt_hint_info[]= { - // hint_type check_upper has_args irregular - {{STRING_WITH_LEN("BKA")}, true, false, false}, - {{STRING_WITH_LEN("BNL")}, true, false, false}, - {{STRING_WITH_LEN("ICP")}, true, false, false}, - {{STRING_WITH_LEN("MRR")}, true, false, false}, - {{STRING_WITH_LEN("NO_RANGE_OPTIMIZATION")}, true, false, false}, - {{STRING_WITH_LEN("QB_NAME")}, false, false, false}, - {{STRING_WITH_LEN("MAX_EXECUTION_TIME")}, false, true, false}, - {{STRING_WITH_LEN("SEMIJOIN")}, false, true, false}, - {{STRING_WITH_LEN("SUBQUERY")}, false, true, false}, - {{STRING_WITH_LEN("JOIN_PREFIX")}, false, true, true}, - {{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")}, true, false, false}, - {{STRING_WITH_LEN("SPLIT_MATERIALIZED")}, false, false, false}, - {{STRING_WITH_LEN("INDEX")}, false, true, false}, - {{STRING_WITH_LEN("JOIN_INDEX")}, false, true, false}, - {{STRING_WITH_LEN("GROUP_INDEX")}, false, true, false}, - {{STRING_WITH_LEN("ORDER_INDEX")}, false, true, false}, - {{STRING_WITH_LEN("ROWID_FILTER")}, false, true, false}, - {{STRING_WITH_LEN("INDEX_MERGE")}, false, false, false}, - {null_clex_str, 0, 0, 0} + // hint_type check_upper has_args irregular resolution_stage + {{STRING_WITH_LEN("BKA")}, true, false, false, hrs::LATE}, + {{STRING_WITH_LEN("BNL")}, true, false, false, hrs::LATE}, + {{STRING_WITH_LEN("ICP")}, true, false, false, hrs::LATE}, + {{STRING_WITH_LEN("MRR")}, true, false, false, hrs::LATE}, + {{STRING_WITH_LEN("NO_RANGE_OPTIMIZATION")}, true, false, false, hrs::LATE}, + {{STRING_WITH_LEN("QB_NAME")}, false, false, false, hrs::EARLY}, + {{STRING_WITH_LEN("MAX_EXECUTION_TIME")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("SEMIJOIN")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("SUBQUERY")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("JOIN_PREFIX")}, false, true, true, hrs::LATE}, + {{STRING_WITH_LEN("JOIN_SUFFIX")}, false, true, true, hrs::LATE}, + {{STRING_WITH_LEN("JOIN_ORDER")}, false, true, true, hrs::LATE}, + {{STRING_WITH_LEN("JOIN_FIXED_ORDER")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("DERIVED_CONDITION_PUSHDOWN")}, false, false, false, hrs::LATE}, + {{STRING_WITH_LEN("MERGE")}, true, false, false, hrs::EARLY}, + {{STRING_WITH_LEN("SPLIT_MATERIALIZED")}, false, false, false, hrs::LATE}, + {{STRING_WITH_LEN("INDEX")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("JOIN_INDEX")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("GROUP_INDEX")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("ORDER_INDEX")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("ROWID_FILTER")}, false, true, false, hrs::LATE}, + {{STRING_WITH_LEN("INDEX_MERGE")}, false, false, false, hrs::LATE}, + {null_clex_str, 0, 0, 0, hrs::LATE} }; /** @@ -84,7 +88,6 @@ int cmp_lex_string(const LEX_CSTRING &s, const LEX_CSTRING &t, (const uchar*)t.str, t.length); } - /* This is a version of push_warning_printf() guaranteeing no escalation of the warning to the level of error @@ -137,7 +140,9 @@ void print_warn(THD *thd, uint err_code, opt_hints_enum hint_type, str.append(opt_hint_info[hint_type].hint_type); /* ER_WARN_UNKNOWN_QB_NAME with two arguments */ - if (err_code == ER_WARN_UNKNOWN_QB_NAME) + if (err_code == ER_WARN_UNKNOWN_QB_NAME || + err_code == ER_WARN_AMBIGUOUS_QB_NAME || + err_code == ER_WARN_IMPLICIT_QB_NAME_FOR_UNION) { String qb_name_str; append_identifier(thd, &qb_name_str, qb_name_arg->str, qb_name_arg->length); @@ -287,6 +292,98 @@ static Opt_hints_qb *find_hints_by_select_number(Parse_context *pc, return qb; } +/** + Helper function to find_qb_hints whereby it matches a qb_name to + an alias of a derived table, view or CTE used in the current query. + For example, for query + `select * from (select ... from t1 ...) as DT` + and given qb_name "DT", this function will return the query block + corresponding to the derived table DT, just like if the name was specified + explicitly using the QB_NAME hint: + `select * from (select / *+ QB_NAME(DT) * / ... from t1 ...) as DT` + + For query + `select * from v1, v1 as v2 where v1.a = v2.a and v1.a < 3` + and given qb_name "v2", this function will return the query block + corresponding to the view v2. + + For query + `with lda as (select ... from t1 ...) + select * from lda` + and given qb_name "lda", this function will return the query block + corresponding to the CTE "lda", just like if the name was specified + explicitly using the QB_NAME hint: + `with lda as (select / *+ QB_NAME(lda) * / ... from t1 ...) + select * from lda` + + @return the pair: - result code + - matching query block hints object, if it exists, + and NULL otherwise + */ + +enum class implicit_qb_result +{ + OK, // Found exactly one match, success + // Failure statuses: + NOT_FOUND, // No matches found + AMBIGUOUS, // More than one alias matches qb_name in the current query + UNION // DT/view/CTE has UNION/EXCEPT/INTERSECT inside + // (i.e., multiple query blocks), so the hint cannot be resolved + // unambiguously +}; + +static std::pair +find_hints_by_implicit_qb_name(Parse_context *pc, const Lex_ident_sys &qb_name) +{ + Opt_hints_qb *qb= nullptr; + + // Traverse the global table list to find all derived tables and views + for (TABLE_LIST *tbl= pc->thd->lex->query_tables; tbl; tbl= tbl->next_global) + { + // Skip if neither a derived table nor a view + if (!tbl->is_view_or_derived()) + continue; + + // Check if the alias equals the implicit QB name + if (cmp_lex_string(tbl->alias, qb_name, system_charset_info)) + continue; // not a match, continue to next table + + if (qb) + { + /* + `qb` was already set before, this means there are multiple tables with + same alias in the query. The name cannot be resolved unambiguously. + */ + return std::make_pair(implicit_qb_result::AMBIGUOUS, nullptr); + } + + SELECT_LEX *child_select; + if (tbl->is_derived()) + { + child_select= tbl->derived->first_select(); + } + else + { + DBUG_ASSERT(tbl->is_view()); + child_select= tbl->view->unit.first_select(); + } + /* + Check if the derived table/view does not contain UNION, because + implicit QB names for UNIONs are ambiguous - we do not know which SELECT + should the hint be applied to. So we only support implicit names + for single-SELECT derived tables/views. + */ + if (child_select->next_select()) + return std::make_pair(implicit_qb_result::UNION, nullptr); + + Parse_context child_ctx(pc, child_select); + qb= get_qb_hints(&child_ctx); + } + + return std::make_pair(qb ? implicit_qb_result::OK : + implicit_qb_result::NOT_FOUND, qb); +} + /** Find existing Opt_hints_qb object, print warning @@ -316,13 +413,37 @@ Opt_hints_qb *find_qb_hints(Parse_context *pc, if (qb_by_name == nullptr) qb_by_number= find_hints_by_select_number(pc, qb_name); + Opt_hints_qb *qb_by_implicit_name= nullptr; + if (qb_by_name == nullptr && qb_by_number == nullptr) + { + std::pair find_res= + find_hints_by_implicit_qb_name(pc, qb_name); + if (find_res.first == implicit_qb_result::AMBIGUOUS) + { + // Warn on ambiguous derived table name + print_warn(pc->thd, ER_WARN_AMBIGUOUS_QB_NAME, + hint_type, hint_state, &qb_name, + nullptr, nullptr, nullptr); + return nullptr; + } + if (find_res.first == implicit_qb_result::UNION) + { + print_warn(pc->thd, ER_WARN_IMPLICIT_QB_NAME_FOR_UNION, + hint_type, hint_state, &qb_name, + nullptr, nullptr, nullptr); + return nullptr; + } + qb_by_implicit_name= find_res.second; + } + // C++-style comment here, otherwise compiler warns of /* within comment. // We don't allow implicit query block names to be specified for hints local // to a view (e.g. CREATE VIEW v1 AS SELECT /*+ NO_ICP(@`select#2` t1) ... // because of select numbering issues. When we're ready to fix that, then we // can remove this gate. + // Implicit QB naming using DT/view aliases is also not supported inside views if (pc->thd->lex->sql_command == SQLCOM_CREATE_VIEW && - qb_by_number) + (qb_by_number || qb_by_implicit_name)) { print_warn(pc->thd, ER_WARN_NO_IMPLICIT_QB_NAMES_IN_VIEW, hint_type, hint_state, &qb_name, @@ -330,7 +451,8 @@ Opt_hints_qb *find_qb_hints(Parse_context *pc, return nullptr; } - Opt_hints_qb *qb= qb_by_name ? qb_by_name : qb_by_number; + Opt_hints_qb *qb= qb_by_name ? qb_by_name : + (qb_by_number ? qb_by_number : qb_by_implicit_name); if (qb == nullptr) print_warn(pc->thd, ER_WARN_UNKNOWN_QB_NAME, hint_type, hint_state, &qb_name, NULL, NULL, NULL); @@ -1656,7 +1778,7 @@ bool is_compound_hint(opt_hints_enum type_arg) /* @brief Perform "Hint Resolution" for Optimizer Hints (see opt_hints.h for - definition) + definition) for both early and late stages. @detail Hints use "Explain select numbering", so this must be called after the @@ -1668,13 +1790,53 @@ bool is_compound_hint(opt_hints_enum type_arg) void LEX::resolve_optimizer_hints() { + resolve_optimizer_hints_for_stage(hint_resolution_stage::EARLY); + resolve_optimizer_hints_for_stage(hint_resolution_stage::LATE); +} + +/* + Perform Hint Resolution for Optimizer Hints in early stage. + + This function processes only those hints that have to be resolved + in the early stage (before opening tables), and skips others. + The function does not clean up the list of SELECT_LEX'es to be resolved, + because resolve_late_optimizer_hints() is expected to be called after. + The stage when a certain hint type should be resolved is specified in + opt_hint_info[]. + + Also see description of resolve_optimizer_hints(). +*/ + +void LEX::resolve_early_optimizer_hints() +{ + resolve_optimizer_hints_for_stage(hint_resolution_stage::EARLY); +} + +/* + Perform Hint Resolution for Optimizer Hints in late stage. + + This function processes only those hints that have to be resolved + in the late stage (after opening tables), and skips others. The function + cleans up the list of SELECT_LEX'es to be resolved after completion. + The stage when a certain hint type should be resolved is specified in + opt_hint_info[]. + + Also see description of resolve_optimizer_hints(). +*/ + +void LEX::resolve_late_optimizer_hints() +{ + resolve_optimizer_hints_for_stage(hint_resolution_stage::LATE); +} + +// Helper function for be called from the three functions above +void LEX::resolve_optimizer_hints_for_stage(hint_resolution_stage stage) +{ + if (selects_for_hint_resolution.is_empty()) + return; + Query_arena *arena, backup; arena= thd->activate_stmt_arena_if_needed(&backup); - SCOPE_EXIT([&] () mutable { - selects_for_hint_resolution.empty(); - if (arena) - thd->restore_active_arena(arena, &backup); - }); List_iterator it(selects_for_hint_resolution); SELECT_LEX *sel; @@ -1682,11 +1844,17 @@ void LEX::resolve_optimizer_hints() { if (!sel->parsed_optimizer_hints) continue; - Parse_context pc(thd, sel); + Parse_context pc(thd, sel, stage); sel->parsed_optimizer_hints->resolve(&pc); } + + if (stage == hint_resolution_stage::LATE) + selects_for_hint_resolution.empty(); // Don't clean up in early stage + if (arena) + thd->restore_active_arena(arena, &backup); } + #ifndef DBUG_OFF static char dbug_print_hint_buf[64]; diff --git a/sql/opt_hints.h b/sql/opt_hints.h index c0973f48ace72..529b299996fbf 100644 --- a/sql/opt_hints.h +++ b/sql/opt_hints.h @@ -113,6 +113,7 @@ #include #include "my_config.h" +#include "opt_hints_structs.h" #include "sql_alloc.h" #include "sql_list.h" #include "mem_root_array.h" @@ -138,6 +139,9 @@ struct st_opt_hint_info bool irregular_hint; // true if hint requires some special handling. // Currently it's used only for join order hints // since they need a special printing procedure. + hint_resolution_stage resolution_stage; // Stage when this hint type has to + // be resolved: early (before opening tables) or late + // (after opening tables). }; typedef Optimizer_hint_parser Parser; diff --git a/sql/opt_hints_parser.cc b/sql/opt_hints_parser.cc index 743c8339f0785..b051e6af1ad13 100644 --- a/sql/opt_hints_parser.cc +++ b/sql/opt_hints_parser.cc @@ -17,6 +17,7 @@ */ #include "opt_hints_parser.h" +#include "mysqld.h" #include "sql_error.h" #include "mysqld_error.h" #include "sql_class.h" @@ -53,12 +54,16 @@ void append_table_name(THD *thd, String *str, const LEX_CSTRING &table_name, static const Lex_ident_sys null_ident_sys; -Parse_context::Parse_context(THD *thd, st_select_lex *select) + +Parse_context::Parse_context(THD *thd, st_select_lex *select, + hint_resolution_stage stage) : thd(thd), mem_root(thd->mem_root), - select(select) + select(select), + resolution_stage(stage) {} + Parse_context::Parse_context(Parse_context *pc, st_select_lex *select) : thd(pc->thd), mem_root(pc->mem_root), @@ -294,6 +299,19 @@ void Parser::push_warning_syntax_error(THD *thd, uint start_lineno) msg, txt.ptr(), start_lineno + lineno()); } +/* + Returns true if the hint should be resolved in the current stage + (early or late) and false otherwise. + Some hints must be resolved in the early stage (before opening tables), + others in the late stage (after opening tables), this is specified in + opt_hint_info[]. +*/ +bool Parser::is_appropriate_resolution_stage(opt_hints_enum hint_type, + Parse_context *pc) +{ + return pc->resolution_stage == opt_hint_info[hint_type].resolution_stage; +} + bool Parser::Table_name_list_container::add(Optimizer_hint_parser *p, @@ -412,6 +430,9 @@ bool Parser::Table_level_hint::resolve(Parse_context *pc) const return true; } + if (!is_appropriate_resolution_stage(hint_type, pc)) + return false; + if (const At_query_block_name_opt_table_name_list & at_query_block_name_opt_table_name_list= *this) { @@ -624,6 +645,9 @@ bool Parser::Index_level_hint::resolve(Parse_context *pc) const return true; } + if (!is_appropriate_resolution_stage(hint_type, pc)) + return false; + const Hint_param_table_ext &table_ext= *this; const Lex_ident_sys qb_name_sys= table_ext.Query_block_name:: to_ident_sys(pc->thd); @@ -775,6 +799,10 @@ Return value: */ bool Parser::Qb_name_hint::resolve(Parse_context *pc) const { + const opt_hints_enum hint_type= QB_NAME_HINT_ENUM; + if (!is_appropriate_resolution_stage(hint_type, pc)) + return false; + Opt_hints_qb *qb= pc->select->opt_hints_qb; DBUG_ASSERT(qb); @@ -784,7 +812,7 @@ bool Parser::Qb_name_hint::resolve(Parse_context *pc) const if (qb->get_name().str || // QB name is already set qb->get_parent()->find_by_name(qb_name_sys)) // Name is already used { - print_warn(pc->thd, ER_WARN_CONFLICTING_HINT, QB_NAME_HINT_ENUM, true, + print_warn(pc->thd, ER_WARN_CONFLICTING_HINT, hint_type, true, &qb_name_sys, nullptr, nullptr, nullptr); return false; } @@ -841,6 +869,9 @@ Return value: */ bool Parser::Semijoin_hint::resolve(Parse_context *pc) const { + if (!is_appropriate_resolution_stage(SEMIJOIN_HINT_ENUM, pc)) + return false; + const Semijoin_hint_type &semijoin_hint_type= *this; bool hint_state; // true - SEMIJOIN(), false - NO_SEMIJOIN() if (semijoin_hint_type.id() == TokenID::keyword_SEMIJOIN) @@ -957,6 +988,9 @@ Return value: */ bool Parser::Subquery_hint::resolve(Parse_context *pc) const { + if (!is_appropriate_resolution_stage(SUBQUERY_HINT_ENUM, pc)) + return false; + Opt_hints_qb *qb; if (const At_query_block_name_subquery_strategy & at_query_block_name_subquery_strategy= *this) @@ -1072,6 +1106,9 @@ void Parser::Subquery_hint::append_args(THD *thd, String *str) const */ bool Parser::Max_execution_time_hint::resolve(Parse_context *pc) const { + if (!is_appropriate_resolution_stage(MAX_EXEC_TIME_HINT_ENUM, pc)) + return false; + const Unsigned_Number& hint_arg= *this; const ULonglong_null time_ms= hint_arg.get_ulonglong(); @@ -1142,6 +1179,9 @@ bool Parser::Join_order_hint::resolve(Parse_context *pc) return true; } + if (!is_appropriate_resolution_stage(hint_type, pc)) + return false; + Opt_hints_qb *qb= nullptr; Lex_ident_sys qb_name; if (const At_query_block_name_opt_table_name_list &at_qb_tab_list= *this) @@ -1283,6 +1323,20 @@ bool Parser::Hint_list::resolve(Parse_context *pc) const if (!get_qb_hints(pc)) return true; + /* + QB_NAME hints are resolved first so following hints can be attached to + the pre-configured query blocks + */ + for (Hint_list::iterator li= this->begin(); li != this->end(); ++li) + { + Parser::Hint &hint= *li; + if (const Qb_name_hint &qb_hint= hint) + { + if (qb_hint.resolve(pc)) + return true; + } + } + for (Hint_list::iterator li= this->begin(); li != this->end(); ++li) { Parser::Hint &hint= *li; @@ -1296,11 +1350,6 @@ bool Parser::Hint_list::resolve(Parse_context *pc) const if (index_hint.resolve(pc)) return true; } - else if (const Qb_name_hint &qb_hint= hint) - { - if (qb_hint.resolve(pc)) - return true; - } else if (const Max_execution_time_hint &max_hint= hint) { if (max_hint.resolve(pc)) @@ -1321,6 +1370,11 @@ bool Parser::Hint_list::resolve(Parse_context *pc) const if (join_order_hint.resolve(pc)) return true; } + else if (const Qb_name_hint &qb_hint __attribute__((unused)) = hint) + { + // QB_NAME hints have been resolved earlier + continue; + } else { DBUG_ASSERT(0); } diff --git a/sql/opt_hints_parser.h b/sql/opt_hints_parser.h index 272982b8ae31d..7d5d56c56fcdc 100644 --- a/sql/opt_hints_parser.h +++ b/sql/opt_hints_parser.h @@ -19,6 +19,7 @@ */ #include "lex_ident_sys.h" +#include "opt_hints_structs.h" #include "simple_tokenizer.h" #include "sql_list.h" #include "sql_string.h" @@ -28,48 +29,16 @@ class st_select_lex; class Opt_hints_qb; -/** - Hint types, MAX_HINT_ENUM should be always last. - This enum should be synchronized with opt_hint_info - array(see opt_hints.cc). -*/ -enum opt_hints_enum -{ - BKA_HINT_ENUM= 0, - BNL_HINT_ENUM, - ICP_HINT_ENUM, - MRR_HINT_ENUM, - NO_RANGE_HINT_ENUM, - QB_NAME_HINT_ENUM, - MAX_EXEC_TIME_HINT_ENUM, - SEMIJOIN_HINT_ENUM, - SUBQUERY_HINT_ENUM, - JOIN_PREFIX_HINT_ENUM, - JOIN_SUFFIX_HINT_ENUM, - JOIN_ORDER_HINT_ENUM, - JOIN_FIXED_ORDER_HINT_ENUM, - DERIVED_CONDITION_PUSHDOWN_HINT_ENUM, - MERGE_HINT_ENUM, - SPLIT_MATERIALIZED_HINT_ENUM, - INDEX_HINT_ENUM, - JOIN_INDEX_HINT_ENUM, - GROUP_INDEX_HINT_ENUM, - ORDER_INDEX_HINT_ENUM, - ROWID_FILTER_HINT_ENUM, - INDEX_MERGE_HINT_ENUM, - MAX_HINT_ENUM // This one must be the last in the list -}; - - /** Environment data for the name resolution phase */ struct Parse_context { - THD * const thd; ///< Current thread handler - MEM_ROOT *mem_root; ///< Current MEM_ROOT - st_select_lex * select; ///< Current SELECT_LEX object + THD * const thd; + MEM_ROOT *mem_root; + st_select_lex * select; + hint_resolution_stage resolution_stage; - Parse_context(THD *thd, st_select_lex *select); + Parse_context(THD *thd, st_select_lex *select, hint_resolution_stage stage); Parse_context(Parse_context *pc, st_select_lex *select); }; @@ -994,6 +963,8 @@ class Optimizer_hint_parser: public Optimizer_hint_tokenizer, bool resolve(Parse_context *pc) const; }; + static bool is_appropriate_resolution_stage(opt_hints_enum hint_type, + Parse_context *pc); public: /* The main rule: diff --git a/sql/opt_hints_structs.h b/sql/opt_hints_structs.h new file mode 100644 index 0000000000000..f4857bf871f96 --- /dev/null +++ b/sql/opt_hints_structs.h @@ -0,0 +1,59 @@ +#ifndef OPT_HINTS_STRUCTS_H +#define OPT_HINTS_STRUCTS_H +/* + Copyright (c) 2024, MariaDB + + This program is free software; you can redistribute it and/or + modify it under the terms of the GNU General Public License + as published by the Free Software Foundation; version 2 of + the License. + + This program is distributed in the hope that it will be useful, + but WITHOUT ANY WARRANTY; without even the implied warranty of + MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + GNU General Public License for more details. + + You should have received a copy of the GNU General Public License + along with this program; if not, write to the Free Software + Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA +*/ + +/** + Hint types, MAX_HINT_ENUM should be always last. + This enum should be synchronized with opt_hint_info + array(see opt_hints.cc). +*/ +enum opt_hints_enum +{ + BKA_HINT_ENUM= 0, + BNL_HINT_ENUM, + ICP_HINT_ENUM, + MRR_HINT_ENUM, + NO_RANGE_HINT_ENUM, + QB_NAME_HINT_ENUM, + MAX_EXEC_TIME_HINT_ENUM, + SEMIJOIN_HINT_ENUM, + SUBQUERY_HINT_ENUM, + JOIN_PREFIX_HINT_ENUM, + JOIN_SUFFIX_HINT_ENUM, + JOIN_ORDER_HINT_ENUM, + JOIN_FIXED_ORDER_HINT_ENUM, + DERIVED_CONDITION_PUSHDOWN_HINT_ENUM, + MERGE_HINT_ENUM, + SPLIT_MATERIALIZED_HINT_ENUM, + INDEX_HINT_ENUM, + JOIN_INDEX_HINT_ENUM, + GROUP_INDEX_HINT_ENUM, + ORDER_INDEX_HINT_ENUM, + ROWID_FILTER_HINT_ENUM, + INDEX_MERGE_HINT_ENUM, + MAX_HINT_ENUM // This one must be the last in the list +}; + +enum class hint_resolution_stage +{ + EARLY, + LATE +}; + +#endif /* OPT_HINTS_STRUCTS_H */ diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index 28cefd3dbf299..c321c12494be4 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -12362,3 +12362,7 @@ ER_WARN_CONFLICTING_COMPOUND_INDEX_HINT_FOR_KEY eng "Hint %s is ignored as conflicting/duplicated (an index hint of the same type or opposite kind has already been specified for the key)" ER_WARN_NO_IMPLICIT_QB_NAMES_IN_VIEW eng "Implicit query block names are ignored for hints specified within VIEWs" +ER_WARN_AMBIGUOUS_QB_NAME + eng "Query block name %s is ambiguous for %s hint" +ER_WARN_IMPLICIT_QB_NAME_FOR_UNION + eng "Implicit query block name %s is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for %s hint" diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 83b3c5ae43c8f..f91dc73ce871d 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -40,6 +40,7 @@ #include "table.h" #include "sql_class.h" // enum enum_column_usage #include "select_handler.h" +#include "opt_hints_structs.h" /* Used for flags of nesting constructs */ #define SELECT_NESTING_MAP_SIZE 64 @@ -3803,6 +3804,8 @@ struct LEX: public Query_tables_list void handle_parsed_optimizer_hints_in_last_select(); void resolve_optimizer_hints(); + void resolve_early_optimizer_hints(); + void resolve_late_optimizer_hints(); bool discard_optimizer_hints_in_last_select(); SELECT_LEX *current_select_or_default() @@ -4993,6 +4996,9 @@ struct LEX: public Query_tables_list create_info.set(options); return main_select_push() || check_create_options(options); } + + void resolve_optimizer_hints_for_stage(hint_resolution_stage stage); + public: bool stmt_create_function_start(const DDL_options_st &options) { diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 81ab65e8f2f88..7b52fa73ad79d 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -3503,7 +3503,6 @@ mysql_execute_command(THD *thd, bool is_called_from_prepared_stmt) */ lex->first_lists_tables_same(); lex->fix_first_select_number(); - lex->resolve_optimizer_hints(); /* should be assigned after making first tables same */ all_tables= lex->query_tables; /* set context for commands which do not use setup_tables */ @@ -4627,6 +4626,7 @@ mysql_execute_command(THD *thd, bool is_called_from_prepared_stmt) select_lex->table_list.first= second_table; select_lex->context.table_list= select_lex->context.first_name_resolution_table= second_table; + lex->resolve_optimizer_hints(); res= mysql_insert_select_prepare(thd, result); Write_record write; if (!res && @@ -6089,8 +6089,10 @@ static bool execute_sqlcom_select(THD *thd, TABLE_LIST *all_tables) (ulonglong) thd->variables.select_limit); } + lex->resolve_early_optimizer_hints(); if (!(res= open_and_lock_tables(thd, all_tables, TRUE, 0))) { + lex->resolve_late_optimizer_hints(); if (lex->describe) { /* diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index 3b87c189017f1..93293a1287d56 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1479,10 +1479,12 @@ static int mysql_test_select(Prepared_statement *stmt, goto error; } + lex->resolve_early_optimizer_hints(); if (open_normal_and_derived_tables(thd, tables, MYSQL_OPEN_FORCE_SHARED_MDL, DT_INIT | DT_PREPARE)) goto error; + lex->resolve_late_optimizer_hints(); thd->lex->used_tables= 0; // Updated by setup_fields /* @@ -2219,7 +2221,6 @@ static bool check_prepared_statement(Prepared_statement *stmt) lex->first_lists_tables_same(); lex->fix_first_select_number(); - lex->resolve_optimizer_hints(); tables= lex->query_tables; /* set context for commands which do not use setup_tables */ diff --git a/sql/sql_select.cc b/sql/sql_select.cc index d5152d5b51566..a5f148201d580 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -34652,7 +34652,7 @@ bool Sql_cmd_dml::prepare(THD *thd) MYSQL_DML_START(thd); lex->context_analysis_only|= CONTEXT_ANALYSIS_ONLY_DERIVED; - + lex->resolve_optimizer_hints(); if (open_tables_for_query(thd, lex->query_tables, &table_count, 0, get_dml_prelocking_strategy())) { diff --git a/sql/sql_show.cc b/sql/sql_show.cc index 18d7ad8215afc..ca30a426cbc37 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -1375,6 +1375,7 @@ mysqld_show_create(THD *thd, TABLE_LIST *table_list) if (mysqld_show_create_get_fields(thd, table_list, &field_list, &buffer)) goto exit; + thd->lex->resolve_optimizer_hints(); if (protocol->send_result_set_metadata(&field_list, Protocol::SEND_NUM_ROWS | Protocol::SEND_EOF)) diff --git a/sql/sql_view.cc b/sql/sql_view.cc index 4ae53c2be50e0..2dbdb475ec977 100644 --- a/sql/sql_view.cc +++ b/sql/sql_view.cc @@ -559,6 +559,7 @@ bool mysql_create_view(THD *thd, TABLE_LIST *views, /* prepare select to resolve all fields */ lex->context_analysis_only|= CONTEXT_ANALYSIS_ONLY_VIEW; + lex->resolve_optimizer_hints(); if (unit->prepare(unit->derived, 0, 0)) { /* @@ -568,7 +569,6 @@ bool mysql_create_view(THD *thd, TABLE_LIST *views, res= TRUE; goto err; } - /* view list (list of view fields names) */ if (lex->view_list.elements) { From a6ceac59b4ecb45c24dfa95d3a9ec8a0151030f6 Mon Sep 17 00:00:00 2001 From: Oleg Smirnov Date: Tue, 2 Dec 2025 17:04:45 +0700 Subject: [PATCH 2/2] MDEV-38045: Implement QB_NAME hint with path syntax for nested query blocks Extended QB_NAME hint to support path-based addressing of query blocks nested within views, derived tables, and CTEs, following TiDB's syntax. New syntax: QB_NAME(name, query_block_path), where query_block_path ::= query_block_path_element [ {, query_block_path_element }... ] query_block_path_element ::= @ qb_path_element_select_num | qb_path_element_view_sel qb_path_element_view_sel ::= qb_path_element_view_name [ @ qb_path_element_select_num ] For example, `SELECT /*+ qb_name(qb_v1, v1) */* FROM v1` The name `qb_v1` is assigned to the inner query block of the view `v1`. `SELECT /*+ qb_name(qb_v1, v1@sel_1) */* FROM v1` Means the same but specifies that `v1` is present in SELECT#1 of the current query block. `SELECT /*+ qb_name(qb_v1, v1@sel_1 .@sel_2) */* FROM v1` This means SELECT#2 of view `v1`, which is present in SELECT#1 of the current query block, gets the name `qb_v1`. It is possible to specify not only view names but also derived tables and CTE's in the path. Views and derived tables may be nested on multiple levels, for example: `SELECT /*+ qb_name(dt2_dt1_v1_1, dt1 .dt2 .v2 .@SEL_2) no_index(t1@dt2_dt1_v1_1)*/ v1.* FROM v1 JOIN (SELECT v1.* FROM v1 JOIN (SELECT * FROM v2) dt2) dt1` --- mysql-test/main/opt_hints_impl_qb_name.inc | 2 +- mysql-test/main/opt_hints_impl_qb_name.result | 6 +- mysql-test/main/opt_hints_qb_name_path.inc | 244 +++++ mysql-test/main/opt_hints_qb_name_path.result | 965 ++++++++++++++++++ mysql-test/main/opt_hints_qb_name_path.test | 35 + sql/opt_hints.cc | 9 +- sql/opt_hints_parser.cc | 247 ++++- sql/opt_hints_parser.h | 115 ++- sql/opt_hints_structs.h | 7 +- sql/share/errmsg-utf8.txt | 2 + 10 files changed, 1609 insertions(+), 23 deletions(-) create mode 100644 mysql-test/main/opt_hints_qb_name_path.inc create mode 100644 mysql-test/main/opt_hints_qb_name_path.result create mode 100644 mysql-test/main/opt_hints_qb_name_path.test diff --git a/mysql-test/main/opt_hints_impl_qb_name.inc b/mysql-test/main/opt_hints_impl_qb_name.inc index f6269e908f824..2b033d77ec8bf 100644 --- a/mysql-test/main/opt_hints_impl_qb_name.inc +++ b/mysql-test/main/opt_hints_impl_qb_name.inc @@ -9,7 +9,7 @@ explain extended select /*+ no_bnl(@dt)*/ * from --echo # Index-level hints --echo # Without the hint 'range' index access would be chosen explain extended select /*+ no_index(t1@`T`)*/ * from - (select * from t1 where a < 3) T; + (select * from t1 where a < 3) t; --echo # Without the hint 'range' index access would be chosen explain extended select /*+ no_range_optimization(t1@t1)*/ * from diff --git a/mysql-test/main/opt_hints_impl_qb_name.result b/mysql-test/main/opt_hints_impl_qb_name.result index 7198578586b5b..2028a23e61951 100644 --- a/mysql-test/main/opt_hints_impl_qb_name.result +++ b/mysql-test/main/opt_hints_impl_qb_name.result @@ -29,7 +29,7 @@ Note 1003 select /*+ NO_BNL(@`select#2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.` # Index-level hints # Without the hint 'range' index access would be chosen explain extended select /*+ no_index(t1@`T`)*/ * from -(select * from t1 where a < 3) T; +(select * from t1 where a < 3) t; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 100 2.00 Using where Warnings: @@ -357,12 +357,12 @@ Note 1003 /* select#1 */ select /*+ NO_BNL(@`select#2`) */ `dt`.`a` AS `a`,`dt`. # Index-level hints # Without the hint 'range' index access would be chosen explain extended select /*+ no_index(t1@`T`)*/ * from -(select * from t1 where a < 3) T; +(select * from t1 where a < 3) t; id select_type table type possible_keys key key_len ref rows filtered Extra 1 PRIMARY ALL NULL NULL NULL NULL 2 100.00 2 DERIVED t1 ALL NULL NULL NULL NULL 100 2.00 Using where Warnings: -Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `T`.`a` AS `a`,`T`.`b` AS `b`,`T`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `T` +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`select#2`) */ `t`.`a` AS `a`,`t`.`b` AS `b`,`t`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 3) `t` # Without the hint 'range' index access would be chosen explain extended select /*+ no_range_optimization(t1@t1)*/ * from (select * from t1 where a > 100 and a < 120) as t1; diff --git a/mysql-test/main/opt_hints_qb_name_path.inc b/mysql-test/main/opt_hints_qb_name_path.inc new file mode 100644 index 0000000000000..7ba948e8f7958 --- /dev/null +++ b/mysql-test/main/opt_hints_qb_name_path.inc @@ -0,0 +1,244 @@ +--echo # ====================================== +--echo # Views +--echo # +--echo # select /* The name of the current query block is @SEL_1 */ * from v1; +--echo # +--echo # Addressing a view having one query block. +--echo # QB_NAME(qb_v1, v1) means: inner query block of the view `v1`, +--echo # which is present in the same query block as the hint, gets the name `qb_v1`. +--echo # This name can be used in other hints. +explain extended + select /*+ qb_name(qb_v1, v1) no_index(t1@qb_v1)*/* from v1; + +--echo # Equivalent to the above but specifying @SEL_1 explicitly. +--echo # QB_NAME(qb_v1, v1@sel_1) means: inner query block of view `v1`, +--echo # which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended + select /*+ qb_name(qb_v1, v1@sel_1) no_index(t1@qb_v1 idx_a)*/* from v1; + +--echo # Equivalent to the above but also specifying @SEL_1 of the view. +--echo # QB_NAME(qb_v1, v1@sel_1 .@sel_1) means: SELECT#1 of view `v1`, +--echo # which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended + select /*+ qb_name(qb_v1, v1@sel_1 .@sel_1) no_index(t1@qb_v1 idx_ab)*/* from v1; + +--echo # +--echo # The case when a particular view is used in more than one query block. +--echo # select /* Name of current query block is @SEL_1 */ * from v1 +--echo # join +--echo # (select /* Name of current query block is @SEL_2 */ * from v1) vvv1; +--echo # The first query block of view v1 can be declared as +--echo # QB_NAME(v1_1, v1@SEL_1 .@SEL_1), +--echo # and the second query block of the view v1 can be declared as +--echo # QB_NAME(v1_2, v1@SEL_1 .@SEL_2). +--echo # +--echo # By default, range access is used for both `t1`'s in the statement below. +explain extended + select * from v1 join (select * from v1) vvv1; + +--echo # Disable index access for t1 from the second occurence of view v1: +explain extended + select /*+ qb_name(v1_2, v1@SEL_2 .@SEL_1) no_index(t1@v1_2)*/ * + from v1 join (select * from v1) vvv1; + +--echo # Disable index access for t1 from both occurences of view v1: +explain extended + select /*+ qb_name(v1_1, v1@SEL_1) qb_name(v1_2, v1@SEL_2 .@SEL_1) + no_index(t1@v1_1) no_index(t1@v1_2)*/ * + from v1 join (select * from v1) vvv1; + +--echo # +--echo # The case when a particular view has more than one query block. +--echo # create view v2 as +--echo # select * from t1 join /* Name of this query block is @SEL_1 */ +--echo # ( +--echo # select count(*) from t1 join v1 /* Name of this query block is @SEL_2 */ +--echo # ) tt; +--echo # The first query block of view v2 can be declared as +--echo # QB_NAME(v2_1, v2@SEL_1 .@SEL_1), and the second query block can be +--echo # declared as QB_NAME(v2_2, v2@SEL_1 .@SEL_2). +--echo # +--echo # See the default execution plan: +explain extended select * from v2; + +--echo # Disable index access for t1 from the second query block of view v2: +explain extended + select /*+ qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2)*/* from v2; + +--echo # Disable index access for `t1` from view `v1` used in +--echo # the first query block of view `v2`: +explain extended + select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1)*/* from v2; + +--echo # Equivalent to the above but specifying @SEL_1 explicitly: +explain extended + select /*+ qb_name(v2_v1_sel1, v2@SEL_1 .v1@SEL_2 .@SEL_1) + no_index(t1@v2_v1_sel1)*/ * from v2; + +--echo # Disable index access for `t1` tables from views `v1` and `v2` +explain extended + select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1) + qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2) */ * from v2; + +--echo # ====================================== +--echo # Views with UNION +--echo # +--echo # Default execution plan: +explain extended select * from v3; + +--echo # `v3` in QB path corresponds to @SEL_1: +explain extended select /*+ qb_name(qb_v3, v3) no_index(t1@qb_v3)*/* from v3; + +--echo # Addressing @SEL_1 of `v3` explicitly: +explain extended + select /*+ qb_name(qb_v3_sel1, v3.@sel_1) no_index(t1@qb_v3_sel1)*/* from v3; + +--echo # Addressing @SEL_2 of `v3` explicitly: +explain extended + select /*+ qb_name(qb_v3_sel2, v3.@sel_2) no_index(t1@qb_v3_sel2)*/* from v3; + + +--echo # ====================================== +--echo # Derived tables +--echo # +--echo # QB_NAME(qb_dt, dt) means: inner query block of derived table `dt`, +--echo # which is present in the same query block as the hint, gets the name `qb_dt`. +--echo # This name can be used in other hints. +explain extended select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from + (select * from t1 where a < 10) dt; + +--echo # QB_NAME(qb_dt, dt@sel_1) means: inner query block of derived table `dt`, +--echo # which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1) no_index(t1@qb_dt)*/* from + (select * from t1 where a < 10) dt; + +--echo # QB_NAME(qb_dt, dt@sel_1 .@sel_1) means: SELECT#1 of derived table `dt`, +--echo # which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1 .@sel_1) no_index(t1@qb_dt)*/* from + (select * from t1 where a < 10) dt; + +--echo # ====================================== +--echo # Derived tables with UNION +--echo # +--echo # Default execution plan: +explain extended +select * from (select * from t1 where a < 10 union select * from t1 where a > 90) dt; + +--echo # `dt` in QB path corresponds to @SEL_1: +explain extended +select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from + (select * from t1 where a < 10 union select * from t1 where a > 90) dt; + +--echo # Addressing @SEL_1 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel1, dt.@sel_1) no_index(t1@qb_dt_sel1)*/* from + (select * from t1 where a < 10 union select * from t1 where a > 90) dt; + +--echo # Addressing @SEL_2 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel2, dt.@sel_2) no_index(t1@qb_dt_sel2)*/* from + (select * from t1 where a < 10 union select * from t1 where a > 90) dt; + +--echo # ====================================== +--echo # Mix of views and derived tables +--echo # +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ * + from v1 join (select * from v1) dt1; + +--echo # More complicated query. Default execution plan: +explain extended +select v1.* from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; + +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ v1.* + from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; + +explain extended +select /*+ qb_name(dt2_dt1_v1_1, dt1 .dt2 .v2 .@SEL_2) + no_index(t1@dt2_dt1_v1_1)*/ v1.* + from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; + +--echo # ====================================== +--echo # CTEs +--echo # +--echo # Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; + +--echo # Disable index access for t1 in CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte; + +--echo # Disable index access for t1 in dt1 of CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; + +--echo # Disable index access for both t1's +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte) + qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; + +--echo # Multiple references to a CTE in a query. +--echo # Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte join cte cte1; + +--echo # Disable index access for t1 in `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte join cte as cte1; + +--echo # Disable index access for t1 in `cte1` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte1, cte1) no_index(t1@qb_cte1)*/ * from cte join cte as cte1; + + +--echo # ====================================== +--echo # Wrong paths generate warnings +--echo # +--disable_ps_protocol +# PS protocol is disabled because the warning is genererated only during +# PREPARE step of a statement. When the QB name cannot be resolved the hint +# is discarded, so it is not present during EXECUTE step. + +explain extended + select /*+ qb_name(`qb_v1`, `v2`)*/* from v1; + +--echo # Wrong select number: +explain extended + select /*+ qb_name(qb_v1, `v2`@`sel_2`)*/* from v1; + +explain extended + select /*+ qb_name(qb_v1, v2@sel_1 .@sel_2)*/* from v1; + +--echo # Attempting to reference a regular table as a query block: +explain extended + select /*+ qb_name(qb_v1, dt .t1)*/* from (select t1.* from t1 join v1) dt; + +--echo # Wrong view name inside a derived table: +explain extended + select /*+ qb_name(qb_v1, dt .v2)*/* from (select t1.* from t1 join v1) dt; + +--echo # Wrong select number: +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_2)*/* from (select t1.* from t1 join v1) dt; + +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_1 .@sel_2)*/* from + (select t1.* from t1 join v1) dt; + +--echo # Wrong select number syntax: +explain extended + select /*+ qb_name(qb_v1, `v1`@`lex_2`)*/* from v1; + +explain extended + select /*+ qb_name(qb_v1, v1 .lex_2)*/* from v1; + +--enable_ps_protocol \ No newline at end of file diff --git a/mysql-test/main/opt_hints_qb_name_path.result b/mysql-test/main/opt_hints_qb_name_path.result new file mode 100644 index 0000000000000..7e18a63d3c888 --- /dev/null +++ b/mysql-test/main/opt_hints_qb_name_path.result @@ -0,0 +1,965 @@ +create table t1 (a int, b int, c char(20), key idx_a(a), key idx_ab(a, b)); +insert into t1 select seq, seq, 'filler' from seq_1_to_100; +create table t2 as select * from t1; +analyze table t1,t2 persistent for all; +Table Op Msg_type Msg_text +test.t1 analyze status Engine-independent statistics collected +test.t1 analyze status Table is already up to date +test.t2 analyze status Engine-independent statistics collected +test.t2 analyze status OK +create view v1 as select * from t1 where a < 10; +create view v2 as +select * from t1 join /* Name of this query block is @SEL_1 */ +( +select count(*) from t1 join v1 /* Name of this query block is @SEL_2 */ +) tt; +create view v3 as +select * from t1 where a < 10 union select * from t1 where a > 90; + +================================================================ +set optimizer_switch= 'derived_merge=on'; +# ====================================== +# Views +# +# select /* The name of the current query block is @SEL_1 */ * from v1; +# +# Addressing a view having one query block. +# QB_NAME(qb_v1, v1) means: inner query block of the view `v1`, +# which is present in the same query block as the hint, gets the name `qb_v1`. +# This name can be used in other hints. +explain extended +select /*+ qb_name(qb_v1, v1) no_index(t1@qb_v1)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Equivalent to the above but specifying @SEL_1 explicitly. +# QB_NAME(qb_v1, v1@sel_1) means: inner query block of view `v1`, +# which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended +select /*+ qb_name(qb_v1, v1@sel_1) no_index(t1@qb_v1 idx_a)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 7 100.00 Using index condition +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1` `idx_a`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Equivalent to the above but also specifying @SEL_1 of the view. +# QB_NAME(qb_v1, v1@sel_1 .@sel_1) means: SELECT#1 of view `v1`, +# which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended +select /*+ qb_name(qb_v1, v1@sel_1 .@sel_1) no_index(t1@qb_v1 idx_ab)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# +# The case when a particular view is used in more than one query block. +# select /* Name of current query block is @SEL_1 */ * from v1 +# join +# (select /* Name of current query block is @SEL_2 */ * from v1) vvv1; +# The first query block of view v1 can be declared as +# QB_NAME(v1_1, v1@SEL_1 .@SEL_1), +# and the second query block of the view v1 can be declared as +# QB_NAME(v1_2, v1@SEL_1 .@SEL_2). +# +# By default, range access is used for both `t1`'s in the statement below. +explain extended +select * from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition; Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +# Disable index access for t1 from the second occurence of view v1: +explain extended +select /*+ qb_name(v1_2, v1@SEL_2 .@SEL_1) no_index(t1@v1_2)*/ * +from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`v1_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +# Disable index access for t1 from both occurences of view v1: +explain extended +select /*+ qb_name(v1_1, v1@SEL_1) qb_name(v1_2, v1@SEL_2 .@SEL_1) +no_index(t1@v1_1) no_index(t1@v1_2)*/ * +from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`v1_1`) NO_INDEX(`t1`@`v1_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +# +# The case when a particular view has more than one query block. +# create view v2 as +# select * from t1 join /* Name of this query block is @SEL_1 */ +# ( +# select count(*) from t1 join v1 /* Name of this query block is @SEL_2 */ +# ) tt; +# The first query block of view v2 can be declared as +# QB_NAME(v2_1, v2@SEL_1 .@SEL_1), and the second query block can be +# declared as QB_NAME(v2_2, v2@SEL_1 .@SEL_2). +# +# See the default execution plan: +explain extended select * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for t1 from the second query block of view v2: +explain extended +select /*+ qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2)*/* from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`v2_2`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for `t1` from view `v1` used in +# the first query block of view `v2`: +explain extended +select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1)*/* from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Equivalent to the above but specifying @SEL_1 explicitly: +explain extended +select /*+ qb_name(v2_v1_sel1, v2@SEL_1 .v1@SEL_2 .@SEL_1) +no_index(t1@v2_v1_sel1)*/ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1_sel1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for `t1` tables from views `v1` and `v2` +explain extended +select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1) +qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2) */ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1`) NO_INDEX(`t1`@`v2_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`v2_2`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# ====================================== +# Views with UNION +# +# Default execution plan: +explain extended select * from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 19 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# `v3` in QB path corresponds to @SEL_1: +explain extended select /*+ qb_name(qb_v3, v3) no_index(t1@qb_v3)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Addressing @SEL_1 of `v3` explicitly: +explain extended +select /*+ qb_name(qb_v3_sel1, v3.@sel_1) no_index(t1@qb_v3_sel1)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3_sel1`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Addressing @SEL_2 of `v3` explicitly: +explain extended +select /*+ qb_name(qb_v3_sel2, v3.@sel_2) no_index(t1@qb_v3_sel2)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 14 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 ALL NULL NULL NULL NULL 100 10.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3_sel2`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# ====================================== +# Derived tables +# +# QB_NAME(qb_dt, dt) means: inner query block of derived table `dt`, +# which is present in the same query block as the hint, gets the name `qb_dt`. +# This name can be used in other hints. +explain extended select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# QB_NAME(qb_dt, dt@sel_1) means: inner query block of derived table `dt`, +# which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# QB_NAME(qb_dt, dt@sel_1 .@sel_1) means: SELECT#1 of derived table `dt`, +# which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1 .@sel_1) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# ====================================== +# Derived tables with UNION +# +# Default execution plan: +explain extended +select * from (select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 19 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# `dt` in QB path corresponds to @SEL_1: +explain extended +select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# Addressing @SEL_1 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel1, dt.@sel_1) no_index(t1@qb_dt_sel1)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt_sel1`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt_sel1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# Addressing @SEL_2 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel2, dt.@sel_2) no_index(t1@qb_dt_sel2)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 14 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 ALL NULL NULL NULL NULL 100 10.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt_sel2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select /*+ QB_NAME(`qb_dt_sel2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# ====================================== +# Mix of views and derived tables +# +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ * +from v1 join (select * from v1) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where; Using join buffer (flat, BNL join) +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +# More complicated query. Default execution plan: +explain extended +select v1.* from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index; Using join buffer (flat, BNL join) +1 PRIMARY t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (incremental, BNL join) +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (incremental, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` join `test`.`t1` join (/* select#7 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ v1.* +from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 9.00 Using where; Using join buffer (flat, BNL join) +1 PRIMARY t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (incremental, BNL join) +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (incremental, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` join `test`.`t1` join (/* select#7 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(dt2_dt1_v1_1, dt1 .dt2 .v2 .@SEL_2) +no_index(t1@dt2_dt1_v1_1)*/ v1.* +from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index; Using join buffer (flat, BNL join) +1 PRIMARY t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (incremental, BNL join) +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (incremental, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt2_dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` join `test`.`t1` join (/* select#7 */ select /*+ QB_NAME(`dt2_dt1_v1_1`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` where `test`.`t1`.`a` < 10 and `test`.`t1`.`a` < 10 +# ====================================== +# CTEs +# +# Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for t1 in CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for t1 in dt1 of CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte_dt1`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for both t1's +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte) +qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) NO_INDEX(`t1`@`qb_cte_dt1`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Multiple references to a CTE in a query. +# Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte join cte cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +4 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# Disable index access for t1 in `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte join cte as cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +4 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) */ `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# Disable index access for t1 in `cte1` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte1, cte1) no_index(t1@qb_cte1)*/ * from cte join cte as cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +4 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using where; Using index +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 5)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte1`) */ `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# ====================================== +# Wrong paths generate warnings +# +explain extended +select /*+ qb_name(`qb_v1`, `v2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Wrong select number: +explain extended +select /*+ qb_name(qb_v1, `v2`@`sel_2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(qb_v1, v2@sel_1 .@sel_2)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`@`sel_1` .@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Attempting to reference a regular table as a query block: +explain extended +select /*+ qb_name(qb_v1, dt .t1)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`t1`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 +# Wrong view name inside a derived table: +explain extended +select /*+ qb_name(qb_v1, dt .v2)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 +# Wrong select number: +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_2)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v1`@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_1 .@sel_2)*/* from +(select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v1`@`sel_1` .@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10 +# Wrong select number syntax: +explain extended +select /*+ qb_name(qb_v1, `v1`@`lex_2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v1`@`lex_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(qb_v1, v1 .lex_2)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v1` .`lex_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 + +================================================================ +set optimizer_switch= 'derived_merge=off'; +# ====================================== +# Views +# +# select /* The name of the current query block is @SEL_1 */ * from v1; +# +# Addressing a view having one query block. +# QB_NAME(qb_v1, v1) means: inner query block of the view `v1`, +# which is present in the same query block as the hint, gets the name `qb_v1`. +# This name can be used in other hints. +explain extended +select /*+ qb_name(qb_v1, v1) no_index(t1@qb_v1)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Equivalent to the above but specifying @SEL_1 explicitly. +# QB_NAME(qb_v1, v1@sel_1) means: inner query block of view `v1`, +# which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended +select /*+ qb_name(qb_v1, v1@sel_1) no_index(t1@qb_v1 idx_a)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_ab idx_ab 5 NULL 7 100.00 Using index condition +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1` `idx_a`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Equivalent to the above but also specifying @SEL_1 of the view. +# QB_NAME(qb_v1, v1@sel_1 .@sel_1) means: SELECT#1 of view `v1`, +# which is present in SELECT#1 of the current query block, gets the name `qb_v1`. +explain extended +select /*+ qb_name(qb_v1, v1@sel_1 .@sel_1) no_index(t1@qb_v1 idx_ab)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Note 1003 select /*+ NO_INDEX(`t1`@`qb_v1` `idx_ab`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# +# The case when a particular view is used in more than one query block. +# select /* Name of current query block is @SEL_1 */ * from v1 +# join +# (select /* Name of current query block is @SEL_2 */ * from v1) vvv1; +# The first query block of view v1 can be declared as +# QB_NAME(v1_1, v1@SEL_1 .@SEL_1), +# and the second query block of the view v1 can be declared as +# QB_NAME(v1_2, v1@SEL_1 .@SEL_2). +# +# By default, range access is used for both `t1`'s in the statement below. +explain extended +select * from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 5 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`vvv1`.`a` AS `a`,`vvv1`.`b` AS `b`,`vvv1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `vvv1` where `test`.`t1`.`a` < 10 +# Disable index access for t1 from the second occurence of view v1: +explain extended +select /*+ qb_name(v1_2, v1@SEL_2 .@SEL_1) no_index(t1@v1_2)*/ * +from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v1_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`vvv1`.`a` AS `a`,`vvv1`.`b` AS `b`,`vvv1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `vvv1` where `test`.`t1`.`a` < 10 +# Disable index access for t1 from both occurences of view v1: +explain extended +select /*+ qb_name(v1_1, v1@SEL_1) qb_name(v1_2, v1@SEL_2 .@SEL_1) +no_index(t1@v1_1) no_index(t1@v1_2)*/ * +from v1 join (select * from v1) vvv1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 9.00 Using where +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v1_1`) NO_INDEX(`t1`@`v1_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`vvv1`.`a` AS `a`,`vvv1`.`b` AS `b`,`vvv1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `vvv1` where `test`.`t1`.`a` < 10 +# +# The case when a particular view has more than one query block. +# create view v2 as +# select * from t1 join /* Name of this query block is @SEL_1 */ +# ( +# select count(*) from t1 join v1 /* Name of this query block is @SEL_2 */ +# ) tt; +# The first query block of view v2 can be declared as +# QB_NAME(v2_1, v2@SEL_1 .@SEL_1), and the second query block can be +# declared as QB_NAME(v2_2, v2@SEL_1 .@SEL_2). +# +# See the default execution plan: +explain extended select * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for t1 from the second query block of view v2: +explain extended +select /*+ qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2)*/* from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`v2_2`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for `t1` from view `v1` used in +# the first query block of view `v2`: +explain extended +select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1)*/* from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Equivalent to the above but specifying @SEL_1 explicitly: +explain extended +select /*+ qb_name(v2_v1_sel1, v2@SEL_1 .v1@SEL_2 .@SEL_1) +no_index(t1@v2_v1_sel1)*/ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1_sel1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# Disable index access for `t1` tables from views `v1` and `v2` +explain extended +select /*+ qb_name(v2_v1, v2@SEL_1 .v1@SEL_2) no_index(t1@v2_v1) +qb_name(v2_2, v2@SEL_1 .@SEL_2) no_index(t1@v2_2) */ * from v2; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 100 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 900 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`v2_v1`) NO_INDEX(`t1`@`v2_2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`v2_2`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt` +# ====================================== +# Views with UNION +# +# Default execution plan: +explain extended select * from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 19 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# `v3` in QB path corresponds to @SEL_1: +explain extended select /*+ qb_name(qb_v3, v3) no_index(t1@qb_v3)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Addressing @SEL_1 of `v3` explicitly: +explain extended +select /*+ qb_name(qb_v3_sel1, v3.@sel_1) no_index(t1@qb_v3_sel1)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3_sel1`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# Addressing @SEL_2 of `v3` explicitly: +explain extended +select /*+ qb_name(qb_v3_sel2, v3.@sel_2) no_index(t1@qb_v3_sel2)*/* from v3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 14 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 ALL NULL NULL NULL NULL 100 10.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_v3_sel2`) */ `v3`.`a` AS `a`,`v3`.`b` AS `b`,`v3`.`c` AS `c` from `test`.`v3` +# ====================================== +# Derived tables +# +# QB_NAME(qb_dt, dt) means: inner query block of derived table `dt`, +# which is present in the same query block as the hint, gets the name `qb_dt`. +# This name can be used in other hints. +explain extended select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# QB_NAME(qb_dt, dt@sel_1) means: inner query block of derived table `dt`, +# which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# QB_NAME(qb_dt, dt@sel_1 .@sel_1) means: SELECT#1 of derived table `dt`, +# which is present in SELECT#1 of the current query block, gets the name `qb_dt`. +explain extended select /*+ qb_name(qb_dt, dt@sel_1 .@sel_1) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# ====================================== +# Derived tables with UNION +# +# Default execution plan: +explain extended +select * from (select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 19 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# `dt` in QB path corresponds to @SEL_1: +explain extended +select /*+ qb_name(qb_dt, dt) no_index(t1@qb_dt)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# Addressing @SEL_1 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel1, dt.@sel_1) no_index(t1@qb_dt_sel1)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 23 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +3 UNION t1 range idx_a,idx_ab idx_ab 5 NULL 14 100.00 Using index condition +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt_sel1`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select /*+ QB_NAME(`qb_dt_sel1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# Addressing @SEL_2 of `dt` explicitly: +explain extended +select /*+ qb_name(qb_dt_sel2, dt.@sel_2) no_index(t1@qb_dt_sel2)*/* from +(select * from t1 where a < 10 union select * from t1 where a > 90) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 14 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +3 UNION t1 ALL NULL NULL NULL NULL 100 10.00 Using where +NULL UNION RESULT ALL NULL NULL NULL NULL NULL NULL +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`qb_dt_sel2`) */ `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 union /* select#3 */ select /*+ QB_NAME(`qb_dt_sel2`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` > 90) `dt` +# ====================================== +# Mix of views and derived tables +# +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ * +from v1 join (select * from v1) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 9 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`dt1`.`a` AS `a`,`dt1`.`b` AS `b`,`dt1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10) `dt1` where `test`.`t1`.`a` < 10 +# More complicated query. Default execution plan: +explain extended +select v1.* from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 250000 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +2 DERIVED ALL NULL NULL NULL NULL 50000 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 +3 DERIVED ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#7 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt`) `dt2` where `test`.`t1`.`a` < 10) `dt1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(dt1_v1_1, dt1 .v1 .@SEL_1) no_index(t1@dt1_v1_1)*/ v1.* +from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 450000 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 ALL NULL NULL NULL NULL 100 9.00 Using where +2 DERIVED ALL NULL NULL NULL NULL 50000 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 +3 DERIVED ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#7 */ select count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt`) `dt2` where `test`.`t1`.`a` < 10) `dt1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(dt2_dt1_v1_1, dt1 .dt2 .v2 .@SEL_2) +no_index(t1@dt2_dt1_v1_1)*/ v1.* +from v1 join (select v1.* from v1 join (select * from v2) dt2) dt1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +1 PRIMARY ALL NULL NULL NULL NULL 250000 100.00 Using join buffer (flat, BNL join) +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +2 DERIVED ALL NULL NULL NULL NULL 50000 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 +3 DERIVED ALL NULL NULL NULL NULL 500 100.00 Using join buffer (flat, BNL join) +7 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +7 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Note 1003 /* select#1 */ select /*+ NO_INDEX(`t1`@`dt2_dt1_v1_1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`tt`.`count(*)` AS `count(*)` from `test`.`t1` join (/* select#7 */ select /*+ QB_NAME(`dt2_dt1_v1_1`) */ count(0) AS `count(*)` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `tt`) `dt2` where `test`.`t1`.`a` < 10) `dt1` where `test`.`t1`.`a` < 10 +# ====================================== +# CTEs +# +# Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for t1 in CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for t1 in dt1 of CTE +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED ALL NULL NULL NULL NULL 4 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`qb_cte_dt1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte_dt1`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Disable index access for both t1's +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte) +qb_name(qb_cte_dt1, cte .dt1) no_index(t1@qb_cte_dt1)*/ * from cte; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 400 100.00 +2 DERIVED ALL NULL NULL NULL NULL 4 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 ALL NULL NULL NULL NULL 100 4.00 Using where +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select /*+ QB_NAME(`qb_cte_dt1`) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) NO_INDEX(`t1`@`qb_cte_dt1`) */ `cte`.`count(*)` AS `count(*)` from `cte` +# Multiple references to a CTE in a query. +# Default execution plan: +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select * from cte join cte cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +5 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# Disable index access for t1 in `cte` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte, cte) no_index(t1@qb_cte)*/ * from cte join cte as cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +5 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select /*+ QB_NAME(`qb_cte`) */ count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte`) */ `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# Disable index access for t1 in `cte1` +explain extended +with cte as (select count(*) from t1, (select * from t1 where a < 5) dt1) +select /*+ qb_name(qb_cte1, cte1) no_index(t1@qb_cte1)*/ * from cte join cte as cte1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 +1 PRIMARY ALL NULL NULL NULL NULL 200 100.00 Using join buffer (flat, BNL join) +4 DERIVED ALL NULL NULL NULL NULL 2 100.00 +4 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +5 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +2 DERIVED ALL NULL NULL NULL NULL 2 100.00 +2 DERIVED t1 index NULL idx_a 5 NULL 100 100.00 Using index; Using join buffer (flat, BNL join) +3 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 2 100.00 Using index condition +Warnings: +Note 1003 with cte as (/* select#2 */ select count(0) AS `count(*)` from `test`.`t1` join (/* select#3 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 5) `dt1`)/* select#1 */ select /*+ NO_INDEX(`t1`@`qb_cte1`) */ `cte`.`count(*)` AS `count(*)`,`cte1`.`count(*)` AS `count(*)` from `cte` join `cte` `cte1` +# ====================================== +# Wrong paths generate warnings +# +explain extended +select /*+ qb_name(`qb_v1`, `v2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Wrong select number: +explain extended +select /*+ qb_name(qb_v1, `v2`@`sel_2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(qb_v1, v2@sel_1 .@sel_2)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v2`@`sel_1` .@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +# Attempting to reference a regular table as a query block: +explain extended +select /*+ qb_name(qb_v1, dt .t1)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`t1`) is ignored. Check whether the path to the query block is correct +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# Wrong view name inside a derived table: +explain extended +select /*+ qb_name(qb_v1, dt .v2)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v2`) is ignored. Check whether the path to the query block is correct +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# Wrong select number: +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_2)*/* from (select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v1`@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +explain extended +select /*+ qb_name(qb_v1, dt .v1@sel_1 .@sel_2)*/* from +(select t1.* from t1 join v1) dt; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 PRIMARY ALL NULL NULL NULL NULL 500 100.00 +2 DERIVED t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using where; Using index +2 DERIVED t1 ALL NULL NULL NULL NULL 100 100.00 Using join buffer (flat, BNL join) +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `dt` .`v1`@`sel_1` .@`sel_2`) is ignored. Check whether the path to the query block is correct +Note 1003 /* select#1 */ select `dt`.`a` AS `a`,`dt`.`b` AS `b`,`dt`.`c` AS `c` from (/* select#2 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` join `test`.`t1` where `test`.`t1`.`a` < 10) `dt` +# Wrong select number syntax: +explain extended +select /*+ qb_name(qb_v1, `v1`@`lex_2`)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v1`@`lex_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +explain extended +select /*+ qb_name(qb_v1, v1 .lex_2)*/* from v1; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range idx_a,idx_ab idx_a 5 NULL 5 100.00 Using index condition +Warnings: +Warning 4245 Hint QB_NAME(`qb_v1` , `v1` .`lex_2`) is ignored. Check whether the path to the query block is correct +Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c` from `test`.`t1` where `test`.`t1`.`a` < 10 +set optimizer_switch= default; +drop table t1, t2; +drop view v1, v2, v3; diff --git a/mysql-test/main/opt_hints_qb_name_path.test b/mysql-test/main/opt_hints_qb_name_path.test new file mode 100644 index 0000000000000..deac2a042cde3 --- /dev/null +++ b/mysql-test/main/opt_hints_qb_name_path.test @@ -0,0 +1,35 @@ +--source include/have_sequence.inc + +create table t1 (a int, b int, c char(20), key idx_a(a), key idx_ab(a, b)); + +insert into t1 select seq, seq, 'filler' from seq_1_to_100; + +create table t2 as select * from t1; + +analyze table t1,t2 persistent for all; + +create view v1 as select * from t1 where a < 10; + +create view v2 as + select * from t1 join /* Name of this query block is @SEL_1 */ + ( + select count(*) from t1 join v1 /* Name of this query block is @SEL_2 */ + ) tt; + +create view v3 as + select * from t1 where a < 10 union select * from t1 where a > 90; + +--echo +--echo ================================================================ +set optimizer_switch= 'derived_merge=on'; +--source opt_hints_qb_name_path.inc + +--echo +--echo ================================================================ +set optimizer_switch= 'derived_merge=off'; +--source opt_hints_qb_name_path.inc + +set optimizer_switch= default; + +drop table t1, t2; +drop view v1, v2, v3; \ No newline at end of file diff --git a/sql/opt_hints.cc b/sql/opt_hints.cc index 1d2aa496caa6d..00878bb536c99 100644 --- a/sql/opt_hints.cc +++ b/sql/opt_hints.cc @@ -42,7 +42,7 @@ struct st_opt_hint_info opt_hint_info[]= {{STRING_WITH_LEN("ICP")}, true, false, false, hrs::LATE}, {{STRING_WITH_LEN("MRR")}, true, false, false, hrs::LATE}, {{STRING_WITH_LEN("NO_RANGE_OPTIMIZATION")}, true, false, false, hrs::LATE}, - {{STRING_WITH_LEN("QB_NAME")}, false, false, false, hrs::EARLY}, + {{STRING_WITH_LEN("QB_NAME")}, false, false, false, hrs::NOT_SET}, {{STRING_WITH_LEN("MAX_EXECUTION_TIME")}, false, true, false, hrs::LATE}, {{STRING_WITH_LEN("SEMIJOIN")}, false, true, false, hrs::LATE}, {{STRING_WITH_LEN("SUBQUERY")}, false, true, false, hrs::LATE}, @@ -88,6 +88,13 @@ int cmp_lex_string(const LEX_CSTRING &s, const LEX_CSTRING &t, (const uchar*)t.str, t.length); } +int cmp_lex_string_limit(const LEX_CSTRING &s, const LEX_CSTRING &t, + const CHARSET_INFO *cs, size_t chars_limit) +{ + return cs->coll->strnncollsp(cs, (const uchar*)s.str, chars_limit, + (const uchar*)t.str, chars_limit); +} + /* This is a version of push_warning_printf() guaranteeing no escalation of the warning to the level of error diff --git a/sql/opt_hints_parser.cc b/sql/opt_hints_parser.cc index b051e6af1ad13..0f975926380d9 100644 --- a/sql/opt_hints_parser.cc +++ b/sql/opt_hints_parser.cc @@ -18,9 +18,11 @@ #include "opt_hints_parser.h" #include "mysqld.h" +#include "opt_hints_structs.h" #include "sql_error.h" #include "mysqld_error.h" #include "sql_class.h" +#include "sql_lex.h" #include "sql_show.h" #include "opt_hints.h" @@ -52,6 +54,12 @@ Opt_hints_table *get_table_hints(Parse_context *pc, void append_table_name(THD *thd, String *str, const LEX_CSTRING &table_name, const LEX_CSTRING &qb_name); +int cmp_lex_string(const LEX_CSTRING &s, const LEX_CSTRING &t, + const CHARSET_INFO *cs); + +int cmp_lex_string_limit(const LEX_CSTRING &s, const LEX_CSTRING &t, + const CHARSET_INFO *cs, size_t chars_limit); + static const Lex_ident_sys null_ident_sys; @@ -141,6 +149,8 @@ Optimizer_hint_tokenizer::find_keyword(const LEX_CSTRING &str) return TokenID::keyword_GROUP_INDEX; if ("INDEX_MERGE"_Lex_ident_column.streq(str)) return TokenID::keyword_INDEX_MERGE; + if ("QB_NAME_LOC"_Lex_ident_column.streq(str)) + return TokenID::keyword_QB_NAME_LOC; break; case 12: @@ -253,6 +263,8 @@ Optimizer_hint_tokenizer::get_token(CHARSET_INFO *cs) TokenID::tIDENT : find_keyword(ident)); if (!get_char(',')) return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tCOMMA); + if (!get_char('.')) + return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tDOT); if (!get_char('@')) return Token(Lex_cstring(m_ptr - 1, 1), TokenID::tAT); if (!get_char('(')) @@ -788,39 +800,246 @@ void Parser::Index_level_hint::append_args(THD *thd, String *str) const } +/* + Check if a SELECT_LEX is a descendant of a given unit +*/ +static bool is_descendant_of_unit(SELECT_LEX *sl, st_select_lex_unit *unit) +{ + // Walk up the tree from sl to see if we reach unit + while (sl) + { + st_select_lex_unit *sl_unit= sl->master_unit(); + if (sl_unit == unit) + return true; + // Move up to the outer SELECT + sl= sl_unit->outer_select(); + } + return false; +} + /* Resolve a parsed query block name hint, i.e. set up proper Opt_hint_* structures which will be used later during query preparation and optimization. -Return value: -- false: no critical errors, warnings on duplicated hints, - unresolved query block names, etc. are allowed -- true: critical errors detected, break further hints processing + Return value: + - false: no critical errors, warnings on duplicated hints, + unresolved query block names, etc. are allowed + - true: critical errors detected, break further hints processing */ bool Parser::Qb_name_hint::resolve(Parse_context *pc) const { const opt_hints_enum hint_type= QB_NAME_HINT_ENUM; - if (!is_appropriate_resolution_stage(hint_type, pc)) - return false; + Opt_hints_qb *target_qb= nullptr; + const Lex_ident_sys qb_name_from_hint= + Query_block_name::to_ident_sys(pc->thd); - Opt_hints_qb *qb= pc->select->opt_hints_qb; + const Opt_query_block_path &path= *this; + if (path.is_empty()) + { + // Simple hint, e.g. QB_NAME(qb1). Resolved in EARLY stage. + if (pc->resolution_stage != hint_resolution_stage::EARLY) + return false; + target_qb= pc->select->opt_hints_qb; + } + else + { + /* + QB_NAME hint with path, for example QB_NAME(qb1, v1@sel_1 .@sel_2) + Resolved in LATE stage. + */ + if (pc->resolution_stage != hint_resolution_stage::LATE) + return false; + + const Query_block_path_list &qb_path_list= path; + + // Start from the current SELECT_LEX + SELECT_LEX *target_select= pc->select; + // Iterate through all path elements + for (const QB_path_element &elem : qb_path_list) + { + Lex_ident_sys select_num_str; + Lex_ident_sys view_name; + if (const At_QB_path_element_select_num &at_select_num= elem) + { + // This path element is a SELECT_LEX number, for example @SEL_1 + const QB_path_element_select_num &qb_path_select_num= at_select_num; + select_num_str= qb_path_select_num.to_ident_sys(pc->thd); + } + else if (const QB_path_element_view_sel &view_sel= elem) + { + /* + This path element is a combination of view name + and optional SELECT_LEX number, for example v1 or v1@SEL_1 + */ + const QB_path_element_view_name &qb_path_view_name= view_sel; + view_name= qb_path_view_name.to_ident_sys(pc->thd); + const Opt_at_QB_path_element_select_num &opt_at_select_num= view_sel; + if (const At_QB_path_element_select_num2 &at_select_num= opt_at_select_num) + { + const QB_path_element_select_num &qb_path_select_num= at_select_num; + select_num_str= qb_path_select_num.to_ident_sys(pc->thd); + } + } - DBUG_ASSERT(qb); + // Find SELECT_LEX corresponding to the parsed path element + if (select_num_str.length > 0) + { + // Check format and extract select number, then wind to the select_lex + const LEX_CSTRING format= { "SEL_", 4 }; + if (cmp_lex_string_limit(select_num_str, format, + system_charset_info, format.length)) + { + print_warn(pc->thd, ER_WARN_WRONG_PATH_IN_QB_NAME, hint_type, + true, &qb_name_from_hint, nullptr, nullptr, this); + return false; + } - const Lex_ident_sys qb_name_sys= Query_block_name::to_ident_sys(pc->thd); + uint hint_select_num= atoi(select_num_str.str + format.length); + /* + Select number in the hint is treated as a relative offset from + current unit's first_select() select_number (base select_number). + I.e., @SEL_N means: find SELECT_LEX with select_number = + base select_number + (N - 1). + @SEL_1 always points to the base SELECT_LEX, @SEL_2 - to the next + one, and so on. + */ + st_select_lex_unit *unit= target_select->master_unit(); + uint base_select_num= unit->first_select()->select_number; + uint target_select_num= base_select_num + (hint_select_num - 1); + /* + Traverse the global SELECT_LEX list to find SELECT_LEX + with target_select_num + */ + target_select= nullptr; + for (SELECT_LEX *sl= pc->thd->lex->all_selects_list; sl; + sl= sl->next_select_in_list()) + { + if (sl->select_number == target_select_num && + is_descendant_of_unit(sl, unit)) + { + target_select= sl; + break; + } + } + if (!target_select) + { + // Target select_number wasn't found + print_warn(pc->thd, ER_WARN_WRONG_PATH_IN_QB_NAME, hint_type, + true, &qb_name_from_hint, nullptr, nullptr, this); + return false; + } + } + if (view_name.length > 0) + { + // Traverse the list of current SELECT_LEX's tables to find `view_name` + bool found= false; + for (TABLE_LIST *tbl= target_select->table_list.first; tbl; + tbl= tbl->next_local) + { + if (tbl->is_view_or_derived() && + !cmp_lex_string(tbl->alias, view_name, system_charset_info)) + { + found= true; + target_select= tbl->get_unit()->first_select(); + break; + } + } + if (!found) + { + print_warn(pc->thd, ER_WARN_WRONG_PATH_IN_QB_NAME, hint_type, + true, &qb_name_from_hint, nullptr, nullptr, this); + return false; + } + } + } + /* + Loop is finished, and target SELECT_LEX has been successfully found. + Create Opt_hints_qb structure for it (or get if it is already created). + */ + Parse_context target_pc(pc->thd, target_select, pc->resolution_stage); + target_qb= get_qb_hints(&target_pc); + if (!target_qb) + return true; + } - if (qb->get_name().str || // QB name is already set - qb->get_parent()->find_by_name(qb_name_sys)) // Name is already used + DBUG_ASSERT(target_qb); + /* + (1) Name is already assigned to this query block + (2) Given name is already used inside this block of hints + */ + if (target_qb->get_name().str || // (1) + target_qb->get_parent()->find_by_name(qb_name_from_hint)) // (2) { print_warn(pc->thd, ER_WARN_CONFLICTING_HINT, hint_type, true, - &qb_name_sys, nullptr, nullptr, nullptr); + &qb_name_from_hint, nullptr, nullptr, nullptr); return false; } - - qb->set_name(qb_name_sys); + target_qb->set_name(qb_name_from_hint); return false; } +/* + Append QB_NAME hint arguments for printing in warnings/EXPLAIN +*/ +void Parser::Qb_name_hint::append_args(THD *thd, String *str) const +{ + const Query_block_path &qb_path= *this; + if (qb_path.is_empty()) // Simple hint, e.g. QB_NAME(qb1) + return; + + // It is a complex QB_NAME hint with path, print the path to the query block + str->append(STRING_WITH_LEN(", ")); + bool first_element= true; + for (const QB_path_element &elem : qb_path) + { + if (!first_element) + str->append(STRING_WITH_LEN(" .")); + first_element= false; + Lex_ident_sys select_num; + + // Check if it's a select number or view/table name + if (const At_QB_path_element_select_num &at_select_num= elem) + { + const QB_path_element_select_num &qb_path_select_num= at_select_num; + select_num= qb_path_select_num.to_ident_sys(thd); + } + else if (const QB_path_element_view_sel &view_sel= elem) + { + const QB_path_element_view_name &qb_path_view_name= view_sel; + Lex_ident_sys view_name= qb_path_view_name.to_ident_sys(thd); + append_identifier(thd, str, &view_name); + + const Opt_at_QB_path_element_select_num &opt_at_select_num= view_sel; + if (const At_QB_path_element_select_num2 &at_select_num= + opt_at_select_num) + { + const QB_path_element_select_num &qb_path_select_num= at_select_num; + select_num= qb_path_select_num.to_ident_sys(thd); + } + } + else + { + DBUG_ASSERT(false); + } + if (select_num.length > 0) + { + str->append(STRING_WITH_LEN("@")); + append_identifier(thd, str, &select_num); + } + } +} + + +bool Parser::Query_block_path_list::add(Optimizer_hint_parser *p, + QB_path_element &&elem) +{ + QB_path_element *pe= (QB_path_element*) p->m_thd->alloc(sizeof(*pe)); + if (!pe) + return true; + *pe= std::move(elem); + return push_back(pe, p->m_thd->mem_root); +} + void Parser::Semijoin_hint::fill_strategies_map(Opt_hints_qb *qb) const { diff --git a/sql/opt_hints_parser.h b/sql/opt_hints_parser.h index 7d5d56c56fcdc..f5ab3a01a1760 100644 --- a/sql/opt_hints_parser.h +++ b/sql/opt_hints_parser.h @@ -62,6 +62,7 @@ class Optimizer_hint_tokenizer: public Extended_string_tokenizer tEOF= 2, // returned when the end of input is reached // One character tokens + tDOT= '.', tCOMMA= ',', tAT= '@', tLPAREN= '(', @@ -80,6 +81,7 @@ class Optimizer_hint_tokenizer: public Extended_string_tokenizer keyword_NO_RANGE_OPTIMIZATION, keyword_MRR, keyword_QB_NAME, + keyword_QB_NAME_LOC, keyword_MAX_EXECUTION_TIME, keyword_SEMIJOIN, keyword_NO_SEMIJOIN, @@ -268,10 +270,14 @@ class Optimizer_hint_parser: public Optimizer_hint_tokenizer, using TokenAT= TokenParser; + using TokenCOMMA= TokenParser; + using TokenEOF= TokenParser; using Keyword_QB_NAME= TokenParser; + using Keyword_QB_NAME_LOC= TokenParser; + using Keyword_MAX_EXECUTION_TIME= TokenParser; @@ -623,18 +629,121 @@ class Optimizer_hint_parser: public Optimizer_hint_tokenizer, void append_args(THD *thd, String *str) const override; }; + // qb_path_element_view_name ::= identifier + class QB_path_element_view_name: public Identifier + { + public: + using Identifier::Identifier; + }; + + // qb_path_element_select_num ::= identifier + class QB_path_element_select_num: public Identifier + { + public: + using Identifier::Identifier; + }; + + // at_qb_path_element_select_num ::= @ qb_path_element_select_num + class At_QB_path_element_select_num: + public AND2 + { + public: + using AND2::AND2; + using AND2::operator=; + }; + + // just a clone of At_QB_path_element_select_num to avoid inheritance issues + class At_QB_path_element_select_num2: + public AND2 + { + public: + using AND2::AND2; + using AND2::operator=; + }; + + class Opt_at_QB_path_element_select_num: + public OPT + { + public: + using OPT::OPT; + }; + + /* + qb_path_element_view_sel ::= qb_path_element_view_name + [ @ qb_path_element_select_num ] + */ + class QB_path_element_view_sel: public AND2 + { + public: + using AND2::AND2; + }; + + // qb_path_element ::= @ qb_path_element_select_num | qb_path_element_view_sel + class QB_path_element: public OR2 + { + public: + using OR2::OR2; + }; - // qb_name_hint ::= QB_NAME ( query_block_name ) + // Container for query block path elements + class Query_block_path_list: public List + { + public: + Query_block_path_list() = default; + + bool add(Optimizer_hint_parser *p, QB_path_element &&elem); + size_t count() const { return elements; } + static Query_block_path_list empty(const Optimizer_hint_parser &) + { + return Query_block_path_list(); + } + }; + + /* + query_block_path ::= query_block_path_element + [ {, query_block_path_element }... ] + */ + class Query_block_path: public LIST + { + using LIST::LIST; + }; + + // opt_query_block_path ::= [, query_block_path] + class Opt_query_block_path: public AND2::Opt + { + public: + using Opt::Opt; + }; + + // qb_name_with_opt_path ::= query_block_name [, query_block_path] + class QB_name_with_opt_path: public AND2 + { + public: + using AND2::AND2; + }; + + // qb_name_hint ::= QB_NAME ( qb_name_with_opt_path ) class Qb_name_hint: public AND4 + QB_name_with_opt_path, + RParen>, + public Printable_parser_rule { public: using AND4::AND4; bool resolve(Parse_context *pc) const; + void append_args(THD *thd, String *str) const override; }; diff --git a/sql/opt_hints_structs.h b/sql/opt_hints_structs.h index f4857bf871f96..9bab8007636ec 100644 --- a/sql/opt_hints_structs.h +++ b/sql/opt_hints_structs.h @@ -53,7 +53,12 @@ enum opt_hints_enum enum class hint_resolution_stage { EARLY, - LATE + LATE, + NOT_SET /* If specified for a hint at `st_opt_hint_info`, then it means that + the resolution stage is not determined by the hint type but + depends on the hint body. For example, simple QB_NAME is resolved + in EARLY stage while QB_NAME with path - in LATE stage. + The particular resolution method is responsible in this case */ }; #endif /* OPT_HINTS_STRUCTS_H */ diff --git a/sql/share/errmsg-utf8.txt b/sql/share/errmsg-utf8.txt index c321c12494be4..cf69ef90ea762 100644 --- a/sql/share/errmsg-utf8.txt +++ b/sql/share/errmsg-utf8.txt @@ -12366,3 +12366,5 @@ ER_WARN_AMBIGUOUS_QB_NAME eng "Query block name %s is ambiguous for %s hint" ER_WARN_IMPLICIT_QB_NAME_FOR_UNION eng "Implicit query block name %s is not supported for derived tables and views with UNION/EXCEPT/INTERSECT and is ignored for %s hint" +ER_WARN_WRONG_PATH_IN_QB_NAME + eng "Hint %s is ignored. Check whether the path to the query block is correct" \ No newline at end of file