3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
11 # This file implements regression tests for SQLite library. The
12 # focus of this file is testing VIEW statements.
14 # $Id: view.test,v 1.39 2008/12/14 14:45:21 danielk1977 Exp $
15 set testdir [file dirname $argv0]
16 source $testdir/tester.tcl
18 # Omit this entire file if the library is not configured with views enabled.
26 CREATE TABLE t1(a,b,c);
27 INSERT INTO t1 VALUES(1,2,3);
28 INSERT INTO t1 VALUES(4,5,6);
29 INSERT INTO t1 VALUES(7,8,9);
37 CREATE VIEW IF NOT EXISTS v1 AS SELECT a,b FROM t1;
38 SELECT * FROM v1 ORDER BY a;
44 SELECT * FROM v1 ORDER BY a;
46 } {1 {no such table: v1}}
49 CREATE VIEW v1 AS SELECT a,b FROM t1;
50 SELECT * FROM v1 ORDER BY a;
57 SELECT * FROM v1 ORDER BY a;
62 DROP VIEW IF EXISTS v1;
63 SELECT * FROM v1 ORDER BY a;
65 } {1 {no such table: v1}}
68 CREATE VIEW v1 AS SELECT a,b FROM t1;
69 SELECT * FROM v1 ORDER BY a;
75 SELECT * FROM v1 ORDER BY a;
77 } {1 {no such table: main.t1}}
80 CREATE TABLE t1(x,a,b,c);
81 INSERT INTO t1 VALUES(1,2,3,4);
82 INSERT INTO t1 VALUES(4,5,6,7);
83 INSERT INTO t1 VALUES(7,8,9,10);
84 SELECT * FROM v1 ORDER BY a;
91 SELECT * FROM v1 ORDER BY a;
95 do_execsql_test view-1.10 {
96 CREATE TABLE t9(x INTEGER);
97 CREATE VIEW v9a AS SELECT x FROM t9;
98 CREATE VIEW v9b AS SELECT * FROM t9;
99 CREATE VIEW v9c(x) AS SELECT x FROM t9;
100 CREATE VIEW v9d(x) AS SELECT * FROM t9;
102 do_execsql_test view-1.11 {
103 PRAGMA table_info(v9a);
104 } {0 x INTEGER 0 {} 0}
105 do_execsql_test view-1.12 {
106 PRAGMA table_info(v9b);
107 } {0 x INTEGER 0 {} 0}
108 do_execsql_test view-1.13 {
109 PRAGMA table_info(v9c);
110 } {0 x INTEGER 0 {} 0}
111 do_execsql_test view-1.14 {
112 PRAGMA table_info(v9d);
113 } {0 x INTEGER 0 {} 0}
117 CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
125 INSERT INTO v2 VALUES(1,2,3,4);
127 } {1 {cannot modify v2 because it is a view}}
130 UPDATE v2 SET a=10 WHERE a=5;
132 } {1 {cannot modify v2 because it is a view}}
137 } {1 {cannot modify v2 because it is a view}}
140 INSERT INTO t1 VALUES(11,12,13,14);
141 SELECT * FROM v2 ORDER BY x;
143 } {7 8 9 10 11 12 13 14}
146 SELECT x FROM v2 WHERE a>10
150 # Test that column name of views are generated correctly.
154 SELECT * FROM v1 LIMIT 1
159 SELECT * FROM v2 LIMIT 1
165 CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
166 SELECT * FROM v1 LIMIT 1
168 } {xyz 2 pqr 7 c-b 1}
171 CREATE VIEW v1b AS SELECT t1.a, b+c, t1.c FROM t1;
172 SELECT * FROM v1b LIMIT 1
177 CREATE VIEW v1c(x,y,z) AS SELECT a, b+c, c-b FROM t1;
178 SELECT * FROM v1c LIMIT 1;
181 do_catchsql_test view-3.3.4 {
182 CREATE VIEW v1err(x,y DESC,z) AS SELECT a, b+c, c-b FROM t1;
183 } {1 {syntax error after column name "y"}}
184 do_catchsql_test view-3.3.5 {
185 DROP VIEW IF EXISTS v1err;
186 CREATE VIEW v1err(x,y) AS SELECT a, b+c, c-b FROM t1;
188 } {1 {expected 2 columns for 'v1err' but got 3}}
189 do_catchsql_test view-3.3.6 {
190 DROP VIEW IF EXISTS v1err;
191 CREATE VIEW v1err(w,x,y,z) AS SELECT a, b+c, c-b FROM t1;
193 } {1 {expected 4 columns for 'v1err' but got 3}}
198 CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
199 SELECT * FROM v3 LIMIT 4;
207 SELECT b AS 'x', a AS 'y' FROM t1
209 SELECT b FROM v4 ORDER BY b LIMIT 4;
212 } ;# ifcapable compound
219 } {1 {use DROP TABLE to delete table t1}}
222 SELECT 1 FROM t1 LIMIT 1;
229 } {1 {use DROP VIEW to delete view v1}}
232 SELECT 1 FROM v1 LIMIT 1;
237 CREATE INDEX i1v1 ON v1(xyz);
239 } {1 {views may not be indexed}}
243 CREATE TABLE t2(y,a);
244 INSERT INTO t2 VALUES(22,2);
245 INSERT INTO t2 VALUES(33,3);
246 INSERT INTO t2 VALUES(44,4);
247 INSERT INTO t2 VALUES(55,5);
250 } {22 2 33 3 44 4 55 5}
254 SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
259 # Verify that the view v5 gets flattened. see sqliteFlattenSubquery().
260 # This will only work if EXPLAIN is enabled.
263 ifcapable {explain} {
266 EXPLAIN SELECT * FROM v5;
271 SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
273 } {1 22 22 2 4 55 55 5}
276 EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
281 SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
283 } {22 2 1 22 55 5 4 55}
286 EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
291 SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
293 } {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
296 EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
303 SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
308 SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
314 CREATE TABLE test1(id integer primary key, a);
315 CREATE TABLE test2(id integer, b);
316 INSERT INTO test1 VALUES(1,2);
317 INSERT INTO test2 VALUES(1,3);
319 SELECT test1.id, a, b
320 FROM test1 JOIN test2 ON test2.id=test1.id;
335 SELECT test1.id, a, b
336 FROM test1 JOIN test2 USING(id);
351 SELECT test1.id, a, b
352 FROM test1 NATURAL JOIN test2;
366 CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
367 SELECT * FROM v6 ORDER BY xyz;
369 } {7 2 13 5 19 8 27 12}
374 SELECT * FROM v6 ORDER BY xyz;
376 } {7 2 13 5 19 8 27 12}
379 CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6;
380 SELECT * FROM v7 ORDER BY a;
387 CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
388 (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
394 SELECT mx+10, mx*2 FROM v8;
399 SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
404 SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
406 } {13 13 13 19 13 27}
407 } ;# ifcapable subquery
409 # Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
413 INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
414 INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
415 INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
416 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
421 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
427 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
433 SELECT * FROM v9 ORDER BY 1 DESC;
439 SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
445 SELECT * FROM v10 ORDER BY 1;
449 # Tables with columns having peculiar quoted names used in views
454 CREATE TABLE t3("9" integer, [4] text);
455 INSERT INTO t3 VALUES(1,2);
456 CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
457 CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
458 SELECT * FROM v_t3_a;
463 SELECT * FROM v_t3_b;
469 CREATE TABLE t4(a COLLATE NOCASE);
470 INSERT INTO t4 VALUES('This');
471 INSERT INTO t4 VALUES('this');
472 INSERT INTO t4 VALUES('THIS');
473 SELECT * FROM t4 WHERE a = 'THIS';
479 SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS';
485 CREATE VIEW v11 AS SELECT * FROM t4;
486 SELECT * FROM v11 WHERE a = 'THIS';
490 # Ticket #1270: Do not allow parameters in view definitions.
494 CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=?
496 } {1 {parameters are not allowed in views}}
499 CREATE VIEW v12(x) AS SELECT a FROM t1 WHERE b=?
501 } {1 {parameters are not allowed in views}}
507 ATTACH 'test2.db' AS two;
508 CREATE TABLE two.t2(x,y);
509 CREATE VIEW v13 AS SELECT y FROM two.t2;
511 } {1 {view v13 cannot reference objects in database two}}
518 CREATE TEMP VIEW t1 AS SELECT a,b FROM t1;
519 SELECT * FROM temp.t1;
521 } {1 {view t1 is circularly defined}}
524 DROP VIEW IF EXISTS temp.t1;
525 CREATE TEMP VIEW t1(a,b) AS SELECT a,b FROM t1;
526 SELECT * FROM temp.t1;
528 } {1 {view t1 is circularly defined}}
530 # Tickets #1688, #1709
534 CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1;
535 SELECT * FROM v15 LIMIT 1;
540 SELECT x, y FROM v15 LIMIT 1
546 CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1;
551 SELECT sql FROM sqlite_master WHERE name='v1'
553 } {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}}
556 DROP VIEW IF EXISTS nosuchview
560 # correct error message when attempting to drop a view that does not
567 } {1 {no such view: nosuchview}}
570 DROP VIEW main.nosuchview
572 } {1 {no such view: main.nosuchview}}
578 CREATE TABLE t1(a, b, c);
579 INSERT INTO t1 VALUES(1, 2, 3);
580 INSERT INTO t1 VALUES(4, 5, 6);
582 CREATE VIEW vv1 AS SELECT * FROM t1;
583 CREATE VIEW vv2 AS SELECT * FROM vv1;
584 CREATE VIEW vv3 AS SELECT * FROM vv2;
585 CREATE VIEW vv4 AS SELECT * FROM vv3;
586 CREATE VIEW vv5 AS SELECT * FROM vv4;
593 # Make sure "rowid" columns in a view are named correctly.
597 CREATE VIEW v3308a AS SELECT rowid, * FROM t1;
602 } {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6}
605 CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1;
610 } {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11}
613 CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1;
618 } {rowid 1 a 1 x 5 rowid 2 a 4 x 11}
620 # Ticket #3539 had this crashing (see commit [5940]).
623 DROP TABLE IF EXISTS t1;
624 DROP VIEW IF EXISTS v1;
626 CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1);
630 # Ticket [d58ccbb3f1b]: Prevent Table.nRef overflow.
636 INSERT INTO t1 VALUES(5);
637 CREATE VIEW v1 AS SELECT x*2 FROM t1;
638 CREATE VIEW v2 AS SELECT * FROM v1 UNION SELECT * FROM v1;
639 CREATE VIEW v4 AS SELECT * FROM v2 UNION SELECT * FROM v2;
640 CREATE VIEW v8 AS SELECT * FROM v4 UNION SELECT * FROM v4;
641 CREATE VIEW v16 AS SELECT * FROM v8 UNION SELECT * FROM v8;
642 CREATE VIEW v32 AS SELECT * FROM v16 UNION SELECT * FROM v16;
643 CREATE VIEW v64 AS SELECT * FROM v32 UNION SELECT * FROM v32;
644 CREATE VIEW v128 AS SELECT * FROM v64 UNION SELECT * FROM v64;
645 CREATE VIEW v256 AS SELECT * FROM v128 UNION SELECT * FROM v128;
646 CREATE VIEW v512 AS SELECT * FROM v256 UNION SELECT * FROM v256;
647 CREATE VIEW v1024 AS SELECT * FROM v512 UNION SELECT * FROM v512;
648 CREATE VIEW v2048 AS SELECT * FROM v1024 UNION SELECT * FROM v1024;
649 CREATE VIEW v4096 AS SELECT * FROM v2048 UNION SELECT * FROM v2048;
650 CREATE VIEW v8192 AS SELECT * FROM v4096 UNION SELECT * FROM v4096;
651 CREATE VIEW v16384 AS SELECT * FROM v8192 UNION SELECT * FROM v8192;
652 CREATE VIEW v32768 AS SELECT * FROM v16384 UNION SELECT * FROM v16384;
653 SELECT * FROM v32768 UNION SELECT * FROM v32768;
655 } {1 {too many references to "v1": max 65535}}
658 db progress 1000 {expr 1}
660 SELECT * FROM v32768;
667 do_execsql_test view-22.1 {
668 CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS '';
673 db eval {SELECT * FROM x1} x break
674 lsort [array names x]