xref: /sqlite-3.40.0/test/rowvalue9.test (revision 151446e7)
127189603Sdan# 2016 September 3
227189603Sdan#
327189603Sdan# The author disclaims copyright to this source code.  In place of
427189603Sdan# a legal notice, here is a blessing:
527189603Sdan#
627189603Sdan#    May you do good and not evil.
727189603Sdan#    May you find forgiveness for yourself and forgive others.
827189603Sdan#    May you share freely, never taking more than you give.
927189603Sdan#
1027189603Sdan#***********************************************************************
1127189603Sdan# This file implements regression tests for SQLite library.  The
1227189603Sdan# focus of this file is testing SQL statements that use row value
1327189603Sdan# constructors.
1427189603Sdan#
1527189603Sdan
1627189603Sdan
1727189603Sdanset testdir [file dirname $argv0]
1827189603Sdansource $testdir/tester.tcl
1927189603Sdanset ::testprefix rowvalue9
2027189603Sdan
2183c434e6Sdan# Tests:
2283c434e6Sdan#
2383c434e6Sdan#  1.*: Test that affinities are handled correctly by various row-value
2483c434e6Sdan#       operations without indexes.
2583c434e6Sdan#
2683c434e6Sdan#  2.*: Test an affinity bug that came up during testing.
2783c434e6Sdan#
2883c434e6Sdan#  3.*: Test a row-value version of the bug tested by 2.*.
2983c434e6Sdan#
3083c434e6Sdan#  4.*: Test that affinities are handled correctly by various row-value
3183c434e6Sdan#       operations with assorted indexes.
3283c434e6Sdan#
3383c434e6Sdan
3427189603Sdando_execsql_test 1.0.1 {
3527189603Sdan  CREATE TABLE a1(c, b INTEGER, a TEXT, PRIMARY KEY(a, b));
3627189603Sdan
3727189603Sdan  INSERT INTO a1 (rowid, c, b, a) VALUES(3,  '0x03', 1, 1);
3827189603Sdan  INSERT INTO a1 (rowid, c, b, a) VALUES(14, '0x0E', 2, 2);
3927189603Sdan  INSERT INTO a1 (rowid, c, b, a) VALUES(15, '0x0F', 3, 3);
4027189603Sdan  INSERT INTO a1 (rowid, c, b, a) VALUES(92, '0x5C', 4, 4);
4127189603Sdan
4227189603Sdan  CREATE TABLE a2(x BLOB, y BLOB);
4327189603Sdan  INSERT INTO a2(x, y) VALUES(1, 1);
4427189603Sdan  INSERT INTO a2(x, y) VALUES(2, '2');
4527189603Sdan  INSERT INTO a2(x, y) VALUES('3', 3);
4627189603Sdan  INSERT INTO a2(x, y) VALUES('4', '4');
4727189603Sdan}
4827189603Sdan
4927189603Sdando_execsql_test 1.0.2 {
5027189603Sdan  SELECT x, typeof(x), y, typeof(y) FROM a2 ORDER BY rowid
5127189603Sdan} {
5227189603Sdan  1 integer 1 integer
5327189603Sdan  2 integer 2 text
5427189603Sdan  3 text    3 integer
5527189603Sdan  4 text    4 text
5627189603Sdan}
5727189603Sdan
5827189603Sdando_execsql_test 1.1.1 {
5927189603Sdan  SELECT (SELECT rowid FROM a1 WHERE a=x AND b=y) FROM a2
6027189603Sdan} {{} {} 15 92}
6127189603Sdando_execsql_test 1.1.2 {
6227189603Sdan  SELECT (SELECT rowid FROM a1 WHERE (a, b) = (x, y)) FROM a2
6327189603Sdan} {{} {} 15 92}
6427189603Sdan
6527189603Sdando_execsql_test 1.2.3 {
6627189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE a=x AND b=y;
6727189603Sdan} {15 92}
6827189603Sdando_execsql_test 1.2.4 {
6927189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE (a, b) = (x, y)
7027189603Sdan} {15 92}
7127189603Sdan
7227189603Sdan
7327189603Sdando_execsql_test 1.3.1 {
7427189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE coalesce(NULL,x)=a AND coalesce(NULL,y)=b
7527189603Sdan} {3 14 15 92}
7627189603Sdando_execsql_test 1.3.2 {
7727189603Sdan  SELECT a1.rowid FROM a1, a2
7827189603Sdan  WHERE (coalesce(NULL,x), coalesce(NULL,y)) = (a, b)
7927189603Sdan} {3 14 15 92}
8027189603Sdan
8127189603Sdando_execsql_test 1.4.1 {
8227189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE +x=a AND +y=b
8327189603Sdan} {3 14 15 92}
8427189603Sdando_execsql_test 1.4.2 {
8527189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE (+x, +y) = (a, b)
8627189603Sdan} {3 14 15 92}
8727189603Sdan
8827189603Sdando_execsql_test 1.5.1 {
8927189603Sdan  SELECT (SELECT rowid FROM a1 WHERE a=+x AND b=+y) FROM a2
9027189603Sdan} {3 14 15 92}
9127189603Sdando_execsql_test 1.5.2 {
9227189603Sdan  SELECT (SELECT rowid FROM a1 WHERE (a, b) = (+x, +y)) FROM a2
9327189603Sdan} {3 14 15 92}
9427189603Sdando_execsql_test 1.5.3 {
9527189603Sdan  SELECT (SELECT rowid FROM a1 WHERE (+x, +y) = (a, b)) FROM a2
9627189603Sdan} {3 14 15 92}
9727189603Sdan
9827189603Sdando_execsql_test 1.6.1 {
9927189603Sdan  SELECT a1.rowid FROM a1 WHERE (a, b) IN (SELECT x, y FROM a2)
10027189603Sdan} {15 92}
10127189603Sdando_execsql_test 1.6.2 {
10227189603Sdan  SELECT a1.rowid FROM a1, a2 WHERE EXISTS (
10327189603Sdan    SELECT 1 FROM a1 WHERE a=x AND b=y
10427189603Sdan  )
10527189603Sdan} {3 14 15 92 3 14 15 92}
10627189603Sdan
10780aa5453Sdan# Test that [199df416] is fixed.
10880aa5453Sdan#
10927189603Sdando_execsql_test 2.1 {
11027189603Sdan  CREATE TABLE b1(a TEXT);
11127189603Sdan  CREATE TABLE b2(x BLOB);
11227189603Sdan  INSERT INTO b1 VALUES(1);
11327189603Sdan  INSERT INTO b2 VALUES(1);
11427189603Sdan}
11527189603Sdando_execsql_test 2.2 { SELECT * FROM b1, b2 WHERE a=x; } {}
11627189603Sdando_execsql_test 2.3 { SELECT * FROM b1 WHERE a IN (SELECT x FROM b2) } {}
11780aa5453Sdando_execsql_test 2.4 { CREATE UNIQUE INDEX b1a ON b1(a); }
11827189603Sdando_execsql_test 2.5 { SELECT * FROM b1 WHERE a IN (SELECT x FROM b2) } {}
11927189603Sdan
12080aa5453Sdan# Test that a multi-column version of the query that revealed problem
12180aa5453Sdan# [199df416] also works.
12280aa5453Sdan#
12327189603Sdando_execsql_test 3.1 {
12427189603Sdan  CREATE TABLE c1(a INTEGER, b TEXT);
12527189603Sdan  INSERT INTO c1 VALUES(1, 1);
12627189603Sdan  CREATE TABLE c2(x BLOB, y BLOB);
12727189603Sdan  INSERT INTO c2 VALUES(1, 1);
12827189603Sdan}
12927189603Sdando_execsql_test 3.2 {
13027189603Sdan  SELECT * FROM c1 WHERE (a, b) IN (SELECT x, y FROM c2)
13127189603Sdan} {}
13227189603Sdando_execsql_test 3.3 {
13327189603Sdan  CREATE UNIQUE INDEX c1ab ON c1(a, b);
13427189603Sdan  SELECT * FROM c1 WHERE (a, b) IN (SELECT x, y FROM c2)
13527189603Sdan} {}
13680aa5453Sdando_execsql_test 3.4 {
13780aa5453Sdan  SELECT * FROM c1 WHERE (a, +b) IN (SELECT x, y FROM c2)
13880aa5453Sdan} {}
13927189603Sdan
14080aa5453Sdando_execsql_test 3.5 {
14180aa5453Sdan  SELECT c1.rowid FROM c1 WHERE b = (SELECT y FROM c2);
14280aa5453Sdan} {}
14380aa5453Sdando_execsql_test 3.6 {
14480aa5453Sdan  SELECT c1.rowid FROM c1 WHERE (a, b) = (SELECT x, y FROM c2);
14580aa5453Sdan} {}
14680aa5453Sdan
14780aa5453Sdan
14880aa5453Sdan#-------------------------------------------------------------------------
14980aa5453Sdan#
15027189603Sdando_execsql_test 4.0 {
15180aa5453Sdan  CREATE TABLE d1(a TEXT, b INTEGER, c NUMERIC);
15280aa5453Sdan  CREATE TABLE d2(x BLOB, y BLOB);
15327189603Sdan
15480aa5453Sdan  INSERT INTO d1 VALUES(1, 1, 1);
15580aa5453Sdan  INSERT INTO d1 VALUES(2, 2, 2);
15680aa5453Sdan  INSERT INTO d1 VALUES(3, 3, 3);
15780aa5453Sdan  INSERT INTO d1 VALUES(4, 4, 4);
15880aa5453Sdan
15980aa5453Sdan  INSERT INTO d2 VALUES (1, 1);
16080aa5453Sdan  INSERT INTO d2 VALUES (2, '2');
16180aa5453Sdan  INSERT INTO d2 VALUES ('3', 3);
16280aa5453Sdan  INSERT INTO d2 VALUES ('4', '4');
16380aa5453Sdan}
16480aa5453Sdan
16580aa5453Sdanforeach {tn idx} {
16680aa5453Sdan  1 {}
16780aa5453Sdan  2 { CREATE INDEX idx ON d1(a) }
16880aa5453Sdan  3 { CREATE INDEX idx ON d1(a, c) }
16980aa5453Sdan  4 { CREATE INDEX idx ON d1(c) }
17080aa5453Sdan  5 { CREATE INDEX idx ON d1(c, a) }
17180aa5453Sdan
17280aa5453Sdan  6 {
17380aa5453Sdan    CREATE INDEX idx ON d1(c, a) ;
17480aa5453Sdan    CREATE INDEX idx1 ON d2(x, y);
17580aa5453Sdan  }
17680aa5453Sdan
17780aa5453Sdan  7 {
17880aa5453Sdan    CREATE INDEX idx ON d1(c, a) ;
17980aa5453Sdan    CREATE UNIQUE INDEX idx2 ON d2(x, y) ;
18080aa5453Sdan  }
18180aa5453Sdan
18280aa5453Sdan  8 {
18380aa5453Sdan    CREATE INDEX idx ON d1(c) ;
18480aa5453Sdan    CREATE UNIQUE INDEX idx2 ON d2(x);
18580aa5453Sdan  }
18680aa5453Sdan
18780aa5453Sdan} {
18880aa5453Sdan  execsql { DROP INDEX IF EXISTS idx }
18980aa5453Sdan  execsql { DROP INDEX IF EXISTS idx2 }
19080aa5453Sdan  execsql { DROP INDEX IF EXISTS idx3 }
19180aa5453Sdan  execsql $idx
19280aa5453Sdan
19380aa5453Sdan  do_execsql_test 4.$tn.1 {
19480aa5453Sdan    SELECT rowid FROM d1 WHERE (a, c) IN (SELECT x, y FROM d2);
19580aa5453Sdan  } {3 4}
19680aa5453Sdan
19780aa5453Sdan  do_execsql_test 4.$tn.2 {
19880aa5453Sdan    SELECT rowid FROM d1 WHERE (c, a) IN (SELECT x, y FROM d2);
19980aa5453Sdan  } {2 4}
20080aa5453Sdan
20180aa5453Sdan  do_execsql_test 4.$tn.3 {
20280aa5453Sdan    SELECT rowid FROM d1 WHERE (+c, a) IN (SELECT x, y FROM d2);
20380aa5453Sdan  } {2}
20480aa5453Sdan
20580aa5453Sdan  do_execsql_test 4.$tn.4 {
20680aa5453Sdan    SELECT rowid FROM d1 WHERE (c, a) = (
20780aa5453Sdan      SELECT x, y FROM d2 WHERE d2.rowid=d1.rowid
20880aa5453Sdan    );
20980aa5453Sdan  } {2 4}
21080aa5453Sdan
21180aa5453Sdan  do_execsql_test 4.$tn.5 {
21280aa5453Sdan    SELECT d1.rowid FROM d1, d2 WHERE a = y;
21380aa5453Sdan  } {2 4}
21480aa5453Sdan
21580aa5453Sdan  do_execsql_test 4.$tn.6 {
21680aa5453Sdan    SELECT d1.rowid FROM d1 WHERE a = (
21780aa5453Sdan      SELECT y FROM d2 where d2.rowid=d1.rowid
21880aa5453Sdan    );
21980aa5453Sdan  } {2 4}
22080aa5453Sdan}
22127189603Sdan
22283c434e6Sdando_execsql_test 5.0 {
22383c434e6Sdan  CREATE TABLE e1(a TEXT, c NUMERIC);
22483c434e6Sdan  CREATE TABLE e2(x BLOB, y BLOB);
22583c434e6Sdan
22683c434e6Sdan  INSERT INTO e1 VALUES(2, 2);
22783c434e6Sdan
22883c434e6Sdan  INSERT INTO e2 VALUES ('2', 2);
22983c434e6Sdan  INSERT INTO e2 VALUES ('2', '2');
23083c434e6Sdan  INSERT INTO e2 VALUES ('2', '2.0');
23183c434e6Sdan
23283c434e6Sdan  CREATE INDEX e1c ON e1(c);
23383c434e6Sdan}
23483c434e6Sdan
23583c434e6Sdando_execsql_test 5.1 {
23683c434e6Sdan  SELECT rowid FROM e1 WHERE (a, c) IN (SELECT x, y FROM e2);
23783c434e6Sdan} {1}
238773d3afaSdando_execsql_test 5.2 {
239773d3afaSdan  SELECT rowid FROM e2 WHERE rowid IN (SELECT +c FROM e1);
240773d3afaSdan} {2}
241773d3afaSdando_execsql_test 5.3 {
242773d3afaSdan  SELECT rowid FROM e2 WHERE rowid IN (SELECT 0+c FROM e1);
243773d3afaSdan} {2}
24483c434e6Sdan
24526c8d0caSdan#-------------------------------------------------------------------------
24626c8d0caSdan#
24726c8d0caSdando_execsql_test 6.0 {
24826c8d0caSdan  CREATE TABLE f1(a, b);
24926c8d0caSdan  CREATE TABLE f2(c, d);
25026c8d0caSdan  CREATE TABLE f3(e, f);
25126c8d0caSdan}
25226c8d0caSdan
25326c8d0caSdando_execsql_test 6.1 {
25426c8d0caSdan  SELECT * FROM f3 WHERE (e, f) IN (
25526c8d0caSdan    SELECT a, b FROM f1 UNION ALL SELECT c, d FROM f2
25626c8d0caSdan  );
25726c8d0caSdan}
25826c8d0caSdando_execsql_test 6.2 {
25926c8d0caSdan  CREATE INDEX f3e ON f3(e);
26026c8d0caSdan  SELECT * FROM f3 WHERE (e, f) IN (
26126c8d0caSdan    SELECT a, b FROM f1 UNION ALL SELECT c, d FROM f2
26226c8d0caSdan  );
26326c8d0caSdan}
26426c8d0caSdan
26526c8d0caSdan
26626c8d0caSdan#-------------------------------------------------------------------------
26726c8d0caSdan#
26826c8d0caSdando_execsql_test 7.0 {
26926c8d0caSdan  CREATE TABLE g1(a, b);
27026c8d0caSdan  INSERT INTO g1 VALUES
27126c8d0caSdan      (1, 1), (1, 2), (1, 3), (1, 'i'), (1, 'j'),
27226c8d0caSdan      (1, 6), (1, 7), (1, 8), (1, 9), (1, 10),
27326c8d0caSdan      (1, 4), (1, 5);
27426c8d0caSdan
27526c8d0caSdan  CREATE TABLE g2(x, y);
27626c8d0caSdan  CREATE INDEX g2x ON g2(x);
27726c8d0caSdan
27826c8d0caSdan  INSERT INTO g2 VALUES(1, 4);
27926c8d0caSdan  INSERT INTO g2 VALUES(1, 5);
28026c8d0caSdan}
28126c8d0caSdan
28226c8d0caSdando_execsql_test 7.1 {
28326c8d0caSdan  SELECT * FROM g2 WHERE (x, y) IN (
28426c8d0caSdan    SELECT a, b FROM g1 ORDER BY +a, +b LIMIT 10
28526c8d0caSdan  );
28626c8d0caSdan} { 1 4 1 5 }
28726c8d0caSdan
28826c8d0caSdando_execsql_test 7.2 {
28926c8d0caSdan  SELECT * FROM g2 WHERE (x, y) IN (
29026c8d0caSdan    SELECT a, b FROM g1 ORDER BY a, b LIMIT 10
29126c8d0caSdan  );
29226c8d0caSdan} { 1 4 1 5 }
29326c8d0caSdan
29426c8d0caSdando_execsql_test 7.3 {
29526c8d0caSdan  SELECT * FROM g2 WHERE (x, y) IN (
29626c8d0caSdan    SELECT a, b FROM g1 ORDER BY 1, 2 LIMIT 10
29726c8d0caSdan  );
29826c8d0caSdan} { 1 4 1 5 }
29926c8d0caSdan
300*151446e7Sdan#-------------------------------------------------------------------------
301*151446e7Sdan#
302*151446e7Sdando_execsql_test 8.1 {
303*151446e7Sdan  CREATE TABLE t1(a ,b FLOAT);
304*151446e7Sdan  CREATE INDEX t1x1 ON t1(a,b,a,a,a,a,a,a,a,a,a,b);
305*151446e7Sdan}
306*151446e7Sdan
307*151446e7Sdando_catchsql_test 8.2 {
308*151446e7Sdan  SELECT a FROM t1 NATURAL JOIN t1 WHERE (a,b)> (SELECT 2 IN (SELECT 2,2), 2);
309*151446e7Sdan} {1 {sub-select returns 2 columns - expected 1}}
310*151446e7Sdan
31126c8d0caSdan
31227189603Sdanfinish_test
313*151446e7Sdan
314*151446e7Sdan
315