MDEV-38045 Implement QB_NAME hint with path syntax for nested query blocks#4482
Open
MDEV-38045 Implement QB_NAME hint with path syntax for nested query blocks#4482
Conversation
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
0135586 to
3818d14
Compare
…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`
3818d14 to
a6ceac5
Compare
5 tasks
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Add this suggestion to a batch that can be applied as a single commit.This suggestion is invalid because no changes were made to the code.Suggestions cannot be applied while the pull request is closed.Suggestions cannot be applied while viewing a subset of changes.Only one suggestion per line can be applied in a batch.Add this suggestion to a batch that can be applied as a single commit.Applying suggestions on deleted lines is not supported.You must change the existing code in this line in order to create a valid suggestion.Outdated suggestions cannot be applied.This suggestion has been applied or marked resolved.Suggestions cannot be applied from pending reviews.Suggestions cannot be applied on multi-line comments.Suggestions cannot be applied while the pull request is queued to merge.Suggestion cannot be applied right now. Please check back later.
Description
This PR follows #4463.
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:
For example,
SELECT /*+ qb_name(qb_v1, v1) */* FROM v1The name
qb_v1is assigned to the inner query block of the viewv1.SELECT /*+ qb_name(qb_v1, v1@sel_1) */* FROM v1Means the same but specifies that
v1is present in SELECT#1 of the currentquery block.
SELECT /*+ qb_name(qb_v1, v1@sel_1 .@sel_2) */* FROM v1This means SELECT#2 of view
v1, which is present in SELECT#1 ofthe 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) dt1How can this PR be tested?
./mtr opt_hints_qb_name_pathBasing the PR against the correct MariaDB version
mainbranch.PR quality check