Skip to content

Commit 2cb6171

Browse files
committed
MDEV-36486 Optimizer hints are resolved against the INSERT part of INSERT..SELECT
When processing queries like INSERT INTO t1 (..) SELECT .. FROM t1, t2 ..., there is a single query block (i.e., a single SELECT_LEX) for both INSERT and SELECT parts. During hints resolution, when hints are attached to particular TABLE_LIST's, the search is performed by table name across the whole query block. So, if a table mentioned in an optimizer hint is present in the INSERT part, the hint is attached to the that table. This is obviously wrong as optimizer hints are supposed to only affect the SELECT part of an INSERT..SELECT clause. This commit disables possible attaching hints to tables in the INSERT part and fixes some other bugs related to INSERT..SELECT statements processing
1 parent 6cd219a commit 2cb6171

12 files changed

+150
-37
lines changed

mysql-test/main/opt_hints.result

+55
Original file line numberDiff line numberDiff line change
@@ -1379,6 +1379,61 @@ SELECT
13791379
Warnings:
13801380
Warning 1064 Optimizer hint syntax error near '? bad syntax */ 1' at line 2
13811381
DROP TABLE t1;
1382+
1383+
# MDEV-36486 Optimizer hints are resolved against the INSERT part of INSERT..SELECT
1384+
1385+
CREATE TABLE t1 (a INT, KEY(a));
1386+
INSERT INTO t1 VALUES (1),(2),(3);
1387+
CREATE TABLE t2 (a INT, KEY(a));
1388+
INSERT INTO t2 VALUES (1),(2),(3);
1389+
# See that the range optimization is employed when there are no hints:
1390+
EXPLAIN EXTENDED
1391+
INSERT INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
1392+
id select_type table type possible_keys key key_len ref rows filtered Extra
1393+
1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index; Using temporary
1394+
Warnings:
1395+
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
1396+
# No range optimization any more:
1397+
EXPLAIN EXTENDED
1398+
INSERT INTO t1 (a) SELECT /*+ no_range_optimization (t1 a)*/ a FROM t1 WHERE a>1 AND a<=3;
1399+
id select_type table type possible_keys key key_len ref rows filtered Extra
1400+
1 SIMPLE t1 index a a 5 NULL 3 100.00 Using where; Using index; Using temporary
1401+
Warnings:
1402+
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
1403+
# Alternatively, a hint may be placed next to INSERT keyword:
1404+
EXPLAIN EXTENDED
1405+
INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
1406+
id select_type table type possible_keys key key_len ref rows filtered Extra
1407+
1 SIMPLE t1 index a a 5 NULL 3 100.00 Using where; Using index; Using temporary
1408+
Warnings:
1409+
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
1410+
# But if hints are present at both INSERT and SELECT parts,
1411+
# those at the INSERT part are ignored:
1412+
EXPLAIN EXTENDED
1413+
INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT /*+ mrr(t1)*/ a
1414+
FROM t1 WHERE a>1 AND a<=3;
1415+
id select_type table type possible_keys key key_len ref rows filtered Extra
1416+
1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index; Using temporary
1417+
Warnings:
1418+
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
1419+
# Table `t2` cannot be resolved since it is not present in the SELECT part
1420+
# (a warning expected):
1421+
EXPLAIN EXTENDED
1422+
INSERT INTO t2 (a) SELECT /*+ no_range_optimization (t2)*/ a FROM t1 WHERE a>1 AND a<=3;
1423+
id select_type table type possible_keys key key_len ref rows filtered Extra
1424+
1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index
1425+
Warnings:
1426+
Warning 4212 Unresolved table name `t2`@`select#2` for NO_RANGE_OPTIMIZATION hint
1427+
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
1428+
# Alternative placement of the hint:
1429+
EXPLAIN EXTENDED
1430+
INSERT /*+ no_range_optimization (t2 ix1)*/ INTO t2 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
1431+
id select_type table type possible_keys key key_len ref rows filtered Extra
1432+
1 SIMPLE t1 range a a 5 NULL 2 100.00 Using where; Using index
1433+
Warnings:
1434+
Warning 4213 Unresolved index name `t2`@`select#1` `ix1` for NO_RANGE_OPTIMIZATION hint
1435+
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
1436+
DROP TABLE t1, t2;
13821437
set optimizer_switch = DEFAULT;
13831438
set join_cache_level = DEFAULT;
13841439
#

