Skip to content

Commit 3694eb1

Browse files
committed
Bug#22343301: Error 1093 (HY000): You can't specify target table'.' for update
In the problem query, a derived table is contained in the SET clause of the UPDATE statement. According to documentation, such derived tables should be materialized, in order to avoid error about updating a table that is also read in the same query. These two mechanisms are used to ensure proper handling: 1. When resolving derived tables, exclude_from_table_unique_test is set so that materialized derived tables are excluded from later uniqueness test. 2. unique_table() later performs the uniqueness test. After refactoring of derived tables in 5.7, exclude_from_table_unique_test is set later, when setup_fields() is called for update_value_list. But this is too late for unique_table() to notice it. The solution is to delay the call to unique_table() to after the derived tables are properly resolved. For single-table UPDATE, this means after setup_fields() has been called for update_value_list. For multi-table UPDATE, it means moving the test to Query_result_update::prepare(), just after setup_fields() has been called for *values. Notice also that since Query_result_update::prepare() is not called during query preparation, the uniqueness test has to be done twice. Some light refactoring has been made to Query_result_update::prepare(), to enhance locality of scope of local variables.
1 parent 5c6c6ec commit 3694eb1

File tree

3 files changed

+189
-65
lines changed

3 files changed

+189
-65
lines changed

mysql-test/r/derived.result

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3827,3 +3827,50 @@ NULL NULL
38273827
1 1
38283828
1 5
38293829
DROP TABLE t1, t2, t3;
3830+
# Bug#22343301: Error 1093 (HY000): You can't specify target table'.'
3831+
# for update in FROM clause
3832+
CREATE TABLE users (
3833+
id int unsigned AUTO_INCREMENT,
3834+
name varchar(255),
3835+
position int DEFAULT NULL,
3836+
PRIMARY KEY (id));
3837+
INSERT INTO users (name, position) VALUES
3838+
('user1','1'), ('user2','2'), ('user3','3'), ('user4','4'), ('user5','5');
3839+
# Single-table update with non-mergeable derived table
3840+
UPDATE users
3841+
SET position = (SELECT COUNT(pos) + 1
3842+
FROM (SELECT DISTINCT position AS pos FROM users) AS t2
3843+
WHERE t2.pos < users.position)
3844+
WHERE id = 3;
3845+
# Single-table update with mergeable derived table
3846+
# (but not merged due to being used in a subquery of an UPDATE statement)
3847+
UPDATE users
3848+
SET position = (SELECT COUNT(pos) + 1
3849+
FROM (SELECT position AS pos FROM users) AS t2
3850+
WHERE t2.pos < users.position)
3851+
WHERE id = 3;
3852+
# Multi-table update with non-mergeable derived table
3853+
UPDATE users, (SELECT 1) AS dummy
3854+
SET position = (SELECT COUNT(pos) + 1
3855+
FROM (SELECT DISTINCT position AS pos FROM users) AS t2
3856+
WHERE t2.pos < users.position)
3857+
WHERE id = 3;
3858+
# Multi-table update with mergeable derived table
3859+
UPDATE users, (SELECT 1) AS dummy
3860+
SET position = (SELECT COUNT(pos) + 1
3861+
FROM (SELECT position AS pos FROM users) AS t2
3862+
WHERE t2.pos < users.position)
3863+
WHERE id = 3;
3864+
UPDATE users
3865+
SET position = (SELECT COUNT(t2.position) + 1
3866+
FROM users AS t2
3867+
WHERE t2.position < users.position)
3868+
WHERE id = 3;
3869+
ERROR HY000: You can't specify target table 'users' for update in FROM clause
3870+
UPDATE users, (SELECT 1) AS dummy
3871+
SET position = (SELECT COUNT(t2.position) + 1
3872+
FROM users AS t2
3873+
WHERE t2.position < users.position)
3874+
WHERE id = 3;
3875+
ERROR HY000: You can't specify target table 'users' for update in FROM clause
3876+
DROP TABLE users;

