1b19a2bc6Sdrh# 2001 September 15 2191b690eSdrh# 3b19a2bc6Sdrh# The author disclaims copyright to this source code. In place of 4b19a2bc6Sdrh# a legal notice, here is a blessing: 5191b690eSdrh# 6b19a2bc6Sdrh# May you do good and not evil. 7b19a2bc6Sdrh# May you find forgiveness for yourself and forgive others. 8b19a2bc6Sdrh# May you share freely, never taking more than you give. 9191b690eSdrh# 10191b690eSdrh#*********************************************************************** 11191b690eSdrh# This file implements regression tests for SQLite library. The 12191b690eSdrh# focus of this file is testing aggregate functions and the 13191b690eSdrh# GROUP BY and HAVING clauses of SELECT statements. 14191b690eSdrh# 15191b690eSdrh 16191b690eSdrhset testdir [file dirname $argv0] 17191b690eSdrhsource $testdir/tester.tcl 18191b690eSdrh 19191b690eSdrh# Build some test data 20191b690eSdrh# 21191b690eSdrhexecsql { 22191b690eSdrh CREATE TABLE t1(x int, y int); 235f3b4ab5Sdrh BEGIN; 24191b690eSdrh} 255f3b4ab5Sdrhfor {set i 1} {$i<32} {incr i} { 2624acd8f9Sdanielk1977 for {set j 0} {(1<<$j)<$i} {incr j} {} 275f3b4ab5Sdrh execsql "INSERT INTO t1 VALUES([expr {32-$i}],[expr {10-$j}])" 285f3b4ab5Sdrh} 295f3b4ab5Sdrhexecsql { 305f3b4ab5Sdrh COMMIT 315f3b4ab5Sdrh} 32191b690eSdrh 33191b690eSdrhdo_test select5-1.0 { 34191b690eSdrh execsql {SELECT DISTINCT y FROM t1 ORDER BY y} 35191b690eSdrh} {5 6 7 8 9 10} 36191b690eSdrh 37191b690eSdrh# Sort by an aggregate function. 38191b690eSdrh# 39191b690eSdrhdo_test select5-1.1 { 40191b690eSdrh execsql {SELECT y, count(*) FROM t1 GROUP BY y ORDER BY y} 41191b690eSdrh} {5 15 6 8 7 4 8 2 9 1 10 1} 42191b690eSdrhdo_test select5-1.2 { 43191b690eSdrh execsql {SELECT y, count(*) FROM t1 GROUP BY y ORDER BY count(*), y} 44191b690eSdrh} {9 1 10 1 8 2 7 4 6 8 5 15} 45aaf88729Sdrhdo_test select5-1.3 { 46aaf88729Sdrh execsql {SELECT count(*), y FROM t1 GROUP BY y ORDER BY count(*), y} 47aaf88729Sdrh} {1 9 1 10 2 8 4 7 8 6 15 5} 48191b690eSdrh 49c837e709Sdrh# Some error messages associated with aggregates and GROUP BY 50c837e709Sdrh# 51f14fd038Sdrhdo_test select5-2.1.1 { 52f14fd038Sdrh catchsql { 53c837e709Sdrh SELECT y, count(*) FROM t1 GROUP BY z ORDER BY y 54f14fd038Sdrh } 55967e8b73Sdrh} {1 {no such column: z}} 56f14fd038Sdrhdo_test select5-2.1.2 { 57f14fd038Sdrh catchsql { 58f14fd038Sdrh SELECT y, count(*) FROM t1 GROUP BY temp.t1.y ORDER BY y 59f14fd038Sdrh } 60f14fd038Sdrh} {1 {no such column: temp.t1.y}} 61c837e709Sdrhdo_test select5-2.2 { 62c837e709Sdrh set v [catch {execsql { 63c837e709Sdrh SELECT y, count(*) FROM t1 GROUP BY z(y) ORDER BY y 64c837e709Sdrh }} msg] 65c837e709Sdrh lappend v $msg 66c837e709Sdrh} {1 {no such function: z}} 67c837e709Sdrhdo_test select5-2.3 { 68c837e709Sdrh set v [catch {execsql { 69c837e709Sdrh SELECT y, count(*) FROM t1 GROUP BY y HAVING count(*)<3 ORDER BY y 70c837e709Sdrh }} msg] 71c837e709Sdrh lappend v $msg 72c837e709Sdrh} {0 {8 2 9 1 10 1}} 73c837e709Sdrhdo_test select5-2.4 { 74c837e709Sdrh set v [catch {execsql { 75c837e709Sdrh SELECT y, count(*) FROM t1 GROUP BY y HAVING z(y)<3 ORDER BY y 76c837e709Sdrh }} msg] 77c837e709Sdrh lappend v $msg 78c837e709Sdrh} {1 {no such function: z}} 79c837e709Sdrhdo_test select5-2.5 { 80c837e709Sdrh set v [catch {execsql { 81c837e709Sdrh SELECT y, count(*) FROM t1 GROUP BY y HAVING count(*)<z ORDER BY y 82c837e709Sdrh }} msg] 83c837e709Sdrh lappend v $msg 84967e8b73Sdrh} {1 {no such column: z}} 85c837e709Sdrh 86c837e709Sdrh# Get the Agg function to rehash in vdbe.c 87c837e709Sdrh# 88c837e709Sdrhdo_test select5-3.1 { 89c837e709Sdrh execsql { 90c837e709Sdrh SELECT x, count(*), avg(y) FROM t1 GROUP BY x HAVING x<4 ORDER BY x 91c837e709Sdrh } 9292febd92Sdrh} {1 1 5.0 2 1 5.0 3 1 5.0} 93c837e709Sdrh 941bee3d7bSdrh# Run various aggregate functions when the count is zero. 95c837e709Sdrh# 96c837e709Sdrhdo_test select5-4.1 { 97c837e709Sdrh execsql { 98c837e709Sdrh SELECT avg(x) FROM t1 WHERE x>100 99c837e709Sdrh } 1001bee3d7bSdrh} {{}} 1011bee3d7bSdrhdo_test select5-4.2 { 1021bee3d7bSdrh execsql { 1031bee3d7bSdrh SELECT count(x) FROM t1 WHERE x>100 1041bee3d7bSdrh } 1051bee3d7bSdrh} {0} 1061bee3d7bSdrhdo_test select5-4.3 { 1071bee3d7bSdrh execsql { 1081bee3d7bSdrh SELECT min(x) FROM t1 WHERE x>100 1091bee3d7bSdrh } 1101bee3d7bSdrh} {{}} 1111bee3d7bSdrhdo_test select5-4.4 { 1121bee3d7bSdrh execsql { 1131bee3d7bSdrh SELECT max(x) FROM t1 WHERE x>100 1141bee3d7bSdrh } 1151bee3d7bSdrh} {{}} 1161bee3d7bSdrhdo_test select5-4.5 { 1171bee3d7bSdrh execsql { 1181bee3d7bSdrh SELECT sum(x) FROM t1 WHERE x>100 1191bee3d7bSdrh } 120c2bd913aSdrh} {{}} 121c837e709Sdrh 122e257300fSdanielk1977# Some tests for queries with a GROUP BY clause but no aggregate functions. 123e257300fSdanielk1977# 124701bb3b4Sdrh# Note: The query in test cases 5.1 through 5.5 are not legal SQL. So if the 125e257300fSdanielk1977# implementation changes in the future and it returns different results, 126e257300fSdanielk1977# this is not such a big deal. 127e257300fSdanielk1977# 128e257300fSdanielk1977do_test select5-5.1 { 129e257300fSdanielk1977 execsql { 130e257300fSdanielk1977 CREATE TABLE t2(a, b, c); 131e257300fSdanielk1977 INSERT INTO t2 VALUES(1, 2, 3); 132e257300fSdanielk1977 INSERT INTO t2 VALUES(1, 4, 5); 133e257300fSdanielk1977 INSERT INTO t2 VALUES(6, 4, 7); 134e257300fSdanielk1977 CREATE INDEX t2_idx ON t2(a); 135e257300fSdanielk1977 } 136e257300fSdanielk1977} {} 137e257300fSdanielk1977do_test select5-5.2 { 138e257300fSdanielk1977 execsql { 139e257300fSdanielk1977 SELECT a FROM t2 GROUP BY a; 140e257300fSdanielk1977 } 141e257300fSdanielk1977} {1 6} 142e257300fSdanielk1977do_test select5-5.3 { 143e257300fSdanielk1977 execsql { 144e257300fSdanielk1977 SELECT a FROM t2 WHERE a>2 GROUP BY a; 145e257300fSdanielk1977 } 146e257300fSdanielk1977} {6} 147e257300fSdanielk1977do_test select5-5.4 { 148e257300fSdanielk1977 execsql { 149e257300fSdanielk1977 SELECT a, b FROM t2 GROUP BY a, b; 150e257300fSdanielk1977 } 151e257300fSdanielk1977} {1 2 1 4 6 4} 152e257300fSdanielk1977do_test select5-5.5 { 153e257300fSdanielk1977 execsql { 154e257300fSdanielk1977 SELECT a, b FROM t2 GROUP BY a; 155e257300fSdanielk1977 } 156280c894bSdan} {1 2 6 4} 157e257300fSdanielk1977 158701bb3b4Sdrh# Test rendering of columns for the GROUP BY clause. 159701bb3b4Sdrh# 160701bb3b4Sdrhdo_test select5-5.11 { 161701bb3b4Sdrh execsql { 162701bb3b4Sdrh SELECT max(c), b*a, b, a FROM t2 GROUP BY b*a, b, a 163701bb3b4Sdrh } 164701bb3b4Sdrh} {3 2 2 1 5 4 4 1 7 24 4 6} 165701bb3b4Sdrh 166e313382eSdrh# NULL compare equal to each other for the purposes of processing 167e313382eSdrh# the GROUP BY clause. 168e313382eSdrh# 169e313382eSdrhdo_test select5-6.1 { 170e313382eSdrh execsql { 171e313382eSdrh CREATE TABLE t3(x,y); 172e313382eSdrh INSERT INTO t3 VALUES(1,NULL); 173e313382eSdrh INSERT INTO t3 VALUES(2,NULL); 174e313382eSdrh INSERT INTO t3 VALUES(3,4); 175e313382eSdrh SELECT count(x), y FROM t3 GROUP BY y ORDER BY 1 176e313382eSdrh } 177e313382eSdrh} {1 4 2 {}} 178de29e3e9Sdrhdo_test select5-6.2 { 179de29e3e9Sdrh execsql { 180de29e3e9Sdrh CREATE TABLE t4(x,y,z); 181de29e3e9Sdrh INSERT INTO t4 VALUES(1,2,NULL); 182de29e3e9Sdrh INSERT INTO t4 VALUES(2,3,NULL); 183de29e3e9Sdrh INSERT INTO t4 VALUES(3,NULL,5); 184de29e3e9Sdrh INSERT INTO t4 VALUES(4,NULL,6); 185de29e3e9Sdrh INSERT INTO t4 VALUES(4,NULL,6); 186de29e3e9Sdrh INSERT INTO t4 VALUES(5,NULL,NULL); 187de29e3e9Sdrh INSERT INTO t4 VALUES(5,NULL,NULL); 188de29e3e9Sdrh INSERT INTO t4 VALUES(6,7,8); 189de29e3e9Sdrh SELECT max(x), count(x), y, z FROM t4 GROUP BY y, z ORDER BY 1 190de29e3e9Sdrh } 191de29e3e9Sdrh} {1 1 2 {} 2 1 3 {} 3 1 {} 5 4 2 {} 6 5 2 {} {} 6 1 7 8} 192e313382eSdrh 1936a012f04Sdrhdo_test select5-7.2 { 194c4da5b9fSdanielk1977 execsql { 195c4da5b9fSdanielk1977 SELECT count(*), count(x) as cnt FROM t4 GROUP BY y ORDER BY cnt; 196c4da5b9fSdanielk1977 } 197c4da5b9fSdanielk1977} {1 1 1 1 1 1 5 5} 198c4da5b9fSdanielk1977 1996a012f04Sdrh# See ticket #3324. 2006a012f04Sdrh# 2016a012f04Sdrhdo_test select5-8.1 { 2026a012f04Sdrh execsql { 2036a012f04Sdrh CREATE TABLE t8a(a,b); 2046a012f04Sdrh CREATE TABLE t8b(x); 2056a012f04Sdrh INSERT INTO t8a VALUES('one', 1); 2066a012f04Sdrh INSERT INTO t8a VALUES('one', 2); 2076a012f04Sdrh INSERT INTO t8a VALUES('two', 3); 2086a012f04Sdrh INSERT INTO t8a VALUES('one', NULL); 2096a012f04Sdrh INSERT INTO t8b(rowid,x) VALUES(1,111); 2106a012f04Sdrh INSERT INTO t8b(rowid,x) VALUES(2,222); 2116a012f04Sdrh INSERT INTO t8b(rowid,x) VALUES(3,333); 2126a012f04Sdrh SELECT a, count(b) FROM t8a, t8b WHERE b=t8b.rowid GROUP BY a ORDER BY a; 2136a012f04Sdrh } 2146a012f04Sdrh} {one 2 two 1} 2156a012f04Sdrhdo_test select5-8.2 { 2166a012f04Sdrh execsql { 2176a012f04Sdrh SELECT a, count(b) FROM t8a, t8b WHERE b=+t8b.rowid GROUP BY a ORDER BY a; 2186a012f04Sdrh } 2196a012f04Sdrh} {one 2 two 1} 2206a012f04Sdrhdo_test select5-8.3 { 2216a012f04Sdrh execsql { 2226a012f04Sdrh SELECT t8a.a, count(t8a.b) FROM t8a, t8b WHERE t8a.b=t8b.rowid 2236a012f04Sdrh GROUP BY 1 ORDER BY 1; 2246a012f04Sdrh } 2256a012f04Sdrh} {one 2 two 1} 2266a012f04Sdrhdo_test select5-8.4 { 2276a012f04Sdrh execsql { 2286a012f04Sdrh SELECT a, count(*) FROM t8a, t8b WHERE b=+t8b.rowid GROUP BY a ORDER BY a; 2296a012f04Sdrh } 2306a012f04Sdrh} {one 2 two 1} 2316a012f04Sdrhdo_test select5-8.5 { 2326a012f04Sdrh execsql { 2336a012f04Sdrh SELECT a, count(b) FROM t8a, t8b WHERE b<x GROUP BY a ORDER BY a; 2346a012f04Sdrh } 2356a012f04Sdrh} {one 6 two 3} 2366a012f04Sdrhdo_test select5-8.6 { 2376a012f04Sdrh execsql { 2386a012f04Sdrh SELECT a, count(t8a.b) FROM t8a, t8b WHERE b=t8b.rowid 2396a012f04Sdrh GROUP BY a ORDER BY 2; 2406a012f04Sdrh } 2416a012f04Sdrh} {two 1 one 2} 2426a012f04Sdrhdo_test select5-8.7 { 2436a012f04Sdrh execsql { 2446a012f04Sdrh SELECT a, count(b) FROM t8a, t8b GROUP BY a ORDER BY 2; 2456a012f04Sdrh } 2466a012f04Sdrh} {two 3 one 6} 2476a012f04Sdrhdo_test select5-8.8 { 2486a012f04Sdrh execsql { 2496a012f04Sdrh SELECT a, count(*) FROM t8a, t8b GROUP BY a ORDER BY 2; 2506a012f04Sdrh } 2516a012f04Sdrh} {two 3 one 9} 2526a012f04Sdrh 253*8ed8ddf7Sdrh# 2021-04-26 forum https://sqlite.org/forum/forumpost/74330094d8 254*8ed8ddf7Sdrhreset_db 255*8ed8ddf7Sdrhdo_execsql_test select5-9.1 { 256*8ed8ddf7Sdrh CREATE TABLE t1(a INT, b INT); 257*8ed8ddf7Sdrh INSERT INTO t1(a,b) VALUES(1,null),(null,null),(1,null); 258*8ed8ddf7Sdrh CREATE UNIQUE INDEX t1b ON t1(abs(b)); 259*8ed8ddf7Sdrh SELECT quote(a), quote(b), '|' FROM t1 GROUP BY a, abs(b); 260*8ed8ddf7Sdrh} {NULL NULL | 1 NULL |} 2616a012f04Sdrh 262191b690eSdrhfinish_test 263