xref: /sqlite-3.40.0/test/rowvalue4.test (revision 8210233c)
17b35a77bSdan# 2016 July 29
27b35a77bSdan#
37b35a77bSdan# The author disclaims copyright to this source code.  In place of
47b35a77bSdan# a legal notice, here is a blessing:
57b35a77bSdan#
67b35a77bSdan#    May you do good and not evil.
77b35a77bSdan#    May you find forgiveness for yourself and forgive others.
87b35a77bSdan#    May you share freely, never taking more than you give.
97b35a77bSdan#
107b35a77bSdan#***********************************************************************
117b35a77bSdan# This file implements regression tests for SQLite library.  The
127b35a77bSdan# focus of this file is syntax errors involving row-value constructors
137b35a77bSdan# and sub-selects that return multiple arguments.
147b35a77bSdan#
157b35a77bSdan
167b35a77bSdanset testdir [file dirname $argv0]
177b35a77bSdansource $testdir/tester.tcl
187b35a77bSdanset ::testprefix rowvalue4
197b35a77bSdan
20d05a7144Sdan#-------------------------------------------------------------------------
21d05a7144Sdan# Test some error conditions:
22d05a7144Sdan#
23d05a7144Sdan#   * row values used where they are not supported,
24d05a7144Sdan#   * row values or sub-selects that contain/return the wrong number
25d05a7144Sdan#     of elements.
26d05a7144Sdan#
27d05a7144Sdando_execsql_test 1.0 {
287b35a77bSdan  CREATE TABLE t1(a, b, c);
297b35a77bSdan  CREATE INDEX t1bac ON t1(b, a, c);
307b35a77bSdan}
317b35a77bSdan
327b35a77bSdanforeach {tn e} {
337b35a77bSdan  1 "(1, 2, 3)"
347b35a77bSdan  2 "1 + (1, 2)"
357b35a77bSdan  3 "(1,2,3) == (1, 2)"
367b35a77bSdan} {
37e835bc12Sdrh  do_catchsql_test 1.$tn "SELECT $e" {1 {row value misused}}
387b35a77bSdan}
397b35a77bSdan
407b35a77bSdanforeach {tn s error} {
41e835bc12Sdrh  1 "SELECT * FROM t1 WHERE a = (1, 2)"       {row value misused}
42e835bc12Sdrh  2 "SELECT * FROM t1 WHERE b = (1, 2)"       {row value misused}
43e835bc12Sdrh  3 "SELECT * FROM t1 WHERE NOT (b = (1, 2))" {row value misused}
44e835bc12Sdrh  4 "SELECT * FROM t1 LIMIT (1, 2)"           {row value misused}
457b35a77bSdan  5 "SELECT (a, b) IN (SELECT * FROM t1) FROM t1"
467b35a77bSdan                             {sub-select returns 3 columns - expected 2}
477b35a77bSdan
487b35a77bSdan  6 "SELECT * FROM t1 WHERE (a, b) IN (SELECT * FROM t1)"
497b35a77bSdan                             {sub-select returns 3 columns - expected 2}
505c3340bdSdan  7 "SELECT * FROM t1 WHERE (c, c) <= 1" {row value misused}
515c3340bdSdan  8 "SELECT * FROM t1 WHERE (b, b) <= 1" {row value misused}
527b35a77bSdan} {
537b35a77bSdan  do_catchsql_test 2.$tn "$s" [list 1 $error]
547b35a77bSdan}
557b35a77bSdan
56d05a7144Sdan#-------------------------------------------------------------------------
57d05a7144Sdando_execsql_test 2.0 {
58d05a7144Sdan  CREATE TABLE t2(a, b, c, d);
59d05a7144Sdan  INSERT INTO t2 VALUES(1, 1, 1,   1);
60d05a7144Sdan  INSERT INTO t2 VALUES(1, 1, 2,   2);
61d05a7144Sdan  INSERT INTO t2 VALUES(1, 1, 3,   3);
62d05a7144Sdan  INSERT INTO t2 VALUES(1, 2, 1,   4);
63d05a7144Sdan  INSERT INTO t2 VALUES(1, 2, 2,   5);
64d05a7144Sdan  INSERT INTO t2 VALUES(1, 2, 3,   6);
65d05a7144Sdan  INSERT INTO t2 VALUES(1, 3, 1,   7);
66d05a7144Sdan  INSERT INTO t2 VALUES(1, 3, 2,   8);
67d05a7144Sdan  INSERT INTO t2 VALUES(1, 3, 3,   9);
68d05a7144Sdan
69d05a7144Sdan  INSERT INTO t2 VALUES(2, 1, 1,   10);
70d05a7144Sdan  INSERT INTO t2 VALUES(2, 1, 2,   11);
71d05a7144Sdan  INSERT INTO t2 VALUES(2, 1, 3,   12);
72d05a7144Sdan  INSERT INTO t2 VALUES(2, 2, 1,   13);
73d05a7144Sdan  INSERT INTO t2 VALUES(2, 2, 2,   14);
74d05a7144Sdan  INSERT INTO t2 VALUES(2, 2, 3,   15);
75d05a7144Sdan  INSERT INTO t2 VALUES(2, 3, 1,   16);
76d05a7144Sdan  INSERT INTO t2 VALUES(2, 3, 2,   17);
77d05a7144Sdan  INSERT INTO t2 VALUES(2, 3, 3,   18);
78d05a7144Sdan
79d05a7144Sdan  INSERT INTO t2 VALUES(3, 1, 1,   19);
80d05a7144Sdan  INSERT INTO t2 VALUES(3, 1, 2,   20);
81d05a7144Sdan  INSERT INTO t2 VALUES(3, 1, 3,   21);
82d05a7144Sdan  INSERT INTO t2 VALUES(3, 2, 1,   22);
83d05a7144Sdan  INSERT INTO t2 VALUES(3, 2, 2,   23);
84d05a7144Sdan  INSERT INTO t2 VALUES(3, 2, 3,   24);
85d05a7144Sdan  INSERT INTO t2 VALUES(3, 3, 1,   25);
86d05a7144Sdan  INSERT INTO t2 VALUES(3, 3, 2,   26);
87d05a7144Sdan  INSERT INTO t2 VALUES(3, 3, 3,   27);
88d05a7144Sdan}
89d05a7144Sdan
90d05a7144Sdanforeach {nm idx} {
91d05a7144Sdan  idx1 {}
92d05a7144Sdan  idx2 { CREATE INDEX t2abc ON t2(a, b, c); }
93d05a7144Sdan  idx3 { CREATE INDEX t2abc ON t2(a, b DESC, c); }
94d05a7144Sdan  idx4 { CREATE INDEX t2abc ON t2(a DESC, b DESC, c DESC); }
95d05a7144Sdan  idx5 { CREATE INDEX t2abc ON t2(a ASC, b ASC, c ASC); }
96d05a7144Sdan  idx6 { CREATE INDEX t2abc ON t2(a DESC, b, c); }
9751d82d1dSdan  idx7 { CREATE INDEX t2abc ON t2(a DESC, b DESC) }
9851d82d1dSdan  idx8 { CREATE INDEX t2abc ON t2(c, b, a); }
9951d82d1dSdan  idx9 { CREATE INDEX t2d ON t2(d); }
1002c628ea9Sdan  idx10 { CREATE INDEX t2abc ON t2(a DESC, b, c DESC); }
101d05a7144Sdan} {
102d05a7144Sdan  drop_all_indexes
103d05a7144Sdan  execsql $idx
104d05a7144Sdan
105d05a7144Sdan  foreach {tn where res} {
106d05a7144Sdan    1 "(a, b, c) < (2, 2, 2)"  {1 2 3 4 5 6 7 8 9 10 11 12 13}
107d05a7144Sdan    2 "(a, b, c) <= (2, 2, 2)" {1 2 3 4 5 6 7 8 9 10 11 12 13 14}
108d05a7144Sdan    3 "(a, b, c) > (2, 2, 2)"  {15 16 17 18 19 20 21 22 23 24 25 26 27}
109d05a7144Sdan    4 "(a, b, c) >= (2, 2, 2)" {14 15 16 17 18 19 20 21 22 23 24 25 26 27}
11051d82d1dSdan    5 "(a, b, c) >= (2, 2, NULL)" {16 17 18 19 20 21 22 23 24 25 26 27}
11151d82d1dSdan    6 "(a, b, c) <= (2, 2, NULL)" {1 2 3 4 5 6 7 8 9 10 11 12}
11251d82d1dSdan    7 "(a, b, c) >= (2, NULL, NULL)" {19 20 21 22 23 24 25 26 27}
11351d82d1dSdan    8 "(a, b, c) <= (2, NULL, NULL)" {1 2 3 4 5 6 7 8 9}
11451d82d1dSdan
11551d82d1dSdan    9 "(a, b, c) < (SELECT a, b, c FROM t2 WHERE d=14)"
11651d82d1dSdan      {1 2 3 4 5 6 7 8 9 10 11 12 13}
11751d82d1dSdan
11851d82d1dSdan    10 "(a, b, c) = (SELECT a, b, c FROM t2 WHERE d=14)" 14
1192c628ea9Sdan
1202c628ea9Sdan    11 "a = 2 AND (b, c) > (2, 2)" {15 16 17 18}
1212c628ea9Sdan    12 "a = 2 AND (b, c) < (3, 3) AND (b, c) > (1, 1)" {11 12 13 14 15 16 17}
122d05a7144Sdan  } {
123d05a7144Sdan    set result [db eval "SELECT d FROM t2 WHERE $where"]
12451d82d1dSdan    do_test 2.1.$nm.$tn { lsort -integer $result } $res
12551d82d1dSdan  }
12651d82d1dSdan
12751d82d1dSdan  foreach {tn e res} {
12851d82d1dSdan    1 "(2, 1) IN (SELECT a, b FROM t2)" 1
12951d82d1dSdan    2 "(2, 1) IN (SELECT a, b FROM t2 ORDER BY d)" 1
13051d82d1dSdan    3 "(2, 1) IN (SELECT a, b FROM t2 ORDER BY d LIMIT 9)" 0
13151d82d1dSdan    4 "(2, 1) IN (SELECT a, b FROM t2 ORDER BY d LIMIT 10)" 1
13251d82d1dSdan
13351d82d1dSdan    5 "(3, 3) = (SELECT a, b FROM t2 ORDER BY d DESC LIMIT 1)" 1
13451d82d1dSdan    6 "(3, 3) = (SELECT a, b FROM t2 ORDER BY d ASC LIMIT 1)" 0
13551d82d1dSdan    7 "(1, NULL) = (SELECT a, b FROM t2 ORDER BY d ASC LIMIT 1)" {{}}
13651d82d1dSdan
13751d82d1dSdan    8 "(3, 1) = (SELECT b, c FROM t2 ORDER BY d DESC LIMIT 1 OFFSET 2)" 1
13851d82d1dSdan    9 "(3, 1) = (SELECT b, c FROM t2 ORDER BY d ASC LIMIT 1 OFFSET 2)" 0
13951d82d1dSdan    10 "(1, NULL) = (SELECT b, c FROM t2 ORDER BY d ASC LIMIT 1 OFFSET 2)" {{}}
14051d82d1dSdan
14151d82d1dSdan    11 "(3, 3) = (SELECT max(a), max(b) FROM t2)" 1
14251d82d1dSdan    12 "(3, 1) = (SELECT max(a), min(b) FROM t2)" 1
14351d82d1dSdan    13 "(NULL, NULL) = (SELECT max(a), min(b) FROM t2)" {{}}
14451d82d1dSdan
14551d82d1dSdan    14 "(2, 1) IN (SELECT a, b FROM t2 ORDER BY d LIMIT 5 OFFSET 11)" 1
14651d82d1dSdan    15 "(2, 1) IN (SELECT a, b FROM t2 ORDER BY d LIMIT 5 OFFSET 12)" 0
14751d82d1dSdan  } {
14851d82d1dSdan    do_execsql_test 2.2.$nm.$tn "SELECT $e" $res
149d05a7144Sdan  }
150d05a7144Sdan}
15151d82d1dSdan
152d66e5794Sdanifcapable stat4 {
153d66e5794Sdan  do_execsql_test 3.0 {
154d66e5794Sdan    CREATE TABLE c1(a, b, c, d);
155d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'a');
156d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'b');
157d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'c');
158d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'd');
159d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'e');
160d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'f');
161d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'g');
162d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'h');
163d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'i');
164d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'j');
165d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'k');
166d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'l');
167d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'm');
168d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'n');
169d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'o');
170d66e5794Sdan    INSERT INTO c1(a, b) VALUES(1, 'p');
171d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'a');
172d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'b');
173d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'c');
174d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'd');
175d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'e');
176d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'f');
177d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'g');
178d66e5794Sdan    INSERT INTO c1(a, b) VALUES(2, 'h');
179d66e5794Sdan
180d66e5794Sdan    INSERT INTO c1(c, d) SELECT a, b FROM c1;
181d66e5794Sdan
182d66e5794Sdan    CREATE INDEX c1ab ON c1(a, b);
183d66e5794Sdan    CREATE INDEX c1cd ON c1(c, d);
184d66e5794Sdan    ANALYZE;
185d66e5794Sdan  }
186d66e5794Sdan
187b3f0276bSdrh  do_eqp_test 3.1.1 { SELECT * FROM c1 WHERE a=1 AND c=2 } \
188*8210233cSdrh     {SEARCH c1 USING INDEX c1cd (c=?)}
189d66e5794Sdan
190b3f0276bSdrh  do_eqp_test 3.1.2 { SELECT * FROM c1 WHERE a=1 AND b>'d' AND c=2 } \
191*8210233cSdrh     {SEARCH c1 USING INDEX c1cd (c=?)}
192b3f0276bSdrh
193b3f0276bSdrh  do_eqp_test 3.1.3 { SELECT * FROM c1 WHERE a=1 AND b>'l' AND c=2 } \
194*8210233cSdrh     {SEARCH c1 USING INDEX c1ab (a=? AND b>?)}
195b3f0276bSdrh
196b3f0276bSdrh  do_eqp_test 3.2.1 { SELECT * FROM c1 WHERE a=1 AND c>1 } \
197*8210233cSdrh     {SEARCH c1 USING INDEX c1cd (c>?)}
198b3f0276bSdrh
199b3f0276bSdrh  do_eqp_test 3.2.2 { SELECT * FROM c1 WHERE a=1 AND c>0 } \
200*8210233cSdrh     {SEARCH c1 USING INDEX c1ab (a=?)}
201b3f0276bSdrh
202b3f0276bSdrh  do_eqp_test 3.2.3 { SELECT * FROM c1 WHERE a=1 AND c>=1 } \
203*8210233cSdrh     {SEARCH c1 USING INDEX c1ab (a=?)}
204b3f0276bSdrh
205b3f0276bSdrh  do_eqp_test 3.2.4 { SELECT * FROM c1 WHERE a=1 AND (c, d)>(1, 'c') } \
206*8210233cSdrh     {SEARCH c1 USING INDEX c1ab (a=?)}
207b3f0276bSdrh
208b3f0276bSdrh  do_eqp_test 3.2.5 { SELECT * FROM c1 WHERE a=1 AND (c, d)>(1, 'o') } \
209*8210233cSdrh     {SEARCH c1 USING INDEX c1cd ((c,d)>(?,?))}
210b3f0276bSdrh
211b3f0276bSdrh  do_eqp_test 3.2.6 { SELECT * FROM c1 WHERE a=1 AND (c, +b)>(1, 'c') } \
212*8210233cSdrh     {SEARCH c1 USING INDEX c1ab (a=?)}
213b3f0276bSdrh
214d66e5794Sdan}
21551d82d1dSdan
2163d1fb1ddSdan#------------------------------------------------------------------------
2173d1fb1ddSdan
2183d1fb1ddSdando_execsql_test 5.0 {
2193d1fb1ddSdan  CREATE TABLE d1(x, y);
2203d1fb1ddSdan  CREATE TABLE d2(a, b, c);
2213d1fb1ddSdan  CREATE INDEX d2ab ON d2(a, b);
2223d1fb1ddSdan  CREATE INDEX d2c ON d2(c);
2233d1fb1ddSdan
2243d1fb1ddSdan  WITH i(i) AS (
2253d1fb1ddSdan    VALUES(1) UNION ALL SELECT i+1 FROM i WHERE i<1000
2263d1fb1ddSdan  )
2276d6decb8Sdrh  INSERT INTO d2 SELECT i/100, i%100, i/100 FROM i;
2283d1fb1ddSdan  ANALYZE;
2293d1fb1ddSdan}
2303d1fb1ddSdan
2313d1fb1ddSdando_eqp_test 5.1 {
2323d1fb1ddSdan  SELECT * FROM d2 WHERE
2333d1fb1ddSdan    (a, b) IN (SELECT x, y FROM d1) AND
2343d1fb1ddSdan    (c) IN (SELECT y FROM d1)
2353d1fb1ddSdan} {
236b3f0276bSdrh  QUERY PLAN
237*8210233cSdrh  |--SEARCH d2 USING INDEX d2ab (a=? AND b=?)
2385198ff57Sdrh  |--LIST SUBQUERY xxxxxx
239*8210233cSdrh  |  `--SCAN d1
2405198ff57Sdrh  `--LIST SUBQUERY xxxxxx
241*8210233cSdrh     `--SCAN d1
2423d1fb1ddSdan}
2433d1fb1ddSdan
2441d9bc9b7Sdando_execsql_test 6.0 {
2451d9bc9b7Sdan  CREATE TABLE e1(a, b, c, d, e);
2461d9bc9b7Sdan  CREATE INDEX e1ab ON e1(a, b);
2471d9bc9b7Sdan  CREATE INDEX e1cde ON e1(c, d, e);
2481d9bc9b7Sdan}
2491d9bc9b7Sdan
2501d9bc9b7Sdando_eqp_test 6.1 {
2511d9bc9b7Sdan  SELECT * FROM e1 WHERE (a, b) > (?, ?)
252*8210233cSdrh} {SEARCH e1 USING INDEX e1ab ((a,b)>(?,?))}
253b3f0276bSdrh
2541d9bc9b7Sdando_eqp_test 6.2 {
2551d9bc9b7Sdan  SELECT * FROM e1 WHERE (a, b) < (?, ?)
256*8210233cSdrh} {SEARCH e1 USING INDEX e1ab ((a,b)<(?,?))}
257b3f0276bSdrh
2581d9bc9b7Sdando_eqp_test 6.3 {
2591d9bc9b7Sdan  SELECT * FROM e1 WHERE c = ? AND (d, e) > (?, ?)
260*8210233cSdrh} {SEARCH e1 USING INDEX e1cde (c=? AND (d,e)>(?,?))}
261b3f0276bSdrh
2621d9bc9b7Sdando_eqp_test 6.4 {
2631d9bc9b7Sdan  SELECT * FROM e1 WHERE c = ? AND (d, e) < (?, ?)
264*8210233cSdrh} {SEARCH e1 USING INDEX e1cde (c=? AND (d,e)<(?,?))}
2651d9bc9b7Sdan
2661d9bc9b7Sdando_eqp_test 6.5 {
2671d9bc9b7Sdan  SELECT * FROM e1 WHERE (d, e) BETWEEN (?, ?) AND (?, ?) AND c = ?
268*8210233cSdrh} {SEARCH e1 USING INDEX e1cde (c=? AND (d,e)>(?,?) AND (d,e)<(?,?))}
2691d9bc9b7Sdan
27017994e3bSdan#-------------------------------------------------------------------------
27117994e3bSdan
27217994e3bSdando_execsql_test 7.1 {
27317994e3bSdan  CREATE TABLE f1(a, b, c);
27417994e3bSdan  CREATE INDEX f1ab ON f1(a, b);
27517994e3bSdan}
27617994e3bSdan
27717994e3bSdando_catchsql_test 7.2 {
27817994e3bSdan  SELECT (a COLLATE nocase, b) IN (SELECT a, b FROM f1) FROM f1;
27917994e3bSdan} {0 {}}
28017994e3bSdan
28117994e3bSdando_catchsql_test 7.3 {
28217994e3bSdan  SELECT (a COLLATE nose, b) IN (SELECT a, b FROM f1) FROM f1;
28317994e3bSdan} {1 {no such collation sequence: nose}}
28417994e3bSdan
28517994e3bSdando_catchsql_test 7.4 {
28617994e3bSdan  SELECT * FROM f1 WHERE (?, ? COLLATE nose) > (a, b);
28717994e3bSdan} {1 {no such collation sequence: nose}}
2883d1fb1ddSdan
289f358009aSdan#-------------------------------------------------------------------------
290f358009aSdandrop_all_tables
291f358009aSdando_execsql_test 8.1 {
292f358009aSdan  CREATE TABLE c1(x, y);
293f358009aSdan  CREATE TABLE c2(a, b, c);
294f358009aSdan  CREATE INDEX c2ab ON c2(a, b);
295f358009aSdan  CREATE INDEX c2c ON c2(c);
296f358009aSdan
297f358009aSdan  CREATE TABLE c3(d);
298f358009aSdan}
299f358009aSdando_catchsql_test 8.2 {
300f358009aSdan  SELECT * FROM c2 CROSS JOIN c3 WHERE
301f358009aSdan    ( (a, b) == (SELECT x, y FROM c1) AND c3.d = c ) OR
302f358009aSdan    ( c == (SELECT x, y FROM c1) AND c3.d = c )
303b29e60c4Sdrh} {1 {row value misused}}
304f358009aSdan
3057b35a77bSdanfinish_test
306