xref: /sqlite-3.40.0/test/window6.test (revision 7d44b22d)
159ff4251Sdan# 2018 May 8
259ff4251Sdan#
359ff4251Sdan# The author disclaims copyright to this source code.  In place of
459ff4251Sdan# a legal notice, here is a blessing:
559ff4251Sdan#
659ff4251Sdan#    May you do good and not evil.
759ff4251Sdan#    May you find forgiveness for yourself and forgive others.
859ff4251Sdan#    May you share freely, never taking more than you give.
959ff4251Sdan#
1059ff4251Sdan#***********************************************************************
1159ff4251Sdan# This file implements regression tests for SQLite library. Specifically,
1259ff4251Sdan# it tests the sqlite3_create_window_function() API.
1359ff4251Sdan#
1459ff4251Sdan
1559ff4251Sdanset testdir [file dirname $argv0]
1659ff4251Sdansource $testdir/tester.tcl
1759ff4251Sdanset testprefix window6
1859ff4251Sdan
1959ff4251Sdanifcapable !windowfunc {
2059ff4251Sdan  finish_test
2159ff4251Sdan  return
2259ff4251Sdan}
2359ff4251Sdan
2459ff4251Sdanset setup {
256e2210e0Sdan  CREATE TABLE %t1(%x, %y %typename);
2659ff4251Sdan  INSERT INTO %t1 VALUES(1, 'a');
2759ff4251Sdan  INSERT INTO %t1 VALUES(2, 'b');
2859ff4251Sdan  INSERT INTO %t1 VALUES(3, 'c');
2959ff4251Sdan  INSERT INTO %t1 VALUES(4, 'd');
3059ff4251Sdan  INSERT INTO %t1 VALUES(5, 'e');
3159ff4251Sdan}
3259ff4251Sdan
3359ff4251Sdanforeach {tn vars} {
3459ff4251Sdan  1 {}
3559ff4251Sdan  2 { set A(%t1) over }
366e2210e0Sdan  3 { set A(%x)  over }
3759ff4251Sdan  4 {
3859ff4251Sdan    set A(%alias)   over
396e2210e0Sdan    set A(%x)       following
406e2210e0Sdan    set A(%y)       over
4159ff4251Sdan  }
4259ff4251Sdan  5 {
4359ff4251Sdan    set A(%t1)      over
446e2210e0Sdan    set A(%x)       following
456e2210e0Sdan    set A(%y)       preceding
4659ff4251Sdan    set A(%w)       current
4759ff4251Sdan    set A(%alias)   filter
4859ff4251Sdan    set A(%typename)  window
4959ff4251Sdan  }
5059ff4251Sdan
5159ff4251Sdan  6 {
526e2210e0Sdan    set A(%x)       window
5359ff4251Sdan  }
5459ff4251Sdan} {
5559ff4251Sdan  set A(%t1)    t1
566e2210e0Sdan  set A(%x)     x
576e2210e0Sdan  set A(%y)     y
5859ff4251Sdan  set A(%w)     w
5959ff4251Sdan  set A(%alias) alias
6059ff4251Sdan  set A(%typename) integer
6159ff4251Sdan  eval $vars
6259ff4251Sdan
6359ff4251Sdan  set MAP [array get A]
6459ff4251Sdan  set setup_sql [string map $MAP $setup]
6559ff4251Sdan  reset_db
6659ff4251Sdan  execsql $setup_sql
6759ff4251Sdan
6859ff4251Sdan  do_execsql_test 1.$tn.1 [string map $MAP {
696e2210e0Sdan    SELECT group_concat(%x, '.') OVER (ORDER BY %y) FROM %t1
7059ff4251Sdan  }] {1 1.2 1.2.3 1.2.3.4 1.2.3.4.5}
7159ff4251Sdan
7259ff4251Sdan  do_execsql_test 1.$tn.2 [string map $MAP {
736e2210e0Sdan    SELECT sum(%x) OVER %w FROM %t1 WINDOW %w AS (ORDER BY %y)
7459ff4251Sdan  }] {1 3 6 10 15}
7559ff4251Sdan
7659ff4251Sdan  do_execsql_test 1.$tn.3 [string map $MAP {
776e2210e0Sdan    SELECT sum(%alias.%x) OVER %w FROM %t1 %alias WINDOW %w AS (ORDER BY %y)
7859ff4251Sdan  }] {1 3 6 10 15}
7959ff4251Sdan
8059ff4251Sdan  do_execsql_test 1.$tn.4 [string map $MAP {
816e2210e0Sdan    SELECT sum(%x) %alias FROM %t1
8259ff4251Sdan  }] {15}
8359ff4251Sdan}
8459ff4251Sdan
8559ff4251Sdan
8659ff4251Sdanproc winproc {args} { return "window: $args" }
8759ff4251Sdandb func window winproc
8859ff4251Sdando_execsql_test 2.0 {
8959ff4251Sdan  SELECT window('hello world');
9059ff4251Sdan} {{window: {hello world}}}
9159ff4251Sdan
9259ff4251Sdanproc wincmp {a b} { string compare $b $a }
9359ff4251Sdandb collate window wincmp
9459ff4251Sdando_execsql_test 3.0 {
9559ff4251Sdan  CREATE TABLE window(x COLLATE window);
9659ff4251Sdan  INSERT INTO window VALUES('bob'), ('alice'), ('cate');
9759ff4251Sdan  SELECT * FROM window ORDER BY x COLLATE window;
9859ff4251Sdan} {cate bob alice}
9959ff4251Sdando_execsql_test 3.1 {
10059ff4251Sdan  DROP TABLE window;
10159ff4251Sdan  CREATE TABLE x1(x);
10259ff4251Sdan  INSERT INTO x1 VALUES('bob'), ('alice'), ('cate');
10359ff4251Sdan  CREATE INDEX window ON x1(x COLLATE window);
10459ff4251Sdan  SELECT * FROM x1 ORDER BY x COLLATE window;
10559ff4251Sdan} {cate bob alice}
10659ff4251Sdan
10759ff4251Sdan
10859ff4251Sdando_execsql_test 4.0 { CREATE TABLE t4(x, y); }
10959ff4251Sdan
11059ff4251Sdan# do_execsql_test 4.1 { PRAGMA parser_trace = 1 }
11159ff4251Sdando_execsql_test 4.1 {
11259ff4251Sdan  SELECT * FROM t4 window, t4;
11359ff4251Sdan}
11459ff4251Sdan
1156e2210e0Sdan#-------------------------------------------------------------------------
1166e2210e0Sdanreset_db
1176e2210e0Sdan
1186e2210e0Sdando_execsql_test 5.0 {
1196e2210e0Sdan  CREATE TABLE over(x, over);
1206e2210e0Sdan  CREATE TABLE window(x, window);
1216e2210e0Sdan  INSERT INTO over VALUES(1, 2), (3, 4), (5, 6);
1226e2210e0Sdan  INSERT INTO window VALUES(1, 2), (3, 4), (5, 6);
1236e2210e0Sdan  SELECT sum(x) over FROM over
1246e2210e0Sdan} {9}
1256e2210e0Sdan
1266e2210e0Sdando_execsql_test 5.1 {
1276e2210e0Sdan  SELECT sum(x) over over FROM over WINDOW over AS ()
1286e2210e0Sdan} {9 9 9}
1296e2210e0Sdan
1306e2210e0Sdando_execsql_test 5.2 {
1316e2210e0Sdan  SELECT sum(over) over over over FROM over over WINDOW over AS (ORDER BY over)
1326e2210e0Sdan} {2 6 12}
1336e2210e0Sdan
1346e2210e0Sdando_execsql_test 5.3 {
1356e2210e0Sdan  SELECT sum(over) over over over FROM over over WINDOW over AS (ORDER BY over);
1366e2210e0Sdan} {2 6 12}
1376e2210e0Sdan
1386e2210e0Sdando_execsql_test 5.4 {
1396e2210e0Sdan  SELECT sum(window) OVER window window FROM window window window window AS (ORDER BY window);
1406e2210e0Sdan} {2 6 12}
14159ff4251Sdan
1427262ca94Sdando_execsql_test 5.5 {
1437262ca94Sdan  SELECT count(*) OVER win FROM over
1447262ca94Sdan  WINDOW win AS (ORDER BY x ROWS BETWEEN +2 FOLLOWING AND +3 FOLLOWING)
1457262ca94Sdan} {1 0 0}
1467262ca94Sdan
1477262ca94Sdan#-------------------------------------------------------------------------
1487262ca94Sdan#
1496b4b8820Sdan
150ca9a5fafSdrhifcapable !icu {
151*7d44b22dSdrh  sqlite3_db_config db SQLITE_DBCONFIG_DQS_DML 1
1527262ca94Sdan  do_execsql_test 6.0 {
1536b4b8820Sdan    SELECT LIKE('!', '', '!') x WHERE x;
1546b4b8820Sdan  } {}
1556b4b8820Sdan  do_execsql_test 6.1 {
1567262ca94Sdan    SELECT LIKE("!","","!")""WHeRE"";
1576b4b8820Sdan  } {}
1586b4b8820Sdan  do_catchsql_test 6.2 {
1597262ca94Sdan    SELECT LIKE("!","","!")""window"";
1607262ca94Sdan  } {1 {near "window": syntax error}}
161ca9a5fafSdrh}
1627262ca94Sdan
1636b4b8820Sdanreset_db
1646b4b8820Sdando_execsql_test 7.0 {
1656b4b8820Sdan  CREATE TABLE t1(x TEXT);
1666b4b8820Sdan  CREATE INDEX i1 ON t1(x COLLATE nocase);
1676b4b8820Sdan  INSERT INTO t1 VALUES('');
1686b4b8820Sdan}
1696b4b8820Sdan
170ca9a5fafSdrhifcapable !icu {
1716b4b8820Sdan  do_execsql_test 7.1 {
1726b4b8820Sdan    SELECT count(*) FROM t1 WHERE x LIKE '!' ESCAPE '!';
1736b4b8820Sdan  } {0}
174ca9a5fafSdrh}
1756b4b8820Sdan
176f607bec7Sdan#-------------------------------------------------------------------------
177f607bec7Sdan#
178f607bec7Sdando_execsql_test 8.0 {
179f607bec7Sdan  CREATE TABLE IF NOT EXISTS "sample" (
180f607bec7Sdan      "id" INTEGER NOT NULL PRIMARY KEY,
181f607bec7Sdan      "counter" INTEGER NOT NULL,
182f607bec7Sdan      "value" REAL NOT NULL
183f607bec7Sdan  );
184f607bec7Sdan
185f607bec7Sdan  INSERT INTO "sample" (counter, value)
186f607bec7Sdan  VALUES (1, 10.), (1, 20.), (2, 1.), (2, 3.), (3, 100.);
187f607bec7Sdan}
188f607bec7Sdan
189f607bec7Sdando_execsql_test 8.1 {
190f607bec7Sdan  SELECT "counter", "value", RANK() OVER w AS "rank"
191f607bec7Sdan  FROM "sample"
192f607bec7Sdan  WINDOW w AS (PARTITION BY "counter" ORDER BY "value" DESC)
193f607bec7Sdan  ORDER BY "counter", RANK() OVER w
194f607bec7Sdan} {
195f607bec7Sdan  1 20.0 1   1 10.0 2   2 3.0 1   2 1.0 2  3 100.0 1
196f607bec7Sdan}
1976b4b8820Sdan
198d736829eSdando_execsql_test 8.2 {
199d736829eSdan  SELECT "counter", "value", SUM("value") OVER
200d736829eSdan  (ORDER BY "id" ROWS 2 PRECEDING)
201d736829eSdan    FROM "sample"
202d736829eSdan  ORDER BY "id"
203d736829eSdan} {
204d736829eSdan  1 10.0 10.0   1 20.0 30.0   2 1.0 31.0   2 3.0 24.0   3 100.0 104.0
205d736829eSdan}
206d736829eSdan
207d736829eSdando_execsql_test 8.3 {
208d736829eSdan  SELECT SUM("value") OVER
209d736829eSdan  (ORDER BY "id" ROWS BETWEEN 2 PRECEDING AND CURRENT ROW)
210d736829eSdan    FROM "sample"
211d736829eSdan  ORDER BY "id"
212d736829eSdan} {
213d736829eSdan  10.0   30.0   31.0   24.0   104.0
214d736829eSdan}
215d736829eSdan
216683b0fffSdando_execsql_test 9.0 {
217683b0fffSdan  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
218683b0fffSdan  SELECT x, group_concat(x) OVER (ORDER BY x ROWS 2 PRECEDING)
219683b0fffSdan  FROM c;
220683b0fffSdan} {
221683b0fffSdan  1 1  2 1,2  3 1,2,3  4 2,3,4  5 3,4,5
222683b0fffSdan}
22372b9fdcfSdan#do_catchsql_test 9.1 {
22472b9fdcfSdan#  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
22572b9fdcfSdan#  SELECT x, group_concat(x) OVER (ORDER BY x RANGE 2 PRECEDING)
22672b9fdcfSdan#  FROM c;
22772b9fdcfSdan#} {1 {RANGE must use only UNBOUNDED or CURRENT ROW}}
22872b9fdcfSdan#
22972b9fdcfSdan#do_catchsql_test 9.2 {
23072b9fdcfSdan#  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
23172b9fdcfSdan#  SELECT x, group_concat(x) OVER (ORDER BY x RANGE BETWEEN UNBOUNDED PRECEDING AND 2 FOLLOWING)
23272b9fdcfSdan#  FROM c;
23372b9fdcfSdan#} {1 {RANGE must use only UNBOUNDED or CURRENT ROW}}
234683b0fffSdan
235e33f6e7cSdando_catchsql_test 9.3 {
236e33f6e7cSdan  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
237e33f6e7cSdan  SELECT count(DISTINCT x) OVER (ORDER BY x) FROM c;
238e33f6e7cSdan} {1 {DISTINCT is not supported for window functions}}
239e33f6e7cSdan
240287fa17bSdando_catchsql_test 9.4 {
241287fa17bSdan  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
242287fa17bSdan  SELECT count() OVER (ORDER BY x RANGE UNBOUNDED FOLLOWING) FROM c;
243287fa17bSdan} {1 {near "FOLLOWING": syntax error}}
244287fa17bSdan
245287fa17bSdando_catchsql_test 9.5 {
246287fa17bSdan  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
247287fa17bSdan  SELECT count() OVER (ORDER BY x RANGE BETWEEN UNBOUNDED FOLLOWING AND UNBOUNDED FOLLOWING) FROM c;
248287fa17bSdan} {1 {near "FOLLOWING": syntax error}}
249287fa17bSdan
250287fa17bSdando_catchsql_test 9.6 {
251287fa17bSdan  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
252287fa17bSdan  SELECT count() OVER (ORDER BY x RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED PRECEDING) FROM c;
253287fa17bSdan} {1 {near "PRECEDING": syntax error}}
254287fa17bSdan
2555d764ac9Sdanforeach {tn frame} {
2565d764ac9Sdan  1 "BETWEEN CURRENT ROW AND 4 PRECEDING"
2575d764ac9Sdan  2 "4 FOLLOWING"
2585d764ac9Sdan  3 "BETWEEN 4 FOLLOWING AND CURRENT ROW"
2595d764ac9Sdan  4 "BETWEEN 4 FOLLOWING AND 2 PRECEDING"
2605d764ac9Sdan} {
2615d764ac9Sdan  do_catchsql_test 9.7.$tn "
2625d764ac9Sdan    WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
2635d764ac9Sdan    SELECT count() OVER (
2645d764ac9Sdan        ORDER BY x ROWS $frame
2655d764ac9Sdan    ) FROM c;
26672b9fdcfSdan  " {1 {unsupported frame specification}}
2675d764ac9Sdan}
2685d764ac9Sdan
269e4984a2bSdrhdo_catchsql_test 9.8.1 {
270e4984a2bSdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
271e4984a2bSdrh  SELECT count() OVER (
272e4984a2bSdrh      ORDER BY x ROWS BETWEEN a PRECEDING AND 2 FOLLOWING
273e4984a2bSdrh  ) FROM c;
274e4984a2bSdrh} {1 {frame starting offset must be a non-negative integer}}
275e4984a2bSdrhdo_catchsql_test 9.8.2 {
276e4984a2bSdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
277e4984a2bSdrh  SELECT count() OVER (
278e4984a2bSdrh      ORDER BY x ROWS BETWEEN 2 PRECEDING AND a FOLLOWING
279e4984a2bSdrh  ) FROM c;
280e4984a2bSdrh} {1 {frame ending offset must be a non-negative integer}}
2817a606e1aSdan
282f5e8e313Sdando_execsql_test 10.0 {
283f5e8e313Sdan  WITH t1(a,b) AS (VALUES(1,2))
284f5e8e313Sdan  SELECT count() FILTER (where b<>5) OVER w1
285f5e8e313Sdan    FROM t1
286f5e8e313Sdan    WINDOW w1 AS (ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING);
287f5e8e313Sdan} {1}
288e4984a2bSdrh
289a1a7e112Sdanforeach {tn stmt} {
290a1a7e112Sdan  1 "SELECT nth_value(b, 0) OVER (ORDER BY a) FROM t1"
291a1a7e112Sdan  2 "SELECT nth_value(b, -1) OVER (ORDER BY a) FROM t1"
292a1a7e112Sdan  3 "SELECT nth_value(b, '4ab') OVER (ORDER BY a) FROM t1"
293a1a7e112Sdan  4 "SELECT nth_value(b, NULL) OVER (ORDER BY a) FROM t1"
294a1a7e112Sdan  5 "SELECT nth_value(b, 8.5) OVER (ORDER BY a) FROM t1"
295a1a7e112Sdan} {
296a1a7e112Sdan  do_catchsql_test 10.1.$tn "
297a1a7e112Sdan    WITH t1(a,b) AS ( VALUES(1, 2), (2, 3), (3, 4) )
298a1a7e112Sdan    $stmt
299a1a7e112Sdan  " {1 {second argument to nth_value must be a positive integer}}
300a1a7e112Sdan}
301a1a7e112Sdan
302a1a7e112Sdanforeach {tn stmt res} {
303a1a7e112Sdan  1 "SELECT nth_value(b, 1) OVER (ORDER BY a) FROM t1"         {2 2 2}
304a1a7e112Sdan  2 "SELECT nth_value(b, 2) OVER (ORDER BY a) FROM t1"         {{} 3 3}
305a1a7e112Sdan  3 "SELECT nth_value(b, '2') OVER (ORDER BY a) FROM t1"       {{} 3 3}
306a1a7e112Sdan  4 "SELECT nth_value(b, 2.0) OVER (ORDER BY a) FROM t1"       {{} 3 3}
307a1a7e112Sdan  5 "SELECT nth_value(b, '2.0') OVER (ORDER BY a) FROM t1"     {{} 3 3}
308a1a7e112Sdan  6 "SELECT nth_value(b, 10000000) OVER (ORDER BY a) FROM t1"  {{} {} {}}
309a1a7e112Sdan} {
310a1a7e112Sdan  do_execsql_test 10.2.$tn "
311a1a7e112Sdan    WITH t1(a,b) AS ( VALUES(1, 2), (2, 3), (3, 4) )
312a1a7e112Sdan    $stmt
313a1a7e112Sdan  " $res
314a1a7e112Sdan}
315a1a7e112Sdan
316b556f261Sdan
317b556f261Sdan#-------------------------------------------------------------------------
318b556f261Sdan#
319b556f261Sdanreset_db
320b556f261Sdando_execsql_test 11.0 {
321b556f261Sdan  CREATE TABLE t1(a INT);
322b556f261Sdan  INSERT INTO t1 VALUES(10),(15),(20),(20),(25),(30),(30),(50);
323b556f261Sdan  CREATE TABLE t3(x INT, y VARCHAR);
324b556f261Sdan  INSERT INTO t3(x,y) VALUES(10,'ten'),('15','fifteen'),(30,'thirty');
325b556f261Sdan}
326b556f261Sdan
327b556f261Sdando_execsql_test 11.1 {
328b556f261Sdan  SELECT a, (SELECT y FROM t3 WHERE x=a) FROM t1 ORDER BY a;
329b556f261Sdan} {
330b556f261Sdan  10 ten 15 fifteen 20 {} 20 {} 25 {} 30 thirty 30 thirty 50 {}
331b556f261Sdan}
332b556f261Sdan
333b556f261Sdando_execsql_test 11.2 {
334b556f261Sdan  SELECT a, (SELECT y FROM t3 WHERE x=a), sum(a) OVER (ORDER BY a)
335b556f261Sdan    FROM t1 ORDER BY a;
336b556f261Sdan} {
337b556f261Sdan  10 ten 10   15 fifteen 25   20 {} 65        20 {} 65
338b556f261Sdan  25 {} 90    30 thirty 150   30 thirty 150   50 {} 200
339b556f261Sdan}
340b556f261Sdan
341725b1cfcSdando_execsql_test 11.3.1 {
342725b1cfcSdan  SELECT a, sum(a) OVER win FROM t1
343725b1cfcSdan  WINDOW win AS (ORDER BY a ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)
344725b1cfcSdan} {
345725b1cfcSdan  10 10 15 25 20 45 20 65 25 90 30 120 30 150 50 200
346725b1cfcSdan}
347725b1cfcSdando_execsql_test 11.3.2 {
348725b1cfcSdan  SELECT a, sum(a) OVER win FROM t1
349725b1cfcSdan  WINDOW win AS (ORDER BY a ROWS BETWEEN UNBOUNDED PRECEDING AND 0 FOLLOWING)
350725b1cfcSdan} {
351725b1cfcSdan  10 10 15 25 20 45 20 65 25 90 30 120 30 150 50 200
352725b1cfcSdan}
353725b1cfcSdando_execsql_test 11.3.3 {
354725b1cfcSdan  SELECT a, sum(a) OVER win FROM t1
355725b1cfcSdan  WINDOW win AS (ORDER BY a ROWS BETWEEN UNBOUNDED PRECEDING AND 0 PRECEDING)
356725b1cfcSdan} {
357725b1cfcSdan  10 10 15 25 20 45 20 65 25 90 30 120 30 150 50 200
358725b1cfcSdan}
359725b1cfcSdan
360725b1cfcSdando_execsql_test 11.4.1 {
361725b1cfcSdan  SELECT y, group_concat(y, '.') OVER win FROM t3
362725b1cfcSdan  WINDOW win AS (
363725b1cfcSdan    ORDER BY y RANGE BETWEEN UNBOUNDED PRECEDING AND 10 PRECEDING
364725b1cfcSdan  );
365725b1cfcSdan} {
366725b1cfcSdan  fifteen fifteen
367725b1cfcSdan  ten     fifteen.ten
368725b1cfcSdan  thirty  fifteen.ten.thirty
369725b1cfcSdan}
370725b1cfcSdan
371e4984a2bSdrhfinish_test
372