xref: /sqlite-3.40.0/test/view.test (revision cf2ad7ae)
1ff78bd2fSdrh# 2002 February 26
2ff78bd2fSdrh#
3ff78bd2fSdrh# The author disclaims copyright to this source code.  In place of
4ff78bd2fSdrh# a legal notice, here is a blessing:
5ff78bd2fSdrh#
6ff78bd2fSdrh#    May you do good and not evil.
7ff78bd2fSdrh#    May you find forgiveness for yourself and forgive others.
8ff78bd2fSdrh#    May you share freely, never taking more than you give.
9ff78bd2fSdrh#
10ff78bd2fSdrh#***********************************************************************
11ff78bd2fSdrh# This file implements regression tests for SQLite library.  The
12ff78bd2fSdrh# focus of this file is testing VIEW statements.
13ff78bd2fSdrh#
1401ecbeebSdanielk1977# $Id: view.test,v 1.39 2008/12/14 14:45:21 danielk1977 Exp $
15ff78bd2fSdrhset testdir [file dirname $argv0]
16ff78bd2fSdrhsource $testdir/tester.tcl
17ff78bd2fSdrh
180fa8ddbdSdanielk1977# Omit this entire file if the library is not configured with views enabled.
190fa8ddbdSdanielk1977ifcapable !view {
200fa8ddbdSdanielk1977  finish_test
210fa8ddbdSdanielk1977  return
220fa8ddbdSdanielk1977}
230fa8ddbdSdanielk1977
24ff78bd2fSdrhdo_test view-1.0 {
25ff78bd2fSdrh  execsql {
26ff78bd2fSdrh    CREATE TABLE t1(a,b,c);
27ff78bd2fSdrh    INSERT INTO t1 VALUES(1,2,3);
28ff78bd2fSdrh    INSERT INTO t1 VALUES(4,5,6);
29ff78bd2fSdrh    INSERT INTO t1 VALUES(7,8,9);
30ff78bd2fSdrh    SELECT * FROM t1;
31ff78bd2fSdrh  }
32ff78bd2fSdrh} {1 2 3 4 5 6 7 8 9}
33ff78bd2fSdrh
34ff78bd2fSdrhdo_test view-1.1 {
35ff78bd2fSdrh  execsql {
36ff78bd2fSdrh    BEGIN;
37fdd48a76Sdrh    CREATE VIEW IF NOT EXISTS v1 AS SELECT a,b FROM t1;
38ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
39ff78bd2fSdrh  }
40ff78bd2fSdrh} {1 2 4 5 7 8}
4111d88e68Sdrhdo_test view-1.1.100 {
4211d88e68Sdrh  db config enable_view off
4311d88e68Sdrh  catchsql {
4411d88e68Sdrh    SELECT * FROM v1 ORDER BY a;
4511d88e68Sdrh  }
4611d88e68Sdrh} {1 {access to view "v1" prohibited}}
4770149ba4Sdrhdo_execsql_test view-1.1.101 {
4870149ba4Sdrh  CREATE TEMP VIEW v1temp AS SELECT a, b FROM t1;
4970149ba4Sdrh  SELECT * FROM v1temp ORDER BY a;
5070149ba4Sdrh} {1 2 4 5 7 8}
5111d88e68Sdrhdo_test view-1.1.110 {
5211d88e68Sdrh  db config enable_view on
5311d88e68Sdrh  catchsql {
5411d88e68Sdrh    SELECT * FROM v1 ORDER BY a;
5570149ba4Sdrh    SELECT * FROM v1temp ORDER BY a;
5611d88e68Sdrh  }
5770149ba4Sdrh} {0 {1 2 4 5 7 8 1 2 4 5 7 8}}
58*37f3ac8fSdanifcapable vtab {
592e50f670Sdrh  do_execsql_test view-1.1.120 {
602e50f670Sdrh    SELECT name, type FROM pragma_table_list('v1');
612e50f670Sdrh  } {v1 view}
62*37f3ac8fSdan}
63ff78bd2fSdrhdo_test view-1.2 {
64ff78bd2fSdrh  catchsql {
65ff78bd2fSdrh    ROLLBACK;
66ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
67ff78bd2fSdrh  }
68ff78bd2fSdrh} {1 {no such table: v1}}
69ff78bd2fSdrhdo_test view-1.3 {
70ff78bd2fSdrh  execsql {
71ff78bd2fSdrh    CREATE VIEW v1 AS SELECT a,b FROM t1;
72ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
73ff78bd2fSdrh  }
74ff78bd2fSdrh} {1 2 4 5 7 8}
75417be79cSdrhdo_test view-1.3.1 {
76417be79cSdrh  db close
77ef4ac8f9Sdrh  sqlite3 db test.db
78417be79cSdrh  execsql {
79417be79cSdrh    SELECT * FROM v1 ORDER BY a;
80417be79cSdrh  }
81417be79cSdrh} {1 2 4 5 7 8}
82ff78bd2fSdrhdo_test view-1.4 {
83ff78bd2fSdrh  catchsql {
84fdd48a76Sdrh    DROP VIEW IF EXISTS v1;
85ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
86ff78bd2fSdrh  }
87ff78bd2fSdrh} {1 {no such table: v1}}
88ff78bd2fSdrhdo_test view-1.5 {
89ff78bd2fSdrh  execsql {
90ff78bd2fSdrh    CREATE VIEW v1 AS SELECT a,b FROM t1;
91ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
92ff78bd2fSdrh  }
93ff78bd2fSdrh} {1 2 4 5 7 8}
94ff78bd2fSdrhdo_test view-1.6 {
95ff78bd2fSdrh  catchsql {
96ff78bd2fSdrh    DROP TABLE t1;
97ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
98ff78bd2fSdrh  }
99f26e09c8Sdrh} {1 {no such table: main.t1}}
100ff78bd2fSdrhdo_test view-1.7 {
101ff78bd2fSdrh  execsql {
102ff78bd2fSdrh    CREATE TABLE t1(x,a,b,c);
103ff78bd2fSdrh    INSERT INTO t1 VALUES(1,2,3,4);
104ff78bd2fSdrh    INSERT INTO t1 VALUES(4,5,6,7);
105ff78bd2fSdrh    INSERT INTO t1 VALUES(7,8,9,10);
106ff78bd2fSdrh    SELECT * FROM v1 ORDER BY a;
107ff78bd2fSdrh  }
108ff78bd2fSdrh} {2 3 5 6 8 9}
109417be79cSdrhdo_test view-1.8 {
110417be79cSdrh  db close
111ef4ac8f9Sdrh  sqlite3 db test.db
112417be79cSdrh  execsql {
113417be79cSdrh    SELECT * FROM v1 ORDER BY a;
114417be79cSdrh  }
115417be79cSdrh} {2 3 5 6 8 9}
116417be79cSdrh
117ed06a131Sdrhdo_execsql_test view-1.10 {
118ed06a131Sdrh  CREATE TABLE t9(x INTEGER);
119ed06a131Sdrh  CREATE VIEW v9a AS SELECT x FROM t9;
120ed06a131Sdrh  CREATE VIEW v9b AS SELECT * FROM t9;
121ed06a131Sdrh  CREATE VIEW v9c(x) AS SELECT x FROM t9;
122ed06a131Sdrh  CREATE VIEW v9d(x) AS SELECT * FROM t9;
123ed06a131Sdrh} {}
124ed06a131Sdrhdo_execsql_test view-1.11 {
125ed06a131Sdrh  PRAGMA table_info(v9a);
126ed06a131Sdrh} {0 x INTEGER 0 {} 0}
127ed06a131Sdrhdo_execsql_test view-1.12 {
128ed06a131Sdrh  PRAGMA table_info(v9b);
129ed06a131Sdrh} {0 x INTEGER 0 {} 0}
130ed06a131Sdrhdo_execsql_test view-1.13 {
131ed06a131Sdrh  PRAGMA table_info(v9c);
132ed06a131Sdrh} {0 x INTEGER 0 {} 0}
133ed06a131Sdrhdo_execsql_test view-1.14 {
134ed06a131Sdrh  PRAGMA table_info(v9d);
135ed06a131Sdrh} {0 x INTEGER 0 {} 0}
136ed06a131Sdrh
1374ff6dfa7Sdrhdo_test view-2.1 {
1384ff6dfa7Sdrh  execsql {
1394ff6dfa7Sdrh    CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
1404ff6dfa7Sdrh  };  # No semicolon
1414ff6dfa7Sdrh  execsql2 {
1424ff6dfa7Sdrh    SELECT * FROM v2;
1434ff6dfa7Sdrh  }
1444ff6dfa7Sdrh} {x 7 a 8 b 9 c 10}
1454ff6dfa7Sdrhdo_test view-2.2 {
1464ff6dfa7Sdrh  catchsql {
1474ff6dfa7Sdrh    INSERT INTO v2 VALUES(1,2,3,4);
1484ff6dfa7Sdrh  }
1495cf590c1Sdrh} {1 {cannot modify v2 because it is a view}}
1504ff6dfa7Sdrhdo_test view-2.3 {
1514ff6dfa7Sdrh  catchsql {
1524ff6dfa7Sdrh    UPDATE v2 SET a=10 WHERE a=5;
1534ff6dfa7Sdrh  }
1545cf590c1Sdrh} {1 {cannot modify v2 because it is a view}}
1554ff6dfa7Sdrhdo_test view-2.4 {
1564ff6dfa7Sdrh  catchsql {
1574ff6dfa7Sdrh    DELETE FROM v2;
1584ff6dfa7Sdrh  }
1595cf590c1Sdrh} {1 {cannot modify v2 because it is a view}}
1604ff6dfa7Sdrhdo_test view-2.5 {
1614ff6dfa7Sdrh  execsql {
1624ff6dfa7Sdrh    INSERT INTO t1 VALUES(11,12,13,14);
1634ff6dfa7Sdrh    SELECT * FROM v2 ORDER BY x;
1644ff6dfa7Sdrh  }
1654ff6dfa7Sdrh} {7 8 9 10 11 12 13 14}
1664ff6dfa7Sdrhdo_test view-2.6 {
1674ff6dfa7Sdrh  execsql {
1684ff6dfa7Sdrh    SELECT x FROM v2 WHERE a>10
1694ff6dfa7Sdrh  }
1704ff6dfa7Sdrh} {11}
1714ff6dfa7Sdrh
1720bb28106Sdrh# Test that column name of views are generated correctly.
1730bb28106Sdrh#
1740bb28106Sdrhdo_test view-3.1 {
1750bb28106Sdrh  execsql2 {
1760bb28106Sdrh    SELECT * FROM v1 LIMIT 1
1770bb28106Sdrh  }
1780bb28106Sdrh} {a 2 b 3}
1790bb28106Sdrhdo_test view-3.2 {
1800bb28106Sdrh  execsql2 {
1810bb28106Sdrh    SELECT * FROM v2 LIMIT 1
1820bb28106Sdrh  }
1830bb28106Sdrh} {x 7 a 8 b 9 c 10}
18493a960a0Sdrhdo_test view-3.3.1 {
1850bb28106Sdrh  execsql2 {
1860bb28106Sdrh    DROP VIEW v1;
1870bb28106Sdrh    CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
1880bb28106Sdrh    SELECT * FROM v1 LIMIT 1
1890bb28106Sdrh  }
1900bb28106Sdrh} {xyz 2 pqr 7 c-b 1}
19193a960a0Sdrhdo_test view-3.3.2 {
19293a960a0Sdrh  execsql2 {
19393a960a0Sdrh    CREATE VIEW v1b AS SELECT t1.a, b+c, t1.c FROM t1;
19493a960a0Sdrh    SELECT * FROM v1b LIMIT 1
19593a960a0Sdrh  }
19693a960a0Sdrh} {a 2 b+c 7 c 4}
1978981b904Sdrhdo_test view-3.3.3 {
1988981b904Sdrh  execsql2 {
1998981b904Sdrh    CREATE VIEW v1c(x,y,z) AS SELECT a, b+c, c-b FROM t1;
2008981b904Sdrh    SELECT * FROM v1c LIMIT 1;
2018981b904Sdrh  }
2028981b904Sdrh} {x 2 y 7 z 1}
2038981b904Sdrhdo_catchsql_test view-3.3.4 {
2048981b904Sdrh  CREATE VIEW v1err(x,y DESC,z) AS SELECT a, b+c, c-b FROM t1;
2058981b904Sdrh} {1 {syntax error after column name "y"}}
2062679f14fSdrhdo_catchsql_test view-3.3.5 {
2072679f14fSdrh  DROP VIEW IF EXISTS v1err;
2082679f14fSdrh  CREATE VIEW v1err(x,y) AS SELECT a, b+c, c-b FROM t1;
2092679f14fSdrh  SELECT * FROM v1err;
2102679f14fSdrh} {1 {expected 2 columns for 'v1err' but got 3}}
2112679f14fSdrhdo_catchsql_test view-3.3.6 {
2122679f14fSdrh  DROP VIEW IF EXISTS v1err;
2132679f14fSdrh  CREATE VIEW v1err(w,x,y,z) AS SELECT a, b+c, c-b FROM t1;
2142679f14fSdrh  SELECT * FROM v1err;
2152679f14fSdrh} {1 {expected 4 columns for 'v1err' but got 3}}
21627c77438Sdanielk1977
21727c77438Sdanielk1977ifcapable compound {
2180bb28106Sdrhdo_test  view-3.4 {
2190bb28106Sdrh  execsql2 {
2200bb28106Sdrh    CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
2210bb28106Sdrh    SELECT * FROM v3 LIMIT 4;
2220bb28106Sdrh  }
22392378253Sdrh} {a 2 a 3 a 5 a 6}
2240f18b450Sdrhdo_test view-3.5 {
2250f18b450Sdrh  execsql2 {
2260f18b450Sdrh    CREATE VIEW v4 AS
2270f18b450Sdrh      SELECT a, b FROM t1
2280f18b450Sdrh      UNION
2290f18b450Sdrh      SELECT b AS 'x', a AS 'y' FROM t1
2300f18b450Sdrh      ORDER BY x, y;
23192378253Sdrh    SELECT b FROM v4 ORDER BY b LIMIT 4;
2320f18b450Sdrh  }
23392378253Sdrh} {b 2 b 3 b 5 b 6}
23427c77438Sdanielk1977} ;# ifcapable compound
2354ff6dfa7Sdrh
236ff78bd2fSdrh
2373b167c75Sdrhdo_test view-4.1 {
2383b167c75Sdrh  catchsql {
2393b167c75Sdrh    DROP VIEW t1;
2403b167c75Sdrh  }
2413b167c75Sdrh} {1 {use DROP TABLE to delete table t1}}
2423b167c75Sdrhdo_test view-4.2 {
2433b167c75Sdrh  execsql {
2443b167c75Sdrh    SELECT 1 FROM t1 LIMIT 1;
2453b167c75Sdrh  }
2463b167c75Sdrh} 1
2473b167c75Sdrhdo_test view-4.3 {
2483b167c75Sdrh  catchsql {
2493b167c75Sdrh    DROP TABLE v1;
2503b167c75Sdrh  }
2513b167c75Sdrh} {1 {use DROP VIEW to delete view v1}}
2523b167c75Sdrhdo_test view-4.4 {
2533b167c75Sdrh  execsql {
2543b167c75Sdrh     SELECT 1 FROM v1 LIMIT 1;
2553b167c75Sdrh  }
2563b167c75Sdrh} {1}
2573b167c75Sdrhdo_test view-4.5 {
2583b167c75Sdrh  catchsql {
2593b167c75Sdrh    CREATE INDEX i1v1 ON v1(xyz);
2603b167c75Sdrh  }
2613b167c75Sdrh} {1 {views may not be indexed}}
2623b167c75Sdrh
2633b167c75Sdrhdo_test view-5.1 {
2643b167c75Sdrh  execsql {
2653b167c75Sdrh    CREATE TABLE t2(y,a);
2663b167c75Sdrh    INSERT INTO t2 VALUES(22,2);
2673b167c75Sdrh    INSERT INTO t2 VALUES(33,3);
2683b167c75Sdrh    INSERT INTO t2 VALUES(44,4);
2693b167c75Sdrh    INSERT INTO t2 VALUES(55,5);
2703b167c75Sdrh    SELECT * FROM t2;
2713b167c75Sdrh  }
2723b167c75Sdrh} {22 2 33 3 44 4 55 5}
2733b167c75Sdrhdo_test view-5.2 {
2743b167c75Sdrh  execsql {
2753b167c75Sdrh    CREATE VIEW v5 AS
276c31c2eb8Sdrh      SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
2773b167c75Sdrh    SELECT * FROM v5;
2783b167c75Sdrh  }
2793b167c75Sdrh} {1 22 4 55}
2803b167c75Sdrh
281c31c2eb8Sdrh# Verify that the view v5 gets flattened.  see sqliteFlattenSubquery().
2826bf89570Sdrh# This will only work if EXPLAIN is enabled.
283c31c2eb8Sdrh# Ticket #272
2846bf89570Sdrh#
2856bf89570Sdrhifcapable {explain} {
286c31c2eb8Sdrhdo_test view-5.3 {
287c31c2eb8Sdrh  lsearch [execsql {
288c31c2eb8Sdrh    EXPLAIN SELECT * FROM v5;
289b9bb7c18Sdrh  }] OpenEphemeral
290c31c2eb8Sdrh} {-1}
291c31c2eb8Sdrhdo_test view-5.4 {
292c31c2eb8Sdrh  execsql {
293c31c2eb8Sdrh    SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
294c31c2eb8Sdrh  }
295c31c2eb8Sdrh} {1 22 22 2 4 55 55 5}
296c31c2eb8Sdrhdo_test view-5.5 {
297c31c2eb8Sdrh  lsearch [execsql {
298c31c2eb8Sdrh    EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
299b9bb7c18Sdrh  }] OpenEphemeral
300c31c2eb8Sdrh} {-1}
301c31c2eb8Sdrhdo_test view-5.6 {
302c31c2eb8Sdrh  execsql {
303c31c2eb8Sdrh    SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
304c31c2eb8Sdrh  }
305c31c2eb8Sdrh} {22 2 1 22 55 5 4 55}
306c31c2eb8Sdrhdo_test view-5.7 {
307c31c2eb8Sdrh  lsearch [execsql {
308c31c2eb8Sdrh    EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
309b9bb7c18Sdrh  }] OpenEphemeral
310c31c2eb8Sdrh} {-1}
311c31c2eb8Sdrhdo_test view-5.8 {
312c31c2eb8Sdrh  execsql {
313c31c2eb8Sdrh    SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
314c31c2eb8Sdrh  }
315c31c2eb8Sdrh} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
316c31c2eb8Sdrhdo_test view-5.9 {
317c31c2eb8Sdrh  lsearch [execsql {
318c31c2eb8Sdrh    EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
319b9bb7c18Sdrh  }] OpenEphemeral
320c31c2eb8Sdrh} {-1}
3216bf89570Sdrh} ;# endif explain
322c31c2eb8Sdrh
3232f2c01e5Sdrhdo_test view-6.1 {
3242f2c01e5Sdrh  execsql {
3252f2c01e5Sdrh    SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
3262f2c01e5Sdrh  }
3272f2c01e5Sdrh} {7 8 9 10 27}
3282f2c01e5Sdrhdo_test view-6.2 {
3292f2c01e5Sdrh  execsql {
3302f2c01e5Sdrh    SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
3312f2c01e5Sdrh  }
3322f2c01e5Sdrh} {11 12 13 14 39}
3332f2c01e5Sdrh
3340c36cbe0Sdrhdo_test view-7.1 {
3350c36cbe0Sdrh  execsql {
3360c36cbe0Sdrh    CREATE TABLE test1(id integer primary key, a);
3370c36cbe0Sdrh    CREATE TABLE test2(id integer, b);
3380c36cbe0Sdrh    INSERT INTO test1 VALUES(1,2);
3390c36cbe0Sdrh    INSERT INTO test2 VALUES(1,3);
3400c36cbe0Sdrh    CREATE VIEW test AS
3410c36cbe0Sdrh      SELECT test1.id, a, b
3420c36cbe0Sdrh      FROM test1 JOIN test2 ON test2.id=test1.id;
3430c36cbe0Sdrh    SELECT * FROM test;
3440c36cbe0Sdrh  }
3450c36cbe0Sdrh} {1 2 3}
3460c36cbe0Sdrhdo_test view-7.2 {
3470c36cbe0Sdrh  db close
348ef4ac8f9Sdrh  sqlite3 db test.db
3490c36cbe0Sdrh  execsql {
3500c36cbe0Sdrh    SELECT * FROM test;
3510c36cbe0Sdrh  }
3520c36cbe0Sdrh} {1 2 3}
3530c36cbe0Sdrhdo_test view-7.3 {
3540c36cbe0Sdrh  execsql {
3550c36cbe0Sdrh    DROP VIEW test;
3560c36cbe0Sdrh    CREATE VIEW test AS
3570c36cbe0Sdrh      SELECT test1.id, a, b
3580c36cbe0Sdrh      FROM test1 JOIN test2 USING(id);
3590c36cbe0Sdrh    SELECT * FROM test;
3600c36cbe0Sdrh  }
3610c36cbe0Sdrh} {1 2 3}
3620c36cbe0Sdrhdo_test view-7.4 {
3630c36cbe0Sdrh  db close
364ef4ac8f9Sdrh  sqlite3 db test.db
3650c36cbe0Sdrh  execsql {
3660c36cbe0Sdrh    SELECT * FROM test;
3670c36cbe0Sdrh  }
3680c36cbe0Sdrh} {1 2 3}
3690c36cbe0Sdrhdo_test view-7.5 {
3700c36cbe0Sdrh  execsql {
3710c36cbe0Sdrh    DROP VIEW test;
3720c36cbe0Sdrh    CREATE VIEW test AS
3730c36cbe0Sdrh      SELECT test1.id, a, b
3740c36cbe0Sdrh      FROM test1 NATURAL JOIN test2;
3750c36cbe0Sdrh    SELECT * FROM test;
3760c36cbe0Sdrh  }
3770c36cbe0Sdrh} {1 2 3}
3780c36cbe0Sdrhdo_test view-7.6 {
3790c36cbe0Sdrh  db close
380ef4ac8f9Sdrh  sqlite3 db test.db
3810c36cbe0Sdrh  execsql {
3820c36cbe0Sdrh    SELECT * FROM test;
3830c36cbe0Sdrh  }
3840c36cbe0Sdrh} {1 2 3}
3852f2c01e5Sdrh
3864b59ab5eSdrhdo_test view-8.1 {
3874b59ab5eSdrh  execsql {
3884b59ab5eSdrh    CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
3894b59ab5eSdrh    SELECT * FROM v6 ORDER BY xyz;
3904b59ab5eSdrh  }
3914b59ab5eSdrh} {7 2 13 5 19 8 27 12}
3924b59ab5eSdrhdo_test view-8.2 {
3934b59ab5eSdrh  db close
394ef4ac8f9Sdrh  sqlite3 db test.db
3954b59ab5eSdrh  execsql {
3964b59ab5eSdrh    SELECT * FROM v6 ORDER BY xyz;
3974b59ab5eSdrh  }
3984b59ab5eSdrh} {7 2 13 5 19 8 27 12}
3994b59ab5eSdrhdo_test view-8.3 {
4004b59ab5eSdrh  execsql {
4018981b904Sdrh    CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6;
4024b59ab5eSdrh    SELECT * FROM v7 ORDER BY a;
4034b59ab5eSdrh  }
4044b59ab5eSdrh} {9 18 27 39}
405e61b9f4fSdanielk1977
406e61b9f4fSdanielk1977ifcapable subquery {
4074b59ab5eSdrh  do_test view-8.4 {
4088c74a8caSdrh    execsql {
4098c74a8caSdrh      CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
4104b59ab5eSdrh        (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
4114b59ab5eSdrh      SELECT * FROM v8;
4124b59ab5eSdrh    }
4134b59ab5eSdrh  } 3
4148c74a8caSdrh  do_test view-8.5 {
4158c74a8caSdrh    execsql {
4168c74a8caSdrh      SELECT mx+10, mx*2 FROM v8;
4174b59ab5eSdrh    }
4188c74a8caSdrh  } {13 6}
4196a3ea0e6Sdrh  do_test view-8.6 {
4206a3ea0e6Sdrh    execsql {
4216a3ea0e6Sdrh      SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
4226a3ea0e6Sdrh    }
4236a3ea0e6Sdrh  } {13 7}
4246a3ea0e6Sdrh  do_test view-8.7 {
4256a3ea0e6Sdrh    execsql {
4266a3ea0e6Sdrh      SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
4276a3ea0e6Sdrh    }
4286a3ea0e6Sdrh  } {13 13 13 19 13 27}
429e61b9f4fSdanielk1977} ;# ifcapable subquery
4304b59ab5eSdrh
431174b6195Sdrh# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
432174b6195Sdrh#
433174b6195Sdrhdo_test view-9.1 {
434174b6195Sdrh  execsql {
435174b6195Sdrh    INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
436174b6195Sdrh    INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
437174b6195Sdrh    INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
438174b6195Sdrh    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
439174b6195Sdrh  }
440174b6195Sdrh} {1 2 4 8}
441174b6195Sdrhdo_test view-9.2 {
442174b6195Sdrh  execsql {
443174b6195Sdrh    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
444174b6195Sdrh  }
445174b6195Sdrh} {1 2 4}
446174b6195Sdrhdo_test view-9.3 {
447174b6195Sdrh  execsql {
448174b6195Sdrh    CREATE VIEW v9 AS
449174b6195Sdrh       SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
450174b6195Sdrh    SELECT * FROM v9;
451174b6195Sdrh  }
452174b6195Sdrh} {1 2 4}
453174b6195Sdrhdo_test view-9.4 {
454174b6195Sdrh  execsql {
455174b6195Sdrh    SELECT * FROM v9 ORDER BY 1 DESC;
456174b6195Sdrh  }
457174b6195Sdrh} {4 2 1}
458174b6195Sdrhdo_test view-9.5 {
459174b6195Sdrh  execsql {
460174b6195Sdrh    CREATE VIEW v10 AS
461174b6195Sdrh       SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
462174b6195Sdrh    SELECT * FROM v10;
463174b6195Sdrh  }
464174b6195Sdrh} {5 1 4 2 3 4}
465174b6195Sdrhdo_test view-9.6 {
466174b6195Sdrh  execsql {
467174b6195Sdrh    SELECT * FROM v10 ORDER BY 1;
468174b6195Sdrh  }
469174b6195Sdrh} {3 4 4 2 5 1}
470174b6195Sdrh
4712c61c070Sdrh# Tables with columns having peculiar quoted names used in views
4722c61c070Sdrh# Ticket #756.
4732c61c070Sdrh#
4742c61c070Sdrhdo_test view-10.1 {
4752c61c070Sdrh  execsql {
4762c61c070Sdrh    CREATE TABLE t3("9" integer, [4] text);
4772c61c070Sdrh    INSERT INTO t3 VALUES(1,2);
4782c61c070Sdrh    CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
4792c61c070Sdrh    CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
4802c61c070Sdrh    SELECT * FROM v_t3_a;
4812c61c070Sdrh  }
4822c61c070Sdrh} {1}
4832c61c070Sdrhdo_test view-10.2 {
4842c61c070Sdrh  execsql {
4852c61c070Sdrh    SELECT * FROM v_t3_b;
4862c61c070Sdrh  }
4872c61c070Sdrh} {2}
488174b6195Sdrh
489142bdf40Sdanielk1977do_test view-11.1 {
490142bdf40Sdanielk1977  execsql {
491142bdf40Sdanielk1977    CREATE TABLE t4(a COLLATE NOCASE);
492142bdf40Sdanielk1977    INSERT INTO t4 VALUES('This');
493142bdf40Sdanielk1977    INSERT INTO t4 VALUES('this');
494142bdf40Sdanielk1977    INSERT INTO t4 VALUES('THIS');
495142bdf40Sdanielk1977    SELECT * FROM t4 WHERE a = 'THIS';
496142bdf40Sdanielk1977  }
497142bdf40Sdanielk1977} {This this THIS}
4981576cd92Sdanielk1977ifcapable subquery {
499142bdf40Sdanielk1977  do_test view-11.2 {
500142bdf40Sdanielk1977    execsql {
501142bdf40Sdanielk1977      SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS';
502142bdf40Sdanielk1977    }
503142bdf40Sdanielk1977  } {This this THIS}
5041576cd92Sdanielk1977}
505142bdf40Sdanielk1977do_test view-11.3 {
506142bdf40Sdanielk1977  execsql {
507142bdf40Sdanielk1977    CREATE VIEW v11 AS SELECT * FROM t4;
508142bdf40Sdanielk1977    SELECT * FROM v11 WHERE a = 'THIS';
509142bdf40Sdanielk1977  }
510142bdf40Sdanielk1977} {This this THIS}
511142bdf40Sdanielk1977
5127c3d64f1Sdrh# Ticket #1270:  Do not allow parameters in view definitions.
5137c3d64f1Sdrh#
5147c3d64f1Sdrhdo_test view-12.1 {
5157c3d64f1Sdrh  catchsql {
5167c3d64f1Sdrh    CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=?
5177c3d64f1Sdrh  }
5187c3d64f1Sdrh} {1 {parameters are not allowed in views}}
51932498f13Sdrhdo_test view-12.2 {
52032498f13Sdrh  catchsql {
52132498f13Sdrh    CREATE VIEW v12(x) AS SELECT a FROM t1 WHERE b=?
52232498f13Sdrh  }
52332498f13Sdrh} {1 {parameters are not allowed in views}}
5247c3d64f1Sdrh
5255a8f9374Sdanielk1977ifcapable attach {
52685c23c61Sdrh  do_test view-13.1 {
527fda06befSmistachkin    forcedelete test2.db
52885c23c61Sdrh    catchsql {
52985c23c61Sdrh      ATTACH 'test2.db' AS two;
53085c23c61Sdrh      CREATE TABLE two.t2(x,y);
53185c23c61Sdrh      CREATE VIEW v13 AS SELECT y FROM two.t2;
53285c23c61Sdrh    }
53385c23c61Sdrh  } {1 {view v13 cannot reference objects in database two}}
5345a8f9374Sdanielk1977}
53585c23c61Sdrh
536fb8de2dcSdrh# Ticket #1658
537fb8de2dcSdrh#
538fb8de2dcSdrhdo_test view-14.1 {
539fb8de2dcSdrh  catchsql {
540fb8de2dcSdrh    CREATE TEMP VIEW t1 AS SELECT a,b FROM t1;
541fb8de2dcSdrh    SELECT * FROM temp.t1;
542fb8de2dcSdrh  }
543fb8de2dcSdrh} {1 {view t1 is circularly defined}}
544bfad7be7Sdrhdo_test view-14.2 {
545bfad7be7Sdrh  catchsql {
546bfad7be7Sdrh    DROP VIEW IF EXISTS temp.t1;
547bfad7be7Sdrh    CREATE TEMP VIEW t1(a,b) AS SELECT a,b FROM t1;
548bfad7be7Sdrh    SELECT * FROM temp.t1;
549bfad7be7Sdrh  }
550bfad7be7Sdrh} {1 {view t1 is circularly defined}}
551fb8de2dcSdrh
552643054c1Sdrh# Tickets #1688, #1709
553643054c1Sdrh#
554643054c1Sdrhdo_test view-15.1 {
555643054c1Sdrh  execsql2 {
556643054c1Sdrh    CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1;
557643054c1Sdrh    SELECT * FROM v15 LIMIT 1;
558643054c1Sdrh  }
559643054c1Sdrh} {x 2 y 3}
560643054c1Sdrhdo_test view-15.2 {
561643054c1Sdrh  execsql2 {
562643054c1Sdrh    SELECT x, y FROM v15 LIMIT 1
563643054c1Sdrh  }
564643054c1Sdrh} {x 2 y 3}
565643054c1Sdrh
566fdd48a76Sdrhdo_test view-16.1 {
567fdd48a76Sdrh  catchsql {
568fdd48a76Sdrh    CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1;
569fdd48a76Sdrh  }
570fdd48a76Sdrh} {0 {}}
571fdd48a76Sdrhdo_test view-16.2 {
572fdd48a76Sdrh  execsql {
573fdd48a76Sdrh    SELECT sql FROM sqlite_master WHERE name='v1'
574fdd48a76Sdrh  }
575fdd48a76Sdrh} {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}}
576fdd48a76Sdrhdo_test view-16.3 {
577fdd48a76Sdrh  catchsql {
578fdd48a76Sdrh    DROP VIEW IF EXISTS nosuchview
579fdd48a76Sdrh  }
580fdd48a76Sdrh} {0 {}}
581643054c1Sdrh
582ca424114Sdrh# correct error message when attempting to drop a view that does not
583ca424114Sdrh# exist.
584ca424114Sdrh#
585ca424114Sdrhdo_test view-17.1 {
586ca424114Sdrh  catchsql {
587ca424114Sdrh    DROP VIEW nosuchview
588ca424114Sdrh  }
589ca424114Sdrh} {1 {no such view: nosuchview}}
590ca424114Sdrhdo_test view-17.2 {
591ca424114Sdrh  catchsql {
592ca424114Sdrh    DROP VIEW main.nosuchview
593ca424114Sdrh  }
594ca424114Sdrh} {1 {no such view: main.nosuchview}}
595ca424114Sdrh
596daf79acbSdanielk1977do_test view-18.1 {
597daf79acbSdanielk1977  execsql {
598daf79acbSdanielk1977    DROP VIEW t1;
599daf79acbSdanielk1977    DROP TABLE t1;
600daf79acbSdanielk1977    CREATE TABLE t1(a, b, c);
601daf79acbSdanielk1977    INSERT INTO t1 VALUES(1, 2, 3);
602daf79acbSdanielk1977    INSERT INTO t1 VALUES(4, 5, 6);
603daf79acbSdanielk1977
604daf79acbSdanielk1977    CREATE VIEW vv1 AS SELECT * FROM t1;
605daf79acbSdanielk1977    CREATE VIEW vv2 AS SELECT * FROM vv1;
606daf79acbSdanielk1977    CREATE VIEW vv3 AS SELECT * FROM vv2;
607daf79acbSdanielk1977    CREATE VIEW vv4 AS SELECT * FROM vv3;
608daf79acbSdanielk1977    CREATE VIEW vv5 AS SELECT * FROM vv4;
609daf79acbSdanielk1977
610daf79acbSdanielk1977    SELECT * FROM vv5;
611daf79acbSdanielk1977  }
612daf79acbSdanielk1977} {1 2 3 4 5 6}
613daf79acbSdanielk1977
614f0209f74Sdrh# Ticket #3308
615f0209f74Sdrh# Make sure "rowid" columns in a view are named correctly.
616f0209f74Sdrh#
617f0209f74Sdrhdo_test view-19.1 {
618f0209f74Sdrh  execsql {
619f0209f74Sdrh    CREATE VIEW v3308a AS SELECT rowid, * FROM t1;
620f0209f74Sdrh  }
621f0209f74Sdrh  execsql2 {
622f0209f74Sdrh    SELECT * FROM v3308a
623f0209f74Sdrh  }
624f0209f74Sdrh} {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6}
625f0209f74Sdrhdo_test view-19.2 {
626f0209f74Sdrh  execsql {
627f0209f74Sdrh    CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1;
628f0209f74Sdrh  }
629f0209f74Sdrh  execsql2 {
630f0209f74Sdrh    SELECT * FROM v3308b
631f0209f74Sdrh  }
632f0209f74Sdrh} {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11}
633f0209f74Sdrhdo_test view-19.3 {
634f0209f74Sdrh  execsql {
635f0209f74Sdrh    CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1;
636f0209f74Sdrh  }
637f0209f74Sdrh  execsql2 {
638f0209f74Sdrh    SELECT * FROM v3308c
639f0209f74Sdrh  }
640f0209f74Sdrh} {rowid 1 a 1 x 5 rowid 2 a 4 x 11}
641ca424114Sdrh
64201ecbeebSdanielk1977# Ticket #3539 had this crashing (see commit [5940]).
64301ecbeebSdanielk1977do_test view-20.1 {
64401ecbeebSdanielk1977  execsql {
64501ecbeebSdanielk1977    DROP TABLE IF EXISTS t1;
64601ecbeebSdanielk1977    DROP VIEW IF EXISTS v1;
64701ecbeebSdanielk1977    CREATE TABLE t1(c1);
64801ecbeebSdanielk1977    CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1);
64901ecbeebSdanielk1977  }
65001ecbeebSdanielk1977} {}
65101ecbeebSdanielk1977
65219c6d96aSdrhdb close
65319c6d96aSdrhsqlite3 db :memory:
65419c6d96aSdrhdo_execsql_test view-22.1 {
65519c6d96aSdrh  CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS '';
65619c6d96aSdrh  SELECT * FROM x1;
65719c6d96aSdrh} {123 234 345}
65819c6d96aSdrhdo_test view-22.2 {
65919c6d96aSdrh  unset -nocomplain x
66019c6d96aSdrh  db eval {SELECT * FROM x1} x break
66119c6d96aSdrh  lsort [array names x]
66219c6d96aSdrh} {{} * :1 :2}
66319c6d96aSdrh
6640fc2da3fSmistachkindo_test view-25.1 {
6650fc2da3fSmistachkin  db eval {
6660fc2da3fSmistachkin    CREATE TABLE t25 (x);
6670fc2da3fSmistachkin    INSERT INTO t25 (x) VALUES (1);
6680fc2da3fSmistachkin    ANALYZE;
6690fc2da3fSmistachkin  }
6700fc2da3fSmistachkin  proc authLogDelete {code arg1 arg2 arg3 arg4 args} {
6710fc2da3fSmistachkin    if {$code=="SQLITE_DELETE" && [string match sqlite_stat* $arg1]} {
67285c6892aSdan      # lappend ::log [list $code $arg1 $arg2 $arg3 $arg4 $args]
67385c6892aSdan      lappend ::log [list $code $arg1 $arg2 $arg3 $arg4]
6740fc2da3fSmistachkin    }
6750fc2da3fSmistachkin    return SQLITE_OK
6760fc2da3fSmistachkin  }
6770fc2da3fSmistachkin  set log ""
6780fc2da3fSmistachkin  db authorizer ::authLogDelete
6790fc2da3fSmistachkin  db eval {DROP VIEW x1;}
6800fc2da3fSmistachkin  set log
6810fc2da3fSmistachkin} {}
68279e9d347Sdan
68385c6892aSdanset res [list {SQLITE_DELETE sqlite_stat1 {} main {}}]
68485c6892aSdanifcapable stat4 { lappend res {SQLITE_DELETE sqlite_stat4 {} main {}} }
6850fc2da3fSmistachkindo_test view-25.2 {
6860fc2da3fSmistachkin  set log ""
6870fc2da3fSmistachkin  db eval {DROP TABLE t25;}
6880fc2da3fSmistachkin  set log
68979e9d347Sdan} $res
69019c6d96aSdrh
691ac4085bcSdan#-------------------------------------------------------------------------
692ac4085bcSdando_execsql_test view-26.0 {
693ac4085bcSdan  CREATE TABLE t16(a, b, c UNIQUE);
694ac4085bcSdan  INSERT INTO t16 VALUES(1, 1, 1);
695ac4085bcSdan  INSERT INTO t16 VALUES(2, 2, 2);
696ac4085bcSdan  INSERT INTO t16 VALUES(3, 3, 3);
697ac4085bcSdan  CREATE VIEW v16 AS SELECT max(a) AS mx, min(b) AS mn FROM t16 GROUP BY c;
698ac4085bcSdan
699ac4085bcSdan  SELECT * FROM v16 AS one, v16 AS two WHERE one.mx=1;
700ac4085bcSdan} {
701ac4085bcSdan  1 1 1 1
702ac4085bcSdan  1 1 2 2
703ac4085bcSdan  1 1 3 3
704ac4085bcSdan}
70553e8709bSdrhdo_execsql_test view-26.1 {
70653e8709bSdrh  WITH v17(x,y) AS (SELECT max(a), min(b) FROM t16 GROUP BY c)
70753e8709bSdrh  SELECT * FROM v17 AS one, v17 AS two WHERE one.x=1;
70853e8709bSdrh} {
70953e8709bSdrh  1 1 1 1
71053e8709bSdrh  1 1 2 2
71153e8709bSdrh  1 1 3 3
71253e8709bSdrh}
713ac4085bcSdan
7140a8d06a9Sdan#-------------------------------------------------------------------------
7150a8d06a9Sdanreset_db
7160a8d06a9Sdando_execsql_test view-27.0 {
7170a8d06a9Sdan  CREATE TABLE t0(c0 TEXT, c1);
7180a8d06a9Sdan  INSERT INTO t0(c0, c1) VALUES (-1, 0);
7190a8d06a9Sdan  CREATE VIEW v0(c0, c1) AS SELECT t0.c0, AVG(t0.c1) FROM t0;
7200a8d06a9Sdan}
7210a8d06a9Sdan
7220a8d06a9Sdando_execsql_test view-27.1 {
723679c9613Sdan  SELECT c0, typeof(c0), c1, typeof(c1) FROM v0;
7240a8d06a9Sdan} {
725679c9613Sdan  -1   text
726679c9613Sdan   0.0 real
7270a8d06a9Sdan}
7280a8d06a9Sdan
7290a8d06a9Sdando_execsql_test view-27.2 { SELECT c0<c1 FROM v0 } 1
7300a8d06a9Sdando_execsql_test view-27.3 { SELECT c1<c0 FROM v0 } 0
7310a8d06a9Sdando_execsql_test view-27.4 {
7320a8d06a9Sdan  SELECT 1 FROM v0 WHERE c1<c0
7330a8d06a9Sdan} {}
7340a8d06a9Sdando_execsql_test view-27.5 {
7350a8d06a9Sdan  SELECT 1 FROM v0 WHERE c0<c1
7360a8d06a9Sdan} {1}
7370a8d06a9Sdan
7380a8d06a9Sdando_execsql_test view-27.6 {
7390a8d06a9Sdan  SELECT c0<c1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0)
7400a8d06a9Sdan} 1
7410a8d06a9Sdando_execsql_test view-27.7 {
7420a8d06a9Sdan  SELECT c1<c0 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0)
7430a8d06a9Sdan} 0
7440a8d06a9Sdando_execsql_test view-27.8 {
7450a8d06a9Sdan  SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c1<c0
7460a8d06a9Sdan} {}
7470a8d06a9Sdando_execsql_test view-27.9 {
7480a8d06a9Sdan  SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c0<c1
7490a8d06a9Sdan} {1}
7500a8d06a9Sdan
7512712b022Sdan#-------------------------------------------------------------------------
7522712b022Sdanreset_db
7532712b022Sdando_execsql_test view-28.0 {
7542712b022Sdan  CREATE TABLE t0(c0 TEXT);
7552712b022Sdan  CREATE VIEW v0(c0) AS SELECT t0.c0 FROM t0;
7562712b022Sdan  INSERT INTO t0(c0) VALUES ('0');
7572712b022Sdan}
7582712b022Sdando_execsql_test view-28.1 {
7592712b022Sdan  SELECT 0 IN (c0) FROM t0;
7602712b022Sdan} {0}
7612712b022Sdando_execsql_test view-28.2 {
7622712b022Sdan  SELECT 0 IN (c0) FROM (SELECT c0 FROM t0);
7632712b022Sdan} {0}
7642712b022Sdan
765ed7974deSdrh#-------------------------------------------------------------------------
766ed7974deSdrh# 2020-10-26.  https://sqlite.org/forum/forumpost/daa2c728cc
767ed7974deSdrh#
768ed7974deSdrhreset_db
769ed7974deSdrhdo_catchsql_test view-29.0 {
770ed7974deSdrh  CREATE TABLE t1(a,b,c);
771ed7974deSdrh  CREATE VIEW IF NOT EXISTS IF AS SELECT null;
772ed7974deSdrh} {1 {malformed database schema (IF) - near "AS": syntax error}}
773ed7974deSdrhdo_catchsql_test view-29.1 {
774ed7974deSdrh  CREATE TABLE t2(c,d,e);
775ed7974deSdrh  SELECT name FROM sqlite_schema ORDER BY name;
776ed7974deSdrh} {0 {t1 t2}}
777ed7974deSdrh
778ed7974deSdrh
779ff78bd2fSdrhfinish_test
780