xref: /sqlite-3.40.0/test/e_select.test (revision 0338f53b)
14ce74880Sdan# 2010 July 16
24ce74880Sdan#
34ce74880Sdan# The author disclaims copyright to this source code.  In place of
44ce74880Sdan# a legal notice, here is a blessing:
54ce74880Sdan#
64ce74880Sdan#    May you do good and not evil.
74ce74880Sdan#    May you find forgiveness for yourself and forgive others.
84ce74880Sdan#    May you share freely, never taking more than you give.
94ce74880Sdan#
104ce74880Sdan#***********************************************************************
114ce74880Sdan#
124ce74880Sdan# This file implements tests to verify that the "testable statements" in
134ce74880Sdan# the lang_select.html document are correct.
144ce74880Sdan#
154ce74880Sdan
164ce74880Sdanset testdir [file dirname $argv0]
174ce74880Sdansource $testdir/tester.tcl
184ce74880Sdan
192f56da3fSdanifcapable !compound {
202f56da3fSdan  finish_test
212f56da3fSdan  return
222f56da3fSdan}
232f56da3fSdan
244ce74880Sdando_execsql_test e_select-1.0 {
254ce74880Sdan  CREATE TABLE t1(a, b);
264ce74880Sdan  INSERT INTO t1 VALUES('a', 'one');
274ce74880Sdan  INSERT INTO t1 VALUES('b', 'two');
284ce74880Sdan  INSERT INTO t1 VALUES('c', 'three');
294ce74880Sdan
304ce74880Sdan  CREATE TABLE t2(a, b);
314ce74880Sdan  INSERT INTO t2 VALUES('a', 'I');
324ce74880Sdan  INSERT INTO t2 VALUES('b', 'II');
334ce74880Sdan  INSERT INTO t2 VALUES('c', 'III');
344ce74880Sdan
354ce74880Sdan  CREATE TABLE t3(a, c);
364ce74880Sdan  INSERT INTO t3 VALUES('a', 1);
374ce74880Sdan  INSERT INTO t3 VALUES('b', 2);
384ce74880Sdan
394ce74880Sdan  CREATE TABLE t4(a, c);
404ce74880Sdan  INSERT INTO t4 VALUES('a', NULL);
414ce74880Sdan  INSERT INTO t4 VALUES('b', 2);
424ce74880Sdan} {}
434ce74880Sdanset t1_cross_t2 [list                \
444ce74880Sdan   a one   a I      a one   b II     \
454ce74880Sdan   a one   c III    b two   a I      \
464ce74880Sdan   b two   b II     b two   c III    \
474ce74880Sdan   c three a I      c three b II     \
484ce74880Sdan   c three c III                     \
494ce74880Sdan]
504ce74880Sdanset t1_cross_t1 [list                  \
514ce74880Sdan   a one   a one      a one   b two    \
524ce74880Sdan   a one   c three    b two   a one    \
534ce74880Sdan   b two   b two      b two   c three  \
544ce74880Sdan   c three a one      c three b two    \
554ce74880Sdan   c three c three                     \
564ce74880Sdan]
574ce74880Sdan
584ce74880Sdan
598663d0fbSdan# This proc is a specialized version of [do_execsql_test].
608663d0fbSdan#
618663d0fbSdan# The second argument to this proc must be a SELECT statement that
628663d0fbSdan# features a cross join of some time. Instead of the usual ",",
638663d0fbSdan# "CROSS JOIN" or "INNER JOIN" join-op, the string %JOIN% must be
648663d0fbSdan# substituted.
658663d0fbSdan#
668663d0fbSdan# This test runs the SELECT three times - once with:
678663d0fbSdan#
688663d0fbSdan#   * s/%JOIN%/,/
695c3f58e4Sdan#   * s/%JOIN%/JOIN/
708663d0fbSdan#   * s/%JOIN%/INNER JOIN/
718663d0fbSdan#   * s/%JOIN%/CROSS JOIN/
728663d0fbSdan#
738663d0fbSdan# and checks that each time the results of the SELECT are $res.
748663d0fbSdan#
758663d0fbSdanproc do_join_test {tn select res} {
768663d0fbSdan  foreach {tn2 joinop} [list    1 ,    2 "CROSS JOIN"    3 "INNER JOIN"] {
778663d0fbSdan    set S [string map [list %JOIN% $joinop] $select]
788663d0fbSdan    uplevel do_execsql_test $tn.$tn2 [list $S] [list $res]
798663d0fbSdan  }
808663d0fbSdan}
818663d0fbSdan
828663d0fbSdan#-------------------------------------------------------------------------
838663d0fbSdan# The following tests check that all paths on the syntax diagrams on
848663d0fbSdan# the lang_select.html page may be taken.
858663d0fbSdan#
8639759747Sdrh# -- syntax diagram join-constraint
878663d0fbSdan#
888663d0fbSdando_join_test e_select-0.1.1 {
898663d0fbSdan  SELECT count(*) FROM t1 %JOIN% t2 ON (t1.a=t2.a)
908663d0fbSdan} {3}
918663d0fbSdando_join_test e_select-0.1.2 {
928663d0fbSdan  SELECT count(*) FROM t1 %JOIN% t2 USING (a)
938663d0fbSdan} {3}
948663d0fbSdando_join_test e_select-0.1.3 {
958663d0fbSdan  SELECT count(*) FROM t1 %JOIN% t2
968663d0fbSdan} {9}
978663d0fbSdando_catchsql_test e_select-0.1.4 {
988663d0fbSdan  SELECT count(*) FROM t1, t2 ON (t1.a=t2.a) USING (a)
99d44f8b23Sdrh} {1 {near "USING": syntax error}}
1008663d0fbSdando_catchsql_test e_select-0.1.5 {
1018663d0fbSdan  SELECT count(*) FROM t1, t2 USING (a) ON (t1.a=t2.a)
1028663d0fbSdan} {1 {near "ON": syntax error}}
1038663d0fbSdan
10439759747Sdrh# -- syntax diagram select-core
105f41627abSdan#
106f41627abSdan#   0: SELECT ...
107f41627abSdan#   1: SELECT DISTINCT ...
108f41627abSdan#   2: SELECT ALL ...
109f41627abSdan#
110f41627abSdan#   0: No FROM clause
111f41627abSdan#   1: Has FROM clause
112f41627abSdan#
113f41627abSdan#   0: No WHERE clause
114f41627abSdan#   1: Has WHERE clause
115f41627abSdan#
116f41627abSdan#   0: No GROUP BY clause
117f41627abSdan#   1: Has GROUP BY clause
118f41627abSdan#   2: Has GROUP BY and HAVING clauses
119f41627abSdan#
1201b89d5d9Sdando_select_tests e_select-0.2 {
121f41627abSdan  0000.1  "SELECT 1, 2, 3 " {1 2 3}
122f41627abSdan  1000.1  "SELECT DISTINCT 1, 2, 3 " {1 2 3}
123f41627abSdan  2000.1  "SELECT ALL 1, 2, 3 " {1 2 3}
124f41627abSdan
125f41627abSdan  0100.1  "SELECT a, b, a||b FROM t1 " {
126f41627abSdan    a one aone b two btwo c three cthree
127f41627abSdan  }
128f41627abSdan  1100.1  "SELECT DISTINCT a, b, a||b FROM t1 " {
129f41627abSdan    a one aone b two btwo c three cthree
130f41627abSdan  }
131f41627abSdan  1200.1  "SELECT ALL a, b, a||b FROM t1 " {
132f41627abSdan    a one aone b two btwo c three cthree
133f41627abSdan  }
134f41627abSdan
135f41627abSdan  0010.1  "SELECT 1, 2, 3 WHERE 1 " {1 2 3}
136f41627abSdan  0010.2  "SELECT 1, 2, 3 WHERE 0 " {}
137f41627abSdan  0010.3  "SELECT 1, 2, 3 WHERE NULL " {}
138f41627abSdan
139f41627abSdan  1010.1  "SELECT DISTINCT 1, 2, 3 WHERE 1 " {1 2 3}
140f41627abSdan
141f41627abSdan  2010.1  "SELECT ALL 1, 2, 3 WHERE 1 " {1 2 3}
142f41627abSdan
143f41627abSdan  0110.1  "SELECT a, b, a||b FROM t1 WHERE a!='x' " {
144f41627abSdan    a one aone b two btwo c three cthree
145f41627abSdan  }
146f41627abSdan  0110.2  "SELECT a, b, a||b FROM t1 WHERE a=='x'" {}
147f41627abSdan
148f41627abSdan  1110.1  "SELECT DISTINCT a, b, a||b FROM t1 WHERE a!='x' " {
149f41627abSdan    a one aone b two btwo c three cthree
150f41627abSdan  }
151f41627abSdan
152f41627abSdan  2110.0  "SELECT ALL a, b, a||b FROM t1 WHERE a=='x'" {}
153f41627abSdan
154f41627abSdan  0001.1  "SELECT 1, 2, 3 GROUP BY 2" {1 2 3}
155f41627abSdan  0002.1  "SELECT 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3}
156f41627abSdan  0002.2  "SELECT 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {}
157f41627abSdan
158f41627abSdan  1001.1  "SELECT DISTINCT 1, 2, 3 GROUP BY 2" {1 2 3}
159f41627abSdan  1002.1  "SELECT DISTINCT 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3}
160f41627abSdan  1002.2  "SELECT DISTINCT 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {}
161f41627abSdan
162f41627abSdan  2001.1  "SELECT ALL 1, 2, 3 GROUP BY 2" {1 2 3}
163f41627abSdan  2002.1  "SELECT ALL 1, 2, 3 GROUP BY 2 HAVING count(*)=1" {1 2 3}
164f41627abSdan  2002.2  "SELECT ALL 1, 2, 3 GROUP BY 2 HAVING count(*)>1" {}
165f41627abSdan
166f41627abSdan  0101.1  "SELECT count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b}
167f41627abSdan  0102.1  "SELECT count(*), max(a) FROM t1 GROUP BY b HAVING count(*)=1" {
168f41627abSdan    1 a 1 c 1 b
169f41627abSdan  }
170f41627abSdan  0102.2  "SELECT count(*), max(a) FROM t1 GROUP BY b HAVING count(*)=2" {}
171f41627abSdan
172f41627abSdan  1101.1  "SELECT DISTINCT count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b}
173f41627abSdan  1102.1  "SELECT DISTINCT count(*), max(a) FROM t1
174f41627abSdan           GROUP BY b HAVING count(*)=1" {
175f41627abSdan    1 a 1 c 1 b
176f41627abSdan  }
177f41627abSdan  1102.2  "SELECT DISTINCT count(*), max(a) FROM t1
1783a07548bSdrh           GROUP BY b HAVING count(*)=2" {}
179f41627abSdan
180f41627abSdan  2101.1  "SELECT ALL count(*), max(a) FROM t1 GROUP BY b" {1 a 1 c 1 b}
181f41627abSdan  2102.1  "SELECT ALL count(*), max(a) FROM t1
182f41627abSdan           GROUP BY b HAVING count(*)=1" {
183f41627abSdan    1 a 1 c 1 b
184f41627abSdan  }
185f41627abSdan  2102.2  "SELECT ALL count(*), max(a) FROM t1
1863a07548bSdrh           GROUP BY b HAVING count(*)=2" {}
187f41627abSdan
188f41627abSdan  0011.1  "SELECT 1, 2, 3 WHERE 1 GROUP BY 2" {1 2 3}
189f41627abSdan  0012.1  "SELECT 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)=1" {}
190f41627abSdan  0012.2  "SELECT 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)>1" {}
191f41627abSdan
192f41627abSdan  1011.1  "SELECT DISTINCT 1, 2, 3 WHERE 0 GROUP BY 2" {}
193f41627abSdan  1012.1  "SELECT DISTINCT 1, 2, 3 WHERE 1 GROUP BY 2 HAVING count(*)=1"
194f41627abSdan          {1 2 3}
195f41627abSdan  1012.2  "SELECT DISTINCT 1, 2, 3 WHERE NULL GROUP BY 2 HAVING count(*)>1" {}
196f41627abSdan
197f41627abSdan  2011.1  "SELECT ALL 1, 2, 3 WHERE 1 GROUP BY 2" {1 2 3}
198f41627abSdan  2012.1  "SELECT ALL 1, 2, 3 WHERE 0 GROUP BY 2 HAVING count(*)=1" {}
199f41627abSdan  2012.2  "SELECT ALL 1, 2, 3 WHERE 'abc' GROUP BY 2 HAVING count(*)>1" {}
200f41627abSdan
201f41627abSdan  0111.1  "SELECT count(*), max(a) FROM t1 WHERE a='a' GROUP BY b" {1 a}
202f41627abSdan  0112.1  "SELECT count(*), max(a) FROM t1
203f41627abSdan           WHERE a='c' GROUP BY b HAVING count(*)=1" {1 c}
204f41627abSdan  0112.2  "SELECT count(*), max(a) FROM t1
205f41627abSdan           WHERE 0 GROUP BY b HAVING count(*)=2" {}
206f41627abSdan  1111.1  "SELECT DISTINCT count(*), max(a) FROM t1 WHERE a<'c' GROUP BY b"
207f41627abSdan          {1 a 1 b}
208f41627abSdan  1112.1  "SELECT DISTINCT count(*), max(a) FROM t1 WHERE a>'a'
209f41627abSdan           GROUP BY b HAVING count(*)=1" {
210f41627abSdan    1 c 1 b
211f41627abSdan  }
212f41627abSdan  1112.2  "SELECT DISTINCT count(*), max(a) FROM t1 WHERE 0
2133a07548bSdrh           GROUP BY b HAVING count(*)=2" {}
214f41627abSdan
215f41627abSdan  2111.1  "SELECT ALL count(*), max(a) FROM t1 WHERE b>'one' GROUP BY b"
216f41627abSdan          {1 c 1 b}
217f41627abSdan  2112.1  "SELECT ALL count(*), max(a) FROM t1 WHERE a!='b'
218f41627abSdan           GROUP BY b HAVING count(*)=1" {
219f41627abSdan    1 a 1 c
220f41627abSdan  }
221f41627abSdan  2112.2  "SELECT ALL count(*), max(a) FROM t1
222f41627abSdan           WHERE 0 GROUP BY b HAVING count(*)=2" {}
223f41627abSdan}
224f41627abSdan
225f41627abSdan
22639759747Sdrh# -- syntax diagram result-column
2271b89d5d9Sdan#
2281b89d5d9Sdando_select_tests e_select-0.3 {
2291b89d5d9Sdan  1  "SELECT * FROM t1" {a one b two c three}
2301b89d5d9Sdan  2  "SELECT t1.* FROM t1" {a one b two c three}
2311b89d5d9Sdan  3  "SELECT 'x'||a||'x' FROM t1" {xax xbx xcx}
2321b89d5d9Sdan  4  "SELECT 'x'||a||'x' alias FROM t1" {xax xbx xcx}
2331b89d5d9Sdan  5  "SELECT 'x'||a||'x' AS alias FROM t1" {xax xbx xcx}
2341b89d5d9Sdan}
2351b89d5d9Sdan
23639759747Sdrh# -- syntax diagram join-source
2371b89d5d9Sdan#
23839759747Sdrh# -- syntax diagram join-op
2391b89d5d9Sdan#
2401b89d5d9Sdando_select_tests e_select-0.4 {
2411b89d5d9Sdan  1  "SELECT t1.rowid FROM t1" {1 2 3}
2421b89d5d9Sdan  2  "SELECT t1.rowid FROM t1,t2" {1 1 1 2 2 2 3 3 3}
2431b89d5d9Sdan  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}
2441b89d5d9Sdan
2451b89d5d9Sdan  4  "SELECT t1.rowid FROM t1" {1 2 3}
2461b89d5d9Sdan  5  "SELECT t1.rowid FROM t1 JOIN t2" {1 1 1 2 2 2 3 3 3}
2471b89d5d9Sdan  6  "SELECT t1.rowid FROM t1 JOIN t2 JOIN t3"
2481b89d5d9Sdan     {1 1 1 1 1 1 2 2 2 2 2 2 3 3 3 3 3 3}
2491b89d5d9Sdan
2501b89d5d9Sdan  7  "SELECT t1.rowid FROM t1 NATURAL JOIN t3" {1 2}
2511b89d5d9Sdan  8  "SELECT t1.rowid FROM t1 NATURAL LEFT OUTER JOIN t3" {1 2 3}
25207bf3918Sdrh  9  "SELECT t1.rowid FROM t1 NATURAL LEFT JOIN t3" {1 2 3}
25307bf3918Sdrh  10 "SELECT t1.rowid FROM t1 NATURAL INNER JOIN t3" {1 2}
25407bf3918Sdrh  11 "SELECT t1.rowid FROM t1 NATURAL CROSS JOIN t3" {1 2}
2551b89d5d9Sdan
25607bf3918Sdrh  12 "SELECT t1.rowid FROM t1 JOIN t3" {1 1 2 2 3 3}
25707bf3918Sdrh  13 "SELECT t1.rowid FROM t1 LEFT OUTER JOIN t3" {1 1 2 2 3 3}
25807bf3918Sdrh  14 "SELECT t1.rowid FROM t1 LEFT JOIN t3" {1 1 2 2 3 3}
25907bf3918Sdrh  15 "SELECT t1.rowid FROM t1 INNER JOIN t3" {1 1 2 2 3 3}
26007bf3918Sdrh  16 "SELECT t1.rowid FROM t1 CROSS JOIN t3" {1 1 2 2 3 3}
2611b89d5d9Sdan}
2621b89d5d9Sdan
26339759747Sdrh# -- syntax diagram compound-operator
2641b89d5d9Sdan#
2651b89d5d9Sdando_select_tests e_select-0.5 {
2661b89d5d9Sdan  1  "SELECT rowid FROM t1 UNION ALL SELECT rowid+2 FROM t4" {1 2 3 3 4}
2671b89d5d9Sdan  2  "SELECT rowid FROM t1 UNION     SELECT rowid+2 FROM t4" {1 2 3 4}
2681b89d5d9Sdan  3  "SELECT rowid FROM t1 INTERSECT SELECT rowid+2 FROM t4" {3}
2691b89d5d9Sdan  4  "SELECT rowid FROM t1 EXCEPT    SELECT rowid+2 FROM t4" {1 2}
2701b89d5d9Sdan}
2711b89d5d9Sdan
27239759747Sdrh# -- syntax diagram ordering-term
2731b89d5d9Sdan#
2741b89d5d9Sdando_select_tests e_select-0.6 {
2751b89d5d9Sdan  1  "SELECT b||a FROM t1 ORDER BY b||a"                  {onea threec twob}
2761b89d5d9Sdan  2  "SELECT b||a FROM t1 ORDER BY (b||a) COLLATE nocase" {onea threec twob}
2771b89d5d9Sdan  3  "SELECT b||a FROM t1 ORDER BY (b||a) ASC"            {onea threec twob}
2781b89d5d9Sdan  4  "SELECT b||a FROM t1 ORDER BY (b||a) DESC"           {twob threec onea}
2791b89d5d9Sdan}
2801b89d5d9Sdan
28139759747Sdrh# -- syntax diagram select-stmt
2821b89d5d9Sdan#
2831b89d5d9Sdando_select_tests e_select-0.7 {
2841b89d5d9Sdan  1  "SELECT * FROM t1" {a one b two c three}
2851b89d5d9Sdan  2  "SELECT * FROM t1 ORDER BY b" {a one c three b two}
2861b89d5d9Sdan  3  "SELECT * FROM t1 ORDER BY b, a" {a one c three b two}
2871b89d5d9Sdan
2881b89d5d9Sdan  4  "SELECT * FROM t1 LIMIT 10" {a one b two c three}
2891b89d5d9Sdan  5  "SELECT * FROM t1 LIMIT 10 OFFSET 5" {}
2901b89d5d9Sdan  6  "SELECT * FROM t1 LIMIT 10, 5" {}
2911b89d5d9Sdan
2921b89d5d9Sdan  7  "SELECT * FROM t1 ORDER BY a LIMIT 10" {a one b two c three}
2931b89d5d9Sdan  8  "SELECT * FROM t1 ORDER BY b LIMIT 10 OFFSET 5" {}
2941b89d5d9Sdan  9  "SELECT * FROM t1 ORDER BY a,b LIMIT 10, 5" {}
2951b89d5d9Sdan
2961b89d5d9Sdan  10  "SELECT * FROM t1 UNION SELECT b, a FROM t1"
2971b89d5d9Sdan     {a one b two c three one a three c two b}
2981b89d5d9Sdan  11  "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b"
2991b89d5d9Sdan     {one a two b three c a one c three b two}
3001b89d5d9Sdan  12  "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b, a"
3011b89d5d9Sdan     {one a two b three c a one c three b two}
3021b89d5d9Sdan  13  "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10"
3031b89d5d9Sdan     {a one b two c three one a three c two b}
3041b89d5d9Sdan  14  "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10 OFFSET 5"
3051b89d5d9Sdan     {two b}
3061b89d5d9Sdan  15  "SELECT * FROM t1 UNION SELECT b, a FROM t1 LIMIT 10, 5"
3071b89d5d9Sdan     {}
3081b89d5d9Sdan  16  "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY a LIMIT 10"
3091b89d5d9Sdan     {a one b two c three one a three c two b}
3101b89d5d9Sdan  17  "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY b LIMIT 10 OFFSET 5"
3111b89d5d9Sdan     {b two}
3121b89d5d9Sdan  18  "SELECT * FROM t1 UNION SELECT b, a FROM t1 ORDER BY a,b LIMIT 10, 5"
3131b89d5d9Sdan     {}
3141b89d5d9Sdan}
315f41627abSdan
3164ce74880Sdan#-------------------------------------------------------------------------
3174ce74880Sdan# The following tests focus on FROM clause (join) processing.
3184ce74880Sdan#
3194ce74880Sdan
3205c3f58e4Sdan# EVIDENCE-OF: R-16074-54196 If the FROM clause is omitted from a simple
3215c3f58e4Sdan# SELECT statement, then the input data is implicitly a single row zero
3225c3f58e4Sdan# columns wide
3234ce74880Sdan#
3241b89d5d9Sdando_select_tests e_select-1.1 {
3251b89d5d9Sdan  1 "SELECT 'abc'"            {abc}
3261b89d5d9Sdan  2 "SELECT 'abc' WHERE NULL" {}
3271b89d5d9Sdan  3 "SELECT NULL"             {{}}
3281b89d5d9Sdan  4 "SELECT count(*)"         {1}
3291b89d5d9Sdan  5 "SELECT count(*) WHERE 0" {0}
3301b89d5d9Sdan  6 "SELECT count(*) WHERE 1" {1}
3311b89d5d9Sdan}
3325c3f58e4Sdan
333a820c05aSdrh# EVIDENCE-OF: R-45424-07352 If there is only a single table or subquery
334a820c05aSdrh# in the FROM clause, then the input data used by the SELECT statement
335a820c05aSdrh# is the contents of the named table.
3365c3f58e4Sdan#
3375c3f58e4Sdan#   The results of the SELECT queries suggest that they are operating on the
3385c3f58e4Sdan#   contents of the table 'xx'.
3395c3f58e4Sdan#
3401b89d5d9Sdando_execsql_test e_select-1.2.0 {
3415c3f58e4Sdan  CREATE TABLE xx(x, y);
3425c3f58e4Sdan  INSERT INTO xx VALUES('IiJlsIPepMuAhU', X'10B00B897A15BAA02E3F98DCE8F2');
3435c3f58e4Sdan  INSERT INTO xx VALUES(NULL, -16.87);
3445c3f58e4Sdan  INSERT INTO xx VALUES(-17.89, 'linguistically');
3455c3f58e4Sdan} {}
3461b89d5d9Sdando_select_tests e_select-1.2 {
3471b89d5d9Sdan  1  "SELECT quote(x), quote(y) FROM xx" {
3481b89d5d9Sdan     'IiJlsIPepMuAhU' X'10B00B897A15BAA02E3F98DCE8F2'
3491b89d5d9Sdan     NULL             -16.87
3501b89d5d9Sdan     -17.89           'linguistically'
3511b89d5d9Sdan  }
3521b89d5d9Sdan
3531b89d5d9Sdan  2  "SELECT count(*), count(x), count(y) FROM xx" {3 2 3}
3541b89d5d9Sdan  3  "SELECT sum(x), sum(y) FROM xx"               {-17.89 -16.87}
3551b89d5d9Sdan}
3565c3f58e4Sdan
357a820c05aSdrh# EVIDENCE-OF: R-28355-09804 If there is more than one table or subquery
358a820c05aSdrh# in FROM clause then the contents of all tables and/or subqueries are
359a820c05aSdrh# joined into a single dataset for the simple SELECT statement to
360a820c05aSdrh# operate on.
3615c3f58e4Sdan#
3625c3f58e4Sdan#   There are more detailed tests for subsequent requirements that add
3635c3f58e4Sdan#   more detail to this idea. We just add a single test that shows that
3645c3f58e4Sdan#   data is coming from each of the three tables following the FROM clause
3655c3f58e4Sdan#   here to show that the statement, vague as it is, is not incorrect.
3665c3f58e4Sdan#
3671b89d5d9Sdando_select_tests e_select-1.3 {
3681b89d5d9Sdan  1 "SELECT * FROM t1, t2, t3" {
3691b89d5d9Sdan      a one a I a 1 a one a I b 2 a one b II a 1
3701b89d5d9Sdan      a one b II b 2 a one c III a 1 a one c III b 2
3711b89d5d9Sdan      b two a I a 1 b two a I b 2 b two b II a 1
3721b89d5d9Sdan      b two b II b 2 b two c III a 1 b two c III b 2
3731b89d5d9Sdan      c three a I a 1 c three a I b 2 c three b II a 1
3741b89d5d9Sdan      c three b II b 2 c three c III a 1 c three c III b 2
3751b89d5d9Sdan  }
3761b89d5d9Sdan}
3775c3f58e4Sdan
3785c3f58e4Sdan#
3795c3f58e4Sdan# The following block of tests - e_select-1.4.* - test that the description
3805c3f58e4Sdan# of cartesian joins in the SELECT documentation is consistent with SQLite.
3815c3f58e4Sdan# In doing so, we test the following three requirements as a side-effect:
3825c3f58e4Sdan#
383a820c05aSdrh# EVIDENCE-OF: R-49872-03192 If the join-operator is "CROSS JOIN",
384a820c05aSdrh# "INNER JOIN", "JOIN" or a comma (",") and there is no ON or USING
385a820c05aSdrh# clause, then the result of the join is simply the cartesian product of
386a820c05aSdrh# the left and right-hand datasets.
3875c3f58e4Sdan#
3885c3f58e4Sdan#    The tests are built on this assertion. Really, they test that the output
3895c3f58e4Sdan#    of a CROSS JOIN, JOIN, INNER JOIN or "," join matches the expected result
3905c3f58e4Sdan#    of calculating the cartesian product of the left and right-hand datasets.
3915c3f58e4Sdan#
3925c3f58e4Sdan# EVIDENCE-OF: R-46256-57243 There is no difference between the "INNER
3935c3f58e4Sdan# JOIN", "JOIN" and "," join operators.
3945c3f58e4Sdan#
39539759747Sdrh# EVIDENCE-OF: R-25071-21202 The "CROSS JOIN" join operator produces the
39639759747Sdrh# same result as the "INNER JOIN", "JOIN" and "," operators
3975c3f58e4Sdan#
3985c3f58e4Sdan#    All tests are run 4 times, with the only difference in each run being
3995c3f58e4Sdan#    which of the 4 equivalent cartesian product join operators are used.
4005c3f58e4Sdan#    Since the output data is the same in all cases, we consider that this
4015c3f58e4Sdan#    qualifies as testing the two statements above.
4025c3f58e4Sdan#
4035c3f58e4Sdando_execsql_test e_select-1.4.0 {
4045c3f58e4Sdan  CREATE TABLE x1(a, b);
4055c3f58e4Sdan  CREATE TABLE x2(c, d, e);
4065c3f58e4Sdan  CREATE TABLE x3(f, g, h, i);
4075c3f58e4Sdan
4085c3f58e4Sdan  -- x1: 3 rows, 2 columns
4095c3f58e4Sdan  INSERT INTO x1 VALUES(24, 'converging');
4105c3f58e4Sdan  INSERT INTO x1 VALUES(NULL, X'CB71');
4115c3f58e4Sdan  INSERT INTO x1 VALUES('blonds', 'proprietary');
4125c3f58e4Sdan
4135c3f58e4Sdan  -- x2: 2 rows, 3 columns
4145c3f58e4Sdan  INSERT INTO x2 VALUES(-60.06, NULL, NULL);
4155c3f58e4Sdan  INSERT INTO x2 VALUES(-58, NULL, 1.21);
4165c3f58e4Sdan
4175c3f58e4Sdan  -- x3: 5 rows, 4 columns
4185c3f58e4Sdan  INSERT INTO x3 VALUES(-39.24, NULL, 'encompass', -1);
4195c3f58e4Sdan  INSERT INTO x3 VALUES('presenting', 51, 'reformation', 'dignified');
4205c3f58e4Sdan  INSERT INTO x3 VALUES('conducting', -87.24, 37.56, NULL);
4215c3f58e4Sdan  INSERT INTO x3 VALUES('coldest', -96, 'dramatists', 82.3);
4225c3f58e4Sdan  INSERT INTO x3 VALUES('alerting', NULL, -93.79, NULL);
4235c3f58e4Sdan} {}
4245c3f58e4Sdan
4255c3f58e4Sdan# EVIDENCE-OF: R-59089-25828 The columns of the cartesian product
4265c3f58e4Sdan# dataset are, in order, all the columns of the left-hand dataset
4275c3f58e4Sdan# followed by all the columns of the right-hand dataset.
4285c3f58e4Sdan#
4295c3f58e4Sdando_join_test e_select-1.4.1.1 {
4305c3f58e4Sdan  SELECT * FROM x1 %JOIN% x2 LIMIT 1
4315c3f58e4Sdan} [concat {24 converging} {-60.06 {} {}}]
4325c3f58e4Sdan
4335c3f58e4Sdando_join_test e_select-1.4.1.2 {
4345c3f58e4Sdan  SELECT * FROM x2 %JOIN% x1 LIMIT 1
4355c3f58e4Sdan} [concat {-60.06 {} {}} {24 converging}]
4365c3f58e4Sdan
4375c3f58e4Sdando_join_test e_select-1.4.1.3 {
4385c3f58e4Sdan  SELECT * FROM x3 %JOIN% x2 LIMIT 1
4395c3f58e4Sdan} [concat {-39.24 {} encompass -1} {-60.06 {} {}}]
4405c3f58e4Sdan
4415c3f58e4Sdando_join_test e_select-1.4.1.4 {
4425c3f58e4Sdan  SELECT * FROM x2 %JOIN% x3 LIMIT 1
4435c3f58e4Sdan} [concat {-60.06 {} {}} {-39.24 {} encompass -1}]
4445c3f58e4Sdan
4455c3f58e4Sdan# EVIDENCE-OF: R-44414-54710 There is a row in the cartesian product
4465c3f58e4Sdan# dataset formed by combining each unique combination of a row from the
4475c3f58e4Sdan# left-hand and right-hand datasets.
4485c3f58e4Sdan#
4495c3f58e4Sdando_join_test e_select-1.4.2.1 {
450186ad8ccSdrh  SELECT * FROM x2 %JOIN% x3 ORDER BY +c, +f
4515c3f58e4Sdan} [list -60.06 {} {}      -39.24 {} encompass -1                 \
4525c3f58e4Sdan        -60.06 {} {}      alerting {} -93.79 {}                  \
453186ad8ccSdrh        -60.06 {} {}      coldest -96 dramatists 82.3            \
454186ad8ccSdrh        -60.06 {} {}      conducting -87.24 37.56 {}             \
455186ad8ccSdrh        -60.06 {} {}      presenting 51 reformation dignified    \
4565c3f58e4Sdan        -58 {} 1.21       -39.24 {} encompass -1                 \
4575c3f58e4Sdan        -58 {} 1.21       alerting {} -93.79 {}                  \
458186ad8ccSdrh        -58 {} 1.21       coldest -96 dramatists 82.3            \
459186ad8ccSdrh        -58 {} 1.21       conducting -87.24 37.56 {}             \
460186ad8ccSdrh        -58 {} 1.21       presenting 51 reformation dignified    \
4615c3f58e4Sdan]
4625c3f58e4Sdan# TODO: Come back and add a few more like the above.
4635c3f58e4Sdan
4649a2555f5Sdrh# EVIDENCE-OF: R-18439-38548 In other words, if the left-hand dataset
4659a2555f5Sdrh# consists of Nleft rows of Mleft columns, and the right-hand dataset of
4669a2555f5Sdrh# Nright rows of Mright columns, then the cartesian product is a dataset
4679a2555f5Sdrh# of Nleft&times;Nright rows, each containing Mleft+Mright columns.
4685c3f58e4Sdan#
4695c3f58e4Sdan# x1, x2    (Nlhs=3, Nrhs=2)   (Mlhs=2, Mrhs=3)
4705c3f58e4Sdando_join_test e_select-1.4.3.1 {
4715c3f58e4Sdan  SELECT count(*) FROM x1 %JOIN% x2
4725c3f58e4Sdan} [expr 3*2]
4735c3f58e4Sdando_test e_select-1.4.3.2 {
4745c3f58e4Sdan  expr {[llength [execsql {SELECT * FROM x1, x2}]] / 6}
4755c3f58e4Sdan} [expr 2+3]
4765c3f58e4Sdan
4775c3f58e4Sdan# x2, x3    (Nlhs=2, Nrhs=5)   (Mlhs=3, Mrhs=4)
4785c3f58e4Sdando_join_test e_select-1.4.3.3 {
4795c3f58e4Sdan  SELECT count(*) FROM x2 %JOIN% x3
4805c3f58e4Sdan} [expr 2*5]
4815c3f58e4Sdando_test e_select-1.4.3.4 {
4825c3f58e4Sdan  expr {[llength [execsql {SELECT * FROM x2 JOIN x3}]] / 10}
4835c3f58e4Sdan} [expr 3+4]
4845c3f58e4Sdan
4855c3f58e4Sdan# x3, x1    (Nlhs=5, Nrhs=3)   (Mlhs=4, Mrhs=2)
4865c3f58e4Sdando_join_test e_select-1.4.3.5 {
4875c3f58e4Sdan  SELECT count(*) FROM x3 %JOIN% x1
4885c3f58e4Sdan} [expr 5*3]
4895c3f58e4Sdando_test e_select-1.4.3.6 {
4905c3f58e4Sdan  expr {[llength [execsql {SELECT * FROM x3 CROSS JOIN x1}]] / 15}
4915c3f58e4Sdan} [expr 4+2]
4925c3f58e4Sdan
4935c3f58e4Sdan# x3, x3    (Nlhs=5, Nrhs=5)   (Mlhs=4, Mrhs=4)
4945c3f58e4Sdando_join_test e_select-1.4.3.7 {
4955c3f58e4Sdan  SELECT count(*) FROM x3 %JOIN% x3
4965c3f58e4Sdan} [expr 5*5]
4975c3f58e4Sdando_test e_select-1.4.3.8 {
4985c3f58e4Sdan  expr {[llength [execsql {SELECT * FROM x3 INNER JOIN x3 AS x4}]] / 25}
4995c3f58e4Sdan} [expr 4+4]
5005c3f58e4Sdan
5015c3f58e4Sdan# Some extra cartesian product tests using tables t1 and t2.
5025c3f58e4Sdan#
5035c3f58e4Sdando_execsql_test e_select-1.4.4.1 { SELECT * FROM t1, t2 } $t1_cross_t2
5045c3f58e4Sdando_execsql_test e_select-1.4.4.2 { SELECT * FROM t1 AS x, t1 AS y} $t1_cross_t1
5051b89d5d9Sdan
5061b89d5d9Sdando_select_tests e_select-1.4.5 [list                                   \
5074ce74880Sdan    1 { SELECT * FROM t1 CROSS JOIN t2 }           $t1_cross_t2        \
5084ce74880Sdan    2 { SELECT * FROM t1 AS y CROSS JOIN t1 AS x } $t1_cross_t1        \
5094ce74880Sdan    3 { SELECT * FROM t1 INNER JOIN t2 }           $t1_cross_t2        \
5104ce74880Sdan    4 { SELECT * FROM t1 AS y INNER JOIN t1 AS x } $t1_cross_t1        \
5111b89d5d9Sdan]
5124ce74880Sdan
513a820c05aSdrh# EVIDENCE-OF: R-38465-03616 If there is an ON clause then the ON
514a820c05aSdrh# expression is evaluated for each row of the cartesian product as a
515a820c05aSdrh# boolean expression. Only rows for which the expression evaluates to
516a820c05aSdrh# true are included from the dataset.
5174ce74880Sdan#
5184ce74880Sdanforeach {tn select res} [list                                              \
5194ce74880Sdan    1 { SELECT * FROM t1 %JOIN% t2 ON (1) }       $t1_cross_t2             \
5204ce74880Sdan    2 { SELECT * FROM t1 %JOIN% t2 ON (0) }       [list]                   \
5214ce74880Sdan    3 { SELECT * FROM t1 %JOIN% t2 ON (NULL) }    [list]                   \
5224ce74880Sdan    4 { SELECT * FROM t1 %JOIN% t2 ON ('abc') }   [list]                   \
5234ce74880Sdan    5 { SELECT * FROM t1 %JOIN% t2 ON ('1ab') }   $t1_cross_t2             \
5244ce74880Sdan    6 { SELECT * FROM t1 %JOIN% t2 ON (0.9) }     $t1_cross_t2             \
5254ce74880Sdan    7 { SELECT * FROM t1 %JOIN% t2 ON ('0.9') }   $t1_cross_t2             \
5264ce74880Sdan    8 { SELECT * FROM t1 %JOIN% t2 ON (0.0) }     [list]                   \
5274ce74880Sdan                                                                           \
5284ce74880Sdan    9 { SELECT t1.b, t2.b FROM t1 %JOIN% t2 ON (t1.a = t2.a) }             \
5294ce74880Sdan      {one I two II three III}                                             \
5304ce74880Sdan   10 { SELECT t1.b, t2.b FROM t1 %JOIN% t2 ON (t1.a = 'a') }              \
5314ce74880Sdan      {one I one II one III}                                               \
5324ce74880Sdan   11 { SELECT t1.b, t2.b
5334ce74880Sdan        FROM t1 %JOIN% t2 ON (CASE WHEN t1.a = 'a' THEN NULL ELSE 1 END) } \
5344ce74880Sdan      {two I two II two III three I three II three III}                    \
5354ce74880Sdan] {
5368663d0fbSdan  do_join_test e_select-1.3.$tn $select $res
5374ce74880Sdan}
5384ce74880Sdan
539a820c05aSdrh# EVIDENCE-OF: R-49933-05137 If there is a USING clause then each of the
540a820c05aSdrh# column names specified must exist in the datasets to both the left and
541a820c05aSdrh# right of the join-operator.
5424ce74880Sdan#
5431b89d5d9Sdando_select_tests e_select-1.4 -error {
5441b89d5d9Sdan  cannot join using column %s - column not present in both tables
5451b89d5d9Sdan} {
5464ce74880Sdan  1 { SELECT * FROM t1, t3 USING (b) }   "b"
5474ce74880Sdan  2 { SELECT * FROM t3, t1 USING (c) }   "c"
5484ce74880Sdan  3 { SELECT * FROM t3, (SELECT a AS b, b AS c FROM t1) USING (a) }   "a"
5494ce74880Sdan}
5504ce74880Sdan
551a820c05aSdrh# EVIDENCE-OF: R-22776-52830 For each pair of named columns, the
5524ce74880Sdan# expression "lhs.X = rhs.X" is evaluated for each row of the cartesian
553a820c05aSdrh# product as a boolean expression. Only rows for which all such
554a820c05aSdrh# expressions evaluates to true are included from the result set.
5554ce74880Sdan#
5561b89d5d9Sdando_select_tests e_select-1.5 {
5574ce74880Sdan  1 { SELECT * FROM t1, t3 USING (a)   }  {a one 1 b two 2}
5584ce74880Sdan  2 { SELECT * FROM t3, t4 USING (a,c) }  {b 2}
5594ce74880Sdan}
5604ce74880Sdan
5614ce74880Sdan# EVIDENCE-OF: R-54046-48600 When comparing values as a result of a
5624ce74880Sdan# USING clause, the normal rules for handling affinities, collation
5634ce74880Sdan# sequences and NULL values in comparisons apply.
5644ce74880Sdan#
565a820c05aSdrh# EVIDENCE-OF: R-38422-04402 The column from the dataset on the
566a820c05aSdrh# left-hand side of the join-operator is considered to be on the
5674ce74880Sdan# left-hand side of the comparison operator (=) for the purposes of
5684ce74880Sdan# collation sequence and affinity precedence.
5694ce74880Sdan#
5704ce74880Sdando_execsql_test e_select-1.6.0 {
5714ce74880Sdan  CREATE TABLE t5(a COLLATE nocase, b COLLATE binary);
5724ce74880Sdan  INSERT INTO t5 VALUES('AA', 'cc');
5734ce74880Sdan  INSERT INTO t5 VALUES('BB', 'dd');
5744ce74880Sdan  INSERT INTO t5 VALUES(NULL, NULL);
5754ce74880Sdan  CREATE TABLE t6(a COLLATE binary, b COLLATE nocase);
5764ce74880Sdan  INSERT INTO t6 VALUES('aa', 'cc');
5774ce74880Sdan  INSERT INTO t6 VALUES('bb', 'DD');
5784ce74880Sdan  INSERT INTO t6 VALUES(NULL, NULL);
5794ce74880Sdan} {}
5804ce74880Sdanforeach {tn select res} {
5814ce74880Sdan  1 { SELECT * FROM t5 %JOIN% t6 USING (a) } {AA cc cc BB dd DD}
5824ce74880Sdan  2 { SELECT * FROM t6 %JOIN% t5 USING (a) } {}
5834ce74880Sdan  3 { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) %JOIN% t5 USING (a) }
5844ce74880Sdan    {aa cc cc bb DD dd}
5854ce74880Sdan  4 { SELECT * FROM t5 %JOIN% t6 USING (a,b) } {AA cc}
5864ce74880Sdan  5 { SELECT * FROM t6 %JOIN% t5 USING (a,b) } {}
5874ce74880Sdan} {
5888663d0fbSdan  do_join_test e_select-1.6.$tn $select $res
5894ce74880Sdan}
5904ce74880Sdan
5918663d0fbSdan# EVIDENCE-OF: R-57047-10461 For each pair of columns identified by a
5928663d0fbSdan# USING clause, the column from the right-hand dataset is omitted from
5938663d0fbSdan# the joined dataset.
5948663d0fbSdan#
5958663d0fbSdan# EVIDENCE-OF: R-56132-15700 This is the only difference between a USING
5968663d0fbSdan# clause and its equivalent ON constraint.
5978663d0fbSdan#
5988663d0fbSdanforeach {tn select res} {
5998663d0fbSdan  1a { SELECT * FROM t1 %JOIN% t2 USING (a)      }
6008663d0fbSdan     {a one I b two II c three III}
6018663d0fbSdan  1b { SELECT * FROM t1 %JOIN% t2 ON (t1.a=t2.a) }
6028663d0fbSdan     {a one a I b two b II c three c III}
6034ce74880Sdan
6048663d0fbSdan  2a { SELECT * FROM t3 %JOIN% t4 USING (a)      }
6058663d0fbSdan     {a 1 {} b 2 2}
6068663d0fbSdan  2b { SELECT * FROM t3 %JOIN% t4 ON (t3.a=t4.a) }
6078663d0fbSdan     {a 1 a {} b 2 b 2}
6084ce74880Sdan
6098663d0fbSdan  3a { SELECT * FROM t3 %JOIN% t4 USING (a,c)                  } {b 2}
6108663d0fbSdan  3b { SELECT * FROM t3 %JOIN% t4 ON (t3.a=t4.a AND t3.c=t4.c) } {b 2 b 2}
6114ce74880Sdan
6128663d0fbSdan  4a { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) AS x
6138663d0fbSdan       %JOIN% t5 USING (a) }
6148663d0fbSdan     {aa cc cc bb DD dd}
6158663d0fbSdan  4b { SELECT * FROM (SELECT a COLLATE nocase, b FROM t6) AS x
6168663d0fbSdan       %JOIN% t5 ON (x.a=t5.a) }
6178663d0fbSdan     {aa cc AA cc bb DD BB dd}
6188663d0fbSdan} {
6198663d0fbSdan  do_join_test e_select-1.7.$tn $select $res
6208663d0fbSdan}
621*0338f53bSdrh
622*0338f53bSdrh# EVIDENCE-OF: R-24610-05866 If the join-operator is a "LEFT JOIN" or
623a820c05aSdrh# "LEFT OUTER JOIN", then after the ON or USING filtering clauses have
624a820c05aSdrh# been applied, an extra row is added to the output for each row in the
625*0338f53bSdrh# original left-hand input dataset that does not match any row in the
626*0338f53bSdrh# right-hand dataset.
6278663d0fbSdan#
6288663d0fbSdando_execsql_test e_select-1.8.0 {
6298663d0fbSdan  CREATE TABLE t7(a, b, c);
6308663d0fbSdan  CREATE TABLE t8(a, d, e);
6314ce74880Sdan
6328663d0fbSdan  INSERT INTO t7 VALUES('x', 'ex',  24);
6338663d0fbSdan  INSERT INTO t7 VALUES('y', 'why', 25);
6344ce74880Sdan
6358663d0fbSdan  INSERT INTO t8 VALUES('x', 'abc', 24);
6368663d0fbSdan  INSERT INTO t8 VALUES('z', 'ghi', 26);
6378663d0fbSdan} {}
6384ce74880Sdan
6391b89d5d9Sdando_select_tests e_select-1.8 {
6401b89d5d9Sdan  1a "SELECT count(*) FROM t7 JOIN t8 ON (t7.a=t8.a)" {1}
6411b89d5d9Sdan  1b "SELECT count(*) FROM t7 LEFT JOIN t8 ON (t7.a=t8.a)" {2}
6421b89d5d9Sdan  2a "SELECT count(*) FROM t7 JOIN t8 USING (a)" {1}
6431b89d5d9Sdan  2b "SELECT count(*) FROM t7 LEFT JOIN t8 USING (a)" {2}
6441b89d5d9Sdan}
6454ce74880Sdan
6468663d0fbSdan
6478663d0fbSdan# EVIDENCE-OF: R-15607-52988 The added rows contain NULL values in the
6488663d0fbSdan# columns that would normally contain values copied from the right-hand
6498663d0fbSdan# input dataset.
6508663d0fbSdan#
6511b89d5d9Sdando_select_tests e_select-1.9 {
6521b89d5d9Sdan  1a "SELECT * FROM t7 JOIN t8 ON (t7.a=t8.a)" {x ex 24 x abc 24}
6531b89d5d9Sdan  1b "SELECT * FROM t7 LEFT JOIN t8 ON (t7.a=t8.a)"
6541b89d5d9Sdan     {x ex 24 x abc 24 y why 25 {} {} {}}
6551b89d5d9Sdan  2a "SELECT * FROM t7 JOIN t8 USING (a)" {x ex 24 abc 24}
6561b89d5d9Sdan  2b "SELECT * FROM t7 LEFT JOIN t8 USING (a)" {x ex 24 abc 24 y why 25 {} {}}
6571b89d5d9Sdan}
6588663d0fbSdan
659a820c05aSdrh# EVIDENCE-OF: R-04932-55942 If the NATURAL keyword is in the
660a820c05aSdrh# join-operator then an implicit USING clause is added to the
6618663d0fbSdan# join-constraints. The implicit USING clause contains each of the
6628663d0fbSdan# column names that appear in both the left and right-hand input
6638663d0fbSdan# datasets.
6648663d0fbSdan#
6651b89d5d9Sdando_select_tests e_select-1-10 {
6661b89d5d9Sdan  1a "SELECT * FROM t7 JOIN t8 USING (a)"        {x ex 24 abc 24}
6671b89d5d9Sdan  1b "SELECT * FROM t7 NATURAL JOIN t8"          {x ex 24 abc 24}
6688663d0fbSdan
6691b89d5d9Sdan  2a "SELECT * FROM t8 JOIN t7 USING (a)"        {x abc 24 ex 24}
6701b89d5d9Sdan  2b "SELECT * FROM t8 NATURAL JOIN t7"          {x abc 24 ex 24}
6718663d0fbSdan
6721b89d5d9Sdan  3a "SELECT * FROM t7 LEFT JOIN t8 USING (a)"   {x ex 24 abc 24 y why 25 {} {}}
6731b89d5d9Sdan  3b "SELECT * FROM t7 NATURAL LEFT JOIN t8"     {x ex 24 abc 24 y why 25 {} {}}
6748663d0fbSdan
6751b89d5d9Sdan  4a "SELECT * FROM t8 LEFT JOIN t7 USING (a)"   {x abc 24 ex 24 z ghi 26 {} {}}
6761b89d5d9Sdan  4b "SELECT * FROM t8 NATURAL LEFT JOIN t7"     {x abc 24 ex 24 z ghi 26 {} {}}
6778663d0fbSdan
6781b89d5d9Sdan  5a "SELECT * FROM t3 JOIN t4 USING (a,c)"      {b 2}
6791b89d5d9Sdan  5b "SELECT * FROM t3 NATURAL JOIN t4"          {b 2}
6808663d0fbSdan
6811b89d5d9Sdan  6a "SELECT * FROM t3 LEFT JOIN t4 USING (a,c)" {a 1 b 2}
6821b89d5d9Sdan  6b "SELECT * FROM t3 NATURAL LEFT JOIN t4"     {a 1 b 2}
6838663d0fbSdan}
6848663d0fbSdan
6858663d0fbSdan# EVIDENCE-OF: R-49566-01570 If the left and right-hand input datasets
6868663d0fbSdan# feature no common column names, then the NATURAL keyword has no effect
6878663d0fbSdan# on the results of the join.
6888663d0fbSdan#
6898663d0fbSdando_execsql_test e_select-1.11.0 {
6908663d0fbSdan  CREATE TABLE t10(x, y);
6918663d0fbSdan  INSERT INTO t10 VALUES(1, 'true');
6928663d0fbSdan  INSERT INTO t10 VALUES(0, 'false');
6938663d0fbSdan} {}
6941b89d5d9Sdando_select_tests e_select-1-11 {
6951b89d5d9Sdan  1a "SELECT a, x FROM t1 CROSS JOIN t10" {a 1 a 0 b 1 b 0 c 1 c 0}
6961b89d5d9Sdan  1b "SELECT a, x FROM t1 NATURAL CROSS JOIN t10" {a 1 a 0 b 1 b 0 c 1 c 0}
6978663d0fbSdan}
6988663d0fbSdan
6998663d0fbSdan# EVIDENCE-OF: R-39625-59133 A USING or ON clause may not be added to a
7008663d0fbSdan# join that specifies the NATURAL keyword.
7018663d0fbSdan#
7028663d0fbSdanforeach {tn sql} {
7038663d0fbSdan  1 {SELECT * FROM t1 NATURAL LEFT JOIN t2 USING (a)}
7048663d0fbSdan  2 {SELECT * FROM t1 NATURAL LEFT JOIN t2 ON (t1.a=t2.a)}
7058663d0fbSdan  3 {SELECT * FROM t1 NATURAL LEFT JOIN t2 ON (45)}
7068663d0fbSdan} {
7078663d0fbSdan  do_catchsql_test e_select-1.12.$tn "
7088663d0fbSdan    $sql
7098663d0fbSdan  " {1 {a NATURAL join may not have an ON or USING clause}}
7108663d0fbSdan}
7114ce74880Sdan
7125c3f58e4Sdan#-------------------------------------------------------------------------
71374138477Sdan# The next block of tests - e_select-3.* - concentrate on verifying
71474138477Sdan# statements made regarding WHERE clause processing.
71574138477Sdan#
71674138477Sdandrop_all_tables
71774138477Sdando_execsql_test e_select-3.0 {
71874138477Sdan  CREATE TABLE x1(k, x, y, z);
71974138477Sdan  INSERT INTO x1 VALUES(1, 'relinquished', 'aphasia', 78.43);
72074138477Sdan  INSERT INTO x1 VALUES(2, X'A8E8D66F',    X'07CF',   -81);
72174138477Sdan  INSERT INTO x1 VALUES(3, -22,            -27.57,    NULL);
72274138477Sdan  INSERT INTO x1 VALUES(4, NULL,           'bygone',  'picky');
72374138477Sdan  INSERT INTO x1 VALUES(5, NULL,           96.28,     NULL);
72474138477Sdan  INSERT INTO x1 VALUES(6, 0,              1,         2);
72574138477Sdan
72674138477Sdan  CREATE TABLE x2(k, x, y2);
72774138477Sdan  INSERT INTO x2 VALUES(1, 50, X'B82838');
72874138477Sdan  INSERT INTO x2 VALUES(5, 84.79, 65.88);
72974138477Sdan  INSERT INTO x2 VALUES(3, -22, X'0E1BE452A393');
73074138477Sdan  INSERT INTO x2 VALUES(7, 'mistrusted', 'standardized');
73174138477Sdan} {}
73274138477Sdan
7339a2555f5Sdrh# EVIDENCE-OF: R-60775-64916 If a WHERE clause is specified, the WHERE
734cc9352e9Sdan# expression is evaluated for each row in the input data as a boolean
7359a2555f5Sdrh# expression. Only rows for which the WHERE clause expression evaluates
7369a2555f5Sdrh# to true are included from the dataset before continuing.
73774138477Sdan#
73874138477Sdando_execsql_test e_select-3.1.1 { SELECT k FROM x1 WHERE x }         {3}
73974138477Sdando_execsql_test e_select-3.1.2 { SELECT k FROM x1 WHERE y }         {3 5 6}
74074138477Sdando_execsql_test e_select-3.1.3 { SELECT k FROM x1 WHERE z }         {1 2 6}
74174138477Sdando_execsql_test e_select-3.1.4 { SELECT k FROM x1 WHERE '1'||z    } {1 2 4 6}
74274138477Sdando_execsql_test e_select-3.1.5 { SELECT k FROM x1 WHERE x IS NULL } {4 5}
74374138477Sdando_execsql_test e_select-3.1.6 { SELECT k FROM x1 WHERE z - 78.43 } {2 4 6}
74474138477Sdan
74574138477Sdando_execsql_test e_select-3.2.1a {
74674138477Sdan  SELECT k FROM x1 LEFT JOIN x2 USING(k)
74774138477Sdan} {1 2 3 4 5 6}
74874138477Sdando_execsql_test e_select-3.2.1b {
7492589787cSdrh  SELECT k FROM x1 LEFT JOIN x2 USING(k) WHERE x2.k ORDER BY +k
75074138477Sdan} {1 3 5}
75174138477Sdando_execsql_test e_select-3.2.2 {
75274138477Sdan  SELECT k FROM x1 LEFT JOIN x2 USING(k) WHERE x2.k IS NULL
75374138477Sdan} {2 4 6}
75474138477Sdan
75574138477Sdando_execsql_test e_select-3.2.3 {
75674138477Sdan  SELECT k FROM x1 NATURAL JOIN x2 WHERE x2.k
75774138477Sdan} {3}
75874138477Sdando_execsql_test e_select-3.2.4 {
75974138477Sdan  SELECT k FROM x1 NATURAL JOIN x2 WHERE x2.k-3
76074138477Sdan} {}
76174138477Sdan
76259d29658Sdan#-------------------------------------------------------------------------
76359d29658Sdan# Tests below this point are focused on verifying the testable statements
76459d29658Sdan# related to caculating the result rows of a simple SELECT statement.
76559d29658Sdan#
76659d29658Sdan
76759d29658Sdandrop_all_tables
76859d29658Sdando_execsql_test e_select-4.0 {
76959d29658Sdan  CREATE TABLE z1(a, b, c);
77059d29658Sdan  CREATE TABLE z2(d, e);
77159d29658Sdan  CREATE TABLE z3(a, b);
77259d29658Sdan
77359d29658Sdan  INSERT INTO z1 VALUES(51.65, -59.58, 'belfries');
77459d29658Sdan  INSERT INTO z1 VALUES(-5, NULL, 75);
77559d29658Sdan  INSERT INTO z1 VALUES(-2.2, -23.18, 'suiters');
77659d29658Sdan  INSERT INTO z1 VALUES(NULL, 67, 'quartets');
77759d29658Sdan  INSERT INTO z1 VALUES(-1.04, -32.3, 'aspen');
77859d29658Sdan  INSERT INTO z1 VALUES(63, 'born', -26);
77959d29658Sdan
78059d29658Sdan  INSERT INTO z2 VALUES(NULL, 21);
78159d29658Sdan  INSERT INTO z2 VALUES(36, 6);
78259d29658Sdan
78359d29658Sdan  INSERT INTO z3 VALUES('subsistence', 'gauze');
78459d29658Sdan  INSERT INTO z3 VALUES(49.17, -67);
78559d29658Sdan} {}
78659d29658Sdan
78759d29658Sdan# EVIDENCE-OF: R-36327-17224 If a result expression is the special
78859d29658Sdan# expression "*" then all columns in the input data are substituted for
78959d29658Sdan# that one expression.
79059d29658Sdan#
79159d29658Sdan# EVIDENCE-OF: R-43693-30522 If the expression is the alias of a table
79259d29658Sdan# or subquery in the FROM clause followed by ".*" then all columns from
79359d29658Sdan# the named table or subquery are substituted for the single expression.
79459d29658Sdan#
7951b89d5d9Sdando_select_tests e_select-4.1 {
79659d29658Sdan  1  "SELECT * FROM z1 LIMIT 1"             {51.65 -59.58 belfries}
79759d29658Sdan  2  "SELECT * FROM z1,z2 LIMIT 1"          {51.65 -59.58 belfries {} 21}
79859d29658Sdan  3  "SELECT z1.* FROM z1,z2 LIMIT 1"       {51.65 -59.58 belfries}
79959d29658Sdan  4  "SELECT z2.* FROM z1,z2 LIMIT 1"       {{} 21}
80059d29658Sdan  5  "SELECT z2.*, z1.* FROM z1,z2 LIMIT 1" {{} 21 51.65 -59.58 belfries}
80159d29658Sdan
802280c894bSdan  6  "SELECT count(*), * FROM z1"           {6 51.65 -59.58 belfries}
80359d29658Sdan  7  "SELECT max(a), * FROM z1"             {63 63 born -26}
80494a6d998Sdrh  8  "SELECT *, min(a) FROM z1"             {-5 {} 75 -5}
80559d29658Sdan
80659d29658Sdan  9  "SELECT *,* FROM z1,z2 LIMIT 1" {
80759d29658Sdan     51.65 -59.58 belfries {} 21 51.65 -59.58 belfries {} 21
80859d29658Sdan  }
80959d29658Sdan  10 "SELECT z1.*,z1.* FROM z2,z1 LIMIT 1" {
81059d29658Sdan     51.65 -59.58 belfries 51.65 -59.58 belfries
81159d29658Sdan  }
81259d29658Sdan}
81359d29658Sdan
814bb44b3deSdrh# EVIDENCE-OF: R-38023-18396 It is an error to use a "*" or "alias.*"
815bb44b3deSdrh# expression in any context other than a result expression list.
81659d29658Sdan#
81759d29658Sdan# EVIDENCE-OF: R-44324-41166 It is also an error to use a "*" or
81859d29658Sdan# "alias.*" expression in a simple SELECT query that does not have a
81959d29658Sdan# FROM clause.
82059d29658Sdan#
82159d29658Sdanforeach {tn select err} {
82259d29658Sdan  1.1  "SELECT a, b, c FROM z1 WHERE *"    {near "*": syntax error}
82359d29658Sdan  1.2  "SELECT a, b, c FROM z1 GROUP BY *" {near "*": syntax error}
82459d29658Sdan  1.3  "SELECT 1 + * FROM z1"              {near "*": syntax error}
82559d29658Sdan  1.4  "SELECT * + 1 FROM z1"              {near "+": syntax error}
82659d29658Sdan
82759d29658Sdan  2.1 "SELECT *" {no tables specified}
82859d29658Sdan  2.2 "SELECT * WHERE 1" {no tables specified}
82959d29658Sdan  2.3 "SELECT * WHERE 0" {no tables specified}
83059d29658Sdan  2.4 "SELECT count(*), *" {no tables specified}
83159d29658Sdan} {
83259d29658Sdan  do_catchsql_test e_select-4.2.$tn $select [list 1 $err]
83359d29658Sdan}
83459d29658Sdan
83559d29658Sdan# EVIDENCE-OF: R-08669-22397 The number of columns in the rows returned
83659d29658Sdan# by a simple SELECT statement is equal to the number of expressions in
83759d29658Sdan# the result expression list after substitution of * and alias.*
83859d29658Sdan# expressions.
83959d29658Sdan#
84059d29658Sdanforeach {tn select nCol} {
84159d29658Sdan  1   "SELECT * FROM z1"   3
84259d29658Sdan  2   "SELECT * FROM z1 NATURAL JOIN z3"            3
84359d29658Sdan  3   "SELECT z1.* FROM z1 NATURAL JOIN z3"         3
84459d29658Sdan  4   "SELECT z3.* FROM z1 NATURAL JOIN z3"         2
84559d29658Sdan  5   "SELECT z1.*, z3.* FROM z1 NATURAL JOIN z3"   5
84659d29658Sdan  6   "SELECT 1, 2, z1.* FROM z1"                   5
84759d29658Sdan  7   "SELECT a, *, b, c FROM z1"                   6
84859d29658Sdan} {
84959d29658Sdan  set ::stmt [sqlite3_prepare_v2 db $select -1 DUMMY]
85059d29658Sdan  do_test e_select-4.3.$tn { sqlite3_column_count $::stmt } $nCol
85159d29658Sdan  sqlite3_finalize $::stmt
85259d29658Sdan}
85359d29658Sdan
8541b89d5d9Sdan
8551b89d5d9Sdan
8561b89d5d9Sdan# In lang_select.html, a non-aggregate query is defined as any simple SELECT
8571b89d5d9Sdan# that has no GROUP BY clause and no aggregate expressions in the result
8581b89d5d9Sdan# expression list. Other queries are aggregate queries. Test cases
8591b89d5d9Sdan# e_select-4.4.* through e_select-4.12.*, inclusive, which test the part of
8601b89d5d9Sdan# simple SELECT that is different for aggregate and non-aggregate queries
8611b89d5d9Sdan# verify (in a way) that these definitions are consistent:
8621b89d5d9Sdan#
8631b89d5d9Sdan# EVIDENCE-OF: R-20637-43463 A simple SELECT statement is an aggregate
8641b89d5d9Sdan# query if it contains either a GROUP BY clause or one or more aggregate
8651b89d5d9Sdan# functions in the result-set.
8661b89d5d9Sdan#
8671b89d5d9Sdan# EVIDENCE-OF: R-23155-55597 Otherwise, if a simple SELECT contains no
8681b89d5d9Sdan# aggregate functions or a GROUP BY clause, it is a non-aggregate query.
8691b89d5d9Sdan#
8701b89d5d9Sdan
87159d29658Sdan# EVIDENCE-OF: R-44050-47362 If the SELECT statement is a non-aggregate
87259d29658Sdan# query, then each expression in the result expression list is evaluated
87359d29658Sdan# for each row in the dataset filtered by the WHERE clause.
87459d29658Sdan#
8751b89d5d9Sdando_select_tests e_select-4.4 {
8761b89d5d9Sdan  1 "SELECT a, b FROM z1"
8771b89d5d9Sdan    {51.65 -59.58 -5 {} -2.2 -23.18 {} 67 -1.04 -32.3 63 born}
87859d29658Sdan
8791b89d5d9Sdan  2 "SELECT a IS NULL, b+1, * FROM z1" {
88059d29658Sdan        0 -58.58   51.65 -59.58 belfries
88159d29658Sdan        0 {}       -5 {} 75
88259d29658Sdan        0 -22.18   -2.2 -23.18 suiters
88359d29658Sdan        1 68       {} 67 quartets
88459d29658Sdan        0 -31.3    -1.04 -32.3 aspen
88559d29658Sdan        0 1        63 born -26
8861b89d5d9Sdan  }
88759d29658Sdan
8881b89d5d9Sdan  3 "SELECT 32*32, d||e FROM z2" {1024 {} 1024 366}
8891b89d5d9Sdan}
8901b89d5d9Sdan
8911b89d5d9Sdan
8921b89d5d9Sdan# Test cases e_select-4.5.* and e_select-4.6.* together show that:
8931b89d5d9Sdan#
8941b89d5d9Sdan# EVIDENCE-OF: R-51988-01124 The single row of result-set data created
8951b89d5d9Sdan# by evaluating the aggregate and non-aggregate expressions in the
8961b89d5d9Sdan# result-set forms the result of an aggregate query without a GROUP BY
8971b89d5d9Sdan# clause.
8981b89d5d9Sdan#
89959d29658Sdan
90059d29658Sdan# EVIDENCE-OF: R-57629-25253 If the SELECT statement is an aggregate
90159d29658Sdan# query without a GROUP BY clause, then each aggregate expression in the
90259d29658Sdan# result-set is evaluated once across the entire dataset.
90359d29658Sdan#
9041b89d5d9Sdando_select_tests e_select-4.5 {
9051b89d5d9Sdan  1 "SELECT count(a), max(a), count(b), max(b) FROM z1"      {5 63 5 born}
9061b89d5d9Sdan  2 "SELECT count(*), max(1)"                                {1 1}
90759d29658Sdan
9081b89d5d9Sdan  3 "SELECT sum(b+1) FROM z1 NATURAL LEFT JOIN z3"           {-43.06}
9091b89d5d9Sdan  4 "SELECT sum(b+2) FROM z1 NATURAL LEFT JOIN z3"           {-38.06}
9101b89d5d9Sdan  5 "SELECT sum(b IS NOT NULL) FROM z1 NATURAL LEFT JOIN z3" {5}
91159d29658Sdan}
91259d29658Sdan
913e6a3838bSdan# EVIDENCE-OF: R-26684-40576 Each non-aggregate expression in the
914e6a3838bSdan# result-set is evaluated once for an arbitrarily selected row of the
915e6a3838bSdan# dataset.
916e6a3838bSdan#
917e6a3838bSdan# EVIDENCE-OF: R-27994-60376 The same arbitrarily selected row is used
918e6a3838bSdan# for each non-aggregate expression.
919e6a3838bSdan#
920e6a3838bSdan#   Note: The results of many of the queries in this block of tests are
921e6a3838bSdan#   technically undefined, as the documentation does not specify which row
922e6a3838bSdan#   SQLite will arbitrarily select to use for the evaluation of the
923e6a3838bSdan#   non-aggregate expressions.
924e6a3838bSdan#
925e6a3838bSdandrop_all_tables
926e6a3838bSdando_execsql_test e_select-4.6.0 {
927e6a3838bSdan  CREATE TABLE a1(one PRIMARY KEY, two);
928e6a3838bSdan  INSERT INTO a1 VALUES(1, 1);
929e6a3838bSdan  INSERT INTO a1 VALUES(2, 3);
930e6a3838bSdan  INSERT INTO a1 VALUES(3, 6);
931e6a3838bSdan  INSERT INTO a1 VALUES(4, 10);
93259d29658Sdan
933e6a3838bSdan  CREATE TABLE a2(one PRIMARY KEY, three);
934e6a3838bSdan  INSERT INTO a2 VALUES(1, 1);
935e6a3838bSdan  INSERT INTO a2 VALUES(3, 2);
936e6a3838bSdan  INSERT INTO a2 VALUES(6, 3);
937e6a3838bSdan  INSERT INTO a2 VALUES(10, 4);
938e6a3838bSdan} {}
9391b89d5d9Sdando_select_tests e_select-4.6 {
940280c894bSdan  1 "SELECT one, two, count(*) FROM a1"                        {1 1 4}
941280c894bSdan  2 "SELECT one, two, count(*) FROM a1 WHERE one<3"            {1 1 2}
9421b89d5d9Sdan  3 "SELECT one, two, count(*) FROM a1 WHERE one>3"            {4 10 1}
943280c894bSdan  4 "SELECT *, count(*) FROM a1 JOIN a2"                       {1 1 1 1 16}
944280c894bSdan  5 "SELECT *, sum(three) FROM a1 NATURAL JOIN a2"             {1 1 1 3}
945280c894bSdan  6 "SELECT *, sum(three) FROM a1 NATURAL JOIN a2"             {1 1 1 3}
946280c894bSdan  7 "SELECT group_concat(three, ''), a1.* FROM a1 NATURAL JOIN a2" {12 1 1}
947e6a3838bSdan}
948e6a3838bSdan
949e6a3838bSdan# EVIDENCE-OF: R-04486-07266 Or, if the dataset contains zero rows, then
950e6a3838bSdan# each non-aggregate expression is evaluated against a row consisting
951e6a3838bSdan# entirely of NULL values.
952e6a3838bSdan#
9531b89d5d9Sdando_select_tests e_select-4.7 {
9541b89d5d9Sdan  1  "SELECT one, two, count(*) FROM a1 WHERE 0"           {{} {} 0}
9551b89d5d9Sdan  2  "SELECT sum(two), * FROM a1, a2 WHERE three>5"        {{} {} {} {} {}}
9561b89d5d9Sdan  3  "SELECT max(one) IS NULL, one IS NULL, two IS NULL FROM a1 WHERE two=7" {
957e6a3838bSdan    1 1 1
958e6a3838bSdan  }
959e6a3838bSdan}
960e6a3838bSdan
961e6a3838bSdan# EVIDENCE-OF: R-64138-28774 An aggregate query without a GROUP BY
962e6a3838bSdan# clause always returns exactly one row of data, even if there are zero
963e6a3838bSdan# rows of input data.
964e6a3838bSdan#
965e6a3838bSdanforeach {tn select} {
966e6a3838bSdan  8.1  "SELECT count(*) FROM a1"
967e6a3838bSdan  8.2  "SELECT count(*) FROM a1 WHERE 0"
968e6a3838bSdan  8.3  "SELECT count(*) FROM a1 WHERE 1"
969e6a3838bSdan  8.4  "SELECT max(a1.one)+min(two), a1.one, two, * FROM a1, a2 WHERE 1"
970e6a3838bSdan  8.5  "SELECT max(a1.one)+min(two), a1.one, two, * FROM a1, a2 WHERE 0"
971e6a3838bSdan} {
972e6a3838bSdan  # Set $nRow to the number of rows returned by $select:
973e6a3838bSdan  set ::stmt [sqlite3_prepare_v2 db $select -1 DUMMY]
974e6a3838bSdan  set nRow 0
975e6a3838bSdan  while {"SQLITE_ROW" == [sqlite3_step $::stmt]} { incr nRow }
976e6a3838bSdan  set rc [sqlite3_finalize $::stmt]
977e6a3838bSdan
978e6a3838bSdan  # Test that $nRow==1 and that statement execution was successful
979e6a3838bSdan  # (rc==SQLITE_OK).
980e6a3838bSdan  do_test e_select-4.$tn [list list $rc $nRow] {SQLITE_OK 1}
981e6a3838bSdan}
982e6a3838bSdan
983e6a3838bSdandrop_all_tables
984e6a3838bSdando_execsql_test e_select-4.9.0 {
985e6a3838bSdan  CREATE TABLE b1(one PRIMARY KEY, two);
986e6a3838bSdan  INSERT INTO b1 VALUES(1, 'o');
987e6a3838bSdan  INSERT INTO b1 VALUES(4, 'f');
988e6a3838bSdan  INSERT INTO b1 VALUES(3, 't');
989e6a3838bSdan  INSERT INTO b1 VALUES(2, 't');
990e6a3838bSdan  INSERT INTO b1 VALUES(5, 'f');
991e6a3838bSdan  INSERT INTO b1 VALUES(7, 's');
992e6a3838bSdan  INSERT INTO b1 VALUES(6, 's');
993e6a3838bSdan
994e6a3838bSdan  CREATE TABLE b2(x, y);
995e6a3838bSdan  INSERT INTO b2 VALUES(NULL, 0);
996e6a3838bSdan  INSERT INTO b2 VALUES(NULL, 1);
997e6a3838bSdan  INSERT INTO b2 VALUES('xyz', 2);
998e6a3838bSdan  INSERT INTO b2 VALUES('abc', 3);
999e6a3838bSdan  INSERT INTO b2 VALUES('xyz', 4);
1000e6a3838bSdan
1001e6a3838bSdan  CREATE TABLE b3(a COLLATE nocase, b COLLATE binary);
1002e6a3838bSdan  INSERT INTO b3 VALUES('abc', 'abc');
1003e6a3838bSdan  INSERT INTO b3 VALUES('aBC', 'aBC');
1004e6a3838bSdan  INSERT INTO b3 VALUES('Def', 'Def');
1005e6a3838bSdan  INSERT INTO b3 VALUES('dEF', 'dEF');
1006e6a3838bSdan} {}
1007e6a3838bSdan
1008cbe83495Sdrh# EVIDENCE-OF: R-40855-36147 If the SELECT statement is an aggregate
1009e6a3838bSdan# query with a GROUP BY clause, then each of the expressions specified
1010e6a3838bSdan# as part of the GROUP BY clause is evaluated for each row of the
1011cbe83495Sdrh# dataset according to the processing rules stated below for ORDER BY
1012cbe83495Sdrh# expressions. Each row is then assigned to a "group" based on the
1013cbe83495Sdrh# results; rows for which the results of evaluating the GROUP BY
1014cbe83495Sdrh# expressions are the same get assigned to the same group.
1015e6a3838bSdan#
10161b89d5d9Sdan#   These tests also show that the following is not untrue:
10171b89d5d9Sdan#
10181b89d5d9Sdan# EVIDENCE-OF: R-25883-55063 The expressions in the GROUP BY clause do
10191b89d5d9Sdan# not have to be expressions that appear in the result.
10201b89d5d9Sdan#
10211b89d5d9Sdando_select_tests e_select-4.9 {
10221b89d5d9Sdan  1  "SELECT group_concat(one), two FROM b1 GROUP BY two" {
10235343b2d4Sdrh    /#,# f   1 o   #,#   s #,# t/
1024e6a3838bSdan  }
10251b89d5d9Sdan  2  "SELECT group_concat(one), sum(one) FROM b1 GROUP BY (one>4)" {
10263f4d1d1bSdrh    1,2,3,4 10    5,6,7 18
1027e6a3838bSdan  }
10281b89d5d9Sdan  3  "SELECT group_concat(one) FROM b1 GROUP BY (two>'o'), one%2" {
1029e6a3838bSdan    4  1,5    2,6   3,7
1030e6a3838bSdan  }
10311b89d5d9Sdan  4  "SELECT group_concat(one) FROM b1 GROUP BY (one==2 OR two=='o')" {
1032e6a3838bSdan    4,3,5,7,6    1,2
1033e6a3838bSdan  }
1034e6a3838bSdan}
1035e6a3838bSdan
1036e6a3838bSdan# EVIDENCE-OF: R-14926-50129 For the purposes of grouping rows, NULL
1037e6a3838bSdan# values are considered equal.
1038e6a3838bSdan#
10391b89d5d9Sdando_select_tests e_select-4.10 {
10405343b2d4Sdrh  1  "SELECT group_concat(y) FROM b2 GROUP BY x" {/#,#   3   #,#/}
10411b89d5d9Sdan  2  "SELECT count(*) FROM b2 GROUP BY CASE WHEN y<4 THEN NULL ELSE 0 END" {4 1}
1042e6a3838bSdan}
1043e6a3838bSdan
1044e6a3838bSdan# EVIDENCE-OF: R-10470-30318 The usual rules for selecting a collation
1045e6a3838bSdan# sequence with which to compare text values apply when evaluating
1046e6a3838bSdan# expressions in a GROUP BY clause.
1047e6a3838bSdan#
10481b89d5d9Sdando_select_tests e_select-4.11 {
10491b89d5d9Sdan  1  "SELECT count(*) FROM b3 GROUP BY b"      {1 1 1 1}
10501b89d5d9Sdan  2  "SELECT count(*) FROM b3 GROUP BY a"      {2 2}
10511b89d5d9Sdan  3  "SELECT count(*) FROM b3 GROUP BY +b"     {1 1 1 1}
10521b89d5d9Sdan  4  "SELECT count(*) FROM b3 GROUP BY +a"     {2 2}
10531b89d5d9Sdan  5  "SELECT count(*) FROM b3 GROUP BY b||''"  {1 1 1 1}
10541b89d5d9Sdan  6  "SELECT count(*) FROM b3 GROUP BY a||''"  {1 1 1 1}
1055e6a3838bSdan}
1056e6a3838bSdan
1057e6a3838bSdan# EVIDENCE-OF: R-63573-50730 The expressions in a GROUP BY clause may
1058e6a3838bSdan# not be aggregate expressions.
1059e6a3838bSdan#
1060e6a3838bSdanforeach {tn select} {
1061e6a3838bSdan  12.1  "SELECT * FROM b3 GROUP BY count(*)"
1062e6a3838bSdan  12.2  "SELECT max(a) FROM b3 GROUP BY max(b)"
1063e6a3838bSdan  12.3  "SELECT group_concat(a) FROM b3 GROUP BY a, max(b)"
1064e6a3838bSdan} {
1065e6a3838bSdan  set res {1 {aggregate functions are not allowed in the GROUP BY clause}}
1066e6a3838bSdan  do_catchsql_test e_select-4.$tn $select $res
1067e6a3838bSdan}
1068e6a3838bSdan
1069cc9352e9Sdan# EVIDENCE-OF: R-31537-00101 If a HAVING clause is specified, it is
1070cc9352e9Sdan# evaluated once for each group of rows as a boolean expression. If the
1071cc9352e9Sdan# result of evaluating the HAVING clause is false, the group is
1072cc9352e9Sdan# discarded.
1073e6a3838bSdan#
1074e6a3838bSdan#   This requirement is tested by all e_select-4.13.* tests.
1075e6a3838bSdan#
1076e6a3838bSdan# EVIDENCE-OF: R-04132-09474 If the HAVING clause is an aggregate
1077e6a3838bSdan# expression, it is evaluated across all rows in the group.
1078e6a3838bSdan#
1079e6a3838bSdan#   Tested by e_select-4.13.1.*
1080e6a3838bSdan#
1081e6a3838bSdan# EVIDENCE-OF: R-28262-47447 If a HAVING clause is a non-aggregate
1082e6a3838bSdan# expression, it is evaluated with respect to an arbitrarily selected
1083e6a3838bSdan# row from the group.
1084e6a3838bSdan#
1085e6a3838bSdan#   Tested by e_select-4.13.2.*
1086e6a3838bSdan#
10871b89d5d9Sdan#   Tests in this block also show that this is not untrue:
10881b89d5d9Sdan#
10891b89d5d9Sdan# EVIDENCE-OF: R-55403-13450 The HAVING expression may refer to values,
10901b89d5d9Sdan# even aggregate functions, that are not in the result.
10911b89d5d9Sdan#
1092e6a3838bSdando_execsql_test e_select-4.13.0 {
1093e6a3838bSdan  CREATE TABLE c1(up, down);
1094e6a3838bSdan  INSERT INTO c1 VALUES('x', 1);
1095e6a3838bSdan  INSERT INTO c1 VALUES('x', 2);
1096e6a3838bSdan  INSERT INTO c1 VALUES('x', 4);
1097e6a3838bSdan  INSERT INTO c1 VALUES('x', 8);
1098e6a3838bSdan  INSERT INTO c1 VALUES('y', 16);
1099e6a3838bSdan  INSERT INTO c1 VALUES('y', 32);
11007c7a766aSdan
11017c7a766aSdan  CREATE TABLE c2(i, j);
11027c7a766aSdan  INSERT INTO c2 VALUES(1, 0);
11037c7a766aSdan  INSERT INTO c2 VALUES(2, 1);
11047c7a766aSdan  INSERT INTO c2 VALUES(3, 3);
11057c7a766aSdan  INSERT INTO c2 VALUES(4, 6);
11067c7a766aSdan  INSERT INTO c2 VALUES(5, 10);
11077c7a766aSdan  INSERT INTO c2 VALUES(6, 15);
11087c7a766aSdan  INSERT INTO c2 VALUES(7, 21);
11097c7a766aSdan  INSERT INTO c2 VALUES(8, 28);
11107c7a766aSdan  INSERT INTO c2 VALUES(9, 36);
11117c7a766aSdan
11127c7a766aSdan  CREATE TABLE c3(i PRIMARY KEY, k TEXT);
11137c7a766aSdan  INSERT INTO c3 VALUES(1,  'hydrogen');
11147c7a766aSdan  INSERT INTO c3 VALUES(2,  'helium');
11157c7a766aSdan  INSERT INTO c3 VALUES(3,  'lithium');
11167c7a766aSdan  INSERT INTO c3 VALUES(4,  'beryllium');
11177c7a766aSdan  INSERT INTO c3 VALUES(5,  'boron');
11187c7a766aSdan  INSERT INTO c3 VALUES(94, 'plutonium');
1119e6a3838bSdan} {}
1120e6a3838bSdan
11211b89d5d9Sdando_select_tests e_select-4.13 {
11221b89d5d9Sdan  1.1  "SELECT up FROM c1 GROUP BY up HAVING count(*)>3" {x}
11231b89d5d9Sdan  1.2  "SELECT up FROM c1 GROUP BY up HAVING sum(down)>16" {y}
11241b89d5d9Sdan  1.3  "SELECT up FROM c1 GROUP BY up HAVING sum(down)<16" {x}
11251b89d5d9Sdan  1.4  "SELECT up||down FROM c1 GROUP BY (down<5) HAVING max(down)<10" {x4}
1126e6a3838bSdan
11271b89d5d9Sdan  2.1  "SELECT up FROM c1 GROUP BY up HAVING down>10" {y}
11281b89d5d9Sdan  2.2  "SELECT up FROM c1 GROUP BY up HAVING up='y'"  {y}
11297c7a766aSdan
1130280c894bSdan  2.3  "SELECT i, j FROM c2 GROUP BY i>4 HAVING j>6"  {5 10}
1131e6a3838bSdan}
113259d29658Sdan
11337c7a766aSdan# EVIDENCE-OF: R-23927-54081 Each expression in the result-set is then
11347c7a766aSdan# evaluated once for each group of rows.
11357c7a766aSdan#
11367c7a766aSdan# EVIDENCE-OF: R-53735-47017 If the expression is an aggregate
11377c7a766aSdan# expression, it is evaluated across all rows in the group.
11387c7a766aSdan#
11391b89d5d9Sdando_select_tests e_select-4.15 {
11401b89d5d9Sdan  1  "SELECT sum(down) FROM c1 GROUP BY up" {15 48}
11411b89d5d9Sdan  2  "SELECT sum(j), max(j) FROM c2 GROUP BY (i%3)"     {54 36 27 21 39 28}
11421b89d5d9Sdan  3  "SELECT sum(j), max(j) FROM c2 GROUP BY (j%2)"     {80 36 40 21}
11431b89d5d9Sdan  4  "SELECT 1+sum(j), max(j)+1 FROM c2 GROUP BY (j%2)" {81 37 41 22}
11441b89d5d9Sdan  5  "SELECT count(*), round(avg(i),2) FROM c1, c2 ON (i=down) GROUP BY j%2"
11457c7a766aSdan        {3 4.33 1 2.0}
11467c7a766aSdan}
114759d29658Sdan
11487c7a766aSdan# EVIDENCE-OF: R-62913-19830 Otherwise, it is evaluated against a single
11497c7a766aSdan# arbitrarily chosen row from within the group.
11507c7a766aSdan#
11517c7a766aSdan# EVIDENCE-OF: R-53924-08809 If there is more than one non-aggregate
11527c7a766aSdan# expression in the result-set, then all such expressions are evaluated
11537c7a766aSdan# for the same row.
11547c7a766aSdan#
11551b89d5d9Sdando_select_tests e_select-4.15 {
1156280c894bSdan  1  "SELECT i, j FROM c2 GROUP BY i%2"             {2 1 1 0}
1157280c894bSdan  2  "SELECT i, j FROM c2 GROUP BY i%2 HAVING j<30" {2 1 1 0}
1158280c894bSdan  3  "SELECT i, j FROM c2 GROUP BY i%2 HAVING j>30" {}
1159280c894bSdan  4  "SELECT i, j FROM c2 GROUP BY i%2 HAVING j>30" {}
11601b89d5d9Sdan  5  "SELECT count(*), i, k FROM c2 NATURAL JOIN c3 GROUP BY substr(k, 1, 1)"
1161280c894bSdan        {2 4 beryllium 2 1 hydrogen 1 3 lithium}
11627c7a766aSdan}
11637c7a766aSdan
11647c7a766aSdan# EVIDENCE-OF: R-19334-12811 Each group of input dataset rows
11657c7a766aSdan# contributes a single row to the set of result rows.
11667c7a766aSdan#
11677c7a766aSdan# EVIDENCE-OF: R-02223-49279 Subject to filtering associated with the
11687c7a766aSdan# DISTINCT keyword, the number of rows returned by an aggregate query
11697c7a766aSdan# with a GROUP BY clause is the same as the number of groups of rows
11707c7a766aSdan# produced by applying the GROUP BY and HAVING clauses to the filtered
11717c7a766aSdan# input dataset.
11727c7a766aSdan#
11731b89d5d9Sdando_select_tests e_select.4.16 -count {
11741b89d5d9Sdan  1  "SELECT i, j FROM c2 GROUP BY i%2"          2
11751b89d5d9Sdan  2  "SELECT i, j FROM c2 GROUP BY i"            9
11761b89d5d9Sdan  3  "SELECT i, j FROM c2 GROUP BY i HAVING i<5" 4
11777c7a766aSdan}
11787c7a766aSdan
11797c7a766aSdan#-------------------------------------------------------------------------
11807c7a766aSdan# The following tests attempt to verify statements made regarding the ALL
11817c7a766aSdan# and DISTINCT keywords.
11827c7a766aSdan#
11837c7a766aSdandrop_all_tables
11847c7a766aSdando_execsql_test e_select-5.1.0 {
11857c7a766aSdan  CREATE TABLE h1(a, b);
11867c7a766aSdan  INSERT INTO h1 VALUES(1, 'one');
11877c7a766aSdan  INSERT INTO h1 VALUES(1, 'I');
11887c7a766aSdan  INSERT INTO h1 VALUES(1, 'i');
11897c7a766aSdan  INSERT INTO h1 VALUES(4, 'four');
11907c7a766aSdan  INSERT INTO h1 VALUES(4, 'IV');
11917c7a766aSdan  INSERT INTO h1 VALUES(4, 'iv');
11927c7a766aSdan
11937c7a766aSdan  CREATE TABLE h2(x COLLATE nocase);
11947c7a766aSdan  INSERT INTO h2 VALUES('One');
11957c7a766aSdan  INSERT INTO h2 VALUES('Two');
11967c7a766aSdan  INSERT INTO h2 VALUES('Three');
11977c7a766aSdan  INSERT INTO h2 VALUES('Four');
11987c7a766aSdan  INSERT INTO h2 VALUES('one');
11997c7a766aSdan  INSERT INTO h2 VALUES('two');
12007c7a766aSdan  INSERT INTO h2 VALUES('three');
12017c7a766aSdan  INSERT INTO h2 VALUES('four');
12027c7a766aSdan
12037c7a766aSdan  CREATE TABLE h3(c, d);
12047c7a766aSdan  INSERT INTO h3 VALUES(1, NULL);
12057c7a766aSdan  INSERT INTO h3 VALUES(2, NULL);
12067c7a766aSdan  INSERT INTO h3 VALUES(3, NULL);
12077c7a766aSdan  INSERT INTO h3 VALUES(4, '2');
12087c7a766aSdan  INSERT INTO h3 VALUES(5, NULL);
12097c7a766aSdan  INSERT INTO h3 VALUES(6, '2,3');
12107c7a766aSdan  INSERT INTO h3 VALUES(7, NULL);
12117c7a766aSdan  INSERT INTO h3 VALUES(8, '2,4');
12127c7a766aSdan  INSERT INTO h3 VALUES(9, '3');
12137c7a766aSdan} {}
12147c7a766aSdan
12157c7a766aSdan# EVIDENCE-OF: R-60770-10612 One of the ALL or DISTINCT keywords may
12167c7a766aSdan# follow the SELECT keyword in a simple SELECT statement.
12177c7a766aSdan#
12181b89d5d9Sdando_select_tests e_select-5.1 {
12191b89d5d9Sdan  1   "SELECT ALL a FROM h1"      {1 1 1 4 4 4}
12201b89d5d9Sdan  2   "SELECT DISTINCT a FROM h1" {1 4}
12211b89d5d9Sdan}
12227c7a766aSdan
12237c7a766aSdan# EVIDENCE-OF: R-08861-34280 If the simple SELECT is a SELECT ALL, then
12247c7a766aSdan# the entire set of result rows are returned by the SELECT.
12257c7a766aSdan#
122639759747Sdrh# EVIDENCE-OF: R-01256-01950 If neither ALL or DISTINCT are present,
122748864df9Smistachkin# then the behavior is as if ALL were specified.
12287c7a766aSdan#
12297c7a766aSdan# EVIDENCE-OF: R-14442-41305 If the simple SELECT is a SELECT DISTINCT,
12307c7a766aSdan# then duplicate rows are removed from the set of result rows before it
12317c7a766aSdan# is returned.
12327c7a766aSdan#
12337c7a766aSdan#   The three testable statements above are tested by e_select-5.2.*,
12347c7a766aSdan#   5.3.* and 5.4.* respectively.
12357c7a766aSdan#
12361b89d5d9Sdando_select_tests e_select-5 {
12377c7a766aSdan  3.1 "SELECT ALL x FROM h2" {One Two Three Four one two three four}
12387c7a766aSdan  3.2 "SELECT ALL x FROM h1, h2 ON (x=b)" {One one Four four}
12397c7a766aSdan
12407c7a766aSdan  3.1 "SELECT x FROM h2" {One Two Three Four one two three four}
12417c7a766aSdan  3.2 "SELECT x FROM h1, h2 ON (x=b)" {One one Four four}
12427c7a766aSdan
124338cc40c2Sdan  4.1 "SELECT DISTINCT x FROM h2" {One Two Three Four}
124438cc40c2Sdan  4.2 "SELECT DISTINCT x FROM h1, h2 ON (x=b)" {One Four}
12457c7a766aSdan}
12467c7a766aSdan
12477c7a766aSdan# EVIDENCE-OF: R-02054-15343 For the purposes of detecting duplicate
12487c7a766aSdan# rows, two NULL values are considered to be equal.
12497c7a766aSdan#
12501b89d5d9Sdando_select_tests e_select-5.5 {
12511b89d5d9Sdan  1  "SELECT DISTINCT d FROM h3" {{} 2 2,3 2,4 3}
12521b89d5d9Sdan}
12537c7a766aSdan
125450da6635Sdrh# EVIDENCE-OF: R-47709-27231 The usual rules apply for selecting a
125550da6635Sdrh# collation sequence to compare text values.
12567c7a766aSdan#
12571b89d5d9Sdando_select_tests e_select-5.6 {
125838cc40c2Sdan  1  "SELECT DISTINCT b FROM h1"                  {one I i four IV iv}
125938cc40c2Sdan  2  "SELECT DISTINCT b COLLATE nocase FROM h1"   {one I four IV}
126038cc40c2Sdan  3  "SELECT DISTINCT x FROM h2"                  {One Two Three Four}
12611b89d5d9Sdan  4  "SELECT DISTINCT x COLLATE binary FROM h2"   {
126238cc40c2Sdan    One Two Three Four one two three four
12637c7a766aSdan  }
12647c7a766aSdan}
126559d29658Sdan
1266135aae8aSdan#-------------------------------------------------------------------------
1267135aae8aSdan# The following tests - e_select-7.* - test that statements made to do
1268135aae8aSdan# with compound SELECT statements are correct.
1269135aae8aSdan#
1270135aae8aSdan
1271135aae8aSdan# EVIDENCE-OF: R-39368-64333 In a compound SELECT, all the constituent
1272135aae8aSdan# SELECTs must return the same number of result columns.
1273135aae8aSdan#
1274135aae8aSdan#   All the other tests in this section use compound SELECTs created
1275135aae8aSdan#   using component SELECTs that do return the same number of columns.
1276135aae8aSdan#   So the tests here just show that it is an error to attempt otherwise.
1277135aae8aSdan#
1278135aae8aSdandrop_all_tables
1279135aae8aSdando_execsql_test e_select-7.1.0 {
1280135aae8aSdan  CREATE TABLE j1(a, b, c);
1281135aae8aSdan  CREATE TABLE j2(e, f);
1282135aae8aSdan  CREATE TABLE j3(g);
1283135aae8aSdan} {}
12841b89d5d9Sdando_select_tests e_select-7.1 -error {
12851b89d5d9Sdan  SELECTs to the left and right of %s do not have the same number of result columns
12861b89d5d9Sdan} {
128751f0698dSdan  1   "SELECT a, b FROM j1    UNION ALL SELECT g FROM j3"    {{UNION ALL}}
128851f0698dSdan  2   "SELECT *    FROM j1    UNION ALL SELECT * FROM j3"    {{UNION ALL}}
128951f0698dSdan  3   "SELECT a, b FROM j1    UNION ALL SELECT g FROM j3"    {{UNION ALL}}
129051f0698dSdan  4   "SELECT a, b FROM j1    UNION ALL SELECT * FROM j3,j2" {{UNION ALL}}
129151f0698dSdan  5   "SELECT *    FROM j3,j2 UNION ALL SELECT a, b FROM j1" {{UNION ALL}}
1292135aae8aSdan
1293135aae8aSdan  6   "SELECT a, b FROM j1    UNION SELECT g FROM j3"        {UNION}
1294135aae8aSdan  7   "SELECT *    FROM j1    UNION SELECT * FROM j3"        {UNION}
1295135aae8aSdan  8   "SELECT a, b FROM j1    UNION SELECT g FROM j3"        {UNION}
1296135aae8aSdan  9   "SELECT a, b FROM j1    UNION SELECT * FROM j3,j2"     {UNION}
1297135aae8aSdan  10  "SELECT *    FROM j3,j2 UNION SELECT a, b FROM j1"     {UNION}
1298135aae8aSdan
1299135aae8aSdan  11  "SELECT a, b FROM j1    INTERSECT SELECT g FROM j3"    {INTERSECT}
1300135aae8aSdan  12  "SELECT *    FROM j1    INTERSECT SELECT * FROM j3"    {INTERSECT}
1301135aae8aSdan  13  "SELECT a, b FROM j1    INTERSECT SELECT g FROM j3"    {INTERSECT}
1302135aae8aSdan  14  "SELECT a, b FROM j1    INTERSECT SELECT * FROM j3,j2" {INTERSECT}
1303135aae8aSdan  15  "SELECT *    FROM j3,j2 INTERSECT SELECT a, b FROM j1" {INTERSECT}
1304135aae8aSdan
1305135aae8aSdan  16  "SELECT a, b FROM j1    EXCEPT SELECT g FROM j3"       {EXCEPT}
1306135aae8aSdan  17  "SELECT *    FROM j1    EXCEPT SELECT * FROM j3"       {EXCEPT}
1307135aae8aSdan  18  "SELECT a, b FROM j1    EXCEPT SELECT g FROM j3"       {EXCEPT}
1308135aae8aSdan  19  "SELECT a, b FROM j1    EXCEPT SELECT * FROM j3,j2"    {EXCEPT}
1309135aae8aSdan  20  "SELECT *    FROM j3,j2 EXCEPT SELECT a, b FROM j1"    {EXCEPT}
1310135aae8aSdan}
1311135aae8aSdan
1312135aae8aSdan# EVIDENCE-OF: R-01450-11152 As the components of a compound SELECT must
1313135aae8aSdan# be simple SELECT statements, they may not contain ORDER BY or LIMIT
1314135aae8aSdan# clauses.
1315135aae8aSdan#
1316135aae8aSdanforeach {tn select op1 op2} {
1317135aae8aSdan  1   "SELECT * FROM j1 ORDER BY a UNION ALL SELECT * FROM j2,j3"
1318135aae8aSdan      {ORDER BY} {UNION ALL}
1319135aae8aSdan  2   "SELECT count(*) FROM j1 ORDER BY 1 UNION ALL SELECT max(e) FROM j2"
1320135aae8aSdan      {ORDER BY} {UNION ALL}
1321135aae8aSdan  3   "SELECT count(*), * FROM j1 ORDER BY 1,2,3 UNION ALL SELECT *,* FROM j2"
1322135aae8aSdan      {ORDER BY} {UNION ALL}
1323135aae8aSdan  4   "SELECT * FROM j1 LIMIT 10 UNION ALL SELECT * FROM j2,j3"
1324135aae8aSdan      LIMIT {UNION ALL}
1325135aae8aSdan  5   "SELECT * FROM j1 LIMIT 10 OFFSET 5 UNION ALL SELECT * FROM j2,j3"
1326135aae8aSdan      LIMIT {UNION ALL}
1327135aae8aSdan  6   "SELECT a FROM j1 LIMIT (SELECT e FROM j2) UNION ALL SELECT g FROM j2,j3"
1328135aae8aSdan      LIMIT {UNION ALL}
1329135aae8aSdan
1330135aae8aSdan  7   "SELECT * FROM j1 ORDER BY a UNION SELECT * FROM j2,j3"
1331135aae8aSdan      {ORDER BY} {UNION}
1332135aae8aSdan  8   "SELECT count(*) FROM j1 ORDER BY 1 UNION SELECT max(e) FROM j2"
1333135aae8aSdan      {ORDER BY} {UNION}
1334135aae8aSdan  9   "SELECT count(*), * FROM j1 ORDER BY 1,2,3 UNION SELECT *,* FROM j2"
1335135aae8aSdan      {ORDER BY} {UNION}
1336135aae8aSdan  10  "SELECT * FROM j1 LIMIT 10 UNION SELECT * FROM j2,j3"
1337135aae8aSdan      LIMIT {UNION}
1338135aae8aSdan  11  "SELECT * FROM j1 LIMIT 10 OFFSET 5 UNION SELECT * FROM j2,j3"
1339135aae8aSdan      LIMIT {UNION}
1340135aae8aSdan  12  "SELECT a FROM j1 LIMIT (SELECT e FROM j2) UNION SELECT g FROM j2,j3"
1341135aae8aSdan      LIMIT {UNION}
1342135aae8aSdan
1343135aae8aSdan  13  "SELECT * FROM j1 ORDER BY a EXCEPT SELECT * FROM j2,j3"
1344135aae8aSdan      {ORDER BY} {EXCEPT}
1345135aae8aSdan  14  "SELECT count(*) FROM j1 ORDER BY 1 EXCEPT SELECT max(e) FROM j2"
1346135aae8aSdan      {ORDER BY} {EXCEPT}
1347135aae8aSdan  15  "SELECT count(*), * FROM j1 ORDER BY 1,2,3 EXCEPT SELECT *,* FROM j2"
1348135aae8aSdan      {ORDER BY} {EXCEPT}
1349135aae8aSdan  16  "SELECT * FROM j1 LIMIT 10 EXCEPT SELECT * FROM j2,j3"
1350135aae8aSdan      LIMIT {EXCEPT}
1351135aae8aSdan  17  "SELECT * FROM j1 LIMIT 10 OFFSET 5 EXCEPT SELECT * FROM j2,j3"
1352135aae8aSdan      LIMIT {EXCEPT}
1353135aae8aSdan  18  "SELECT a FROM j1 LIMIT (SELECT e FROM j2) EXCEPT SELECT g FROM j2,j3"
1354135aae8aSdan      LIMIT {EXCEPT}
1355135aae8aSdan
1356135aae8aSdan  19  "SELECT * FROM j1 ORDER BY a INTERSECT SELECT * FROM j2,j3"
1357135aae8aSdan      {ORDER BY} {INTERSECT}
1358135aae8aSdan  20  "SELECT count(*) FROM j1 ORDER BY 1 INTERSECT SELECT max(e) FROM j2"
1359135aae8aSdan      {ORDER BY} {INTERSECT}
1360135aae8aSdan  21  "SELECT count(*), * FROM j1 ORDER BY 1,2,3 INTERSECT SELECT *,* FROM j2"
1361135aae8aSdan      {ORDER BY} {INTERSECT}
1362135aae8aSdan  22  "SELECT * FROM j1 LIMIT 10 INTERSECT SELECT * FROM j2,j3"
1363135aae8aSdan      LIMIT {INTERSECT}
1364135aae8aSdan  23  "SELECT * FROM j1 LIMIT 10 OFFSET 5 INTERSECT SELECT * FROM j2,j3"
1365135aae8aSdan      LIMIT {INTERSECT}
1366135aae8aSdan  24  "SELECT a FROM j1 LIMIT (SELECT e FROM j2) INTERSECT SELECT g FROM j2,j3"
1367135aae8aSdan      LIMIT {INTERSECT}
1368135aae8aSdan} {
1369135aae8aSdan  set err "$op1 clause should come after $op2 not before"
1370135aae8aSdan  do_catchsql_test e_select-7.2.$tn $select [list 1 $err]
1371135aae8aSdan}
1372135aae8aSdan
1373a88aca54Sdrh# EVIDENCE-OF: R-45440-25633 ORDER BY and LIMIT clauses may only occur
1374a88aca54Sdrh# at the end of the entire compound SELECT, and then only if the final
1375a88aca54Sdrh# element of the compound is not a VALUES clause.
1376135aae8aSdan#
1377135aae8aSdanforeach {tn select} {
1378135aae8aSdan  1   "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 ORDER BY a"
1379135aae8aSdan  2   "SELECT count(*) FROM j1 UNION ALL SELECT max(e) FROM j2 ORDER BY 1"
1380135aae8aSdan  3   "SELECT count(*), * FROM j1 UNION ALL SELECT *,* FROM j2 ORDER BY 1,2,3"
1381135aae8aSdan  4   "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 LIMIT 10"
1382135aae8aSdan  5   "SELECT * FROM j1 UNION ALL SELECT * FROM j2,j3 LIMIT 10 OFFSET 5"
1383135aae8aSdan  6   "SELECT a FROM j1 UNION ALL SELECT g FROM j2,j3 LIMIT (SELECT 10)"
1384135aae8aSdan
1385135aae8aSdan  7   "SELECT * FROM j1 UNION SELECT * FROM j2,j3 ORDER BY a"
1386135aae8aSdan  8   "SELECT count(*) FROM j1 UNION SELECT max(e) FROM j2 ORDER BY 1"
1387a88aca54Sdrh  8b  "VALUES('8b') UNION SELECT max(e) FROM j2 ORDER BY 1"
1388135aae8aSdan  9   "SELECT count(*), * FROM j1 UNION SELECT *,* FROM j2 ORDER BY 1,2,3"
1389135aae8aSdan  10  "SELECT * FROM j1 UNION SELECT * FROM j2,j3 LIMIT 10"
1390135aae8aSdan  11  "SELECT * FROM j1 UNION SELECT * FROM j2,j3 LIMIT 10 OFFSET 5"
1391135aae8aSdan  12  "SELECT a FROM j1 UNION SELECT g FROM j2,j3 LIMIT (SELECT 10)"
1392135aae8aSdan
1393135aae8aSdan  13  "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 ORDER BY a"
1394135aae8aSdan  14  "SELECT count(*) FROM j1 EXCEPT SELECT max(e) FROM j2 ORDER BY 1"
1395135aae8aSdan  15  "SELECT count(*), * FROM j1 EXCEPT SELECT *,* FROM j2 ORDER BY 1,2,3"
1396135aae8aSdan  16  "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 LIMIT 10"
1397135aae8aSdan  17  "SELECT * FROM j1 EXCEPT SELECT * FROM j2,j3 LIMIT 10 OFFSET 5"
1398135aae8aSdan  18  "SELECT a FROM j1 EXCEPT SELECT g FROM j2,j3 LIMIT (SELECT 10)"
1399135aae8aSdan
1400135aae8aSdan  19  "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 ORDER BY a"
1401135aae8aSdan  20  "SELECT count(*) FROM j1 INTERSECT SELECT max(e) FROM j2 ORDER BY 1"
1402135aae8aSdan  21  "SELECT count(*), * FROM j1 INTERSECT SELECT *,* FROM j2 ORDER BY 1,2,3"
1403135aae8aSdan  22  "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 LIMIT 10"
1404135aae8aSdan  23  "SELECT * FROM j1 INTERSECT SELECT * FROM j2,j3 LIMIT 10 OFFSET 5"
1405135aae8aSdan  24  "SELECT a FROM j1 INTERSECT SELECT g FROM j2,j3 LIMIT (SELECT 10)"
1406135aae8aSdan} {
1407135aae8aSdan  do_test e_select-7.3.$tn { catch {execsql $select} msg } 0
1408135aae8aSdan}
1409a88aca54Sdrhforeach {tn select} {
1410a88aca54Sdrh  50   "SELECT * FROM j1 ORDER BY 1 UNION ALL SELECT * FROM j2,j3"
1411a88aca54Sdrh  51   "SELECT * FROM j1 LIMIT 1 UNION ALL SELECT * FROM j2,j3"
1412a88aca54Sdrh  52   "SELECT count(*) FROM j1 UNION ALL VALUES(11) ORDER BY 1"
1413a88aca54Sdrh  53   "SELECT count(*) FROM j1 UNION ALL VALUES(11) LIMIT 1"
1414a88aca54Sdrh} {
1415a88aca54Sdrh  do_test e_select-7.3.$tn { catch {execsql $select} msg } 1
1416a88aca54Sdrh}
1417135aae8aSdan
1418135aae8aSdan# EVIDENCE-OF: R-08531-36543 A compound SELECT created using UNION ALL
1419135aae8aSdan# operator returns all the rows from the SELECT to the left of the UNION
1420135aae8aSdan# ALL operator, and all the rows from the SELECT to the right of it.
1421135aae8aSdan#
1422135aae8aSdandrop_all_tables
1423135aae8aSdando_execsql_test e_select-7.4.0 {
1424135aae8aSdan  CREATE TABLE q1(a TEXT, b INTEGER, c);
1425135aae8aSdan  CREATE TABLE q2(d NUMBER, e BLOB);
142623fb1330Sdan  CREATE TABLE q3(f REAL, g);
1427135aae8aSdan
1428135aae8aSdan  INSERT INTO q1 VALUES(16, -87.66, NULL);
1429135aae8aSdan  INSERT INTO q1 VALUES('legible', 94, -42.47);
1430135aae8aSdan  INSERT INTO q1 VALUES('beauty', 36, NULL);
1431135aae8aSdan
1432135aae8aSdan  INSERT INTO q2 VALUES('legible', 1);
1433135aae8aSdan  INSERT INTO q2 VALUES('beauty', 2);
1434135aae8aSdan  INSERT INTO q2 VALUES(-65.91, 4);
1435135aae8aSdan  INSERT INTO q2 VALUES('emanating', -16.56);
143623fb1330Sdan
143723fb1330Sdan  INSERT INTO q3 VALUES('beauty', 2);
143823fb1330Sdan  INSERT INTO q3 VALUES('beauty', 2);
1439135aae8aSdan} {}
14401b89d5d9Sdando_select_tests e_select-7.4 {
144123fb1330Sdan  1   {SELECT a FROM q1 UNION ALL SELECT d FROM q2}
144223fb1330Sdan      {16 legible beauty legible beauty -65.91 emanating}
1443135aae8aSdan
144423fb1330Sdan  2   {SELECT * FROM q1 WHERE a=16 UNION ALL SELECT 'x', * FROM q2 WHERE oid=1}
1445135aae8aSdan      {16 -87.66 {} x legible 1}
1446135aae8aSdan
144723fb1330Sdan  3   {SELECT count(*) FROM q1 UNION ALL SELECT min(e) FROM q2}
144823fb1330Sdan      {3 -16.56}
144923fb1330Sdan
145023fb1330Sdan  4   {SELECT * FROM q2 UNION ALL SELECT * FROM q3}
145123fb1330Sdan      {legible 1 beauty 2 -65.91 4 emanating -16.56 beauty 2 beauty 2}
1452135aae8aSdan}
1453135aae8aSdan
145423fb1330Sdan# EVIDENCE-OF: R-20560-39162 The UNION operator works the same way as
145523fb1330Sdan# UNION ALL, except that duplicate rows are removed from the final
145623fb1330Sdan# result set.
145723fb1330Sdan#
14581b89d5d9Sdando_select_tests e_select-7.5 {
145923fb1330Sdan  1   {SELECT a FROM q1 UNION SELECT d FROM q2}
146023fb1330Sdan      {-65.91 16 beauty emanating legible}
146123fb1330Sdan
146223fb1330Sdan  2   {SELECT * FROM q1 WHERE a=16 UNION SELECT 'x', * FROM q2 WHERE oid=1}
146323fb1330Sdan      {16 -87.66 {} x legible 1}
146423fb1330Sdan
146523fb1330Sdan  3   {SELECT count(*) FROM q1 UNION SELECT min(e) FROM q2}
146623fb1330Sdan      {-16.56 3}
146723fb1330Sdan
146823fb1330Sdan  4   {SELECT * FROM q2 UNION SELECT * FROM q3}
146923fb1330Sdan      {-65.91 4 beauty 2 emanating -16.56 legible 1}
147023fb1330Sdan}
147123fb1330Sdan
147223fb1330Sdan# EVIDENCE-OF: R-45764-31737 The INTERSECT operator returns the
147323fb1330Sdan# intersection of the results of the left and right SELECTs.
147423fb1330Sdan#
14751b89d5d9Sdando_select_tests e_select-7.6 {
147623fb1330Sdan  1   {SELECT a FROM q1 INTERSECT SELECT d FROM q2} {beauty legible}
147723fb1330Sdan  2   {SELECT * FROM q2 INTERSECT SELECT * FROM q3} {beauty 2}
147823fb1330Sdan}
147923fb1330Sdan
148023fb1330Sdan# EVIDENCE-OF: R-25787-28949 The EXCEPT operator returns the subset of
148123fb1330Sdan# rows returned by the left SELECT that are not also returned by the
148223fb1330Sdan# right-hand SELECT.
148323fb1330Sdan#
14841b89d5d9Sdando_select_tests e_select-7.7 {
148523fb1330Sdan  1   {SELECT a FROM q1 EXCEPT SELECT d FROM q2} {16}
148623fb1330Sdan
148723fb1330Sdan  2   {SELECT * FROM q2 EXCEPT SELECT * FROM q3}
148823fb1330Sdan      {-65.91 4 emanating -16.56 legible 1}
148923fb1330Sdan}
149023fb1330Sdan
149123fb1330Sdan# EVIDENCE-OF: R-40729-56447 Duplicate rows are removed from the results
149223fb1330Sdan# of INTERSECT and EXCEPT operators before the result set is returned.
149323fb1330Sdan#
14941b89d5d9Sdando_select_tests e_select-7.8 {
149523fb1330Sdan  0   {SELECT * FROM q3} {beauty 2 beauty 2}
149623fb1330Sdan
149723fb1330Sdan  1   {SELECT * FROM q3 INTERSECT SELECT * FROM q3} {beauty 2}
149823fb1330Sdan  2   {SELECT * FROM q3 EXCEPT SELECT a,b FROM q1}  {beauty 2}
149923fb1330Sdan}
150023fb1330Sdan
150123fb1330Sdan# EVIDENCE-OF: R-46765-43362 For the purposes of determining duplicate
150223fb1330Sdan# rows for the results of compound SELECT operators, NULL values are
150323fb1330Sdan# considered equal to other NULL values and distinct from all non-NULL
150423fb1330Sdan# values.
150523fb1330Sdan#
150623fb1330Sdandb nullvalue null
15071b89d5d9Sdando_select_tests e_select-7.9 {
150823fb1330Sdan  1   {SELECT NULL UNION ALL SELECT NULL} {null null}
150923fb1330Sdan  2   {SELECT NULL UNION     SELECT NULL} {null}
151023fb1330Sdan  3   {SELECT NULL INTERSECT SELECT NULL} {null}
151123fb1330Sdan  4   {SELECT NULL EXCEPT    SELECT NULL} {}
151223fb1330Sdan
151323fb1330Sdan  5   {SELECT NULL UNION ALL SELECT 'ab'} {null ab}
151423fb1330Sdan  6   {SELECT NULL UNION     SELECT 'ab'} {null ab}
151523fb1330Sdan  7   {SELECT NULL INTERSECT SELECT 'ab'} {}
151623fb1330Sdan  8   {SELECT NULL EXCEPT    SELECT 'ab'} {null}
151723fb1330Sdan
151823fb1330Sdan  9   {SELECT NULL UNION ALL SELECT 0} {null 0}
151923fb1330Sdan  10  {SELECT NULL UNION     SELECT 0} {null 0}
152023fb1330Sdan  11  {SELECT NULL INTERSECT SELECT 0} {}
152123fb1330Sdan  12  {SELECT NULL EXCEPT    SELECT 0} {null}
152223fb1330Sdan
152323fb1330Sdan  13  {SELECT c FROM q1 UNION ALL SELECT g FROM q3} {null -42.47 null 2 2}
152423fb1330Sdan  14  {SELECT c FROM q1 UNION     SELECT g FROM q3} {null -42.47 2}
152523fb1330Sdan  15  {SELECT c FROM q1 INTERSECT SELECT g FROM q3} {}
152623fb1330Sdan  16  {SELECT c FROM q1 EXCEPT    SELECT g FROM q3} {null -42.47}
152723fb1330Sdan}
152823fb1330Sdandb nullvalue {}
152923fb1330Sdan
153023fb1330Sdan# EVIDENCE-OF: R-51232-50224 The collation sequence used to compare two
153123fb1330Sdan# text values is determined as if the columns of the left and right-hand
153223fb1330Sdan# SELECT statements were the left and right-hand operands of the equals
153323fb1330Sdan# (=) operator, except that greater precedence is not assigned to a
153423fb1330Sdan# collation sequence specified with the postfix COLLATE operator.
153523fb1330Sdan#
153623fb1330Sdandrop_all_tables
153723fb1330Sdando_execsql_test e_select-7.10.0 {
153823fb1330Sdan  CREATE TABLE y1(a COLLATE nocase, b COLLATE binary, c);
153923fb1330Sdan  INSERT INTO y1 VALUES('Abc', 'abc', 'aBC');
154023fb1330Sdan} {}
15411b89d5d9Sdando_select_tests e_select-7.10 {
154223fb1330Sdan  1   {SELECT 'abc'                UNION SELECT 'ABC'} {ABC abc}
154323fb1330Sdan  2   {SELECT 'abc' COLLATE nocase UNION SELECT 'ABC'} {ABC}
154423fb1330Sdan  3   {SELECT 'abc'                UNION SELECT 'ABC' COLLATE nocase} {ABC}
154523fb1330Sdan  4   {SELECT 'abc' COLLATE binary UNION SELECT 'ABC' COLLATE nocase} {ABC abc}
154623fb1330Sdan  5   {SELECT 'abc' COLLATE nocase UNION SELECT 'ABC' COLLATE binary} {ABC}
154723fb1330Sdan
154823fb1330Sdan  6   {SELECT a FROM y1 UNION SELECT b FROM y1}                {abc}
154923fb1330Sdan  7   {SELECT b FROM y1 UNION SELECT a FROM y1}                {Abc abc}
155023fb1330Sdan  8   {SELECT a FROM y1 UNION SELECT c FROM y1}                {aBC}
155123fb1330Sdan
155223fb1330Sdan  9   {SELECT a FROM y1 UNION SELECT c COLLATE binary FROM y1} {aBC}
155323fb1330Sdan}
155423fb1330Sdan
155523fb1330Sdan# EVIDENCE-OF: R-32706-07403 No affinity transformations are applied to
155623fb1330Sdan# any values when comparing rows as part of a compound SELECT.
155723fb1330Sdan#
155823fb1330Sdandrop_all_tables
155923fb1330Sdando_execsql_test e_select-7.10.0 {
156023fb1330Sdan  CREATE TABLE w1(a TEXT, b NUMBER);
156123fb1330Sdan  CREATE TABLE w2(a, b TEXT);
156223fb1330Sdan
156323fb1330Sdan  INSERT INTO w1 VALUES('1', 4.1);
156423fb1330Sdan  INSERT INTO w2 VALUES(1, 4.1);
156523fb1330Sdan} {}
156623fb1330Sdan
15671b89d5d9Sdando_select_tests e_select-7.11 {
156823fb1330Sdan  1  { SELECT a FROM w1 UNION SELECT a FROM w2 } {1 1}
156923fb1330Sdan  2  { SELECT a FROM w2 UNION SELECT a FROM w1 } {1 1}
157023fb1330Sdan  3  { SELECT b FROM w1 UNION SELECT b FROM w2 } {4.1 4.1}
157123fb1330Sdan  4  { SELECT b FROM w2 UNION SELECT b FROM w1 } {4.1 4.1}
157223fb1330Sdan
157323fb1330Sdan  5  { SELECT a FROM w1 INTERSECT SELECT a FROM w2 } {}
157423fb1330Sdan  6  { SELECT a FROM w2 INTERSECT SELECT a FROM w1 } {}
157523fb1330Sdan  7  { SELECT b FROM w1 INTERSECT SELECT b FROM w2 } {}
157623fb1330Sdan  8  { SELECT b FROM w2 INTERSECT SELECT b FROM w1 } {}
157723fb1330Sdan
157823fb1330Sdan  9  { SELECT a FROM w1 EXCEPT SELECT a FROM w2 } {1}
157923fb1330Sdan  10 { SELECT a FROM w2 EXCEPT SELECT a FROM w1 } {1}
158023fb1330Sdan  11 { SELECT b FROM w1 EXCEPT SELECT b FROM w2 } {4.1}
158123fb1330Sdan  12 { SELECT b FROM w2 EXCEPT SELECT b FROM w1 } {4.1}
158223fb1330Sdan}
158323fb1330Sdan
1584135aae8aSdan
1585135aae8aSdan# EVIDENCE-OF: R-32562-20566 When three or more simple SELECTs are
1586135aae8aSdan# connected into a compound SELECT, they group from left to right. In
1587135aae8aSdan# other words, if "A", "B" and "C" are all simple SELECT statements, (A
1588135aae8aSdan# op B op C) is processed as ((A op B) op C).
1589135aae8aSdan#
159023fb1330Sdan#   e_select-7.12.1: Precedence of UNION vs. INTERSECT
159123fb1330Sdan#   e_select-7.12.2: Precedence of UNION vs. UNION ALL
159223fb1330Sdan#   e_select-7.12.3: Precedence of UNION vs. EXCEPT
159323fb1330Sdan#   e_select-7.12.4: Precedence of INTERSECT vs. UNION ALL
159423fb1330Sdan#   e_select-7.12.5: Precedence of INTERSECT vs. EXCEPT
159523fb1330Sdan#   e_select-7.12.6: Precedence of UNION ALL vs. EXCEPT
159623fb1330Sdan#   e_select-7.12.7: Check that "a EXCEPT b EXCEPT c" is processed as
1597135aae8aSdan#                   "(a EXCEPT b) EXCEPT c".
1598135aae8aSdan#
1599135aae8aSdan# The INTERSECT and EXCEPT operations are mutually commutative. So
160023fb1330Sdan# the e_select-7.12.5 test cases do not prove very much.
1601135aae8aSdan#
1602135aae8aSdandrop_all_tables
160323fb1330Sdando_execsql_test e_select-7.12.0 {
1604135aae8aSdan  CREATE TABLE t1(x);
1605135aae8aSdan  INSERT INTO t1 VALUES(1);
1606135aae8aSdan  INSERT INTO t1 VALUES(2);
1607135aae8aSdan  INSERT INTO t1 VALUES(3);
1608135aae8aSdan} {}
1609135aae8aSdanforeach {tn select res} {
1610135aae8aSdan  1a "(1,2) INTERSECT (1)   UNION     (3)"   {1 3}
1611135aae8aSdan  1b "(3)   UNION     (1,2) INTERSECT (1)"   {1}
1612135aae8aSdan
1613135aae8aSdan  2a "(1,2) UNION     (3)   UNION ALL (1)"   {1 2 3 1}
1614135aae8aSdan  2b "(1)   UNION ALL (3)   UNION     (1,2)" {1 2 3}
1615135aae8aSdan
1616135aae8aSdan  3a "(1,2) UNION     (3)   EXCEPT    (1)"   {2 3}
1617135aae8aSdan  3b "(1,2) EXCEPT    (3)   UNION     (1)"   {1 2}
1618135aae8aSdan
1619135aae8aSdan  4a "(1,2) INTERSECT (1)   UNION ALL (3)"   {1 3}
1620135aae8aSdan  4b "(3)   UNION     (1,2) INTERSECT (1)"   {1}
1621135aae8aSdan
1622135aae8aSdan  5a "(1,2) INTERSECT (2)   EXCEPT    (2)"   {}
1623135aae8aSdan  5b "(2,3) EXCEPT    (2)   INTERSECT (2)"   {}
1624135aae8aSdan
1625135aae8aSdan  6a "(2)   UNION ALL (2)   EXCEPT    (2)"   {}
1626135aae8aSdan  6b "(2)   EXCEPT    (2)   UNION ALL (2)"   {2}
1627135aae8aSdan
1628135aae8aSdan  7  "(2,3) EXCEPT    (2)   EXCEPT    (3)"   {}
1629135aae8aSdan} {
1630135aae8aSdan  set select [string map {( {SELECT x FROM t1 WHERE x IN (}} $select]
163123fb1330Sdan  do_execsql_test e_select-7.12.$tn $select [list {*}$res]
1632135aae8aSdan}
1633135aae8aSdan
1634eea831faSdan
1635eea831faSdan#-------------------------------------------------------------------------
1636eea831faSdan# ORDER BY clauses
1637eea831faSdan#
1638eea831faSdan
1639eea831faSdandrop_all_tables
1640eea831faSdando_execsql_test e_select-8.1.0 {
1641eea831faSdan  CREATE TABLE d1(x, y, z);
1642eea831faSdan
1643eea831faSdan  INSERT INTO d1 VALUES(1, 2, 3);
1644eea831faSdan  INSERT INTO d1 VALUES(2, 5, -1);
1645eea831faSdan  INSERT INTO d1 VALUES(1, 2, 8);
1646eea831faSdan  INSERT INTO d1 VALUES(1, 2, 7);
1647eea831faSdan  INSERT INTO d1 VALUES(2, 4, 93);
1648eea831faSdan  INSERT INTO d1 VALUES(1, 2, -20);
1649eea831faSdan  INSERT INTO d1 VALUES(1, 4, 93);
1650eea831faSdan  INSERT INTO d1 VALUES(1, 5, -1);
1651eea831faSdan
1652eea831faSdan  CREATE TABLE d2(a, b);
1653eea831faSdan  INSERT INTO d2 VALUES('gently', 'failings');
1654eea831faSdan  INSERT INTO d2 VALUES('commercials', 'bathrobe');
1655eea831faSdan  INSERT INTO d2 VALUES('iterate', 'sexton');
1656eea831faSdan  INSERT INTO d2 VALUES('babied', 'charitableness');
1657eea831faSdan  INSERT INTO d2 VALUES('solemnness', 'annexed');
1658eea831faSdan  INSERT INTO d2 VALUES('rejoicing', 'liabilities');
1659eea831faSdan  INSERT INTO d2 VALUES('pragmatist', 'guarded');
1660eea831faSdan  INSERT INTO d2 VALUES('barked', 'interrupted');
1661eea831faSdan  INSERT INTO d2 VALUES('reemphasizes', 'reply');
1662eea831faSdan  INSERT INTO d2 VALUES('lad', 'relenting');
1663eea831faSdan} {}
1664eea831faSdan
1665eea831faSdan# EVIDENCE-OF: R-44988-41064 Rows are first sorted based on the results
1666eea831faSdan# of evaluating the left-most expression in the ORDER BY list, then ties
1667eea831faSdan# are broken by evaluating the second left-most expression and so on.
1668eea831faSdan#
16691b89d5d9Sdando_select_tests e_select-8.1 {
1670eea831faSdan  1  "SELECT * FROM d1 ORDER BY x, y, z" {
1671eea831faSdan     1 2 -20    1 2 3    1 2 7    1 2 8
1672eea831faSdan     1 4  93    1 5 -1   2 4 93   2 5 -1
1673eea831faSdan  }
1674eea831faSdan}
1675eea831faSdan
1676eea831faSdan# EVIDENCE-OF: R-06617-54588 Each ORDER BY expression may be optionally
1677eea831faSdan# followed by one of the keywords ASC (smaller values are returned
1678eea831faSdan# first) or DESC (larger values are returned first).
1679eea831faSdan#
1680eea831faSdan#   Test cases e_select-8.2.* test the above.
1681eea831faSdan#
1682eea831faSdan# EVIDENCE-OF: R-18705-33393 If neither ASC or DESC are specified, rows
1683eea831faSdan# are sorted in ascending (smaller values first) order by default.
1684eea831faSdan#
1685eea831faSdan#   Test cases e_select-8.3.* test the above. All 8.3 test cases are
1686eea831faSdan#   copies of 8.2 test cases with the explicit "ASC" removed.
1687eea831faSdan#
16881b89d5d9Sdando_select_tests e_select-8 {
1689eea831faSdan  2.1  "SELECT * FROM d1 ORDER BY x ASC, y ASC, z ASC" {
1690eea831faSdan     1 2 -20    1 2 3    1 2 7    1 2 8
1691eea831faSdan     1 4  93    1 5 -1   2 4 93   2 5 -1
1692eea831faSdan  }
1693eea831faSdan  2.2  "SELECT * FROM d1 ORDER BY x DESC, y DESC, z DESC" {
1694eea831faSdan     2 5 -1     2 4 93   1 5 -1   1 4  93
1695eea831faSdan     1 2 8      1 2 7    1 2 3    1 2 -20
1696eea831faSdan  }
1697eea831faSdan  2.3 "SELECT * FROM d1 ORDER BY x DESC, y ASC, z DESC" {
1698eea831faSdan     2 4 93   2 5 -1     1 2 8      1 2 7
1699eea831faSdan     1 2 3    1 2 -20    1 4  93    1 5 -1
1700eea831faSdan  }
1701eea831faSdan  2.4  "SELECT * FROM d1 ORDER BY x DESC, y ASC, z ASC" {
1702eea831faSdan     2 4 93   2 5 -1     1 2 -20    1 2 3
1703eea831faSdan     1 2 7    1 2 8      1 4  93    1 5 -1
1704eea831faSdan  }
1705eea831faSdan
1706eea831faSdan  3.1  "SELECT * FROM d1 ORDER BY x, y, z" {
1707eea831faSdan     1 2 -20    1 2 3    1 2 7    1 2 8
1708eea831faSdan     1 4  93    1 5 -1   2 4 93   2 5 -1
1709eea831faSdan  }
1710eea831faSdan  3.3  "SELECT * FROM d1 ORDER BY x DESC, y, z DESC" {
1711eea831faSdan     2 4 93   2 5 -1     1 2 8      1 2 7
1712eea831faSdan     1 2 3    1 2 -20    1 4  93    1 5 -1
1713eea831faSdan  }
1714eea831faSdan  3.4 "SELECT * FROM d1 ORDER BY x DESC, y, z" {
1715eea831faSdan     2 4 93   2 5 -1     1 2 -20    1 2 3
1716eea831faSdan     1 2 7    1 2 8      1 4  93    1 5 -1
1717eea831faSdan  }
1718eea831faSdan}
1719eea831faSdan
1720eea831faSdan# EVIDENCE-OF: R-29779-04281 If the ORDER BY expression is a constant
1721eea831faSdan# integer K then the expression is considered an alias for the K-th
1722eea831faSdan# column of the result set (columns are numbered from left to right
1723eea831faSdan# starting with 1).
1724eea831faSdan#
17251b89d5d9Sdando_select_tests e_select-8.4 {
1726eea831faSdan  1  "SELECT * FROM d1 ORDER BY 1 ASC, 2 ASC, 3 ASC" {
1727eea831faSdan     1 2 -20    1 2 3    1 2 7    1 2 8
1728eea831faSdan     1 4  93    1 5 -1   2 4 93   2 5 -1
1729eea831faSdan  }
1730eea831faSdan  2  "SELECT * FROM d1 ORDER BY 1 DESC, 2 DESC, 3 DESC" {
1731eea831faSdan     2 5 -1     2 4 93   1 5 -1   1 4  93
1732eea831faSdan     1 2 8      1 2 7    1 2 3    1 2 -20
1733eea831faSdan  }
1734eea831faSdan  3 "SELECT * FROM d1 ORDER BY 1 DESC, 2 ASC, 3 DESC" {
1735eea831faSdan     2 4 93   2 5 -1     1 2 8      1 2 7
1736eea831faSdan     1 2 3    1 2 -20    1 4  93    1 5 -1
1737eea831faSdan  }
1738eea831faSdan  4  "SELECT * FROM d1 ORDER BY 1 DESC, 2 ASC, 3 ASC" {
1739eea831faSdan     2 4 93   2 5 -1     1 2 -20    1 2 3
1740eea831faSdan     1 2 7    1 2 8      1 4  93    1 5 -1
1741eea831faSdan  }
1742eea831faSdan  5  "SELECT * FROM d1 ORDER BY 1, 2, 3" {
1743eea831faSdan     1 2 -20    1 2 3    1 2 7    1 2 8
1744eea831faSdan     1 4  93    1 5 -1   2 4 93   2 5 -1
1745eea831faSdan  }
1746eea831faSdan  6  "SELECT * FROM d1 ORDER BY 1 DESC, 2, 3 DESC" {
1747eea831faSdan     2 4 93   2 5 -1     1 2 8      1 2 7
1748eea831faSdan     1 2 3    1 2 -20    1 4  93    1 5 -1
1749eea831faSdan  }
1750eea831faSdan  7  "SELECT * FROM d1 ORDER BY 1 DESC, 2, 3" {
1751eea831faSdan     2 4 93   2 5 -1     1 2 -20    1 2 3
1752eea831faSdan     1 2 7    1 2 8      1 4  93    1 5 -1
1753eea831faSdan  }
1754eea831faSdan  8  "SELECT z, x FROM d1 ORDER BY 2" {
17555343b2d4Sdrh     /# 1    # 1    # 1   # 1
17565343b2d4Sdrh      # 1    # 1    # 2   # 2/
1757eea831faSdan  }
1758eea831faSdan  9  "SELECT z, x FROM d1 ORDER BY 1" {
17595343b2d4Sdrh     /-20 1  -1 #   -1 #   3 1
17605343b2d4Sdrh     7 1     8 1   93 #   93 #/
1761eea831faSdan  }
1762eea831faSdan}
1763eea831faSdan
1764eea831faSdan# EVIDENCE-OF: R-63286-51977 If the ORDER BY expression is an identifier
1765eea831faSdan# that corresponds to the alias of one of the output columns, then the
1766eea831faSdan# expression is considered an alias for that column.
1767eea831faSdan#
17681b89d5d9Sdando_select_tests e_select-8.5 {
1769eea831faSdan  1   "SELECT z+1 AS abc FROM d1 ORDER BY abc" {
1770eea831faSdan    -19 0 0 4 8 9 94 94
1771eea831faSdan  }
1772eea831faSdan  2   "SELECT z+1 AS abc FROM d1 ORDER BY abc DESC" {
1773eea831faSdan    94 94 9 8 4 0 0 -19
1774eea831faSdan  }
1775eea831faSdan  3  "SELECT z AS x, x AS z FROM d1 ORDER BY z" {
17765343b2d4Sdrh    /# 1    # 1    # 1    # 1    # 1    # 1    # 2    # 2/
1777eea831faSdan  }
1778eea831faSdan  4  "SELECT z AS x, x AS z FROM d1 ORDER BY x" {
17795343b2d4Sdrh    /-20 1    -1 #    -1 #    3 1    7 1    8 1    93 #    93 #/
1780eea831faSdan  }
1781eea831faSdan}
1782eea831faSdan
17831a475194Sdrh# EVIDENCE-OF: R-65068-27207 Otherwise, if the ORDER BY expression is
17841a475194Sdrh# any other expression, it is evaluated and the returned value used to
17851a475194Sdrh# order the output rows.
1786eea831faSdan#
1787eea831faSdan# EVIDENCE-OF: R-03421-57988 If the SELECT statement is a simple SELECT,
1788eea831faSdan# then an ORDER BY may contain any arbitrary expressions.
1789eea831faSdan#
17901b89d5d9Sdando_select_tests e_select-8.6 {
1791eea831faSdan  1   "SELECT * FROM d1 ORDER BY x+y+z" {
1792eea831faSdan    1 2 -20    1 5 -1    1 2 3    2 5 -1
1793eea831faSdan    1 2 7      1 2 8     1 4 93   2 4 93
1794eea831faSdan  }
1795eea831faSdan  2   "SELECT * FROM d1 ORDER BY x*z" {
1796eea831faSdan    1 2 -20    2 5 -1    1 5 -1    1 2 3
1797eea831faSdan    1 2 7      1 2 8     1 4 93    2 4 93
1798eea831faSdan  }
1799eea831faSdan  3   "SELECT * FROM d1 ORDER BY y*z" {
1800eea831faSdan    1 2 -20    2 5 -1    1 5 -1    1 2 3
1801eea831faSdan    1 2 7      1 2 8     2 4 93    1 4 93
1802eea831faSdan  }
1803eea831faSdan}
1804eea831faSdan
1805eea831faSdan# EVIDENCE-OF: R-28853-08147 However, if the SELECT is a compound
1806eea831faSdan# SELECT, then ORDER BY expressions that are not aliases to output
1807eea831faSdan# columns must be exactly the same as an expression used as an output
1808eea831faSdan# column.
1809eea831faSdan#
18101b89d5d9Sdando_select_tests e_select-8.7.1 -error {
18111b89d5d9Sdan  %s ORDER BY term does not match any column in the result set
18121b89d5d9Sdan} {
1813eea831faSdan  1   "SELECT x FROM d1 UNION ALL SELECT a FROM d2 ORDER BY x*z"        1st
1814eea831faSdan  2   "SELECT x,z FROM d1 UNION ALL SELECT a,b FROM d2 ORDER BY x, x/z" 2nd
1815eea831faSdan}
18161b89d5d9Sdan
18171b89d5d9Sdando_select_tests e_select-8.7.2 {
1818eea831faSdan  1   "SELECT x*z FROM d1 UNION ALL SELECT a FROM d2 ORDER BY x*z" {
1819eea831faSdan    -20 -2 -1 3 7 8 93 186 babied barked commercials gently
1820eea831faSdan    iterate lad pragmatist reemphasizes rejoicing solemnness
1821eea831faSdan  }
1822eea831faSdan  2   "SELECT x, x/z FROM d1 UNION ALL SELECT a,b FROM d2 ORDER BY x, x/z" {
1823eea831faSdan    1 -1 1 0 1 0 1 0 1 0 1 0 2 -2 2 0
1824eea831faSdan    babied charitableness barked interrupted commercials bathrobe gently
1825eea831faSdan    failings iterate sexton lad relenting pragmatist guarded reemphasizes reply
1826eea831faSdan    rejoicing liabilities solemnness annexed
1827eea831faSdan  }
1828eea831faSdan}
1829eea831faSdan
1830eea831faSdando_execsql_test e_select-8.8.0 {
1831eea831faSdan  CREATE TABLE d3(a);
1832eea831faSdan  INSERT INTO d3 VALUES('text');
1833eea831faSdan  INSERT INTO d3 VALUES(14.1);
1834eea831faSdan  INSERT INTO d3 VALUES(13);
1835eea831faSdan  INSERT INTO d3 VALUES(X'78787878');
1836eea831faSdan  INSERT INTO d3 VALUES(15);
1837eea831faSdan  INSERT INTO d3 VALUES(12.9);
1838eea831faSdan  INSERT INTO d3 VALUES(null);
1839eea831faSdan
1840eea831faSdan  CREATE TABLE d4(x COLLATE nocase);
1841eea831faSdan  INSERT INTO d4 VALUES('abc');
1842eea831faSdan  INSERT INTO d4 VALUES('ghi');
1843eea831faSdan  INSERT INTO d4 VALUES('DEF');
1844eea831faSdan  INSERT INTO d4 VALUES('JKL');
1845eea831faSdan} {}
1846eea831faSdan
1847eea831faSdan# EVIDENCE-OF: R-10883-17697 For the purposes of sorting rows, values
1848eea831faSdan# are compared in the same way as for comparison expressions.
1849eea831faSdan#
1850eea831faSdan#   The following tests verify that values of different types are sorted
1851eea831faSdan#   correctly, and that mixed real and integer values are compared properly.
1852eea831faSdan#
1853eea831faSdando_execsql_test e_select-8.8.1 {
1854eea831faSdan  SELECT a FROM d3 ORDER BY a
1855eea831faSdan} {{} 12.9 13 14.1 15 text xxxx}
1856eea831faSdando_execsql_test e_select-8.8.2 {
1857eea831faSdan  SELECT a FROM d3 ORDER BY a DESC
1858eea831faSdan} {xxxx text 15 14.1 13 12.9 {}}
1859eea831faSdan
1860eea831faSdan
1861eea831faSdan# EVIDENCE-OF: R-64199-22471 If the ORDER BY expression is assigned a
1862eea831faSdan# collation sequence using the postfix COLLATE operator, then the
1863eea831faSdan# specified collation sequence is used.
1864eea831faSdan#
1865eea831faSdando_execsql_test e_select-8.9.1 {
1866eea831faSdan  SELECT x FROM d4 ORDER BY 1 COLLATE binary
1867eea831faSdan} {DEF JKL abc ghi}
1868eea831faSdando_execsql_test e_select-8.9.2 {
1869eea831faSdan  SELECT x COLLATE binary FROM d4 ORDER BY 1 COLLATE nocase
1870eea831faSdan} {abc DEF ghi JKL}
1871eea831faSdan
1872eea831faSdan# EVIDENCE-OF: R-09398-26102 Otherwise, if the ORDER BY expression is
1873eea831faSdan# an alias to an expression that has been assigned a collation sequence
1874eea831faSdan# using the postfix COLLATE operator, then the collation sequence
1875eea831faSdan# assigned to the aliased expression is used.
1876eea831faSdan#
1877eea831faSdan#   In the test 8.10.2, the only result-column expression has no alias. So the
1878eea831faSdan#   ORDER BY expression is not a reference to it and therefore does not inherit
1879eea831faSdan#   the collation sequence. In test 8.10.3, "x" is the alias (as well as the
1880eea831faSdan#   column name), so the ORDER BY expression is interpreted as an alias and the
1881eea831faSdan#   collation sequence attached to the result column is used for sorting.
1882eea831faSdan#
1883eea831faSdando_execsql_test e_select-8.10.1 {
1884eea831faSdan  SELECT x COLLATE binary FROM d4 ORDER BY 1
1885eea831faSdan} {DEF JKL abc ghi}
1886eea831faSdando_execsql_test e_select-8.10.2 {
1887eea831faSdan  SELECT x COLLATE binary FROM d4 ORDER BY x
1888eea831faSdan} {abc DEF ghi JKL}
1889eea831faSdando_execsql_test e_select-8.10.3 {
1890eea831faSdan  SELECT x COLLATE binary AS x FROM d4 ORDER BY x
1891eea831faSdan} {DEF JKL abc ghi}
1892eea831faSdan
1893eea831faSdan# EVIDENCE-OF: R-27301-09658 Otherwise, if the ORDER BY expression is a
1894eea831faSdan# column or an alias of an expression that is a column, then the default
1895eea831faSdan# collation sequence for the column is used.
1896eea831faSdan#
1897eea831faSdando_execsql_test e_select-8.11.1 {
1898eea831faSdan  SELECT x AS y FROM d4 ORDER BY y
1899eea831faSdan} {abc DEF ghi JKL}
1900eea831faSdando_execsql_test e_select-8.11.2 {
1901eea831faSdan  SELECT x||'' FROM d4 ORDER BY x
1902eea831faSdan} {abc DEF ghi JKL}
1903eea831faSdan
1904eea831faSdan# EVIDENCE-OF: R-49925-55905 Otherwise, the BINARY collation sequence is
1905eea831faSdan# used.
1906eea831faSdan#
1907eea831faSdando_execsql_test e_select-8.12.1 {
1908eea831faSdan  SELECT x FROM d4 ORDER BY x||''
1909eea831faSdan} {DEF JKL abc ghi}
1910eea831faSdan
1911201ed8a4Sdan# EVIDENCE-OF: R-44130-32593 If an ORDER BY expression is not an integer
1912201ed8a4Sdan# alias, then SQLite searches the left-most SELECT in the compound for a
1913201ed8a4Sdan# result column that matches either the second or third rules above. If
1914201ed8a4Sdan# a match is found, the search stops and the expression is handled as an
1915201ed8a4Sdan# alias for the result column that it has been matched against.
1916201ed8a4Sdan# Otherwise, the next SELECT to the right is tried, and so on.
1917201ed8a4Sdan#
1918201ed8a4Sdando_execsql_test e_select-8.13.0 {
1919201ed8a4Sdan  CREATE TABLE d5(a, b);
1920201ed8a4Sdan  CREATE TABLE d6(c, d);
1921201ed8a4Sdan  CREATE TABLE d7(e, f);
1922201ed8a4Sdan
1923201ed8a4Sdan  INSERT INTO d5 VALUES(1, 'f');
1924201ed8a4Sdan  INSERT INTO d6 VALUES(2, 'e');
1925201ed8a4Sdan  INSERT INTO d7 VALUES(3, 'd');
1926201ed8a4Sdan  INSERT INTO d5 VALUES(4, 'c');
1927201ed8a4Sdan  INSERT INTO d6 VALUES(5, 'b');
1928201ed8a4Sdan  INSERT INTO d7 VALUES(6, 'a');
1929201ed8a4Sdan
1930201ed8a4Sdan  CREATE TABLE d8(x COLLATE nocase);
1931201ed8a4Sdan  CREATE TABLE d9(y COLLATE nocase);
1932201ed8a4Sdan
1933201ed8a4Sdan  INSERT INTO d8 VALUES('a');
1934201ed8a4Sdan  INSERT INTO d9 VALUES('B');
1935201ed8a4Sdan  INSERT INTO d8 VALUES('c');
1936201ed8a4Sdan  INSERT INTO d9 VALUES('D');
1937201ed8a4Sdan} {}
19381b89d5d9Sdando_select_tests e_select-8.13 {
1939201ed8a4Sdan  1   { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7
1940201ed8a4Sdan         ORDER BY a
1941201ed8a4Sdan      } {1 2 3 4 5 6}
1942201ed8a4Sdan  2   { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7
1943201ed8a4Sdan         ORDER BY c
1944201ed8a4Sdan      } {1 2 3 4 5 6}
1945201ed8a4Sdan  3   { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7
1946201ed8a4Sdan         ORDER BY e
1947201ed8a4Sdan      } {1 2 3 4 5 6}
1948201ed8a4Sdan  4   { SELECT a FROM d5 UNION ALL SELECT c FROM d6 UNION ALL SELECT e FROM d7
1949201ed8a4Sdan         ORDER BY 1
1950201ed8a4Sdan      } {1 2 3 4 5 6}
1951201ed8a4Sdan
1952201ed8a4Sdan  5   { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY b }
1953201ed8a4Sdan      {f 1   c 4   4 c   1 f}
1954201ed8a4Sdan  6   { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY 2 }
1955201ed8a4Sdan      {f 1   c 4   4 c   1 f}
1956201ed8a4Sdan
1957201ed8a4Sdan  7   { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY a }
1958201ed8a4Sdan      {1 f   4 c   c 4   f 1}
1959201ed8a4Sdan  8   { SELECT a, b FROM d5 UNION ALL SELECT b, a FROM d5 ORDER BY 1 }
1960201ed8a4Sdan      {1 f   4 c   c 4   f 1}
1961201ed8a4Sdan
1962201ed8a4Sdan  9   { SELECT a, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY a+1 }
1963201ed8a4Sdan      {f 2   c 5   4 c   1 f}
1964201ed8a4Sdan  10  { SELECT a, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY 2 }
1965201ed8a4Sdan      {f 2   c 5   4 c   1 f}
1966201ed8a4Sdan
1967201ed8a4Sdan  11  { SELECT a+1, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY a+1 }
1968201ed8a4Sdan      {2 f   5 c   c 5   f 2}
1969201ed8a4Sdan  12  { SELECT a+1, b FROM d5 UNION ALL SELECT b, a+1 FROM d5 ORDER BY 1 }
1970201ed8a4Sdan      {2 f   5 c   c 5   f 2}
1971201ed8a4Sdan}
1972201ed8a4Sdan
1973201ed8a4Sdan# EVIDENCE-OF: R-39265-04070 If no matching expression can be found in
1974201ed8a4Sdan# the result columns of any constituent SELECT, it is an error.
1975201ed8a4Sdan#
19761b89d5d9Sdando_select_tests e_select-8.14 -error {
19771b89d5d9Sdan  %s ORDER BY term does not match any column in the result set
19781b89d5d9Sdan} {
1979201ed8a4Sdan  1   { SELECT a FROM d5 UNION SELECT c FROM d6 ORDER BY a+1 }          1st
1980201ed8a4Sdan  2   { SELECT a FROM d5 UNION SELECT c FROM d6 ORDER BY a, a+1 }       2nd
1981201ed8a4Sdan  3   { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY 'hello' }  1st
1982201ed8a4Sdan  4   { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY blah    }  1st
1983201ed8a4Sdan  5   { SELECT * FROM d5 INTERSECT SELECT * FROM d6 ORDER BY c,d,c+d }  3rd
1984201ed8a4Sdan  6   { SELECT * FROM d5 EXCEPT SELECT * FROM d7 ORDER BY 1,2,b,a/b  }  4th
1985201ed8a4Sdan}
1986201ed8a4Sdan
1987201ed8a4Sdan# EVIDENCE-OF: R-03407-11483 Each term of the ORDER BY clause is
1988201ed8a4Sdan# processed separately and may be matched against result columns from
1989201ed8a4Sdan# different SELECT statements in the compound.
1990201ed8a4Sdan#
19911b89d5d9Sdando_select_tests e_select-8.15 {
1992201ed8a4Sdan  1  { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY a, d }
1993201ed8a4Sdan     {1 e   1 f   4 b   4 c}
1994201ed8a4Sdan  2  { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY c-1, b }
1995201ed8a4Sdan     {1 e   1 f   4 b   4 c}
1996201ed8a4Sdan  3  { SELECT a, b FROM d5 UNION ALL SELECT c-1, d FROM d6 ORDER BY 1, 2 }
1997201ed8a4Sdan     {1 e   1 f   4 b   4 c}
1998201ed8a4Sdan}
1999201ed8a4Sdan
2000201ed8a4Sdan
2001201ed8a4Sdan#-------------------------------------------------------------------------
2002201ed8a4Sdan# Tests related to statements made about the LIMIT/OFFSET clause.
2003201ed8a4Sdan#
2004201ed8a4Sdando_execsql_test e_select-9.0 {
2005201ed8a4Sdan  CREATE TABLE f1(a, b);
2006201ed8a4Sdan  INSERT INTO f1 VALUES(26, 'z');
2007201ed8a4Sdan  INSERT INTO f1 VALUES(25, 'y');
2008201ed8a4Sdan  INSERT INTO f1 VALUES(24, 'x');
2009201ed8a4Sdan  INSERT INTO f1 VALUES(23, 'w');
2010201ed8a4Sdan  INSERT INTO f1 VALUES(22, 'v');
2011201ed8a4Sdan  INSERT INTO f1 VALUES(21, 'u');
2012201ed8a4Sdan  INSERT INTO f1 VALUES(20, 't');
2013201ed8a4Sdan  INSERT INTO f1 VALUES(19, 's');
2014201ed8a4Sdan  INSERT INTO f1 VALUES(18, 'r');
2015201ed8a4Sdan  INSERT INTO f1 VALUES(17, 'q');
2016201ed8a4Sdan  INSERT INTO f1 VALUES(16, 'p');
2017201ed8a4Sdan  INSERT INTO f1 VALUES(15, 'o');
2018201ed8a4Sdan  INSERT INTO f1 VALUES(14, 'n');
2019201ed8a4Sdan  INSERT INTO f1 VALUES(13, 'm');
2020201ed8a4Sdan  INSERT INTO f1 VALUES(12, 'l');
2021201ed8a4Sdan  INSERT INTO f1 VALUES(11, 'k');
2022201ed8a4Sdan  INSERT INTO f1 VALUES(10, 'j');
2023201ed8a4Sdan  INSERT INTO f1 VALUES(9, 'i');
2024201ed8a4Sdan  INSERT INTO f1 VALUES(8, 'h');
2025201ed8a4Sdan  INSERT INTO f1 VALUES(7, 'g');
2026201ed8a4Sdan  INSERT INTO f1 VALUES(6, 'f');
2027201ed8a4Sdan  INSERT INTO f1 VALUES(5, 'e');
2028201ed8a4Sdan  INSERT INTO f1 VALUES(4, 'd');
2029201ed8a4Sdan  INSERT INTO f1 VALUES(3, 'c');
2030201ed8a4Sdan  INSERT INTO f1 VALUES(2, 'b');
2031201ed8a4Sdan  INSERT INTO f1 VALUES(1, 'a');
2032201ed8a4Sdan} {}
2033201ed8a4Sdan
2034201ed8a4Sdan# EVIDENCE-OF: R-30481-56627 Any scalar expression may be used in the
2035201ed8a4Sdan# LIMIT clause, so long as it evaluates to an integer or a value that
2036201ed8a4Sdan# can be losslessly converted to an integer.
2037201ed8a4Sdan#
20381b89d5d9Sdando_select_tests e_select-9.1 {
2039201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 5 } {a b c d e}
2040201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT 2+3 } {a b c d e}
2041201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a LIMIT (SELECT a FROM f1 WHERE b = 'e') }
2042201ed8a4Sdan     {a b c d e}
2043201ed8a4Sdan  4  { SELECT b FROM f1 ORDER BY a LIMIT 5.0 } {a b c d e}
2044201ed8a4Sdan  5  { SELECT b FROM f1 ORDER BY a LIMIT '5' } {a b c d e}
2045201ed8a4Sdan}
2046201ed8a4Sdan
2047201ed8a4Sdan# EVIDENCE-OF: R-46155-47219 If the expression evaluates to a NULL value
2048201ed8a4Sdan# or any other value that cannot be losslessly converted to an integer,
2049201ed8a4Sdan# an error is returned.
2050201ed8a4Sdan#
20511b89d5d9Sdan
20521b89d5d9Sdando_select_tests e_select-9.2 -error "datatype mismatch" {
20531b89d5d9Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 'hello' } {}
20541b89d5d9Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT NULL } {}
20551b89d5d9Sdan  3  { SELECT b FROM f1 ORDER BY a LIMIT X'ABCD' } {}
20561b89d5d9Sdan  4  { SELECT b FROM f1 ORDER BY a LIMIT 5.1 } {}
20571b89d5d9Sdan  5  { SELECT b FROM f1 ORDER BY a LIMIT (SELECT group_concat(b) FROM f1) } {}
2058201ed8a4Sdan}
2059201ed8a4Sdan
2060201ed8a4Sdan# EVIDENCE-OF: R-03014-26414 If the LIMIT expression evaluates to a
2061201ed8a4Sdan# negative value, then there is no upper bound on the number of rows
2062201ed8a4Sdan# returned.
2063201ed8a4Sdan#
20641b89d5d9Sdando_select_tests e_select-9.4 {
2065201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT -1 }
2066201ed8a4Sdan     {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}
2067201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT length('abc')-100 }
2068201ed8a4Sdan     {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}
2069201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a LIMIT (SELECT count(*) FROM f1)/2 - 14 }
2070201ed8a4Sdan     {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}
2071201ed8a4Sdan}
2072201ed8a4Sdan
2073201ed8a4Sdan# EVIDENCE-OF: R-33750-29536 Otherwise, the SELECT returns the first N
2074201ed8a4Sdan# rows of its result set only, where N is the value that the LIMIT
2075201ed8a4Sdan# expression evaluates to.
2076201ed8a4Sdan#
20771b89d5d9Sdando_select_tests e_select-9.5 {
2078201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 0 } {}
2079201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a DESC LIMIT 4 } {z y x w}
2080201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a DESC LIMIT 8 } {z y x w v u t s}
2081201ed8a4Sdan  4  { SELECT b FROM f1 ORDER BY a DESC LIMIT '12.0' } {z y x w v u t s r q p o}
2082201ed8a4Sdan}
2083201ed8a4Sdan
2084201ed8a4Sdan# EVIDENCE-OF: R-54935-19057 Or, if the SELECT statement would return
2085201ed8a4Sdan# less than N rows without a LIMIT clause, then the entire result set is
2086201ed8a4Sdan# returned.
2087201ed8a4Sdan#
20881b89d5d9Sdando_select_tests e_select-9.6 {
2089201ed8a4Sdan  1  { SELECT b FROM f1 WHERE a>21 ORDER BY a LIMIT 10 } {v w x y z}
2090201ed8a4Sdan  2  { SELECT count(*) FROM f1 GROUP BY a/5 ORDER BY 1 LIMIT 10 } {2 4 5 5 5 5}
2091201ed8a4Sdan}
2092201ed8a4Sdan
2093201ed8a4Sdan
2094201ed8a4Sdan# EVIDENCE-OF: R-24188-24349 The expression attached to the optional
2095201ed8a4Sdan# OFFSET clause that may follow a LIMIT clause must also evaluate to an
2096201ed8a4Sdan# integer, or a value that can be losslessly converted to an integer.
2097201ed8a4Sdan#
2098201ed8a4Sdanforeach {tn select} {
2099201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET 'hello' }
2100201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET NULL }
2101201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET X'ABCD' }
2102201ed8a4Sdan  4  { SELECT b FROM f1 ORDER BY a LIMIT 2 OFFSET 5.1 }
2103201ed8a4Sdan  5  { SELECT b FROM f1 ORDER BY a
2104201ed8a4Sdan       LIMIT 2 OFFSET (SELECT group_concat(b) FROM f1)
2105201ed8a4Sdan  }
2106201ed8a4Sdan} {
2107201ed8a4Sdan  do_catchsql_test e_select-9.7.$tn $select {1 {datatype mismatch}}
2108201ed8a4Sdan}
2109201ed8a4Sdan
2110201ed8a4Sdan# EVIDENCE-OF: R-20467-43422 If an expression has an OFFSET clause, then
2111201ed8a4Sdan# the first M rows are omitted from the result set returned by the
2112201ed8a4Sdan# SELECT statement and the next N rows are returned, where M and N are
2113201ed8a4Sdan# the values that the OFFSET and LIMIT clauses evaluate to,
2114201ed8a4Sdan# respectively.
2115201ed8a4Sdan#
21161b89d5d9Sdando_select_tests e_select-9.8 {
2117201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 10 OFFSET 5} {f g h i j k l m n o}
2118201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT 2+3 OFFSET 10} {k l m n o}
2119201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a
2120201ed8a4Sdan       LIMIT  (SELECT a FROM f1 WHERE b='j')
2121201ed8a4Sdan       OFFSET (SELECT a FROM f1 WHERE b='b')
2122201ed8a4Sdan     } {c d e f g h i j k l}
2123201ed8a4Sdan  4  { SELECT b FROM f1 ORDER BY a LIMIT '5' OFFSET 3.0 } {d e f g h}
2124201ed8a4Sdan  5  { SELECT b FROM f1 ORDER BY a LIMIT '5' OFFSET 0 } {a b c d e}
2125201ed8a4Sdan  6  { SELECT b FROM f1 ORDER BY a LIMIT 0 OFFSET 10 } {}
2126201ed8a4Sdan  7  { SELECT b FROM f1 ORDER BY a LIMIT 3 OFFSET '1'||'5' } {p q r}
2127201ed8a4Sdan}
2128201ed8a4Sdan
2129201ed8a4Sdan# EVIDENCE-OF: R-34648-44875 Or, if the SELECT would return less than
2130201ed8a4Sdan# M+N rows if it did not have a LIMIT clause, then the first M rows are
2131201ed8a4Sdan# skipped and the remaining rows (if any) are returned.
2132201ed8a4Sdan#
21331b89d5d9Sdando_select_tests e_select-9.9 {
2134201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 10 OFFSET 20} {u v w x y z}
2135201ed8a4Sdan  2  { SELECT a FROM f1 ORDER BY a DESC LIMIT 100 OFFSET 18+4} {4 3 2 1}
2136201ed8a4Sdan}
2137201ed8a4Sdan
2138201ed8a4Sdan
2139201ed8a4Sdan# EVIDENCE-OF: R-23293-62447 If the OFFSET clause evaluates to a
2140201ed8a4Sdan# negative value, the results are the same as if it had evaluated to
2141201ed8a4Sdan# zero.
2142201ed8a4Sdan#
21431b89d5d9Sdando_select_tests e_select-9.10 {
2144201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET -1 } {a b c d e}
2145201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET -500 } {a b c d e}
2146201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a LIMIT 5 OFFSET 0  } {a b c d e}
2147201ed8a4Sdan}
2148201ed8a4Sdan
2149201ed8a4Sdan# EVIDENCE-OF: R-19509-40356 Instead of a separate OFFSET clause, the
2150201ed8a4Sdan# LIMIT clause may specify two scalar expressions separated by a comma.
2151201ed8a4Sdan#
2152201ed8a4Sdan# EVIDENCE-OF: R-33788-46243 In this case, the first expression is used
2153201ed8a4Sdan# as the OFFSET expression and the second as the LIMIT expression.
2154201ed8a4Sdan#
21551b89d5d9Sdando_select_tests e_select-9.11 {
2156201ed8a4Sdan  1  { SELECT b FROM f1 ORDER BY a LIMIT 5, 10 } {f g h i j k l m n o}
2157201ed8a4Sdan  2  { SELECT b FROM f1 ORDER BY a LIMIT 10, 2+3 } {k l m n o}
2158201ed8a4Sdan  3  { SELECT b FROM f1 ORDER BY a
2159201ed8a4Sdan       LIMIT (SELECT a FROM f1 WHERE b='b'), (SELECT a FROM f1 WHERE b='j')
2160201ed8a4Sdan     } {c d e f g h i j k l}
2161201ed8a4Sdan  4  { SELECT b FROM f1 ORDER BY a LIMIT 3.0, '5' } {d e f g h}
2162201ed8a4Sdan  5  { SELECT b FROM f1 ORDER BY a LIMIT 0, '5' } {a b c d e}
2163201ed8a4Sdan  6  { SELECT b FROM f1 ORDER BY a LIMIT 10, 0 } {}
2164201ed8a4Sdan  7  { SELECT b FROM f1 ORDER BY a LIMIT '1'||'5', 3 } {p q r}
2165201ed8a4Sdan
2166201ed8a4Sdan  8  { SELECT b FROM f1 ORDER BY a LIMIT 20, 10 } {u v w x y z}
2167201ed8a4Sdan  9  { SELECT a FROM f1 ORDER BY a DESC LIMIT 18+4, 100 } {4 3 2 1}
2168201ed8a4Sdan
2169201ed8a4Sdan  10 { SELECT b FROM f1 ORDER BY a LIMIT -1, 5 } {a b c d e}
2170201ed8a4Sdan  11 { SELECT b FROM f1 ORDER BY a LIMIT -500, 5 } {a b c d e}
2171201ed8a4Sdan  12 { SELECT b FROM f1 ORDER BY a LIMIT 0, 5 } {a b c d e}
2172201ed8a4Sdan}
2173201ed8a4Sdan
21744ce74880Sdanfinish_test
2175