mirror of
https://github.com/sqlite/sqlite.git
synced 2025-08-07 02:42:48 +03:00
Experimental implementation of FILTER clause for aggregate functions.
FossilOrigin-Name: 1f1ae2d6ac8dcbb62e5aa3dc17bc67d559cb565fc0d0a8c00a596075d35f8130
This commit is contained in:
90
test/filter1.test
Normal file
90
test/filter1.test
Normal file
@@ -0,0 +1,90 @@
|
||||
# 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 filter1
|
||||
|
||||
ifcapable !windowfunc {
|
||||
finish_test
|
||||
return
|
||||
}
|
||||
|
||||
do_execsql_test 1.0 {
|
||||
CREATE TABLE t1(a);
|
||||
CREATE INDEX i1 ON t1(a);
|
||||
INSERT INTO t1 VALUES(1), (2), (3), (4), (5), (6), (7), (8), (9);
|
||||
}
|
||||
|
||||
do_execsql_test 1.1 { SELECT sum(a) FROM t1; } 45
|
||||
do_execsql_test 1.2 { SELECT sum(a) FILTER( WHERE a<5 ) FROM t1; } 10
|
||||
|
||||
do_execsql_test 1.3 {
|
||||
SELECT sum(a) FILTER( WHERE a>9 ),
|
||||
sum(a) FILTER( WHERE a>8 ),
|
||||
sum(a) FILTER( WHERE a>7 ),
|
||||
sum(a) FILTER( WHERE a>6 ),
|
||||
sum(a) FILTER( WHERE a>5 ),
|
||||
sum(a) FILTER( WHERE a>4 ),
|
||||
sum(a) FILTER( WHERE a>3 ),
|
||||
sum(a) FILTER( WHERE a>2 ),
|
||||
sum(a) FILTER( WHERE a>1 ),
|
||||
sum(a) FILTER( WHERE a>0 )
|
||||
FROM t1;
|
||||
} {{} 9 17 24 30 35 39 42 44 45}
|
||||
|
||||
do_execsql_test 1.4 {
|
||||
SELECT max(a) FILTER (WHERE (a % 2)==0) FROM t1
|
||||
} {8}
|
||||
|
||||
do_execsql_test 1.5 {
|
||||
SELECT min(a) FILTER (WHERE a>4) FROM t1
|
||||
} {5}
|
||||
|
||||
do_execsql_test 1.6 {
|
||||
SELECT count(*) FILTER (WHERE a!=5) FROM t1
|
||||
} {8}
|
||||
|
||||
do_execsql_test 1.6 {
|
||||
SELECT min(a) FILTER (WHERE a>3) FROM t1 GROUP BY (a%2) ORDER BY 1;
|
||||
} {4 5}
|
||||
|
||||
|
||||
#-------------------------------------------------------------------------
|
||||
# Test some errors:
|
||||
#
|
||||
# .1 FILTER on a non-aggregate function,
|
||||
# .2 Window function in FILTER clause,
|
||||
# .3 Aggregate function in FILTER clause,
|
||||
#
|
||||
reset_db
|
||||
do_execsql_test 2.0 {
|
||||
CREATE TABLE t1(a);
|
||||
INSERT INTO t1 VALUES(1), (2), (3), (4), (5), (6), (7), (8), (9);
|
||||
}
|
||||
|
||||
do_catchsql_test 2.1 {
|
||||
SELECT upper(a) FILTER (WHERE a=1) FROM t1
|
||||
} {1 {filter clause may not be used with non-aggregate upper()}}
|
||||
|
||||
do_catchsql_test 2.2 {
|
||||
SELECT sum(a) FILTER (WHERE 1 - max(a) OVER () > 0) FROM t1
|
||||
} {1 {misuse of window function max()}}
|
||||
|
||||
do_catchsql_test 2.3 {
|
||||
SELECT sum(a) FILTER (WHERE 1 - count(a)) FROM t1
|
||||
} {1 {misuse of aggregate: count()}}
|
||||
|
||||
finish_test
|
||||
|
||||
|
73
test/filter2.tcl
Normal file
73
test/filter2.tcl
Normal file
@@ -0,0 +1,73 @@
|
||||
# 2018 May 19
|
||||
#
|
||||
# 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.
|
||||
#
|
||||
#***********************************************************************
|
||||
#
|
||||
|
||||
source [file join [file dirname $argv0] pg_common.tcl]
|
||||
|
||||
#=========================================================================
|
||||
|
||||
|
||||
start_test filter2 "2019 July 2"
|
||||
|
||||
ifcapable !windowfunc
|
||||
|
||||
execsql_test 1.0 {
|
||||
DROP TABLE IF EXISTS t1;
|
||||
CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
|
||||
INSERT INTO t1 VALUES
|
||||
(1, 7), (2, 3), (3, 5), (4, 30), (5, 26), (6, 23), (7, 27),
|
||||
(8, 3), (9, 17), (10, 26), (11, 33), (12, 25), (13, NULL), (14, 47),
|
||||
(15, 36), (16, 13), (17, 45), (18, 31), (19, 11), (20, 36), (21, 37),
|
||||
(22, 21), (23, 22), (24, 14), (25, 16), (26, 3), (27, 7), (28, 29),
|
||||
(29, 50), (30, 38), (31, 3), (32, 36), (33, 12), (34, 4), (35, 46),
|
||||
(36, 3), (37, 48), (38, 23), (39, NULL), (40, 24), (41, 5), (42, 46),
|
||||
(43, 11), (44, NULL), (45, 18), (46, 25), (47, 15), (48, 18), (49, 23);
|
||||
}
|
||||
|
||||
execsql_test 1.1 { SELECT sum(b) FROM t1 }
|
||||
|
||||
execsql_test 1.2 { SELECT sum(b) FILTER (WHERE a<10) FROM t1 }
|
||||
|
||||
execsql_test 1.3 { SELECT count(DISTINCT b) FROM t1 }
|
||||
|
||||
execsql_test 1.4 { SELECT count(DISTINCT b) FILTER (WHERE a!=19) FROM t1 }
|
||||
|
||||
execsql_test 1.5 {
|
||||
SELECT min(b) FILTER (WHERE a>19),
|
||||
min(b) FILTER (WHERE a>0),
|
||||
max(a+b) FILTER (WHERE a>19),
|
||||
max(b+a) FILTER (WHERE a BETWEEN 10 AND 40)
|
||||
FROM t1;
|
||||
}
|
||||
|
||||
execsql_test 1.6 {
|
||||
SELECT min(b),
|
||||
min(b),
|
||||
max(a+b),
|
||||
max(b+a)
|
||||
FROM t1
|
||||
GROUP BY (a%10)
|
||||
ORDER BY 1, 2, 3, 4;
|
||||
}
|
||||
|
||||
execsql_test 1.7 {
|
||||
SELECT min(b) FILTER (WHERE a>19),
|
||||
min(b) FILTER (WHERE a>0),
|
||||
max(a+b) FILTER (WHERE a>19),
|
||||
max(b+a) FILTER (WHERE a BETWEEN 10 AND 40)
|
||||
FROM t1
|
||||
GROUP BY (a%10)
|
||||
ORDER BY 1, 2, 3, 4;
|
||||
}
|
||||
|
||||
finish_test
|
||||
|
||||
|
82
test/filter2.test
Normal file
82
test/filter2.test
Normal file
@@ -0,0 +1,82 @@
|
||||
# 2019 July 2
|
||||
#
|
||||
# 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.
|
||||
#
|
||||
|
||||
####################################################
|
||||
# DO NOT EDIT! THIS FILE IS AUTOMATICALLY GENERATED!
|
||||
####################################################
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
set testprefix filter2
|
||||
|
||||
ifcapable !windowfunc { finish_test ; return }
|
||||
do_execsql_test 1.0 {
|
||||
DROP TABLE IF EXISTS t1;
|
||||
CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
|
||||
INSERT INTO t1 VALUES
|
||||
(1, 7), (2, 3), (3, 5), (4, 30), (5, 26), (6, 23), (7, 27),
|
||||
(8, 3), (9, 17), (10, 26), (11, 33), (12, 25), (13, NULL), (14, 47),
|
||||
(15, 36), (16, 13), (17, 45), (18, 31), (19, 11), (20, 36), (21, 37),
|
||||
(22, 21), (23, 22), (24, 14), (25, 16), (26, 3), (27, 7), (28, 29),
|
||||
(29, 50), (30, 38), (31, 3), (32, 36), (33, 12), (34, 4), (35, 46),
|
||||
(36, 3), (37, 48), (38, 23), (39, NULL), (40, 24), (41, 5), (42, 46),
|
||||
(43, 11), (44, NULL), (45, 18), (46, 25), (47, 15), (48, 18), (49, 23);
|
||||
} {}
|
||||
|
||||
do_execsql_test 1.1 {
|
||||
SELECT sum(b) FROM t1
|
||||
} {1041}
|
||||
|
||||
do_execsql_test 1.2 {
|
||||
SELECT sum(b) FILTER (WHERE a<10) FROM t1
|
||||
} {141}
|
||||
|
||||
do_execsql_test 1.3 {
|
||||
SELECT count(DISTINCT b) FROM t1
|
||||
} {31}
|
||||
|
||||
do_execsql_test 1.4 {
|
||||
SELECT count(DISTINCT b) FILTER (WHERE a!=19) FROM t1
|
||||
} {31}
|
||||
|
||||
do_execsql_test 1.5 {
|
||||
SELECT min(b) FILTER (WHERE a>19),
|
||||
min(b) FILTER (WHERE a>0),
|
||||
max(a+b) FILTER (WHERE a>19),
|
||||
max(b+a) FILTER (WHERE a BETWEEN 10 AND 40)
|
||||
FROM t1;
|
||||
} {3 3 88 85}
|
||||
|
||||
do_execsql_test 1.6 {
|
||||
SELECT min(b),
|
||||
min(b),
|
||||
max(a+b),
|
||||
max(b+a)
|
||||
FROM t1
|
||||
GROUP BY (a%10)
|
||||
ORDER BY 1, 2, 3, 4;
|
||||
} {3 3 58 58 3 3 66 66 3 3 71 71 3 3 88 88 4 4 61 61 5 5 54 54
|
||||
7 7 85 85 11 11 79 79 16 16 81 81 24 24 68 68}
|
||||
|
||||
do_execsql_test 1.7 {
|
||||
SELECT min(b) FILTER (WHERE a>19),
|
||||
min(b) FILTER (WHERE a>0),
|
||||
max(a+b) FILTER (WHERE a>19),
|
||||
max(b+a) FILTER (WHERE a BETWEEN 10 AND 40)
|
||||
FROM t1
|
||||
GROUP BY (a%10)
|
||||
ORDER BY 1, 2, 3, 4;
|
||||
} {3 3 58 58 3 3 71 39 4 4 38 61 7 7 85 85 11 5 54 45 16 16 81 81
|
||||
18 3 66 61 21 3 88 68 23 11 79 79 24 24 68 68}
|
||||
|
||||
finish_test
|
Reference in New Issue
Block a user