sqlite/test/aggorderby.test
drh 07117f8118 Pass subtype information through the aggregate ORDER BY sorter for
aggregate functions that use subtype information.

FossilOrigin-Name: 3536f4030eab6d650b7ed729d2f71eb6cc3b5fbe16b4e96b99008d66522aaccb
2023-12-14 13:58:50 +00:00

163 lines
5.3 KiB
Plaintext

# 2023-10-18
#
# 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 tests for ORDER BY on aggregate functions.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
do_execsql_test aggorderby-1.1 {
CREATE TABLE t1(a TEXT,b INT,c INT,d INT);
WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<9)
INSERT INTO t1(a,b,c,d) SELECT printf('%d',(x*7)%10),1,x,10-x FROM c;
INSERT INTO t1(a,b,c,d) SELECT a, 2, c, 10-d FROM t1;
CREATE INDEX t1b ON t1(b);
}
do_catchsql_test aggorderby-1.2 {
SELECT b, group_concat(a ORDER BY max(d)) FROM t1 GROUP BY b;
} {1 {misuse of aggregate function max()}}
do_catchsql_test aggorderby-1.3 {
SELECT abs(a ORDER BY max(d)) FROM t1;
} {1 {ORDER BY may not be used with non-aggregate abs()}}
do_execsql_test aggorderby-2.0 {
SELECT group_concat(a ORDER BY a) FROM t1 WHERE b=1;
} {0,1,2,3,4,5,6,7,8,9}
do_execsql_test aggorderby-2.1 {
SELECT group_concat(a ORDER BY c) FROM t1 WHERE b=1;
} {0,7,4,1,8,5,2,9,6,3}
do_execsql_test aggorderby-2.2 {
SELECT group_concat(a ORDER BY b, d) FROM t1;
} {3,6,9,2,5,8,1,4,7,0,0,7,4,1,8,5,2,9,6,3}
do_execsql_test aggorderby-2.3 {
SELECT string_agg(a, ',' ORDER BY b DESC, d) FROM t1;
} {0,7,4,1,8,5,2,9,6,3,3,6,9,2,5,8,1,4,7,0}
do_execsql_test aggorderby-2.4 {
SELECT b, group_concat(a ORDER BY d) FROM t1 GROUP BY b ORDER BY b;
} {1 3,6,9,2,5,8,1,4,7,0 2 0,7,4,1,8,5,2,9,6,3}
do_execsql_test aggorderby-3.0 {
SELECT group_concat(DISTINCT a ORDER BY a) FROM t1;
} {0,1,2,3,4,5,6,7,8,9}
do_execsql_test aggorderby-3.1 {
SELECT group_concat(DISTINCT a ORDER BY c) FROM t1;
} {0,7,4,1,8,5,2,9,6,3}
do_execsql_test aggorderby-4.0 {
SELECT count(ORDER BY a) FROM t1;
} 20
do_execsql_test aggorderby-4.1 {
SELECT c, max(a ORDER BY a) FROM t1;
} {7 9}
do_execsql_test aggorderby-5.0 {
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t3;
CREATE TABLE t1(a TEXT); INSERT INTO t1 VALUES('aaa'),('bbb');
CREATE TABLE t3(d TEXT); INSERT INTO t3 VALUES('/'),('-');
SELECT (SELECT string_agg(a,d) FROM t3) FROM t1;
} {aaa-aaa bbb-bbb}
do_execsql_test aggorderby-5.1 {
SELECT (SELECT group_concat(a,d ORDER BY d) FROM t3) FROM t1;
} {aaa/aaa bbb/bbb}
do_execsql_test aggorderby-5.2 {
SELECT (SELECT string_agg(a,d ORDER BY d DESC) FROM t3) FROM t1;
} {aaa-aaa bbb-bbb}
do_execsql_test aggorderby-5.3 {
SELECT (SELECT string_agg(a,'#' ORDER BY d) FROM t3) FROM t1;
} {aaa#aaa bbb#bbb}
# COLLATE works on the ORDER BY.
#
do_execsql_test aggorderby-6.0 {
WITH c(x) AS (VALUES('abc'),('DEF'),('xyz'),('ABC'),('XYZ'))
SELECT string_agg(x,',' ORDER BY x COLLATE nocase),
string_agg(x,',' ORDER BY x) FROM c;
} {abc,ABC,DEF,xyz,XYZ ABC,DEF,XYZ,abc,xyz}
do_execsql_test aggorderby-6.1 {
WITH c(x,y) AS (VALUES(1,'a'),(2,'B'),(3,'c'),(4,'D'))
SELECT group_concat(x ORDER BY y COLLATE nocase),
group_concat(x ORDER BY y COLLATE binary) FROM c;
} {1,2,3,4 2,4,1,3}
# NULLS FIRST and NULLS LAST work on the ORDER BY
#
do_execsql_test aggorderby-7.0 {
WITH c(x) AS (VALUES(1),(NULL),(2.5),(NULL),('three'))
SELECT json_group_array(x ORDER BY x NULLS FIRST),
json_group_array(x ORDER BY x NULLS LAST) FROM c;
} {[null,null,1,2.5,"three"] [1,2.5,"three",null,null]}
do_execsql_test aggorderby-7.1 {
WITH c(x,y) AS (VALUES(1,9),(2,null),(3,5),(4,null),(5,1))
SELECT json_group_array(x ORDER BY y NULLS FIRST, x),
json_group_array(x ORDER BY y NULLS LAST, x) FROM c;
} {[2,4,5,3,1] [5,3,1,2,4]}
# The DISTINCT only applies to the function arguments, not to the
# ORDER BY arguments.
#
do_execsql_test aggorderby-8.0 {
WITH c(x,y,z) AS (VALUES('a',4,5),('b',3,6),('c',2,7),('c',1,8))
SELECT group_concat(DISTINCT x ORDER BY y, z) FROM c;
} {c,b,a}
do_execsql_test aggorderby-8.1 {
WITH c(x,y,z) AS (VALUES('a',4,5),('b',3,6),('b',2,7),('c',1,8))
SELECT group_concat(DISTINCT x ORDER BY y, z) FROM c;
} {c,b,a}
do_execsql_test aggorderby-8.2 {
WITH c(x,y) AS (VALUES(1,1),(2,2),(3,3),(3,4),(3,5),(3,6))
SELECT sum(DISTINCT x ORDER BY y) FROM c;
} 6
# Subtype information is transfered through the sorter for aggregates
# that make use of subtype info.
#
do_execsql_test aggorderby-9.0 {
WITH c(x,y) AS (VALUES
('{a:3}', 3),
('[1,1]', 1),
('[4,4]', 4),
('{x:2}', 2))
SELECT json_group_array(json(x) ORDER BY y) FROM c;
} {{[[1,1],{"x":2},{"a":3},[4,4]]}}
do_execsql_test aggorderby-9.1 {
WITH c(x,y) AS (VALUES
('[4,4]', 4),
('{a:3}', 3),
('[4,4]', 4),
('[1,1]', 1),
('[4,4]', 4),
('{x:2}', 2))
SELECT json_group_array(DISTINCT json(x) ORDER BY y) FROM c;
} {{[[1,1],{"x":2},{"a":3},[4,4]]}}
do_execsql_test aggorderby-9.2 {
WITH c(x,y) AS (VALUES
('{a:3}', 3),
('[1,1]', 1),
('[4,4]', 4),
('{x:2}', 2))
SELECT json_group_array(json(x) ORDER BY json(x)) FROM c;
} {{[[1,1],[4,4],{"a":3},{"x":2}]}}
do_execsql_test aggorderby-9.3 {
WITH c(x,y) AS (VALUES
('[4,4]', 4),
('{a:3}', 3),
('[4,4]', 4),
('[1,1]', 1),
('[4,4]', 4),
('{x:2}', 2))
SELECT json_group_array(DISTINCT json(x) ORDER BY json(x)) FROM c;
} {{[[1,1],[4,4],{"a":3},{"x":2}]}}
finish_test