diff --git a/mysql-test/main/opt_hints.result b/mysql-test/main/opt_hints.result index 44ad291ae53..4682b82c484 100644 --- a/mysql-test/main/opt_hints.result +++ b/mysql-test/main/opt_hints.result @@ -1379,6 +1379,61 @@ SELECT Warnings: Warning 1064 Optimizer hint syntax error near '? bad syntax */ 1' at line 2 DROP TABLE t1; + +# MDEV-36486 Optimizer hints are resolved against the INSERT part of INSERT..SELECT + +CREATE TABLE t1 (a INT, KEY(a)); +INSERT INTO t1 VALUES (1),(2),(3); +CREATE TABLE t2 (a INT, KEY(a)); +INSERT INTO t2 VALUES (1),(2),(3); +# See that the range optimization is employed when there are no hints: +EXPLAIN EXTENDED +INSERT INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index; Using temporary +Warnings: +Note 1003 insert into `test`.`t1`(a) select sql_buffer_result `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +# No range optimization any more: +EXPLAIN EXTENDED +INSERT INTO t1 (a) SELECT /*+ no_range_optimization (t1 a)*/ a FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 index a a 5 NULL 3 100.00 Using where; Using index; Using temporary +Warnings: +Note 1003 insert into `test`.`t1`(a) select /*+ NO_RANGE_OPTIMIZATION(`t1`@`select#2` `a`) */ sql_buffer_result `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +# Alternatively, a hint may be placed next to INSERT keyword: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 index a a 5 NULL 3 100.00 Using where; Using index; Using temporary +Warnings: +Note 1003 insert into `test`.`t1`(a) select /*+ NO_RANGE_OPTIMIZATION(`t1`@`select#1`) */ sql_buffer_result `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +# But if hints are present at both INSERT and SELECT parts, +# those at the INSERT part are ignored: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT /*+ mrr(t1)*/ a +FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index; Using temporary +Warnings: +Note 1003 insert into `test`.`t1`(a) select /*+ MRR(`t1`@`select#2`) */ sql_buffer_result `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +# Table `t2` cannot be resolved since it is not present in the SELECT part +# (a warning expected): +EXPLAIN EXTENDED +INSERT INTO t2 (a) SELECT /*+ no_range_optimization (t2)*/ a FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index +Warnings: +Warning 4212 Unresolved table name `t2`@`select#2` for NO_RANGE_OPTIMIZATION hint +Note 1003 insert into `test`.`t2`(a) select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +# Alternative placement of the hint: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t2 ix1)*/ INTO t2 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index +Warnings: +Warning 4213 Unresolved index name `t2`@`select#1` `ix1` for NO_RANGE_OPTIMIZATION hint +Note 1003 insert into `test`.`t2`(a) select `test`.`t1`.`a` AS `a` from `test`.`t1` where `test`.`t1`.`a` > 1 and `test`.`t1`.`a` <= 3 +DROP TABLE t1, t2; set optimizer_switch = DEFAULT; set join_cache_level = DEFAULT; # diff --git a/mysql-test/main/opt_hints.test b/mysql-test/main/opt_hints.test index 08ff3532a41..907c68c766f 100644 --- a/mysql-test/main/opt_hints.test +++ b/mysql-test/main/opt_hints.test @@ -704,6 +704,46 @@ SELECT /*+ ? bad syntax */ 1; DROP TABLE t1; + +--echo +--echo # MDEV-36486 Optimizer hints are resolved against the INSERT part of INSERT..SELECT +--echo + +CREATE TABLE t1 (a INT, KEY(a)); +INSERT INTO t1 VALUES (1),(2),(3); + +CREATE TABLE t2 (a INT, KEY(a)); +INSERT INTO t2 VALUES (1),(2),(3); + +--echo # See that the range optimization is employed when there are no hints: +EXPLAIN EXTENDED +INSERT INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; + +--echo # No range optimization any more: +EXPLAIN EXTENDED +INSERT INTO t1 (a) SELECT /*+ no_range_optimization (t1 a)*/ a FROM t1 WHERE a>1 AND a<=3; + +--echo # Alternatively, a hint may be placed next to INSERT keyword: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; + +--echo # But if hints are present at both INSERT and SELECT parts, +--echo # those at the INSERT part are ignored: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT /*+ mrr(t1)*/ a + FROM t1 WHERE a>1 AND a<=3; + +--echo # Table `t2` cannot be resolved since it is not present in the SELECT part +--echo # (a warning expected): +EXPLAIN EXTENDED +INSERT INTO t2 (a) SELECT /*+ no_range_optimization (t2)*/ a FROM t1 WHERE a>1 AND a<=3; + +--echo # Alternative placement of the hint: +EXPLAIN EXTENDED +INSERT /*+ no_range_optimization (t2 ix1)*/ INTO t2 (a) SELECT a FROM t1 WHERE a>1 AND a<=3; + +DROP TABLE t1, t2; + set optimizer_switch = DEFAULT; set join_cache_level = DEFAULT; diff --git a/sql/opt_hints_parser.cc b/sql/opt_hints_parser.cc index 55beaa1b378..3e0f38639f5 100644 --- a/sql/opt_hints_parser.cc +++ b/sql/opt_hints_parser.cc @@ -475,7 +475,7 @@ bool Parser::Index_level_hint::resolve(Parse_context *pc) const if (!idx) { idx= new (pc->thd->mem_root) - Opt_hints_key(index_name_sys, tab, pc->thd->mem_root); + Opt_hints_key(index_name_sys, tab, pc->thd->mem_root); tab->register_child(idx); } diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 4fa5675c479..759fbb218bc 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -8229,7 +8229,6 @@ void make_leaves_list(THD *thd, List &list, TABLE_LIST *tables, refresh It is only refresh for subquery select_insert It is SELECT ... INSERT command full_table_list a parameter to pass to the make_leaves_list function - resolve_opt_hints Whether optimizer hints must be resolved here NOTE Check also that the 'used keys' and 'ignored keys' exists and set up the @@ -8249,7 +8248,7 @@ void make_leaves_list(THD *thd, List &list, TABLE_LIST *tables, bool setup_tables(THD *thd, Name_resolution_context *context, List *from_clause, TABLE_LIST *tables, List &leaves, bool select_insert, - bool full_table_list, bool resolve_opt_hints) + bool full_table_list) { uint tablenr= 0; List_iterator ti(leaves); @@ -8285,18 +8284,23 @@ bool setup_tables(THD *thd, Name_resolution_context *context, leaves.push_back(table_list, thd->mem_root); } - bool is_insert_tables_num_set= false; + /* + This variable is only used for INSERT..SELECT's: + true: processing the INSERT part of an INSERT..SELECT + false: processing the SELECT part of it + */ + bool is_insert_part= true; while ((table_list= ti++)) { TABLE *table= table_list->table; if (table && !table->pos_in_table_list) table->pos_in_table_list= table_list; - if (select_insert && !is_insert_tables_num_set && + if (select_insert && is_insert_part && table_list->top_table() == first_select_table) { /* new counting for SELECT of INSERT ... SELECT command */ thd->lex->first_select_lex()->insert_tables= tablenr; - is_insert_tables_num_set= true; + is_insert_part= false; tablenr= 0; } if(table_list->jtbm_subselect) @@ -8321,15 +8325,22 @@ bool setup_tables(THD *thd, Name_resolution_context *context, DBUG_RETURN(1); } - if (qb_hints && // QB hints initialized - !table_list->opt_hints_table) // Table hints are not adjusted yet + /* + Conditions to meet for optimizer hints resolution: + (1) QB hints initialized + (2) Table hints are not adjusted yet + (3) Table is not in the INSERT part of INSERT..SELECT + */ + if (qb_hints && // (1) + !table_list->opt_hints_table && // (2) + !(select_insert && is_insert_part)) // (3) { table_list->opt_hints_table= qb_hints->fix_hints_for_table(table_list->table, table_list->alias); } } - if (select_insert && !is_insert_tables_num_set) + if (select_insert && is_insert_part) { /* This happens for statements like `INSERT INTO t1 SELECT 1`, @@ -8396,19 +8407,6 @@ bool setup_tables(THD *thd, Name_resolution_context *context, if (setup_natural_join_row_types(thd, from_clause, context)) DBUG_RETURN(1); - if (resolve_opt_hints) - { - if (thd->lex->opt_hints_global && select_lex->select_number == 1) - { - thd->lex->opt_hints_global->fix_hint(thd); - /* - There's no need to call opt_hints_global->check_unresolved(), - this is done for each query block individually - */ - } - if (qb_hints) - qb_hints->check_unfixed(thd); - } DBUG_RETURN(0); } @@ -8428,7 +8426,6 @@ bool setup_tables(THD *thd, Name_resolution_context *context, select_insert It is SELECT ... INSERT command want_access what access is needed full_table_list a parameter to pass to the make_leaves_list function - resolve_opt_hints Whether optimizer hints must be resolved here NOTE a wrapper for check_tables that will also check the resulting @@ -8445,13 +8442,12 @@ bool setup_tables_and_check_access(THD *thd, Name_resolution_context *context, bool select_insert, privilege_t want_access_first, privilege_t want_access, - bool full_table_list, - bool resolve_opt_hints) + bool full_table_list) { DBUG_ENTER("setup_tables_and_check_access"); if (setup_tables(thd, context, from_clause, tables, - leaves, select_insert, full_table_list, resolve_opt_hints)) + leaves, select_insert, full_table_list)) DBUG_RETURN(TRUE); List_iterator ti(leaves); diff --git a/sql/sql_base.h b/sql/sql_base.h index 0c1947f1c83..a37e57852ed 100644 --- a/sql/sql_base.h +++ b/sql/sql_base.h @@ -228,7 +228,7 @@ Item ** find_item_in_list(Item *item, List &items, uint *counter, bool setup_tables(THD *thd, Name_resolution_context *context, List *from_clause, TABLE_LIST *tables, List &leaves, bool select_insert, - bool full_table_list, bool resolve_opt_hints); + bool full_table_list); bool setup_tables_and_check_access(THD *thd, Name_resolution_context *context, List *from_clause, @@ -237,8 +237,7 @@ bool setup_tables_and_check_access(THD *thd, bool select_insert, privilege_t want_access_first, privilege_t want_access, - bool full_table_list, - bool resolve_opt_hints); + bool full_table_list); bool wait_while_table_is_used(THD *thd, TABLE *table, enum ha_extra_function function); diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index b74ca7e44f6..f644c0c659e 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -1880,11 +1880,11 @@ bool Sql_cmd_delete::prepare_inner(THD *thd) if (setup_tables_and_check_access(thd, &select_lex->context, &select_lex->top_join_list, table_list, select_lex->leaf_tables, - false, DELETE_ACL, SELECT_ACL, true, false)) + false, DELETE_ACL, SELECT_ACL, true)) DBUG_RETURN(TRUE); if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list, - table_list, select_lex->leaf_tables, false, false, true)) + table_list, select_lex->leaf_tables, false, false)) DBUG_RETURN(TRUE); if (!multitable) diff --git a/sql/sql_help.cc b/sql/sql_help.cc index e079e8b793a..a028c219936 100644 --- a/sql/sql_help.cc +++ b/sql/sql_help.cc @@ -801,7 +801,7 @@ static bool init_items_for_help_command(THD *thd, if (setup_tables(thd, &first_select_lex->context, &first_select_lex->top_join_list, - &tables[0], leaves, false, false, true)) + &tables[0], leaves, false, false)) return true; memcpy((char*) used_fields, (char*) init_used_fields, diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index 4290a74d43f..a703efb593e 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -1647,7 +1647,7 @@ static bool mysql_prepare_insert_check_table(THD *thd, TABLE_LIST *table_list, table_list, thd->lex->first_select_lex()->leaf_tables, select_insert, INSERT_ACL, SELECT_ACL, - true, true)) + true)) DBUG_RETURN(TRUE); if (insert_into_view && !fields.elements) diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index b4406a4f592..57fd4c896ea 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -11189,6 +11189,18 @@ bool LEX::parsed_insert_select(SELECT_LEX *first_select) SELECT_LEX *blt __attribute__((unused))= pop_select(); DBUG_ASSERT(blt == &builtin_select); push_select(first_select); + + // INSERT..SELECT allows placing hints next to either INSERT or SELECT, i.e.: + // `INSERT /* hint(t1) */ INTO t2 SELECT a FROM t1` or + // `INSERT INTO t2 SELECT /* hint(t1) */ a FROM t1` + // but not at both places at the same time. + // `first_select` represents the SELECT part here while `builtin_select` - + // the INSERT part. Future processing will proceed with `first_select`, + // so transfer the hints from `builtin_select` to `first_select` in case + // they were not already set. If hints are present for both INSERT and SELECT + // parts, SELECT part hints are preserved while INSERT part hints are discarded + if (!first_select->opt_hints_qb && blt->opt_hints_qb) + first_select->opt_hints_qb= blt->opt_hints_qb; return false; } diff --git a/sql/sql_load.cc b/sql/sql_load.cc index 96d00a2d198..97f5f0011ba 100644 --- a/sql/sql_load.cc +++ b/sql/sql_load.cc @@ -419,7 +419,7 @@ int mysql_load(THD *thd, const sql_exchange *ex, TABLE_LIST *table_list, thd->lex->first_select_lex()->leaf_tables, FALSE, INSERT_ACL | UPDATE_ACL, - INSERT_ACL | UPDATE_ACL, false, true)) + INSERT_ACL | UPDATE_ACL, false)) DBUG_RETURN(-1); if (!table_list->table || // do not support join view !table_list->single_table_updatable() || // and derived tables diff --git a/sql/sql_select.cc b/sql/sql_select.cc index baf9df6ce31..25d2294943f 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1468,9 +1468,20 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num, if (!(select_options & OPTION_SETUP_TABLES_DONE) && setup_tables_and_check_access(thd, &select_lex->context, join_list, tables_list, select_lex->leaf_tables, - false, SELECT_ACL, SELECT_ACL, false, true)) + false, SELECT_ACL, SELECT_ACL, false)) DBUG_RETURN(-1); + if (thd->lex->opt_hints_global && select_lex->select_number == 1) + { + thd->lex->opt_hints_global->fix_hint(thd); + /* + There's no need to call opt_hints_global->check_unresolved(), + this is done for each query block individually + */ + } + if (select_lex->opt_hints_qb) + select_lex->opt_hints_qb->check_unfixed(thd); + /* System Versioning: handle FOR SYSTEM_TIME clause. */ if (select_lex->vers_setup_conds(thd, tables_list) < 0) DBUG_RETURN(-1); diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 9d5289169bf..542802b0848 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -1672,7 +1672,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd) if (setup_tables_and_check_access(thd, &select_lex->context, &select_lex->top_join_list, table_list, select_lex->leaf_tables, - false, UPDATE_ACL, SELECT_ACL, true, false)) + false, UPDATE_ACL, SELECT_ACL, true)) DBUG_RETURN(1); if (table_list->has_period() && @@ -3118,7 +3118,7 @@ bool Sql_cmd_update::prepare_inner(THD *thd) DBUG_RETURN(TRUE); if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list, - table_list, select_lex->leaf_tables, false, false, true)) + table_list, select_lex->leaf_tables, false, false)) DBUG_RETURN(TRUE); if (select_lex->vers_setup_conds(thd, table_list))