1
0
mirror of https://github.com/MariaDB/server.git synced 2025-12-10 19:44:09 +03:00
Files
mariadb/mysql-test/t/win.test
Sergei Petrunia ce8a0d8e19 MDEV-9676: RANGE-type frames for window functions
- Handle ORDER BY DESC in window definitions.
- Fix an issue in Frame_range_current_row_top
2016-03-14 14:13:59 +03:00

640 lines
13 KiB
Plaintext

#
# Window Functions Tests
#
--disable_warnings
drop table if exists t1,t2;
--enable_warnings
--echo # ########################################################################
--echo # # Parser tests
--echo # ########################################################################
--echo #
--echo # Check what happens when one attempts to use window function without OVER clause
create table t1 (a int, b int);
insert into t1 values (1,1),(2,2);
--error ER_PARSE_ERROR
select row_number() from t1;
--error ER_PARSE_ERROR
select rank() from t1;
--echo # Attempt to use window function in the WHERE clause
--error ER_INVALID_GROUP_FUNC_USE
select * from t1 where 1=rank() over (order by a);
--error ER_INVALID_GROUP_FUNC_USE
select * from t1 where 1>row_number() over (partition by b order by a);
drop table t1;
--echo # ########################################################################
--echo # # Functionality tests
--echo # ########################################################################
--echo #
--echo # Check if ROW_NUMBER() works in basic cases
create table t1(a int, b int, x char(32));
insert into t1 values (2, 10, 'xx');
insert into t1 values (2, 10, 'zz');
insert into t1 values (2, 20, 'yy');
insert into t1 values (3, 10, 'xxx');
insert into t1 values (3, 20, 'vvv');
--sorted_result
select a, row_number() over (partition by a order by b) from t1;
select a, b, x, row_number() over (partition by a order by x) from t1;
drop table t1;
create table t1 (pk int primary key, a int, b int);
insert into t1 values
(1, 10, 22),
(2, 11, 21),
(3, 12, 20),
(4, 13, 19),
(5, 14, 18);
select
pk, a, b,
row_number() over (order by a),
row_number() over (order by b)
from t1;
drop table t1;
--echo #
--echo # Try RANK() function
--echo #
create table t2 (
pk int primary key,
a int
);
insert into t2 values
( 1 , 0),
( 2 , 0),
( 3 , 1),
( 4 , 1),
( 8 , 2),
( 5 , 2),
( 6 , 2),
( 7 , 2),
( 9 , 4),
(10 , 4);
select pk, a, rank() over (order by a) from t2;
select pk, a, rank() over (order by a desc) from t2;
drop table t2;
--echo #
--echo # Try DENSE_RANK() function
--echo #
create table t3 (
pk int primary key,
a int,
b int
);
insert into t3 values
( 1 , 0, 10),
( 2 , 0, 10),
( 3 , 1, 10),
( 4 , 1, 10),
( 8 , 2, 10),
( 5 , 2, 20),
( 6 , 2, 20),
( 7 , 2, 20),
( 9 , 4, 20),
(10 , 4, 20);
select pk, a, b, rank() over (order by a), dense_rank() over (order by a) from t3;
select pk, a, b, rank() over (partition by b order by a), dense_rank() over (partition by b order by a) from t3;
drop table t3;
--echo #
--echo # Try Aggregates as window functions. With frames.
--echo #
create table t0 (a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t1 (pk int, c int);
insert into t1 select a+1,1 from t0;
update t1 set c=2 where pk not in (1,2,3,4);
select * from t1;
select
pk, c,
count(*) over (partition by c order by pk
rows between 2 preceding and 2 following) as CNT
from t1;
select
pk, c,
count(*) over (partition by c order by pk
rows between 1 preceding and 2 following) as CNT
from t1;
select
pk, c,
count(*) over (partition by c order by pk
rows between 2 preceding and current row) as CNT
from t1;
select
pk,c,
count(*) over (partition by c order by pk rows
between 1 following and 2 following) as CNT
from t1;
select
pk,c,
count(*) over (partition by c order by pk rows
between 2 preceding and 1 preceding) as CNT
from t1;
select
pk, c,
count(*) over (partition by c order by pk
rows between current row and 1 following) as CNT
from t1;
--echo # Check ORDER BY DESC
select
pk, c,
count(*) over (partition by c order by pk desc
rows between 2 preceding and 2 following) as CNT
from t1;
drop table t0,t1;
--echo #
--echo # Resolution of window names
--echo #
create table t0 (a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t1 (pk int, c int);
insert into t1 select a+1,1 from t0;
update t1 set c=2 where pk not in (1,2,3,4);
select * from t1;
select
pk, c,
count(*) over w1 as CNT
from t1
window w1 as (partition by c order by pk
rows between 2 preceding and 2 following);
select
pk, c,
count(*) over (w1 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c order by pk);
select
pk, c,
count(*) over (w1 order by pk rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c);
select
pk, c,
count(*) over (w2 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c), w2 as (w1 order by pk);
select
pk, c,
count(*) over w3 as CNT
from t1
window
w1 as (partition by c),
w2 as (w1 order by pk),
w3 as (w2 rows between 2 preceding and 2 following);
--error ER_WRONG_WINDOW_SPEC_NAME
select
pk, c,
count(*) over w as CNT
from t1
window w1 as (partition by c order by pk
rows between 2 preceding and 2 following);
--error ER_DUP_WINDOW_NAME
select
pk, c,
count(*) over (w2 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c), w1 as (order by pk);
--error ER_WRONG_WINDOW_SPEC_NAME
select
pk, c,
count(*) over (w2 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c), w2 as (w partition by c order by pk);
--error ER_PARTITION_LIST_IN_REFERENCING_WINDOW_SPEC
select
pk, c,
count(*) over (w2 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c), w2 as (w1 partition by c order by pk);
--error ER_ORDER_LIST_IN_REFERENCING_WINDOW_SPEC
select
pk, c,
count(*) over (w2 rows between 2 preceding and 2 following) as CNT
from t1
window w1 as (partition by c order by pk), w2 as (w1 order by pk);
--error ER_WINDOW_FRAME_IN_REFERENCED_WINDOW_SPEC
select
pk, c,
count(*) over w3 as CNT
from t1
window
w1 as (partition by c),
w2 as (w1 order by pk rows between 3 preceding and 2 following),
w3 as (w2 rows between 2 preceding and 2 following);
--error ER_BAD_COMBINATION_OF_WINDOW_FRAME_BOUND_SPECS
select
pk, c,
count(*) over w1 as CNT
from t1
window w1 as (partition by c order by pk
rows between unbounded following and 2 following);
--error ER_BAD_COMBINATION_OF_WINDOW_FRAME_BOUND_SPECS
select
pk, c,
count(*) over (w1 rows between 2 preceding and unbounded preceding) as CNT
from t1
window w1 as (partition by c order by pk);
--error ER_BAD_COMBINATION_OF_WINDOW_FRAME_BOUND_SPECS
select
pk, c,
count(*) over (w1 order by pk rows between current row and 2 preceding) as CNT
from t1
window w1 as (partition by c);
--error ER_BAD_COMBINATION_OF_WINDOW_FRAME_BOUND_SPECS
select
pk, c,
count(*) over (w2 rows between 2 following and current row) as CNT
from t1
window w1 as (partition by c), w2 as (w1 order by pk);
drop table t0,t1;
--echo #
--echo # MDEV-9634: Window function produces incorrect value
--echo #
create table t0 (a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2 (part_id int, pk int, a int);
insert into t2 select
if(a<5, 0, 1), a, if(a<5, NULL, 1) from t0;
select * from t2;
select
part_id, pk, a,
count(a) over (partition by part_id order by pk
rows between 1 preceding and 1 following) as CNT
from t2;
drop table t0, t2;
--echo #
--echo # RANGE-type bounds
--echo #
create table t3 (
pk int,
val int
);
insert into t3 values
(0, 1),
(1, 1),
(2, 1),
(3, 2),
(4, 2),
(5, 2),
(6, 2);
select
pk,
val,
count(val) over (order by val
range between current row and
current row)
as CNT
from t3;
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;
drop table t3;
--echo # Now, check with PARTITION BY
create table t4 (
part_id int,
pk int,
val int
);
insert into t4 values
(1234, 100, 1),
(1234, 101, 1),
(1234, 102, 1),
(1234, 103, 2),
(1234, 104, 2),
(1234, 105, 2),
(1234, 106, 2),
(1234, 107, 3),
(1234, 108, 3),
(5678, 200, 1),
(5678, 201, 1),
(5678, 202, 1),
(5678, 203, 2),
(5678, 204, 2),
(5678, 205, 2),
(5678, 206, 2),
(5678, 207, 3),
(5678, 208, 3);
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
range between current row and
current row)
as CNT
from t4;
--echo #
--echo # Try RANGE UNBOUNDED PRECEDING | FOLLOWING
--echo #
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
range between unbounded preceding and
current row)
as CNT
from t4;
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
range between current row and
unbounded following)
as CNT
from t4;
select
part_id,
pk,
val,
count(val) over (partition by part_id
order by val
range between unbounded preceding and
unbounded following)
as CNT
from t4;
drop table t4;
--echo #
--echo # MDEV-9695: Wrong window frame when using RANGE BETWEEN N FOLLOWING AND PRECEDING
--echo #
create table t1 (pk int, a int, b int);
insert into t1 values
( 1 , 0, 1),
( 2 , 0, 2),
( 3 , 1, 4),
( 4 , 1, 8),
( 5 , 2, 32),
( 6 , 2, 64),
( 7 , 2, 128),
( 8 , 2, 16);
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING) as bit_or
from t1;
--echo # Extra ROWS n PRECEDING tests
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING) as bit_or
from t1;
drop table t1;
create table t2 (
pk int,
a int,
b int
);
insert into t2 values
( 1, 0, 1),
( 2, 0, 2),
( 3, 0, 4),
( 4, 0, 8),
( 5, 1, 16),
( 6, 1, 32),
( 7, 1, 64),
( 8, 1, 128),
( 9, 2, 256),
(10, 2, 512),
(11, 2, 1024),
(12, 2, 2048);
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 PRECEDING) as bit_or
from t2;
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN 2 PRECEDING AND 2 PRECEDING) as bit_or
from t2;
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN 2 PRECEDING AND 1 PRECEDING) as bit_or
from t2;
--echo # Check CURRENT ROW
select pk, a, b,
bit_or(b) over (partition by a order by pk ROWS BETWEEN CURRENT ROW AND CURRENT ROW) as bit_or
from t2;
drop table t2;
--echo #
--echo # Try RANGE PRECEDING|FOLLWING n
--echo #
create table t1 (
part_id int,
pk int,
a int
);
insert into t1 values
(10, 1, 1),
(10, 2, 2),
(10, 3, 4),
(10, 4, 8),
(10, 5,26),
(10, 6,27),
(10, 7,40),
(10, 8,71),
(10, 9,72);
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 FOLLOWING) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a DESC
RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 FOLLOWING) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 1 FOLLOWING) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 PRECEDING) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a DESC
RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 PRECEDING) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 1 PRECEDING) as cnt
from t1;
# Try bottom bound
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN 1 PRECEDING
AND CURRENT ROW) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a DESC
RANGE BETWEEN 1 PRECEDING
AND CURRENT ROW) as cnt
from t1;
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN 1 FOLLOWING
AND 3 FOLLOWING) as cnt
from t1;
--echo # Try CURRENT ROW with[out] DESC
select
pk, a,
count(a) over (ORDER BY a
RANGE BETWEEN CURRENT ROW
AND 1 FOLLOWING) as cnt
from t1;
select
pk, a,
count(a) over (order by a desc
range between current row
and 1 following) as cnt
from t1;
# Try with partitions
insert into t1 select 22, pk, a from t1;
select
part_id, pk, a,
count(a) over (PARTITION BY part_id
ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 10 FOLLOWING) as cnt
from t1;
select
pk, a,
count(a) over (PARTITION BY part_id
ORDER BY a
RANGE BETWEEN UNBOUNDED PRECEDING
AND 1 PRECEDING) as cnt
from t1;
drop table t1;
--echo # Try a RANGE frame over non-integer datatype:
create table t1 (
col1 int,
a decimal(5,3)
);
insert into t1 values (1, 0.45);
insert into t1 values (1, 0.5);
insert into t1 values (1, 0.55);
insert into t1 values (1, 1.21);
insert into t1 values (1, 1.22);
insert into t1 values (1, 3.33);
select
a,
count(col1) over (order by a
range between 0.1 preceding
and 0.1 following)
from t1;
drop table t1;