mysql-test/t/derived.test

Lines changed: 57 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2632,3 +2632,60 @@ eval explain $query;
26322632
eval $query;
26332633

26342634
DROP TABLE t1, t2, t3;
2635+
2636+
--echo # Bug#22343301: Error 1093 (HY000): You can't specify target table'.'
2637+
--echo # for update in FROM clause
2638+
2639+
CREATE TABLE users (
2640+
id int unsigned AUTO_INCREMENT,
2641+
name varchar(255),
2642+
position int DEFAULT NULL,
2643+
PRIMARY KEY (id));
2644+
2645+
INSERT INTO users (name, position) VALUES
2646+
('user1','1'), ('user2','2'), ('user3','3'), ('user4','4'), ('user5','5');
2647+
2648+
--echo # Single-table update with non-mergeable derived table
2649+
UPDATE users
2650+
SET position = (SELECT COUNT(pos) + 1
2651+
FROM (SELECT DISTINCT position AS pos FROM users) AS t2
2652+
WHERE t2.pos < users.position)
2653+
WHERE id = 3;
2654+
2655+
--echo # Single-table update with mergeable derived table
2656+
--echo # (but not merged due to being used in a subquery of an UPDATE statement)
2657+
UPDATE users
2658+
SET position = (SELECT COUNT(pos) + 1
2659+
FROM (SELECT position AS pos FROM users) AS t2
2660+
WHERE t2.pos < users.position)
2661+
WHERE id = 3;
2662+
2663+
--echo # Multi-table update with non-mergeable derived table
2664+
UPDATE users, (SELECT 1) AS dummy
2665+
SET position = (SELECT COUNT(pos) + 1
2666+
FROM (SELECT DISTINCT position AS pos FROM users) AS t2
2667+
WHERE t2.pos < users.position)
2668+
WHERE id = 3;
2669+
2670+
--echo # Multi-table update with mergeable derived table
2671+
UPDATE users, (SELECT 1) AS dummy
2672+
SET position = (SELECT COUNT(pos) + 1
2673+
FROM (SELECT position AS pos FROM users) AS t2
2674+
WHERE t2.pos < users.position)
2675+
WHERE id = 3;
2676+
2677+
--error ER_UPDATE_TABLE_USED
2678+
UPDATE users
2679+
SET position = (SELECT COUNT(t2.position) + 1
2680+
FROM users AS t2
2681+
WHERE t2.position < users.position)
2682+
WHERE id = 3;
2683+
2684+
--error ER_UPDATE_TABLE_USED
2685+
UPDATE users, (SELECT 1) AS dummy
2686+
SET position = (SELECT COUNT(t2.position) + 1
2687+
FROM users AS t2
2688+
WHERE t2.position < users.position)
2689+
WHERE id = 3;
2690+
2691+
DROP TABLE users;

sql/sql_update.cc

Lines changed: 85 additions & 65 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
/* Copyright (c) 2000, 2015, Oracle and/or its affiliates. All rights reserved.
1+
/* Copyright (c) 2000, 2016, Oracle and/or its affiliates. All rights reserved.
22
33
This program is free software; you can redistribute it and/or modify
44
it under the terms of the GNU General Public License as published by
@@ -1143,15 +1143,6 @@ bool mysql_prepare_update(THD *thd, const TABLE_LIST *update_table_ref,
11431143
// Return covering keys derived from conditions and ORDER BY clause:
11441144
*covering_keys_for_cond= update_table_ref->table->covering_keys;
11451145

1146-
// Check that table to be updated is not used in a subquery
1147-
TABLE_LIST *const duplicate= unique_table(thd, update_table_ref,
1148-
table_list->next_global, 0);
1149-
if (duplicate)
1150-
{
1151-
update_non_unique_table_error(table_list, "UPDATE", duplicate);
1152-
DBUG_RETURN(true);
1153-
}
1154-
11551146
// Check the fields we are going to modify
11561147
#ifndef NO_EMBEDDED_ACCESS_CHECKS
11571148
table_list->set_want_privilege(UPDATE_ACL);
@@ -1179,6 +1170,15 @@ bool mysql_prepare_update(THD *thd, const TABLE_LIST *update_table_ref,
11791170

11801171
thd->mark_used_columns= mark_used_columns_saved;
11811172

1173+
// Check that table to be updated is not used in a subquery
1174+
TABLE_LIST *const duplicate= unique_table(thd, update_table_ref,
1175+
table_list->next_global, 0);
1176+
if (duplicate)
1177+
{
1178+
update_non_unique_table_error(table_list, "UPDATE", duplicate);
1179+
DBUG_RETURN(true);
1180+
}
1181+
11821182
if (setup_ftfuncs(select))
11831183
DBUG_RETURN(true); /* purecov: inspected */
11841184

