Skip to content
/ server Public

MDEV-38045: Implement implicit query block names for optimizer hints#4463

Open
Olernov wants to merge 1 commit intomainfrom
12.3-MDEV-38045-impl-qb-name
Open

MDEV-38045: Implement implicit query block names for optimizer hints#4463
Olernov wants to merge 1 commit intomainfrom
12.3-MDEV-38045-impl-qb-name

Conversation

@Olernov
Copy link
Contributor

@Olernov Olernov commented Nov 30, 2025

Description

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
  • The Jira issue number for this PR is: MDEV-38045

Release Notes

How can this PR be tested?

./mtr opt_hints_impl_qb_name

If the changes are not amenable to automated testing, please explain why not and carefully describe how to test manually.

Basing the PR against the correct MariaDB version

  • This is a new feature or a refactoring, and the PR is based against the main branch.
  • This is a bug fix, and the PR is based against the earliest maintained branch in which the bug can be reproduced.

PR quality check

  • I checked the CODING_STANDARDS.md file and my PR conforms to this where appropriate.
  • For any trivial modifications to the PR, I am ok with the reviewer making the changes themselves.

@Olernov Olernov force-pushed the 12.3-MDEV-38045-impl-qb-name branch 3 times, most recently from c1f3882 to c01df37 Compare December 2, 2025 14:35
Copy link
Member

@DaveGosselin-MariaDB DaveGosselin-MariaDB left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'm glad to see many cases where we keep the happy path on the left. It makes the code easier to read and cuts down on the number of details to keep in mind when reading deeper into functions. Thank you!

I'm wondering why we don't support cases of deeply nested hints. Consider the following example:

SELECT /*+ NO_MERGE(dv) */ * FROM (
  SELECT /*+ NO_MERGE(du) */ * FROM (
    SELECT /*+ NO_MERGE(dt) */ * FROM (
      SELECT * FROM t1 ...
    ) dt
  ) du
) dv;

I don't see a way to address a hint to t1 from the top-level query. It seems like addressing hints goes only one layer deep. Why can't I specify another hint at the top like INDEX_MERGE(t1@dt@du@dv ...) ? Similar idea to TiDB's path-like syntax for reaching down through the query "tree" to apply hints. (If this is supported then there doesn't appear to be a test case for it).

sql/opt_hints.cc Outdated
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())

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Minor nit: this is equivalent to

if (tbl->is_non_derived())

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Agree, this one is more concise.

sql/opt_hints.cc Outdated

void LEX::resolve_optimizer_hints()
{
resolve_optimizer_hints_for_stage(hint_resolution_stage::EARLY);

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This is fine, but it seems like it would make for a better hourglass if resolve_optimizer_hints called resolve_early_optimizer_hints and resolve_late_optimizer_hints.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Indeed, I somehow missed that.

@@ -0,0 +1,177 @@
--echo # Table-level hint
explain extended select /*+ no_bnl(t2@dt)*/ * from

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

In the result file, the implicit query block name is what is shown in the SHOW WARNINGS output rather than the alias name. Is it possible to instead show the alias name?


enum class hint_resolution_stage
{
EARLY,

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

In most places where these are mentioned in comments, there's a little explainer that accompanies them. For example, "early (before opening tables)" or similar. Rather, why not give these more explicit names and dispense with the explainers in the code? I think useful names might be PARSING instead of EARLY and PREPARE instead of LATE (because those correspond to typical query processing phases). Alternatively, we could put the comments here next to the values instead.

(I say 'typical query processing phases' because in other systems, parsing completes before opening tables and query preparation more or less occurs at or after opening tables).

@spetrunia
Copy link
Member

spetrunia commented Feb 2, 2026

In Sql_cmd_dml::prepare(), I can see this:

  lex->resolve_optimizer_hints();
  if (open_tables_for_query(thd, lex->query_tables, &table_count, 0,
                            get_dml_prelocking_strategy()))

Why do both Early and Late stage resolution before opening tables?
Shouldn't Late resolution be done afterwards?

Like this patch does it, e.g. in mysql_test_select():

  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();

sql/opt_hints.cc Outdated
`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);
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Is there any value in using std::make_pair everywhere?
I've made this change and it seems to work:

@@ -354,7 +354,7 @@ find_hints_by_implicit_qb_name(Parse_context *pc, const Lex_ident_sys &qb_name)
         `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);
+      return {implicit_qb_result::AMBIGUOUS, nullptr};
     }
 
     SELECT_LEX *child_select= tbl->get_unit()->first_select();

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Indeed, I changed std::make_pair with {..} and it managed to compile on all buildbot builders

#ifndef OPT_HINTS_STRUCTS_H
#define OPT_HINTS_STRUCTS_H
/*
Copyright (c) 2024, MariaDB
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

2024 ?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Agree, let's make it 2026.

@Olernov
Copy link
Contributor Author

Olernov commented Feb 6, 2026

Sql_cmd_dml::prepare()

The problem here is related to the processing of UPDATEs. Preparation of derived tables happens early, during opening tables:

Sql_cmd_dml::prepare(...)
|
->  open_tables_for_query(...)
    |
    ->   open_tables(...)
         |
         ->   prelocking_strategy->handle_end()
              |
              ->    mysql_handle_derived(lex, DT_PREPARE))
                    |
                    ->   setup_tables()
                         |
                         ->   fix_hints_for_table()

That means by that time all optimizer hints must be already resolved. That is why both early and late hints are resolved before open_tables_for_query in Sql_cmd_dml::prepare().

However, there is a downside of that: implicit QB names are not supported for UPDATEs and DELETEs.

In contrast, during processing of SELECTs, preparation of derived tables happens later, after opening tables (thd->prepare_derived_at_open == false normally):

bool open_and_lock_tables(...)
{
...
    open_tables(..);
...
      if (thd->prepare_derived_at_open &&
        (mysql_handle_derived(thd->lex, DT_PREPARE)))
...

That allows to split the resolution of hints into two phases.

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
@Olernov Olernov force-pushed the 12.3-MDEV-38045-impl-qb-name branch from 32fa3c5 to 78854dc Compare February 6, 2026 19:28
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Development

Successfully merging this pull request may close these issues.

4 participants