xref: /sqlite-3.40.0/test/view.test (revision 4dfe98a8)
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"}}
164
165ifcapable compound {
166do_test  view-3.4 {
167  execsql2 {
168    CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
169    SELECT * FROM v3 LIMIT 4;
170  }
171} {a 2 a 3 a 5 a 6}
172do_test view-3.5 {
173  execsql2 {
174    CREATE VIEW v4 AS
175      SELECT a, b FROM t1
176      UNION
177      SELECT b AS 'x', a AS 'y' FROM t1
178      ORDER BY x, y;
179    SELECT b FROM v4 ORDER BY b LIMIT 4;
180  }
181} {b 2 b 3 b 5 b 6}
182} ;# ifcapable compound
183
184
185do_test view-4.1 {
186  catchsql {
187    DROP VIEW t1;
188  }
189} {1 {use DROP TABLE to delete table t1}}
190do_test view-4.2 {
191  execsql {
192    SELECT 1 FROM t1 LIMIT 1;
193  }
194} 1
195do_test view-4.3 {
196  catchsql {
197    DROP TABLE v1;
198  }
199} {1 {use DROP VIEW to delete view v1}}
200do_test view-4.4 {
201  execsql {
202     SELECT 1 FROM v1 LIMIT 1;
203  }
204} {1}
205do_test view-4.5 {
206  catchsql {
207    CREATE INDEX i1v1 ON v1(xyz);
208  }
209} {1 {views may not be indexed}}
210
211do_test view-5.1 {
212  execsql {
213    CREATE TABLE t2(y,a);
214    INSERT INTO t2 VALUES(22,2);
215    INSERT INTO t2 VALUES(33,3);
216    INSERT INTO t2 VALUES(44,4);
217    INSERT INTO t2 VALUES(55,5);
218    SELECT * FROM t2;
219  }
220} {22 2 33 3 44 4 55 5}
221do_test view-5.2 {
222  execsql {
223    CREATE VIEW v5 AS
224      SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
225    SELECT * FROM v5;
226  }
227} {1 22 4 55}
228
229# Verify that the view v5 gets flattened.  see sqliteFlattenSubquery().
230# This will only work if EXPLAIN is enabled.
231# Ticket #272
232#
233ifcapable {explain} {
234do_test view-5.3 {
235  lsearch [execsql {
236    EXPLAIN SELECT * FROM v5;
237  }] OpenEphemeral
238} {-1}
239do_test view-5.4 {
240  execsql {
241    SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
242  }
243} {1 22 22 2 4 55 55 5}
244do_test view-5.5 {
245  lsearch [execsql {
246    EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
247  }] OpenEphemeral
248} {-1}
249do_test view-5.6 {
250  execsql {
251    SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
252  }
253} {22 2 1 22 55 5 4 55}
254do_test view-5.7 {
255  lsearch [execsql {
256    EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
257  }] OpenEphemeral
258} {-1}
259do_test view-5.8 {
260  execsql {
261    SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
262  }
263} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
264do_test view-5.9 {
265  lsearch [execsql {
266    EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
267  }] OpenEphemeral
268} {-1}
269} ;# endif explain
270
271do_test view-6.1 {
272  execsql {
273    SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
274  }
275} {7 8 9 10 27}
276do_test view-6.2 {
277  execsql {
278    SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
279  }
280} {11 12 13 14 39}
281
282do_test view-7.1 {
283  execsql {
284    CREATE TABLE test1(id integer primary key, a);
285    CREATE TABLE test2(id integer, b);
286    INSERT INTO test1 VALUES(1,2);
287    INSERT INTO test2 VALUES(1,3);
288    CREATE VIEW test AS
289      SELECT test1.id, a, b
290      FROM test1 JOIN test2 ON test2.id=test1.id;
291    SELECT * FROM test;
292  }
293} {1 2 3}
294do_test view-7.2 {
295  db close
296  sqlite3 db test.db
297  execsql {
298    SELECT * FROM test;
299  }
300} {1 2 3}
301do_test view-7.3 {
302  execsql {
303    DROP VIEW test;
304    CREATE VIEW test AS
305      SELECT test1.id, a, b
306      FROM test1 JOIN test2 USING(id);
307    SELECT * FROM test;
308  }
309} {1 2 3}
310do_test view-7.4 {
311  db close
312  sqlite3 db test.db
313  execsql {
314    SELECT * FROM test;
315  }
316} {1 2 3}
317do_test view-7.5 {
318  execsql {
319    DROP VIEW test;
320    CREATE VIEW test AS
321      SELECT test1.id, a, b
322      FROM test1 NATURAL JOIN test2;
323    SELECT * FROM test;
324  }
325} {1 2 3}
326do_test view-7.6 {
327  db close
328  sqlite3 db test.db
329  execsql {
330    SELECT * FROM test;
331  }
332} {1 2 3}
333
334do_test view-8.1 {
335  execsql {
336    CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
337    SELECT * FROM v6 ORDER BY xyz;
338  }
339} {7 2 13 5 19 8 27 12}
340do_test view-8.2 {
341  db close
342  sqlite3 db test.db
343  execsql {
344    SELECT * FROM v6 ORDER BY xyz;
345  }
346} {7 2 13 5 19 8 27 12}
347do_test view-8.3 {
348  execsql {
349    CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6;
350    SELECT * FROM v7 ORDER BY a;
351  }
352} {9 18 27 39}
353
354ifcapable subquery {
355  do_test view-8.4 {
356    execsql {
357      CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
358        (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
359      SELECT * FROM v8;
360    }
361  } 3
362  do_test view-8.5 {
363    execsql {
364      SELECT mx+10, mx*2 FROM v8;
365    }
366  } {13 6}
367  do_test view-8.6 {
368    execsql {
369      SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
370    }
371  } {13 7}
372  do_test view-8.7 {
373    execsql {
374      SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
375    }
376  } {13 13 13 19 13 27}
377} ;# ifcapable subquery
378
379# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
380#
381do_test view-9.1 {
382  execsql {
383    INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
384    INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
385    INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
386    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
387  }
388} {1 2 4 8}
389do_test view-9.2 {
390  execsql {
391    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
392  }
393} {1 2 4}
394do_test view-9.3 {
395  execsql {
396    CREATE VIEW v9 AS
397       SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
398    SELECT * FROM v9;
399  }
400} {1 2 4}
401do_test view-9.4 {
402  execsql {
403    SELECT * FROM v9 ORDER BY 1 DESC;
404  }
405} {4 2 1}
406do_test view-9.5 {
407  execsql {
408    CREATE VIEW v10 AS
409       SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
410    SELECT * FROM v10;
411  }
412} {5 1 4 2 3 4}
413do_test view-9.6 {
414  execsql {
415    SELECT * FROM v10 ORDER BY 1;
416  }
417} {3 4 4 2 5 1}
418
419# Tables with columns having peculiar quoted names used in views
420# Ticket #756.
421#
422do_test view-10.1 {
423  execsql {
424    CREATE TABLE t3("9" integer, [4] text);
425    INSERT INTO t3 VALUES(1,2);
426    CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
427    CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
428    SELECT * FROM v_t3_a;
429  }
430} {1}
431do_test view-10.2 {
432  execsql {
433    SELECT * FROM v_t3_b;
434  }
435} {2}
436
437do_test view-11.1 {
438  execsql {
439    CREATE TABLE t4(a COLLATE NOCASE);
440    INSERT INTO t4 VALUES('This');
441    INSERT INTO t4 VALUES('this');
442    INSERT INTO t4 VALUES('THIS');
443    SELECT * FROM t4 WHERE a = 'THIS';
444  }
445} {This this THIS}
446ifcapable subquery {
447  do_test view-11.2 {
448    execsql {
449      SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS';
450    }
451  } {This this THIS}
452}
453do_test view-11.3 {
454  execsql {
455    CREATE VIEW v11 AS SELECT * FROM t4;
456    SELECT * FROM v11 WHERE a = 'THIS';
457  }
458} {This this THIS}
459
460# Ticket #1270:  Do not allow parameters in view definitions.
461#
462do_test view-12.1 {
463  catchsql {
464    CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=?
465  }
466} {1 {parameters are not allowed in views}}
467
468ifcapable attach {
469  do_test view-13.1 {
470    forcedelete test2.db
471    catchsql {
472      ATTACH 'test2.db' AS two;
473      CREATE TABLE two.t2(x,y);
474      CREATE VIEW v13 AS SELECT y FROM two.t2;
475    }
476  } {1 {view v13 cannot reference objects in database two}}
477}
478
479# Ticket #1658
480#
481do_test view-14.1 {
482  catchsql {
483    CREATE TEMP VIEW t1 AS SELECT a,b FROM t1;
484    SELECT * FROM temp.t1;
485  }
486} {1 {view t1 is circularly defined}}
487
488# Tickets #1688, #1709
489#
490do_test view-15.1 {
491  execsql2 {
492    CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1;
493    SELECT * FROM v15 LIMIT 1;
494  }
495} {x 2 y 3}
496do_test view-15.2 {
497  execsql2 {
498    SELECT x, y FROM v15 LIMIT 1
499  }
500} {x 2 y 3}
501
502do_test view-16.1 {
503  catchsql {
504    CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1;
505  }
506} {0 {}}
507do_test view-16.2 {
508  execsql {
509    SELECT sql FROM sqlite_master WHERE name='v1'
510  }
511} {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}}
512do_test view-16.3 {
513  catchsql {
514    DROP VIEW IF EXISTS nosuchview
515  }
516} {0 {}}
517
518# correct error message when attempting to drop a view that does not
519# exist.
520#
521do_test view-17.1 {
522  catchsql {
523    DROP VIEW nosuchview
524  }
525} {1 {no such view: nosuchview}}
526do_test view-17.2 {
527  catchsql {
528    DROP VIEW main.nosuchview
529  }
530} {1 {no such view: main.nosuchview}}
531
532do_test view-18.1 {
533  execsql {
534    DROP VIEW t1;
535    DROP TABLE t1;
536    CREATE TABLE t1(a, b, c);
537    INSERT INTO t1 VALUES(1, 2, 3);
538    INSERT INTO t1 VALUES(4, 5, 6);
539
540    CREATE VIEW vv1 AS SELECT * FROM t1;
541    CREATE VIEW vv2 AS SELECT * FROM vv1;
542    CREATE VIEW vv3 AS SELECT * FROM vv2;
543    CREATE VIEW vv4 AS SELECT * FROM vv3;
544    CREATE VIEW vv5 AS SELECT * FROM vv4;
545
546    SELECT * FROM vv5;
547  }
548} {1 2 3 4 5 6}
549
550# Ticket #3308
551# Make sure "rowid" columns in a view are named correctly.
552#
553do_test view-19.1 {
554  execsql {
555    CREATE VIEW v3308a AS SELECT rowid, * FROM t1;
556  }
557  execsql2 {
558    SELECT * FROM v3308a
559  }
560} {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6}
561do_test view-19.2 {
562  execsql {
563    CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1;
564  }
565  execsql2 {
566    SELECT * FROM v3308b
567  }
568} {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11}
569do_test view-19.3 {
570  execsql {
571    CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1;
572  }
573  execsql2 {
574    SELECT * FROM v3308c
575  }
576} {rowid 1 a 1 x 5 rowid 2 a 4 x 11}
577
578# Ticket #3539 had this crashing (see commit [5940]).
579do_test view-20.1 {
580  execsql {
581    DROP TABLE IF EXISTS t1;
582    DROP VIEW IF EXISTS v1;
583    CREATE TABLE t1(c1);
584    CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1);
585  }
586} {}
587
588# Ticket [d58ccbb3f1b]: Prevent Table.nRef overflow.
589db close
590sqlite3 db :memory:
591do_test view-21.1 {
592  catchsql {
593    CREATE TABLE t1(x);
594    INSERT INTO t1 VALUES(5);
595    CREATE VIEW v1 AS SELECT x*2 FROM t1;
596    CREATE VIEW v2 AS SELECT * FROM v1 UNION SELECT * FROM v1;
597    CREATE VIEW v4 AS SELECT * FROM v2 UNION SELECT * FROM v2;
598    CREATE VIEW v8 AS SELECT * FROM v4 UNION SELECT * FROM v4;
599    CREATE VIEW v16 AS SELECT * FROM v8 UNION SELECT * FROM v8;
600    CREATE VIEW v32 AS SELECT * FROM v16 UNION SELECT * FROM v16;
601    CREATE VIEW v64 AS SELECT * FROM v32 UNION SELECT * FROM v32;
602    CREATE VIEW v128 AS SELECT * FROM v64 UNION SELECT * FROM v64;
603    CREATE VIEW v256 AS SELECT * FROM v128 UNION SELECT * FROM v128;
604    CREATE VIEW v512 AS SELECT * FROM v256 UNION SELECT * FROM v256;
605    CREATE VIEW v1024 AS SELECT * FROM v512 UNION SELECT * FROM v512;
606    CREATE VIEW v2048 AS SELECT * FROM v1024 UNION SELECT * FROM v1024;
607    CREATE VIEW v4096 AS SELECT * FROM v2048 UNION SELECT * FROM v2048;
608    CREATE VIEW v8192 AS SELECT * FROM v4096 UNION SELECT * FROM v4096;
609    CREATE VIEW v16384 AS SELECT * FROM v8192 UNION SELECT * FROM v8192;
610    CREATE VIEW v32768 AS SELECT * FROM v16384 UNION SELECT * FROM v16384;
611    SELECT * FROM v32768 UNION SELECT * FROM v32768;
612  }
613} {1 {too many references to "v1": max 65535}}
614ifcapable progress {
615  do_test view-21.2 {
616    db progress 1000 {expr 1}
617    catchsql {
618      SELECT * FROM v32768;
619    }
620  } {1 interrupted}
621}
622
623db close
624sqlite3 db :memory:
625do_execsql_test view-22.1 {
626  CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS '';
627  SELECT * FROM x1;
628} {123 234 345}
629do_test view-22.2 {
630  unset -nocomplain x
631  db eval {SELECT * FROM x1} x break
632  lsort [array names x]
633} {{} * :1 :2}
634
635
636finish_test
637