Commit a6ea7996 authored by Varun Gupta's avatar Varun Gupta

MDEV-14791: Crash with order by expression containing window functions

The issue here is that for a window function in the ORDER BY clause, we were not
creating an extra field in the temporary table for the window function
(which is contained in an expression).
So a call to split_sum_func is added to handle this case

Also we need to update all items that contain a window function
in the temp table during window function computation as filesort would need
these values to be updated to calculate the ORDER BY clause of the select.
parent e292c67b
......@@ -3536,5 +3536,50 @@ AVG(0) OVER () MAX('2')
0.0000 NULL
drop table t1;
#
# MDEV-14791: Crash with order by expression containing window functions
#
CREATE TABLE t1 (b1 int, b2 int);
INSERT INTO t1 VALUES (1,1),(0,0);
explain
SELECT b1 from t1 order by row_number() over (ORDER BY b2) + 1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 Using temporary; Using filesort
SELECT b1 from t1 order by row_number() over (ORDER BY b2) + 1;
b1
0
1
explain
SELECT b1 from t1 order by row_number() over (ORDER BY b2);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 Using temporary; Using filesort
SELECT b1 from t1 order by row_number() over (ORDER BY b2);
b1
0
1
DROP TABLE t1;
CREATE TABLE t1 (a int, b int, c int);
INSERT INTO t1 VALUES (2,3,207), (1,21,909), (7,13,312), (8,64,248);
explain
SELECT * FROM t1 ORDER BY max(t1.a) over (partition by c);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using temporary; Using filesort
SELECT * FROM t1 ORDER BY max(t1.a) over (partition by c);
a b c
1 21 909
2 3 207
7 13 312
8 64 248
explain
SELECT max(t1.a) over (partition by c) as x, b, c from t1 order by max(t1.a) over (partition by c);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using temporary; Using filesort
SELECT max(t1.a) over (partition by c) as x, b, c from t1 order by max(t1.a) over (partition by c);
x b c
1 21 909
2 3 207
7 13 312
8 64 248
drop table t1;
#
# End of 10.2 tests
#
......@@ -2279,6 +2279,37 @@ UNION ALL
(SELECT AVG(0) OVER (), MAX('2') FROM t1);
drop table t1;
--echo #
--echo # MDEV-14791: Crash with order by expression containing window functions
--echo #
CREATE TABLE t1 (b1 int, b2 int);
INSERT INTO t1 VALUES (1,1),(0,0);
explain
SELECT b1 from t1 order by row_number() over (ORDER BY b2) + 1;
SELECT b1 from t1 order by row_number() over (ORDER BY b2) + 1;
explain
SELECT b1 from t1 order by row_number() over (ORDER BY b2);
SELECT b1 from t1 order by row_number() over (ORDER BY b2);
DROP TABLE t1;
CREATE TABLE t1 (a int, b int, c int);
INSERT INTO t1 VALUES (2,3,207), (1,21,909), (7,13,312), (8,64,248);
explain
SELECT * FROM t1 ORDER BY max(t1.a) over (partition by c);
SELECT * FROM t1 ORDER BY max(t1.a) over (partition by c);
explain
SELECT max(t1.a) over (partition by c) as x, b, c from t1 order by max(t1.a) over (partition by c);
SELECT max(t1.a) over (partition by c) as x, b, c from t1 order by max(t1.a) over (partition by c);
drop table t1;
--echo #
--echo # End of 10.2 tests
--echo #
......@@ -933,8 +933,9 @@ JOIN::prepare(TABLE_LIST *tables_init,
item->max_length)))
real_order= TRUE;
if (item->with_sum_func && item->type() != Item::SUM_FUNC_ITEM)
item->split_sum_func(thd, ref_ptrs, all_fields, 0);
if ((item->with_sum_func && item->type() != Item::SUM_FUNC_ITEM) ||
item->with_window_func)
item->split_sum_func(thd, ref_ptrs, all_fields, SPLIT_SUM_SELECT);
}
if (!real_order)
order= NULL;
......@@ -26714,27 +26715,6 @@ AGGR_OP::end_send()
}
else
{
/*
In case we have window functions present, an extra step is required
to compute all the fields from the temporary table.
In case we have a compound expression such as: expr + expr,
where one of the terms has a window function inside it, only
after computing window function values we actually know the true
final result of the compounded expression.
Go through all the func items and save their values once again in the
corresponding temp table fields. Do this for each row in the table.
*/
if (join_tab->window_funcs_step)
{
Item **func_ptr= join_tab->tmp_table_param->items_to_copy;
Item *func;
for (; (func = *func_ptr) ; func_ptr++)
{
if (func->with_window_func)
func->save_in_result_field(true);
}
}
rc= evaluate_join_record(join, join_tab, 0);
}
}
......
......@@ -2527,11 +2527,38 @@ bool save_window_function_values(List<Item_window_func>& window_functions,
TABLE *tbl, uchar *rowid_buf)
{
List_iterator_fast<Item_window_func> iter(window_functions);
JOIN_TAB *join_tab= tbl->reginfo.join_tab;
tbl->file->ha_rnd_pos(tbl->record[0], rowid_buf);
store_record(tbl, record[1]);
while (Item_window_func *item_win= iter++)
item_win->save_in_field(item_win->result_field, true);
/*
In case we have window functions present, an extra step is required
to compute all the fields from the temporary table.
In case we have a compound expression such as: expr + expr,
where one of the terms has a window function inside it, only
after computing window function values we actually know the true
final result of the compounded expression.
Go through all the func items and save their values once again in the
corresponding temp table fields. Do this for each row in the table.
This needs to be done earlier because ORDER BY clause can also have
a window function, so we need to make sure all the fields of the temp.table
are updated before we do the filesort. So is best to update the other fields
that contain the window functions along with the computation of window
functions.
*/
Item **func_ptr= join_tab->tmp_table_param->items_to_copy;
Item *func;
for (; (func = *func_ptr) ; func_ptr++)
{
if (func->with_window_func && func->type() != Item::WINDOW_FUNC_ITEM)
func->save_in_result_field(true);
}
int err= tbl->file->ha_update_row(tbl->record[1], tbl->record[0]);
if (err && err != HA_ERR_RECORD_IS_THE_SAME)
return true;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment