Skip to content

Commit 7148b84

Browse files
author
Varun Gupta
committed
MDEV-13694: Wrong result upon GROUP BY with orderby_uses_equalities=on
For the case when the SJM scan table is the first table in the join order, then if we want to do the sorting on the SJM scan table, then we need to make sure that we unpack the values to base table fields in two cases: 1) Reading the SJM table and writing the sort-keys inside the sort-buffer 2) Reading the sorted data from the sort file
1 parent 9701759 commit 7148b84

File tree

11 files changed

+289
-64
lines changed

11 files changed

+289
-64
lines changed

mysql-test/main/order_by.result

Lines changed: 137 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3417,7 +3417,7 @@ WHERE books.library_id = 8663 AND
34173417
books.scheduled_for_removal=0 )
34183418
ORDER BY wings.id;
34193419
id select_type table type possible_keys key key_len ref rows filtered Extra
3420-
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 2 100.00 Using temporary; Using filesort
3420+
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 2 100.00 Using filesort
34213421
1 PRIMARY wings eq_ref PRIMARY PRIMARY 4 test.books.wings_id 1 100.00
34223422
2 MATERIALIZED books ref library_idx library_idx 4 const 2 100.00 Using where
34233423
Warnings:
@@ -4023,4 +4023,140 @@ COUNT(DISTINCT a)
40234023
34
40244024
SET @@tmp_memory_table_size= @save_tmp_memory_table_size;
40254025
DROP TABLE t1;
4026+
#
4027+
# MDEV-13694: Wrong result upon GROUP BY with orderby_uses_equalities=on
4028+
#
4029+
CREATE TABLE t1 (a INT, b int, primary key(a));
4030+
CREATE TABLE t2 (a INT, b INT);
4031+
INSERT INTO t1 (a,b) VALUES (58,1),(96,2),(273,3),(23,4),(231,5),(525,6),
4032+
(2354,7),(321421,3),(535,2),(4535,3);
4033+
INSERT INTO t2 (a,b) VALUES (58,3),(96,3),(273,3);
4034+
# Join order should have the SJM scan table as the first table for both
4035+
# the queries with GROUP BY and ORDER BY clause.
4036+
EXPLAIN SELECT t1.a
4037+
FROM t1
4038+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4039+
ORDER BY t1.a DESC;
4040+
id select_type table type possible_keys key key_len ref rows Extra
4041+
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 3 Using filesort
4042+
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t2.a 1 Using index
4043+
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 Using where
4044+
EXPLAIN FORMAT=JSON SELECT t1.a
4045+
FROM t1
4046+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4047+
ORDER BY t1.a DESC;
4048+
EXPLAIN
4049+
{
4050+
"query_block": {
4051+
"select_id": 1,
4052+
"read_sorted_file": {
4053+
"filesort": {
4054+
"sort_key": "t1.a desc",
4055+
"table": {
4056+
"table_name": "<subquery2>",
4057+
"access_type": "ALL",
4058+
"possible_keys": ["distinct_key"],
4059+
"rows": 3,
4060+
"filtered": 100,
4061+
"materialized": {
4062+
"unique": 1,
4063+
"query_block": {
4064+
"select_id": 2,
4065+
"table": {
4066+
"table_name": "t2",
4067+
"access_type": "ALL",
4068+
"rows": 3,
4069+
"filtered": 100,
4070+
"attached_condition": "t2.b = 3 and t2.a is not null"
4071+
}
4072+
}
4073+
}
4074+
}
4075+
}
4076+
},
4077+
"table": {
4078+
"table_name": "t1",
4079+
"access_type": "eq_ref",
4080+
"possible_keys": ["PRIMARY"],
4081+
"key": "PRIMARY",
4082+
"key_length": "4",
4083+
"used_key_parts": ["a"],
4084+
"ref": ["test.t2.a"],
4085+
"rows": 1,
4086+
"filtered": 100,
4087+
"using_index": true
4088+
}
4089+
}
4090+
}
4091+
SELECT t1.a
4092+
FROM t1
4093+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4094+
ORDER BY t1.a DESC;
4095+
a
4096+
273
4097+
96
4098+
58
4099+
EXPLAIN SELECT t1.a, group_concat(t1.b)
4100+
FROM t1
4101+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4102+
GROUP BY t1.a DESC;
4103+
id select_type table type possible_keys key key_len ref rows Extra
4104+
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 3 Using filesort
4105+
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t2.a 1
4106+
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 Using where
4107+
EXPLAIN FORMAT=JSON SELECT t1.a, group_concat(t1.b)
4108+
FROM t1
4109+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4110+
GROUP BY t1.a DESC;
4111+
EXPLAIN
4112+
{
4113+
"query_block": {
4114+
"select_id": 1,
4115+
"read_sorted_file": {
4116+
"filesort": {
4117+
"sort_key": "t1.a desc",
4118+
"table": {
4119+
"table_name": "<subquery2>",
4120+
"access_type": "ALL",
4121+
"possible_keys": ["distinct_key"],
4122+
"rows": 3,
4123+
"filtered": 100,
4124+
"materialized": {
4125+
"unique": 1,
4126+
"query_block": {
4127+
"select_id": 2,
4128+
"table": {
4129+
"table_name": "t2",
4130+
"access_type": "ALL",
4131+
"rows": 3,
4132+
"filtered": 100,
4133+
"attached_condition": "t2.b = 3 and t2.a is not null"
4134+
}
4135+
}
4136+
}
4137+
}
4138+
}
4139+
},
4140+
"table": {
4141+
"table_name": "t1",
4142+
"access_type": "eq_ref",
4143+
"possible_keys": ["PRIMARY"],
4144+
"key": "PRIMARY",
4145+
"key_length": "4",
4146+
"used_key_parts": ["a"],
4147+
"ref": ["test.t2.a"],
4148+
"rows": 1,
4149+
"filtered": 100
4150+
}
4151+
}
4152+
}
4153+
SELECT t1.a, group_concat(t1.b)
4154+
FROM t1
4155+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
4156+
GROUP BY t1.a DESC;
4157+
a group_concat(t1.b)
4158+
273 3
4159+
96 2
4160+
58 1
4161+
DROP TABLE t1, t2;
40264162
# End of 10.5 tests

