From 73f630500bcb3034f65dc5af6cb410b3221fe717 Mon Sep 17 00:00:00 2001 From: Neil Conway Date: Wed, 2 Feb 2005 06:36:02 +0000 Subject: [PATCH] Add support for temporary views, including documentation and regression tests. Contributed by Koju Iijima, review from Neil Conway, Gavin Sherry and Tom Lane. Also, fix error in description of WITH CHECK OPTION clause in the CREATE VIEW reference page: it should be "CASCADED", not "CASCADE". --- doc/src/sgml/ref/create_table.sgml | 14 +- doc/src/sgml/ref/create_view.sgml | 47 ++++- src/backend/commands/view.c | 74 ++++++- src/backend/parser/gram.y | 25 ++- src/include/commands/view.h | 4 +- src/test/regress/expected/create_view.out | 246 ++++++++++++++++++++++ src/test/regress/sql/create_view.sql | 128 +++++++++++ 7 files changed, 508 insertions(+), 30 deletions(-) diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index 192e64d69b..191f29ccd4 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -1,5 +1,5 @@ @@ -66,12 +66,12 @@ and table_constraint is: If a schema name is given (for example, CREATE TABLE - myschema.mytable ...) then the table is created in the - specified schema. Otherwise it is created in the current schema. - Temporary tables exist in a special schema, so a schema name may not be - given when creating a temporary table. - The table name must be distinct from the name of any other table, - sequence, index, or view in the same schema. + myschema.mytable ...) then the table is created in the specified + schema. Otherwise it is created in the current schema. Temporary + tables exist in a special schema, so a schema name may not be given + when creating a temporary table. The name of the table must be + distinct from the name of any other table, sequence, index, or view + in the same schema. diff --git a/doc/src/sgml/ref/create_view.sgml b/doc/src/sgml/ref/create_view.sgml index 2957821691..8c18378dee 100644 --- a/doc/src/sgml/ref/create_view.sgml +++ b/doc/src/sgml/ref/create_view.sgml @@ -1,5 +1,5 @@ @@ -20,7 +20,7 @@ PostgreSQL documentation -CREATE [ OR REPLACE ] VIEW name [ ( name [ ( column_name [, ...] ) ] AS query @@ -43,10 +43,12 @@ class="PARAMETER">column_name [, ...] ) ] AS column_name [, ...] ) ] AS name @@ -102,7 +126,8 @@ class="PARAMETER">column_name [, ...] ) ] AS + statement to drop views. @@ -153,7 +178,7 @@ CREATE VIEW comedies AS CREATE VIEW name [ ( column [, ...] ) ] AS query - [ WITH [ CASCADE | LOCAL ] CHECK OPTION ] + [ WITH [ CASCADED | LOCAL ] CHECK OPTION ] @@ -184,12 +209,12 @@ CREATE VIEW name [ ( - CASCADE + CASCADED Check for integrity on this view and on any dependent - view. CASCADE is assumed if neither - CASCADE nor LOCAL is specified. + view. CASCADED is assumed if neither + CASCADED nor LOCAL is specified. diff --git a/src/backend/commands/view.c b/src/backend/commands/view.c index 270b9f8b13..10caef1375 100644 --- a/src/backend/commands/view.c +++ b/src/backend/commands/view.c @@ -8,7 +8,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/commands/view.c,v 1.86 2004/12/31 21:59:42 pgsql Exp $ + * $PostgreSQL: pgsql/src/backend/commands/view.c,v 1.87 2005/02/02 06:36:00 neilc Exp $ * *------------------------------------------------------------------------- */ @@ -21,6 +21,7 @@ #include "commands/view.h" #include "miscadmin.h" #include "nodes/makefuncs.h" +#include "optimizer/clauses.h" #include "parser/parse_relation.h" #include "rewrite/rewriteDefine.h" #include "rewrite/rewriteManip.h" @@ -30,7 +31,55 @@ static void checkViewTupleDesc(TupleDesc newdesc, TupleDesc olddesc); +static bool isViewOnTempTable_walker(Node *node, void *context); +/*--------------------------------------------------------------------- + * isViewOnTempTable + * + * Returns true iff any of the relations underlying this view are + * temporary tables. + *--------------------------------------------------------------------- + */ +static bool +isViewOnTempTable(Query *viewParse) +{ + return isViewOnTempTable_walker((Node *) viewParse, NULL); +} + +static bool +isViewOnTempTable_walker(Node *node, void *context) +{ + if (node == NULL) + return false; + + if (IsA(node, Query)) + { + Query *query = (Query *) node; + ListCell *rtable; + + foreach (rtable, query->rtable) + { + RangeTblEntry *rte = lfirst(rtable); + if (rte->rtekind == RTE_RELATION) + { + Relation rel = heap_open(rte->relid, AccessShareLock); + bool istemp = rel->rd_istemp; + heap_close(rel, AccessShareLock); + if (istemp) + return true; + } + } + + return query_tree_walker(query, + isViewOnTempTable_walker, + context, + QTW_IGNORE_JOINALIASES); + } + + return expression_tree_walker(node, + isViewOnTempTable_walker, + context); +} /*--------------------------------------------------------------------- * DefineVirtualRelation @@ -117,6 +166,13 @@ DefineVirtualRelation(const RangeVar *relation, List *tlist, bool replace) aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_CLASS, RelationGetRelationName(rel)); + /* + * Due to the namespace visibility rules for temporary + * objects, we should only end up replacing a temporary view + * with another temporary view, and vice versa. + */ + Assert(relation->istemp == rel->rd_istemp); + /* * Create a tuple descriptor to compare against the existing view, * and verify it matches. @@ -326,17 +382,29 @@ UpdateRangeTableOfViewParse(Oid viewOid, Query *viewParse) *------------------------------------------------------------------- */ void -DefineView(const RangeVar *view, Query *viewParse, bool replace) +DefineView(RangeVar *view, Query *viewParse, bool replace) { Oid viewOid; + /* + * If the user didn't explicitly ask for a temporary view, check + * whether we need one implicitly. + */ + if (!view->istemp) + { + view->istemp = isViewOnTempTable(viewParse); + if (view->istemp) + ereport(NOTICE, + (errmsg("view \"%s\" will be a temporary view", + view->relname))); + } + /* * Create the view relation * * NOTE: if it already exists and replace is false, the xact will be * aborted. */ - viewOid = DefineVirtualRelation(view, viewParse->targetList, replace); /* diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index 757a17e891..69e7082197 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -11,7 +11,7 @@ * * * IDENTIFICATION - * $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.482 2005/01/27 03:17:59 tgl Exp $ + * $PostgreSQL: pgsql/src/backend/parser/gram.y,v 2.483 2005/02/02 06:36:01 neilc Exp $ * * HISTORY * AUTHOR DATE MAJOR EVENT @@ -4075,24 +4075,35 @@ transaction_mode_list_or_empty: /***************************************************************************** * - * QUERY: - * create view '('target-list ')' AS + * QUERY: + * CREATE [ OR REPLACE ] [ TEMP ] VIEW '('target-list ')' AS * *****************************************************************************/ -ViewStmt: CREATE opt_or_replace VIEW qualified_name opt_column_list +ViewStmt: CREATE OptTemp VIEW qualified_name opt_column_list AS SelectStmt { ViewStmt *n = makeNode(ViewStmt); - n->replace = $2; + n->replace = false; n->view = $4; + n->view->istemp = $2; n->aliases = $5; n->query = (Query *) $7; - $$ = (Node *)n; + $$ = (Node *) n; + } + | CREATE OR REPLACE OptTemp VIEW qualified_name opt_column_list + AS SelectStmt + { + ViewStmt *n = makeNode(ViewStmt); + n->replace = true; + n->view = $6; + n->view->istemp = $4; + n->aliases = $7; + n->query = (Query *) $9; + $$ = (Node *) n; } ; - /***************************************************************************** * * QUERY: diff --git a/src/include/commands/view.h b/src/include/commands/view.h index bbd57131ce..bce253834e 100644 --- a/src/include/commands/view.h +++ b/src/include/commands/view.h @@ -7,7 +7,7 @@ * Portions Copyright (c) 1996-2005, PostgreSQL Global Development Group * Portions Copyright (c) 1994, Regents of the University of California * - * $PostgreSQL: pgsql/src/include/commands/view.h,v 1.21 2004/12/31 22:03:28 pgsql Exp $ + * $PostgreSQL: pgsql/src/include/commands/view.h,v 1.22 2005/02/02 06:36:01 neilc Exp $ * *------------------------------------------------------------------------- */ @@ -16,7 +16,7 @@ #include "nodes/parsenodes.h" -extern void DefineView(const RangeVar *view, Query *view_parse, bool replace); +extern void DefineView(RangeVar *view, Query *view_parse, bool replace); extern void RemoveView(const RangeVar *view, DropBehavior behavior); #endif /* VIEW_H */ diff --git a/src/test/regress/expected/create_view.out b/src/test/regress/expected/create_view.out index 04e62f7084..b6be745063 100644 --- a/src/test/regress/expected/create_view.out +++ b/src/test/regress/expected/create_view.out @@ -60,3 +60,249 @@ CREATE OR REPLACE VIEW viewtest AS ERROR: cannot change data type of view column "b" DROP VIEW viewtest; DROP TABLE viewtest_tbl; +-- tests for temporary views +CREATE SCHEMA temp_view_test + CREATE TABLE base_table (a int, id int) + CREATE TABLE base_table2 (a int, id int); +SET search_path TO temp_view_test, public; +CREATE TEMPORARY TABLE temp_table (a int, id int); +-- should be created in temp_view_test schema +CREATE VIEW v1 AS SELECT * FROM base_table; +-- should be created in temp object schema +CREATE VIEW v1_temp AS SELECT * FROM temp_table; +NOTICE: view "v1_temp" will be a temporary view +-- should be created in temp object schema +CREATE TEMP VIEW v2_temp AS SELECT * FROM base_table; +-- should be created in temp_views schema +CREATE VIEW temp_view_test.v2 AS SELECT * FROM base_table; +-- should fail +CREATE VIEW temp_view_test.v3_temp AS SELECT * FROM temp_table; +NOTICE: view "v3_temp" will be a temporary view +ERROR: temporary tables may not specify a schema name +-- should fail +CREATE SCHEMA test_schema + CREATE TEMP VIEW testview AS SELECT 1; +ERROR: temporary tables may not specify a schema name +-- joins: if any of the join relations are temporary, the view +-- should also be temporary +-- should be non-temp +CREATE VIEW v3 AS + SELECT t1.a AS t1_a, t2.a AS t2_a + FROM base_table t1, base_table2 t2 + WHERE t1.id = t2.id; +-- should be temp (one join rel is temp) +CREATE VIEW v4_temp AS + SELECT t1.a AS t1_a, t2.a AS t2_a + FROM base_table t1, temp_table t2 + WHERE t1.id = t2.id; +NOTICE: view "v4_temp" will be a temporary view +-- should be temp +CREATE VIEW v5_temp AS + SELECT t1.a AS t1_a, t2.a AS t2_a, t3.a AS t3_a + FROM base_table t1, base_table2 t2, temp_table t3 + WHERE t1.id = t2.id and t2.id = t3.id; +NOTICE: view "v5_temp" will be a temporary view +-- subqueries +CREATE VIEW v4 AS SELECT * FROM base_table WHERE id IN (SELECT id FROM base_table2); +CREATE VIEW v5 AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM base_table2) t2; +CREATE VIEW v6 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM base_table2); +CREATE VIEW v7 AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM base_table2); +CREATE VIEW v8 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1); +CREATE VIEW v6_temp AS SELECT * FROM base_table WHERE id IN (SELECT id FROM temp_table); +NOTICE: view "v6_temp" will be a temporary view +CREATE VIEW v7_temp AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM temp_table) t2; +NOTICE: view "v7_temp" will be a temporary view +CREATE VIEW v8_temp AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM temp_table); +NOTICE: view "v8_temp" will be a temporary view +CREATE VIEW v9_temp AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM temp_table); +NOTICE: view "v9_temp" will be a temporary view +-- a view should also be temporary if it references a temporary view +CREATE VIEW v10_temp AS SELECT * FROM v7_temp; +NOTICE: view "v10_temp" will be a temporary view +CREATE VIEW v11_temp AS SELECT t1.id, t2.a FROM base_table t1, v10_temp t2; +NOTICE: view "v11_temp" will be a temporary view +CREATE VIEW v12_temp AS SELECT true FROM v11_temp; +NOTICE: view "v12_temp" will be a temporary view +-- a view should also be temporary if it references a temporary sequence +CREATE SEQUENCE seq1; +CREATE TEMPORARY SEQUENCE seq1_temp; +CREATE VIEW v9 AS SELECT seq1.is_called; +CREATE VIEW v13_temp AS SELECT seq1_temp.is_called; +NOTICE: view "v13_temp" will be a temporary view +SELECT relname FROM pg_class + WHERE relname LIKE 'v_' + AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'temp_view_test') + ORDER BY relname; + relname +--------- + v1 + v2 + v3 + v4 + v5 + v6 + v7 + v8 + v9 +(9 rows) + +SELECT relname FROM pg_class + WHERE relname LIKE 'v%' + AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%') + ORDER BY relname; + relname +---------- + v10_temp + v11_temp + v12_temp + v13_temp + v1_temp + v2_temp + v4_temp + v5_temp + v6_temp + v7_temp + v8_temp + v9_temp +(12 rows) + +CREATE SCHEMA testviewschm2; +SET search_path TO testviewschm2, public; +CREATE TABLE t1 (num int, name text); +CREATE TABLE t2 (num2 int, value text); +CREATE TEMP TABLE tt (num2 int, value text); +CREATE VIEW nontemp1 AS SELECT * FROM t1 CROSS JOIN t2; +CREATE VIEW temporal1 AS SELECT * FROM t1 CROSS JOIN tt; +NOTICE: view "temporal1" will be a temporary view +CREATE VIEW nontemp2 AS SELECT * FROM t1 INNER JOIN t2 ON t1.num = t2.num2; +CREATE VIEW temporal2 AS SELECT * FROM t1 INNER JOIN tt ON t1.num = tt.num2; +NOTICE: view "temporal2" will be a temporary view +CREATE VIEW nontemp3 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2; +CREATE VIEW temporal3 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2; +NOTICE: view "temporal3" will be a temporary view +CREATE VIEW nontemp4 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2 AND t2.value = 'xxx'; +CREATE VIEW temporal4 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2 AND tt.value = 'xxx'; +NOTICE: view "temporal4" will be a temporary view +SELECT relname FROM pg_class + WHERE relname LIKE 'nontemp%' + AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'testviewschm2') + ORDER BY relname; + relname +---------- + nontemp1 + nontemp2 + nontemp3 + nontemp4 +(4 rows) + +SELECT relname FROM pg_class + WHERE relname LIKE 'temporal%' + AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%') + ORDER BY relname; + relname +----------- + temporal1 + temporal2 + temporal3 + temporal4 +(4 rows) + +CREATE TABLE tbl1 ( a int, b int); +CREATE TABLE tbl2 (c int, d int); +CREATE TABLE tbl3 (e int, f int); +CREATE TABLE tbl4 (g int, h int); +CREATE TEMP TABLE tmptbl (i int, j int); +--Should be in testviewschm2 +CREATE VIEW pubview AS SELECT * FROM tbl1 WHERE tbl1.a +BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2) +AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f); +SELECT count(*) FROM pg_class where relname = 'pubview' +AND relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname = 'testviewschm2'); + count +------- + 1 +(1 row) + +--Should be in temp object schema +CREATE VIEW mytempview AS SELECT * FROM tbl1 WHERE tbl1.a +BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2) +AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f) +AND NOT EXISTS (SELECT g FROM tbl4 LEFT JOIN tmptbl ON tbl4.h = tmptbl.j); +NOTICE: view "mytempview" will be a temporary view +SELECT count(*) FROM pg_class where relname LIKE 'mytempview' +And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%'); + count +------- + 1 +(1 row) + +DROP SCHEMA temp_view_test CASCADE; +NOTICE: drop cascades to view temp_view_test.v9 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v9 +NOTICE: drop cascades to sequence temp_view_test.seq1 +NOTICE: drop cascades to view temp_view_test.v8 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v8 +NOTICE: drop cascades to view temp_view_test.v7 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v7 +NOTICE: drop cascades to view temp_view_test.v6 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v6 +NOTICE: drop cascades to view temp_view_test.v5 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v5 +NOTICE: drop cascades to view temp_view_test.v4 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v4 +NOTICE: drop cascades to view temp_view_test.v3 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v3 +NOTICE: drop cascades to view temp_view_test.v2 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v2 +NOTICE: drop cascades to view temp_view_test.v1 +NOTICE: drop cascades to rule _RETURN on view temp_view_test.v1 +NOTICE: drop cascades to table temp_view_test.base_table2 +NOTICE: drop cascades to rule _RETURN on view v5_temp +NOTICE: drop cascades to view v5_temp +NOTICE: drop cascades to table temp_view_test.base_table +NOTICE: drop cascades to rule _RETURN on view v9_temp +NOTICE: drop cascades to view v9_temp +NOTICE: drop cascades to rule _RETURN on view v8_temp +NOTICE: drop cascades to view v8_temp +NOTICE: drop cascades to rule _RETURN on view v6_temp +NOTICE: drop cascades to view v6_temp +NOTICE: drop cascades to rule _RETURN on view v4_temp +NOTICE: drop cascades to view v4_temp +NOTICE: drop cascades to rule _RETURN on view v2_temp +NOTICE: drop cascades to view v2_temp +NOTICE: drop cascades to rule _RETURN on view v11_temp +NOTICE: drop cascades to view v11_temp +NOTICE: drop cascades to rule _RETURN on view v12_temp +NOTICE: drop cascades to view v12_temp +NOTICE: drop cascades to rule _RETURN on view v7_temp +NOTICE: drop cascades to view v7_temp +NOTICE: drop cascades to rule _RETURN on view v10_temp +NOTICE: drop cascades to view v10_temp +DROP SCHEMA testviewschm2 CASCADE; +NOTICE: drop cascades to view pubview +NOTICE: drop cascades to rule _RETURN on view pubview +NOTICE: drop cascades to table tbl4 +NOTICE: drop cascades to rule _RETURN on view mytempview +NOTICE: drop cascades to view mytempview +NOTICE: drop cascades to table tbl3 +NOTICE: drop cascades to table tbl2 +NOTICE: drop cascades to table tbl1 +NOTICE: drop cascades to view nontemp4 +NOTICE: drop cascades to rule _RETURN on view nontemp4 +NOTICE: drop cascades to view nontemp3 +NOTICE: drop cascades to rule _RETURN on view nontemp3 +NOTICE: drop cascades to view nontemp2 +NOTICE: drop cascades to rule _RETURN on view nontemp2 +NOTICE: drop cascades to view nontemp1 +NOTICE: drop cascades to rule _RETURN on view nontemp1 +NOTICE: drop cascades to table t2 +NOTICE: drop cascades to table t1 +NOTICE: drop cascades to rule _RETURN on view temporal4 +NOTICE: drop cascades to view temporal4 +NOTICE: drop cascades to rule _RETURN on view temporal3 +NOTICE: drop cascades to view temporal3 +NOTICE: drop cascades to rule _RETURN on view temporal2 +NOTICE: drop cascades to view temporal2 +NOTICE: drop cascades to rule _RETURN on view temporal1 +NOTICE: drop cascades to view temporal1 +SET search_path to public; diff --git a/src/test/regress/sql/create_view.sql b/src/test/regress/sql/create_view.sql index acc82b3e0e..008ebae704 100644 --- a/src/test/regress/sql/create_view.sql +++ b/src/test/regress/sql/create_view.sql @@ -63,3 +63,131 @@ CREATE OR REPLACE VIEW viewtest AS DROP VIEW viewtest; DROP TABLE viewtest_tbl; + +-- tests for temporary views + +CREATE SCHEMA temp_view_test + CREATE TABLE base_table (a int, id int) + CREATE TABLE base_table2 (a int, id int); + +SET search_path TO temp_view_test, public; + +CREATE TEMPORARY TABLE temp_table (a int, id int); + +-- should be created in temp_view_test schema +CREATE VIEW v1 AS SELECT * FROM base_table; +-- should be created in temp object schema +CREATE VIEW v1_temp AS SELECT * FROM temp_table; +-- should be created in temp object schema +CREATE TEMP VIEW v2_temp AS SELECT * FROM base_table; +-- should be created in temp_views schema +CREATE VIEW temp_view_test.v2 AS SELECT * FROM base_table; +-- should fail +CREATE VIEW temp_view_test.v3_temp AS SELECT * FROM temp_table; +-- should fail +CREATE SCHEMA test_schema + CREATE TEMP VIEW testview AS SELECT 1; + +-- joins: if any of the join relations are temporary, the view +-- should also be temporary + +-- should be non-temp +CREATE VIEW v3 AS + SELECT t1.a AS t1_a, t2.a AS t2_a + FROM base_table t1, base_table2 t2 + WHERE t1.id = t2.id; +-- should be temp (one join rel is temp) +CREATE VIEW v4_temp AS + SELECT t1.a AS t1_a, t2.a AS t2_a + FROM base_table t1, temp_table t2 + WHERE t1.id = t2.id; +-- should be temp +CREATE VIEW v5_temp AS + SELECT t1.a AS t1_a, t2.a AS t2_a, t3.a AS t3_a + FROM base_table t1, base_table2 t2, temp_table t3 + WHERE t1.id = t2.id and t2.id = t3.id; + +-- subqueries +CREATE VIEW v4 AS SELECT * FROM base_table WHERE id IN (SELECT id FROM base_table2); +CREATE VIEW v5 AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM base_table2) t2; +CREATE VIEW v6 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM base_table2); +CREATE VIEW v7 AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM base_table2); +CREATE VIEW v8 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1); + +CREATE VIEW v6_temp AS SELECT * FROM base_table WHERE id IN (SELECT id FROM temp_table); +CREATE VIEW v7_temp AS SELECT t1.id, t2.a FROM base_table t1, (SELECT * FROM temp_table) t2; +CREATE VIEW v8_temp AS SELECT * FROM base_table WHERE EXISTS (SELECT 1 FROM temp_table); +CREATE VIEW v9_temp AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM temp_table); + +-- a view should also be temporary if it references a temporary view +CREATE VIEW v10_temp AS SELECT * FROM v7_temp; +CREATE VIEW v11_temp AS SELECT t1.id, t2.a FROM base_table t1, v10_temp t2; +CREATE VIEW v12_temp AS SELECT true FROM v11_temp; + +-- a view should also be temporary if it references a temporary sequence +CREATE SEQUENCE seq1; +CREATE TEMPORARY SEQUENCE seq1_temp; +CREATE VIEW v9 AS SELECT seq1.is_called; +CREATE VIEW v13_temp AS SELECT seq1_temp.is_called; + +SELECT relname FROM pg_class + WHERE relname LIKE 'v_' + AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'temp_view_test') + ORDER BY relname; +SELECT relname FROM pg_class + WHERE relname LIKE 'v%' + AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%') + ORDER BY relname; + +CREATE SCHEMA testviewschm2; +SET search_path TO testviewschm2, public; + +CREATE TABLE t1 (num int, name text); +CREATE TABLE t2 (num2 int, value text); +CREATE TEMP TABLE tt (num2 int, value text); + +CREATE VIEW nontemp1 AS SELECT * FROM t1 CROSS JOIN t2; +CREATE VIEW temporal1 AS SELECT * FROM t1 CROSS JOIN tt; +CREATE VIEW nontemp2 AS SELECT * FROM t1 INNER JOIN t2 ON t1.num = t2.num2; +CREATE VIEW temporal2 AS SELECT * FROM t1 INNER JOIN tt ON t1.num = tt.num2; +CREATE VIEW nontemp3 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2; +CREATE VIEW temporal3 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2; +CREATE VIEW nontemp4 AS SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num2 AND t2.value = 'xxx'; +CREATE VIEW temporal4 AS SELECT * FROM t1 LEFT JOIN tt ON t1.num = tt.num2 AND tt.value = 'xxx'; + +SELECT relname FROM pg_class + WHERE relname LIKE 'nontemp%' + AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'testviewschm2') + ORDER BY relname; +SELECT relname FROM pg_class + WHERE relname LIKE 'temporal%' + AND relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname LIKE 'pg_temp%') + ORDER BY relname; + +CREATE TABLE tbl1 ( a int, b int); +CREATE TABLE tbl2 (c int, d int); +CREATE TABLE tbl3 (e int, f int); +CREATE TABLE tbl4 (g int, h int); +CREATE TEMP TABLE tmptbl (i int, j int); + +--Should be in testviewschm2 +CREATE VIEW pubview AS SELECT * FROM tbl1 WHERE tbl1.a +BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2) +AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f); + +SELECT count(*) FROM pg_class where relname = 'pubview' +AND relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname = 'testviewschm2'); + +--Should be in temp object schema +CREATE VIEW mytempview AS SELECT * FROM tbl1 WHERE tbl1.a +BETWEEN (SELECT d FROM tbl2 WHERE c = 1) AND (SELECT e FROM tbl3 WHERE f = 2) +AND EXISTS (SELECT g FROM tbl4 LEFT JOIN tbl3 ON tbl4.h = tbl3.f) +AND NOT EXISTS (SELECT g FROM tbl4 LEFT JOIN tmptbl ON tbl4.h = tmptbl.j); + +SELECT count(*) FROM pg_class where relname LIKE 'mytempview' +And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%'); + +DROP SCHEMA temp_view_test CASCADE; +DROP SCHEMA testviewschm2 CASCADE; + +SET search_path to public;