@@ -1569,12 +1569,33 @@ int Sql_cmd_update::mysql_multi_update_prepare(THD *thd)
15691569
2) This validation is done by Query_result_update::prepare() but it is
15701570
not called by PREPARE.
15711571
3) So we do it below.
1572+
@todo Remove this code duplication as part of WL#6570
15721573
*/
15731574
if (thd->stmt_arena->is_stmt_prepare())
15741575
{
15751576
if (setup_fields(thd, Ref_ptr_array(), update_value_list, SELECT_ACL,
15761577
NULL, false, false))
15771578
DBUG_RETURN(true);
1579+
1580+
/*
1581+
Check that table being updated is not being used in a subquery, but
1582+
skip all tables of the UPDATE query block itself
1583+
*/
1584+
select->exclude_from_table_unique_test= true;
1585+
for (TABLE_LIST *tr= select->leaf_tables; tr; tr= tr->next_leaf)
1586+
{
1587+
if (tr->lock_type != TL_READ &&
1588+
tr->lock_type != TL_READ_NO_INSERT)
1589+
{
1590+
TABLE_LIST *duplicate= unique_table(thd, tr, select->leaf_tables, 0);
1591+
if (duplicate != NULL)
1592+
{
1593+
update_non_unique_table_error(select->leaf_tables, "UPDATE",
1594+
duplicate);
1595+
DBUG_RETURN(true);
1596+
}
1597+
}
1598+
}
15781599
}
15791600

15801601
/* check single table update for view compound from several tables */
@@ -1602,29 +1623,6 @@ int Sql_cmd_update::mysql_multi_update_prepare(THD *thd)
16021623

16031624
/* @todo: downgrade the metadata locks here. */
16041625