mysql-test/main/opt_hints.test

+40
Original file line numberDiff line numberDiff line change
@@ -704,6 +704,46 @@ SELECT
704704
/*+ ? bad syntax */ 1;
705705

706706
DROP TABLE t1;
707+
708+
--echo
709+
--echo # MDEV-36486 Optimizer hints are resolved against the INSERT part of INSERT..SELECT
710+
--echo
711+
712+
CREATE TABLE t1 (a INT, KEY(a));
713+
INSERT INTO t1 VALUES (1),(2),(3);
714+
715+
CREATE TABLE t2 (a INT, KEY(a));
716+
INSERT INTO t2 VALUES (1),(2),(3);
717+
718+
--echo # See that the range optimization is employed when there are no hints:
719+
EXPLAIN EXTENDED
720+
INSERT INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
721+
722+
--echo # No range optimization any more:
723+
EXPLAIN EXTENDED
724+
INSERT INTO t1 (a) SELECT /*+ no_range_optimization (t1 a)*/ a FROM t1 WHERE a>1 AND a<=3;
725+
726+
--echo # Alternatively, a hint may be placed next to INSERT keyword:
727+
EXPLAIN EXTENDED
728+
INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
729+
730+
--echo # But if hints are present at both INSERT and SELECT parts,
731+
--echo # those at the INSERT part are ignored:
732+
EXPLAIN EXTENDED
733+
INSERT /*+ no_range_optimization (t1)*/ INTO t1 (a) SELECT /*+ mrr(t1)*/ a
734+
FROM t1 WHERE a>1 AND a<=3;
735+
736+
--echo # Table `t2` cannot be resolved since it is not present in the SELECT part
737+
--echo # (a warning expected):
738+
EXPLAIN EXTENDED
739+
INSERT INTO t2 (a) SELECT /*+ no_range_optimization (t2)*/ a FROM t1 WHERE a>1 AND a<=3;
740+
741+
--echo # Alternative placement of the hint:
742+
EXPLAIN EXTENDED
743+
INSERT /*+ no_range_optimization (t2 ix1)*/ INTO t2 (a) SELECT a FROM t1 WHERE a>1 AND a<=3;
744+
745+
DROP TABLE t1, t2;
746+
707747
set optimizer_switch = DEFAULT;
708748
set join_cache_level = DEFAULT;
709749

sql/opt_hints_parser.cc

+1-1
Original file line numberDiff line numberDiff line change
@@ -475,7 +475,7 @@ bool Parser::Index_level_hint::resolve(Parse_context *pc) const
475475
if (!idx)
476476
{
477477
idx= new (pc->thd->mem_root)
478-
Opt_hints_key(index_name_sys, tab, pc->thd->mem_root);
478+
Opt_hints_key(index_name_sys, tab, pc->thd->mem_root);
479479
tab->register_child(idx);
480480
}
481481

sql/sql_base.cc

+21-25
Original file line numberDiff line numberDiff line change
@@ -8227,7 +8227,6 @@ void make_leaves_list(THD *thd, List<TABLE_LIST> &list, TABLE_LIST *tables,
82278227
refresh It is only refresh for subquery
82288228
select_insert It is SELECT ... INSERT command
82298229
full_table_list a parameter to pass to the make_leaves_list function
8230-
resolve_opt_hints Whether optimizer hints must be resolved here
82318230
82328231
NOTE
82338232
Check also that the 'used keys' and 'ignored keys' exists and set up the
@@ -8247,7 +8246,7 @@ void make_leaves_list(THD *thd, List<TABLE_LIST> &list, TABLE_LIST *tables,
82478246
bool setup_tables(THD *thd, Name_resolution_context *context,
82488247
List<TABLE_LIST> *from_clause, TABLE_LIST *tables,
82498248
List<TABLE_LIST> &leaves, bool select_insert,
8250-
bool full_table_list, bool resolve_opt_hints)
8249+
bool full_table_list)
82518250
{
82528251
uint tablenr= 0;
82538252
List_iterator<TABLE_LIST> ti(leaves);
@@ -8283,18 +8282,23 @@ bool setup_tables(THD *thd, Name_resolution_context *context,
82838282
leaves.push_back(table_list, thd->mem_root);
82848283
}
82858284

8286-
bool is_insert_tables_num_set= false;
8285+
/*
8286+
This variable is only used for INSERT..SELECT's:
8287+
true: processing the INSERT part of an INSERT..SELECT
8288+
false: processing the SELECT part of it
8289+
*/
8290+
bool is_insert_part= true;
82878291
while ((table_list= ti++))
82888292
{
82898293
TABLE *table= table_list->table;
82908294
if (table && !table->pos_in_table_list)
82918295
table->pos_in_table_list= table_list;
8292-
if (select_insert && !is_insert_tables_num_set &&
8296+
if (select_insert && is_insert_part &&
82938297
table_list->top_table() == first_select_table)
82948298
{
82958299
/* new counting for SELECT of INSERT ... SELECT command */
82968300
thd->lex->first_select_lex()->insert_tables= tablenr;
8297-
is_insert_tables_num_set= true;
8301+
is_insert_part= false;
82988302
tablenr= 0;
82998303
}
83008304
if(table_list->jtbm_subselect)
@@ -8319,15 +8323,22 @@ bool setup_tables(THD *thd, Name_resolution_context *context,
83198323
DBUG_RETURN(1);
83208324
}
83218325

8322-
if (qb_hints && // QB hints initialized
8323-
!table_list->opt_hints_table) // Table hints are not adjusted yet
8326+
/*
8327+
Conditions to meet for optimizer hints resolution:
8328+
(1) QB hints initialized
8329+
(2) Table hints are not adjusted yet
8330+
(3) Table is not in the INSERT part of INSERT..SELECT
8331+
*/
8332+
if (qb_hints && // (1)
8333+
!table_list->opt_hints_table && // (2)
8334+
!(select_insert && is_insert_part)) // (3)
83248335
{
83258336
table_list->opt_hints_table=
83268337
qb_hints->fix_hints_for_table(table_list->table,
83278338
table_list->alias);
83288339
}
83298340
}
8330-
if (select_insert && !is_insert_tables_num_set)
8341+
if (select_insert && is_insert_part)
83318342
{
83328343
/*
83338344
This happens for statements like `INSERT INTO t1 SELECT 1`,
@@ -8394,19 +8405,6 @@ bool setup_tables(THD *thd, Name_resolution_context *context,
83948405
if (setup_natural_join_row_types(thd, from_clause, context))
83958406
DBUG_RETURN(1);
83968407

8397-
if (resolve_opt_hints)
8398-
{
8399-
if (thd->lex->opt_hints_global && select_lex->select_number == 1)
8400-
{
8401-
thd->lex->opt_hints_global->fix_hint(thd);
8402-
/*
8403-
There's no need to call opt_hints_global->check_unresolved(),
8404-
this is done for each query block individually
8405-
*/
8406-
}
8407-
if (qb_hints)
8408-
qb_hints->check_unfixed(thd);
8409-
}
84108408
DBUG_RETURN(0);
84118409
}
84128410

@@ -8426,7 +8424,6 @@ bool setup_tables(THD *thd, Name_resolution_context *context,
84268424
select_insert It is SELECT ... INSERT command
84278425
want_access what access is needed
84288426
full_table_list a parameter to pass to the make_leaves_list function
8429-
resolve_opt_hints Whether optimizer hints must be resolved here
84308427
84318428
NOTE
84328429
a wrapper for check_tables that will also check the resulting
@@ -8443,13 +8440,12 @@ bool setup_tables_and_check_access(THD *thd, Name_resolution_context *context,
84438440
bool select_insert,
84448441
privilege_t want_access_first,
84458442
privilege_t want_access,
8446-
bool full_table_list,
8447-
bool resolve_opt_hints)
8443+
bool full_table_list)
84488444
{
84498445
DBUG_ENTER("setup_tables_and_check_access");
84508446

84518447
if (setup_tables(thd, context, from_clause, tables,
8452-
leaves, select_insert, full_table_list, resolve_opt_hints))
8448+
leaves, select_insert, full_table_list))
84538449
DBUG_RETURN(TRUE);
84548450