mysql-test/main/order_by.test

Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2500,5 +2500,37 @@ SELECT COUNT(DISTINCT a) FROM t1;
25002500
SET @@tmp_memory_table_size= @save_tmp_memory_table_size;
25012501
DROP TABLE t1;
25022502

2503+
--echo #
2504+
--echo # MDEV-13694: Wrong result upon GROUP BY with orderby_uses_equalities=on
2505+
--echo #
2506+
2507+
CREATE TABLE t1 (a INT, b int, primary key(a));
2508+
CREATE TABLE t2 (a INT, b INT);
2509+
2510+
INSERT INTO t1 (a,b) VALUES (58,1),(96,2),(273,3),(23,4),(231,5),(525,6),
2511+
(2354,7),(321421,3),(535,2),(4535,3);
2512+
INSERT INTO t2 (a,b) VALUES (58,3),(96,3),(273,3);
2513+
2514+
--echo # Join order should have the SJM scan table as the first table for both
2515+
--echo # the queries with GROUP BY and ORDER BY clause.
2516+
2517+
let $query= SELECT t1.a
2518+
FROM t1
2519+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
2520+
ORDER BY t1.a DESC;
2521+
2522+
eval EXPLAIN $query;
2523+
eval EXPLAIN FORMAT=JSON $query;
2524+
eval $query;
2525+
2526+
let $query= SELECT t1.a, group_concat(t1.b)
2527+
FROM t1
2528+
WHERE t1.a IN (SELECT a FROM t2 WHERE b=3)
2529+
GROUP BY t1.a DESC;
2530+
2531+
eval EXPLAIN $query;
2532+
eval EXPLAIN FORMAT=JSON $query;
2533+
eval $query;
2534+
DROP TABLE t1, t2;
25032535

25042536
--echo # End of 10.5 tests

