Commit 7a5c984f authored by Monty's avatar Monty

MDEV-20010 Equal on two RANK window functions create wrong result

The problematic query outlined a bug in window functions sorting
optimization. When multiple window functions are present in a query,
we sort the sorting key (as defined by PARTITION BY and ORDER BY) from
generic to specific.

SELECT RANK() OVER (ORDER BY const_col) as r1,
       RANK() OVER (ORDER BY const_col, a) as r2,
       RANK() OVER (PARTITION BY c) as r3,
       RANK() OVER (PARTITION BY c ORDER BY b) as r4
FROM table;

For these functions, the sorting we need to do for window function
computations are: [(const_col), (const_col, a)] and [(c), (c, b)].

Instead of doing 4 different sort order, the sorts grouped within [] are
compatible and we can use the most *specific* sort to cover both window
functions.

The bug was caused by an incorrect flagging of which sort is most
specific for a compatible group of functions. In our specific test case,
instead of picking (const_col, a) as the most specific sort, it would
only sort by (const_col), which lead to wrong results for rank function.
By ensuring that we pick the last sort key before an "incompatible sort"
flag is met in our "ordered array of sorting specifications", we
guarantee correct results.
parent 12a5fb4b
......@@ -5800,4 +5800,52 @@ a a
9 9
10 10
drop table t1;
#
# MDEV-20010 Equal on two RANK window functions create wrong result
#
create table t1 (a int, b int) engine= innodb;
insert into t1 values (4, -2), (3, -1);
SELECT RANK() OVER (ORDER BY D.C) = RANK() OVER (ORDER BY B.a) FROM
(SELECT 5 AS C FROM t1) as D, (SELECT t1.b AS A FROM t1) AS B;
RANK() OVER (ORDER BY D.C) = RANK() OVER (ORDER BY B.a)
1
1
0
0
select b, rank() over (order by c) , rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
b rank() over (order by c) rank() over (order by dt1.b)
-2 1 1
-2 1 1
-1 1 3
-1 1 3
select b, rank() over (order by c) , rank() over (order by dt1.b),
rank() over (order by c) = rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
b rank() over (order by c) rank() over (order by dt1.b) rank() over (order by c) = rank() over (order by dt1.b)
-2 1 1 1
-2 1 1 1
-1 1 3 0
-1 1 3 0
alter table t1 engine=myisam;
select b, rank() over (order by c) , rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
b rank() over (order by c) rank() over (order by dt1.b)
-2 1 1
-2 1 1
-1 1 3
-1 1 3
create view v1 as select b,5 as c from t1;
select b, rank() over (order by c) from v1 order by b;
b rank() over (order by c)
-2 1
-1 1
drop view v1;
drop table t1;
# End of 10.4 tests
--source include/default_optimizer_switch.inc
--source include/have_innodb.inc
create table t1 (a int, b varchar(32));
insert into t1 values
......@@ -4013,4 +4014,37 @@ with cte_e as (
drop table t1;
--echo #
--echo # MDEV-20010 Equal on two RANK window functions create wrong result
--echo #
create table t1 (a int, b int) engine= innodb;
insert into t1 values (4, -2), (3, -1);
SELECT RANK() OVER (ORDER BY D.C) = RANK() OVER (ORDER BY B.a) FROM
(SELECT 5 AS C FROM t1) as D, (SELECT t1.b AS A FROM t1) AS B;
select b, rank() over (order by c) , rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
select b, rank() over (order by c) , rank() over (order by dt1.b),
rank() over (order by c) = rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
alter table t1 engine=myisam;
select b, rank() over (order by c) , rank() over (order by dt1.b)
from
(select 5 as c from t1) as dt,
(select b from t1) as dt1;
create view v1 as select b,5 as c from t1;
select b, rank() over (order by c) from v1 order by b;
drop view v1;
drop table t1;
--echo # End of 10.4 tests
......@@ -3076,7 +3076,7 @@ bool Window_funcs_sort::setup(THD *thd, SQL_SELECT *sel,
spec= win_func->window_spec;
int win_func_order_elements= spec->partition_list->elements +
spec->order_list->elements;
if (win_func_order_elements > longest_order_elements)
if (win_func_order_elements >= longest_order_elements)
{
win_func_with_longest_order= win_func;
longest_order_elements= win_func_order_elements;
......
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