84558451
List_iterator<TABLE_LIST> ti(leaves);

sql/sql_base.h

+2-3
Original file line numberDiff line numberDiff line change
@@ -228,7 +228,7 @@ Item ** find_item_in_list(Item *item, List<Item> &items, uint *counter,
228228
bool setup_tables(THD *thd, Name_resolution_context *context,
229229
List<TABLE_LIST> *from_clause, TABLE_LIST *tables,
230230
List<TABLE_LIST> &leaves, bool select_insert,
231-
bool full_table_list, bool resolve_opt_hints);
231+
bool full_table_list);
232232
bool setup_tables_and_check_access(THD *thd,
233233
Name_resolution_context *context,
234234
List<TABLE_LIST> *from_clause,
@@ -237,8 +237,7 @@ bool setup_tables_and_check_access(THD *thd,
237237
bool select_insert,
238238
privilege_t want_access_first,
239239
privilege_t want_access,
240-
bool full_table_list,
241-
bool resolve_opt_hints);
240+
bool full_table_list);
242241
bool wait_while_table_is_used(THD *thd, TABLE *table,
243242
enum ha_extra_function function);
244243

sql/sql_delete.cc

+2-2
Original file line numberDiff line numberDiff line change
@@ -1865,11 +1865,11 @@ bool Sql_cmd_delete::prepare_inner(THD *thd)
18651865
if (setup_tables_and_check_access(thd, &select_lex->context,
18661866
&select_lex->top_join_list,
18671867
table_list, select_lex->leaf_tables,
1868-
false, DELETE_ACL, SELECT_ACL, true, false))
1868+
false, DELETE_ACL, SELECT_ACL, true))
18691869
DBUG_RETURN(TRUE);
18701870

18711871
if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list,
1872-
table_list, select_lex->leaf_tables, false, false, true))
1872+
table_list, select_lex->leaf_tables, false, false))
18731873
DBUG_RETURN(TRUE);
18741874

18751875
if (!multitable)

sql/sql_help.cc

+1-1
Original file line numberDiff line numberDiff line change
@@ -801,7 +801,7 @@ static bool init_items_for_help_command(THD *thd,
801801

802802
if (setup_tables(thd, &first_select_lex->context,
803803
&first_select_lex->top_join_list,
804-
&tables[0], leaves, false, false, true))
804+
&tables[0], leaves, false, false))
805805
return true;
806806

807807
memcpy((char*) used_fields, (char*) init_used_fields,

sql/sql_insert.cc

+1-1
Original file line numberDiff line numberDiff line change
@@ -1629,7 +1629,7 @@ static bool mysql_prepare_insert_check_table(THD *thd, TABLE_LIST *table_list,
16291629
table_list,
16301630
thd->lex->first_select_lex()->leaf_tables,
16311631
select_insert, INSERT_ACL, SELECT_ACL,
1632-
true, true))
1632+
true))
16331633
DBUG_RETURN(TRUE);
16341634

16351635
if (insert_into_view && !fields.elements)

sql/sql_lex.cc

+12
Original file line numberDiff line numberDiff line change
@@ -11189,6 +11189,18 @@ bool LEX::parsed_insert_select(SELECT_LEX *first_select)
1118911189
SELECT_LEX *blt __attribute__((unused))= pop_select();
1119011190
DBUG_ASSERT(blt == &builtin_select);
1119111191
push_select(first_select);
11192+
11193+
// INSERT..SELECT allows placing hints next to either INSERT or SELECT, i.e.:
11194+
// `INSERT /* hint(t1) */ INTO t2 SELECT a FROM t1` or
11195+
// `INSERT INTO t2 SELECT /* hint(t1) */ a FROM t1`
11196+
// but not at both places at the same time.
11197+
// `first_select` represents the SELECT part here while `builtin_select` -
11198+
// the INSERT part. Future processing will proceed with `first_select`,
11199+
// so transfer the hints from `builtin_select` to `first_select` in case
11200+
// they were not already set. If hints are present for both INSERT and SELECT
11201+
// parts, SELECT part hints are preserved while INSERT part hints are discarded
11202+
if (!first_select->opt_hints_qb && blt->opt_hints_qb)
11203+
first_select->opt_hints_qb= blt->opt_hints_qb;
1119211204
return false;
1119311205
}
1119411206

sql/sql_load.cc

+1-1
Original file line numberDiff line numberDiff line change
@@ -419,7 +419,7 @@ int mysql_load(THD *thd, const sql_exchange *ex, TABLE_LIST *table_list,
419419
thd->lex->first_select_lex()->leaf_tables,
420420
FALSE,
421421
INSERT_ACL | UPDATE_ACL,
422-
INSERT_ACL | UPDATE_ACL, false, true))
422+
INSERT_ACL | UPDATE_ACL, false))
423423
DBUG_RETURN(-1);
424424
if (!table_list->table || // do not support join view
425425
!table_list->single_table_updatable() || // and derived tables

sql/sql_select.cc

+12-1
Original file line numberDiff line numberDiff line change
@@ -1468,9 +1468,20 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num,
14681468
if (!(select_options & OPTION_SETUP_TABLES_DONE) &&
14691469
setup_tables_and_check_access(thd, &select_lex->context, join_list,
14701470
tables_list, select_lex->leaf_tables,
1471-
false, SELECT_ACL, SELECT_ACL, false, true))
1471+
false, SELECT_ACL, SELECT_ACL, false))
14721472
DBUG_RETURN(-1);
14731473

1474+
if (thd->lex->opt_hints_global && select_lex->select_number == 1)
1475+
{
1476+
thd->lex->opt_hints_global->fix_hint(thd);
1477+
/*
1478+
There's no need to call opt_hints_global->check_unresolved(),
1479+
this is done for each query block individually
1480+
*/
1481+
}
1482+
if (select_lex->opt_hints_qb)
1483+
select_lex->opt_hints_qb->check_unfixed(thd);
1484+
14741485
/* System Versioning: handle FOR SYSTEM_TIME clause. */
14751486
if (select_lex->vers_setup_conds(thd, tables_list) < 0)
14761487
DBUG_RETURN(-1);

sql/sql_update.cc

+2-2
Original file line numberDiff line numberDiff line change
@@ -1666,7 +1666,7 @@ bool Multiupdate_prelocking_strategy::handle_end(THD *thd)
16661666

16671667
if (setup_tables_and_check_access(thd, &select_lex->context,
16681668
&select_lex->top_join_list, table_list, select_lex->leaf_tables,
1669-
false, UPDATE_ACL, SELECT_ACL, true, false))
1669+
false, UPDATE_ACL, SELECT_ACL, true))
16701670
DBUG_RETURN(1);
16711671

16721672
if (table_list->has_period() &&
@@ -3105,7 +3105,7 @@ bool Sql_cmd_update::prepare_inner(THD *thd)
31053105
DBUG_RETURN(TRUE);
31063106

31073107
if (setup_tables(thd, &select_lex->context, &select_lex->top_join_list,
3108-
table_list, select_lex->leaf_tables, false, false, true))
3108+
table_list, select_lex->leaf_tables, false, false))
31093109
DBUG_RETURN(TRUE);
31103110

31113111
if (select_lex->vers_setup_conds(thd, table_list))

0 commit comments

Comments
 (0)