xref: /sqlite-3.40.0/test/distinct.test (revision 9cffb0ff)
1# 2011 July 1
2#
3# The author disclaims copyright to this source code.  In place of
4# a legal notice, here is a blessing:
5#
6#    May you do good and not evil.
7#    May you find forgiveness for yourself and forgive others.
8#    May you share freely, never taking more than you give.
9#
10#***********************************************************************
11# This file implements regression tests for SQLite library.  The
12# focus of this script is the DISTINCT modifier.
13#
14
15set testdir [file dirname $argv0]
16source $testdir/tester.tcl
17
18ifcapable !compound {
19  finish_test
20  return
21}
22
23set testprefix distinct
24
25
26proc is_distinct_noop {sql} {
27  set sql1 $sql
28  set sql2 [string map {DISTINCT ""} $sql]
29
30  set program1 [list]
31  set program2 [list]
32  db eval "EXPLAIN $sql1" {
33    if {$opcode != "Noop" && $opcode != "Explain"} { lappend program1 $opcode }
34  }
35  db eval "EXPLAIN $sql2" {
36    if {$opcode != "Noop" && $opcode != "Explain"} { lappend program2 $opcode }
37  }
38  return [expr {$program1==$program2}]
39}
40
41proc do_distinct_noop_test {tn sql} {
42  uplevel [list do_test $tn [list is_distinct_noop $sql] 1]
43}
44proc do_distinct_not_noop_test {tn sql} {
45  uplevel [list do_test $tn [list is_distinct_noop $sql] 0]
46}
47
48proc do_temptables_test {tn sql temptables} {
49  uplevel [list do_test $tn [subst -novar {
50    set ret ""
51    db eval "EXPLAIN [set sql]" {
52      if {$opcode == "OpenEphemeral" || $opcode == "SorterOpen"} {
53        if {$p5!=8 && $p5!=0} { error "p5 = $p5" }
54        if {$p5==8} {
55          lappend ret hash
56        } else {
57          lappend ret btree
58        }
59      }
60    }
61    set ret
62  }] $temptables]
63}
64
65
66#-------------------------------------------------------------------------
67# The following tests - distinct-1.* - check that the planner correctly
68# detects cases where a UNIQUE index means that a DISTINCT clause is
69# redundant. Currently the planner only detects such cases when there
70# is a single table in the FROM clause.
71#
72do_execsql_test 1.0 {
73  CREATE TABLE t1(a, b, c, d);
74  CREATE UNIQUE INDEX i1 ON t1(b, c);
75  CREATE UNIQUE INDEX i2 ON t1(d COLLATE nocase);
76
77  CREATE TABLE t2(x INTEGER PRIMARY KEY, y);
78
79  CREATE TABLE t3(c1 PRIMARY KEY NOT NULL, c2 NOT NULL);
80  CREATE INDEX i3 ON t3(c2);
81
82  CREATE TABLE t4(a, b NOT NULL, c NOT NULL, d NOT NULL);
83  CREATE UNIQUE INDEX t4i1 ON t4(b, c);
84  CREATE UNIQUE INDEX t4i2 ON t4(d COLLATE nocase);
85}
86foreach {tn noop sql} {
87
88  1.1 0   "SELECT DISTINCT b, c FROM t1"
89  1.2 1   "SELECT DISTINCT b, c FROM t4"
90  2.1 0   "SELECT DISTINCT c FROM t1 WHERE b = ?"
91  2.2 1   "SELECT DISTINCT c FROM t4 WHERE b = ?"
92  3   1   "SELECT DISTINCT rowid FROM t1"
93  4   1   "SELECT DISTINCT rowid, a FROM t1"
94  5   1   "SELECT DISTINCT x FROM t2"
95  6   1   "SELECT DISTINCT * FROM t2"
96  7   1   "SELECT DISTINCT * FROM (SELECT * FROM t2)"
97
98  8.1 0   "SELECT DISTINCT * FROM t1"
99  8.2 1   "SELECT DISTINCT * FROM t4"
100
101  8   0   "SELECT DISTINCT a, b FROM t1"
102
103  9   0   "SELECT DISTINCT c FROM t1 WHERE b IN (1,2)"
104  10  0   "SELECT DISTINCT c FROM t1"
105  11  0   "SELECT DISTINCT b FROM t1"
106
107  12.1 0   "SELECT DISTINCT a, d FROM t1"
108  12.2 0   "SELECT DISTINCT a, d FROM t4"
109  13.1 0   "SELECT DISTINCT a, b, c COLLATE nocase FROM t1"
110  13.2 0   "SELECT DISTINCT a, b, c COLLATE nocase FROM t4"
111  14.1 0   "SELECT DISTINCT a, d COLLATE nocase FROM t1"
112  14.2 1   "SELECT DISTINCT a, d COLLATE nocase FROM t4"
113
114  15   0   "SELECT DISTINCT a, d COLLATE binary FROM t1"
115  16.1 0   "SELECT DISTINCT a, b, c COLLATE binary FROM t1"
116  16.2 1   "SELECT DISTINCT a, b, c COLLATE binary FROM t4"
117
118  16  0   "SELECT DISTINCT t1.rowid FROM t1, t2"
119  17  0   { /* Technically, it would be possible to detect that DISTINCT
120            ** is a no-op in cases like the following. But SQLite does not
121            ** do so. */
122            SELECT DISTINCT t1.rowid FROM t1, t2 WHERE t1.rowid=t2.rowid }
123
124  18  1   "SELECT DISTINCT c1, c2 FROM t3"
125  19  1   "SELECT DISTINCT c1 FROM t3"
126  20  1   "SELECT DISTINCT * FROM t3"
127  21  0   "SELECT DISTINCT c2 FROM t3"
128
129  22  0   "SELECT DISTINCT * FROM (SELECT 1, 2, 3 UNION SELECT 4, 5, 6)"
130  23  1   "SELECT DISTINCT rowid FROM (SELECT 1, 2, 3 UNION SELECT 4, 5, 6)"
131
132  24  0   "SELECT DISTINCT rowid/2 FROM t1"
133  25  1   "SELECT DISTINCT rowid/2, rowid FROM t1"
134  26.1  0   "SELECT DISTINCT rowid/2, b FROM t1 WHERE c = ?"
135  26.2  1   "SELECT DISTINCT rowid/2, b FROM t4 WHERE c = ?"
136} {
137  if {$noop} {
138    do_distinct_noop_test 1.$tn $sql
139  } else {
140    do_distinct_not_noop_test 1.$tn $sql
141  }
142}
143
144#-------------------------------------------------------------------------
145# The following tests - distinct-2.* - test cases where an index is
146# used to deliver results in order of the DISTINCT expressions.
147#
148drop_all_tables
149do_execsql_test 2.0 {
150  CREATE TABLE t1(a, b, c);
151
152  CREATE INDEX i1 ON t1(a, b);
153  CREATE INDEX i2 ON t1(b COLLATE nocase, c COLLATE nocase);
154
155  INSERT INTO t1 VALUES('a', 'b', 'c');
156  INSERT INTO t1 VALUES('A', 'B', 'C');
157  INSERT INTO t1 VALUES('a', 'b', 'c');
158  INSERT INTO t1 VALUES('A', 'B', 'C');
159}
160
161foreach {tn sql temptables res} {
162  1   "a, b FROM t1"                                       {}      {A B a b}
163  2   "b, a FROM t1"                                       {}      {B A b a}
164  3   "a, b, c FROM t1"                                    {hash}  {A B C a b c}
165  4   "a, b, c FROM t1 ORDER BY a, b, c"                   {btree} {A B C a b c}
166  5   "b FROM t1 WHERE a = 'a'"                            {}      {b}
167  6   "b FROM t1 ORDER BY +b COLLATE binary"          {btree hash} {B b}
168  7   "a FROM t1"                                          {}      {A a}
169  8   "b COLLATE nocase FROM t1"                           {}      {b}
170  9   "b COLLATE nocase FROM t1 ORDER BY b COLLATE nocase" {}      {b}
171} {
172  do_execsql_test    2.$tn.1 "SELECT DISTINCT $sql" $res
173  do_temptables_test 2.$tn.2 "SELECT DISTINCT $sql" $temptables
174}
175
176do_execsql_test 2.A {
177  SELECT (SELECT DISTINCT o.a FROM t1 AS i) FROM t1 AS o ORDER BY rowid;
178} {a A a A}
179
180do_test 3.0 {
181  db eval {
182    CREATE TABLE t3(a INTEGER, b INTEGER, c, UNIQUE(a,b));
183    INSERT INTO t3 VALUES
184        (null, null, 1),
185        (null, null, 2),
186        (null, 3, 4),
187        (null, 3, 5),
188        (6, null, 7),
189        (6, null, 8);
190    SELECT DISTINCT a, b FROM t3 ORDER BY +a, +b;
191  }
192} {{} {} {} 3 6 {}}
193do_test 3.1 {
194  regexp {OpenEphemeral} [db eval {
195    EXPLAIN SELECT DISTINCT a, b FROM t3 ORDER BY +a, +b;
196  }]
197} {0}
198
199#-------------------------------------------------------------------------
200# Ticket  [fccbde530a6583bf2748400919f1603d5425995c] (2014-01-08)
201# The logic that computes DISTINCT sometimes thinks that a zeroblob()
202# and a blob of all zeros are different when they should be the same.
203#
204do_execsql_test 4.1 {
205  DROP TABLE IF EXISTS t1;
206  DROP TABLE IF EXISTS t2;
207  CREATE TABLE t1(a INTEGER);
208  INSERT INTO t1 VALUES(3);
209  INSERT INTO t1 VALUES(2);
210  INSERT INTO t1 VALUES(1);
211  INSERT INTO t1 VALUES(2);
212  INSERT INTO t1 VALUES(3);
213  INSERT INTO t1 VALUES(1);
214  CREATE TABLE t2(x);
215  INSERT INTO t2
216    SELECT DISTINCT
217      CASE a WHEN 1 THEN x'0000000000'
218             WHEN 2 THEN zeroblob(5)
219             ELSE 'xyzzy' END
220      FROM t1;
221  SELECT quote(x) FROM t2 ORDER BY 1;
222} {'xyzzy' X'0000000000'}
223
224#----------------------------------------------------------------------------
225# Ticket [c5ea805691bfc4204b1cb9e9aa0103bd48bc7d34] (2014-12-04)
226# Make sure that DISTINCT works together with ORDER BY and descending
227# indexes.
228#
229do_execsql_test 5.1 {
230  DROP TABLE IF EXISTS t1;
231  CREATE TABLE t1(x);
232  INSERT INTO t1(x) VALUES(3),(1),(5),(2),(6),(4),(5),(1),(3);
233  CREATE INDEX t1x ON t1(x DESC);
234  SELECT DISTINCT x FROM t1 ORDER BY x ASC;
235} {1 2 3 4 5 6}
236do_execsql_test 5.2 {
237  SELECT DISTINCT x FROM t1 ORDER BY x DESC;
238} {6 5 4 3 2 1}
239do_execsql_test 5.3 {
240  SELECT DISTINCT x FROM t1 ORDER BY x;
241} {1 2 3 4 5 6}
242do_execsql_test 5.4 {
243  DROP INDEX t1x;
244  CREATE INDEX t1x ON t1(x ASC);
245  SELECT DISTINCT x FROM t1 ORDER BY x ASC;
246} {1 2 3 4 5 6}
247do_execsql_test 5.5 {
248  SELECT DISTINCT x FROM t1 ORDER BY x DESC;
249} {6 5 4 3 2 1}
250do_execsql_test 5.6 {
251  SELECT DISTINCT x FROM t1 ORDER BY x;
252} {1 2 3 4 5 6}
253
254#-------------------------------------------------------------------------
255# 2015-11-23.  Problem discovered by Kostya Serebryany using libFuzzer
256#
257db close
258sqlite3 db :memory:
259do_execsql_test 6.1 {
260  CREATE TABLE jjj(x);
261  SELECT (SELECT 'mmm' UNION SELECT DISTINCT max(name) ORDER BY 1)
262    FROM sqlite_master;
263} {jjj}
264do_execsql_test 6.2 {
265  CREATE TABLE nnn(x);
266  SELECT (SELECT 'mmm' UNION SELECT DISTINCT max(name) ORDER BY 1)
267    FROM sqlite_master;
268} {mmm}
269
270#-------------------------------------------------------------------------
271# Ticket [9c944882]
272#
273reset_db
274do_execsql_test 7.0 {
275  CREATE TABLE t1(a INTEGER PRIMARY KEY);
276  CREATE TABLE t3(a INTEGER PRIMARY KEY);
277
278  CREATE TABLE t4(x);
279  CREATE TABLE t5(y);
280
281  INSERT INTO t5 VALUES(1), (2), (2);
282  INSERT INTO t1 VALUES(2);
283  INSERT INTO t3 VALUES(2);
284  INSERT INTO t4 VALUES(2);
285}
286
287do_execsql_test 7.1 {
288  WITH t2(b) AS (
289    SELECT DISTINCT y FROM t5 ORDER BY y
290  )
291  SELECT * FROM
292    t4 CROSS JOIN t3 CROSS JOIN t1
293  WHERE (t1.a=t3.a) AND (SELECT count(*) FROM t2 AS y WHERE t4.x!='abc')=t1.a
294} {2 2 2}
295
296finish_test
297