1# 2010 July 16 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 6# May you do good and not evil. 7# May you find forgiveness for yourself and forgive others. 8# May you share freely, never taking more than you give. 9# 10#*********************************************************************** 11# 12# This file implements tests to verify that the "testable statements" in 13# the lang_select.html document are correct. 14# 15 16set testdir [file dirname $argv0] 17source $testdir/tester.tcl 18 19ifcapable !compound { 20 finish_test 21 return 22} 23 24do_execsql_test e_select-1.0 { 25 CREATE TABLE t1(a, b); 26 INSERT INTO t1 VALUES('a', 'one'); 27 INSERT INTO t1 VALUES('b', 'two'); 28 INSERT INTO t1 VALUES('c', 'three'); 29 30 CREATE TABLE t2(a, b); 31 INSERT INTO t2 VALUES('a', 'I'); 32 INSERT INTO t2 VALUES('b', 'II'); 33 INSERT INTO t2 VALUES('c', 'III'); 34 35 CREATE TABLE t3(a, c); 36 INSERT INTO t3 VALUES('a', 1); 37 INSERT INTO t3 VALUES('b', 2); 38 39 CREATE TABLE t4(a, c); 40 INSERT INTO t4 VALUES('a', NULL); 41 INSERT INTO t4 VALUES('b', 2); 42} {} 43set t1_cross_t2 [list \ 44 a one a I a one b II \ 45 a one c III b two a I \ 46 b two b II b two c III \ 47 c three a I c three b II \ 48 c three c III \ 49] 50set t1_cross_t1 [list \ 51 a one a one a one b two \ 52 a one c three b two a one \ 53 b two b two b two c three \ 54 c three a one c three b two \ 55 c three c three \ 56] 57 58 59# This proc is a specialized version of [do_execsql_test]. 60# 61# The second argument to this proc must be a SELECT statement that 62# features a cross join of some time. Instead of the usual ",", 63# "CROSS JOIN" or "INNER JOIN" join-op, the string %JOIN% must be 64# substituted. 65# 66# This test runs the SELECT three times - once with: 67# 68# * s/%JOIN%/,/ 69# * s/%JOIN%/JOIN/ 70# * s/%JOIN%/INNER JOIN/ 71# * s/%JOIN%/CROSS JOIN/ 72# 73# and checks that each time the results of the SELECT are $res. 74# 75proc do_join_test {tn select res} { 76 foreach {tn2 joinop} [list 1 , 2 "CROSS JOIN" 3 "INNER JOIN"] { 77 set S [string map [list %JOIN% $joinop] $select] 78 uplevel do_execsql_test $tn.$tn2 [list $S] [list $res] 79 } 80} 81 82#------------------------------------------------------------------------- 83# The following tests check that all paths on the syntax diagrams on 84# the lang_select.html page may be taken. 85# 86# -- syntax diagram join-constraint 87# 88do_join_test e_select-0.1.1 { 89 SELECT count(*) FROM t1 %JOIN% t2 ON (t1.a=t2.a) 90} {3} 91do_join_test e_select-0.1.2 { 92 SELECT count(*) FROM t1 %JOIN% t2 USING (a) 93} {3} 94do_join_test e_select-0.1.3 { 95 SELECT count(*) FROM t1 %JOIN% t2 96} {9} 97do_catchsql_test e_select-0.1.4 { 98 SELECT count(*) FROM t1, t2 ON (t1.a=t2.a) USING (a) 99} {1 {cannot have both ON and USING clauses in the same join}} 100do_catchsql_test e_select-0.1.5 { 101 SELECT count(*) FROM t1, t2 USING (a) ON (t1.a=t2.a) 102} {1 {near "ON": syntax error}} 103 104# -- syntax diagram select-core 105# 106# 0: SELECT ... 107# 1: SELECT DISTINCT ... 108# 2: SELECT ALL ... 109# 110# 0: No FROM clause 111# 1: Has FROM clause 112# 113# 0: No WHERE clause 114# 1: Has WHERE clause 115# 116# 0: No GROUP BY clause 117# 1: Has GROUP BY clause 118# 2: Has GROUP BY and HAVING clauses 119# 120do_select_tests e_select-0.2 { 121 0000.1 "SELECT 1, 2, 3 " {1 2 3} 122 1000.1 "SELECT DISTINCT 1, 2, 3 " {1 2 3} 123 2000.1 "SELECT ALL 1, 2, 3 " {1 2 3} 124 125 0100.1 "SELECT a, b, a||b FROM t1 " { 126 a one aone b two btwo c three cthree 127 } 128 1100.1 "SELECT DISTINCT a, b, a||b FROM t1 " { 129 a one aone b two btwo c three cthree 130 } 131 1200.1 "SELECT ALL a, b, a||b FROM t1 " { 132 a one aone b two btwo c three cthree 133 } 134 135 0010.1 "SELECT 1, 2, 3 WHERE 1 " {1 2 3} 136 0010.2 "SELECT 1, 2, 3 WHERE 0 " {} 137 0010.3 "SELECT 1, 2, 3 WHERE NULL " {} 138 139 1010.1 "SELECT DISTINCT 1, 2, 3 WHERE 1 " {1 2 3} 140 141 2010.1 "SELECT ALL 1, 2, 3 WHERE 1 " {1 2 3} 142 143 0110.1 "SELECT a, b, a||b FROM t1 WHERE a!='x' " { 144 a one aone b two btwo c three cthree 145 } 146 0110.2 "SELECT a, b, a||b FROM t1 WHERE a=='x'" {} 147 148 1110.1 "SELECT DISTINCT a, b, a||b FROM t1 WHERE a!='x' " { 149 a one aone b two btwo c three cthree 150 } 151 152 2110.0 "SELECT ALL a, b, a||b FROM t1 WHERE a=='x'" {} 153 154 0001.1 "SELECT 1, 2, 3 GROUP BY 2" {1 2 3} 155 0002.1 "SELECT 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3} 156 0002.2 "SELECT 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {} 157 158 1001.1 "SELECT DISTINCT 1, 2, 3 GROUP BY 2" {1 2 3} 159 1002.1 "SELECT DISTINCT 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3} 160 1002.2 "SELECT DISTINCT 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {} 161 162 2001.1 "SELECT ALL 1, 2, 3 GROUP BY 2" {1 2 3} 163 2002.1 "SELECT ALL 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3} 164 2002.2 "SELECT ALL 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {} 165 166 0101.1 "SELECT count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b} 167 0102.1 "SELECT count(*), max(a) FROM t1 GROUP BY b HAVING count(*)=1" { 168 1 a 1 c 1 b 169 } 170 0102.2 "SELECT count(*), max(a) FROM t1 GROUP BY b HAVING count(*)=2" {} 171 172 1101.1 "SELECT DISTINCT count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b} 173 1102.1 "SELECT DISTINCT count(*), max(a) FROM t1 174 GROUP BY b HAVING count(*)=1" { 175 1 a 1 c 1 b 176 } 177 1102.2 "SELECT DISTINCT count(*), max(a) FROM t1 178 GROUP BY b HAVING count(*)=2" {} 179 180 2101.1 "SELECT ALL count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b} 181 2102.1 "SELECT ALL count(*), max(a) FROM t1 182 GROUP BY b HAVING count(*)=1" { 183 1 a 1 c 1 b 184 } 185 2102.2 "SELECT ALL count(*), max(a) FROM t1 186 GROUP BY b HAVING count(*)=2" {} 187 188 0011.1 "SELECT 1, 2, 3 WHERE 1 GROUP BY 2" {1 2 3} 189 0012.1 "SELECT 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)=1" {} 190 0012.2 "SELECT 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)>1" {} 191 192 1011.1 "SELECT DISTINCT 1, 2, 3 WHERE 0 GROUP BY 2" {} 193 1012.1 "SELECT DISTINCT 1, 2, 3 WHERE 1 GROUP BY 2 HAVING count(*)=1" 194 {1 2 3} 195 1012.2 "SELECT DISTINCT 1, 2, 3 WHERE NULL GROUP BY 2 HAVING count(*)>1" {} 196 197 2011.1 "SELECT ALL 1, 2, 3 WHERE 1 GROUP BY 2" {1 2 3} 198 2012.1 "SELECT ALL 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)=1" {} 199 2012.2 "SELECT ALL 1, 2, 3 WHERE 'abc' GROUP BY 2 HAVING count(*)>1" {} 200 201 0111.1 "SELECT count(*), max(a) FROM t1 WHERE a='a' GROUP BY b" {1 a} 202 0112.1 "SELECT count(*), max(a) FROM t1 203 WHERE a='c' GROUP BY b HAVING count(*)=1" {1 c} 204 0112.2 "SELECT count(*), max(a) FROM t1 205 WHERE 0 GROUP BY b HAVING count(*)=2" {} 206 1111.1 "SELECT DISTINCT count(*), max(a) FROM t1 WHERE a<'c' GROUP BY b" 207 {1 a 1 b} 208 1112.1 "SELECT DISTINCT count(*), max(a) FROM t1 WHERE a>'a' 209 GROUP BY b HAVING count(*)=1" { 210 1 c 1 b 211 } 212 1112.2 "SELECT DISTINCT count(*), max(a) FROM t1 WHERE 0 213 GROUP BY b HAVING count(*)=2" {} 214 215 2111.1 "SELECT ALL count(*), max(a) FROM t1 WHERE b>'one' GROUP BY b" 216 {1 c 1 b} 217 2112.1 "SELECT ALL count(*), max(a) FROM t1 WHERE a!='b' 218 GROUP BY b HAVING count(*)=1" { 219 1 a 1 c 220 } 221 2112.2 "SELECT ALL count(*), max(a) FROM t1 222 WHERE 0 GROUP BY b HAVING count(*)=2" {} 223} 224 225 226# -- syntax diagram result-column 227# 228do_select_tests e_select-0.3 { 229 1 "SELECT * FROM t1" {a one b two c three} 230 2 "SELECT t1.* FROM t1" {a one b two c three} 231 3 "SELECT 'x'||a||'x' FROM t1" {xax xbx xcx} 232 4 "SELECT 'x'||a||'x' alias FROM t1" {xax xbx xcx} 233 5 "SELECT 'x'||a||'x' AS alias FROM t1" {xax xbx xcx} 234} 235 236# -- syntax diagram join-source 237# 238# -- syntax diagram join-op 239# 240do_select_tests e_select-0.4 { 241 1 "SELECT t1.rowid FROM t1" {1 2 3} 242 2 "SELECT t1.rowid FROM t1,t2" {1 1 1 2 2 2 3 3 3} 243 3 "SELECT t1.rowid FROM t1,t2,t3" {1 1 1 1 1 1 2 2 2 2 2 2 3 3 3 3 3 3} 244 245 4 "SELECT t1.rowid FROM t1" {1 2 3} 246 5 "SELECT t1.rowid FROM t1 JOIN t2" {1 1 1 2 2 2 3 3 3} 247 6 "SELECT t1.rowid FROM t1 JOIN t2 JOIN t3" 248 {1 1 1 1 1 1 2 2 2 2 2 2 3 3 3 3 3 3} 249 250 7 "SELECT t1.rowid FROM t1 NATURAL JOIN t3" {1 2} 251 8 "SELECT t1.rowid FROM t1 NATURAL LEFT OUTER JOIN t3" {1 2 3} 252 9 "SELECT t1.rowid FROM t1 NATURAL LEFT JOIN t3" {1 2 3} 253 10 "SELECT t1.rowid FROM t1 NATURAL INNER JOIN t3" {1 2} 254 11 "SELECT t1.rowid FROM t1 NATURAL CROSS JOIN t3" {1 2} 255 256 12 "SELECT t1.rowid FROM t1 JOIN t3" {1 1 2 2 3 3} 257 13 "SELECT t1.rowid FROM t1 LEFT OUTER JOIN t3" {1 1 2 2 3 3} 258 14 "SELECT t1.rowid FROM t1 LEFT JOIN t3" {1 1 2 2 3 3} 259 15 "SELECT t1.rowid FROM t1 INNER JOIN t3" {1 1 2 2 3 3} 260 16 "SELECT t1.rowid FROM t1 CROSS JOIN t3" {1 1 2 2 3 3} 261} 262 263# -- syntax diagram compound-operator 264# 265do_select_tests e_select-0.5 { 266 1 "SELECT rowid FROM t1 UNION ALL SELECT rowid+2 FROM t4" {1 2 3 3 4} 267 2 "SELECT rowid FROM t1 UNION SELECT rowid+2 FROM t4" {1 2 3 4} 268 3 "SELECT rowid FROM t1 INTERSECT SELECT rowid+2 FROM t4" {3} 269 4 "SELECT rowid FROM t1 EXCEPT SELECT rowid+2 FROM t4" {1 2} 270} 271 272# -- syntax diagram ordering-term 273# 274do_select_tests e_select-0.6 { 275 1 "SELECT b||a FROM t1 ORDER BY b||a" {onea threec twob} 276 2 "SELECT b||a FROM t1 ORDER BY (b||a) COLLATE nocase" {onea threec twob} 277 3 "SELECT b||a FROM t1 ORDER BY (b||a) ASC" {onea threec twob} 278 4 "SELECT b||a FROM t1 ORDER BY (b||a) DESC" {twob threec onea} 279} 280 281# -- syntax diagram select-stmt 282# 283do_select_tests e_select-0.7 { 284 1 "SELECT * FROM t1" {a one b two c three} 285 2 "SELECT * FROM t1 ORDER BY b" {a one c three b two} 286 3 "SELECT * FROM t1 ORDER BY b, a" {a one c three b two} 287 288 4 "SELECT * FROM t1 LIMIT 10" {a one b two c three} 289 5 "SELECT * FROM t1 LIMIT 10 OFFSET 5" {} 290 6 "SELECT * FROM t1 LIMIT 10, 5" {} 291 292 7 "SELECT * FROM t1 ORDER BY a LIMIT 10" {a one b two c three} 293 8 "SELECT * FROM t1 ORDER BY b LIMIT 10 OFFSET 5" {} 294 9 "SELECT * FROM t1 ORDER BY a,b LIMIT 10, 5" {} 295 296 10 "SELECT * FROM t1 UNION SELECT b, a FROM t1" 297 {a one b two c three one a three c two b} 298 11 "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b" 299 {one a two b three c a one c three b two} 300 12 "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b, a" 301 {one a two b three c a one c three b two} 302 13 "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10" 303 {a one b two c three one a three c two b} 304 14 "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10 OFFSET 5" 305 {two b} 306 15 "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10, 5" 307 {} 308 16 "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY a LIMIT 10" 309 {a one b two c three one a three c two b} 310 17 "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b LIMIT 10 OFFSET 5" 311 {b two} 312 18 "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY a,b LIMIT 10, 5" 313 {} 314} 315 316#------------------------------------------------------------------------- 317# The following tests focus on FROM clause (join) processing. 318# 319 320# EVIDENCE-OF: R-16074-54196 If the FROM clause is omitted from a simple 321# SELECT statement, then the input data is implicitly a single row zero 322# columns wide 323# 324do_select_tests e_select-1.1 { 325 1 "SELECT 'abc'" {abc} 326 2 "SELECT 'abc' WHERE NULL" {} 327 3 "SELECT NULL" {{}} 328 4 "SELECT count(*)" {1} 329 5 "SELECT count(*) WHERE 0" {0} 330 6 "SELECT count(*) WHERE 1" {1} 331} 332 333# EVIDENCE-OF: R-45424-07352 If there is only a single table or subquery 334# in the FROM clause, then the input data used by the SELECT statement 335# is the contents of the named table. 336# 337# The results of the SELECT queries suggest that they are operating on the 338# contents of the table 'xx'. 339# 340do_execsql_test e_select-1.2.0 { 341 CREATE TABLE xx(x, y); 342 INSERT INTO xx VALUES('IiJlsIPepMuAhU', X'10B00B897A15BAA02E3F98DCE8F2'); 343 INSERT INTO xx VALUES(NULL, -16.87); 344 INSERT INTO xx VALUES(-17.89, 'linguistically'); 345} {} 346do_select_tests e_select-1.2 { 347 1 "SELECT quote(x), quote(y) FROM xx" { 348 'IiJlsIPepMuAhU' X'10B00B897A15BAA02E3F98DCE8F2' 349 NULL -16.87 350 -17.89 'linguistically' 351 } 352 353 2 "SELECT count(*), count(x), count(y) FROM xx" {3 2 3} 354 3 "SELECT sum(x), sum(y) FROM xx" {-17.89 -16.87} 355} 356 357# EVIDENCE-OF: R-28355-09804 If there is more than one table or subquery 358# in FROM clause then the contents of all tables and/or subqueries are 359# joined into a single dataset for the simple SELECT statement to 360# operate on. 361# 362# There are more detailed tests for subsequent requirements that add 363# more detail to this idea. We just add a single test that shows that 364# data is coming from each of the three tables following the FROM clause 365# here to show that the statement, vague as it is, is not incorrect. 366# 367do_select_tests e_select-1.3 { 368 1 "SELECT * FROM t1, t2, t3" { 369 a one a I a 1 a one a I b 2 a one b II a 1 370 a one b II b 2 a one c III a 1 a one c III b 2 371 b two a I a 1 b two a I b 2 b two b II a 1 372 b two b II b 2 b two c III a 1 b two c III b 2 373 c three a I a 1 c three a I b 2 c three b II a 1 374 c three b II b 2 c three c III a 1 c three c III b 2 375 } 376} 377 378# 379# The following block of tests - e_select-1.4.* - test that the description 380# of cartesian joins in the SELECT documentation is consistent with SQLite. 381# In doing so, we test the following three requirements as a side-effect: 382# 383# EVIDENCE-OF: R-49872-03192 If the join-operator is "CROSS JOIN", 384# "INNER JOIN", "JOIN" or a comma (",") and there is no ON or USING 385# clause, then the result of the join is simply the cartesian product of 386# the left and right-hand datasets. 387# 388# The tests are built on this assertion. Really, they test that the output 389# of a CROSS JOIN, JOIN, INNER JOIN or "," join matches the expected result 390# of calculating the cartesian product of the left and right-hand datasets. 391# 392# EVIDENCE-OF: R-46256-57243 There is no difference between the "INNER 393# JOIN", "JOIN" and "," join operators. 394# 395# EVIDENCE-OF: R-25071-21202 The "CROSS JOIN" join operator produces the 396# same result as the "INNER JOIN", "JOIN" and "," operators 397# 398# All tests are run 4 times, with the only difference in each run being 399# which of the 4 equivalent cartesian product join operators are used. 400# Since the output data is the same in all cases, we consider that this 401# qualifies as testing the two statements above. 402# 403do_execsql_test e_select-1.4.0 { 404 CREATE TABLE x1(a, b); 405 CREATE TABLE x2(c, d, e); 406 CREATE TABLE x3(f, g, h, i); 407 408 -- x1: 3 rows, 2 columns 409 INSERT INTO x1 VALUES(24, 'converging'); 410 INSERT INTO x1 VALUES(NULL, X'CB71'); 411 INSERT INTO x1 VALUES('blonds', 'proprietary'); 412 413 -- x2: 2 rows, 3 columns 414 INSERT INTO x2 VALUES(-60.06, NULL, NULL); 415 INSERT INTO x2 VALUES(-58, NULL, 1.21); 416 417 -- x3: 5 rows, 4 columns 418 INSERT INTO x3 VALUES(-39.24, NULL, 'encompass', -1); 419 INSERT INTO x3 VALUES('presenting', 51, 'reformation', 'dignified'); 420 INSERT INTO x3 VALUES('conducting', -87.24, 37.56, NULL); 421 INSERT INTO x3 VALUES('coldest', -96, 'dramatists', 82.3); 422 INSERT INTO x3 VALUES('alerting', NULL, -93.79, NULL); 423} {} 424 425# EVIDENCE-OF: R-59089-25828 The columns of the cartesian product 426# dataset are, in order, all the columns of the left-hand dataset 427# followed by all the columns of the right-hand dataset. 428# 429do_join_test e_select-1.4.1.1 { 430 SELECT * FROM x1 %JOIN% x2 LIMIT 1 431} [concat {24 converging} {-60.06 {} {}}] 432 433do_join_test e_select-1.4.1.2 { 434 SELECT * FROM x2 %JOIN% x1 LIMIT 1 435} [concat {-60.06 {} {}} {24 converging}] 436 437do_join_test e_select-1.4.1.3 { 438 SELECT * FROM x3 %JOIN% x2 LIMIT 1 439} [concat {-39.24 {} encompass -1} {-60.06 {} {}}] 440 441do_join_test e_select-1.4.1.4 { 442 SELECT * FROM x2 %JOIN% x3 LIMIT 1 443} [concat {-60.06 {} {}} {-39.24 {} encompass -1}] 444 445# EVIDENCE-OF: R-44414-54710 There is a row in the cartesian product 446# dataset formed by combining each unique combination of a row from the 447# left-hand and right-hand datasets. 448# 449do_join_test e_select-1.4.2.1 { 450 SELECT * FROM x2 %JOIN% x3 ORDER BY +c, +f 451} [list -60.06 {} {} -39.24 {} encompass -1 \ 452 -60.06 {} {} alerting {} -93.79 {} \ 453 -60.06 {} {} coldest -96 dramatists 82.3 \ 454 -60.06 {} {} conducting -87.24 37.56 {} \ 455 -60.06 {} {} presenting 51 reformation dignified \ 456 -58 {} 1.21 -39.24 {} encompass -1 \ 457 -58 {} 1.21 alerting {} -93.79 {} \ 458 -58 {} 1.21 coldest -96 dramatists 82.3 \ 459 -58 {} 1.21 conducting -87.24 37.56 {} \ 460 -58 {} 1.21 presenting 51 reformation dignified \ 461] 462# TODO: Come back and add a few more like the above. 463 464# EVIDENCE-OF: R-18439-38548 In other words, if the left-hand dataset 465# consists of Nleft rows of Mleft columns, and the right-hand dataset of 466# Nright rows of Mright columns, then the cartesian product is a dataset 467# of Nleft×Nright rows, each containing Mleft+Mright columns. 468# 469# x1, x2 (Nlhs=3, Nrhs=2) (Mlhs=2, Mrhs=3) 470do_join_test e_select-1.4.3.1 { 471 SELECT count(*) FROM x1 %JOIN% x2 472} [expr 3*2] 473do_test e_select-1.4.3.2 { 474 expr {[llength [execsql {SELECT * FROM x1, x2}]] / 6} 475} [expr 2+3] 476 477# x2, x3 (Nlhs=2, Nrhs=5) (Mlhs=3, Mrhs=4) 478do_join_test e_select-1.4.3.3 { 479 SELECT count(*) FROM x2 %JOIN% x3 480} [expr 2*5] 481do_test e_select-1.4.3.4 { 482 expr {[llength [execsql {SELECT * FROM x2 JOIN x3}]] / 10} 483} [expr 3+4] 484 485# x3, x1 (Nlhs=5, Nrhs=3) (Mlhs=4, Mrhs=2) 486do_join_test e_select-1.4.3.5 { 487 SELECT count(*) FROM x3 %JOIN% x1 488} [expr 5*3] 489do_test e_select-1.4.3.6 { 490 expr {[llength [execsql {SELECT * FROM x3 CROSS JOIN x1}]] / 15} 491} [expr 4+2] 492 493# x3, x3 (Nlhs=5, Nrhs=5) (Mlhs=4, Mrhs=4) 494do_join_test e_select-1.4.3.7 { 495 SELECT count(*) FROM x3 %JOIN% x3 496} [expr 5*5] 497do_test e_select-1.4.3.8 { 498 expr {[llength [execsql {SELECT * FROM x3 INNER JOIN x3 AS x4}]] / 25} 499} [expr 4+4] 500 501# Some extra cartesian product tests using tables t1 and t2. 502# 503do_execsql_test e_select-1.4.4.1 { SELECT * FROM t1, t2 } $t1_cross_t2 504do_execsql_test e_select-1.4.4.2 { SELECT * FROM t1 AS x, t1 AS y} $t1_cross_t1 505 506do_select_tests e_select-1.4.5 [list \ 507 1 { SELECT * FROM t1 CROSS JOIN t2 } $t1_cross_t2 \ 508 2 { SELECT * FROM t1 AS y CROSS JOIN t1 AS x } $t1_cross_t1 \ 509 3 { SELECT * FROM t1 INNER JOIN t2 } $t1_cross_t2 \ 510 4 { SELECT * FROM t1 AS y INNER JOIN t1 AS x } $t1_cross_t1 \ 511] 512 513# EVIDENCE-OF: R-38465-03616 If there is an ON clause then the ON 514# expression is evaluated for each row of the cartesian product as a 515# boolean expression. Only rows for which the expression evaluates to 516# true are included from the dataset. 517# 518foreach {tn select res} [list \ 519 1 { SELECT * FROM t1 %JOIN% t2 ON (1) } $t1_cross_t2 \ 520 2 { SELECT * FROM t1 %JOIN% t2 ON (0) } [list] \ 521 3 { SELECT * FROM t1 %JOIN% t2 ON (NULL) } [list] \ 522 4 { SELECT * FROM t1 %JOIN% t2 ON ('abc') } [list] \ 523 5 { SELECT * FROM t1 %JOIN% t2 ON ('1ab') } $t1_cross_t2 \ 524 6 { SELECT * FROM t1 %JOIN% t2 ON (0.9) } $t1_cross_t2 \ 525 7 { SELECT * FROM t1 %JOIN% t2 ON ('0.9') } $t1_cross_t2 \ 526 8 { SELECT * FROM t1 %JOIN% t2 ON (0.0) } [list] \ 527 \ 528 9 { SELECT t1.b, t2.b FROM t1 %JOIN% t2 ON (t1.a = t2.a) } \ 529 {one I two II three III} \ 530 10 { SELECT t1.b, t2.b FROM t1 %JOIN% t2 ON (t1.a = 'a') } \ 531 {one I one II one III} \ 532 11 { SELECT t1.b, t2.b 533 FROM t1 %JOIN% t2 ON (CASE WHEN t1.a = 'a' THEN NULL ELSE 1 END) } \ 534 {two I two II two III three I three II three III} \ 535] { 536 do_join_test e_select-1.3.$tn $select $res 537} 538 539# EVIDENCE-OF: R-49933-05137 If there is a USING clause then each of the 540# column names specified must exist in the datasets to both the left and 541# right of the join-operator. 542# 543do_select_tests e_select-1.4 -error { 544 cannot join using column %s - column not present in both tables 545} { 546 1 { SELECT * FROM t1, t3 USING (b) } "b" 547 2 { SELECT * FROM t3, t1 USING (c) } "c" 548 3 { SELECT * FROM t3, (SELECT a AS b, b AS c FROM t1) USING (a) } "a" 549} 550 551# EVIDENCE-OF: R-22776-52830 For each pair of named columns, the 552# expression "lhs.X = rhs.X" is evaluated for each row of the cartesian 553# product as a boolean expression. Only rows for which all such 554# expressions evaluates to true are included from the result set. 555# 556do_select_tests e_select-1.5 { 557 1 { SELECT * FROM t1, t3 USING (a) } {a one 1 b two 2} 558 2 { SELECT * FROM t3, t4 USING (a,c) } {b 2} 559} 560 561# EVIDENCE-OF: R-54046-48600 When comparing values as a result of a 562# USING clause, the normal rules for handling affinities, collation 563# sequences and NULL values in comparisons apply. 564# 565# EVIDENCE-OF: R-38422-04402 The column from the dataset on the 566# left-hand side of the join-operator is considered to be on the 567# left-hand side of the comparison operator (=) for the purposes of 568# collation sequence and affinity precedence. 569# 570do_execsql_test e_select-1.6.0 { 571 CREATE TABLE t5(a COLLATE nocase, b COLLATE binary); 572 INSERT INTO t5 VALUES('AA', 'cc'); 573 INSERT INTO t5 VALUES('BB', 'dd'); 574 INSERT INTO t5 VALUES(NULL, NULL); 575 CREATE TABLE t6(a COLLATE binary, b COLLATE nocase); 576 INSERT INTO t6 VALUES('aa', 'cc'); 577 INSERT INTO t6 VALUES('bb', 'DD'); 578 INSERT INTO t6 VALUES(NULL, NULL); 579} {} 580foreach {tn select res} { 581 1 { SELECT * FROM t5 %JOIN% t6 USING (a) } {AA cc cc BB dd DD} 582 2 { SELECT * FROM t6 %JOIN% t5 USING (a) } {} 583 3 { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) %JOIN% t5 USING (a) } 584 {aa cc cc bb DD dd} 585 4 { SELECT * FROM t5 %JOIN% t6 USING (a,b) } {AA cc} 586 5 { SELECT * FROM t6 %JOIN% t5 USING (a,b) } {} 587} { 588 do_join_test e_select-1.6.$tn $select $res 589} 590 591# EVIDENCE-OF: R-57047-10461 For each pair of columns identified by a 592# USING clause, the column from the right-hand dataset is omitted from 593# the joined dataset. 594# 595# EVIDENCE-OF: R-56132-15700 This is the only difference between a USING 596# clause and its equivalent ON constraint. 597# 598foreach {tn select res} { 599 1a { SELECT * FROM t1 %JOIN% t2 USING (a) } 600 {a one I b two II c three III} 601 1b { SELECT * FROM t1 %JOIN% t2 ON (t1.a=t2.a) } 602 {a one a I b two b II c three c III} 603 604 2a { SELECT * FROM t3 %JOIN% t4 USING (a) } 605 {a 1 {} b 2 2} 606 2b { SELECT * FROM t3 %JOIN% t4 ON (t3.a=t4.a) } 607 {a 1 a {} b 2 b 2} 608 609 3a { SELECT * FROM t3 %JOIN% t4 USING (a,c) } {b 2} 610 3b { SELECT * FROM t3 %JOIN% t4 ON (t3.a=t4.a AND t3.c=t4.c) } {b 2 b 2} 611 612 4a { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) AS x 613 %JOIN% t5 USING (a) } 614 {aa cc cc bb DD dd} 615 4b { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) AS x 616 %JOIN% t5 ON (x.a=t5.a) } 617 {aa cc AA cc bb DD BB dd} 618} { 619 do_join_test e_select-1.7.$tn $select $res 620} 621# EVIDENCE-OF: R-42531-52874 If the join-operator is a "LEFT JOIN" or 622# "LEFT OUTER JOIN", then after the ON or USING filtering clauses have 623# been applied, an extra row is added to the output for each row in the 624# original left-hand input dataset that corresponds to no rows at all in 625# the composite dataset (if any). 626# 627do_execsql_test e_select-1.8.0 { 628 CREATE TABLE t7(a, b, c); 629 CREATE TABLE t8(a, d, e); 630 631 INSERT INTO t7 VALUES('x', 'ex', 24); 632 INSERT INTO t7 VALUES('y', 'why', 25); 633 634 INSERT INTO t8 VALUES('x', 'abc', 24); 635 INSERT INTO t8 VALUES('z', 'ghi', 26); 636} {} 637 638do_select_tests e_select-1.8 { 639 1a "SELECT count(*) FROM t7 JOIN t8 ON (t7.a=t8.a)" {1} 640 1b "SELECT count(*) FROM t7 LEFT JOIN t8 ON (t7.a=t8.a)" {2} 641 2a "SELECT count(*) FROM t7 JOIN t8 USING (a)" {1} 642 2b "SELECT count(*) FROM t7 LEFT JOIN t8 USING (a)" {2} 643} 644 645 646# EVIDENCE-OF: R-15607-52988 The added rows contain NULL values in the 647# columns that would normally contain values copied from the right-hand 648# input dataset. 649# 650do_select_tests e_select-1.9 { 651 1a "SELECT * FROM t7 JOIN t8 ON (t7.a=t8.a)" {x ex 24 x abc 24} 652 1b "SELECT * FROM t7 LEFT JOIN t8 ON (t7.a=t8.a)" 653 {x ex 24 x abc 24 y why 25 {} {} {}} 654 2a "SELECT * FROM t7 JOIN t8 USING (a)" {x ex 24 abc 24} 655 2b "SELECT * FROM t7 LEFT JOIN t8 USING (a)" {x ex 24 abc 24 y why 25 {} {}} 656} 657 658# EVIDENCE-OF: R-04932-55942 If the NATURAL keyword is in the 659# join-operator then an implicit USING clause is added to the 660# join-constraints. The implicit USING clause contains each of the 661# column names that appear in both the left and right-hand input 662# datasets. 663# 664do_select_tests e_select-1-10 { 665 1a "SELECT * FROM t7 JOIN t8 USING (a)" {x ex 24 abc 24} 666 1b "SELECT * FROM t7 NATURAL JOIN t8" {x ex 24 abc 24} 667 668 2a "SELECT * FROM t8 JOIN t7 USING (a)" {x abc 24 ex 24} 669 2b "SELECT * FROM t8 NATURAL JOIN t7" {x abc 24 ex 24} 670 671 3a "SELECT * FROM t7 LEFT JOIN t8 USING (a)" {x ex 24 abc 24 y why 25 {} {}} 672 3b "SELECT * FROM t7 NATURAL LEFT JOIN t8" {x ex 24 abc 24 y why 25 {} {}} 673 674 4a "SELECT * FROM t8 LEFT JOIN t7 USING (a)" {x abc 24 ex 24 z ghi 26 {} {}} 675 4b "SELECT * FROM t8 NATURAL LEFT JOIN t7" {x abc 24 ex 24 z ghi 26 {} {}} 676 677 5a "SELECT * FROM t3 JOIN t4 USING (a,c)" {b 2} 678 5b "SELECT * FROM t3 NATURAL JOIN t4" {b 2} 679 680 6a "SELECT * FROM t3 LEFT JOIN t4 USING (a,c)" {a 1 b 2} 681 6b "SELECT * FROM t3 NATURAL LEFT JOIN t4" {a 1 b 2} 682} 683 684# EVIDENCE-OF: R-49566-01570 If the left and right-hand input datasets 685# feature no common column names, then the NATURAL keyword has no effect 686# on the results of the join. 687# 688do_execsql_test e_select-1.11.0 { 689 CREATE TABLE t10(x, y); 690 INSERT INTO t10 VALUES(1, 'true'); 691 INSERT INTO t10 VALUES(0, 'false'); 692} {} 693do_select_tests e_select-1-11 { 694 1a "SELECT a, x FROM t1 CROSS JOIN t10" {a 1 a 0 b 1 b 0 c 1 c 0} 695 1b "SELECT a, x FROM t1 NATURAL CROSS JOIN t10" {a 1 a 0 b 1 b 0 c 1 c 0} 696} 697 698# EVIDENCE-OF: R-39625-59133 A USING or ON clause may not be added to a 699# join that specifies the NATURAL keyword. 700# 701foreach {tn sql} { 702 1 {SELECT * FROM t1 NATURAL LEFT JOIN t2 USING (a)} 703 2 {SELECT * FROM t1 NATURAL LEFT JOIN t2 ON (t1.a=t2.a)} 704 3 {SELECT * FROM t1 NATURAL LEFT JOIN t2 ON (45)} 705} { 706 do_catchsql_test e_select-1.12.$tn " 707 $sql 708 " {1 {a NATURAL join may not have an ON or USING clause}} 709} 710 711#------------------------------------------------------------------------- 712# The next block of tests - e_select-3.* - concentrate on verifying 713# statements made regarding WHERE clause processing. 714# 715drop_all_tables 716do_execsql_test e_select-3.0 { 717 CREATE TABLE x1(k, x, y, z); 718 INSERT INTO x1 VALUES(1, 'relinquished', 'aphasia', 78.43); 719 INSERT INTO x1 VALUES(2, X'A8E8D66F', X'07CF', -81); 720 INSERT INTO x1 VALUES(3, -22, -27.57, NULL); 721 INSERT INTO x1 VALUES(4, NULL, 'bygone', 'picky'); 722 INSERT INTO x1 VALUES(5, NULL, 96.28, NULL); 723 INSERT INTO x1 VALUES(6, 0, 1, 2); 724 725 CREATE TABLE x2(k, x, y2); 726 INSERT INTO x2 VALUES(1, 50, X'B82838'); 727 INSERT INTO x2 VALUES(5, 84.79, 65.88); 728 INSERT INTO x2 VALUES(3, -22, X'0E1BE452A393'); 729 INSERT INTO x2 VALUES(7, 'mistrusted', 'standardized'); 730} {} 731 732# EVIDENCE-OF: R-60775-64916 If a WHERE clause is specified, the WHERE 733# expression is evaluated for each row in the input data as a boolean 734# expression. Only rows for which the WHERE clause expression evaluates 735# to true are included from the dataset before continuing. 736# 737do_execsql_test e_select-3.1.1 { SELECT k FROM x1 WHERE x } {3} 738do_execsql_test e_select-3.1.2 { SELECT k FROM x1 WHERE y } {3 5 6} 739do_execsql_test e_select-3.1.3 { SELECT k FROM x1 WHERE z } {1 2 6} 740do_execsql_test e_select-3.1.4 { SELECT k FROM x1 WHERE '1'||z } {1 2 4 6} 741do_execsql_test e_select-3.1.5 { SELECT k FROM x1 WHERE x IS NULL } {4 5} 742do_execsql_test e_select-3.1.6 { SELECT k FROM x1 WHERE z - 78.43 } {2 4 6} 743 744do_execsql_test e_select-3.2.1a { 745 SELECT k FROM x1 LEFT JOIN x2 USING(k) 746} {1 2 3 4 5 6} 747do_execsql_test e_select-3.2.1b { 748 SELECT k FROM x1 LEFT JOIN x2 USING(k) WHERE x2.k ORDER BY +k 749} {1 3 5} 750do_execsql_test e_select-3.2.2 { 751 SELECT k FROM x1 LEFT JOIN x2 USING(k) WHERE x2.k IS NULL 752} {2 4 6} 753 754do_execsql_test e_select-3.2.3 { 755 SELECT k FROM x1 NATURAL JOIN x2 WHERE x2.k 756} {3} 757do_execsql_test e_select-3.2.4 { 758 SELECT k FROM x1 NATURAL JOIN x2 WHERE x2.k-3 759} {} 760 761#------------------------------------------------------------------------- 762# Tests below this point are focused on verifying the testable statements 763# related to caculating the result rows of a simple SELECT statement. 764# 765 766drop_all_tables 767do_execsql_test e_select-4.0 { 768 CREATE TABLE z1(a, b, c); 769 CREATE TABLE z2(d, e); 770 CREATE TABLE z3(a, b); 771 772 INSERT INTO z1 VALUES(51.65, -59.58, 'belfries'); 773 INSERT INTO z1 VALUES(-5, NULL, 75); 774 INSERT INTO z1 VALUES(-2.2, -23.18, 'suiters'); 775 INSERT INTO z1 VALUES(NULL, 67, 'quartets'); 776 INSERT INTO z1 VALUES(-1.04, -32.3, 'aspen'); 777 INSERT INTO z1 VALUES(63, 'born', -26); 778 779 INSERT INTO z2 VALUES(NULL, 21); 780 INSERT INTO z2 VALUES(36, 6); 781 782 INSERT INTO z3 VALUES('subsistence', 'gauze'); 783 INSERT INTO z3 VALUES(49.17, -67); 784} {} 785 786# EVIDENCE-OF: R-36327-17224 If a result expression is the special 787# expression "*" then all columns in the input data are substituted for 788# that one expression. 789# 790# EVIDENCE-OF: R-43693-30522 If the expression is the alias of a table 791# or subquery in the FROM clause followed by ".*" then all columns from 792# the named table or subquery are substituted for the single expression. 793# 794do_select_tests e_select-4.1 { 795 1 "SELECT * FROM z1 LIMIT 1" {51.65 -59.58 belfries} 796 2 "SELECT * FROM z1,z2 LIMIT 1" {51.65 -59.58 belfries {} 21} 797 3 "SELECT z1.* FROM z1,z2 LIMIT 1" {51.65 -59.58 belfries} 798 4 "SELECT z2.* FROM z1,z2 LIMIT 1" {{} 21} 799 5 "SELECT z2.*, z1.* FROM z1,z2 LIMIT 1" {{} 21 51.65 -59.58 belfries} 800 801 6 "SELECT count(*), * FROM z1" {6 51.65 -59.58 belfries} 802 7 "SELECT max(a), * FROM z1" {63 63 born -26} 803 8 "SELECT *, min(a) FROM z1" {-5 {} 75 -5} 804 805 9 "SELECT *,* FROM z1,z2 LIMIT 1" { 806 51.65 -59.58 belfries {} 21 51.65 -59.58 belfries {} 21 807 } 808 10 "SELECT z1.*,z1.* FROM z2,z1 LIMIT 1" { 809 51.65 -59.58 belfries 51.65 -59.58 belfries 810 } 811} 812 813# EVIDENCE-OF: R-38023-18396 It is an error to use a "*" or "alias.*" 814# expression in any context other than a result expression list. 815# 816# EVIDENCE-OF: R-44324-41166 It is also an error to use a "*" or 817# "alias.*" expression in a simple SELECT query that does not have a 818# FROM clause. 819# 820foreach {tn select err} { 821 1.1 "SELECT a, b, c FROM z1 WHERE *" {near "*": syntax error} 822 1.2 "SELECT a, b, c FROM z1 GROUP BY *" {near "*": syntax error} 823 1.3 "SELECT 1 + * FROM z1" {near "*": syntax error} 824 1.4 "SELECT * + 1 FROM z1" {near "+": syntax error} 825 826 2.1 "SELECT *" {no tables specified} 827 2.2 "SELECT * WHERE 1" {no tables specified} 828 2.3 "SELECT * WHERE 0" {no tables specified} 829 2.4 "SELECT count(*), *" {no tables specified} 830} { 831 do_catchsql_test e_select-4.2.$tn $select [list 1 $err] 832} 833 834# EVIDENCE-OF: R-08669-22397 The number of columns in the rows returned 835# by a simple SELECT statement is equal to the number of expressions in 836# the result expression list after substitution of * and alias.* 837# expressions. 838# 839foreach {tn select nCol} { 840 1 "SELECT * FROM z1" 3 841 2 "SELECT * FROM z1 NATURAL JOIN z3" 3 842 3 "SELECT z1.* FROM z1 NATURAL JOIN z3" 3 843 4 "SELECT z3.* FROM z1 NATURAL JOIN z3" 2 844 5 "SELECT z1.*, z3.* FROM z1 NATURAL JOIN z3" 5 845 6 "SELECT 1, 2, z1.* FROM z1" 5 846 7 "SELECT a, *, b, c FROM z1" 6 847} { 848 set ::stmt [sqlite3_prepare_v2 db $select -1 DUMMY] 849 do_test e_select-4.3.$tn { sqlite3_column_count $::stmt } $nCol 850 sqlite3_finalize $::stmt 851} 852 853 854 855# In lang_select.html, a non-aggregate query is defined as any simple SELECT 856# that has no GROUP BY clause and no aggregate expressions in the result 857# expression list. Other queries are aggregate queries. Test cases 858# e_select-4.4.* through e_select-4.12.*, inclusive, which test the part of 859# simple SELECT that is different for aggregate and non-aggregate queries 860# verify (in a way) that these definitions are consistent: 861# 862# EVIDENCE-OF: R-20637-43463 A simple SELECT statement is an aggregate 863# query if it contains either a GROUP BY clause or one or more aggregate 864# functions in the result-set. 865# 866# EVIDENCE-OF: R-23155-55597 Otherwise, if a simple SELECT contains no 867# aggregate functions or a GROUP BY clause, it is a non-aggregate query. 868# 869 870# EVIDENCE-OF: R-44050-47362 If the SELECT statement is a non-aggregate 871# query, then each expression in the result expression list is evaluated 872# for each row in the dataset filtered by the WHERE clause. 873# 874do_select_tests e_select-4.4 { 875 1 "SELECT a, b FROM z1" 876 {51.65 -59.58 -5 {} -2.2 -23.18 {} 67 -1.04 -32.3 63 born} 877 878 2 "SELECT a IS NULL, b+1, * FROM z1" { 879 0 -58.58 51.65 -59.58 belfries 880 0 {} -5 {} 75 881 0 -22.18 -2.2 -23.18 suiters 882 1 68 {} 67 quartets 883 0 -31.3 -1.04 -32.3 aspen 884 0 1 63 born -26 885 } 886 887 3 "SELECT 32*32, d||e FROM z2" {1024 {} 1024 366} 888} 889 890 891# Test cases e_select-4.5.* and e_select-4.6.* together show that: 892# 893# EVIDENCE-OF: R-51988-01124 The single row of result-set data created 894# by evaluating the aggregate and non-aggregate expressions in the 895# result-set forms the result of an aggregate query without a GROUP BY 896# clause. 897# 898 899# EVIDENCE-OF: R-57629-25253 If the SELECT statement is an aggregate 900# query without a GROUP BY clause, then each aggregate expression in the 901# result-set is evaluated once across the entire dataset. 902# 903do_select_tests e_select-4.5 { 904 1 "SELECT count(a), max(a), count(b), max(b) FROM z1" {5 63 5 born} 905 2 "SELECT count(*), max(1)" {1 1} 906 907 3 "SELECT sum(b+1) FROM z1 NATURAL LEFT JOIN z3" {-43.06} 908 4 "SELECT sum(b+2) FROM z1 NATURAL LEFT JOIN z3" {-38.06} 909 5 "SELECT sum(b IS NOT NULL) FROM z1 NATURAL LEFT JOIN z3" {5} 910} 911 912# EVIDENCE-OF: R-26684-40576 Each non-aggregate expression in the 913# result-set is evaluated once for an arbitrarily selected row of the 914# dataset. 915# 916# EVIDENCE-OF: R-27994-60376 The same arbitrarily selected row is used 917# for each non-aggregate expression. 918# 919# Note: The results of many of the queries in this block of tests are 920# technically undefined, as the documentation does not specify which row 921# SQLite will arbitrarily select to use for the evaluation of the 922# non-aggregate expressions. 923# 924drop_all_tables 925do_execsql_test e_select-4.6.0 { 926 CREATE TABLE a1(one PRIMARY KEY, two); 927 INSERT INTO a1 VALUES(1, 1); 928 INSERT INTO a1 VALUES(2, 3); 929 INSERT INTO a1 VALUES(3, 6); 930 INSERT INTO a1 VALUES(4, 10); 931 932 CREATE TABLE a2(one PRIMARY KEY, three); 933 INSERT INTO a2 VALUES(1, 1); 934 INSERT INTO a2 VALUES(3, 2); 935 INSERT INTO a2 VALUES(6, 3); 936 INSERT INTO a2 VALUES(10, 4); 937} {} 938do_select_tests e_select-4.6 { 939 1 "SELECT one, two, count(*) FROM a1" {1 1 4} 940 2 "SELECT one, two, count(*) FROM a1 WHERE one<3" {1 1 2} 941 3 "SELECT one, two, count(*) FROM a1 WHERE one>3" {4 10 1} 942 4 "SELECT *, count(*) FROM a1 JOIN a2" {1 1 1 1 16} 943 5 "SELECT *, sum(three) FROM a1 NATURAL JOIN a2" {1 1 1 3} 944 6 "SELECT *, sum(three) FROM a1 NATURAL JOIN a2" {1 1 1 3} 945 7 "SELECT group_concat(three, ''), a1.* FROM a1 NATURAL JOIN a2" {12 1 1} 946} 947 948# EVIDENCE-OF: R-04486-07266 Or, if the dataset contains zero rows, then 949# each non-aggregate expression is evaluated against a row consisting 950# entirely of NULL values. 951# 952do_select_tests e_select-4.7 { 953 1 "SELECT one, two, count(*) FROM a1 WHERE 0" {{} {} 0} 954 2 "SELECT sum(two), * FROM a1, a2 WHERE three>5" {{} {} {} {} {}} 955 3 "SELECT max(one) IS NULL, one IS NULL, two IS NULL FROM a1 WHERE two=7" { 956 1 1 1 957 } 958} 959 960# EVIDENCE-OF: R-64138-28774 An aggregate query without a GROUP BY 961# clause always returns exactly one row of data, even if there are zero 962# rows of input data. 963# 964foreach {tn select} { 965 8.1 "SELECT count(*) FROM a1" 966 8.2 "SELECT count(*) FROM a1 WHERE 0" 967 8.3 "SELECT count(*) FROM a1 WHERE 1" 968 8.4 "SELECT max(a1.one)+min(two), a1.one, two, * FROM a1, a2 WHERE 1" 969 8.5 "SELECT max(a1.one)+min(two), a1.one, two, * FROM a1, a2 WHERE 0" 970} { 971 # Set $nRow to the number of rows returned by $select: 972 set ::stmt [sqlite3_prepare_v2 db $select -1 DUMMY] 973 set nRow 0 974 while {"SQLITE_ROW" == [sqlite3_step $::stmt]} { incr nRow } 975 set rc [sqlite3_finalize $::stmt] 976 977 # Test that $nRow==1 and that statement execution was successful 978 # (rc==SQLITE_OK). 979 do_test e_select-4.$tn [list list $rc $nRow] {SQLITE_OK 1} 980} 981 982drop_all_tables 983do_execsql_test e_select-4.9.0 { 984 CREATE TABLE b1(one PRIMARY KEY, two); 985 INSERT INTO b1 VALUES(1, 'o'); 986 INSERT INTO b1 VALUES(4, 'f'); 987 INSERT INTO b1 VALUES(3, 't'); 988 INSERT INTO b1 VALUES(2, 't'); 989 INSERT INTO b1 VALUES(5, 'f'); 990 INSERT INTO b1 VALUES(7, 's'); 991 INSERT INTO b1 VALUES(6, 's'); 992 993 CREATE TABLE b2(x, y); 994 INSERT INTO b2 VALUES(NULL, 0); 995 INSERT INTO b2 VALUES(NULL, 1); 996 INSERT INTO b2 VALUES('xyz', 2); 997 INSERT INTO b2 VALUES('abc', 3); 998 INSERT INTO b2 VALUES('xyz', 4); 999 1000 CREATE TABLE b3(a COLLATE nocase, b COLLATE binary); 1001 INSERT INTO b3 VALUES('abc', 'abc'); 1002 INSERT INTO b3 VALUES('aBC', 'aBC'); 1003 INSERT INTO b3 VALUES('Def', 'Def'); 1004 INSERT INTO b3 VALUES('dEF', 'dEF'); 1005} {} 1006 1007# EVIDENCE-OF: R-07284-35990 If the SELECT statement is an aggregate 1008# query with a GROUP BY clause, then each of the expressions specified 1009# as part of the GROUP BY clause is evaluated for each row of the 1010# dataset. Each row is then assigned to a "group" based on the results; 1011# rows for which the results of evaluating the GROUP BY expressions are 1012# the same get assigned to the same group. 1013# 1014# These tests also show that the following is not untrue: 1015# 1016# EVIDENCE-OF: R-25883-55063 The expressions in the GROUP BY clause do 1017# not have to be expressions that appear in the result. 1018# 1019do_select_tests e_select-4.9 { 1020 1 "SELECT group_concat(one), two FROM b1 GROUP BY two" { 1021 /#,# f 1 o #,# s #,# t/ 1022 } 1023 2 "SELECT group_concat(one), sum(one) FROM b1 GROUP BY (one>4)" { 1024 1,2,3,4 10 5,6,7 18 1025 } 1026 3 "SELECT group_concat(one) FROM b1 GROUP BY (two>'o'), one%2" { 1027 4 1,5 2,6 3,7 1028 } 1029 4 "SELECT group_concat(one) FROM b1 GROUP BY (one==2 OR two=='o')" { 1030 4,3,5,7,6 1,2 1031 } 1032} 1033 1034# EVIDENCE-OF: R-14926-50129 For the purposes of grouping rows, NULL 1035# values are considered equal. 1036# 1037do_select_tests e_select-4.10 { 1038 1 "SELECT group_concat(y) FROM b2 GROUP BY x" {/#,# 3 #,#/} 1039 2 "SELECT count(*) FROM b2 GROUP BY CASE WHEN y<4 THEN NULL ELSE 0 END" {4 1} 1040} 1041 1042# EVIDENCE-OF: R-10470-30318 The usual rules for selecting a collation 1043# sequence with which to compare text values apply when evaluating 1044# expressions in a GROUP BY clause. 1045# 1046do_select_tests e_select-4.11 { 1047 1 "SELECT count(*) FROM b3 GROUP BY b" {1 1 1 1} 1048 2 "SELECT count(*) FROM b3 GROUP BY a" {2 2} 1049 3 "SELECT count(*) FROM b3 GROUP BY +b" {1 1 1 1} 1050 4 "SELECT count(*) FROM b3 GROUP BY +a" {2 2} 1051 5 "SELECT count(*) FROM b3 GROUP BY b||''" {1 1 1 1} 1052 6 "SELECT count(*) FROM b3 GROUP BY a||''" {1 1 1 1} 1053} 1054 1055# EVIDENCE-OF: R-63573-50730 The expressions in a GROUP BY clause may 1056# not be aggregate expressions. 1057# 1058foreach {tn select} { 1059 12.1 "SELECT * FROM b3 GROUP BY count(*)" 1060 12.2 "SELECT max(a) FROM b3 GROUP BY max(b)" 1061 12.3 "SELECT group_concat(a) FROM b3 GROUP BY a, max(b)" 1062} { 1063 set res {1 {aggregate functions are not allowed in the GROUP BY clause}} 1064 do_catchsql_test e_select-4.$tn $select $res 1065} 1066 1067# EVIDENCE-OF: R-31537-00101 If a HAVING clause is specified, it is 1068# evaluated once for each group of rows as a boolean expression. If the 1069# result of evaluating the HAVING clause is false, the group is 1070# discarded. 1071# 1072# This requirement is tested by all e_select-4.13.* tests. 1073# 1074# EVIDENCE-OF: R-04132-09474 If the HAVING clause is an aggregate 1075# expression, it is evaluated across all rows in the group. 1076# 1077# Tested by e_select-4.13.1.* 1078# 1079# EVIDENCE-OF: R-28262-47447 If a HAVING clause is a non-aggregate 1080# expression, it is evaluated with respect to an arbitrarily selected 1081# row from the group. 1082# 1083# Tested by e_select-4.13.2.* 1084# 1085# Tests in this block also show that this is not untrue: 1086# 1087# EVIDENCE-OF: R-55403-13450 The HAVING expression may refer to values, 1088# even aggregate functions, that are not in the result. 1089# 1090do_execsql_test e_select-4.13.0 { 1091 CREATE TABLE c1(up, down); 1092 INSERT INTO c1 VALUES('x', 1); 1093 INSERT INTO c1 VALUES('x', 2); 1094 INSERT INTO c1 VALUES('x', 4); 1095 INSERT INTO c1 VALUES('x', 8); 1096 INSERT INTO c1 VALUES('y', 16); 1097 INSERT INTO c1 VALUES('y', 32); 1098 1099 CREATE TABLE c2(i, j); 1100 INSERT INTO c2 VALUES(1, 0); 1101 INSERT INTO c2 VALUES(2, 1); 1102 INSERT INTO c2 VALUES(3, 3); 1103 INSERT INTO c2 VALUES(4, 6); 1104 INSERT INTO c2 VALUES(5, 10); 1105 INSERT INTO c2 VALUES(6, 15); 1106 INSERT INTO c2 VALUES(7, 21); 1107 INSERT INTO c2 VALUES(8, 28); 1108 INSERT INTO c2 VALUES(9, 36); 1109 1110 CREATE TABLE c3(i PRIMARY KEY, k TEXT); 1111 INSERT INTO c3 VALUES(1, 'hydrogen'); 1112 INSERT INTO c3 VALUES(2, 'helium'); 1113 INSERT INTO c3 VALUES(3, 'lithium'); 1114 INSERT INTO c3 VALUES(4, 'beryllium'); 1115 INSERT INTO c3 VALUES(5, 'boron'); 1116 INSERT INTO c3 VALUES(94, 'plutonium'); 1117} {} 1118 1119do_select_tests e_select-4.13 { 1120 1.1 "SELECT up FROM c1 GROUP BY up HAVING count(*)>3" {x} 1121 1.2 "SELECT up FROM c1 GROUP BY up HAVING sum(down)>16" {y} 1122 1.3 "SELECT up FROM c1 GROUP BY up HAVING sum(down)<16" {x} 1123 1.4 "SELECT up||down FROM c1 GROUP BY (down<5) HAVING max(down)<10" {x4} 1124 1125 2.1 "SELECT up FROM c1 GROUP BY up HAVING down>10" {y} 1126 2.2 "SELECT up FROM c1 GROUP BY up HAVING up='y'" {y} 1127 1128 2.3 "SELECT i, j FROM c2 GROUP BY i>4 HAVING j>6" {5 10} 1129} 1130 1131# EVIDENCE-OF: R-23927-54081 Each expression in the result-set is then 1132# evaluated once for each group of rows. 1133# 1134# EVIDENCE-OF: R-53735-47017 If the expression is an aggregate 1135# expression, it is evaluated across all rows in the group. 1136# 1137do_select_tests e_select-4.15 { 1138 1 "SELECT sum(down) FROM c1 GROUP BY up" {15 48} 1139 2 "SELECT sum(j), max(j) FROM c2 GROUP BY (i%3)" {54 36 27 21 39 28} 1140 3 "SELECT sum(j), max(j) FROM c2 GROUP BY (j%2)" {80 36 40 21} 1141 4 "SELECT 1+sum(j), max(j)+1 FROM c2 GROUP BY (j%2)" {81 37 41 22} 1142 5 "SELECT count(*), round(avg(i),2) FROM c1, c2 ON (i=down) GROUP BY j%2" 1143 {3 4.33 1 2.0} 1144} 1145 1146# EVIDENCE-OF: R-62913-19830 Otherwise, it is evaluated against a single 1147# arbitrarily chosen row from within the group. 1148# 1149# EVIDENCE-OF: R-53924-08809 If there is more than one non-aggregate 1150# expression in the result-set, then all such expressions are evaluated 1151# for the same row. 1152# 1153do_select_tests e_select-4.15 { 1154 1 "SELECT i, j FROM c2 GROUP BY i%2" {2 1 1 0} 1155 2 "SELECT i, j FROM c2 GROUP BY i%2 HAVING j<30" {2 1 1 0} 1156 3 "SELECT i, j FROM c2 GROUP BY i%2 HAVING j>30" {} 1157 4 "SELECT i, j FROM c2 GROUP BY i%2 HAVING j>30" {} 1158 5 "SELECT count(*), i, k FROM c2 NATURAL JOIN c3 GROUP BY substr(k, 1, 1)" 1159 {2 4 beryllium 2 1 hydrogen 1 3 lithium} 1160} 1161 1162# EVIDENCE-OF: R-19334-12811 Each group of input dataset rows 1163# contributes a single row to the set of result rows. 1164# 1165# EVIDENCE-OF: R-02223-49279 Subject to filtering associated with the 1166# DISTINCT keyword, the number of rows returned by an aggregate query 1167# with a GROUP BY clause is the same as the number of groups of rows 1168# produced by applying the GROUP BY and HAVING clauses to the filtered 1169# input dataset. 1170# 1171do_select_tests e_select.4.16 -count { 1172 1 "SELECT i, j FROM c2 GROUP BY i%2" 2 1173 2 "SELECT i, j FROM c2 GROUP BY i" 9 1174 3 "SELECT i, j FROM c2 GROUP BY i HAVING i<5" 4 1175} 1176 1177#------------------------------------------------------------------------- 1178# The following tests attempt to verify statements made regarding the ALL 1179# and DISTINCT keywords. 1180# 1181drop_all_tables 1182do_execsql_test e_select-5.1.0 { 1183 CREATE TABLE h1(a, b); 1184 INSERT INTO h1 VALUES(1, 'one'); 1185 INSERT INTO h1 VALUES(1, 'I'); 1186 INSERT INTO h1 VALUES(1, 'i'); 1187 INSERT INTO h1 VALUES(4, 'four'); 1188 INSERT INTO h1 VALUES(4, 'IV'); 1189 INSERT INTO h1 VALUES(4, 'iv'); 1190 1191 CREATE TABLE h2(x COLLATE nocase); 1192 INSERT INTO h2 VALUES('One'); 1193 INSERT INTO h2 VALUES('Two'); 1194 INSERT INTO h2 VALUES('Three'); 1195 INSERT INTO h2 VALUES('Four'); 1196 INSERT INTO h2 VALUES('one'); 1197 INSERT INTO h2 VALUES('two'); 1198 INSERT INTO h2 VALUES('three'); 1199 INSERT INTO h2 VALUES('four'); 1200 1201 CREATE TABLE h3(c, d); 1202 INSERT INTO h3 VALUES(1, NULL); 1203 INSERT INTO h3 VALUES(2, NULL); 1204 INSERT INTO h3 VALUES(3, NULL); 1205 INSERT INTO h3 VALUES(4, '2'); 1206 INSERT INTO h3 VALUES(5, NULL); 1207 INSERT INTO h3 VALUES(6, '2,3'); 1208 INSERT INTO h3 VALUES(7, NULL); 1209 INSERT INTO h3 VALUES(8, '2,4'); 1210 INSERT INTO h3 VALUES(9, '3'); 1211} {} 1212 1213# EVIDENCE-OF: R-60770-10612 One of the ALL or DISTINCT keywords may 1214# follow the SELECT keyword in a simple SELECT statement. 1215# 1216do_select_tests e_select-5.1 { 1217 1 "SELECT ALL a FROM h1" {1 1 1 4 4 4} 1218 2 "SELECT DISTINCT a FROM h1" {1 4} 1219} 1220 1221# EVIDENCE-OF: R-08861-34280 If the simple SELECT is a SELECT ALL, then 1222# the entire set of result rows are returned by the SELECT. 1223# 1224# EVIDENCE-OF: R-01256-01950 If neither ALL or DISTINCT are present, 1225# then the behavior is as if ALL were specified. 1226# 1227# EVIDENCE-OF: R-14442-41305 If the simple SELECT is a SELECT DISTINCT, 1228# then duplicate rows are removed from the set of result rows before it 1229# is returned. 1230# 1231# The three testable statements above are tested by e_select-5.2.*, 1232# 5.3.* and 5.4.* respectively. 1233# 1234do_select_tests e_select-5 { 1235 3.1 "SELECT ALL x FROM h2" {One Two Three Four one two three four} 1236 3.2 "SELECT ALL x FROM h1, h2 ON (x=b)" {One one Four four} 1237 1238 3.1 "SELECT x FROM h2" {One Two Three Four one two three four} 1239 3.2 "SELECT x FROM h1, h2 ON (x=b)" {One one Four four} 1240 1241 4.1 "SELECT DISTINCT x FROM h2" {One Two Three Four} 1242 4.2 "SELECT DISTINCT x FROM h1, h2 ON (x=b)" {One Four} 1243} 1244 1245# EVIDENCE-OF: R-02054-15343 For the purposes of detecting duplicate 1246# rows, two NULL values are considered to be equal. 1247# 1248do_select_tests e_select-5.5 { 1249 1 "SELECT DISTINCT d FROM h3" {{} 2 2,3 2,4 3} 1250} 1251 1252# EVIDENCE-OF: R-47709-27231 The usual rules apply for selecting a 1253# collation sequence to compare text values. 1254# 1255do_select_tests e_select-5.6 { 1256 1 "SELECT DISTINCT b FROM h1" {one I i four IV iv} 1257 2 "SELECT DISTINCT b COLLATE nocase FROM h1" {one I four IV} 1258 3 "SELECT DISTINCT x FROM h2" {One Two Three Four} 1259 4 "SELECT DISTINCT x COLLATE binary FROM h2" { 1260 One Two Three Four one two three four 1261 } 1262} 1263 1264#------------------------------------------------------------------------- 1265# The following tests - e_select-7.* - test that statements made to do 1266# with compound SELECT statements are correct. 1267# 1268 1269# EVIDENCE-OF: R-39368-64333 In a compound SELECT, all the constituent 1270# SELECTs must return the same number of result columns. 1271# 1272# All the other tests in this section use compound SELECTs created 1273# using component SELECTs that do return the same number of columns. 1274# So the tests here just show that it is an error to attempt otherwise. 1275# 1276drop_all_tables 1277do_execsql_test e_select-7.1.0 { 1278 CREATE TABLE j1(a, b, c); 1279 CREATE TABLE j2(e, f); 1280 CREATE TABLE j3(g); 1281} {} 1282do_select_tests e_select-7.1 -error { 1283 SELECTs to the left and right of %s do not have the same number of result columns 1284} { 1285 1 "SELECT a, b FROM j1 UNION ALL SELECT g FROM j3" {{UNION ALL}} 1286 2 "SELECT * FROM j1 UNION ALL SELECT * FROM j3" {{UNION ALL}} 1287 3 "SELECT a, b FROM j1 UNION ALL SELECT g FROM j3" {{UNION ALL}} 1288 4 "SELECT a, b FROM j1 UNION ALL SELECT * FROM j3,j2" {{UNION ALL}} 1289 5 "SELECT * FROM j3,j2 UNION ALL SELECT a, b FROM j1" {{UNION ALL}} 1290 1291 6 "SELECT a, b FROM j1 UNION SELECT g FROM j3" {UNION} 1292 7 "SELECT * FROM j1 UNION SELECT * FROM j3" {UNION} 1293 8 "SELECT a, b FROM j1 UNION SELECT g FROM j3" {UNION} 1294 9 "SELECT a, b FROM j1 UNION SELECT * FROM j3,j2" {UNION} 1295 10 "SELECT * FROM j3,j2 UNION SELECT a, b FROM j1" {UNION} 1296 1297 11 "SELECT a, b FROM j1 INTERSECT SELECT g FROM j3" {INTERSECT} 1298 12 "SELECT * FROM j1 INTERSECT SELECT * FROM j3" {INTERSECT} 1299 13 "SELECT a, b FROM j1 INTERSECT SELECT g FROM j3" {INTERSECT} 1300 14 "SELECT a, b FROM j1 INTERSECT SELECT * FROM j3,j2" {INTERSECT} 1301 15 "SELECT * FROM j3,j2 INTERSECT SELECT a, b FROM j1" {INTERSECT} 1302 1303 16 "SELECT a, b FROM j1 EXCEPT SELECT g FROM j3" {EXCEPT} 1304 17 "SELECT * FROM j1 EXCEPT SELECT * FROM j3" {EXCEPT} 1305 18 "SELECT a, b FROM j1 EXCEPT SELECT g FROM j3" {EXCEPT} 1306 19 "SELECT a, b FROM j1 EXCEPT SELECT * FROM j3,j2" {EXCEPT} 1307 20 "SELECT * FROM j3,j2 EXCEPT SELECT a, b FROM j1" {EXCEPT} 1308} 1309 1310# EVIDENCE-OF: R-01450-11152 As the components of a compound SELECT must 1311# be simple SELECT statements, they may not contain ORDER BY or LIMIT 1312# clauses. 1313# 1314foreach {tn select op1 op2} { 1315 1 "SELECT * FROM j1 ORDER BY a UNION ALL SELECT * FROM j2,j3" 1316 {ORDER BY} {UNION ALL} 1317 2 "SELECT count(*) FROM j1 ORDER BY 1 UNION ALL SELECT max(e) FROM j2" 1318 {ORDER BY} {UNION ALL} 1319 3 "SELECT count(*), * FROM j1 ORDER BY 1,2,3 UNION ALL SELECT *,* FROM j2" 1320 {ORDER BY} {UNION ALL} 1321 4 "SELECT * FROM j1 LIMIT 10 UNION ALL SELECT * FROM j2,j3" 1322 LIMIT {UNION ALL} 1323 5 "SELECT * FROM j1 LIMIT 10 OFFSET 5 UNION ALL SELECT * FROM j2,j3" 1324 LIMIT {UNION ALL} 1325 6 "SELECT a FROM j1 LIMIT (SELECT e FROM j2) UNION ALL SELECT g FROM j2,j3" 1326 LIMIT {UNION ALL} 1327 1328 7 "SELECT * FROM j1 ORDER BY a UNION SELECT * FROM j2,j3" 1329 {ORDER BY} {UNION} 1330 8 "SELECT count(*) FROM j1 ORDER BY 1 UNION SELECT max(e) FROM j2" 1331 {ORDER BY} {UNION} 1332 9 "SELECT count(*), * FROM j1 ORDER BY 1,2,3 UNION SELECT *,* FROM j2" 1333 {ORDER BY} {UNION} 1334 10 "SELECT * FROM j1 LIMIT 10 UNION SELECT * FROM j2,j3" 1335 LIMIT {UNION} 1336 11 "SELECT * FROM j1 LIMIT 10 OFFSET 5 UNION SELECT * FROM j2,j3" 1337 LIMIT {UNION} 1338 12 "SELECT a FROM j1 LIMIT (SELECT e FROM j2) UNION SELECT g FROM j2,j3" 1339 LIMIT {UNION} 1340 1341 13 "SELECT * FROM j1 ORDER BY a EXCEPT SELECT * FROM j2,j3" 1342 {ORDER BY} {EXCEPT} 1343 14 "SELECT count(*) FROM j1 ORDER BY 1 EXCEPT SELECT max(e) FROM j2" 1344 {ORDER BY} {EXCEPT} 1345 15 "SELECT count(*), * FROM j1 ORDER BY 1,2,3 EXCEPT SELECT *,* FROM j2" 1346 {ORDER BY} {EXCEPT} 1347 16 "SELECT * FROM j1 LIMIT 10 EXCEPT SELECT * FROM j2,j3" 1348 LIMIT {EXCEPT} 1349 17 "SELECT * FROM j1 LIMIT 10 OFFSET 5 EXCEPT SELECT * FROM j2,j3" 1350 LIMIT {EXCEPT} 1351 18 "SELECT a FROM j1 LIMIT (SELECT e FROM j2) EXCEPT SELECT g FROM j2,j3" 1352 LIMIT {EXCEPT} 1353 1354 19 "SELECT * FROM j1 ORDER BY a INTERSECT SELECT * FROM j2,j3" 1355 {ORDER BY} {INTERSECT} 1356 20 "SELECT count(*) FROM j1 ORDER BY 1 INTERSECT SELECT max(e) FROM j2" 1357 {ORDER BY} {INTERSECT} 1358 21 "SELECT count(*), * FROM j1 ORDER BY 1,2,3 INTERSECT SELECT *,* FROM j2" 1359 {ORDER BY} {INTERSECT} 1360 22 "SELECT * FROM j1 LIMIT 10 INTERSECT SELECT * FROM j2,j3" 1361 LIMIT {INTERSECT} 1362 23 "SELECT * FROM j1 LIMIT 10 OFFSET 5 INTERSECT SELECT * FROM j2,j3" 1363 LIMIT {INTERSECT} 1364 24 "SELECT a FROM j1 LIMIT (SELECT e FROM j2) INTERSECT SELECT g FROM j2,j3" 1365 LIMIT {INTERSECT} 1366} { 1367 set err "$op1 clause should come after $op2 not before" 1368 do_catchsql_test e_select-7.2.$tn $select [list 1 $err] 1369} 1370 1371# EVIDENCE-OF: R-45440-25633 ORDER BY and LIMIT clauses may only occur 1372# at the end of the entire compound SELECT, and then only if the final 1373# element of the compound is not a VALUES clause. 1374# 1375foreach {tn select} { 1376 1 "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 ORDER BY a" 1377 2 "SELECT count(*) FROM j1 UNION ALL SELECT max(e) FROM j2 ORDER BY 1" 1378 3 "SELECT count(*), * FROM j1 UNION ALL SELECT *,* FROM j2 ORDER BY 1,2,3" 1379 4 "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 LIMIT 10" 1380 5 "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 LIMIT 10 OFFSET 5" 1381 6 "SELECT a FROM j1 UNION ALL SELECT g FROM j2,j3 LIMIT (SELECT 10)" 1382 1383 7 "SELECT * FROM j1 UNION SELECT * FROM j2,j3 ORDER BY a" 1384 8 "SELECT count(*) FROM j1 UNION SELECT max(e) FROM j2 ORDER BY 1" 1385 8b "VALUES('8b') UNION SELECT max(e) FROM j2 ORDER BY 1" 1386 9 "SELECT count(*), * FROM j1 UNION SELECT *,* FROM j2 ORDER BY 1,2,3" 1387 10 "SELECT * FROM j1 UNION SELECT * FROM j2,j3 LIMIT 10" 1388 11 "SELECT * FROM j1 UNION SELECT * FROM j2,j3 LIMIT 10 OFFSET 5" 1389 12 "SELECT a FROM j1 UNION SELECT g FROM j2,j3 LIMIT (SELECT 10)" 1390 1391 13 "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 ORDER BY a" 1392 14 "SELECT count(*) FROM j1 EXCEPT SELECT max(e) FROM j2 ORDER BY 1" 1393 15 "SELECT count(*), * FROM j1 EXCEPT SELECT *,* FROM j2 ORDER BY 1,2,3" 1394 16 "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 LIMIT 10" 1395 17 "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 LIMIT 10 OFFSET 5" 1396 18 "SELECT a FROM j1 EXCEPT SELECT g FROM j2,j3 LIMIT (SELECT 10)" 1397 1398 19 "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 ORDER BY a" 1399 20 "SELECT count(*) FROM j1 INTERSECT SELECT max(e) FROM j2 ORDER BY 1" 1400 21 "SELECT count(*), * FROM j1 INTERSECT SELECT *,* FROM j2 ORDER BY 1,2,3" 1401 22 "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 LIMIT 10" 1402 23 "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 LIMIT 10 OFFSET 5" 1403 24 "SELECT a FROM j1 INTERSECT SELECT g FROM j2,j3 LIMIT (SELECT 10)" 1404} { 1405 do_test e_select-7.3.$tn { catch {execsql $select} msg } 0 1406} 1407foreach {tn select} { 1408 50 "SELECT * FROM j1 ORDER BY 1 UNION ALL SELECT * FROM j2,j3" 1409 51 "SELECT * FROM j1 LIMIT 1 UNION ALL SELECT * FROM j2,j3" 1410 52 "SELECT count(*) FROM j1 UNION ALL VALUES(11) ORDER BY 1" 1411 53 "SELECT count(*) FROM j1 UNION ALL VALUES(11) LIMIT 1" 1412} { 1413 do_test e_select-7.3.$tn { catch {execsql $select} msg } 1 1414} 1415 1416# EVIDENCE-OF: R-08531-36543 A compound SELECT created using UNION ALL 1417# operator returns all the rows from the SELECT to the left of the UNION 1418# ALL operator, and all the rows from the SELECT to the right of it. 1419# 1420drop_all_tables 1421do_execsql_test e_select-7.4.0 { 1422 CREATE TABLE q1(a TEXT, b INTEGER, c); 1423 CREATE TABLE q2(d NUMBER, e BLOB); 1424 CREATE TABLE q3(f REAL, g); 1425 1426 INSERT INTO q1 VALUES(16, -87.66, NULL); 1427 INSERT INTO q1 VALUES('legible', 94, -42.47); 1428 INSERT INTO q1 VALUES('beauty', 36, NULL); 1429 1430 INSERT INTO q2 VALUES('legible', 1); 1431 INSERT INTO q2 VALUES('beauty', 2); 1432 INSERT INTO q2 VALUES(-65.91, 4); 1433 INSERT INTO q2 VALUES('emanating', -16.56); 1434 1435 INSERT INTO q3 VALUES('beauty', 2); 1436 INSERT INTO q3 VALUES('beauty', 2); 1437} {} 1438do_select_tests e_select-7.4 { 1439 1 {SELECT a FROM q1 UNION ALL SELECT d FROM q2} 1440 {16 legible beauty legible beauty -65.91 emanating} 1441 1442 2 {SELECT * FROM q1 WHERE a=16 UNION ALL SELECT 'x', * FROM q2 WHERE oid=1} 1443 {16 -87.66 {} x legible 1} 1444 1445 3 {SELECT count(*) FROM q1 UNION ALL SELECT min(e) FROM q2} 1446 {3 -16.56} 1447 1448 4 {SELECT * FROM q2 UNION ALL SELECT * FROM q3} 1449 {legible 1 beauty 2 -65.91 4 emanating -16.56 beauty 2 beauty 2} 1450} 1451 1452# EVIDENCE-OF: R-20560-39162 The UNION operator works the same way as 1453# UNION ALL, except that duplicate rows are removed from the final 1454# result set. 1455# 1456do_select_tests e_select-7.5 { 1457 1 {SELECT a FROM q1 UNION SELECT d FROM q2} 1458 {-65.91 16 beauty emanating legible} 1459 1460 2 {SELECT * FROM q1 WHERE a=16 UNION SELECT 'x', * FROM q2 WHERE oid=1} 1461 {16 -87.66 {} x legible 1} 1462 1463 3 {SELECT count(*) FROM q1 UNION SELECT min(e) FROM q2} 1464 {-16.56 3} 1465 1466 4 {SELECT * FROM q2 UNION SELECT * FROM q3} 1467 {-65.91 4 beauty 2 emanating -16.56 legible 1} 1468} 1469 1470# EVIDENCE-OF: R-45764-31737 The INTERSECT operator returns the 1471# intersection of the results of the left and right SELECTs. 1472# 1473do_select_tests e_select-7.6 { 1474 1 {SELECT a FROM q1 INTERSECT SELECT d FROM q2} {beauty legible} 1475 2 {SELECT * FROM q2 INTERSECT SELECT * FROM q3} {beauty 2} 1476} 1477 1478# EVIDENCE-OF: R-25787-28949 The EXCEPT operator returns the subset of 1479# rows returned by the left SELECT that are not also returned by the 1480# right-hand SELECT. 1481# 1482do_select_tests e_select-7.7 { 1483 1 {SELECT a FROM q1 EXCEPT SELECT d FROM q2} {16} 1484 1485 2 {SELECT * FROM q2 EXCEPT SELECT * FROM q3} 1486 {-65.91 4 emanating -16.56 legible 1} 1487} 1488 1489# EVIDENCE-OF: R-40729-56447 Duplicate rows are removed from the results 1490# of INTERSECT and EXCEPT operators before the result set is returned. 1491# 1492do_select_tests e_select-7.8 { 1493 0 {SELECT * FROM q3} {beauty 2 beauty 2} 1494 1495 1 {SELECT * FROM q3 INTERSECT SELECT * FROM q3} {beauty 2} 1496 2 {SELECT * FROM q3 EXCEPT SELECT a,b FROM q1} {beauty 2} 1497} 1498 1499# EVIDENCE-OF: R-46765-43362 For the purposes of determining duplicate 1500# rows for the results of compound SELECT operators, NULL values are 1501# considered equal to other NULL values and distinct from all non-NULL 1502# values. 1503# 1504db nullvalue null 1505do_select_tests e_select-7.9 { 1506 1 {SELECT NULL UNION ALL SELECT NULL} {null null} 1507 2 {SELECT NULL UNION SELECT NULL} {null} 1508 3 {SELECT NULL INTERSECT SELECT NULL} {null} 1509 4 {SELECT NULL EXCEPT SELECT NULL} {} 1510 1511 5 {SELECT NULL UNION ALL SELECT 'ab'} {null ab} 1512 6 {SELECT NULL UNION SELECT 'ab'} {null ab} 1513 7 {SELECT NULL INTERSECT SELECT 'ab'} {} 1514 8 {SELECT NULL EXCEPT SELECT 'ab'} {null} 1515 1516 9 {SELECT NULL UNION ALL SELECT 0} {null 0} 1517 10 {SELECT NULL UNION SELECT 0} {null 0} 1518 11 {SELECT NULL INTERSECT SELECT 0} {} 1519 12 {SELECT NULL EXCEPT SELECT 0} {null} 1520 1521 13 {SELECT c FROM q1 UNION ALL SELECT g FROM q3} {null -42.47 null 2 2} 1522 14 {SELECT c FROM q1 UNION SELECT g FROM q3} {null -42.47 2} 1523 15 {SELECT c FROM q1 INTERSECT SELECT g FROM q3} {} 1524 16 {SELECT c FROM q1 EXCEPT SELECT g FROM q3} {null -42.47} 1525} 1526db nullvalue {} 1527 1528# EVIDENCE-OF: R-51232-50224 The collation sequence used to compare two 1529# text values is determined as if the columns of the left and right-hand 1530# SELECT statements were the left and right-hand operands of the equals 1531# (=) operator, except that greater precedence is not assigned to a 1532# collation sequence specified with the postfix COLLATE operator. 1533# 1534drop_all_tables 1535do_execsql_test e_select-7.10.0 { 1536 CREATE TABLE y1(a COLLATE nocase, b COLLATE binary, c); 1537 INSERT INTO y1 VALUES('Abc', 'abc', 'aBC'); 1538} {} 1539do_select_tests e_select-7.10 { 1540 1 {SELECT 'abc' UNION SELECT 'ABC'} {ABC abc} 1541 2 {SELECT 'abc' COLLATE nocase UNION SELECT 'ABC'} {ABC} 1542 3 {SELECT 'abc' UNION SELECT 'ABC' COLLATE nocase} {ABC} 1543 4 {SELECT 'abc' COLLATE binary UNION SELECT 'ABC' COLLATE nocase} {ABC abc} 1544 5 {SELECT 'abc' COLLATE nocase UNION SELECT 'ABC' COLLATE binary} {ABC} 1545 1546 6 {SELECT a FROM y1 UNION SELECT b FROM y1} {abc} 1547 7 {SELECT b FROM y1 UNION SELECT a FROM y1} {Abc abc} 1548 8 {SELECT a FROM y1 UNION SELECT c FROM y1} {aBC} 1549 1550 9 {SELECT a FROM y1 UNION SELECT c COLLATE binary FROM y1} {aBC} 1551} 1552 1553# EVIDENCE-OF: R-32706-07403 No affinity transformations are applied to 1554# any values when comparing rows as part of a compound SELECT. 1555# 1556drop_all_tables 1557do_execsql_test e_select-7.10.0 { 1558 CREATE TABLE w1(a TEXT, b NUMBER); 1559 CREATE TABLE w2(a, b TEXT); 1560 1561 INSERT INTO w1 VALUES('1', 4.1); 1562 INSERT INTO w2 VALUES(1, 4.1); 1563} {} 1564 1565do_select_tests e_select-7.11 { 1566 1 { SELECT a FROM w1 UNION SELECT a FROM w2 } {1 1} 1567 2 { SELECT a FROM w2 UNION SELECT a FROM w1 } {1 1} 1568 3 { SELECT b FROM w1 UNION SELECT b FROM w2 } {4.1 4.1} 1569 4 { SELECT b FROM w2 UNION SELECT b FROM w1 } {4.1 4.1} 1570 1571 5 { SELECT a FROM w1 INTERSECT SELECT a FROM w2 } {} 1572 6 { SELECT a FROM w2 INTERSECT SELECT a FROM w1 } {} 1573 7 { SELECT b FROM w1 INTERSECT SELECT b FROM w2 } {} 1574 8 { SELECT b FROM w2 INTERSECT SELECT b FROM w1 } {} 1575 1576 9 { SELECT a FROM w1 EXCEPT SELECT a FROM w2 } {1} 1577 10 { SELECT a FROM w2 EXCEPT SELECT a FROM w1 } {1} 1578 11 { SELECT b FROM w1 EXCEPT SELECT b FROM w2 } {4.1} 1579 12 { SELECT b FROM w2 EXCEPT SELECT b FROM w1 } {4.1} 1580} 1581 1582 1583# EVIDENCE-OF: R-32562-20566 When three or more simple SELECTs are 1584# connected into a compound SELECT, they group from left to right. In 1585# other words, if "A", "B" and "C" are all simple SELECT statements, (A 1586# op B op C) is processed as ((A op B) op C). 1587# 1588# e_select-7.12.1: Precedence of UNION vs. INTERSECT 1589# e_select-7.12.2: Precedence of UNION vs. UNION ALL 1590# e_select-7.12.3: Precedence of UNION vs. EXCEPT 1591# e_select-7.12.4: Precedence of INTERSECT vs. UNION ALL 1592# e_select-7.12.5: Precedence of INTERSECT vs. EXCEPT 1593# e_select-7.12.6: Precedence of UNION ALL vs. EXCEPT 1594# e_select-7.12.7: Check that "a EXCEPT b EXCEPT c" is processed as 1595# "(a EXCEPT b) EXCEPT c". 1596# 1597# The INTERSECT and EXCEPT operations are mutually commutative. So 1598# the e_select-7.12.5 test cases do not prove very much. 1599# 1600drop_all_tables 1601do_execsql_test e_select-7.12.0 { 1602 CREATE TABLE t1(x); 1603 INSERT INTO t1 VALUES(1); 1604 INSERT INTO t1 VALUES(2); 1605 INSERT INTO t1 VALUES(3); 1606} {} 1607foreach {tn select res} { 1608 1a "(1,2) INTERSECT (1) UNION (3)" {1 3} 1609 1b "(3) UNION (1,2) INTERSECT (1)" {1} 1610 1611 2a "(1,2) UNION (3) UNION ALL (1)" {1 2 3 1} 1612 2b "(1) UNION ALL (3) UNION (1,2)" {1 2 3} 1613 1614 3a "(1,2) UNION (3) EXCEPT (1)" {2 3} 1615 3b "(1,2) EXCEPT (3) UNION (1)" {1 2} 1616 1617 4a "(1,2) INTERSECT (1) UNION ALL (3)" {1 3} 1618 4b "(3) UNION (1,2) INTERSECT (1)" {1} 1619 1620 5a "(1,2) INTERSECT (2) EXCEPT (2)" {} 1621 5b "(2,3) EXCEPT (2) INTERSECT (2)" {} 1622 1623 6a "(2) UNION ALL (2) EXCEPT (2)" {} 1624 6b "(2) EXCEPT (2) UNION ALL (2)" {2} 1625 1626 7 "(2,3) EXCEPT (2) EXCEPT (3)" {} 1627} { 1628 set select [string map {( {SELECT x FROM t1 WHERE x IN (}} $select] 1629 do_execsql_test e_select-7.12.$tn $select [list {*}$res] 1630} 1631 1632 1633#------------------------------------------------------------------------- 1634# ORDER BY clauses 1635# 1636 1637drop_all_tables 1638do_execsql_test e_select-8.1.0 { 1639 CREATE TABLE d1(x, y, z); 1640 1641 INSERT INTO d1 VALUES(1, 2, 3); 1642 INSERT INTO d1 VALUES(2, 5, -1); 1643 INSERT INTO d1 VALUES(1, 2, 8); 1644 INSERT INTO d1 VALUES(1, 2, 7); 1645 INSERT INTO d1 VALUES(2, 4, 93); 1646 INSERT INTO d1 VALUES(1, 2, -20); 1647 INSERT INTO d1 VALUES(1, 4, 93); 1648 INSERT INTO d1 VALUES(1, 5, -1); 1649 1650 CREATE TABLE d2(a, b); 1651 INSERT INTO d2 VALUES('gently', 'failings'); 1652 INSERT INTO d2 VALUES('commercials', 'bathrobe'); 1653 INSERT INTO d2 VALUES('iterate', 'sexton'); 1654 INSERT INTO d2 VALUES('babied', 'charitableness'); 1655 INSERT INTO d2 VALUES('solemnness', 'annexed'); 1656 INSERT INTO d2 VALUES('rejoicing', 'liabilities'); 1657 INSERT INTO d2 VALUES('pragmatist', 'guarded'); 1658 INSERT INTO d2 VALUES('barked', 'interrupted'); 1659 INSERT INTO d2 VALUES('reemphasizes', 'reply'); 1660 INSERT INTO d2 VALUES('lad', 'relenting'); 1661} {} 1662 1663# EVIDENCE-OF: R-44988-41064 Rows are first sorted based on the results 1664# of evaluating the left-most expression in the ORDER BY list, then ties 1665# are broken by evaluating the second left-most expression and so on. 1666# 1667do_select_tests e_select-8.1 { 1668 1 "SELECT * FROM d1 ORDER BY x, y, z" { 1669 1 2 -20 1 2 3 1 2 7 1 2 8 1670 1 4 93 1 5 -1 2 4 93 2 5 -1 1671 } 1672} 1673 1674# EVIDENCE-OF: R-06617-54588 Each ORDER BY expression may be optionally 1675# followed by one of the keywords ASC (smaller values are returned 1676# first) or DESC (larger values are returned first). 1677# 1678# Test cases e_select-8.2.* test the above. 1679# 1680# EVIDENCE-OF: R-18705-33393 If neither ASC or DESC are specified, rows 1681# are sorted in ascending (smaller values first) order by default. 1682# 1683# Test cases e_select-8.3.* test the above. All 8.3 test cases are 1684# copies of 8.2 test cases with the explicit "ASC" removed. 1685# 1686do_select_tests e_select-8 { 1687 2.1 "SELECT * FROM d1 ORDER BY x ASC, y ASC, z ASC" { 1688 1 2 -20 1 2 3 1 2 7 1 2 8 1689 1 4 93 1 5 -1 2 4 93 2 5 -1 1690 } 1691 2.2 "SELECT * FROM d1 ORDER BY x DESC, y DESC, z DESC" { 1692 2 5 -1 2 4 93 1 5 -1 1 4 93 1693 1 2 8 1 2 7 1 2 3 1 2 -20 1694 } 1695 2.3 "SELECT * FROM d1 ORDER BY x DESC, y ASC, z DESC" { 1696 2 4 93 2 5 -1 1 2 8 1 2 7 1697 1 2 3 1 2 -20 1 4 93 1 5 -1 1698 } 1699 2.4 "SELECT * FROM d1 ORDER BY x DESC, y ASC, z ASC" { 1700 2 4 93 2 5 -1 1 2 -20 1 2 3 1701 1 2 7 1 2 8 1 4 93 1 5 -1 1702 } 1703 1704 3.1 "SELECT * FROM d1 ORDER BY x, y, z" { 1705 1 2 -20 1 2 3 1 2 7 1 2 8 1706 1 4 93 1 5 -1 2 4 93 2 5 -1 1707 } 1708 3.3 "SELECT * FROM d1 ORDER BY x DESC, y, z DESC" { 1709 2 4 93 2 5 -1 1 2 8 1 2 7 1710 1 2 3 1 2 -20 1 4 93 1 5 -1 1711 } 1712 3.4 "SELECT * FROM d1 ORDER BY x DESC, y, z" { 1713 2 4 93 2 5 -1 1 2 -20 1 2 3 1714 1 2 7 1 2 8 1 4 93 1 5 -1 1715 } 1716} 1717 1718# EVIDENCE-OF: R-29779-04281 If the ORDER BY expression is a constant 1719# integer K then the expression is considered an alias for the K-th 1720# column of the result set (columns are numbered from left to right 1721# starting with 1). 1722# 1723do_select_tests e_select-8.4 { 1724 1 "SELECT * FROM d1 ORDER BY 1 ASC, 2 ASC, 3 ASC" { 1725 1 2 -20 1 2 3 1 2 7 1 2 8 1726 1 4 93 1 5 -1 2 4 93 2 5 -1 1727 } 1728 2 "SELECT * FROM d1 ORDER BY 1 DESC, 2 DESC, 3 DESC" { 1729 2 5 -1 2 4 93 1 5 -1 1 4 93 1730 1 2 8 1 2 7 1 2 3 1 2 -20 1731 } 1732 3 "SELECT * FROM d1 ORDER BY 1 DESC, 2 ASC, 3 DESC" { 1733 2 4 93 2 5 -1 1 2 8 1 2 7 1734 1 2 3 1 2 -20 1 4 93 1 5 -1 1735 } 1736 4 "SELECT * FROM d1 ORDER BY 1 DESC, 2 ASC, 3 ASC" { 1737 2 4 93 2 5 -1 1 2 -20 1 2 3 1738 1 2 7 1 2 8 1 4 93 1 5 -1 1739 } 1740 5 "SELECT * FROM d1 ORDER BY 1, 2, 3" { 1741 1 2 -20 1 2 3 1 2 7 1 2 8 1742 1 4 93 1 5 -1 2 4 93 2 5 -1 1743 } 1744 6 "SELECT * FROM d1 ORDER BY 1 DESC, 2, 3 DESC" { 1745 2 4 93 2 5 -1 1 2 8 1 2 7 1746 1 2 3 1 2 -20 1 4 93 1 5 -1 1747 } 1748 7 "SELECT * FROM d1 ORDER BY 1 DESC, 2, 3" { 1749 2 4 93 2 5 -1 1 2 -20 1 2 3 1750 1 2 7 1 2 8 1 4 93 1 5 -1 1751 } 1752 8 "SELECT z, x FROM d1 ORDER BY 2" { 1753 /# 1 # 1 # 1 # 1 1754 # 1 # 1 # 2 # 2/ 1755 } 1756 9 "SELECT z, x FROM d1 ORDER BY 1" { 1757 /-20 1 -1 # -1 # 3 1 1758 7 1 8 1 93 # 93 #/ 1759 } 1760} 1761 1762# EVIDENCE-OF: R-63286-51977 If the ORDER BY expression is an identifier 1763# that corresponds to the alias of one of the output columns, then the 1764# expression is considered an alias for that column. 1765# 1766do_select_tests e_select-8.5 { 1767 1 "SELECT z+1 AS abc FROM d1 ORDER BY abc" { 1768 -19 0 0 4 8 9 94 94 1769 } 1770 2 "SELECT z+1 AS abc FROM d1 ORDER BY abc DESC" { 1771 94 94 9 8 4 0 0 -19 1772 } 1773 3 "SELECT z AS x, x AS z FROM d1 ORDER BY z" { 1774 /# 1 # 1 # 1 # 1 # 1 # 1 # 2 # 2/ 1775 } 1776 4 "SELECT z AS x, x AS z FROM d1 ORDER BY x" { 1777 /-20 1 -1 # -1 # 3 1 7 1 8 1 93 # 93 #/ 1778 } 1779} 1780 1781# EVIDENCE-OF: R-65068-27207 Otherwise, if the ORDER BY expression is 1782# any other expression, it is evaluated and the returned value used to 1783# order the output rows. 1784# 1785# EVIDENCE-OF: R-03421-57988 If the SELECT statement is a simple SELECT, 1786# then an ORDER BY may contain any arbitrary expressions. 1787# 1788do_select_tests e_select-8.6 { 1789 1 "SELECT * FROM d1 ORDER BY x+y+z" { 1790 1 2 -20 1 5 -1 1 2 3 2 5 -1 1791 1 2 7 1 2 8 1 4 93 2 4 93 1792 } 1793 2 "SELECT * FROM d1 ORDER BY x*z" { 1794 1 2 -20 2 5 -1 1 5 -1 1 2 3 1795 1 2 7 1 2 8 1 4 93 2 4 93 1796 } 1797 3 "SELECT * FROM d1 ORDER BY y*z" { 1798 1 2 -20 2 5 -1 1 5 -1 1 2 3 1799 1 2 7 1 2 8 2 4 93 1 4 93 1800 } 1801} 1802 1803# EVIDENCE-OF: R-28853-08147 However, if the SELECT is a compound 1804# SELECT, then ORDER BY expressions that are not aliases to output 1805# columns must be exactly the same as an expression used as an output 1806# column. 1807# 1808do_select_tests e_select-8.7.1 -error { 1809 %s ORDER BY term does not match any column in the result set 1810} { 1811 1 "SELECT x FROM d1 UNION ALL SELECT a FROM d2 ORDER BY x*z" 1st 1812 2 "SELECT x,z FROM d1 UNION ALL SELECT a,b FROM d2 ORDER BY x, x/z" 2nd 1813} 1814 1815do_select_tests e_select-8.7.2 { 1816 1 "SELECT x*z FROM d1 UNION ALL SELECT a FROM d2 ORDER BY x*z" { 1817 -20 -2 -1 3 7 8 93 186 babied barked commercials gently 1818 iterate lad pragmatist reemphasizes rejoicing solemnness 1819 } 1820 2 "SELECT x, x/z FROM d1 UNION ALL SELECT a,b FROM d2 ORDER BY x, x/z" { 1821 1 -1 1 0 1 0 1 0 1 0 1 0 2 -2 2 0 1822 babied charitableness barked interrupted commercials bathrobe gently 1823 failings iterate sexton lad relenting pragmatist guarded reemphasizes reply 1824 rejoicing liabilities solemnness annexed 1825 } 1826} 1827 1828do_execsql_test e_select-8.8.0 { 1829 CREATE TABLE d3(a); 1830 INSERT INTO d3 VALUES('text'); 1831 INSERT INTO d3 VALUES(14.1); 1832 INSERT INTO d3 VALUES(13); 1833 INSERT INTO d3 VALUES(X'78787878'); 1834 INSERT INTO d3 VALUES(15); 1835 INSERT INTO d3 VALUES(12.9); 1836 INSERT INTO d3 VALUES(null); 1837 1838 CREATE TABLE d4(x COLLATE nocase); 1839 INSERT INTO d4 VALUES('abc'); 1840 INSERT INTO d4 VALUES('ghi'); 1841 INSERT INTO d4 VALUES('DEF'); 1842 INSERT INTO d4 VALUES('JKL'); 1843} {} 1844 1845# EVIDENCE-OF: R-10883-17697 For the purposes of sorting rows, values 1846# are compared in the same way as for comparison expressions. 1847# 1848# The following tests verify that values of different types are sorted 1849# correctly, and that mixed real and integer values are compared properly. 1850# 1851do_execsql_test e_select-8.8.1 { 1852 SELECT a FROM d3 ORDER BY a 1853} {{} 12.9 13 14.1 15 text xxxx} 1854do_execsql_test e_select-8.8.2 { 1855 SELECT a FROM d3 ORDER BY a DESC 1856} {xxxx text 15 14.1 13 12.9 {}} 1857 1858 1859# EVIDENCE-OF: R-64199-22471 If the ORDER BY expression is assigned a 1860# collation sequence using the postfix COLLATE operator, then the 1861# specified collation sequence is used. 1862# 1863do_execsql_test e_select-8.9.1 { 1864 SELECT x FROM d4 ORDER BY 1 COLLATE binary 1865} {DEF JKL abc ghi} 1866do_execsql_test e_select-8.9.2 { 1867 SELECT x COLLATE binary FROM d4 ORDER BY 1 COLLATE nocase 1868} {abc DEF ghi JKL} 1869 1870# EVIDENCE-OF: R-09398-26102 Otherwise, if the ORDER BY expression is 1871# an alias to an expression that has been assigned a collation sequence 1872# using the postfix COLLATE operator, then the collation sequence 1873# assigned to the aliased expression is used. 1874# 1875# In the test 8.10.2, the only result-column expression has no alias. So the 1876# ORDER BY expression is not a reference to it and therefore does not inherit 1877# the collation sequence. In test 8.10.3, "x" is the alias (as well as the 1878# column name), so the ORDER BY expression is interpreted as an alias and the 1879# collation sequence attached to the result column is used for sorting. 1880# 1881do_execsql_test e_select-8.10.1 { 1882 SELECT x COLLATE binary FROM d4 ORDER BY 1 1883} {DEF JKL abc ghi} 1884do_execsql_test e_select-8.10.2 { 1885 SELECT x COLLATE binary FROM d4 ORDER BY x 1886} {abc DEF ghi JKL} 1887do_execsql_test e_select-8.10.3 { 1888 SELECT x COLLATE binary AS x FROM d4 ORDER BY x 1889} {DEF JKL abc ghi} 1890 1891# EVIDENCE-OF: R-27301-09658 Otherwise, if the ORDER BY expression is a 1892# column or an alias of an expression that is a column, then the default 1893# collation sequence for the column is used. 1894# 1895do_execsql_test e_select-8.11.1 { 1896 SELECT x AS y FROM d4 ORDER BY y 1897} {abc DEF ghi JKL} 1898do_execsql_test e_select-8.11.2 { 1899 SELECT x||'' FROM d4 ORDER BY x 1900} {abc DEF ghi JKL} 1901 1902# EVIDENCE-OF: R-49925-55905 Otherwise, the BINARY collation sequence is 1903# used. 1904# 1905do_execsql_test e_select-8.12.1 { 1906 SELECT x FROM d4 ORDER BY x||'' 1907} {DEF JKL abc ghi} 1908 1909# EVIDENCE-OF: R-44130-32593 If an ORDER BY expression is not an integer 1910# alias, then SQLite searches the left-most SELECT in the compound for a 1911# result column that matches either the second or third rules above. If 1912# a match is found, the search stops and the expression is handled as an 1913# alias for the result column that it has been matched against. 1914# Otherwise, the next SELECT to the right is tried, and so on. 1915# 1916do_execsql_test e_select-8.13.0 { 1917 CREATE TABLE d5(a, b); 1918 CREATE TABLE d6(c, d); 1919 CREATE TABLE d7(e, f); 1920 1921 INSERT INTO d5 VALUES(1, 'f'); 1922 INSERT INTO d6 VALUES(2, 'e'); 1923 INSERT INTO d7 VALUES(3, 'd'); 1924 INSERT INTO d5 VALUES(4, 'c'); 1925 INSERT INTO d6 VALUES(5, 'b'); 1926 INSERT INTO d7 VALUES(6, 'a'); 1927 1928 CREATE TABLE d8(x COLLATE nocase); 1929 CREATE TABLE d9(y COLLATE nocase); 1930 1931 INSERT INTO d8 VALUES('a'); 1932 INSERT INTO d9 VALUES('B'); 1933 INSERT INTO d8 VALUES('c'); 1934 INSERT INTO d9 VALUES('D'); 1935} {} 1936do_select_tests e_select-8.13 { 1937 1 { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7 1938 ORDER BY a 1939 } {1 2 3 4 5 6} 1940 2 { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7 1941 ORDER BY c 1942 } {1 2 3 4 5 6} 1943 3 { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7 1944 ORDER BY e 1945 } {1 2 3 4 5 6} 1946 4 { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7 1947 ORDER BY 1 1948 } {1 2 3 4 5 6} 1949 1950 5 { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY b } 1951 {f 1 c 4 4 c 1 f} 1952 6 { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY 2 } 1953 {f 1 c 4 4 c 1 f} 1954 1955 7 { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY a } 1956 {1 f 4 c c 4 f 1} 1957 8 { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY 1 } 1958 {1 f 4 c c 4 f 1} 1959 1960 9 { SELECT a, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY a+1 } 1961 {f 2 c 5 4 c 1 f} 1962 10 { SELECT a, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY 2 } 1963 {f 2 c 5 4 c 1 f} 1964 1965 11 { SELECT a+1, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY a+1 } 1966 {2 f 5 c c 5 f 2} 1967 12 { SELECT a+1, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY 1 } 1968 {2 f 5 c c 5 f 2} 1969} 1970 1971# EVIDENCE-OF: R-39265-04070 If no matching expression can be found in 1972# the result columns of any constituent SELECT, it is an error. 1973# 1974do_select_tests e_select-8.14 -error { 1975 %s ORDER BY term does not match any column in the result set 1976} { 1977 1 { SELECT a FROM d5 UNION SELECT c FROM d6 ORDER BY a+1 } 1st 1978 2 { SELECT a FROM d5 UNION SELECT c FROM d6 ORDER BY a, a+1 } 2nd 1979 3 { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY 'hello' } 1st 1980 4 { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY blah } 1st 1981 5 { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY c,d,c+d } 3rd 1982 6 { SELECT * FROM d5 EXCEPT SELECT * FROM d7 ORDER BY 1,2,b,a/b } 4th 1983} 1984 1985# EVIDENCE-OF: R-03407-11483 Each term of the ORDER BY clause is 1986# processed separately and may be matched against result columns from 1987# different SELECT statements in the compound. 1988# 1989do_select_tests e_select-8.15 { 1990 1 { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY a, d } 1991 {1 e 1 f 4 b 4 c} 1992 2 { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY c-1, b } 1993 {1 e 1 f 4 b 4 c} 1994 3 { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY 1, 2 } 1995 {1 e 1 f 4 b 4 c} 1996} 1997 1998 1999#------------------------------------------------------------------------- 2000# Tests related to statements made about the LIMIT/OFFSET clause. 2001# 2002do_execsql_test e_select-9.0 { 2003 CREATE TABLE f1(a, b); 2004 INSERT INTO f1 VALUES(26, 'z'); 2005 INSERT INTO f1 VALUES(25, 'y'); 2006 INSERT INTO f1 VALUES(24, 'x'); 2007 INSERT INTO f1 VALUES(23, 'w'); 2008 INSERT INTO f1 VALUES(22, 'v'); 2009 INSERT INTO f1 VALUES(21, 'u'); 2010 INSERT INTO f1 VALUES(20, 't'); 2011 INSERT INTO f1 VALUES(19, 's'); 2012 INSERT INTO f1 VALUES(18, 'r'); 2013 INSERT INTO f1 VALUES(17, 'q'); 2014 INSERT INTO f1 VALUES(16, 'p'); 2015 INSERT INTO f1 VALUES(15, 'o'); 2016 INSERT INTO f1 VALUES(14, 'n'); 2017 INSERT INTO f1 VALUES(13, 'm'); 2018 INSERT INTO f1 VALUES(12, 'l'); 2019 INSERT INTO f1 VALUES(11, 'k'); 2020 INSERT INTO f1 VALUES(10, 'j'); 2021 INSERT INTO f1 VALUES(9, 'i'); 2022 INSERT INTO f1 VALUES(8, 'h'); 2023 INSERT INTO f1 VALUES(7, 'g'); 2024 INSERT INTO f1 VALUES(6, 'f'); 2025 INSERT INTO f1 VALUES(5, 'e'); 2026 INSERT INTO f1 VALUES(4, 'd'); 2027 INSERT INTO f1 VALUES(3, 'c'); 2028 INSERT INTO f1 VALUES(2, 'b'); 2029 INSERT INTO f1 VALUES(1, 'a'); 2030} {} 2031 2032# EVIDENCE-OF: R-30481-56627 Any scalar expression may be used in the 2033# LIMIT clause, so long as it evaluates to an integer or a value that 2034# can be losslessly converted to an integer. 2035# 2036do_select_tests e_select-9.1 { 2037 1 { SELECT b FROM f1 ORDER BY a LIMIT 5 } {a b c d e} 2038 2 { SELECT b FROM f1 ORDER BY a LIMIT 2+3 } {a b c d e} 2039 3 { SELECT b FROM f1 ORDER BY a LIMIT (SELECT a FROM f1 WHERE b = 'e') } 2040 {a b c d e} 2041 4 { SELECT b FROM f1 ORDER BY a LIMIT 5.0 } {a b c d e} 2042 5 { SELECT b FROM f1 ORDER BY a LIMIT '5' } {a b c d e} 2043} 2044 2045# EVIDENCE-OF: R-46155-47219 If the expression evaluates to a NULL value 2046# or any other value that cannot be losslessly converted to an integer, 2047# an error is returned. 2048# 2049 2050do_select_tests e_select-9.2 -error "datatype mismatch" { 2051 1 { SELECT b FROM f1 ORDER BY a LIMIT 'hello' } {} 2052 2 { SELECT b FROM f1 ORDER BY a LIMIT NULL } {} 2053 3 { SELECT b FROM f1 ORDER BY a LIMIT X'ABCD' } {} 2054 4 { SELECT b FROM f1 ORDER BY a LIMIT 5.1 } {} 2055 5 { SELECT b FROM f1 ORDER BY a LIMIT (SELECT group_concat(b) FROM f1) } {} 2056} 2057 2058# EVIDENCE-OF: R-03014-26414 If the LIMIT expression evaluates to a 2059# negative value, then there is no upper bound on the number of rows 2060# returned. 2061# 2062do_select_tests e_select-9.4 { 2063 1 { SELECT b FROM f1 ORDER BY a LIMIT -1 } 2064 {a b c d e f g h i j k l m n o p q r s t u v w x y z} 2065 2 { SELECT b FROM f1 ORDER BY a LIMIT length('abc')-100 } 2066 {a b c d e f g h i j k l m n o p q r s t u v w x y z} 2067 3 { SELECT b FROM f1 ORDER BY a LIMIT (SELECT count(*) FROM f1)/2 - 14 } 2068 {a b c d e f g h i j k l m n o p q r s t u v w x y z} 2069} 2070 2071# EVIDENCE-OF: R-33750-29536 Otherwise, the SELECT returns the first N 2072# rows of its result set only, where N is the value that the LIMIT 2073# expression evaluates to. 2074# 2075do_select_tests e_select-9.5 { 2076 1 { SELECT b FROM f1 ORDER BY a LIMIT 0 } {} 2077 2 { SELECT b FROM f1 ORDER BY a DESC LIMIT 4 } {z y x w} 2078 3 { SELECT b FROM f1 ORDER BY a DESC LIMIT 8 } {z y x w v u t s} 2079 4 { SELECT b FROM f1 ORDER BY a DESC LIMIT '12.0' } {z y x w v u t s r q p o} 2080} 2081 2082# EVIDENCE-OF: R-54935-19057 Or, if the SELECT statement would return 2083# less than N rows without a LIMIT clause, then the entire result set is 2084# returned. 2085# 2086do_select_tests e_select-9.6 { 2087 1 { SELECT b FROM f1 WHERE a>21 ORDER BY a LIMIT 10 } {v w x y z} 2088 2 { SELECT count(*) FROM f1 GROUP BY a/5 ORDER BY 1 LIMIT 10 } {2 4 5 5 5 5} 2089} 2090 2091 2092# EVIDENCE-OF: R-24188-24349 The expression attached to the optional 2093# OFFSET clause that may follow a LIMIT clause must also evaluate to an 2094# integer, or a value that can be losslessly converted to an integer. 2095# 2096foreach {tn select} { 2097 1 { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET 'hello' } 2098 2 { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET NULL } 2099 3 { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET X'ABCD' } 2100 4 { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET 5.1 } 2101 5 { SELECT b FROM f1 ORDER BY a 2102 LIMIT 2 OFFSET (SELECT group_concat(b) FROM f1) 2103 } 2104} { 2105 do_catchsql_test e_select-9.7.$tn $select {1 {datatype mismatch}} 2106} 2107 2108# EVIDENCE-OF: R-20467-43422 If an expression has an OFFSET clause, then 2109# the first M rows are omitted from the result set returned by the 2110# SELECT statement and the next N rows are returned, where M and N are 2111# the values that the OFFSET and LIMIT clauses evaluate to, 2112# respectively. 2113# 2114do_select_tests e_select-9.8 { 2115 1 { SELECT b FROM f1 ORDER BY a LIMIT 10 OFFSET 5} {f g h i j k l m n o} 2116 2 { SELECT b FROM f1 ORDER BY a LIMIT 2+3 OFFSET 10} {k l m n o} 2117 3 { SELECT b FROM f1 ORDER BY a 2118 LIMIT (SELECT a FROM f1 WHERE b='j') 2119 OFFSET (SELECT a FROM f1 WHERE b='b') 2120 } {c d e f g h i j k l} 2121 4 { SELECT b FROM f1 ORDER BY a LIMIT '5' OFFSET 3.0 } {d e f g h} 2122 5 { SELECT b FROM f1 ORDER BY a LIMIT '5' OFFSET 0 } {a b c d e} 2123 6 { SELECT b FROM f1 ORDER BY a LIMIT 0 OFFSET 10 } {} 2124 7 { SELECT b FROM f1 ORDER BY a LIMIT 3 OFFSET '1'||'5' } {p q r} 2125} 2126 2127# EVIDENCE-OF: R-34648-44875 Or, if the SELECT would return less than 2128# M+N rows if it did not have a LIMIT clause, then the first M rows are 2129# skipped and the remaining rows (if any) are returned. 2130# 2131do_select_tests e_select-9.9 { 2132 1 { SELECT b FROM f1 ORDER BY a LIMIT 10 OFFSET 20} {u v w x y z} 2133 2 { SELECT a FROM f1 ORDER BY a DESC LIMIT 100 OFFSET 18+4} {4 3 2 1} 2134} 2135 2136 2137# EVIDENCE-OF: R-23293-62447 If the OFFSET clause evaluates to a 2138# negative value, the results are the same as if it had evaluated to 2139# zero. 2140# 2141do_select_tests e_select-9.10 { 2142 1 { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET -1 } {a b c d e} 2143 2 { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET -500 } {a b c d e} 2144 3 { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET 0 } {a b c d e} 2145} 2146 2147# EVIDENCE-OF: R-19509-40356 Instead of a separate OFFSET clause, the 2148# LIMIT clause may specify two scalar expressions separated by a comma. 2149# 2150# EVIDENCE-OF: R-33788-46243 In this case, the first expression is used 2151# as the OFFSET expression and the second as the LIMIT expression. 2152# 2153do_select_tests e_select-9.11 { 2154 1 { SELECT b FROM f1 ORDER BY a LIMIT 5, 10 } {f g h i j k l m n o} 2155 2 { SELECT b FROM f1 ORDER BY a LIMIT 10, 2+3 } {k l m n o} 2156 3 { SELECT b FROM f1 ORDER BY a 2157 LIMIT (SELECT a FROM f1 WHERE b='b'), (SELECT a FROM f1 WHERE b='j') 2158 } {c d e f g h i j k l} 2159 4 { SELECT b FROM f1 ORDER BY a LIMIT 3.0, '5' } {d e f g h} 2160 5 { SELECT b FROM f1 ORDER BY a LIMIT 0, '5' } {a b c d e} 2161 6 { SELECT b FROM f1 ORDER BY a LIMIT 10, 0 } {} 2162 7 { SELECT b FROM f1 ORDER BY a LIMIT '1'||'5', 3 } {p q r} 2163 2164 8 { SELECT b FROM f1 ORDER BY a LIMIT 20, 10 } {u v w x y z} 2165 9 { SELECT a FROM f1 ORDER BY a DESC LIMIT 18+4, 100 } {4 3 2 1} 2166 2167 10 { SELECT b FROM f1 ORDER BY a LIMIT -1, 5 } {a b c d e} 2168 11 { SELECT b FROM f1 ORDER BY a LIMIT -500, 5 } {a b c d e} 2169 12 { SELECT b FROM f1 ORDER BY a LIMIT 0, 5 } {a b c d e} 2170} 2171 2172finish_test 2173