1309be024Sdrh# 2007 July 17 2309be024Sdrh# 3309be024Sdrh# The author disclaims copyright to this source code. In place of 4309be024Sdrh# a legal notice, here is a blessing: 5309be024Sdrh# 6309be024Sdrh# May you do good and not evil. 7309be024Sdrh# May you find forgiveness for yourself and forgive others. 8309be024Sdrh# May you share freely, never taking more than you give. 9309be024Sdrh# 10309be024Sdrh#*********************************************************************** 11309be024Sdrh# This file implements regression tests for SQLite library. The 12309be024Sdrh# focus of this file is testing SELECT statements that contain 13309be024Sdrh# aggregate min() and max() functions and which are handled as 14309be024Sdrh# as a special case. This file makes sure that the min/max 15309be024Sdrh# optimization works right in the presence of descending 16309be024Sdrh# indices. Ticket #2514. 17309be024Sdrh# 18a9d1ccb9Sdanielk1977# $Id: minmax2.test,v 1.2 2008/01/05 17:39:30 danielk1977 Exp $ 19309be024Sdrh 20309be024Sdrhset testdir [file dirname $argv0] 21309be024Sdrhsource $testdir/tester.tcl 22309be024Sdrh 23309be024Sdrhdo_test minmax2-1.0 { 2466c48907Sdrh sqlite3_db_config db LEGACY_FILE_FORMAT 0 25309be024Sdrh execsql { 26309be024Sdrh BEGIN; 27309be024Sdrh CREATE TABLE t1(x, y); 28309be024Sdrh INSERT INTO t1 VALUES(1,1); 29309be024Sdrh INSERT INTO t1 VALUES(2,2); 30309be024Sdrh INSERT INTO t1 VALUES(3,2); 31309be024Sdrh INSERT INTO t1 VALUES(4,3); 32309be024Sdrh INSERT INTO t1 VALUES(5,3); 33309be024Sdrh INSERT INTO t1 VALUES(6,3); 34309be024Sdrh INSERT INTO t1 VALUES(7,3); 35309be024Sdrh INSERT INTO t1 VALUES(8,4); 36309be024Sdrh INSERT INTO t1 VALUES(9,4); 37309be024Sdrh INSERT INTO t1 VALUES(10,4); 38309be024Sdrh INSERT INTO t1 VALUES(11,4); 39309be024Sdrh INSERT INTO t1 VALUES(12,4); 40309be024Sdrh INSERT INTO t1 VALUES(13,4); 41309be024Sdrh INSERT INTO t1 VALUES(14,4); 42309be024Sdrh INSERT INTO t1 VALUES(15,4); 43309be024Sdrh INSERT INTO t1 VALUES(16,5); 44309be024Sdrh INSERT INTO t1 VALUES(17,5); 45309be024Sdrh INSERT INTO t1 VALUES(18,5); 46309be024Sdrh INSERT INTO t1 VALUES(19,5); 47309be024Sdrh INSERT INTO t1 VALUES(20,5); 48309be024Sdrh COMMIT; 49309be024Sdrh SELECT DISTINCT y FROM t1 ORDER BY y; 50309be024Sdrh } 51309be024Sdrh} {1 2 3 4 5} 52309be024Sdrh 53309be024Sdrhdo_test minmax2-1.1 { 54309be024Sdrh set sqlite_search_count 0 55309be024Sdrh execsql {SELECT min(x) FROM t1} 56309be024Sdrh} {1} 57309be024Sdrhdo_test minmax2-1.2 { 58309be024Sdrh set sqlite_search_count 59309be024Sdrh} {19} 60309be024Sdrhdo_test minmax2-1.3 { 61309be024Sdrh set sqlite_search_count 0 62309be024Sdrh execsql {SELECT max(x) FROM t1} 63309be024Sdrh} {20} 64309be024Sdrhdo_test minmax2-1.4 { 65309be024Sdrh set sqlite_search_count 66309be024Sdrh} {19} 67309be024Sdrhdo_test minmax2-1.5 { 68309be024Sdrh execsql {CREATE INDEX t1i1 ON t1(x DESC)} 69309be024Sdrh set sqlite_search_count 0 70309be024Sdrh execsql {SELECT min(x) FROM t1} 71309be024Sdrh} {1} 72309be024Sdrhdo_test minmax2-1.6 { 73309be024Sdrh set sqlite_search_count 74a9d1ccb9Sdanielk1977} {1} 75309be024Sdrhdo_test minmax2-1.7 { 76309be024Sdrh set sqlite_search_count 0 77309be024Sdrh execsql {SELECT max(x) FROM t1} 78309be024Sdrh} {20} 79309be024Sdrhdo_test minmax2-1.8 { 80309be024Sdrh set sqlite_search_count 81a9d1ccb9Sdanielk1977} {0} 82309be024Sdrhdo_test minmax2-1.9 { 83309be024Sdrh set sqlite_search_count 0 84309be024Sdrh execsql {SELECT max(y) FROM t1} 85309be024Sdrh} {5} 86309be024Sdrhdo_test minmax2-1.10 { 87309be024Sdrh set sqlite_search_count 88309be024Sdrh} {19} 89309be024Sdrh 90309be024Sdrhdo_test minmax2-2.0 { 91309be024Sdrh execsql { 92309be024Sdrh CREATE TABLE t2(a INTEGER PRIMARY KEY, b); 93309be024Sdrh INSERT INTO t2 SELECT * FROM t1; 94309be024Sdrh } 95309be024Sdrh set sqlite_search_count 0 96309be024Sdrh execsql {SELECT min(a) FROM t2} 97309be024Sdrh} {1} 98309be024Sdrhdo_test minmax2-2.1 { 99309be024Sdrh set sqlite_search_count 100309be024Sdrh} {0} 101309be024Sdrhdo_test minmax2-2.2 { 102309be024Sdrh set sqlite_search_count 0 103309be024Sdrh execsql {SELECT max(a) FROM t2} 104309be024Sdrh} {20} 105309be024Sdrhdo_test minmax2-2.3 { 106309be024Sdrh set sqlite_search_count 107309be024Sdrh} {0} 108309be024Sdrh 109309be024Sdrhdo_test minmax2-3.0 { 110309be024Sdrh ifcapable subquery { 111309be024Sdrh execsql {INSERT INTO t2 VALUES((SELECT max(a) FROM t2)+1,999)} 112309be024Sdrh } else { 113309be024Sdrh db function max_a_t2 {execsql {SELECT max(a) FROM t2}} 114309be024Sdrh execsql {INSERT INTO t2 VALUES(max_a_t2()+1,999)} 115309be024Sdrh } 116309be024Sdrh set sqlite_search_count 0 117309be024Sdrh execsql {SELECT max(a) FROM t2} 118309be024Sdrh} {21} 119309be024Sdrhdo_test minmax2-3.1 { 120309be024Sdrh set sqlite_search_count 121309be024Sdrh} {0} 122309be024Sdrhdo_test minmax2-3.2 { 123309be024Sdrh ifcapable subquery { 124309be024Sdrh execsql {INSERT INTO t2 VALUES((SELECT max(a) FROM t2)+1,999)} 125309be024Sdrh } else { 126309be024Sdrh db function max_a_t2 {execsql {SELECT max(a) FROM t2}} 127309be024Sdrh execsql {INSERT INTO t2 VALUES(max_a_t2()+1,999)} 128309be024Sdrh } 129309be024Sdrh set sqlite_search_count 0 130309be024Sdrh ifcapable subquery { 131309be024Sdrh execsql { SELECT b FROM t2 WHERE a=(SELECT max(a) FROM t2) } 132309be024Sdrh } else { 133309be024Sdrh execsql { SELECT b FROM t2 WHERE a=max_a_t2() } 134309be024Sdrh } 135309be024Sdrh} {999} 136309be024Sdrhdo_test minmax2-3.3 { 137309be024Sdrh set sqlite_search_count 138309be024Sdrh} {0} 139309be024Sdrh 140309be024Sdrhifcapable {compound && subquery} { 141309be024Sdrh do_test minmax2-4.1 { 142309be024Sdrh execsql { 143309be024Sdrh SELECT coalesce(min(x+0),-1), coalesce(max(x+0),-1) FROM 144309be024Sdrh (SELECT * FROM t1 UNION SELECT NULL as 'x', NULL as 'y') 145309be024Sdrh } 146309be024Sdrh } {1 20} 147309be024Sdrh do_test minmax2-4.2 { 148309be024Sdrh execsql { 149309be024Sdrh SELECT y, coalesce(sum(x),0) FROM 150309be024Sdrh (SELECT null AS x, y+1 AS y FROM t1 UNION SELECT * FROM t1) 151309be024Sdrh GROUP BY y ORDER BY y; 152309be024Sdrh } 153309be024Sdrh } {1 1 2 5 3 22 4 92 5 90 6 0} 154309be024Sdrh do_test minmax2-4.3 { 155309be024Sdrh execsql { 156309be024Sdrh SELECT y, count(x), count(*) FROM 157309be024Sdrh (SELECT null AS x, y+1 AS y FROM t1 UNION SELECT * FROM t1) 158309be024Sdrh GROUP BY y ORDER BY y; 159309be024Sdrh } 160309be024Sdrh } {1 1 1 2 2 3 3 4 5 4 8 9 5 5 6 6 0 1} 161309be024Sdrh} ;# ifcapable compound 162309be024Sdrh 163309be024Sdrh# Make sure the min(x) and max(x) optimizations work on empty tables 164309be024Sdrh# including empty tables with indices. Ticket #296. 165309be024Sdrh# 166309be024Sdrhdo_test minmax2-5.1 { 167309be024Sdrh execsql { 168309be024Sdrh CREATE TABLE t3(x INTEGER UNIQUE NOT NULL); 169309be024Sdrh SELECT coalesce(min(x),999) FROM t3; 170309be024Sdrh } 171309be024Sdrh} {999} 172309be024Sdrhdo_test minmax2-5.2 { 173309be024Sdrh execsql { 174309be024Sdrh SELECT coalesce(min(rowid),999) FROM t3; 175309be024Sdrh } 176309be024Sdrh} {999} 177309be024Sdrhdo_test minmax2-5.3 { 178309be024Sdrh execsql { 179309be024Sdrh SELECT coalesce(max(x),999) FROM t3; 180309be024Sdrh } 181309be024Sdrh} {999} 182309be024Sdrhdo_test minmax2-5.4 { 183309be024Sdrh execsql { 184309be024Sdrh SELECT coalesce(max(rowid),999) FROM t3; 185309be024Sdrh } 186309be024Sdrh} {999} 187309be024Sdrhdo_test minmax2-5.5 { 188309be024Sdrh execsql { 189309be024Sdrh SELECT coalesce(max(rowid),999) FROM t3 WHERE rowid<25; 190309be024Sdrh } 191309be024Sdrh} {999} 192309be024Sdrh 193309be024Sdrh# Make sure the min(x) and max(x) optimizations work when there 194309be024Sdrh# is a LIMIT clause. Ticket #396. 195309be024Sdrh# 196309be024Sdrhdo_test minmax2-6.1 { 197309be024Sdrh execsql { 198309be024Sdrh SELECT min(a) FROM t2 LIMIT 1 199309be024Sdrh } 200309be024Sdrh} {1} 201309be024Sdrhdo_test minmax2-6.2 { 202309be024Sdrh execsql { 203309be024Sdrh SELECT max(a) FROM t2 LIMIT 3 204309be024Sdrh } 205309be024Sdrh} {22} 206309be024Sdrhdo_test minmax2-6.3 { 207309be024Sdrh execsql { 208309be024Sdrh SELECT min(a) FROM t2 LIMIT 0,100 209309be024Sdrh } 210309be024Sdrh} {1} 211309be024Sdrhdo_test minmax2-6.4 { 212309be024Sdrh execsql { 213309be024Sdrh SELECT max(a) FROM t2 LIMIT 1,100 214309be024Sdrh } 215309be024Sdrh} {} 216309be024Sdrhdo_test minmax2-6.5 { 217309be024Sdrh execsql { 218309be024Sdrh SELECT min(x) FROM t3 LIMIT 1 219309be024Sdrh } 220309be024Sdrh} {{}} 221309be024Sdrhdo_test minmax2-6.6 { 222309be024Sdrh execsql { 223309be024Sdrh SELECT max(x) FROM t3 LIMIT 0 224309be024Sdrh } 225309be024Sdrh} {} 226309be024Sdrhdo_test minmax2-6.7 { 227309be024Sdrh execsql { 228309be024Sdrh SELECT max(a) FROM t2 LIMIT 0 229309be024Sdrh } 230309be024Sdrh} {} 231309be024Sdrh 232309be024Sdrh# Make sure the max(x) and min(x) optimizations work for nested 233309be024Sdrh# queries. Ticket #587. 234309be024Sdrh# 235309be024Sdrhdo_test minmax2-7.1 { 236309be024Sdrh execsql { 237309be024Sdrh SELECT max(x) FROM t1; 238309be024Sdrh } 239309be024Sdrh} 20 240309be024Sdrhifcapable subquery { 241309be024Sdrh do_test minmax2-7.2 { 242309be024Sdrh execsql { 243309be024Sdrh SELECT * FROM (SELECT max(x) FROM t1); 244309be024Sdrh } 245309be024Sdrh } 20 246309be024Sdrh} 247309be024Sdrhdo_test minmax2-7.3 { 248309be024Sdrh execsql { 249309be024Sdrh SELECT min(x) FROM t1; 250309be024Sdrh } 251309be024Sdrh} 1 252309be024Sdrhifcapable subquery { 253309be024Sdrh do_test minmax2-7.4 { 254309be024Sdrh execsql { 255309be024Sdrh SELECT * FROM (SELECT min(x) FROM t1); 256309be024Sdrh } 257309be024Sdrh } 1 258309be024Sdrh} 259309be024Sdrh 260309be024Sdrh# Make sure min(x) and max(x) work correctly when the datatype is 261309be024Sdrh# TEXT instead of NUMERIC. Ticket #623. 262309be024Sdrh# 263309be024Sdrhdo_test minmax2-8.1 { 264309be024Sdrh execsql { 265309be024Sdrh CREATE TABLE t4(a TEXT); 266309be024Sdrh INSERT INTO t4 VALUES('1234'); 267309be024Sdrh INSERT INTO t4 VALUES('234'); 268309be024Sdrh INSERT INTO t4 VALUES('34'); 269309be024Sdrh SELECT min(a), max(a) FROM t4; 270309be024Sdrh } 271309be024Sdrh} {1234 34} 272309be024Sdrhdo_test minmax2-8.2 { 273309be024Sdrh execsql { 274309be024Sdrh CREATE TABLE t5(a INTEGER); 275309be024Sdrh INSERT INTO t5 VALUES('1234'); 276309be024Sdrh INSERT INTO t5 VALUES('234'); 277309be024Sdrh INSERT INTO t5 VALUES('34'); 278309be024Sdrh SELECT min(a), max(a) FROM t5; 279309be024Sdrh } 280309be024Sdrh} {34 1234} 281309be024Sdrh 282309be024Sdrh# Ticket #658: Test the min()/max() optimization when the FROM clause 283309be024Sdrh# is a subquery. 284309be024Sdrh# 285309be024Sdrhifcapable {compound && subquery} { 286*6e5020e8Sdrh do_test minmax2-9.0 { 287*6e5020e8Sdrh execsql { 288*6e5020e8Sdrh SELECT max(rowid) FROM t4 UNION SELECT max(rowid) FROM t5 289*6e5020e8Sdrh } 290*6e5020e8Sdrh } {3} 291309be024Sdrh do_test minmax2-9.1 { 292309be024Sdrh execsql { 293*6e5020e8Sdrh SELECT max(yy) FROM ( 294*6e5020e8Sdrh SELECT max(rowid) AS yy FROM t4 UNION SELECT max(rowid) FROM t5 295309be024Sdrh ) 296309be024Sdrh } 297*6e5020e8Sdrh } {3} 298309be024Sdrh do_test minmax2-9.2 { 299309be024Sdrh execsql { 300*6e5020e8Sdrh SELECT max(yy) FROM ( 301*6e5020e8Sdrh SELECT max(rowid) AS yy FROM t4 EXCEPT SELECT max(rowid) FROM t5 302309be024Sdrh ) 303309be024Sdrh } 304309be024Sdrh } {{}} 305309be024Sdrh} ;# ifcapable compound&&subquery 306309be024Sdrh 307309be024Sdrh# If there is a NULL in an aggregate max() or min(), ignore it. An 308309be024Sdrh# aggregate min() or max() will only return NULL if all values are NULL. 309309be024Sdrh# 310309be024Sdrhdo_test minmax2-10.1 { 311309be024Sdrh execsql { 312309be024Sdrh CREATE TABLE t6(x); 313309be024Sdrh INSERT INTO t6 VALUES(1); 314309be024Sdrh INSERT INTO t6 VALUES(2); 315309be024Sdrh INSERT INTO t6 VALUES(NULL); 316309be024Sdrh SELECT coalesce(min(x),-1) FROM t6; 317309be024Sdrh } 318309be024Sdrh} {1} 319309be024Sdrhdo_test minmax2-10.2 { 320309be024Sdrh execsql { 321309be024Sdrh SELECT max(x) FROM t6; 322309be024Sdrh } 323309be024Sdrh} {2} 324309be024Sdrhdo_test minmax2-10.3 { 325309be024Sdrh execsql { 326309be024Sdrh CREATE INDEX i6 ON t6(x DESC); 327309be024Sdrh SELECT coalesce(min(x),-1) FROM t6; 328309be024Sdrh } 329309be024Sdrh} {1} 330309be024Sdrhdo_test minmax2-10.4 { 331309be024Sdrh execsql { 332309be024Sdrh SELECT max(x) FROM t6; 333309be024Sdrh } 334309be024Sdrh} {2} 335309be024Sdrhdo_test minmax2-10.5 { 336309be024Sdrh execsql { 337309be024Sdrh DELETE FROM t6 WHERE x NOT NULL; 338309be024Sdrh SELECT count(*) FROM t6; 339309be024Sdrh } 340309be024Sdrh} 1 341309be024Sdrhdo_test minmax2-10.6 { 342309be024Sdrh execsql { 343309be024Sdrh SELECT count(x) FROM t6; 344309be024Sdrh } 345309be024Sdrh} 0 346309be024Sdrhifcapable subquery { 347309be024Sdrh do_test minmax2-10.7 { 348309be024Sdrh execsql { 349309be024Sdrh SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6); 350309be024Sdrh } 351309be024Sdrh } {{} {}} 352309be024Sdrh} 353309be024Sdrhdo_test minmax2-10.8 { 354309be024Sdrh execsql { 355309be024Sdrh SELECT min(x), max(x) FROM t6; 356309be024Sdrh } 357309be024Sdrh} {{} {}} 358309be024Sdrhdo_test minmax2-10.9 { 359309be024Sdrh execsql { 360309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 361309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 362309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 363309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 364309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 365309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 366309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 367309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 368309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 369309be024Sdrh INSERT INTO t6 SELECT * FROM t6; 370309be024Sdrh SELECT count(*) FROM t6; 371309be024Sdrh } 372309be024Sdrh} 1024 373309be024Sdrhdo_test minmax2-10.10 { 374309be024Sdrh execsql { 375309be024Sdrh SELECT count(x) FROM t6; 376309be024Sdrh } 377309be024Sdrh} 0 378309be024Sdrhifcapable subquery { 379309be024Sdrh do_test minmax2-10.11 { 380309be024Sdrh execsql { 381309be024Sdrh SELECT (SELECT min(x) FROM t6), (SELECT max(x) FROM t6); 382309be024Sdrh } 383309be024Sdrh } {{} {}} 384309be024Sdrh} 385309be024Sdrhdo_test minmax2-10.12 { 386309be024Sdrh execsql { 387309be024Sdrh SELECT min(x), max(x) FROM t6; 388309be024Sdrh } 389309be024Sdrh} {{} {}} 390309be024Sdrh 39147d9f839Sdrh# 2017-10-26. Extend the min/max optimization to indexes on expressions 39247d9f839Sdrh# 39347d9f839Sdrhdo_execsql_test minmax2-11.100 { 39447d9f839Sdrh CREATE TABLE t11(a,b,c); 39547d9f839Sdrh INSERT INTO t11(a,b,c) VALUES(1,10,5),(2,8,11),(3,1,4),(4,20,1),(5,16,4); 39647d9f839Sdrh CREATE INDEX t11bc ON t11(b+c); 39747d9f839Sdrh SELECT max(b+c) FROM t11; 39847d9f839Sdrh} {21} 39947d9f839Sdrhdo_execsql_test minmax2-11.110 { 40047d9f839Sdrh SELECT a, max(b+c) FROM t11; 40147d9f839Sdrh} {4 21} 40247d9f839Sdrhdo_test minmax2-11.111 { 40347d9f839Sdrh db eval {SELECT max(b+c) FROM t11} 40447d9f839Sdrh db status step 40547d9f839Sdrh} {0} 40647d9f839Sdrhdo_test minmax2-11.112 { 40747d9f839Sdrh db eval {SELECT max(c+b) FROM t11} 40847d9f839Sdrh db status step 40947d9f839Sdrh} {4} 41047d9f839Sdrhdo_execsql_test minmax2-11.120 { 41147d9f839Sdrh SELECT a, min(b+c) FROM t11; 41247d9f839Sdrh} {3 5} 41347d9f839Sdrhdo_test minmax2-11.121 { 41447d9f839Sdrh db eval {SELECT min(b+c) FROM t11} 41547d9f839Sdrh db status step 41647d9f839Sdrh} {0} 41747d9f839Sdrhdo_test minmax2-11.122 { 41847d9f839Sdrh db eval {SELECT min(c+b) FROM t11} 41947d9f839Sdrh db status step 42047d9f839Sdrh} {4} 42147d9f839Sdrhdo_execsql_test minmax2-11.130 { 42247d9f839Sdrh INSERT INTO t11(a,b,c) VALUES(6,NULL,0),(7,0,NULL); 42347d9f839Sdrh SELECT a, min(b+c) FROM t11; 42447d9f839Sdrh} {3 5} 425309be024Sdrh 426309be024Sdrhfinish_test 427