sql/filesort.cc

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -251,6 +251,9 @@ SORT_INFO *filesort(THD *thd, TABLE *table, Filesort *filesort,
251251

252252
param.init_for_filesort(sort_len, table, max_rows, filesort->sort_positions);
253253

254+
param.set_all_read_bits= filesort->set_all_read_bits;
255+
param.unpack= filesort->unpack;
256+
254257
sort->addon_fields= param.addon_fields;
255258
sort->sort_keys= param.sort_keys;
256259

@@ -883,14 +886,20 @@ static ha_rows find_all_keys(THD *thd, Sort_param *param, SQL_SELECT *select,
883886
goto err;
884887
}
885888

889+
if (param->set_all_read_bits)
890+
sort_form->column_bitmaps_set(save_read_set, save_write_set);
886891
DEBUG_SYNC(thd, "after_index_merge_phase1");
887892

888893
for (;;)
889894
{
890895
if (quick_select)
891896
error= select->quick->get_next();
892897
else /* Not quick-select */
898+
{
893899
error= file->ha_rnd_next(sort_form->record[0]);
900+
if (param->unpack)
901+
param->unpack(sort_form);
902+
}
894903
if (unlikely(error))
895904
break;
896905
file->position(sort_form->record[0]);

sql/filesort.h

Lines changed: 12 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -62,6 +62,13 @@ class Filesort: public Sql_alloc
6262
Filesort_tracker *tracker;
6363
Sort_keys *sort_keys;
6464

65+
/*
66+
TRUE means all the fields of table of whose bitmap read_set is set
67+
need to be read while reading records in the sort buffer.
68+
FALSE otherwise
69+
*/
70+
bool set_all_read_bits;
71+
6572
Filesort(ORDER *order_arg, ha_rows limit_arg, bool sort_positions_arg,
6673
SQL_SELECT *select_arg):
6774
order(order_arg),
@@ -71,14 +78,18 @@ class Filesort: public Sql_alloc
7178
own_select(false),
7279
using_pq(false),
7380
sort_positions(sort_positions_arg),
74-
sort_keys(NULL)
81+
sort_keys(NULL),
82+
set_all_read_bits(FALSE),
83+
unpack(NULL)
7584
{
7685
DBUG_ASSERT(order);
7786
};
7887

7988
~Filesort() { cleanup(); }
8089
/* Prepare ORDER BY list for sorting. */
8190
Sort_keys* make_sortorder(THD *thd, JOIN *join, table_map first_table_bit);
91+
/* Unpack temp table columns to base table columns*/
92+
void (*unpack)(TABLE *);
8293

8394
private:
8495
void cleanup();

sql/opt_subselect.cc

Lines changed: 15 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -4285,11 +4285,11 @@ bool setup_sj_materialization_part2(JOIN_TAB *sjm_tab)
42854285
sjm_tab->type= JT_ALL;
42864286

42874287
/* Initialize full scan */
4288-
sjm_tab->read_first_record= join_read_record_no_init;
4288+
sjm_tab->read_first_record= join_init_read_record;
42894289
sjm_tab->read_record.copy_field= sjm->copy_field;
42904290
sjm_tab->read_record.copy_field_end= sjm->copy_field +
42914291
sjm->sjm_table_cols.elements;
4292-
sjm_tab->read_record.read_record_func= rr_sequential_and_unpack;
4292+
sjm_tab->read_record.read_record_func= read_record_func_for_rr_and_unpack;
42934293
}
42944294

42954295
sjm_tab->bush_children->end[-1].next_select= end_sj_materialize;
@@ -7132,3 +7132,16 @@ bool Item_in_subselect::pushdown_cond_for_in_subquery(THD *thd, Item *cond)
71327132
thd->lex->current_select= save_curr_select;
71337133
DBUG_RETURN(FALSE);
71347134
}
7135+
7136+
/*
7137+
@brief
7138+
Check if a table is a SJM Scan table
7139+
7140+
@retval
7141+
TRUE SJM scan table
7142+
FALSE Otherwise
7143+
*/
7144+
bool TABLE_LIST::is_sjm_scan_table()
7145+
{
7146+
return is_active_sjm() && sj_mat_info->is_sj_scan;
7147+
}

sql/records.cc

Lines changed: 29 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -822,3 +822,32 @@ inline void SORT_INFO::unpack_addon_fields(uchar *buff)
822822
field->unpack(field->ptr, buff + addonf->offset, buff_end, 0);
823823
}
824824
}
825+
826+
827+
/*
828+
@brief
829+
Read and unpack next record from a table
830+
831+
@details
832+
The function first reads the next record from the table.
833+
If a success then it unpacks the values to the base table fields.
834+
This is used by SJM scan table to unpack the values of the materialized
835+
table to the base table fields
836+
837+
@retval
838+
0 Record successfully read.
839+
@retval
840+
-1 There is no record to be read anymore.
841+
>0 Error
842+
*/
843+
int read_record_func_for_rr_and_unpack(READ_RECORD *info)
844+
{
845+
int error;
846+
if ((error= info->read_record_func_and_unpack_calls(info)))
847+
return error;
848+
849+
for (Copy_field *cp= info->copy_field; cp != info->copy_field_end; cp++)
850+
(*cp->do_copy)(cp);
851+
852+
return error;
853+
}

sql/records.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -55,6 +55,7 @@ struct READ_RECORD
5555
TABLE *table; /* Head-form */
5656
Unlock_row_func unlock_row;
5757
Read_func read_record_func;
58+
Read_func read_record_func_and_unpack_calls;
5859
THD *thd;
5960
SQL_SELECT *select;
6061
uint ref_length, reclength, rec_cache_size, error_offset;

0 commit comments

Comments
 (0)