1605-
/*
1606-
Check that we are not using table that we are updating, but we should
1607-
skip all tables of UPDATE SELECT itself
1608-
*/
1609-
select->exclude_from_table_unique_test= true;
1610-
for (TABLE_LIST *tl= select->leaf_tables; tl; tl= tl->next_leaf)
1611-
{
1612-
if (tl->lock_type != TL_READ &&
1613-
tl->lock_type != TL_READ_NO_INSERT)
1614-
{
1615-
TABLE_LIST *duplicate;
1616-
if ((duplicate= unique_table(thd, tl, table_list, 0)))
1617-
{
1618-
update_non_unique_table_error(table_list, "UPDATE", duplicate);
1619-
DBUG_RETURN(true);
1620-
}
1621-
}
1622-
}
1623-
/*
1624-
Set exclude_from_table_unique_test value back to FALSE. It is needed for
1625-
further check in Query_result_update::prepare whether to use record cache.
1626-
*/
1627-
select->exclude_from_table_unique_test= false;
16281626
/*
16291627
Syntax rule for multi-table update prevents these constructs.
16301628
But they are possible for single-table UPDATE against multi-table view.
@@ -1705,21 +1703,18 @@ Query_result_update::Query_result_update(TABLE_LIST *table_list,
17051703
int Query_result_update::prepare(List<Item> &not_used_values,
17061704
SELECT_LEX_UNIT *lex_unit)
17071705
{
1708-
TABLE_LIST *table_ref;
17091706
SQL_I_List<TABLE_LIST> update;
1710-
table_map tables_to_update;
1711-
Item_field *item;
17121707
List_iterator_fast<Item> field_it(*fields);
17131708
List_iterator_fast<Item> value_it(*values);
1714-
uint i, max_fields;
1715-
uint leaf_table_count= 0;
17161709
DBUG_ENTER("Query_result_update::prepare");
17171710

1711+
SELECT_LEX *const select= lex_unit->first_select();
1712+
17181713
thd->count_cuted_fields= CHECK_FIELD_WARN;
17191714
thd->cuted_fields=0L;
17201715
THD_STAGE_INFO(thd, stage_updating_main_table);
17211716

1722-
tables_to_update= get_table_map(fields);
1717+
const table_map tables_to_update= get_table_map(fields);
17231718

17241719
if (!tables_to_update)
17251720
{
@@ -1732,18 +1727,18 @@ int Query_result_update::prepare(List<Item> &not_used_values,
17321727
TABLE::tmp_set by pointing TABLE::read_set to it and then restore it after
17331728
setup_fields().
17341729
*/
1735-
for (table_ref= leaves; table_ref; table_ref= table_ref->next_leaf)
1730+
for (TABLE_LIST *tr= leaves; tr; tr= tr->next_leaf)
17361731
{
1737-
if (tables_to_update & table_ref->map())
1732+
if (tables_to_update & tr->map())
17381733
{
1739-
TABLE *const table= table_ref->table;
1734+
TABLE *const table= tr->table;
17401735
DBUG_ASSERT(table->read_set == &table->def_read_set);
17411736
table->read_set= &table->tmp_set;
17421737
bitmap_clear_all(table->read_set);
17431738
}
17441739
// Resolving may be needed for subsequent executions
1745-
if (table_ref->check_option && !table_ref->check_option->fixed &&
1746-
table_ref->check_option->fix_fields(thd, NULL))
1740+
if (tr->check_option && !tr->check_option->fixed &&
1741+
tr->check_option->fix_fields(thd, NULL))
17471742
DBUG_RETURN(1); /* purecov: inspected */
17481743
}
17491744

