xref: /onnv-gate/usr/src/lib/libsqlite/test/view.test (revision 4520:7dbeadedd7fe)
1*4520Snw141292
2*4520Snw141292#pragma ident	"%Z%%M%	%I%	%E% SMI"
3*4520Snw141292
4*4520Snw141292# 2002 February 26
5*4520Snw141292#
6*4520Snw141292# The author disclaims copyright to this source code.  In place of
7*4520Snw141292# a legal notice, here is a blessing:
8*4520Snw141292#
9*4520Snw141292#    May you do good and not evil.
10*4520Snw141292#    May you find forgiveness for yourself and forgive others.
11*4520Snw141292#    May you share freely, never taking more than you give.
12*4520Snw141292#
13*4520Snw141292#***********************************************************************
14*4520Snw141292# This file implements regression tests for SQLite library.  The
15*4520Snw141292# focus of this file is testing VIEW statements.
16*4520Snw141292#
17*4520Snw141292# $Id: view.test,v 1.16.2.1 2004/07/20 00:20:47 drh Exp $
18*4520Snw141292set testdir [file dirname $argv0]
19*4520Snw141292source $testdir/tester.tcl
20*4520Snw141292
21*4520Snw141292do_test view-1.0 {
22*4520Snw141292  execsql {
23*4520Snw141292    CREATE TABLE t1(a,b,c);
24*4520Snw141292    INSERT INTO t1 VALUES(1,2,3);
25*4520Snw141292    INSERT INTO t1 VALUES(4,5,6);
26*4520Snw141292    INSERT INTO t1 VALUES(7,8,9);
27*4520Snw141292    SELECT * FROM t1;
28*4520Snw141292  }
29*4520Snw141292} {1 2 3 4 5 6 7 8 9}
30*4520Snw141292
31*4520Snw141292do_test view-1.1 {
32*4520Snw141292  execsql {
33*4520Snw141292    BEGIN;
34*4520Snw141292    CREATE VIEW v1 AS SELECT a,b FROM t1;
35*4520Snw141292    SELECT * FROM v1 ORDER BY a;
36*4520Snw141292  }
37*4520Snw141292} {1 2 4 5 7 8}
38*4520Snw141292do_test view-1.2 {
39*4520Snw141292  catchsql {
40*4520Snw141292    ROLLBACK;
41*4520Snw141292    SELECT * FROM v1 ORDER BY a;
42*4520Snw141292  }
43*4520Snw141292} {1 {no such table: v1}}
44*4520Snw141292do_test view-1.3 {
45*4520Snw141292  execsql {
46*4520Snw141292    CREATE VIEW v1 AS SELECT a,b FROM t1;
47*4520Snw141292    SELECT * FROM v1 ORDER BY a;
48*4520Snw141292  }
49*4520Snw141292} {1 2 4 5 7 8}
50*4520Snw141292do_test view-1.3.1 {
51*4520Snw141292  db close
52*4520Snw141292  sqlite db test.db
53*4520Snw141292  execsql {
54*4520Snw141292    SELECT * FROM v1 ORDER BY a;
55*4520Snw141292  }
56*4520Snw141292} {1 2 4 5 7 8}
57*4520Snw141292do_test view-1.4 {
58*4520Snw141292  catchsql {
59*4520Snw141292    DROP VIEW v1;
60*4520Snw141292    SELECT * FROM v1 ORDER BY a;
61*4520Snw141292  }
62*4520Snw141292} {1 {no such table: v1}}
63*4520Snw141292do_test view-1.5 {
64*4520Snw141292  execsql {
65*4520Snw141292    CREATE VIEW v1 AS SELECT a,b FROM t1;
66*4520Snw141292    SELECT * FROM v1 ORDER BY a;
67*4520Snw141292  }
68*4520Snw141292} {1 2 4 5 7 8}
69*4520Snw141292do_test view-1.6 {
70*4520Snw141292  catchsql {
71*4520Snw141292    DROP TABLE t1;
72*4520Snw141292    SELECT * FROM v1 ORDER BY a;
73*4520Snw141292  }
74*4520Snw141292} {1 {no such table: main.t1}}
75*4520Snw141292do_test view-1.7 {
76*4520Snw141292  execsql {
77*4520Snw141292    CREATE TABLE t1(x,a,b,c);
78*4520Snw141292    INSERT INTO t1 VALUES(1,2,3,4);
79*4520Snw141292    INSERT INTO t1 VALUES(4,5,6,7);
80*4520Snw141292    INSERT INTO t1 VALUES(7,8,9,10);
81*4520Snw141292    SELECT * FROM v1 ORDER BY a;
82*4520Snw141292  }
83*4520Snw141292} {2 3 5 6 8 9}
84*4520Snw141292do_test view-1.8 {
85*4520Snw141292  db close
86*4520Snw141292  sqlite db test.db
87*4520Snw141292  execsql {
88*4520Snw141292    SELECT * FROM v1 ORDER BY a;
89*4520Snw141292  }
90*4520Snw141292} {2 3 5 6 8 9}
91*4520Snw141292
92*4520Snw141292do_test view-2.1 {
93*4520Snw141292  execsql {
94*4520Snw141292    CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
95*4520Snw141292  };  # No semicolon
96*4520Snw141292  execsql2 {
97*4520Snw141292    SELECT * FROM v2;
98*4520Snw141292  }
99*4520Snw141292} {x 7 a 8 b 9 c 10}
100*4520Snw141292do_test view-2.2 {
101*4520Snw141292  catchsql {
102*4520Snw141292    INSERT INTO v2 VALUES(1,2,3,4);
103*4520Snw141292  }
104*4520Snw141292} {1 {cannot modify v2 because it is a view}}
105*4520Snw141292do_test view-2.3 {
106*4520Snw141292  catchsql {
107*4520Snw141292    UPDATE v2 SET a=10 WHERE a=5;
108*4520Snw141292  }
109*4520Snw141292} {1 {cannot modify v2 because it is a view}}
110*4520Snw141292do_test view-2.4 {
111*4520Snw141292  catchsql {
112*4520Snw141292    DELETE FROM v2;
113*4520Snw141292  }
114*4520Snw141292} {1 {cannot modify v2 because it is a view}}
115*4520Snw141292do_test view-2.5 {
116*4520Snw141292  execsql {
117*4520Snw141292    INSERT INTO t1 VALUES(11,12,13,14);
118*4520Snw141292    SELECT * FROM v2 ORDER BY x;
119*4520Snw141292  }
120*4520Snw141292} {7 8 9 10 11 12 13 14}
121*4520Snw141292do_test view-2.6 {
122*4520Snw141292  execsql {
123*4520Snw141292    SELECT x FROM v2 WHERE a>10
124*4520Snw141292  }
125*4520Snw141292} {11}
126*4520Snw141292
127*4520Snw141292# Test that column name of views are generated correctly.
128*4520Snw141292#
129*4520Snw141292do_test view-3.1 {
130*4520Snw141292  execsql2 {
131*4520Snw141292    SELECT * FROM v1 LIMIT 1
132*4520Snw141292  }
133*4520Snw141292} {a 2 b 3}
134*4520Snw141292do_test view-3.2 {
135*4520Snw141292  execsql2 {
136*4520Snw141292    SELECT * FROM v2 LIMIT 1
137*4520Snw141292  }
138*4520Snw141292} {x 7 a 8 b 9 c 10}
139*4520Snw141292do_test view-3.3 {
140*4520Snw141292  execsql2 {
141*4520Snw141292    DROP VIEW v1;
142*4520Snw141292    CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
143*4520Snw141292    SELECT * FROM v1 LIMIT 1
144*4520Snw141292  }
145*4520Snw141292} {xyz 2 pqr 7 c-b 1}
146*4520Snw141292do_test  view-3.4 {
147*4520Snw141292  execsql2 {
148*4520Snw141292    CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
149*4520Snw141292    SELECT * FROM v3 LIMIT 4;
150*4520Snw141292  }
151*4520Snw141292} {b 2 b 3 b 5 b 6}
152*4520Snw141292do_test  view-3.5 {
153*4520Snw141292  execsql2 {
154*4520Snw141292    CREATE VIEW v4 AS
155*4520Snw141292      SELECT a, b FROM t1
156*4520Snw141292      UNION
157*4520Snw141292      SELECT b AS 'x', a AS 'y' FROM t1
158*4520Snw141292      ORDER BY x, y;
159*4520Snw141292    SELECT y FROM v4 ORDER BY y LIMIT 4;
160*4520Snw141292  }
161*4520Snw141292} {y 2 y 3 y 5 y 6}
162*4520Snw141292
163*4520Snw141292
164*4520Snw141292do_test view-4.1 {
165*4520Snw141292  catchsql {
166*4520Snw141292    DROP VIEW t1;
167*4520Snw141292  }
168*4520Snw141292} {1 {use DROP TABLE to delete table t1}}
169*4520Snw141292do_test view-4.2 {
170*4520Snw141292  execsql {
171*4520Snw141292    SELECT 1 FROM t1 LIMIT 1;
172*4520Snw141292  }
173*4520Snw141292} 1
174*4520Snw141292do_test view-4.3 {
175*4520Snw141292  catchsql {
176*4520Snw141292    DROP TABLE v1;
177*4520Snw141292  }
178*4520Snw141292} {1 {use DROP VIEW to delete view v1}}
179*4520Snw141292do_test view-4.4 {
180*4520Snw141292  execsql {
181*4520Snw141292     SELECT 1 FROM v1 LIMIT 1;
182*4520Snw141292  }
183*4520Snw141292} {1}
184*4520Snw141292do_test view-4.5 {
185*4520Snw141292  catchsql {
186*4520Snw141292    CREATE INDEX i1v1 ON v1(xyz);
187*4520Snw141292  }
188*4520Snw141292} {1 {views may not be indexed}}
189*4520Snw141292
190*4520Snw141292do_test view-5.1 {
191*4520Snw141292  execsql {
192*4520Snw141292    CREATE TABLE t2(y,a);
193*4520Snw141292    INSERT INTO t2 VALUES(22,2);
194*4520Snw141292    INSERT INTO t2 VALUES(33,3);
195*4520Snw141292    INSERT INTO t2 VALUES(44,4);
196*4520Snw141292    INSERT INTO t2 VALUES(55,5);
197*4520Snw141292    SELECT * FROM t2;
198*4520Snw141292  }
199*4520Snw141292} {22 2 33 3 44 4 55 5}
200*4520Snw141292do_test view-5.2 {
201*4520Snw141292  execsql {
202*4520Snw141292    CREATE VIEW v5 AS
203*4520Snw141292      SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
204*4520Snw141292    SELECT * FROM v5;
205*4520Snw141292  }
206*4520Snw141292} {1 22 4 55}
207*4520Snw141292
208*4520Snw141292# Verify that the view v5 gets flattened.  see sqliteFlattenSubquery().
209*4520Snw141292# Ticket #272
210*4520Snw141292do_test view-5.3 {
211*4520Snw141292  lsearch [execsql {
212*4520Snw141292    EXPLAIN SELECT * FROM v5;
213*4520Snw141292  }] OpenTemp
214*4520Snw141292} {-1}
215*4520Snw141292do_test view-5.4 {
216*4520Snw141292  execsql {
217*4520Snw141292    SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
218*4520Snw141292  }
219*4520Snw141292} {1 22 22 2 4 55 55 5}
220*4520Snw141292do_test view-5.5 {
221*4520Snw141292  lsearch [execsql {
222*4520Snw141292    EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
223*4520Snw141292  }] OpenTemp
224*4520Snw141292} {-1}
225*4520Snw141292do_test view-5.6 {
226*4520Snw141292  execsql {
227*4520Snw141292    SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
228*4520Snw141292  }
229*4520Snw141292} {22 2 1 22 55 5 4 55}
230*4520Snw141292do_test view-5.7 {
231*4520Snw141292  lsearch [execsql {
232*4520Snw141292    EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
233*4520Snw141292  }] OpenTemp
234*4520Snw141292} {-1}
235*4520Snw141292do_test view-5.8 {
236*4520Snw141292  execsql {
237*4520Snw141292    SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
238*4520Snw141292  }
239*4520Snw141292} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
240*4520Snw141292do_test view-5.9 {
241*4520Snw141292  lsearch [execsql {
242*4520Snw141292    EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
243*4520Snw141292  }] OpenTemp
244*4520Snw141292} {-1}
245*4520Snw141292
246*4520Snw141292do_test view-6.1 {
247*4520Snw141292  execsql {
248*4520Snw141292    SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
249*4520Snw141292  }
250*4520Snw141292} {7 8 9 10 27}
251*4520Snw141292do_test view-6.2 {
252*4520Snw141292  execsql {
253*4520Snw141292    SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
254*4520Snw141292  }
255*4520Snw141292} {11 12 13 14 39}
256*4520Snw141292
257*4520Snw141292do_test view-7.1 {
258*4520Snw141292  execsql {
259*4520Snw141292    CREATE TABLE test1(id integer primary key, a);
260*4520Snw141292    CREATE TABLE test2(id integer, b);
261*4520Snw141292    INSERT INTO test1 VALUES(1,2);
262*4520Snw141292    INSERT INTO test2 VALUES(1,3);
263*4520Snw141292    CREATE VIEW test AS
264*4520Snw141292      SELECT test1.id, a, b
265*4520Snw141292      FROM test1 JOIN test2 ON test2.id=test1.id;
266*4520Snw141292    SELECT * FROM test;
267*4520Snw141292  }
268*4520Snw141292} {1 2 3}
269*4520Snw141292do_test view-7.2 {
270*4520Snw141292  db close
271*4520Snw141292  sqlite db test.db
272*4520Snw141292  execsql {
273*4520Snw141292    SELECT * FROM test;
274*4520Snw141292  }
275*4520Snw141292} {1 2 3}
276*4520Snw141292do_test view-7.3 {
277*4520Snw141292  execsql {
278*4520Snw141292    DROP VIEW test;
279*4520Snw141292    CREATE VIEW test AS
280*4520Snw141292      SELECT test1.id, a, b
281*4520Snw141292      FROM test1 JOIN test2 USING(id);
282*4520Snw141292    SELECT * FROM test;
283*4520Snw141292  }
284*4520Snw141292} {1 2 3}
285*4520Snw141292do_test view-7.4 {
286*4520Snw141292  db close
287*4520Snw141292  sqlite db test.db
288*4520Snw141292  execsql {
289*4520Snw141292    SELECT * FROM test;
290*4520Snw141292  }
291*4520Snw141292} {1 2 3}
292*4520Snw141292do_test view-7.5 {
293*4520Snw141292  execsql {
294*4520Snw141292    DROP VIEW test;
295*4520Snw141292    CREATE VIEW test AS
296*4520Snw141292      SELECT test1.id, a, b
297*4520Snw141292      FROM test1 NATURAL JOIN test2;
298*4520Snw141292    SELECT * FROM test;
299*4520Snw141292  }
300*4520Snw141292} {1 2 3}
301*4520Snw141292do_test view-7.6 {
302*4520Snw141292  db close
303*4520Snw141292  sqlite db test.db
304*4520Snw141292  execsql {
305*4520Snw141292    SELECT * FROM test;
306*4520Snw141292  }
307*4520Snw141292} {1 2 3}
308*4520Snw141292
309*4520Snw141292do_test view-8.1 {
310*4520Snw141292  execsql {
311*4520Snw141292    CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
312*4520Snw141292    SELECT * FROM v6 ORDER BY xyz;
313*4520Snw141292  }
314*4520Snw141292} {7 2 13 5 19 8 27 12}
315*4520Snw141292do_test view-8.2 {
316*4520Snw141292  db close
317*4520Snw141292  sqlite db test.db
318*4520Snw141292  execsql {
319*4520Snw141292    SELECT * FROM v6 ORDER BY xyz;
320*4520Snw141292  }
321*4520Snw141292} {7 2 13 5 19 8 27 12}
322*4520Snw141292do_test view-8.3 {
323*4520Snw141292  execsql {
324*4520Snw141292    CREATE VIEW v7 AS SELECT pqr+xyz AS a FROM v6;
325*4520Snw141292    SELECT * FROM v7 ORDER BY a;
326*4520Snw141292  }
327*4520Snw141292} {9 18 27 39}
328*4520Snw141292do_test view-8.4 {
329*4520Snw141292  execsql {
330*4520Snw141292    CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
331*4520Snw141292      (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
332*4520Snw141292    SELECT * FROM v8;
333*4520Snw141292  }
334*4520Snw141292} 3
335*4520Snw141292do_test view-8.5 {
336*4520Snw141292  execsql {
337*4520Snw141292    SELECT mx+10, mx*2 FROM v8;
338*4520Snw141292  }
339*4520Snw141292} {13 6}
340*4520Snw141292do_test view-8.6 {
341*4520Snw141292  execsql {
342*4520Snw141292    SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
343*4520Snw141292  }
344*4520Snw141292} {13 7}
345*4520Snw141292do_test view-8.7 {
346*4520Snw141292  execsql {
347*4520Snw141292    SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
348*4520Snw141292  }
349*4520Snw141292} {13 13 13 19 13 27}
350*4520Snw141292
351*4520Snw141292# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
352*4520Snw141292#
353*4520Snw141292do_test view-9.1 {
354*4520Snw141292  execsql {
355*4520Snw141292    INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
356*4520Snw141292    INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
357*4520Snw141292    INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
358*4520Snw141292    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
359*4520Snw141292  }
360*4520Snw141292} {1 2 4 8}
361*4520Snw141292do_test view-9.2 {
362*4520Snw141292  execsql {
363*4520Snw141292    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
364*4520Snw141292  }
365*4520Snw141292} {1 2 4}
366*4520Snw141292do_test view-9.3 {
367*4520Snw141292  execsql {
368*4520Snw141292    CREATE VIEW v9 AS
369*4520Snw141292       SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
370*4520Snw141292    SELECT * FROM v9;
371*4520Snw141292  }
372*4520Snw141292} {1 2 4}
373*4520Snw141292do_test view-9.4 {
374*4520Snw141292  execsql {
375*4520Snw141292    SELECT * FROM v9 ORDER BY 1 DESC;
376*4520Snw141292  }
377*4520Snw141292} {4 2 1}
378*4520Snw141292do_test view-9.5 {
379*4520Snw141292  execsql {
380*4520Snw141292    CREATE VIEW v10 AS
381*4520Snw141292       SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
382*4520Snw141292    SELECT * FROM v10;
383*4520Snw141292  }
384*4520Snw141292} {5 1 4 2 3 4}
385*4520Snw141292do_test view-9.6 {
386*4520Snw141292  execsql {
387*4520Snw141292    SELECT * FROM v10 ORDER BY 1;
388*4520Snw141292  }
389*4520Snw141292} {3 4 4 2 5 1}
390*4520Snw141292
391*4520Snw141292# Tables with columns having peculiar quoted names used in views
392*4520Snw141292# Ticket #756.
393*4520Snw141292#
394*4520Snw141292do_test view-10.1 {
395*4520Snw141292  execsql {
396*4520Snw141292    CREATE TABLE t3("9" integer, [4] text);
397*4520Snw141292    INSERT INTO t3 VALUES(1,2);
398*4520Snw141292    CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
399*4520Snw141292    CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
400*4520Snw141292    SELECT * FROM v_t3_a;
401*4520Snw141292  }
402*4520Snw141292} {1}
403*4520Snw141292do_test view-10.2 {
404*4520Snw141292  execsql {
405*4520Snw141292    SELECT * FROM v_t3_b;
406*4520Snw141292  }
407*4520Snw141292} {2}
408*4520Snw141292
409*4520Snw141292
410*4520Snw141292finish_test
411