blob: 94e220328c159bbe27f917d1094435b5f4b4f52d [file] [log] [blame]
drhd092ed42015-05-29 14:36:30 +00001# 2014-10-24
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#
12# This file implements regression tests for SQLite library. The
13# focus of this script is testing automatic index creation logic,
14# and specifically ensuring that automatic indexes can be used with
15# co-routine subqueries.
16#
17
18set testdir [file dirname $argv0]
19source $testdir/tester.tcl
danfb785b22015-10-24 20:31:22 +000020set testprefix autoindex5
drhd092ed42015-05-29 14:36:30 +000021
22# Schema is from the Debian security database
23#
24do_execsql_test autoindex5-1.0 {
25 CREATE TABLE source_package_status
26 (bug_name TEXT NOT NULL,
27 package INTEGER NOT NULL,
28 vulnerable INTEGER NOT NULL,
29 urgency TEXT NOT NULL,
30 PRIMARY KEY (bug_name, package));
31 CREATE INDEX source_package_status_package
32 ON source_package_status(package);
33
34 CREATE TABLE source_packages
35 (name TEXT NOT NULL,
36 release TEXT NOT NULL,
37 subrelease TEXT NOT NULL,
38 archive TEXT NOT NULL,
39 version TEXT NOT NULL,
40 version_id INTEGER NOT NULL DEFAULT 0,
41 PRIMARY KEY (name, release, subrelease, archive));
42
43 CREATE TABLE bugs
44 (name TEXT NOT NULL PRIMARY KEY,
45 cve_status TEXT NOT NULL
46 CHECK (cve_status IN
47 ('', 'CANDIDATE', 'ASSIGNED', 'RESERVED', 'REJECTED')),
48 not_for_us INTEGER NOT NULL CHECK (not_for_us IN (0, 1)),
49 description TEXT NOT NULL,
50 release_date TEXT NOT NULL,
51 source_file TEXT NOT NULL,
52 source_line INTEGER NOT NULL);
53
54 CREATE TABLE package_notes
55 (id INTEGER NOT NULL PRIMARY KEY,
56 bug_name TEXT NOT NULL,
57 package TEXT NOT NULL,
58 fixed_version TEXT
59 CHECK (fixed_version IS NULL OR fixed_version <> ''),
60 fixed_version_id INTEGER NOT NULL DEFAULT 0,
61 release TEXT NOT NULL,
62 package_kind TEXT NOT NULL DEFAULT 'unknown',
63 urgency TEXT NOT NULL,
64 bug_origin TEXT NOT NULL DEFAULT '');
65 CREATE INDEX package_notes_package
66 ON package_notes(package);
67 CREATE UNIQUE INDEX package_notes_bug
68 ON package_notes(bug_name, package, release);
69
70 CREATE TABLE debian_bugs
71 (bug INTEGER NOT NULL,
72 note INTEGER NOT NULL,
73 PRIMARY KEY (bug, note));
74
75
76 CREATE VIEW debian_cve AS
77 SELECT DISTINCT debian_bugs.bug, st.bug_name
78 FROM package_notes, debian_bugs, source_package_status AS st
79 WHERE package_notes.bug_name = st.bug_name
80 AND debian_bugs.note = package_notes.id
81 ORDER BY debian_bugs.bug;
82} {}
83
84# The following query should use an automatic index for the view
85# in FROM clause of the subquery of the second result column.
86#
drhcdf88762018-05-02 19:42:33 +000087do_eqp_test autoindex5-1.1 {
drhd092ed42015-05-29 14:36:30 +000088 SELECT
89 st.bug_name,
90 (SELECT ALL debian_cve.bug FROM debian_cve
91 WHERE debian_cve.bug_name = st.bug_name
92 ORDER BY debian_cve.bug),
93 sp.release
94 FROM
95 source_package_status AS st,
96 source_packages AS sp,
97 bugs
98 WHERE
99 sp.rowid = st.package
100 AND st.bug_name = bugs.name
101 AND ( st.bug_name LIKE 'CVE-%' OR st.bug_name LIKE 'TEMP-%' )
102 AND ( sp.release = 'sid' OR sp.release = 'stretch' OR sp.release = 'jessie'
103 OR sp.release = 'wheezy' OR sp.release = 'squeeze' )
104 ORDER BY sp.name, st.bug_name, sp.release, sp.subrelease;
drhcdf88762018-05-02 19:42:33 +0000105} {SEARCH SUBQUERY * USING AUTOMATIC COVERING INDEX (bug_name=?)}
danfb785b22015-10-24 20:31:22 +0000106
107#-------------------------------------------------------------------------
108# Test that ticket [8a2adec1] has been fixed.
109#
110do_execsql_test 2.1 {
111 CREATE TABLE one(o);
112 INSERT INTO one DEFAULT VALUES;
113
114 CREATE TABLE t1(x, z);
115 INSERT INTO t1 VALUES('aaa', 4.0);
116 INSERT INTO t1 VALUES('aaa', 4.0);
117 CREATE VIEW vvv AS
118 SELECT * FROM t1
119 UNION ALL
120 SELECT 0, 0 WHERE 0;
121
122 SELECT (
123 SELECT sum(z) FROM vvv WHERE x='aaa'
124 ) FROM one;
125} {8.0}
drh00a61532019-06-28 07:08:13 +0000126do_execsql_test 2.2 {
127 DROP TABLE t1;
128 CREATE TABLE t1(aaa);
129 INSERT INTO t1(aaa) VALUES(9);
130 SELECT (
131 SELECT aaa FROM t1 GROUP BY (
132 SELECT bbb FROM (
133 SELECT ccc AS bbb FROM (
134 SELECT 1 ccc
135 ) WHERE rowid IS NOT 1
136 ) WHERE bbb = 1
137 )
138 );
139} {9}
drh0b57d312018-11-09 14:17:51 +0000140
141# Ticket https://www.sqlite.org/src/info/787fa716be3a7f65
142# Segfault due to multiple uses of the same subquery where the
143# subquery is implemented via coroutine.
144#
dan8cd2e4a2019-02-11 11:34:01 +0000145ifcapable windowfunc {
drh0b57d312018-11-09 14:17:51 +0000146sqlite3 db :memory:
147do_execsql_test 3.0 {
148 -- This is the original test case reported on the mailing list
149 CREATE TABLE artists (
150 id integer NOT NULL PRIMARY KEY AUTOINCREMENT,
151 name varchar(255)
152 );
153 CREATE TABLE albums (
154 id integer NOT NULL PRIMARY KEY AUTOINCREMENT,
155 name varchar(255),
156 artist_id integer REFERENCES artists
157 );
158 INSERT INTO artists (name) VALUES ('Ar');
159 INSERT INTO albums (name, artist_id) VALUES ('Al', 1);
160 SELECT artists.*
161 FROM artists
162 INNER JOIN artists AS 'b' ON (b.id = artists.id)
163 WHERE (artists.id IN (
164 SELECT albums.artist_id
165 FROM albums
166 WHERE ((name = 'Al')
167 AND (albums.artist_id IS NOT NULL)
168 AND (albums.id IN (
169 SELECT id
170 FROM (
171 SELECT albums.id,
172 row_number() OVER (
173 PARTITION BY albums.artist_id
174 ORDER BY name
175 ) AS 'x'
176 FROM albums
177 WHERE (name = 'Al')
178 ) AS 't1'
179 WHERE (x = 1)
180 ))
181 AND (albums.id IN (1, 2)))
182 ));
183} {1 Ar}
dan8cd2e4a2019-02-11 11:34:01 +0000184} ;# windowfunc
185
drh0b57d312018-11-09 14:17:51 +0000186# The remaining test cases were discovered (by Dan) during trouble-shooting
187sqlite3 db :memory:
188do_execsql_test 3.1 {
189 CREATE TABLE t1 (a); INSERT INTO t1 (a) VALUES (104);
190 CREATE TABLE t2 (b); INSERT INTO t2 (b) VALUES (104);
191 CREATE TABLE t3 (c); INSERT INTO t3 (c) VALUES (104);
192 CREATE TABLE t4 (d); INSERT INTO t4 (d) VALUES (104);
193 SELECT *
194 FROM t1 CROSS JOIN t2 ON (t1.a = t2.b) WHERE t2.b IN (
195 SELECT t3.c
196 FROM t3
197 WHERE t3.c IN (
198 SELECT d FROM (SELECT DISTINCT d FROM t4) AS x WHERE x.d=104
199 )
200 );
201} {104 104}
202sqlite3 db :memory:
203do_execsql_test 3.2 {
204 CREATE TABLE t5(a, b, c, d);
205 CREATE INDEX t5a ON t5(a);
206 CREATE INDEX t5b ON t5(b);
207 CREATE TABLE t6(e);
208 INSERT INTO t6 VALUES(1);
209 INSERT INTO t5 VALUES(1,1,1,1), (2,2,2,2);
210 SELECT * FROM t5 WHERE (a=1 OR b=2) AND c IN (
211 SELECT e FROM (SELECT DISTINCT e FROM t6) WHERE e=1
212 );
213} {1 1 1 1}
214sqlite3 db :memory:
215do_execsql_test 3.3 {
216 CREATE TABLE t1(a1, a2, a3);
217 CREATE INDEX t1a2 ON t1(a2, a1);
218 CREATE INDEX t1a3 ON t1(a3, a1);
219 CREATE TABLE t2(d);
220 INSERT INTO t1 VALUES(3, 1, 1), (3, 2, 2);
221 INSERT INTO t2 VALUES(3);
222 SELECT *, 'x' FROM t1 WHERE (a2=1 OR a3=2) AND a1 = (
223 SELECT d FROM (SELECT DISTINCT d FROM t2) WHERE d=3
224 );
225} {3 1 1 x 3 2 2 x}
226
227
drhd092ed42015-05-29 14:36:30 +0000228
229
230finish_test