sqlite/test/window1.test

357 lines
9.0 KiB
Plaintext
Raw Normal View History

# 2018 May 8
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
#
# May you do good and not evil.
# May you find forgiveness for yourself and forgive others.
# May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix window1
do_execsql_test 1.0 {
CREATE TABLE t1(a, b, c, d);
INSERT INTO t1 VALUES(1, 2, 3, 4);
INSERT INTO t1 VALUES(5, 6, 7, 8);
INSERT INTO t1 VALUES(9, 10, 11, 12);
}
do_execsql_test 1.1 {
SELECT sum(b) OVER () FROM t1
} {18 18 18}
do_execsql_test 1.2 {
SELECT a, sum(b) OVER () FROM t1
} {1 18 5 18 9 18}
do_execsql_test 1.3 {
SELECT a, 4 + sum(b) OVER () FROM t1
} {1 22 5 22 9 22}
do_execsql_test 1.4 {
SELECT a + 4 + sum(b) OVER () FROM t1
} {23 27 31}
do_execsql_test 1.5 {
SELECT a, sum(b) OVER (PARTITION BY c) FROM t1
} {1 2 5 6 9 10}
foreach {tn sql} {
1 "SELECT sum(b) OVER () FROM t1"
2 "SELECT sum(b) OVER (PARTITION BY c) FROM t1"
3 "SELECT sum(b) OVER (ORDER BY c) FROM t1"
4 "SELECT sum(b) OVER (PARTITION BY d ORDER BY c) FROM t1"
5 "SELECT sum(b) FILTER (WHERE a>0) OVER (PARTITION BY d ORDER BY c) FROM t1"
6 "SELECT sum(b) OVER (ORDER BY c RANGE UNBOUNDED PRECEDING) FROM t1"
7 "SELECT sum(b) OVER (ORDER BY c ROWS 45 PRECEDING) FROM t1"
8 "SELECT sum(b) OVER (ORDER BY c RANGE CURRENT ROW) FROM t1"
9 "SELECT sum(b) OVER (ORDER BY c RANGE BETWEEN UNBOUNDED PRECEDING
AND CURRENT ROW) FROM t1"
10 "SELECT sum(b) OVER (ORDER BY c ROWS BETWEEN UNBOUNDED PRECEDING
AND UNBOUNDED FOLLOWING) FROM t1"
} {
do_test 2.$tn { lindex [catchsql $sql] 0 } 0
}
foreach {tn sql} {
1 "SELECT * FROM t1 WHERE sum(b) OVER ()"
2 "SELECT * FROM t1 GROUP BY sum(b) OVER ()"
3 "SELECT * FROM t1 GROUP BY a HAVING sum(b) OVER ()"
} {
do_catchsql_test 3.$tn $sql {1 {misuse of window function sum()}}
}
do_execsql_test 4.0 {
CREATE TABLE t2(a, b, c);
INSERT INTO t2 VALUES(0, 0, 0);
INSERT INTO t2 VALUES(1, 1, 1);
INSERT INTO t2 VALUES(2, 0, 2);
INSERT INTO t2 VALUES(3, 1, 0);
INSERT INTO t2 VALUES(4, 0, 1);
INSERT INTO t2 VALUES(5, 1, 2);
INSERT INTO t2 VALUES(6, 0, 0);
}
do_execsql_test 4.1 {
SELECT a, sum(a) OVER (PARTITION BY b) FROM t2;
} {
0 12 2 12 4 12 6 12 1 9 3 9 5 9
}
do_execsql_test 4.2 {
SELECT a, sum(a) OVER (PARTITION BY b) FROM t2 ORDER BY a;
} {
0 12 1 9 2 12 3 9 4 12 5 9 6 12
}
do_execsql_test 4.3 {
SELECT a, sum(a) OVER () FROM t2 ORDER BY a;
} {
0 21 1 21 2 21 3 21 4 21 5 21 6 21
}
do_execsql_test 4.4 {
SELECT a, sum(a) OVER (ORDER BY a) FROM t2;
} {
0 0 1 1 2 3 3 6 4 10 5 15 6 21
}
do_execsql_test 4.5 {
SELECT a, sum(a) OVER (PARTITION BY b ORDER BY a) FROM t2 ORDER BY a
} {
0 0 1 1 2 2 3 4 4 6 5 9 6 12
}
do_execsql_test 4.6 {
SELECT a, sum(a) OVER (PARTITION BY c ORDER BY a) FROM t2 ORDER BY a
} {
0 0 1 1 2 2 3 3 4 5 5 7 6 9
}
do_execsql_test 4.7 {
SELECT a, sum(a) OVER (PARTITION BY b ORDER BY a DESC) FROM t2 ORDER BY a
} {
0 12 1 9 2 12 3 8 4 10 5 5 6 6
}
do_execsql_test 4.8 {
SELECT a,
sum(a) OVER (PARTITION BY b ORDER BY a DESC),
sum(a) OVER (PARTITION BY c ORDER BY a)
FROM t2 ORDER BY a
} {
0 12 0
1 9 1
2 12 2
3 8 3
4 10 5
5 5 7
6 6 9
}
do_execsql_test 4.9 {
SELECT a,
sum(a) OVER (ORDER BY a),
avg(a) OVER (ORDER BY a)
FROM t2 ORDER BY a
} {
0 0 0.0
1 1 0.5
2 3 1.0
3 6 1.5
4 10 2.0
5 15 2.5
6 21 3.0
}
do_execsql_test 4.10.1 {
SELECT a,
count() OVER (ORDER BY a DESC),
group_concat(a, '.') OVER (ORDER BY a DESC)
FROM t2 ORDER BY a DESC
} {
6 1 6
5 2 6.5
4 3 6.5.4
3 4 6.5.4.3
2 5 6.5.4.3.2
1 6 6.5.4.3.2.1
0 7 6.5.4.3.2.1.0
}
do_execsql_test 4.10.2 {
SELECT a,
count(*) OVER (ORDER BY a DESC),
group_concat(a, '.') OVER (ORDER BY a DESC)
FROM t2 ORDER BY a DESC
} {
6 1 6
5 2 6.5
4 3 6.5.4
3 4 6.5.4.3
2 5 6.5.4.3.2
1 6 6.5.4.3.2.1
0 7 6.5.4.3.2.1.0
}
do_catchsql_test 5.1 {
SELECT ntile(0) OVER (ORDER BY a) FROM t2;
} {1 {argument of ntile must be a positive integer}}
do_catchsql_test 5.2 {
SELECT ntile(-1) OVER (ORDER BY a) FROM t2;
} {1 {argument of ntile must be a positive integer}}
do_catchsql_test 5.3 {
SELECT ntile('zbc') OVER (ORDER BY a) FROM t2;
} {1 {argument of ntile must be a positive integer}}
do_execsql_test 5.4 {
CREATE TABLE t4(a, b);
SELECT ntile(1) OVER (ORDER BY a) FROM t4;
} {}
#-------------------------------------------------------------------------
reset_db
do_execsql_test 6.1 {
CREATE TABLE t1(x);
INSERT INTO t1 VALUES(7), (6), (5), (4), (3), (2), (1);
CREATE TABLE t2(x);
INSERT INTO t2 VALUES('b'), ('a');
SELECT x, count(*) OVER (ORDER BY x) FROM t1;
} {1 1 2 2 3 3 4 4 5 5 6 6 7 7}
do_execsql_test 6.2 {
SELECT * FROM t2, (SELECT x, count(*) OVER (ORDER BY x) FROM t1);
} {
b 1 1 b 2 2 b 3 3 b 4 4 b 5 5 b 6 6 b 7 7
a 1 1 a 2 2 a 3 3 a 4 4 a 5 5 a 6 6 a 7 7
}
do_catchsql_test 6.3 {
SELECT x, lag(x) FILTER (WHERE (x%2)=0) OVER w FROM t1
WINDOW w AS (ORDER BY x)
} {1 {FILTER clause may only be used with aggregate window functions}}
#-------------------------------------------------------------------------
# Attempt to use a window function as an aggregate. And other errors.
#
reset_db
do_execsql_test 7.0 {
CREATE TABLE t1(x, y);
INSERT INTO t1 VALUES(1, 2);
INSERT INTO t1 VALUES(3, 4);
INSERT INTO t1 VALUES(5, 6);
INSERT INTO t1 VALUES(7, 8);
INSERT INTO t1 VALUES(9, 10);
}
do_catchsql_test 7.1.1 {
SELECT nth_value(x, 1) FROM t1;
} {1 {misuse of window function nth_value()}}
do_catchsql_test 7.1.2 {
SELECT * FROM t1 WHERE nth_value(x, 1) OVER (ORDER BY y);
} {1 {misuse of window function nth_value()}}
do_catchsql_test 7.1.3 {
SELECT count(*) FROM t1 GROUP BY y HAVING nth_value(x, 1) OVER (ORDER BY y);
} {1 {misuse of window function nth_value()}}
do_catchsql_test 7.1.4 {
SELECT count(*) FROM t1 GROUP BY nth_value(x, 1) OVER (ORDER BY y);
} {1 {misuse of window function nth_value()}}
do_catchsql_test 7.1.5 {
SELECT count(*) FROM t1 LIMIT nth_value(x, 1) OVER (ORDER BY y);
} {1 {no such column: x}}
do_catchsql_test 7.1.6 {
SELECT trim(x) OVER (ORDER BY y) FROM t1;
} {1 {trim() may not be used as a window function}}
do_catchsql_test 7.1.7 {
SELECT max(x) OVER abc FROM t1 WINDOW def AS (ORDER BY y);
} {1 {no such window: abc}}
do_execsql_test 7.2 {
SELECT
lead(y) OVER win,
lead(y, 2) OVER win,
lead(y, 3, 'default') OVER win
FROM t1
WINDOW win AS (ORDER BY x)
} {
4 6 8 6 8 10 8 10 default 10 {} default {} {} default
}
do_execsql_test 7.3 {
SELECT row_number() OVER (ORDER BY x) FROM t1
} {1 2 3 4 5}
do_execsql_test 7.4 {
SELECT
row_number() OVER win,
lead(x) OVER win
FROM t1
WINDOW win AS (ORDER BY x ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)
} {1 3 2 5 3 7 4 9 5 {}}
#-------------------------------------------------------------------------
# Attempt to use a window function in a view.
#
do_execsql_test 8.0 {
CREATE TABLE t3(a, b, c);
WITH s(i) AS ( VALUES(1) UNION ALL SELECT i+1 FROM s WHERE i<6 )
INSERT INTO t3 SELECT i, i, i FROM s;
CREATE VIEW v1 AS SELECT
sum(b) OVER (ORDER BY c),
min(b) OVER (ORDER BY c),
max(b) OVER (ORDER BY c)
FROM t3;
CREATE VIEW v2 AS SELECT
sum(b) OVER win,
min(b) OVER win,
max(b) OVER win
FROM t3
WINDOW win AS (ORDER BY c);
}
do_execsql_test 8.1.1 {
SELECT * FROM v1
} {1 1 1 3 1 2 6 1 3 10 1 4 15 1 5 21 1 6}
do_execsql_test 8.1.2 {
SELECT * FROM v2
} {1 1 1 3 1 2 6 1 3 10 1 4 15 1 5 21 1 6}
db close
sqlite3 db test.db
do_execsql_test 8.2.1 {
SELECT * FROM v1
} {1 1 1 3 1 2 6 1 3 10 1 4 15 1 5 21 1 6}
do_execsql_test 8.2.2 {
SELECT * FROM v2
} {1 1 1 3 1 2 6 1 3 10 1 4 15 1 5 21 1 6}
#-------------------------------------------------------------------------
# Attempt to use a window function in a trigger.
#
do_execsql_test 9.0 {
CREATE TABLE t4(x, y);
INSERT INTO t4 VALUES(1, 'g');
INSERT INTO t4 VALUES(2, 'i');
INSERT INTO t4 VALUES(3, 'l');
INSERT INTO t4 VALUES(4, 'g');
INSERT INTO t4 VALUES(5, 'a');
CREATE TABLE t5(x, y, m);
CREATE TRIGGER t4i AFTER INSERT ON t4 BEGIN
DELETE FROM t5;
INSERT INTO t5
SELECT x, y, max(y) OVER xyz FROM t4
WINDOW xyz AS (PARTITION BY (x%2) ORDER BY x);
END;
}
do_execsql_test 9.1.1 {
SELECT x, y, max(y) OVER xyz FROM t4
WINDOW xyz AS (PARTITION BY (x%2) ORDER BY x) ORDER BY 1
} {1 g g 2 i i 3 l l 4 g i 5 a l}
do_execsql_test 9.1.2 {
INSERT INTO t4 VALUES(6, 'm');
SELECT x, y, max(y) OVER xyz FROM t4
WINDOW xyz AS (PARTITION BY (x%2) ORDER BY x) ORDER BY 1
} {1 g g 2 i i 3 l l 4 g i 5 a l 6 m m}
do_execsql_test 9.1.3 {
SELECT * FROM t5 ORDER BY 1
} {1 g g 2 i i 3 l l 4 g i 5 a l 6 m m}
finish_test