xref: /sqlite-3.40.0/test/rowvalue3.test (revision 48619160)
1ba00e30aSdan# 2016 June 17
2ba00e30aSdan#
3ba00e30aSdan# The author disclaims copyright to this source code.  In place of
4ba00e30aSdan# a legal notice, here is a blessing:
5ba00e30aSdan#
6ba00e30aSdan#    May you do good and not evil.
7ba00e30aSdan#    May you find forgiveness for yourself and forgive others.
8ba00e30aSdan#    May you share freely, never taking more than you give.
9ba00e30aSdan#
10ba00e30aSdan#***********************************************************************
11ba00e30aSdan# This file implements regression tests for SQLite library.  The
12ba00e30aSdan# focus of this file is testing "(...) IN (SELECT ...)" expressions
13ba00e30aSdan# where the SELECT statement returns more than one column.
14ba00e30aSdan#
15ba00e30aSdan
16ba00e30aSdanset testdir [file dirname $argv0]
17ba00e30aSdansource $testdir/tester.tcl
18ba00e30aSdanset ::testprefix rowvalue3
19ba00e30aSdan
20ba00e30aSdando_execsql_test 1.0 {
21ba00e30aSdan  CREATE TABLE t1(a, b, c);
22ba00e30aSdan  CREATE INDEX i1 ON t1(a, b);
23ba00e30aSdan  INSERT INTO t1 VALUES(1, 2, 3);
24ba00e30aSdan  INSERT INTO t1 VALUES(4, 5, 6);
25ba00e30aSdan  INSERT INTO t1 VALUES(7, 8, 9);
26ba00e30aSdan}
27ba00e30aSdan
28ba00e30aSdanforeach {tn sql res} {
29ba00e30aSdan  1  "SELECT 1 WHERE (4, 5) IN (SELECT a, b FROM t1)"  1
30ba00e30aSdan  2  "SELECT 1 WHERE (5, 5) IN (SELECT a, b FROM t1)"  {}
31ba00e30aSdan  3  "SELECT 1 WHERE (5, 4) IN (SELECT a, b FROM t1)"  {}
32ba00e30aSdan  4  "SELECT 1 WHERE (5, 4) IN (SELECT b, a FROM t1)"  1
33ba00e30aSdan  5  "SELECT 1 WHERE (SELECT a, b FROM t1 WHERE c=6) IN (SELECT a, b FROM t1)" 1
34ba00e30aSdan  6  "SELECT (5, 4) IN (SELECT a, b FROM t1)" 0
35ba00e30aSdan  7  "SELECT 1 WHERE (5, 4) IN (SELECT +b, +a FROM t1)"  1
36ba00e30aSdan  8  "SELECT (5, 4) IN (SELECT +b, +a FROM t1)"  1
37ba00e30aSdan  9  "SELECT (1, 2) IN (SELECT rowid, b FROM t1)"  1
38ba00e30aSdan  10 "SELECT 1 WHERE (1, 2) IN (SELECT rowid, b FROM t1)"  1
39ba00e30aSdan  11 "SELECT 1 WHERE (1, NULL) IN (SELECT rowid, b FROM t1)"  {}
40145b4ea5Sdan  12 "SELECT 1 FROM t1 WHERE (a, b) = (SELECT +a, +b FROM t1)" {1}
41ba00e30aSdan} {
42ba00e30aSdan  do_execsql_test 1.$tn $sql $res
43ba00e30aSdan}
44ba00e30aSdan
458da209b1Sdan#-------------------------------------------------------------------------
46ba00e30aSdan
478da209b1Sdando_execsql_test 2.0 {
488da209b1Sdan  CREATE TABLE z1(x, y, z);
498da209b1Sdan  CREATE TABLE kk(a, b);
50ba00e30aSdan
518da209b1Sdan  INSERT INTO z1 VALUES('a', 'b', 'c');
528da209b1Sdan  INSERT INTO z1 VALUES('d', 'e', 'f');
538da209b1Sdan  INSERT INTO z1 VALUES('g', 'h', 'i');
54ba00e30aSdan
558da209b1Sdan  -- INSERT INTO kk VALUES('y', 'y');
568da209b1Sdan  INSERT INTO kk VALUES('d', 'e');
578da209b1Sdan  -- INSERT INTO kk VALUES('x', 'x');
588da209b1Sdan
598da209b1Sdan}
608da209b1Sdan
618da209b1Sdanforeach {tn idx} {
628da209b1Sdan  1 { }
638da209b1Sdan  2 { CREATE INDEX z1idx ON z1(x, y) }
648da209b1Sdan  3 { CREATE UNIQUE INDEX z1idx ON z1(x, y) }
65d49fd4e8Sdan  4 { CREATE INDEX z1idx ON kk(a, b) }
668da209b1Sdan} {
678da209b1Sdan  execsql "DROP INDEX IF EXISTS z1idx"
688da209b1Sdan  execsql $idx
698da209b1Sdan
708da209b1Sdan  do_execsql_test 2.$tn.1 {
718da209b1Sdan    SELECT * FROM z1 WHERE x IN (SELECT a FROM kk)
728da209b1Sdan  } {d e f}
738da209b1Sdan
748da209b1Sdan  do_execsql_test 2.$tn.2 {
758da209b1Sdan    SELECT * FROM z1 WHERE (x,y) IN (SELECT a, b FROM kk)
768da209b1Sdan  } {d e f}
778da209b1Sdan
788da209b1Sdan  do_execsql_test 2.$tn.3 {
798da209b1Sdan    SELECT * FROM z1 WHERE (x, +y) IN (SELECT a, b FROM kk)
808da209b1Sdan  } {d e f}
818da209b1Sdan
828da209b1Sdan  do_execsql_test 2.$tn.4 {
838da209b1Sdan    SELECT * FROM z1 WHERE (x, +y) IN (SELECT a, b||'x' FROM kk)
848da209b1Sdan  } {}
858da209b1Sdan
868da209b1Sdan  do_execsql_test 2.$tn.5 {
878da209b1Sdan    SELECT * FROM z1 WHERE (+x, y) IN (SELECT a, b FROM kk)
888da209b1Sdan  } {d e f}
898da209b1Sdan}
908da209b1Sdan
91d49fd4e8Sdan#-------------------------------------------------------------------------
92d49fd4e8Sdan#
93d49fd4e8Sdan
94d49fd4e8Sdando_execsql_test 3.0 {
95d49fd4e8Sdan  CREATE TABLE c1(a, b, c, d);
96d49fd4e8Sdan  INSERT INTO c1(rowid, a, b) VALUES(1,   NULL, 1);
97d49fd4e8Sdan  INSERT INTO c1(rowid, a, b) VALUES(2,   2, NULL);
98d49fd4e8Sdan  INSERT INTO c1(rowid, a, b) VALUES(3,   2, 2);
99d49fd4e8Sdan  INSERT INTO c1(rowid, a, b) VALUES(4,   3, 3);
100d49fd4e8Sdan
101d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(101, 'a', 'b', 1, 1);
102d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(102, 'a', 'b', 1, 2);
103d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(103, 'a', 'b', 1, 3);
104d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(104, 'a', 'b', 2, 1);
105d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(105, 'a', 'b', 2, 2);
106d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(106, 'a', 'b', 2, 3);
107d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(107, 'a', 'b', 3, 1);
108d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(108, 'a', 'b', 3, 2);
109d49fd4e8Sdan  INSERT INTO c1(rowid, a, b, c, d) VALUES(109, 'a', 'b', 3, 3);
1108da209b1Sdan}
111ba00e30aSdan
112ba00e30aSdan
113d49fd4e8Sdanforeach {tn idx} {
114d49fd4e8Sdan  1 { }
115d49fd4e8Sdan  2 { CREATE INDEX c1ab ON c1(a, b); }
116d49fd4e8Sdan  3 { CREATE INDEX c1ba ON c1(b, a); }
117d49fd4e8Sdan
118d49fd4e8Sdan  4 { CREATE INDEX c1cd ON c1(c, d); }
119d49fd4e8Sdan  5 { CREATE INDEX c1dc ON c1(d, c); }
120d49fd4e8Sdan} {
121d49fd4e8Sdan  drop_all_indexes
122d49fd4e8Sdan
123d49fd4e8Sdan  foreach {tn2 sql res} {
124d49fd4e8Sdan    1 "SELECT (1, 2) IN (SELECT a, b FROM c1)" {0}
125d49fd4e8Sdan    2 "SELECT (1, 1) IN (SELECT a, b FROM c1)" {{}}
126d49fd4e8Sdan    3 "SELECT (2, 1) IN (SELECT a, b FROM c1)" {{}}
127d49fd4e8Sdan    4 "SELECT (2, 2) IN (SELECT a, b FROM c1)" {1}
128d49fd4e8Sdan    5 "SELECT c, d FROM c1 WHERE (c, d) IN (SELECT d, c FROM c1)"
129d49fd4e8Sdan      { 1 1 1 2 1 3   2 1 2 2 2 3   3 1 3 2 3 3 }
130d49fd4e8Sdan
131d49fd4e8Sdan    6 "SELECT c, d FROM c1 WHERE (c,d) IN (SELECT d, c FROM c1) ORDER BY c DESC"
132d49fd4e8Sdan      { 3 1 3 2 3 3   2 1 2 2 2 3   1 1 1 2 1 3 }
133d49fd4e8Sdan
134d49fd4e8Sdan    7 {
135d49fd4e8Sdan        SELECT c, d FROM c1 WHERE (c,d) IN (SELECT d, c FROM c1)
136d49fd4e8Sdan        ORDER BY c DESC, d ASC
137d49fd4e8Sdan      } { 3 1 3 2 3 3   2 1 2 2 2 3   1 1 1 2 1 3 }
138d49fd4e8Sdan
139d49fd4e8Sdan    8 {
140d49fd4e8Sdan        SELECT c, d FROM c1 WHERE (c,d) IN (SELECT d, c FROM c1)
141d49fd4e8Sdan        ORDER BY c ASC, d DESC
142d49fd4e8Sdan      } { 1 3 1 2 1 1   2 3 2 2 2 1   3 3 3 2 3 1 }
143d49fd4e8Sdan
144d49fd4e8Sdan    9 {
145d49fd4e8Sdan        SELECT c, d FROM c1 WHERE (c,d) IN (SELECT d, c FROM c1)
146d49fd4e8Sdan        ORDER BY c ASC, d ASC
147d49fd4e8Sdan      } { 1 1 1 2 1 3   2 1 2 2 2 3   3 1 3 2 3 3 }
148d49fd4e8Sdan    10 {
149d49fd4e8Sdan        SELECT c, d FROM c1 WHERE (c,d) IN (SELECT d, c FROM c1)
150d49fd4e8Sdan        ORDER BY c DESC, d DESC
151d49fd4e8Sdan      } { 3 3 3 2 3 1   2 3 2 2 2 1   1 3 1 2 1 1 }
152d49fd4e8Sdan
153d49fd4e8Sdan  } {
154d49fd4e8Sdan    do_execsql_test 3.$tn.$tn2 $sql $res
155d49fd4e8Sdan  }
156d49fd4e8Sdan}
157d49fd4e8Sdan
158d49fd4e8Sdan#-------------------------------------------------------------------------
159d49fd4e8Sdan
160d49fd4e8Sdando_execsql_test 4.0 {
161d49fd4e8Sdan  CREATE TABLE hh(a, b, c);
162d49fd4e8Sdan
163d49fd4e8Sdan  INSERT INTO hh VALUES('a', 'a', 1);
164d49fd4e8Sdan  INSERT INTO hh VALUES('a', 'b', 2);
165d49fd4e8Sdan  INSERT INTO hh VALUES('b', 'a', 3);
166d49fd4e8Sdan  INSERT INTO hh VALUES('b', 'b', 4);
167d49fd4e8Sdan
168d49fd4e8Sdan  CREATE TABLE k1(x, y);
169d49fd4e8Sdan  INSERT INTO k1 VALUES('a', 'a');
170d49fd4e8Sdan  INSERT INTO k1 VALUES('b', 'b');
171d49fd4e8Sdan  INSERT INTO k1 VALUES('a', 'b');
172d49fd4e8Sdan  INSERT INTO k1 VALUES('b', 'a');
173d49fd4e8Sdan}
174d49fd4e8Sdan
175d49fd4e8Sdanforeach {tn idx} {
176d49fd4e8Sdan  1 { }
177d49fd4e8Sdan  2 { CREATE INDEX h1 ON hh(a, b); }
178d49fd4e8Sdan  3 { CREATE UNIQUE INDEX k1idx ON k1(x, y) }
179d49fd4e8Sdan  4 { CREATE UNIQUE INDEX k1idx ON k1(x, y DESC) }
180d49fd4e8Sdan  5 {
181d49fd4e8Sdan    CREATE INDEX h1 ON hh(a, b);
182d49fd4e8Sdan    CREATE UNIQUE INDEX k1idx ON k1(x, y);
183d49fd4e8Sdan  }
184d49fd4e8Sdan  6 {
185d49fd4e8Sdan    CREATE INDEX h1 ON hh(a, b);
186d49fd4e8Sdan    CREATE UNIQUE INDEX k1idx ON k1(x, y DESC);
187d49fd4e8Sdan  }
188d49fd4e8Sdan} {
189d49fd4e8Sdan  drop_all_indexes
190d49fd4e8Sdan  execsql $idx
191d49fd4e8Sdan  foreach {tn2 orderby res} {
192d49fd4e8Sdan    1 "a ASC, b ASC"  {1 2 3 4}
193d49fd4e8Sdan    2 "a ASC, b DESC" {2 1 4 3}
194d49fd4e8Sdan    3 "a DESC, b ASC" {3 4 1 2}
195d49fd4e8Sdan    4 "a DESC, b DESC" {4 3 2 1}
196d49fd4e8Sdan  } {
197d49fd4e8Sdan    do_execsql_test 4.$tn.$tn2 "
198d49fd4e8Sdan      SELECT c FROM hh WHERE (a, b) in (SELECT x, y FROM k1) ORDER BY $orderby
199d49fd4e8Sdan    " $res
200d49fd4e8Sdan  }
201d49fd4e8Sdan}
202d49fd4e8Sdan
203145b4ea5Sdan#-------------------------------------------------------------------------
204145b4ea5Sdan
20554cda4edSdrh# 2016-11-17.  Query flattening in a vector SELECT on the RHS of an IN
20654cda4edSdrh# operator.  Ticket https://www.sqlite.org/src/info/da7841375186386c
20754cda4edSdrh#
20854cda4edSdrhdo_execsql_test 5.0 {
20954cda4edSdrh  DROP TABLE IF EXISTS t1;
21054cda4edSdrh  DROP TABLE IF EXISTS t2;
21154cda4edSdrh  CREATE TABLE T1(a TEXT);
21254cda4edSdrh  INSERT INTO T1(a) VALUES ('aaa');
21354cda4edSdrh  CREATE TABLE T2(a TEXT PRIMARY KEY,n INT);
21454cda4edSdrh  INSERT INTO T2(a, n) VALUES('aaa',0);
21554cda4edSdrh  SELECT * FROM T2
216*48619160Sdrh   WHERE (a,n) IN (SELECT T1.a, V.n
217*48619160Sdrh                     FROM T1, (SELECT * FROM (SELECT 0 n) T3) V);
21854cda4edSdrh} {aaa 0}
21954cda4edSdrh
220d49fd4e8Sdan
221d49fd4e8Sdanfinish_test
222