Commit 1c6b982e authored by Vicențiu Ciorbaru's avatar Vicențiu Ciorbaru

MDEV-12779 Oracle/DB2 Compatibility Implicit Ordering for ROW_NUMBER OVER

Users expect window functions to produce a certain ordering of rows in
the final result set. Although the standard does not require this, we
already have the filesort result done for when we computed the window
function. If there is no ORDER BY attached to the query, just keep it
till the SELECT is completely evaluated and use that to print the
result.

Update test cases as many did not take care to guarantee a stable
result.
parent dd6e74c6
......@@ -38,10 +38,10 @@ a row_number() over (partition by a order by b)
select a, b, x, row_number() over (partition by a order by x) from t1;
a b x row_number() over (partition by a order by x)
2 10 xx 1
2 10 zz 3
2 20 yy 2
3 10 xxx 2
2 10 zz 3
3 20 vvv 1
3 10 xxx 2
drop table t1;
create table t1 (pk int primary key, a int, b int);
insert into t1 values
......@@ -54,13 +54,14 @@ select
pk, a, b,
row_number() over (order by a),
row_number() over (order by b)
from t1;
from t1
order by b;
pk a b row_number() over (order by a) row_number() over (order by b)
1 10 22 1 5
2 11 21 2 4
3 12 20 3 3
4 13 19 4 2
5 14 18 5 1
4 13 19 4 2
3 12 20 3 3
2 11 21 2 4
1 10 22 1 5
drop table t1;
#
# Try RANK() function
......@@ -228,16 +229,16 @@ count(*) over (partition by c order by pk desc
rows between 2 preceding and 2 following) as CNT
from t1;
pk c CNT
1 1 3
2 1 4
3 1 4
4 1 3
5 2 3
6 2 4
7 2 5
8 2 5
9 2 4
3 1 4
2 1 4
1 1 3
10 2 3
9 2 4
8 2 5
7 2 5
6 2 4
5 2 3
drop table t0,t1;
#
# Resolution of window names
......@@ -535,42 +536,40 @@ insert into t3 values
(5, 2),
(6, 2);
select
pk,
val,
count(val) over (order by val
range between current row and
current row)
as CNT
from t3;
pk val CNT
0 1 3
1 1 3
2 1 3
3 2 4
4 2 4
5 2 4
6 2 4
val CNT
1 3
1 3
1 3
2 4
2 4
2 4
2 4
insert into t3 values
(7, 3),
(8, 3);
select
pk,
val,
count(val) over (order by val
range between current row and
current row)
as CNT
from t3;
pk val CNT
0 1 3
1 1 3
2 1 3
3 2 4
4 2 4
5 2 4
6 2 4
7 3 2
8 3 2
val CNT
1 3
1 3
1 3
2 4
2 4
2 4
2 4
3 2
3 2
drop table t3;
# Now, check with PARTITION BY
create table t4 (
......@@ -599,7 +598,6 @@ insert into t4 values
(5678, 208, 3);
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -607,31 +605,30 @@ range between current row and
current row)
as CNT
from t4;
part_id pk val CNT
1234 100 1 3
1234 101 1 3
1234 102 1 3
1234 103 2 4
1234 104 2 4
1234 105 2 4
1234 106 2 4
1234 107 3 2
1234 108 3 2
5678 200 1 3
5678 201 1 3
5678 202 1 3
5678 203 2 4
5678 204 2 4
5678 205 2 4
5678 206 2 4
5678 207 3 2
5678 208 3 2
part_id val CNT
1234 1 3
1234 1 3
1234 1 3
1234 2 4
1234 2 4
1234 2 4
1234 2 4
1234 3 2
1234 3 2
5678 1 3
5678 1 3
5678 1 3
5678 2 4
5678 2 4
5678 2 4
5678 2 4
5678 3 2
5678 3 2
#
# Try RANGE UNBOUNDED PRECEDING | FOLLOWING
#
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -639,28 +636,27 @@ range between unbounded preceding and
current row)
as CNT
from t4;
part_id pk val CNT
1234 100 1 3
1234 101 1 3
1234 102 1 3
1234 103 2 7
1234 104 2 7
1234 105 2 7
1234 106 2 7
1234 107 3 9
1234 108 3 9
5678 200 1 3
5678 201 1 3
5678 202 1 3
5678 203 2 7
5678 204 2 7
5678 205 2 7
5678 206 2 7
5678 207 3 9
5678 208 3 9
part_id val CNT
1234 1 3
1234 1 3
1234 1 3
1234 2 7
1234 2 7
1234 2 7
1234 2 7
1234 3 9
1234 3 9
5678 1 3
5678 1 3
5678 1 3
5678 2 7
5678 2 7
5678 2 7
5678 2 7
5678 3 9
5678 3 9
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -668,28 +664,27 @@ range between current row and
unbounded following)
as CNT
from t4;
part_id pk val CNT
1234 100 1 9
1234 101 1 9
1234 102 1 9
1234 103 2 6
1234 104 2 6
1234 105 2 6
1234 106 2 6
1234 107 3 2
1234 108 3 2
5678 200 1 9
5678 201 1 9
5678 202 1 9
5678 203 2 6
5678 204 2 6
5678 205 2 6
5678 206 2 6
5678 207 3 2
5678 208 3 2
part_id val CNT
1234 1 9
1234 1 9
1234 1 9
1234 2 6
1234 2 6
1234 2 6
1234 2 6
1234 3 2
1234 3 2
5678 1 9
5678 1 9
5678 1 9
5678 2 6
5678 2 6
5678 2 6
5678 2 6
5678 3 2
5678 3 2
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -697,25 +692,25 @@ range between unbounded preceding and
unbounded following)
as CNT
from t4;
part_id pk val CNT
1234 100 1 9
1234 101 1 9
1234 102 1 9
1234 103 2 9
1234 104 2 9
1234 105 2 9
1234 106 2 9
1234 107 3 9
1234 108 3 9
5678 200 1 9
5678 201 1 9
5678 202 1 9
5678 203 2 9
5678 204 2 9
5678 205 2 9
5678 206 2 9
5678 207 3 9
5678 208 3 9
part_id val CNT
1234 1 9
1234 1 9
1234 1 9
1234 2 9
1234 2 9
1234 2 9
1234 2 9
1234 3 9
1234 3 9
5678 1 9
5678 1 9
5678 1 9
5678 2 9
5678 2 9
5678 2 9
5678 2 9
5678 3 9
5678 3 9
drop table t4;
#
# MDEV-9695: Wrong window frame when using RANGE BETWEEN N FOLLOWING AND PRECEDING
......@@ -881,15 +876,15 @@ RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 FOLLOWING) as cnt
from t1;
pk a cnt
1 1 9
2 2 9
3 4 9
4 8 9
5 26 5
6 27 5
7 40 3
8 71 2
9 72 2
8 71 2
7 40 3
6 27 5
5 26 5
4 8 9
3 4 9
2 2 9
1 1 9
select
pk, a,
count(a) over (ORDER BY a
......@@ -929,15 +924,15 @@ RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 PRECEDING) as cnt
from t1;
pk a cnt
1 1 5
2 2 5
3 4 5
4 8 5
5 26 3
6 27 3
7 40 2
8 71 0
9 72 0
8 71 0
7 40 2
6 27 3
5 26 3
4 8 5
3 4 5
2 2 5
1 1 5
select
pk, a,
count(a) over (ORDER BY a
......@@ -977,15 +972,15 @@ RANGE BETWEEN 1 PRECEDING
AND CURRENT ROW) as cnt
from t1;
pk a cnt
1 1 2
2 2 1
3 4 1
4 8 1
5 26 2
6 27 1
7 40 1
8 71 2
9 72 1
8 71 2
7 40 1
6 27 1
5 26 2
4 8 1
3 4 1
2 2 1
1 1 2
select
pk, a,
count(a) over (ORDER BY a
......@@ -1026,15 +1021,15 @@ range between current row
and 1 following) as cnt
from t1;
pk a cnt
1 1 1
2 2 2
3 4 1
4 8 1
5 26 1
6 27 2
7 40 1
8 71 1
9 72 2
8 71 1
7 40 1
6 27 2
5 26 1
4 8 1
3 4 1
2 2 2
1 1 1
insert into t1 select 22, pk, a from t1;
select
part_id, pk, a,
......@@ -1137,7 +1132,8 @@ pk, a,
count(b) over (order by a
range between 2 preceding
and 2 following) as CNT
from t1;
from t1
order by a, pk;
pk a CNT
1 NULL 3
2 NULL 3
......@@ -1969,12 +1965,12 @@ ROW_NUMBER() OVER (order by s1),
CUME_DIST() OVER (order by -s1)
from t1;
s1 s2 ROW_NUMBER() OVER (order by s1) CUME_DIST() OVER (order by -s1)
-1 2 1.0000000000
1 a 3 0.8333333333
NULL NULL 1 0.1666666667
2 b 4 0.6666666667
3 NULL 5 0.5000000000
4 a 6 0.3333333333
2 b 4 0.6666666667
-1 2 1.0000000000
NULL NULL 1 0.1666666667
drop table t1;
#
# MDEV-9925: Wrong result with aggregate function as a window function
......@@ -2012,8 +2008,8 @@ o_custkey avg(o_custkey) OVER (PARTITION BY abs(o_custkey)
ORDER BY o_custkey
RANGE BETWEEN 15 FOLLOWING
AND 15 FOLLOWING)
242 NULL
238 NULL
242 NULL
DROP table orders;
#
# MDEV-10842: window functions with the same order column
......@@ -2042,20 +2038,20 @@ row_number() over (order by pk desc) as r_desc,
row_number() over (order by pk asc) as r_asc
from t1;
pk r_desc r_asc
1 11 1
2 10 2
3 9 3
4 8 4
5 7 5
6 6 6
7 5 7
8 4 8
9 3 9
10 2 10
11 1 11
10 2 10
9 3 9
8 4 8
7 5 7
6 6 6
5 7 5
4 8 4
3 9 3
2 10 2
1 11 1
drop table t1;
#
# MDEV-10874: two window functions with ccompatible sorting
# MDEV-10874: two window functions with compatible sorting
#
create table t1 (
pk int primary key,
......@@ -2130,17 +2126,17 @@ sum(d) over (order by a
ROWS BETWEEN 1 preceding and 2 following) as sum_2
from t1;
pk a d sum_1 sum_2
1 0 0.100 0.300 1.400
2 0 0.200 0.500 1.200
3 0 0.300 0.300 0.600
4 1 0.400 0.900 2.600
5 1 0.500 1.100 2.400
2 0 0.200 0.500 1.200
1 0 0.100 0.300 1.400
6 1 0.600 0.600 1.600
7 2 0.500 0.500 0.500
8 2 NULL 0.700 1.200
9 2 0.700 1.500 2.000
10 2 0.800 1.700 2.400
5 1 0.500 1.100 2.400
4 1 0.400 0.900 2.600
11 2 0.900 0.900 2.800
10 2 0.800 1.700 2.400
9 2 0.700 1.500 2.000
8 2 NULL 0.700 1.200
7 2 0.500 0.500 0.500
drop table t1;
#
# MDEV-9941: two window functions with compatible partitions
......@@ -2232,9 +2228,9 @@ SELECT sum(t.a) over (partition by t.b order by a),
sqrt(ifnull((sum(t.a) over (partition by t.b order by a)), 0))
from t;
sum(t.a) over (partition by t.b order by a) sqrt(ifnull((sum(t.a) over (partition by t.b order by a)), 0))
0.0000000000 0
1.0000000000 1
3.0000000000 1.7320508075688772
0.0000000000 0
drop table t;
#
# MDEV-10868: view definitions with window functions
......@@ -2391,9 +2387,9 @@ CREATE TABLE t2 (c VARCHAR(8));
INSERT INTO t2 VALUES ('foo'),('bar'),('foo');
SELECT COUNT(*) OVER (PARTITION BY c) FROM t2;
COUNT(*) OVER (PARTITION BY c)
2
1
2
2
SELECT * FROM t1 WHERE i IN ( SELECT COUNT(*) OVER (PARTITION BY c) FROM t2 );
i
1
......@@ -2511,14 +2507,14 @@ select id, rank() over (order by id) from t1;
id rank() over (order by id)
1 1
2 2
3 4
2 2
3 4
select * from v1;
id rnk
1 1
2 2
3 4
2 2
3 4
drop view v1;
drop table t1;
#
......@@ -2879,64 +2875,64 @@ CDEC min(TDEC.CDEC) over ()
NULL -1
-1 -1
0 -1
1 -1
0 -1
1 -1
10 -1
select VDEC.CDEC, min(VDEC.CDEC) over () from VDEC;
CDEC min(VDEC.CDEC) over ()
NULL -1
-1 -1
0 -1
1 -1
0 -1
1 -1
10 -1
select TDEC.CDEC, max(TDEC.CDEC) over () from TDEC;
CDEC max(TDEC.CDEC) over ()
NULL 10
-1 10
0 10
1 10
0 10
1 10
10 10
select VDEC.CDEC, max(VDEC.CDEC) over () from VDEC;
CDEC max(VDEC.CDEC) over ()
NULL 10
-1 10
0 10
1 10
0 10
1 10
10 10
select TDEC.CDEC, min(distinct TDEC.CDEC) over () from TDEC;
CDEC min(distinct TDEC.CDEC) over ()
NULL -1
-1 -1
0 -1
1 -1
0 -1
1 -1
10 -1
select VDEC.CDEC, min(distinct VDEC.CDEC) over () from VDEC;
CDEC min(distinct VDEC.CDEC) over ()
NULL -1
-1 -1
0 -1
1 -1
0 -1
1 -1
10 -1
select TDEC.CDEC, max(distinct TDEC.CDEC) over () from TDEC;
CDEC max(distinct TDEC.CDEC) over ()
NULL 10
-1 10
0 10
1 10
0 10
1 10
10 10
select VDEC.CDEC, max(distinct VDEC.CDEC) over () from VDEC;
CDEC max(distinct VDEC.CDEC) over ()
NULL 10
-1 10
0 10
1 10
0 10
1 10
10 10
#
# These should be removed once support for them is added.
......@@ -3339,27 +3335,29 @@ SET @save_sql_mode= @@sql_mode;
SET sql_mode = 'ONLY_FULL_GROUP_BY';
SELECT name, test, score,
AVG(score) OVER (PARTITION BY test) AS average_by_test
FROM t1;
FROM t1
ORDER BY test, name;
name test score average_by_test
Chun SQL 75 65.2500
Chun Tuning 73 68.7500
Esben SQL 43 65.2500
Esben Tuning 31 68.7500
Kaolin SQL 56 65.2500
Kaolin Tuning 88 68.7500
Tatiana SQL 87 65.2500
Chun Tuning 73 68.7500
Esben Tuning 31 68.7500
Kaolin Tuning 88 68.7500
Tatiana Tuning 83 68.7500
set @@sql_mode= @save_sql_mode;
SELECT name, test, score,
AVG(score) OVER (PARTITION BY test) AS average_by_test
FROM t1;
FROM t1
ORDER BY test, name;
name test score average_by_test
Chun SQL 75 65.2500
Chun Tuning 73 68.7500
Esben SQL 43 65.2500
Esben Tuning 31 68.7500
Kaolin SQL 56 65.2500
Kaolin Tuning 88 68.7500
Tatiana SQL 87 65.2500
Chun Tuning 73 68.7500
Esben Tuning 31 68.7500
Kaolin Tuning 88 68.7500
Tatiana Tuning 83 68.7500
drop table t1;
......@@ -68,17 +68,17 @@ first_value(pk) over (order by pk desc),
last_value(pk) over (order by pk desc)
from t1;
pk first_value(pk) over (order by pk desc) last_value(pk) over (order by pk desc)
1 11 1
2 11 2
3 11 3
4 11 4
5 11 5
6 11 6
7 11 7
8 11 8
9 11 9
10 11 10
11 11 11
10 11 10
9 11 9
8 11 8
7 11 7
6 11 6
5 11 5
4 11 4
3 11 3
2 11 2
1 11 1
select pk, a, b, c, d, e,
first_value(b) over (partition by a order by pk) as fst_b,
last_value(b) over (partition by a order by pk) as lst_b,
......
......@@ -14,49 +14,49 @@ insert into t1 values
( 7 , 2, 20),
( 9 , 4, 20),
(10 , 4, 20);
select pk, a, b,
select a,
percent_rank() over (order by a),
cume_dist() over (order by a)
from t1;
pk a b percent_rank() over (order by a) cume_dist() over (order by a)
1 0 10 0.0000000000 0.2000000000
2 0 10 0.0000000000 0.2000000000
3 1 10 0.2222222222 0.4000000000
4 1 10 0.2222222222 0.4000000000
8 2 10 0.4444444444 0.8000000000
5 2 20 0.4444444444 0.8000000000
6 2 20 0.4444444444 0.8000000000
7 2 20 0.4444444444 0.8000000000
9 4 20 0.8888888889 1.0000000000
10 4 20 0.8888888889 1.0000000000
select pk, a, b,
a percent_rank() over (order by a) cume_dist() over (order by a)
0 0.0000000000 0.2000000000
0 0.0000000000 0.2000000000
1 0.2222222222 0.4000000000
1 0.2222222222 0.4000000000
2 0.4444444444 0.8000000000
2 0.4444444444 0.8000000000
2 0.4444444444 0.8000000000
2 0.4444444444 0.8000000000
4 0.8888888889 1.0000000000
4 0.8888888889 1.0000000000
select pk,
percent_rank() over (order by pk),
cume_dist() over (order by pk)
from t1 order by pk;
pk a b percent_rank() over (order by pk) cume_dist() over (order by pk)
1 0 10 0.0000000000 0.1000000000
2 0 10 0.1111111111 0.2000000000
3 1 10 0.2222222222 0.3000000000
4 1 10 0.3333333333 0.4000000000
5 2 20 0.4444444444 0.5000000000
6 2 20 0.5555555556 0.6000000000
7 2 20 0.6666666667 0.7000000000
8 2 10 0.7777777778 0.8000000000
9 4 20 0.8888888889 0.9000000000
10 4 20 1.0000000000 1.0000000000
select pk, a, b,
pk percent_rank() over (order by pk) cume_dist() over (order by pk)
1 0.0000000000 0.1000000000
2 0.1111111111 0.2000000000
3 0.2222222222 0.3000000000
4 0.3333333333 0.4000000000
5 0.4444444444 0.5000000000
6 0.5555555556 0.6000000000
7 0.6666666667 0.7000000000
8 0.7777777778 0.8000000000
9 0.8888888889 0.9000000000
10 1.0000000000 1.0000000000
select a,
percent_rank() over (partition by a order by a),
cume_dist() over (partition by a order by a)
from t1;
pk a b percent_rank() over (partition by a order by a) cume_dist() over (partition by a order by a)
1 0 10 0.0000000000 1.0000000000
2 0 10 0.0000000000 1.0000000000
3 1 10 0.0000000000 1.0000000000
4 1 10 0.0000000000 1.0000000000
8 2 10 0.0000000000 1.0000000000
5 2 20 0.0000000000 1.0000000000
6 2 20 0.0000000000 1.0000000000
7 2 20 0.0000000000 1.0000000000
9 4 20 0.0000000000 1.0000000000
10 4 20 0.0000000000 1.0000000000
a percent_rank() over (partition by a order by a) cume_dist() over (partition by a order by a)
0 0.0000000000 1.0000000000
0 0.0000000000 1.0000000000
1 0.0000000000 1.0000000000
1 0.0000000000 1.0000000000
2 0.0000000000 1.0000000000
2 0.0000000000 1.0000000000
2 0.0000000000 1.0000000000
2 0.0000000000 1.0000000000
4 0.0000000000 1.0000000000
4 0.0000000000 1.0000000000
drop table t1;
......@@ -17,34 +17,34 @@ insert into t1 values
( 7 , 2, 20),
( 9 , 4, 20),
(10 , 4, 20);
select pk, a, b, rank() over (order by a) as rank,
select a, rank() over (order by a) as rank,
dense_rank() over (order by a) as dense_rank
from t1;
pk a b rank dense_rank
1 0 10 1 1
2 0 10 1 1
3 1 10 3 2
4 1 10 3 2
8 2 10 5 3
5 2 20 5 3
6 2 20 5 3
7 2 20 5 3
9 4 20 9 4
10 4 20 9 4
select pk, a, b, rank() over (partition by b order by a) as rank,
a rank dense_rank
0 1 1
0 1 1
1 3 2
1 3 2
2 5 3
2 5 3
2 5 3
2 5 3
4 9 4
4 9 4
select a, b, rank() over (partition by b order by a) as rank,
dense_rank() over (partition by b order by a) as dense_rank
from t1;
pk a b rank dense_rank
1 0 10 1 1
2 0 10 1 1
3 1 10 3 2
4 1 10 3 2
8 2 10 5 3
5 2 20 1 1
6 2 20 1 1
7 2 20 1 1
9 4 20 4 2
10 4 20 4 2
a b rank dense_rank
0 10 1 1
0 10 1 1
1 10 3 2
1 10 3 2
2 10 5 3
2 20 1 1
2 20 1 1
2 20 1 1
4 20 4 2
4 20 4 2
drop table t1;
#
# Test with null values in the table.
......@@ -59,46 +59,49 @@ insert into t2 values (2,'b');
insert into t2 values (-1,'');
select *, rank() over (order by s1) as rank,
dense_rank() over (order by s1) as dense_rank
from t2;
from t2
order by s1, s2;
s1 s2 rank dense_rank
1 a 5 3
NULL NULL 1 1
1 NULL 5 3
NULL a 1 1
NULL c 1 1
2 b 7 4
-1 4 2
1 NULL 5 3
1 a 5 3
2 b 7 4
select *, rank() over (partition by s2 order by s1) as rank,
dense_rank() over (partition by s2 order by s1) as dense_rank
from t2;
from t2
order by s1, s2;
s1 s2 rank dense_rank
1 a 2 2
NULL NULL 1 1
1 NULL 2 2
NULL a 1 1
NULL c 1 1
2 b 1 1
-1 1 1
1 NULL 2 2
1 a 2 2
2 b 1 1
select *, rank() over (order by s2) as rank,
dense_rank() over (order by s2) as dense_rank
from t2;
from t2
order by s2, s1;
s1 s2 rank dense_rank
1 a 4 3
NULL NULL 1 1
1 NULL 1 1
-1 3 2
NULL a 4 3
NULL c 7 5
1 a 4 3
2 b 6 4
-1 3 2
NULL c 7 5
select *, rank() over (partition by s1 order by s2) as rank,
dense_rank() over (partition by s1 order by s2) as dense_rank
from t2;
s1 s2 rank dense_rank
1 a 2 2
NULL NULL 1 1
1 NULL 1 1
NULL a 2 2
NULL c 3 3
2 b 1 1
-1 1 1
1 NULL 1 1
1 a 2 2
2 b 1 1
drop table t2;
......@@ -58,7 +58,8 @@ select
pk, a, b,
row_number() over (order by a),
row_number() over (order by b)
from t1;
from t1
order by b;
drop table t1;
......@@ -391,7 +392,6 @@ insert into t3 values
(6, 2);
select
pk,
val,
count(val) over (order by val
range between current row and
......@@ -404,7 +404,6 @@ insert into t3 values
(8, 3);
select
pk,
val,
count(val) over (order by val
range between current row and
......@@ -444,7 +443,6 @@ insert into t4 values
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -458,7 +456,6 @@ from t4;
--echo #
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -469,7 +466,6 @@ from t4;
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -480,7 +476,6 @@ from t4;
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
......@@ -723,7 +718,8 @@ select
count(b) over (order by a
range between 2 preceding
and 2 following) as CNT
from t1;
from t1
order by a, pk;
drop table t1;
--echo #
......@@ -1023,6 +1019,7 @@ insert into t1 values
--echo # Check using counters
flush status;
--sorted_result
select
rank() over (partition by c order by a),
rank() over (partition by c order by b)
......@@ -1030,6 +1027,7 @@ from t1;
show status like '%sort%';
flush status;
--sorted_result
select
rank() over (partition by c order by a),
rank() over (partition by c order by a)
......@@ -1101,6 +1099,7 @@ insert into t1 values
(2,2),
(3,1);
--sorted_result
select
a, b,
rank() over (order by a), rank() over (order by b),
......@@ -1192,6 +1191,7 @@ insert into t1 values (4,'a');
insert into t1 values (2,'b');
insert into t1 values (-1,'');
--sorted_result
select
*,
ROW_NUMBER() OVER (order by s1),
......@@ -1267,7 +1267,7 @@ from t1;
drop table t1;
--echo #
--echo # MDEV-10874: two window functions with ccompatible sorting
--echo # MDEV-10874: two window functions with compatible sorting
--echo #
create table t1 (
......@@ -2110,10 +2110,12 @@ SET sql_mode = 'ONLY_FULL_GROUP_BY';
SELECT name, test, score,
AVG(score) OVER (PARTITION BY test) AS average_by_test
FROM t1;
FROM t1
ORDER BY test, name;
set @@sql_mode= @save_sql_mode;
SELECT name, test, score,
AVG(score) OVER (PARTITION BY test) AS average_by_test
FROM t1;
FROM t1
ORDER BY test, name;
drop table t1;
......@@ -17,17 +17,17 @@ insert into t1 values
( 9 , 4, 20),
(10 , 4, 20);
select pk, a, b,
select a,
percent_rank() over (order by a),
cume_dist() over (order by a)
from t1;
select pk, a, b,
select pk,
percent_rank() over (order by pk),
cume_dist() over (order by pk)
from t1 order by pk;
select pk, a, b,
select a,
percent_rank() over (partition by a order by a),
cume_dist() over (partition by a order by a)
from t1;
......
......@@ -20,11 +20,11 @@ insert into t1 values
( 9 , 4, 20),
(10 , 4, 20);
select pk, a, b, rank() over (order by a) as rank,
dense_rank() over (order by a) as dense_rank
select a, rank() over (order by a) as rank,
dense_rank() over (order by a) as dense_rank
from t1;
select pk, a, b, rank() over (partition by b order by a) as rank,
dense_rank() over (partition by b order by a) as dense_rank
select a, b, rank() over (partition by b order by a) as rank,
dense_rank() over (partition by b order by a) as dense_rank
from t1;
drop table t1;
......@@ -44,13 +44,16 @@ insert into t2 values (-1,'');
select *, rank() over (order by s1) as rank,
dense_rank() over (order by s1) as dense_rank
from t2;
from t2
order by s1, s2;
select *, rank() over (partition by s2 order by s1) as rank,
dense_rank() over (partition by s2 order by s1) as dense_rank
from t2;
from t2
order by s1, s2;
select *, rank() over (order by s2) as rank,
dense_rank() over (order by s2) as dense_rank
from t2;
from t2
order by s2, s1;
select *, rank() over (partition by s1 order by s2) as rank,
dense_rank() over (partition by s1 order by s2) as dense_rank
from t2;
......
......@@ -80,9 +80,11 @@ select std(b) over (order by a rows between current row and 0 following)
from t2;
--echo # Only peers frame.
--sorted_result
select a, b, std(b) over (order by a range between 0 preceding and 0 preceding)
from t2;
--sorted_result
select a, b, std(b) over (order by a range between 0 preceding and current row)
from t2;
......@@ -90,9 +92,11 @@ from t2;
select a, b, std(b) over (order by a range between current row and 0 preceding)
from t2;
--sorted_result
select a, b, std(b) over (order by a range between current row and 0 following)
from t2;
--sorted_result
select a, b, std(b) over (order by a range between 0 following and 0 following)
from t2;
......
......@@ -353,6 +353,15 @@ int init_slave_io_cache(IO_CACHE *master, IO_CACHE *slave)
void end_slave_io_cache(IO_CACHE *cache)
{
/* Remove the cache from the next_file_user circular linked list. */
if (cache->next_file_user != cache)
{
IO_CACHE *p= cache->next_file_user;
while (p->next_file_user != cache)
p= p->next_file_user;
p->next_file_user= cache->next_file_user;
}
my_free(cache->buffer);
}
......
......@@ -26649,9 +26649,10 @@ AGGR_OP::end_send()
// Update ref array
join_tab->join->set_items_ref_array(*join_tab->ref_array);
bool keep_last_filesort_result = join_tab->filesort ? false : true;
if (join_tab->window_funcs_step)
{
if (join_tab->window_funcs_step->exec(join))
if (join_tab->window_funcs_step->exec(join, keep_last_filesort_result))
return NESTED_LOOP_ERROR;
}
......@@ -26705,6 +26706,12 @@ AGGR_OP::end_send()
}
}
if (keep_last_filesort_result)
{
delete join_tab->filesort_result;
join_tab->filesort_result= NULL;
}
// Finish rnd scn after sending records
if (join_tab->table->file->inited)
join_tab->table->file->ha_rnd_end();
......
......@@ -2751,7 +2751,7 @@ bool Window_func_runner::exec(THD *thd, TABLE *tbl, SORT_INFO *filesort_result)
}
bool Window_funcs_sort::exec(JOIN *join)
bool Window_funcs_sort::exec(JOIN *join, bool keep_filesort_result)
{
THD *thd= join->thd;
JOIN_TAB *join_tab= join->join_tab + join->total_join_tab_cnt();
......@@ -2766,8 +2766,11 @@ bool Window_funcs_sort::exec(JOIN *join)
bool is_error= runner.exec(thd, tbl, filesort_result);
delete join_tab->filesort_result;
join_tab->filesort_result= NULL;
if (!keep_filesort_result)
{
delete join_tab->filesort_result;
join_tab->filesort_result= NULL;
}
return is_error;
}
......@@ -2876,14 +2879,18 @@ bool Window_funcs_computation::setup(THD *thd,
}
bool Window_funcs_computation::exec(JOIN *join)
bool Window_funcs_computation::exec(JOIN *join, bool keep_last_filesort_result)
{
List_iterator<Window_funcs_sort> it(win_func_sorts);
Window_funcs_sort *srt;
uint counter= 0; /* Count how many sorts we've executed. */
/* Execute each sort */
while ((srt = it++))
{
if (srt->exec(join))
counter++;
bool keep_filesort_result= keep_last_filesort_result &&
counter == win_func_sorts.elements;
if (srt->exec(join, keep_filesort_result))
return true;
}
return false;
......
......@@ -195,7 +195,7 @@ class Window_funcs_sort : public Sql_alloc
public:
bool setup(THD *thd, SQL_SELECT *sel, List_iterator<Item_window_func> &it,
st_join_table *join_tab);
bool exec(JOIN *join);
bool exec(JOIN *join, bool keep_filesort_result);
void cleanup() { delete filesort; }
friend class Window_funcs_computation;
......@@ -225,7 +225,7 @@ class Window_funcs_computation : public Sql_alloc
List<Window_funcs_sort> win_func_sorts;
public:
bool setup(THD *thd, List<Item_window_func> *window_funcs, st_join_table *tab);
bool exec(JOIN *join);
bool exec(JOIN *join, bool keep_last_filesort_result);
Explain_aggr_window_funcs *save_explain_plan(MEM_ROOT *mem_root, bool is_analyze);
void cleanup();
......
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