@@ -1755,11 +1750,11 @@ int Query_result_update::prepare(List<Item> &not_used_values,
17551750
int error= setup_fields(thd, Ref_ptr_array(), *values, SELECT_ACL, NULL,
17561751
false, false);
17571752

1758-
for (table_ref= leaves; table_ref; table_ref= table_ref->next_leaf)
1753+
for (TABLE_LIST *tr= leaves; tr; tr= tr->next_leaf)
17591754
{
1760-
if (tables_to_update & table_ref->map())
1755+
if (tables_to_update & tr->map())
17611756
{
1762-
TABLE *const table= table_ref->table;
1757+
TABLE *const table= tr->table;
17631758
table->read_set= &table->def_read_set;
17641759
bitmap_union(table->read_set, &table->tmp_set);
17651760
bitmap_clear_all(&table->tmp_set);
@@ -1769,31 +1764,54 @@ int Query_result_update::prepare(List<Item> &not_used_values,
17691764
if (error)
17701765
DBUG_RETURN(1);
17711766

1767+
/*
1768+
Check that table being updated is not being used in a subquery, but
1769+
skip all tables of the UPDATE query block itself
1770+
*/
1771+
select->exclude_from_table_unique_test= true;
1772+
for (TABLE_LIST *tr= select->leaf_tables; tr; tr= tr->next_leaf)
1773+
{
1774+
if (tr->lock_type != TL_READ &&
1775+
tr->lock_type != TL_READ_NO_INSERT)
1776+
{
1777+
TABLE_LIST *duplicate= unique_table(thd, tr, all_tables, 0);
1778+
if (duplicate != NULL)
1779+
{
1780+
update_non_unique_table_error(all_tables, "UPDATE", duplicate);
1781+
DBUG_RETURN(true);
1782+
}
1783+
}
1784+
}
1785+
/*
1786+
Set exclude_from_table_unique_test value back to FALSE. It is needed for
1787+
further check whether to use record cache.
1788+
*/
1789+
select->exclude_from_table_unique_test= false;
17721790
/*
17731791
Save tables beeing updated in update_tables
17741792
update_table->shared is position for table
17751793
Don't use key read on tables that are updated
17761794
*/
17771795

17781796
update.empty();
1779-
for (table_ref= leaves; table_ref; table_ref= table_ref->next_leaf)
1797+
uint leaf_table_count= 0;
1798+
for (TABLE_LIST *tr= leaves; tr; tr= tr->next_leaf)
17801799
{
17811800
/* TODO: add support of view of join support */
17821801
leaf_table_count++;
1783-
if (tables_to_update & table_ref->map())
1802+
if (tables_to_update & tr->map())
17841803
{
1785-
TABLE_LIST *tl= (TABLE_LIST*) thd->memdup(table_ref,
1786-
sizeof(*tl));
1787-
if (!tl)
1804+
TABLE_LIST *dup= (TABLE_LIST*) thd->memdup(tr, sizeof(*dup));
1805+
if (dup == NULL)
17881806
DBUG_RETURN(1);
17891807

1790-
TABLE *const table= table_ref->table;
1808+
TABLE *const table= tr->table;
17911809

1792-
update.link_in_list(tl, &tl->next_local);
1793-
table_ref->shared= tl->shared= table_count++;
1810+
update.link_in_list(dup, &dup->next_local);
1811+
tr->shared= dup->shared= table_count++;
17941812
table->no_keyread=1;
17951813
table->covering_keys.clear_all();
1796-
table->pos_in_table_list= tl;
1814+
table->pos_in_table_list= dup;
17971815
if (table->triggers &&
17981816
table->triggers->has_triggers(TRG_EVENT_UPDATE,
17991817
TRG_ACTION_AFTER))
@@ -1823,31 +1841,33 @@ int Query_result_update::prepare(List<Item> &not_used_values,
18231841
update_operations= (COPY_INFO**) thd->mem_calloc(sizeof(COPY_INFO*) *
18241842
table_count);
18251843

1826-
if (thd->is_fatal_error)
1844+
if (thd->is_error())
18271845
DBUG_RETURN(1);
1828-
for (i=0 ; i < table_count ; i++)
1846+
for (uint i= 0; i < table_count; i++)
18291847
{
18301848
fields_for_table[i]= new List_item;
18311849
values_for_table[i]= new List_item;
18321850
}
1833-
if (thd->is_fatal_error)
1851+
if (thd->is_error())
18341852
DBUG_RETURN(1);
18351853

18361854
/* Split fields into fields_for_table[] and values_by_table[] */
18371855

1838-
while ((item= (Item_field *) field_it++))
1856+
Item *item;
1857+
while ((item= field_it++))
18391858
{
1840-
Item *value= value_it++;
1841-
uint offset= item->table_ref->shared;
1842-
fields_for_table[offset]->push_back(item);
1859+
Item_field *const field= down_cast<Item_field *>(item);
1860+
Item *const value= value_it++;
1861+
uint offset= field->table_ref->shared;
1862+
fields_for_table[offset]->push_back(field);
18431863
values_for_table[offset]->push_back(value);
18441864
}
18451865
if (thd->is_fatal_error)
18461866
DBUG_RETURN(1);
18471867

18481868
/* Allocate copy fields */
1849-
max_fields=0;
1850-
for (i=0 ; i < table_count ; i++)
1869+
uint max_fields= 0;
1870+
for (uint i= 0; i < table_count; i++)
18511871
set_if_bigger(max_fields, fields_for_table[i]->elements + leaf_table_count);
18521872
copy_field= new Copy_field[max_fields];
18531873

0 commit comments

Comments
 (0)