xref: /sqlite-3.40.0/test/window9.test (revision b03786ad)
162742fd2Sdan# 2019 June 8
262742fd2Sdan#
362742fd2Sdan# The author disclaims copyright to this source code.  In place of
462742fd2Sdan# a legal notice, here is a blessing:
562742fd2Sdan#
662742fd2Sdan#    May you do good and not evil.
762742fd2Sdan#    May you find forgiveness for yourself and forgive others.
862742fd2Sdan#    May you share freely, never taking more than you give.
962742fd2Sdan#
1062742fd2Sdan#***********************************************************************
1162742fd2Sdan# This file implements regression tests for SQLite library.
1262742fd2Sdan#
1362742fd2Sdan
1462742fd2Sdanset testdir [file dirname $argv0]
1562742fd2Sdansource $testdir/tester.tcl
1662742fd2Sdanset testprefix window9
1762742fd2Sdan
1862742fd2Sdanifcapable !windowfunc {
1962742fd2Sdan  finish_test
2062742fd2Sdan  return
2162742fd2Sdan}
2262742fd2Sdan
2362742fd2Sdando_execsql_test 1.0 {
2462742fd2Sdan  CREATE TABLE fruits(
2562742fd2Sdan     name TEXT COLLATE NOCASE,
2662742fd2Sdan     color TEXT COLLATE NOCASE
2762742fd2Sdan  );
2862742fd2Sdan}
2962742fd2Sdan
3062742fd2Sdando_execsql_test 1.1 {
3162742fd2Sdan  INSERT INTO fruits (name, color) VALUES ('apple', 'RED');
3262742fd2Sdan  INSERT INTO fruits (name, color) VALUES ('APPLE', 'yellow');
3362742fd2Sdan  INSERT INTO fruits (name, color) VALUES ('pear', 'YELLOW');
3462742fd2Sdan  INSERT INTO fruits (name, color) VALUES ('PEAR', 'green');
3562742fd2Sdan}
3662742fd2Sdan
3762742fd2Sdando_execsql_test 1.2 {
3862742fd2Sdan  SELECT name, color, dense_rank() OVER (ORDER BY name) FROM fruits;
3962742fd2Sdan} {
4062742fd2Sdan  apple RED    1
4162742fd2Sdan  APPLE yellow 1
4262742fd2Sdan  pear  YELLOW 2
4362742fd2Sdan  PEAR  green  2
4462742fd2Sdan}
4562742fd2Sdan
4662742fd2Sdando_execsql_test 1.3 {
4762742fd2Sdan  SELECT name, color,
4862742fd2Sdan    dense_rank() OVER (PARTITION BY name ORDER BY color)
4962742fd2Sdan  FROM fruits;
5062742fd2Sdan} {
5162742fd2Sdan  apple RED    1
5262742fd2Sdan  APPLE yellow 2
5362742fd2Sdan  PEAR green   1
5462742fd2Sdan  pear YELLOW  2
5562742fd2Sdan}
5662742fd2Sdan
5762742fd2Sdando_execsql_test 1.4 {
5862742fd2Sdan  SELECT name, color,
5962742fd2Sdan    dense_rank() OVER (ORDER BY name),
6062742fd2Sdan    dense_rank() OVER (PARTITION BY name ORDER BY color)
6162742fd2Sdan  FROM fruits;
6262742fd2Sdan} {
6362742fd2Sdan  apple RED    1 1
6462742fd2Sdan  APPLE yellow 1 2
6562742fd2Sdan  PEAR  green  2 1
6662742fd2Sdan  pear  YELLOW 2 2
6762742fd2Sdan}
6862742fd2Sdan
6962742fd2Sdando_execsql_test 1.5 {
7062742fd2Sdan  SELECT name, color,
7162742fd2Sdan    dense_rank() OVER (ORDER BY name),
7262742fd2Sdan    dense_rank() OVER (PARTITION BY name ORDER BY color)
7362742fd2Sdan  FROM fruits ORDER BY color;
7462742fd2Sdan} {
7562742fd2Sdan  PEAR  green  2 1
7662742fd2Sdan  apple RED    1 1
7762742fd2Sdan  APPLE yellow 1 2
7862742fd2Sdan  pear  YELLOW 2 2
7962742fd2Sdan}
8062742fd2Sdan
8162742fd2Sdando_execsql_test 2.0 {
8262742fd2Sdan  CREATE TABLE t1(a BLOB, b INTEGER, c COLLATE nocase);
8362742fd2Sdan  INSERT INTO t1 VALUES(1, 2, 'abc');
8462742fd2Sdan  INSERT INTO t1 VALUES(3, 4, 'ABC');
8562742fd2Sdan}
8662742fd2Sdan
8762742fd2Sdando_execsql_test 2.1.1 {
8862742fd2Sdan  SELECT c=='Abc' FROM t1
8962742fd2Sdan} {1     1}
9062742fd2Sdando_execsql_test 2.1.2 {
9162742fd2Sdan  SELECT c=='Abc', rank() OVER (ORDER BY b) FROM t1
9262742fd2Sdan} {1 1   1 2}
9362742fd2Sdan
9462742fd2Sdando_execsql_test 2.2.1 {
9562742fd2Sdan  SELECT b=='2' FROM t1
9662742fd2Sdan} {1     0}
9762742fd2Sdando_execsql_test 2.2.2 {
9862742fd2Sdan  SELECT b=='2', rank() OVER (ORDER BY a) FROM t1
9962742fd2Sdan} {1 1   0 2}
10062742fd2Sdan
10175b0821eSdan#-------------------------------------------------------------------------
10275b0821eSdanreset_db
10375b0821eSdando_execsql_test 3.0 {
10475b0821eSdan  CREATE TABLE t1(a);
10575b0821eSdan  CREATE TABLE t2(a,b,c);
10675b0821eSdan}
10775b0821eSdan
10875b0821eSdando_execsql_test 3.1 {
10975b0821eSdan  SELECT EXISTS(SELECT 1 FROM t1 ORDER BY sum(a) OVER ()) FROM t1;
11075b0821eSdan}
11175b0821eSdan
11275b0821eSdando_execsql_test 3.2 {
11375b0821eSdan  SELECT sum(a) OVER () FROM t2
11475b0821eSdan   ORDER BY EXISTS(SELECT 1 FROM t2 ORDER BY sum(a) OVER ());
11575b0821eSdan}
11675b0821eSdan
11775b0821eSdando_catchsql_test 3.3 {
11875b0821eSdan  SELECT a, sum(a) OVER (ORDER BY a DESC) FROM t2
11975b0821eSdan  ORDER BY EXISTS(
12075b0821eSdan    SELECT 1 FROM t2 ORDER BY sum(a) OVER (ORDER BY a)
12175b0821eSdan  ) OVER (ORDER BY a);
12275b0821eSdan} {1 {near "OVER": syntax error}}
12375b0821eSdan
124e0ae3f69Sdando_catchsql_test 3.4 {
125e0ae3f69Sdan  SELECT y, y+1, y+2 FROM (
126e0ae3f69Sdan      SELECT c IN (
127e0ae3f69Sdan        SELECT min(a) OVER (),
128e0ae3f69Sdan        (abs(row_number() OVER())+22)/19,
129e0ae3f69Sdan        max(a) OVER () FROM t1
130e0ae3f69Sdan        ) AS y FROM t2
131e0ae3f69Sdan      );
132e0ae3f69Sdan} {1 {sub-select returns 3 columns - expected 1}}
133e0ae3f69Sdan
1340a8d06a9Sdan#-------------------------------------------------------------------------
1350a8d06a9Sdanreset_db
1360a8d06a9Sdando_execsql_test 4.0 {
1370a8d06a9Sdan  CREATE TABLE t1(a, b TEXT);
1380a8d06a9Sdan  INSERT INTO t1 VALUES('A', 1), ('A', 2), ('2', 1), ('2', 2);
1390a8d06a9Sdan}
1400a8d06a9Sdan
1410a8d06a9Sdando_execsql_test 4.1.1 {
1420a8d06a9Sdan  SELECT b, b=count(*), '1,2'                   FROM t1 GROUP BY b;
1430a8d06a9Sdan} {1 0 1,2 2 1 1,2}
1440a8d06a9Sdando_execsql_test 4.1.2 {
1450a8d06a9Sdan  SELECT b, b=count(*), group_concat(b) OVER () FROM t1 GROUP BY b;
1460a8d06a9Sdan} {1 0 1,2 2 1 1,2}
1470a8d06a9Sdan
1480e3c50c5Sdan#--------------------------------------------------------------------------
1490e3c50c5Sdanreset_db
1500e3c50c5Sdando_execsql_test 5.0 {
1510e3c50c5Sdan  CREATE TABLE t1(a, b, c, d, e);
1520e3c50c5Sdan  CREATE INDEX i1 ON t1(a, b, c, d, e);
1530e3c50c5Sdan}
1540e3c50c5Sdan
1550e3c50c5Sdanforeach {tn sql} {
1560e3c50c5Sdan  1 {
1570e3c50c5Sdan    SELECT
1580e3c50c5Sdan      sum(e) OVER (),
1590e3c50c5Sdan      sum(e) OVER (ORDER BY a),
1600e3c50c5Sdan      sum(e) OVER (PARTITION BY a ORDER BY b),
1610e3c50c5Sdan      sum(e) OVER (PARTITION BY a, b ORDER BY c),
1620e3c50c5Sdan      sum(e) OVER (PARTITION BY a, b, c ORDER BY d)
1630e3c50c5Sdan    FROM t1;
1640e3c50c5Sdan  }
1650e3c50c5Sdan  2 {
1660e3c50c5Sdan    SELECT sum(e) OVER (PARTITION BY a ORDER BY b) FROM t1 ORDER BY a;
1670e3c50c5Sdan  }
1680e3c50c5Sdan} {
1690e3c50c5Sdan  do_test 5.1.$tn {
1700e3c50c5Sdan    execsql "EXPLAIN QUERY PLAN $sql"
1710e3c50c5Sdan  } {~/ORDER/}
1720e3c50c5Sdan}
1730e3c50c5Sdan
174a3fcc000Sdan#-------------------------------------------------------------------------
175a3fcc000Sdanreset_db
176a3fcc000Sdando_execsql_test 6.0 {
177a3fcc000Sdan  CREATE TABLE t0(c0);
178a3fcc000Sdan  INSERT INTO t0(c0) VALUES (0);
179a3fcc000Sdan}
180a3fcc000Sdan
181a3fcc000Sdando_execsql_test 6.1 {
182a3fcc000Sdan  SELECT * FROM t0 WHERE
183a3fcc000Sdan  EXISTS (
184a3fcc000Sdan    SELECT MIN(c0) OVER (), CUME_DIST() OVER () FROM t0
185a3fcc000Sdan  ) >=1 AND
186a3fcc000Sdan  EXISTS (
187a3fcc000Sdan    SELECT MIN(c0) OVER (), CUME_DIST() OVER () FROM t0
188a3fcc000Sdan  ) <=1;
189a3fcc000Sdan} {0}
190a3fcc000Sdan
191a3fcc000Sdando_execsql_test 6.2 {
192a3fcc000Sdan  SELECT * FROM t0 WHERE EXISTS (
193a3fcc000Sdan    SELECT MIN(c0) OVER (), CUME_DIST() OVER () FROM t0
194a3fcc000Sdan  )
195a3fcc000Sdan  BETWEEN 1 AND 1;
196a3fcc000Sdan} {0}
1970a8d06a9Sdan
198a51ddb1eSdan#-------------------------------------------------------------------------
199a51ddb1eSdanreset_db
200a51ddb1eSdando_execsql_test 7.0 {
201a51ddb1eSdan  DROP TABLE IF EXISTS t1;
202a51ddb1eSdan  CREATE TABLE t1(x, y);
203a51ddb1eSdan  INSERT INTO t1 VALUES(10, 1);
204a51ddb1eSdan  INSERT INTO t1 VALUES(20, 2);
205a51ddb1eSdan  INSERT INTO t1 VALUES(3, 3);
206a51ddb1eSdan  INSERT INTO t1 VALUES(2, 4);
207a51ddb1eSdan  INSERT INTO t1 VALUES(1, 5);
208a51ddb1eSdan} {}
209a51ddb1eSdan
210a51ddb1eSdan
211a51ddb1eSdando_execsql_test 7.1 {
212a51ddb1eSdan  SELECT avg(x) OVER (ORDER BY y) AS z FROM t1 ORDER BY z
213a51ddb1eSdan} {
214a51ddb1eSdan  7.2 8.75 10.0 11.0 15.0
215a51ddb1eSdan}
216a51ddb1eSdan
217a51ddb1eSdando_execsql_test 7.2 {
218a51ddb1eSdan  SELECT avg(x) OVER (ORDER BY y) z FROM t1 ORDER BY (z IS y);
219a51ddb1eSdan} {
220a51ddb1eSdan  10.0 15.0 11.0 8.75 7.2
221a51ddb1eSdan}
222a51ddb1eSdan
223a51ddb1eSdando_execsql_test 7.3 {
224a51ddb1eSdan  SELECT avg(x) OVER (ORDER BY y) z FROM t1 ORDER BY (y IS z);
225a51ddb1eSdan} {
226a51ddb1eSdan  10.0 15.0 11.0 8.75 7.2
227a51ddb1eSdan}
228a51ddb1eSdan
229a51ddb1eSdando_execsql_test 7.4 {
230a51ddb1eSdan  SELECT avg(x) OVER (ORDER BY y) z FROM t1 ORDER BY z + 0.0;
231a51ddb1eSdan} {
232a51ddb1eSdan  7.2 8.75 10.0 11.0 15.0
233a51ddb1eSdan}
23475b0821eSdan
235553948e5Sdan#-------------------------------------------------------------------------
236553948e5Sdanreset_db
237553948e5Sdando_execsql_test 8.1.1 {
238553948e5Sdan  CREATE TABLE t1(a, b);
239553948e5Sdan  INSERT INTO t1 VALUES(1, 2), (3, 4);
240553948e5Sdan  SELECT min( sum(a) ) OVER () FROM t1;
241553948e5Sdan} {4}
242553948e5Sdan
243553948e5Sdando_execsql_test 8.1.2 {
244553948e5Sdan  SELECT min( sum(a) ) OVER () FROM t1 GROUP BY a;
245553948e5Sdan} {1 1}
246553948e5Sdan
247553948e5Sdando_execsql_test 8.2 {
248553948e5Sdan  CREATE VIEW v1 AS
249553948e5Sdan    SELECT 0 AS x
250553948e5Sdan      UNION
251553948e5Sdan    SELECT count() OVER() FROM (SELECT 0)
252553948e5Sdan    ORDER BY 1
253553948e5Sdan  ;
254553948e5Sdan}
255553948e5Sdan
256553948e5Sdando_catchsql_test 8.3 {
257553948e5Sdan  SELECT min( max((SELECT x FROM v1)) ) OVER()
258ed41a96bSdan} {0 0}
259553948e5Sdan
260553948e5Sdando_execsql_test 8.4 {
261553948e5Sdan  SELECT(
262553948e5Sdan      SELECT x UNION
263553948e5Sdan      SELECT sum( avg((SELECT x FROM v1)) ) OVER()
264553948e5Sdan  )
265553948e5Sdan  FROM v1;
266ed41a96bSdan} {0.0 0.0}
267553948e5Sdan
268*b03786adSdan#--------------------------------------------------------------------------
269*b03786adSdanreset_db
270*b03786adSdando_execsql_test 9.0 {
271*b03786adSdan  CREATE TABLE t1(a, b, c);
272*b03786adSdan  INSERT INTO t1 VALUES(NULL,'bb',356);
273*b03786adSdan  INSERT INTO t1 VALUES('CB','aa',158);
274*b03786adSdan  INSERT INTO t1 VALUES('BB','aa',399);
275*b03786adSdan  INSERT INTO t1 VALUES('FF','bb',938);
276*b03786adSdan}
277*b03786adSdan
278*b03786adSdando_catchsql_test 9.1 {
279*b03786adSdan  SELECT sum(c) OVER (
280*b03786adSdan    ORDER BY c RANGE BETWEEN 0 PRECEDING AND '-700' PRECEDING
281*b03786adSdan  )
282*b03786adSdan  FROM t1
283*b03786adSdan} {1 {frame ending offset must be a non-negative number}}
284*b03786adSdan
28562742fd2Sdanfinish_test
286