xref: /sqlite-3.40.0/test/view.test (revision c56fac74)
1# 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#
14# $Id: view.test,v 1.39 2008/12/14 14:45:21 danielk1977 Exp $
15set testdir [file dirname $argv0]
16source $testdir/tester.tcl
17
18# Omit this entire file if the library is not configured with views enabled.
19ifcapable !view {
20  finish_test
21  return
22}
23
24do_test view-1.0 {
25  execsql {
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);
30    SELECT * FROM t1;
31  }
32} {1 2 3 4 5 6 7 8 9}
33
34do_test view-1.1 {
35  execsql {
36    BEGIN;
37    CREATE VIEW IF NOT EXISTS v1 AS SELECT a,b FROM t1;
38    SELECT * FROM v1 ORDER BY a;
39  }
40} {1 2 4 5 7 8}
41do_test view-1.2 {
42  catchsql {
43    ROLLBACK;
44    SELECT * FROM v1 ORDER BY a;
45  }
46} {1 {no such table: v1}}
47do_test view-1.3 {
48  execsql {
49    CREATE VIEW v1 AS SELECT a,b FROM t1;
50    SELECT * FROM v1 ORDER BY a;
51  }
52} {1 2 4 5 7 8}
53do_test view-1.3.1 {
54  db close
55  sqlite3 db test.db
56  execsql {
57    SELECT * FROM v1 ORDER BY a;
58  }
59} {1 2 4 5 7 8}
60do_test view-1.4 {
61  catchsql {
62    DROP VIEW IF EXISTS v1;
63    SELECT * FROM v1 ORDER BY a;
64  }
65} {1 {no such table: v1}}
66do_test view-1.5 {
67  execsql {
68    CREATE VIEW v1 AS SELECT a,b FROM t1;
69    SELECT * FROM v1 ORDER BY a;
70  }
71} {1 2 4 5 7 8}
72do_test view-1.6 {
73  catchsql {
74    DROP TABLE t1;
75    SELECT * FROM v1 ORDER BY a;
76  }
77} {1 {no such table: main.t1}}
78do_test view-1.7 {
79  execsql {
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;
85  }
86} {2 3 5 6 8 9}
87do_test view-1.8 {
88  db close
89  sqlite3 db test.db
90  execsql {
91    SELECT * FROM v1 ORDER BY a;
92  }
93} {2 3 5 6 8 9}
94
95do_test view-2.1 {
96  execsql {
97    CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
98  };  # No semicolon
99  execsql2 {
100    SELECT * FROM v2;
101  }
102} {x 7 a 8 b 9 c 10}
103do_test view-2.2 {
104  catchsql {
105    INSERT INTO v2 VALUES(1,2,3,4);
106  }
107} {1 {cannot modify v2 because it is a view}}
108do_test view-2.3 {
109  catchsql {
110    UPDATE v2 SET a=10 WHERE a=5;
111  }
112} {1 {cannot modify v2 because it is a view}}
113do_test view-2.4 {
114  catchsql {
115    DELETE FROM v2;
116  }
117} {1 {cannot modify v2 because it is a view}}
118do_test view-2.5 {
119  execsql {
120    INSERT INTO t1 VALUES(11,12,13,14);
121    SELECT * FROM v2 ORDER BY x;
122  }
123} {7 8 9 10 11 12 13 14}
124do_test view-2.6 {
125  execsql {
126    SELECT x FROM v2 WHERE a>10
127  }
128} {11}
129
130# Test that column name of views are generated correctly.
131#
132do_test view-3.1 {
133  execsql2 {
134    SELECT * FROM v1 LIMIT 1
135  }
136} {a 2 b 3}
137do_test view-3.2 {
138  execsql2 {
139    SELECT * FROM v2 LIMIT 1
140  }
141} {x 7 a 8 b 9 c 10}
142do_test view-3.3.1 {
143  execsql2 {
144    DROP VIEW v1;
145    CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
146    SELECT * FROM v1 LIMIT 1
147  }
148} {xyz 2 pqr 7 c-b 1}
149do_test view-3.3.2 {
150  execsql2 {
151    CREATE VIEW v1b AS SELECT t1.a, b+c, t1.c FROM t1;
152    SELECT * FROM v1b LIMIT 1
153  }
154} {a 2 b+c 7 c 4}
155do_test view-3.3.3 {
156  execsql2 {
157    CREATE VIEW v1c(x,y,z) AS SELECT a, b+c, c-b FROM t1;
158    SELECT * FROM v1c LIMIT 1;
159  }
160} {x 2 y 7 z 1}
161do_catchsql_test view-3.3.4 {
162  CREATE VIEW v1err(x,y DESC,z) AS SELECT a, b+c, c-b FROM t1;
163} {1 {syntax error after column name "y"}}
164do_catchsql_test view-3.3.5 {
165  DROP VIEW IF EXISTS v1err;
166  CREATE VIEW v1err(x,y) AS SELECT a, b+c, c-b FROM t1;
167  SELECT * FROM v1err;
168} {1 {expected 2 columns for 'v1err' but got 3}}
169do_catchsql_test view-3.3.6 {
170  DROP VIEW IF EXISTS v1err;
171  CREATE VIEW v1err(w,x,y,z) AS SELECT a, b+c, c-b FROM t1;
172  SELECT * FROM v1err;
173} {1 {expected 4 columns for 'v1err' but got 3}}
174
175ifcapable compound {
176do_test  view-3.4 {
177  execsql2 {
178    CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
179    SELECT * FROM v3 LIMIT 4;
180  }
181} {a 2 a 3 a 5 a 6}
182do_test view-3.5 {
183  execsql2 {
184    CREATE VIEW v4 AS
185      SELECT a, b FROM t1
186      UNION
187      SELECT b AS 'x', a AS 'y' FROM t1
188      ORDER BY x, y;
189    SELECT b FROM v4 ORDER BY b LIMIT 4;
190  }
191} {b 2 b 3 b 5 b 6}
192} ;# ifcapable compound
193
194
195do_test view-4.1 {
196  catchsql {
197    DROP VIEW t1;
198  }
199} {1 {use DROP TABLE to delete table t1}}
200do_test view-4.2 {
201  execsql {
202    SELECT 1 FROM t1 LIMIT 1;
203  }
204} 1
205do_test view-4.3 {
206  catchsql {
207    DROP TABLE v1;
208  }
209} {1 {use DROP VIEW to delete view v1}}
210do_test view-4.4 {
211  execsql {
212     SELECT 1 FROM v1 LIMIT 1;
213  }
214} {1}
215do_test view-4.5 {
216  catchsql {
217    CREATE INDEX i1v1 ON v1(xyz);
218  }
219} {1 {views may not be indexed}}
220
221do_test view-5.1 {
222  execsql {
223    CREATE TABLE t2(y,a);
224    INSERT INTO t2 VALUES(22,2);
225    INSERT INTO t2 VALUES(33,3);
226    INSERT INTO t2 VALUES(44,4);
227    INSERT INTO t2 VALUES(55,5);
228    SELECT * FROM t2;
229  }
230} {22 2 33 3 44 4 55 5}
231do_test view-5.2 {
232  execsql {
233    CREATE VIEW v5 AS
234      SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
235    SELECT * FROM v5;
236  }
237} {1 22 4 55}
238
239# Verify that the view v5 gets flattened.  see sqliteFlattenSubquery().
240# This will only work if EXPLAIN is enabled.
241# Ticket #272
242#
243ifcapable {explain} {
244do_test view-5.3 {
245  lsearch [execsql {
246    EXPLAIN SELECT * FROM v5;
247  }] OpenEphemeral
248} {-1}
249do_test view-5.4 {
250  execsql {
251    SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
252  }
253} {1 22 22 2 4 55 55 5}
254do_test view-5.5 {
255  lsearch [execsql {
256    EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
257  }] OpenEphemeral
258} {-1}
259do_test view-5.6 {
260  execsql {
261    SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
262  }
263} {22 2 1 22 55 5 4 55}
264do_test view-5.7 {
265  lsearch [execsql {
266    EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
267  }] OpenEphemeral
268} {-1}
269do_test view-5.8 {
270  execsql {
271    SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
272  }
273} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
274do_test view-5.9 {
275  lsearch [execsql {
276    EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
277  }] OpenEphemeral
278} {-1}
279} ;# endif explain
280
281do_test view-6.1 {
282  execsql {
283    SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
284  }
285} {7 8 9 10 27}
286do_test view-6.2 {
287  execsql {
288    SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
289  }
290} {11 12 13 14 39}
291
292do_test view-7.1 {
293  execsql {
294    CREATE TABLE test1(id integer primary key, a);
295    CREATE TABLE test2(id integer, b);
296    INSERT INTO test1 VALUES(1,2);
297    INSERT INTO test2 VALUES(1,3);
298    CREATE VIEW test AS
299      SELECT test1.id, a, b
300      FROM test1 JOIN test2 ON test2.id=test1.id;
301    SELECT * FROM test;
302  }
303} {1 2 3}
304do_test view-7.2 {
305  db close
306  sqlite3 db test.db
307  execsql {
308    SELECT * FROM test;
309  }
310} {1 2 3}
311do_test view-7.3 {
312  execsql {
313    DROP VIEW test;
314    CREATE VIEW test AS
315      SELECT test1.id, a, b
316      FROM test1 JOIN test2 USING(id);
317    SELECT * FROM test;
318  }
319} {1 2 3}
320do_test view-7.4 {
321  db close
322  sqlite3 db test.db
323  execsql {
324    SELECT * FROM test;
325  }
326} {1 2 3}
327do_test view-7.5 {
328  execsql {
329    DROP VIEW test;
330    CREATE VIEW test AS
331      SELECT test1.id, a, b
332      FROM test1 NATURAL JOIN test2;
333    SELECT * FROM test;
334  }
335} {1 2 3}
336do_test view-7.6 {
337  db close
338  sqlite3 db test.db
339  execsql {
340    SELECT * FROM test;
341  }
342} {1 2 3}
343
344do_test view-8.1 {
345  execsql {
346    CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
347    SELECT * FROM v6 ORDER BY xyz;
348  }
349} {7 2 13 5 19 8 27 12}
350do_test view-8.2 {
351  db close
352  sqlite3 db test.db
353  execsql {
354    SELECT * FROM v6 ORDER BY xyz;
355  }
356} {7 2 13 5 19 8 27 12}
357do_test view-8.3 {
358  execsql {
359    CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6;
360    SELECT * FROM v7 ORDER BY a;
361  }
362} {9 18 27 39}
363
364ifcapable subquery {
365  do_test view-8.4 {
366    execsql {
367      CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
368        (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
369      SELECT * FROM v8;
370    }
371  } 3
372  do_test view-8.5 {
373    execsql {
374      SELECT mx+10, mx*2 FROM v8;
375    }
376  } {13 6}
377  do_test view-8.6 {
378    execsql {
379      SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
380    }
381  } {13 7}
382  do_test view-8.7 {
383    execsql {
384      SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
385    }
386  } {13 13 13 19 13 27}
387} ;# ifcapable subquery
388
389# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
390#
391do_test view-9.1 {
392  execsql {
393    INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
394    INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
395    INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
396    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
397  }
398} {1 2 4 8}
399do_test view-9.2 {
400  execsql {
401    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
402  }
403} {1 2 4}
404do_test view-9.3 {
405  execsql {
406    CREATE VIEW v9 AS
407       SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
408    SELECT * FROM v9;
409  }
410} {1 2 4}
411do_test view-9.4 {
412  execsql {
413    SELECT * FROM v9 ORDER BY 1 DESC;
414  }
415} {4 2 1}
416do_test view-9.5 {
417  execsql {
418    CREATE VIEW v10 AS
419       SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
420    SELECT * FROM v10;
421  }
422} {5 1 4 2 3 4}
423do_test view-9.6 {
424  execsql {
425    SELECT * FROM v10 ORDER BY 1;
426  }
427} {3 4 4 2 5 1}
428
429# Tables with columns having peculiar quoted names used in views
430# Ticket #756.
431#
432do_test view-10.1 {
433  execsql {
434    CREATE TABLE t3("9" integer, [4] text);
435    INSERT INTO t3 VALUES(1,2);
436    CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
437    CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
438    SELECT * FROM v_t3_a;
439  }
440} {1}
441do_test view-10.2 {
442  execsql {
443    SELECT * FROM v_t3_b;
444  }
445} {2}
446
447do_test view-11.1 {
448  execsql {
449    CREATE TABLE t4(a COLLATE NOCASE);
450    INSERT INTO t4 VALUES('This');
451    INSERT INTO t4 VALUES('this');
452    INSERT INTO t4 VALUES('THIS');
453    SELECT * FROM t4 WHERE a = 'THIS';
454  }
455} {This this THIS}
456ifcapable subquery {
457  do_test view-11.2 {
458    execsql {
459      SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS';
460    }
461  } {This this THIS}
462}
463do_test view-11.3 {
464  execsql {
465    CREATE VIEW v11 AS SELECT * FROM t4;
466    SELECT * FROM v11 WHERE a = 'THIS';
467  }
468} {This this THIS}
469
470# Ticket #1270:  Do not allow parameters in view definitions.
471#
472do_test view-12.1 {
473  catchsql {
474    CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=?
475  }
476} {1 {parameters are not allowed in views}}
477do_test view-12.2 {
478  catchsql {
479    CREATE VIEW v12(x) AS SELECT a FROM t1 WHERE b=?
480  }
481} {1 {parameters are not allowed in views}}
482
483ifcapable attach {
484  do_test view-13.1 {
485    forcedelete test2.db
486    catchsql {
487      ATTACH 'test2.db' AS two;
488      CREATE TABLE two.t2(x,y);
489      CREATE VIEW v13 AS SELECT y FROM two.t2;
490    }
491  } {1 {view v13 cannot reference objects in database two}}
492}
493
494# Ticket #1658
495#
496do_test view-14.1 {
497  catchsql {
498    CREATE TEMP VIEW t1 AS SELECT a,b FROM t1;
499    SELECT * FROM temp.t1;
500  }
501} {1 {view t1 is circularly defined}}
502do_test view-14.2 {
503  catchsql {
504    DROP VIEW IF EXISTS temp.t1;
505    CREATE TEMP VIEW t1(a,b) AS SELECT a,b FROM t1;
506    SELECT * FROM temp.t1;
507  }
508} {1 {view t1 is circularly defined}}
509
510# Tickets #1688, #1709
511#
512do_test view-15.1 {
513  execsql2 {
514    CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1;
515    SELECT * FROM v15 LIMIT 1;
516  }
517} {x 2 y 3}
518do_test view-15.2 {
519  execsql2 {
520    SELECT x, y FROM v15 LIMIT 1
521  }
522} {x 2 y 3}
523
524do_test view-16.1 {
525  catchsql {
526    CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1;
527  }
528} {0 {}}
529do_test view-16.2 {
530  execsql {
531    SELECT sql FROM sqlite_master WHERE name='v1'
532  }
533} {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}}
534do_test view-16.3 {
535  catchsql {
536    DROP VIEW IF EXISTS nosuchview
537  }
538} {0 {}}
539
540# correct error message when attempting to drop a view that does not
541# exist.
542#
543do_test view-17.1 {
544  catchsql {
545    DROP VIEW nosuchview
546  }
547} {1 {no such view: nosuchview}}
548do_test view-17.2 {
549  catchsql {
550    DROP VIEW main.nosuchview
551  }
552} {1 {no such view: main.nosuchview}}
553
554do_test view-18.1 {
555  execsql {
556    DROP VIEW t1;
557    DROP TABLE t1;
558    CREATE TABLE t1(a, b, c);
559    INSERT INTO t1 VALUES(1, 2, 3);
560    INSERT INTO t1 VALUES(4, 5, 6);
561
562    CREATE VIEW vv1 AS SELECT * FROM t1;
563    CREATE VIEW vv2 AS SELECT * FROM vv1;
564    CREATE VIEW vv3 AS SELECT * FROM vv2;
565    CREATE VIEW vv4 AS SELECT * FROM vv3;
566    CREATE VIEW vv5 AS SELECT * FROM vv4;
567
568    SELECT * FROM vv5;
569  }
570} {1 2 3 4 5 6}
571
572# Ticket #3308
573# Make sure "rowid" columns in a view are named correctly.
574#
575do_test view-19.1 {
576  execsql {
577    CREATE VIEW v3308a AS SELECT rowid, * FROM t1;
578  }
579  execsql2 {
580    SELECT * FROM v3308a
581  }
582} {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6}
583do_test view-19.2 {
584  execsql {
585    CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1;
586  }
587  execsql2 {
588    SELECT * FROM v3308b
589  }
590} {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11}
591do_test view-19.3 {
592  execsql {
593    CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1;
594  }
595  execsql2 {
596    SELECT * FROM v3308c
597  }
598} {rowid 1 a 1 x 5 rowid 2 a 4 x 11}
599
600# Ticket #3539 had this crashing (see commit [5940]).
601do_test view-20.1 {
602  execsql {
603    DROP TABLE IF EXISTS t1;
604    DROP VIEW IF EXISTS v1;
605    CREATE TABLE t1(c1);
606    CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1);
607  }
608} {}
609
610# Ticket [d58ccbb3f1b]: Prevent Table.nRef overflow.
611db close
612sqlite3 db :memory:
613do_test view-21.1 {
614  catchsql {
615    CREATE TABLE t1(x);
616    INSERT INTO t1 VALUES(5);
617    CREATE VIEW v1 AS SELECT x*2 FROM t1;
618    CREATE VIEW v2 AS SELECT * FROM v1 UNION SELECT * FROM v1;
619    CREATE VIEW v4 AS SELECT * FROM v2 UNION SELECT * FROM v2;
620    CREATE VIEW v8 AS SELECT * FROM v4 UNION SELECT * FROM v4;
621    CREATE VIEW v16 AS SELECT * FROM v8 UNION SELECT * FROM v8;
622    CREATE VIEW v32 AS SELECT * FROM v16 UNION SELECT * FROM v16;
623    CREATE VIEW v64 AS SELECT * FROM v32 UNION SELECT * FROM v32;
624    CREATE VIEW v128 AS SELECT * FROM v64 UNION SELECT * FROM v64;
625    CREATE VIEW v256 AS SELECT * FROM v128 UNION SELECT * FROM v128;
626    CREATE VIEW v512 AS SELECT * FROM v256 UNION SELECT * FROM v256;
627    CREATE VIEW v1024 AS SELECT * FROM v512 UNION SELECT * FROM v512;
628    CREATE VIEW v2048 AS SELECT * FROM v1024 UNION SELECT * FROM v1024;
629    CREATE VIEW v4096 AS SELECT * FROM v2048 UNION SELECT * FROM v2048;
630    CREATE VIEW v8192 AS SELECT * FROM v4096 UNION SELECT * FROM v4096;
631    CREATE VIEW v16384 AS SELECT * FROM v8192 UNION SELECT * FROM v8192;
632    CREATE VIEW v32768 AS SELECT * FROM v16384 UNION SELECT * FROM v16384;
633    SELECT * FROM v32768 UNION SELECT * FROM v32768;
634  }
635} {1 {too many references to "v1": max 65535}}
636ifcapable progress {
637  do_test view-21.2 {
638    db progress 1000 {expr 1}
639    catchsql {
640      SELECT * FROM v32768;
641    }
642  } {1 interrupted}
643}
644
645db close
646sqlite3 db :memory:
647do_execsql_test view-22.1 {
648  CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS '';
649  SELECT * FROM x1;
650} {123 234 345}
651do_test view-22.2 {
652  unset -nocomplain x
653  db eval {SELECT * FROM x1} x break
654  lsort [array names x]
655} {{} * :1 :2}
656
657
658finish_test
659