MDEV-35955 Wrong result for UPDATE ... ORDER BY LIMIT which uses tmp.table
(Variant 2) Multi-table UPDATE ... ORDER BY ... LIMIT could update the wrong rows when ORDER BY was resolved by Using temporary + Using filesort. == Background: ref_pointer_array == join->order[->next*]->item point into join->ref_pointer_array, which has pointers to the used Item objects. This indirection is employed so that we can switch the ORDER BY expressions from using the original Items to using the values of their "image" fields in the temporary table. The variant of ref_pointer_array that has pointers to temp table fields is created when JOIN::make_aggr_tables_info() calls change_refs_to_tmp_fields(). == The problem == The created array didn't match element-by-element the original ref_pointer_array. When arrays were switched, ORDER BY elements started to point to the wrong temp.table fields, causing the wrong sorting. == The cause == The cause is JOIN::add_fields_for_current_rowid(). This function is called for UPDATE statements to make the rowids of rows in the original tables to be saved in the temporary tables. It adds extra columns to the select list in table_fields argument. However, select lists are organized in a way that extra elements must be added *to the front* of the list, and then change_refs_to_tmp_fields() will add extra fields *to the end* of ref_pointer_array. So, add_fields_for_current_rowid() adds new fields to the back of table_fields list. This caused change_refs_to_tmp_fields() to produce ref_pointer_array slice with extra elements in the front, causing any references through ref_pointer_array to come to the wrong values. == The fix == Make JOIN::add_fields_for_current_rowid() add fields to the front of the select list.
This commit is contained in:
parent
5001300bd4
commit
8ec275da16
@ -838,3 +838,82 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
drop table t1, t2;
|
||||
# End of 11.7 tests
|
||||
ALTER DATABASE test CHARACTER SET utf8mb4 COLLATE utf8mb4_uca1400_ai_ci;
|
||||
# MDEV-35955 Wrong result for UPDATE ... ORDER BY LIMIT which uses tmp.table
|
||||
#
|
||||
create table t1 (id int primary key, v int);
|
||||
create table t2 (id int primary key, v int);
|
||||
insert into t1 (id, v) values (2,3),(1,4);
|
||||
insert into t2 (id, v) values (5,5),(6,6);
|
||||
select t1.*, t2.* from t1, t2 order by t1.id, t2.id limit 2;
|
||||
id v id v
|
||||
1 4 5 5
|
||||
1 4 6 6
|
||||
UPDATE t1, t2 SET t1.v=-1, t2.v=-1 ORDER BY t1.id, t2.id LIMIT 2;
|
||||
select * from t1;
|
||||
id v
|
||||
2 3
|
||||
1 -1
|
||||
select * from t2;
|
||||
id v
|
||||
5 -1
|
||||
6 -1
|
||||
drop table t1, t2;
|
||||
create table t1 (id int primary key, v text) engine=myisam;
|
||||
create table t2 (id int primary key, v text) engine=myisam;
|
||||
insert into t1 (id, v) values (1,'b'),(2,'fo'),(3,'bar'),(4,'barr'),(5,'bazzz');
|
||||
insert into t2 (id, v) values (6,'quxqux'),(7,'foofoof'),(8,'barbarba'),(9,'quxquxqux'),(10,'bazbazbazb');
|
||||
select t1.*, t2.* from t1, t2 order by t1.id, t2.id limit 2;
|
||||
id v id v
|
||||
1 b 6 quxqux
|
||||
1 b 7 foofoof
|
||||
update t1, t2 set t1.v='DELETED', t2.v='DELETED' order by t1.id, t2.id limit 2;
|
||||
select * from t1;
|
||||
id v
|
||||
1 DELETED
|
||||
2 fo
|
||||
3 bar
|
||||
4 barr
|
||||
5 bazzz
|
||||
select * from t2;
|
||||
id v
|
||||
6 DELETED
|
||||
7 DELETED
|
||||
8 barbarba
|
||||
9 quxquxqux
|
||||
10 bazbazbazb
|
||||
drop table t1, t2;
|
||||
create table t1 (id int primary key, v int);
|
||||
create table t2 (id int primary key, v int);
|
||||
create table t3 (id int primary key, v int);
|
||||
insert into t1 (id, v) values (1, 1000), (2, 2000), (3, 3000), (4, 4000), (5, 5000);
|
||||
insert into t2 (id, v) values (10, 100), (20, 200), (30, 300), (40, 400), (50, 500);
|
||||
insert into t3 (id, v) values (11, 111), (22, 222), (33, 333), (44, 444), (55, 555);
|
||||
select t1.*, t2.*, t3.* from t1, t2, t3 order by t1.id, t2.id, t3.id limit 3;
|
||||
id v id v id v
|
||||
1 1000 10 100 11 111
|
||||
1 1000 10 100 22 222
|
||||
1 1000 10 100 33 333
|
||||
UPDATE t1, t2, t3 SET t1.v=-1, t2.v=-2, t3.v=-3 ORDER BY t1.id, t2.id, t3.id LIMIT 3;
|
||||
select * from t1;
|
||||
id v
|
||||
1 -1
|
||||
2 2000
|
||||
3 3000
|
||||
4 4000
|
||||
5 5000
|
||||
select * from t2;
|
||||
id v
|
||||
10 -2
|
||||
20 200
|
||||
30 300
|
||||
40 400
|
||||
50 500
|
||||
select * from t3;
|
||||
id v
|
||||
11 -3
|
||||
22 -3
|
||||
33 -3
|
||||
44 444
|
||||
55 555
|
||||
drop table t1, t2, t3;
|
||||
# End of MariaDB 10.11 tests
|
||||
|
@ -787,3 +787,41 @@ drop table t1, t2;
|
||||
--echo # End of 11.7 tests
|
||||
|
||||
--source include/test_db_charset_restore.inc
|
||||
--echo # MDEV-35955 Wrong result for UPDATE ... ORDER BY LIMIT which uses tmp.table
|
||||
--echo #
|
||||
|
||||
create table t1 (id int primary key, v int);
|
||||
create table t2 (id int primary key, v int);
|
||||
insert into t1 (id, v) values (2,3),(1,4);
|
||||
insert into t2 (id, v) values (5,5),(6,6);
|
||||
select t1.*, t2.* from t1, t2 order by t1.id, t2.id limit 2;
|
||||
UPDATE t1, t2 SET t1.v=-1, t2.v=-1 ORDER BY t1.id, t2.id LIMIT 2;
|
||||
select * from t1;
|
||||
select * from t2;
|
||||
|
||||
drop table t1, t2;
|
||||
create table t1 (id int primary key, v text) engine=myisam;
|
||||
create table t2 (id int primary key, v text) engine=myisam;
|
||||
insert into t1 (id, v) values (1,'b'),(2,'fo'),(3,'bar'),(4,'barr'),(5,'bazzz');
|
||||
insert into t2 (id, v) values (6,'quxqux'),(7,'foofoof'),(8,'barbarba'),(9,'quxquxqux'),(10,'bazbazbazb');
|
||||
select t1.*, t2.* from t1, t2 order by t1.id, t2.id limit 2;
|
||||
update t1, t2 set t1.v='DELETED', t2.v='DELETED' order by t1.id, t2.id limit 2;
|
||||
select * from t1;
|
||||
select * from t2;
|
||||
|
||||
drop table t1, t2;
|
||||
create table t1 (id int primary key, v int);
|
||||
create table t2 (id int primary key, v int);
|
||||
create table t3 (id int primary key, v int);
|
||||
insert into t1 (id, v) values (1, 1000), (2, 2000), (3, 3000), (4, 4000), (5, 5000);
|
||||
insert into t2 (id, v) values (10, 100), (20, 200), (30, 300), (40, 400), (50, 500);
|
||||
insert into t3 (id, v) values (11, 111), (22, 222), (33, 333), (44, 444), (55, 555);
|
||||
select t1.*, t2.*, t3.* from t1, t2, t3 order by t1.id, t2.id, t3.id limit 3;
|
||||
UPDATE t1, t2, t3 SET t1.v=-1, t2.v=-2, t3.v=-3 ORDER BY t1.id, t2.id, t3.id LIMIT 3;
|
||||
select * from t1;
|
||||
select * from t2;
|
||||
select * from t3;
|
||||
|
||||
drop table t1, t2, t3;
|
||||
|
||||
--echo # End of MariaDB 10.11 tests
|
||||
|
@ -3649,7 +3649,14 @@ bool JOIN::add_fields_for_current_rowid(JOIN_TAB *cur, List<Item> *table_fields)
|
||||
continue;
|
||||
Item *item= new (thd->mem_root) Item_temptable_rowid(tab->table);
|
||||
item->fix_fields(thd, 0);
|
||||
table_fields->push_back(item, thd->mem_root);
|
||||
/*
|
||||
table_fields points to JOIN::all_fields or JOIN::tmp_all_fields_*.
|
||||
These lists start with "added" fields and then their suffix is shared
|
||||
with JOIN::fields_list or JOIN::tmp_fields_list*.
|
||||
Because of that, new elements can only be added to the front of the list,
|
||||
not to the back.
|
||||
*/
|
||||
table_fields->push_front(item, thd->mem_root);
|
||||
cur->tmp_table_param->func_count++;
|
||||
}
|
||||
return 0;
|
||||
|
Loading…
x
Reference in New Issue
Block a user