xref: /sqlite-3.40.0/test/distinct2.test (revision 40386968)
18489bf5aSdrh# 2016-04-15
28489bf5aSdrh#
38489bf5aSdrh# The author disclaims copyright to this source code.  In place of
48489bf5aSdrh# a legal notice, here is a blessing:
58489bf5aSdrh#
68489bf5aSdrh#    May you do good and not evil.
78489bf5aSdrh#    May you find forgiveness for yourself and forgive others.
88489bf5aSdrh#    May you share freely, never taking more than you give.
98489bf5aSdrh#
108489bf5aSdrh#***********************************************************************
118489bf5aSdrh# This file implements regression tests for SQLite library.  The
128489bf5aSdrh# focus of this script is DISTINCT queries using the skip-ahead
138489bf5aSdrh# optimization.
148489bf5aSdrh#
158489bf5aSdrh
168489bf5aSdrhset testdir [file dirname $argv0]
178489bf5aSdrhsource $testdir/tester.tcl
188489bf5aSdrh
198489bf5aSdrhset testprefix distinct2
208489bf5aSdrh
218489bf5aSdrhdo_execsql_test 100 {
228489bf5aSdrh  CREATE TABLE t1(x INTEGER PRIMARY KEY);
238489bf5aSdrh  INSERT INTO t1 VALUES(0),(1),(2);
248489bf5aSdrh  CREATE TABLE t2 AS
258489bf5aSdrh     SELECT DISTINCT a.x AS aa, b.x AS bb
268489bf5aSdrh      FROM t1 a, t1 b;
278489bf5aSdrh  SELECT *, '|' FROM t2 ORDER BY aa, bb;
288489bf5aSdrh} {0 0 | 0 1 | 0 2 | 1 0 | 1 1 | 1 2 | 2 0 | 2 1 | 2 2 |}
298489bf5aSdrhdo_execsql_test 110 {
308489bf5aSdrh  DROP TABLE t2;
318489bf5aSdrh  CREATE TABLE t2 AS
328489bf5aSdrh     SELECT DISTINCT a.x AS aa, b.x AS bb
338489bf5aSdrh       FROM t1 a, t1 b
348489bf5aSdrh      WHERE a.x IN t1 AND b.x IN t1;
358489bf5aSdrh  SELECT *, '|' FROM t2 ORDER BY aa, bb;
368489bf5aSdrh} {0 0 | 0 1 | 0 2 | 1 0 | 1 1 | 1 2 | 2 0 | 2 1 | 2 2 |}
378489bf5aSdrhdo_execsql_test 120 {
388489bf5aSdrh  CREATE TABLE t102 (i0 TEXT UNIQUE NOT NULL);
398489bf5aSdrh  INSERT INTO t102 VALUES ('0'),('1'),('2');
408489bf5aSdrh  DROP TABLE t2;
418489bf5aSdrh  CREATE TABLE t2 AS
428489bf5aSdrh    SELECT DISTINCT *
438489bf5aSdrh    FROM t102 AS t0
448489bf5aSdrh    JOIN t102 AS t4 ON (t2.i0 IN t102)
458489bf5aSdrh    NATURAL JOIN t102 AS t3
468489bf5aSdrh    JOIN t102 AS t1 ON (t0.i0 IN t102)
478489bf5aSdrh    JOIN t102 AS t2 ON (t2.i0=+t0.i0 OR (t0.i0<>500 AND t2.i0=t1.i0));
488489bf5aSdrh  SELECT *, '|' FROM t2 ORDER BY 1, 2, 3, 4, 5;
498489bf5aSdrh} {0 0 0 0 | 0 0 1 0 | 0 0 1 1 | 0 0 2 0 | 0 0 2 2 | 0 1 0 0 | 0 1 1 0 | 0 1 1 1 | 0 1 2 0 | 0 1 2 2 | 0 2 0 0 | 0 2 1 0 | 0 2 1 1 | 0 2 2 0 | 0 2 2 2 | 1 0 0 0 | 1 0 0 1 | 1 0 1 1 | 1 0 2 1 | 1 0 2 2 | 1 1 0 0 | 1 1 0 1 | 1 1 1 1 | 1 1 2 1 | 1 1 2 2 | 1 2 0 0 | 1 2 0 1 | 1 2 1 1 | 1 2 2 1 | 1 2 2 2 | 2 0 0 0 | 2 0 0 2 | 2 0 1 1 | 2 0 1 2 | 2 0 2 2 | 2 1 0 0 | 2 1 0 2 | 2 1 1 1 | 2 1 1 2 | 2 1 2 2 | 2 2 0 0 | 2 2 0 2 | 2 2 1 1 | 2 2 1 2 | 2 2 2 2 |}
508489bf5aSdrh
518489bf5aSdrhdo_execsql_test 400 {
528489bf5aSdrh  CREATE TABLE t4(a,b,c,d,e,f,g,h,i,j);
538489bf5aSdrh  INSERT INTO t4 VALUES(0,1,2,3,4,5,6,7,8,9);
548489bf5aSdrh  INSERT INTO t4 SELECT * FROM t4;
558489bf5aSdrh  INSERT INTO t4 SELECT * FROM t4;
568489bf5aSdrh  CREATE INDEX t4x ON t4(c,d,e);
578489bf5aSdrh  SELECT DISTINCT a,b,c FROM t4 WHERE a=0 AND b=1;
588489bf5aSdrh} {0 1 2}
598489bf5aSdrhdo_execsql_test 410 {
608489bf5aSdrh  SELECT DISTINCT a,b,c,d FROM t4 WHERE a=0 AND b=1;
618489bf5aSdrh} {0 1 2 3}
628489bf5aSdrhdo_execsql_test 411 {
638489bf5aSdrh  SELECT DISTINCT d,a,b,c FROM t4 WHERE a=0 AND b=1;
648489bf5aSdrh} {3 0 1 2}
658489bf5aSdrhdo_execsql_test 420 {
668489bf5aSdrh  SELECT DISTINCT a,b,c,d,e FROM t4 WHERE a=0 AND b=1;
678489bf5aSdrh} {0 1 2 3 4}
688489bf5aSdrhdo_execsql_test 430 {
698489bf5aSdrh  SELECT DISTINCT a,b,c,d,e,f FROM t4 WHERE a=0 AND b=1;
708489bf5aSdrh} {0 1 2 3 4 5}
718489bf5aSdrh
728489bf5aSdrhdo_execsql_test 500 {
738489bf5aSdrh  CREATE TABLE t5(a INT, b INT);
748489bf5aSdrh  CREATE UNIQUE INDEX t5x ON t5(a+b);
758489bf5aSdrh  INSERT INTO t5(a,b) VALUES(0,0),(1,0),(1,1),(0,3);
768489bf5aSdrh  CREATE TEMP TABLE out AS SELECT DISTINCT a+b FROM t5;
778489bf5aSdrh  SELECT * FROM out ORDER BY 1;
788489bf5aSdrh} {0 1 2 3}
798489bf5aSdrh
808489bf5aSdrhdo_execsql_test 600 {
818489bf5aSdrh  CREATE TABLE t6a(x INTEGER PRIMARY KEY);
828489bf5aSdrh  INSERT INTO t6a VALUES(1);
838489bf5aSdrh  CREATE TABLE t6b(y INTEGER PRIMARY KEY);
848489bf5aSdrh  INSERT INTO t6b VALUES(2),(3);
858489bf5aSdrh  SELECT DISTINCT x, x FROM t6a, t6b;
868489bf5aSdrh} {1 1}
878489bf5aSdrh
88a74f5c29Sdando_execsql_test 700 {
89a74f5c29Sdan  CREATE TABLE t7(a, b, c);
90a74f5c29Sdan  WITH s(i) AS (
91a74f5c29Sdan    SELECT 1 UNION ALL SELECT i+1 FROM s WHERE (i+1)<200
92a74f5c29Sdan  )
93a74f5c29Sdan  INSERT INTO t7 SELECT i/100, i/50, i FROM s;
94a74f5c29Sdan}
95a74f5c29Sdando_execsql_test 710 {
96a74f5c29Sdan  SELECT DISTINCT a, b FROM t7;
97a74f5c29Sdan} {
98a74f5c29Sdan  0 0    0 1
99a74f5c29Sdan  1 2    1 3
100a74f5c29Sdan}
101a74f5c29Sdando_execsql_test 720 {
102a74f5c29Sdan  SELECT DISTINCT a, b+1 FROM t7;
103a74f5c29Sdan} {
104a74f5c29Sdan  0 1    0 2
105a74f5c29Sdan  1 3    1 4
106a74f5c29Sdan}
107a74f5c29Sdando_execsql_test 730 {
108a74f5c29Sdan  CREATE INDEX i7 ON t7(a, b+1);
109a74f5c29Sdan  ANALYZE;
110a74f5c29Sdan  SELECT DISTINCT a, b+1 FROM t7;
111a74f5c29Sdan} {
112a74f5c29Sdan  0 1    0 2
113a74f5c29Sdan  1 3    1 4
114a74f5c29Sdan}
115a74f5c29Sdan
116a74f5c29Sdando_execsql_test 800 {
117a74f5c29Sdan  CREATE TABLE t8(a, b, c);
118a74f5c29Sdan  WITH s(i) AS (
119a74f5c29Sdan    SELECT 1 UNION ALL SELECT i+1 FROM s WHERE (i+1)<100
120a74f5c29Sdan  )
121a74f5c29Sdan  INSERT INTO t8 SELECT i/40, i/20, i/40 FROM s;
122a74f5c29Sdan}
123a74f5c29Sdan
124a74f5c29Sdando_execsql_test 820 {
125a74f5c29Sdan  SELECT DISTINCT a, b, c FROM t8;
126a74f5c29Sdan} {
127a74f5c29Sdan  0 0 0    0 1 0
128a74f5c29Sdan  1 2 1    1 3 1
129a74f5c29Sdan  2 4 2
130a74f5c29Sdan}
131a74f5c29Sdan
132a74f5c29Sdando_execsql_test 820 {
133a74f5c29Sdan  SELECT DISTINCT a, b, c FROM t8 WHERE b=3;
134a74f5c29Sdan} {1 3 1}
135a74f5c29Sdan
136a74f5c29Sdando_execsql_test 830 {
137a74f5c29Sdan  CREATE INDEX i8 ON t8(a, c);
138a74f5c29Sdan  ANALYZE;
139a74f5c29Sdan  SELECT DISTINCT a, b, c FROM t8 WHERE b=3;
140a74f5c29Sdan} {1 3 1}
141a74f5c29Sdan
142172806e4Sdrhdo_execsql_test 900 {
143172806e4Sdrh  CREATE TABLE t9(v);
144172806e4Sdrh  INSERT INTO t9 VALUES
145172806e4Sdrh    ('abcd'), ('Abcd'), ('aBcd'), ('ABcd'), ('abCd'), ('AbCd'), ('aBCd'),
146172806e4Sdrh    ('ABCd'), ('abcD'), ('AbcD'), ('aBcD'), ('ABcD'), ('abCD'), ('AbCD'),
147172806e4Sdrh    ('aBCD'), ('ABCD'),
148172806e4Sdrh    ('wxyz'), ('Wxyz'), ('wXyz'), ('WXyz'), ('wxYz'), ('WxYz'), ('wXYz'),
149172806e4Sdrh    ('WXYz'), ('wxyZ'), ('WxyZ'), ('wXyZ'), ('WXyZ'), ('wxYZ'), ('WxYZ'),
150172806e4Sdrh    ('wXYZ'), ('WXYZ');
151172806e4Sdrh}
152172806e4Sdrh
153172806e4Sdrhdo_execsql_test 910 {
154172806e4Sdrh  SELECT DISTINCT v COLLATE NOCASE, v FROM t9 ORDER BY +v;
155172806e4Sdrh} {
156172806e4Sdrh  ABCD ABCD ABCd ABCd ABcD ABcD ABcd ABcd AbCD
157172806e4Sdrh  AbCD AbCd AbCd AbcD AbcD Abcd Abcd
158172806e4Sdrh  WXYZ WXYZ WXYz WXYz WXyZ WXyZ WXyz WXyz WxYZ
159172806e4Sdrh  WxYZ WxYz WxYz WxyZ WxyZ Wxyz Wxyz
160172806e4Sdrh  aBCD aBCD aBCd aBCd aBcD aBcD aBcd aBcd abCD
161172806e4Sdrh  abCD abCd abCd abcD abcD abcd abcd
162172806e4Sdrh  wXYZ wXYZ wXYz wXYz wXyZ wXyZ wXyz wXyz wxYZ
163172806e4Sdrh  wxYZ wxYz wxYz wxyZ wxyZ wxyz wxyz
164172806e4Sdrh}
165172806e4Sdrh
166172806e4Sdrhdo_execsql_test 920 {
167172806e4Sdrh  CREATE INDEX i9 ON t9(v COLLATE NOCASE, v);
168172806e4Sdrh  ANALYZE;
169172806e4Sdrh
170172806e4Sdrh  SELECT DISTINCT v COLLATE NOCASE, v FROM t9 ORDER BY +v;
171172806e4Sdrh} {
172172806e4Sdrh  ABCD ABCD ABCd ABCd ABcD ABcD ABcd ABcd AbCD
173172806e4Sdrh  AbCD AbCd AbCd AbcD AbcD Abcd Abcd
174172806e4Sdrh  WXYZ WXYZ WXYz WXYz WXyZ WXyZ WXyz WXyz WxYZ
175172806e4Sdrh  WxYZ WxYz WxYz WxyZ WxyZ Wxyz Wxyz
176172806e4Sdrh  aBCD aBCD aBCd aBCd aBcD aBcD aBcd aBcd abCD
177172806e4Sdrh  abCD abCd abCd abcD abcD abcd abcd
178172806e4Sdrh  wXYZ wXYZ wXYz wXYz wXyZ wXyZ wXyz wXyz wxYZ
179172806e4Sdrh  wxYZ wxYz wxYz wxyZ wxyZ wxyz wxyz
180172806e4Sdrh}
181172806e4Sdrh
182065b34f6Sdrh# Ticket https://sqlite.org/src/info/ef9318757b152e3a on 2017-11-21
183065b34f6Sdrh# Incorrect result due to a skip-ahead-distinct optimization on a
184065b34f6Sdrh# join where no rows of the inner loop appear in the result set.
185065b34f6Sdrh#
186065b34f6Sdrhdb close
187065b34f6Sdrhsqlite3 db :memory:
188065b34f6Sdrhdo_execsql_test 1000 {
189065b34f6Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
190065b34f6Sdrh  CREATE INDEX t1b ON t1(b);
191065b34f6Sdrh  CREATE TABLE t2(x INTEGER PRIMARY KEY, y INTEGER);
192065b34f6Sdrh  CREATE INDEX t2y ON t2(y);
193065b34f6Sdrh  WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<49)
194065b34f6Sdrh    INSERT INTO t1(b) SELECT x/10 - 1 FROM c;
195065b34f6Sdrh  WITH RECURSIVE c(x) AS (VALUES(-1) UNION ALL SELECT x+1 FROM c WHERE x<19)
196065b34f6Sdrh    INSERT INTO t2(x,y) SELECT x, 1 FROM c;
197065b34f6Sdrh  SELECT DISTINCT y FROM t1, t2 WHERE b=x AND b<>-1;
198065b34f6Sdrh  ANALYZE;
199065b34f6Sdrh  SELECT DISTINCT y FROM t1, t2 WHERE b=x AND b<>-1;
200065b34f6Sdrh} {1 1}
201fa337cc1Sdrhdb close
202fa337cc1Sdrhsqlite3 db :memory:
203fa337cc1Sdrhdo_execsql_test 1010 {
204fa337cc1Sdrh  CREATE TABLE t1(a INTEGER PRIMARY KEY, b INTEGER);
205fa337cc1Sdrh  CREATE INDEX t1b ON t1(b);
206fa337cc1Sdrh  CREATE TABLE t2(x INTEGER PRIMARY KEY, y INTEGER);
207fa337cc1Sdrh  CREATE INDEX t2y ON t2(y);
208fa337cc1Sdrh  WITH RECURSIVE c(x) AS (VALUES(0) UNION ALL SELECT x+1 FROM c WHERE x<49)
209fa337cc1Sdrh    INSERT INTO t1(b) SELECT -(x/10 - 1) FROM c;
210fa337cc1Sdrh  WITH RECURSIVE c(x) AS (VALUES(-1) UNION ALL SELECT x+1 FROM c WHERE x<19)
211fa337cc1Sdrh    INSERT INTO t2(x,y) SELECT -x, 1 FROM c;
212fa337cc1Sdrh  SELECT DISTINCT y FROM t1, t2 WHERE b=x AND b<>1 ORDER BY y DESC;
213fa337cc1Sdrh  ANALYZE;
214fa337cc1Sdrh  SELECT DISTINCT y FROM t1, t2 WHERE b=x AND b<>1 ORDER BY y DESC;
215fa337cc1Sdrh} {1 1}
216fa337cc1Sdrhdb close
217fa337cc1Sdrhsqlite3 db :memory:
218fa337cc1Sdrhdo_execsql_test 1020 {
219fa337cc1Sdrh  CREATE TABLE t1(a, b);
220fa337cc1Sdrh  CREATE INDEX t1a ON t1(a, b);
221fa337cc1Sdrh  -- Lots of rows of (1, 'no'), followed by a single (1, 'yes').
222fa337cc1Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<100)
223fa337cc1Sdrh    INSERT INTO t1(a, b) SELECT 1, 'no' FROM c;
224fa337cc1Sdrh  INSERT INTO t1(a, b) VALUES(1, 'yes');
225fa337cc1Sdrh  CREATE TABLE t2(x PRIMARY KEY);
226fa337cc1Sdrh  INSERT INTO t2 VALUES('yes');
227fa337cc1Sdrh  SELECT DISTINCT a FROM t1, t2 WHERE x=b;
228fa337cc1Sdrh  ANALYZE;
229fa337cc1Sdrh  SELECT DISTINCT a FROM t1, t2 WHERE x=b;
230fa337cc1Sdrh} {1 1}
231fa337cc1Sdrh
232a79a0e73Sdan#-------------------------------------------------------------------------
233a79a0e73Sdanreset_db
234a79a0e73Sdan
235a79a0e73Sdando_execsql_test 2000 {
236a79a0e73Sdan  CREATE TABLE t0 (c0, c1, c2, PRIMARY KEY (c0, c1));
237a79a0e73Sdan  CREATE TABLE t1 (c2);
238a79a0e73Sdan  INSERT INTO t0(c2) VALUES (0),(1),(3),(4),(5),(6),(7),(8),(9),(10),(11);
239a79a0e73Sdan  INSERT INTO t0(c1) VALUES ('a');
240a79a0e73Sdan  INSERT INTO t1(c2) VALUES (0);
241a79a0e73Sdan}
242a79a0e73Sdando_execsql_test 2010 {
243a79a0e73Sdan  SELECT DISTINCT t0.c0, t1._rowid_, t0.c1 FROM t1 CROSS JOIN t0 ORDER BY t0.c0;
244a79a0e73Sdan} {{} 1 {} {} 1 a}
245a79a0e73Sdando_execsql_test 1.2 {
246a79a0e73Sdan  ANALYZE;
247a79a0e73Sdan}
248a79a0e73Sdando_execsql_test 2020 {
249a79a0e73Sdan  SELECT DISTINCT t0.c0, t1._rowid_, t0.c1 FROM t1 CROSS JOIN t0 ORDER BY t0.c0;
250a79a0e73Sdan} {{} 1 {} {} 1 a}
251a79a0e73Sdan
252a79a0e73Sdan
253a79a0e73Sdando_execsql_test 2030 {
254a79a0e73Sdan  CREATE TABLE t2(a, b, c);
255a79a0e73Sdan  CREATE INDEX t2ab ON t2(a, b);
256a79a0e73Sdan
257a79a0e73Sdan  WITH c(i) AS (SELECT 1 UNION ALL SELECT i+1 FROM c WHERE i<64)
258a79a0e73Sdan    INSERT INTO t2 SELECT 'one', i%2, 'one' FROM c;
259a79a0e73Sdan
260a79a0e73Sdan  WITH c(i) AS (SELECT 1 UNION ALL SELECT i+1 FROM c WHERE i<64)
261a79a0e73Sdan    INSERT INTO t2 SELECT 'two', i%2, 'two' FROM c;
262a79a0e73Sdan
263a79a0e73Sdan  CREATE TABLE t3(x INTEGER PRIMARY KEY);
264a79a0e73Sdan  INSERT INTO t3 VALUES(1);
265a79a0e73Sdan
266a79a0e73Sdan  ANALYZE;
267a79a0e73Sdan}
268a79a0e73Sdando_execsql_test 2040 {
269*40386968Sdrh  SELECT DISTINCT a, b, x FROM t3 CROSS JOIN t2 ORDER BY a, +b;
270a79a0e73Sdan} {
271a79a0e73Sdan  one 0 1
272a79a0e73Sdan  one 1 1
273a79a0e73Sdan  two 0 1
274a79a0e73Sdan  two 1 1
275a79a0e73Sdan}
276a79a0e73Sdan
277f7c92e82Sdan#-------------------------------------------------------------------------
278f7c92e82Sdan#
279f7c92e82Sdanreset_db
280f7c92e82Sdando_execsql_test 3000 {
281f7c92e82Sdan  CREATE TABLE t0 (c0, c1 NOT NULL DEFAULT 1, c2, PRIMARY KEY (c0, c1));
282f7c92e82Sdan  INSERT INTO t0(c2) VALUES (NULL), (NULL), (NULL), (NULL), (NULL), (NULL), (NULL), (NULL), (NULL), (NULL), (NULL);
283f7c92e82Sdan  INSERT INTO t0(c2) VALUES('a');
284f7c92e82Sdan}
285a79a0e73Sdan
286f7c92e82Sdando_execsql_test 3010 {
287f7c92e82Sdan  SELECT DISTINCT * FROM t0 WHERE NULL IS t0.c0;
288f7c92e82Sdan} {
289f7c92e82Sdan  {} 1 {}
290f7c92e82Sdan  {} 1 a
291f7c92e82Sdan}
292f7c92e82Sdan
293f7c92e82Sdando_execsql_test 3020 {
294f7c92e82Sdan  ANALYZE;
295f7c92e82Sdan}
296f7c92e82Sdan
297f7c92e82Sdando_execsql_test 3030 {
298f7c92e82Sdan  SELECT DISTINCT * FROM t0 WHERE NULL IS c0;
299f7c92e82Sdan} {
300f7c92e82Sdan  {} 1 {}
301f7c92e82Sdan  {} 1 a
302f7c92e82Sdan}
303a74f5c29Sdan
3048489bf5aSdrhfinish_test
305