blob: 5f379d684edbc9300527b0c88a4ac9769646d5f4 [file] [log] [blame]
drhff78bd22002-02-27 01:47:11 +00001# 2002 February 26
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 file is testing VIEW statements.
13#
drh6bf89572004-11-03 16:27:01 +000014# $Id: view.test,v 1.19 2004/11/03 16:27:02 drh Exp $
drhff78bd22002-02-27 01:47:11 +000015set testdir [file dirname $argv0]
16source $testdir/tester.tcl
17
18do_test view-1.0 {
19 execsql {
20 CREATE TABLE t1(a,b,c);
21 INSERT INTO t1 VALUES(1,2,3);
22 INSERT INTO t1 VALUES(4,5,6);
23 INSERT INTO t1 VALUES(7,8,9);
24 SELECT * FROM t1;
25 }
26} {1 2 3 4 5 6 7 8 9}
27
28do_test view-1.1 {
29 execsql {
30 BEGIN;
31 CREATE VIEW v1 AS SELECT a,b FROM t1;
32 SELECT * FROM v1 ORDER BY a;
33 }
34} {1 2 4 5 7 8}
35do_test view-1.2 {
36 catchsql {
37 ROLLBACK;
38 SELECT * FROM v1 ORDER BY a;
39 }
40} {1 {no such table: v1}}
41do_test view-1.3 {
42 execsql {
43 CREATE VIEW v1 AS SELECT a,b FROM t1;
44 SELECT * FROM v1 ORDER BY a;
45 }
46} {1 2 4 5 7 8}
drh417be792002-03-03 18:59:40 +000047do_test view-1.3.1 {
48 db close
drhef4ac8f2004-06-19 00:16:31 +000049 sqlite3 db test.db
drh417be792002-03-03 18:59:40 +000050 execsql {
51 SELECT * FROM v1 ORDER BY a;
52 }
53} {1 2 4 5 7 8}
drhff78bd22002-02-27 01:47:11 +000054do_test view-1.4 {
55 catchsql {
56 DROP VIEW v1;
57 SELECT * FROM v1 ORDER BY a;
58 }
59} {1 {no such table: v1}}
60do_test view-1.5 {
61 execsql {
62 CREATE VIEW v1 AS SELECT a,b FROM t1;
63 SELECT * FROM v1 ORDER BY a;
64 }
65} {1 2 4 5 7 8}
66do_test view-1.6 {
67 catchsql {
68 DROP TABLE t1;
69 SELECT * FROM v1 ORDER BY a;
70 }
drhf26e09c2003-05-31 16:21:12 +000071} {1 {no such table: main.t1}}
drhff78bd22002-02-27 01:47:11 +000072do_test view-1.7 {
73 execsql {
74 CREATE TABLE t1(x,a,b,c);
75 INSERT INTO t1 VALUES(1,2,3,4);
76 INSERT INTO t1 VALUES(4,5,6,7);
77 INSERT INTO t1 VALUES(7,8,9,10);
78 SELECT * FROM v1 ORDER BY a;
79 }
80} {2 3 5 6 8 9}
drh417be792002-03-03 18:59:40 +000081do_test view-1.8 {
82 db close
drhef4ac8f2004-06-19 00:16:31 +000083 sqlite3 db test.db
drh417be792002-03-03 18:59:40 +000084 execsql {
85 SELECT * FROM v1 ORDER BY a;
86 }
87} {2 3 5 6 8 9}
88
drh4ff6dfa2002-03-03 23:06:00 +000089do_test view-2.1 {
90 execsql {
91 CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
92 }; # No semicolon
93 execsql2 {
94 SELECT * FROM v2;
95 }
96} {x 7 a 8 b 9 c 10}
97do_test view-2.2 {
98 catchsql {
99 INSERT INTO v2 VALUES(1,2,3,4);
100 }
drh5cf590c2003-04-24 01:45:04 +0000101} {1 {cannot modify v2 because it is a view}}
drh4ff6dfa2002-03-03 23:06:00 +0000102do_test view-2.3 {
103 catchsql {
104 UPDATE v2 SET a=10 WHERE a=5;
105 }
drh5cf590c2003-04-24 01:45:04 +0000106} {1 {cannot modify v2 because it is a view}}
drh4ff6dfa2002-03-03 23:06:00 +0000107do_test view-2.4 {
108 catchsql {
109 DELETE FROM v2;
110 }
drh5cf590c2003-04-24 01:45:04 +0000111} {1 {cannot modify v2 because it is a view}}
drh4ff6dfa2002-03-03 23:06:00 +0000112do_test view-2.5 {
113 execsql {
114 INSERT INTO t1 VALUES(11,12,13,14);
115 SELECT * FROM v2 ORDER BY x;
116 }
117} {7 8 9 10 11 12 13 14}
118do_test view-2.6 {
119 execsql {
120 SELECT x FROM v2 WHERE a>10
121 }
122} {11}
123
drh0bb28102002-05-08 11:54:14 +0000124# Test that column name of views are generated correctly.
125#
126do_test view-3.1 {
127 execsql2 {
128 SELECT * FROM v1 LIMIT 1
129 }
130} {a 2 b 3}
131do_test view-3.2 {
132 execsql2 {
133 SELECT * FROM v2 LIMIT 1
134 }
135} {x 7 a 8 b 9 c 10}
136do_test view-3.3 {
137 execsql2 {
138 DROP VIEW v1;
139 CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
140 SELECT * FROM v1 LIMIT 1
141 }
142} {xyz 2 pqr 7 c-b 1}
143do_test view-3.4 {
144 execsql2 {
145 CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
146 SELECT * FROM v3 LIMIT 4;
147 }
148} {b 2 b 3 b 5 b 6}
drh0f18b452002-05-08 21:30:15 +0000149do_test view-3.5 {
150 execsql2 {
151 CREATE VIEW v4 AS
152 SELECT a, b FROM t1
153 UNION
154 SELECT b AS 'x', a AS 'y' FROM t1
155 ORDER BY x, y;
156 SELECT y FROM v4 ORDER BY y LIMIT 4;
157 }
158} {y 2 y 3 y 5 y 6}
drh4ff6dfa2002-03-03 23:06:00 +0000159
drhff78bd22002-02-27 01:47:11 +0000160
drh3b167c72002-06-28 12:18:47 +0000161do_test view-4.1 {
162 catchsql {
163 DROP VIEW t1;
164 }
165} {1 {use DROP TABLE to delete table t1}}
166do_test view-4.2 {
167 execsql {
168 SELECT 1 FROM t1 LIMIT 1;
169 }
170} 1
171do_test view-4.3 {
172 catchsql {
173 DROP TABLE v1;
174 }
175} {1 {use DROP VIEW to delete view v1}}
176do_test view-4.4 {
177 execsql {
178 SELECT 1 FROM v1 LIMIT 1;
179 }
180} {1}
181do_test view-4.5 {
182 catchsql {
183 CREATE INDEX i1v1 ON v1(xyz);
184 }
185} {1 {views may not be indexed}}
186
187do_test view-5.1 {
188 execsql {
189 CREATE TABLE t2(y,a);
190 INSERT INTO t2 VALUES(22,2);
191 INSERT INTO t2 VALUES(33,3);
192 INSERT INTO t2 VALUES(44,4);
193 INSERT INTO t2 VALUES(55,5);
194 SELECT * FROM t2;
195 }
196} {22 2 33 3 44 4 55 5}
197do_test view-5.2 {
198 execsql {
199 CREATE VIEW v5 AS
drhc31c2eb2003-05-02 16:04:17 +0000200 SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
drh3b167c72002-06-28 12:18:47 +0000201 SELECT * FROM v5;
202 }
203} {1 22 4 55}
204
drhc31c2eb2003-05-02 16:04:17 +0000205# Verify that the view v5 gets flattened. see sqliteFlattenSubquery().
drh6bf89572004-11-03 16:27:01 +0000206# This will only work if EXPLAIN is enabled.
drhc31c2eb2003-05-02 16:04:17 +0000207# Ticket #272
drh6bf89572004-11-03 16:27:01 +0000208#
209ifcapable {explain} {
drhc31c2eb2003-05-02 16:04:17 +0000210do_test view-5.3 {
211 lsearch [execsql {
212 EXPLAIN SELECT * FROM v5;
213 }] OpenTemp
214} {-1}
215do_test view-5.4 {
216 execsql {
217 SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
218 }
219} {1 22 22 2 4 55 55 5}
220do_test view-5.5 {
221 lsearch [execsql {
222 EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
223 }] OpenTemp
224} {-1}
225do_test view-5.6 {
226 execsql {
227 SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
228 }
229} {22 2 1 22 55 5 4 55}
230do_test view-5.7 {
231 lsearch [execsql {
232 EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
233 }] OpenTemp
234} {-1}
235do_test view-5.8 {
236 execsql {
237 SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
238 }
239} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
240do_test view-5.9 {
241 lsearch [execsql {
242 EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
243 }] OpenTemp
244} {-1}
drh6bf89572004-11-03 16:27:01 +0000245} ;# endif explain
drhc31c2eb2003-05-02 16:04:17 +0000246
drh2f2c01e2002-07-02 13:05:04 +0000247do_test view-6.1 {
248 execsql {
249 SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
250 }
251} {7 8 9 10 27}
252do_test view-6.2 {
253 execsql {
254 SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
255 }
256} {11 12 13 14 39}
257
drh0c36cbe2002-07-16 02:05:43 +0000258do_test view-7.1 {
259 execsql {
260 CREATE TABLE test1(id integer primary key, a);
261 CREATE TABLE test2(id integer, b);
262 INSERT INTO test1 VALUES(1,2);
263 INSERT INTO test2 VALUES(1,3);
264 CREATE VIEW test AS
265 SELECT test1.id, a, b
266 FROM test1 JOIN test2 ON test2.id=test1.id;
267 SELECT * FROM test;
268 }
269} {1 2 3}
270do_test view-7.2 {
271 db close
drhef4ac8f2004-06-19 00:16:31 +0000272 sqlite3 db test.db
drh0c36cbe2002-07-16 02:05:43 +0000273 execsql {
274 SELECT * FROM test;
275 }
276} {1 2 3}
277do_test view-7.3 {
278 execsql {
279 DROP VIEW test;
280 CREATE VIEW test AS
281 SELECT test1.id, a, b
282 FROM test1 JOIN test2 USING(id);
283 SELECT * FROM test;
284 }
285} {1 2 3}
286do_test view-7.4 {
287 db close
drhef4ac8f2004-06-19 00:16:31 +0000288 sqlite3 db test.db
drh0c36cbe2002-07-16 02:05:43 +0000289 execsql {
290 SELECT * FROM test;
291 }
292} {1 2 3}
293do_test view-7.5 {
294 execsql {
295 DROP VIEW test;
296 CREATE VIEW test AS
297 SELECT test1.id, a, b
298 FROM test1 NATURAL JOIN test2;
299 SELECT * FROM test;
300 }
301} {1 2 3}
302do_test view-7.6 {
303 db close
drhef4ac8f2004-06-19 00:16:31 +0000304 sqlite3 db test.db
drh0c36cbe2002-07-16 02:05:43 +0000305 execsql {
306 SELECT * FROM test;
307 }
308} {1 2 3}
drh2f2c01e2002-07-02 13:05:04 +0000309
drh4b59ab52002-08-24 18:24:51 +0000310do_test view-8.1 {
311 execsql {
312 CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
313 SELECT * FROM v6 ORDER BY xyz;
314 }
315} {7 2 13 5 19 8 27 12}
drh4b59ab52002-08-24 18:24:51 +0000316do_test view-8.2 {
317 db close
drhef4ac8f2004-06-19 00:16:31 +0000318 sqlite3 db test.db
drh4b59ab52002-08-24 18:24:51 +0000319 execsql {
320 SELECT * FROM v6 ORDER BY xyz;
321 }
322} {7 2 13 5 19 8 27 12}
323do_test view-8.3 {
324 execsql {
325 CREATE VIEW v7 AS SELECT pqr+xyz AS a FROM v6;
326 SELECT * FROM v7 ORDER BY a;
327 }
328} {9 18 27 39}
329do_test view-8.4 {
drh8c74a8c2002-08-25 19:20:40 +0000330 execsql {
331 CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
drh4b59ab52002-08-24 18:24:51 +0000332 (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
333 SELECT * FROM v8;
334 }
335} 3
drh8c74a8c2002-08-25 19:20:40 +0000336do_test view-8.5 {
337 execsql {
338 SELECT mx+10, mx*2 FROM v8;
339 }
340} {13 6}
drh6a3ea0e2003-05-02 14:32:12 +0000341do_test view-8.6 {
342 execsql {
343 SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
344 }
345} {13 7}
346do_test view-8.7 {
347 execsql {
348 SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
349 }
350} {13 13 13 19 13 27}
drh4b59ab52002-08-24 18:24:51 +0000351
drh174b6192002-12-03 02:22:52 +0000352# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
353#
354do_test view-9.1 {
355 execsql {
356 INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
357 INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
358 INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
359 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
360 }
361} {1 2 4 8}
362do_test view-9.2 {
363 execsql {
364 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
365 }
366} {1 2 4}
367do_test view-9.3 {
368 execsql {
369 CREATE VIEW v9 AS
370 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
371 SELECT * FROM v9;
372 }
373} {1 2 4}
374do_test view-9.4 {
375 execsql {
376 SELECT * FROM v9 ORDER BY 1 DESC;
377 }
378} {4 2 1}
379do_test view-9.5 {
380 execsql {
381 CREATE VIEW v10 AS
382 SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
383 SELECT * FROM v10;
384 }
385} {5 1 4 2 3 4}
386do_test view-9.6 {
387 execsql {
388 SELECT * FROM v10 ORDER BY 1;
389 }
390} {3 4 4 2 5 1}
391
drh2c61c072004-07-20 00:20:23 +0000392# Tables with columns having peculiar quoted names used in views
393# Ticket #756.
394#
395do_test view-10.1 {
396 execsql {
397 CREATE TABLE t3("9" integer, [4] text);
398 INSERT INTO t3 VALUES(1,2);
399 CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
400 CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
401 SELECT * FROM v_t3_a;
402 }
403} {1}
404do_test view-10.2 {
405 execsql {
406 SELECT * FROM v_t3_b;
407 }
408} {2}
drh174b6192002-12-03 02:22:52 +0000409
drhff78bd22002-02-27 01:47:11 +0000410finish_test