Commit 73f63050 authored by Neil Conway's avatar Neil Conway

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".
parent f94197ef
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table.sgml,v 1.91 2005/01/22 23:22:17 momjian Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table.sgml,v 1.92 2005/02/02 06:35:59 neilc Exp $
PostgreSQL documentation
-->
......@@ -66,12 +66,12 @@ and <replaceable class="PARAMETER">table_constraint</replaceable> is:
<para>
If a schema name is given (for example, <literal>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.
</para>
<para>
......
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.29 2005/01/04 00:39:53 tgl Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.30 2005/02/02 06:35:59 neilc Exp $
PostgreSQL documentation
-->
......@@ -20,7 +20,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
CREATE [ OR REPLACE ] VIEW <replaceable class="PARAMETER">name</replaceable> [ ( <replaceable
CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">name</replaceable> [ ( <replaceable
class="PARAMETER">column_name</replaceable> [, ...] ) ] AS <replaceable class="PARAMETER">query</replaceable>
</synopsis>
</refsynopsisdiv>
......@@ -43,10 +43,12 @@ class="PARAMETER">column_name</replaceable> [, ...] ) ] AS <replaceable class="P
<para>
If a schema name is given (for example, <literal>CREATE VIEW
myschema.myview ...</>) then the view is created in the
specified schema. Otherwise it is created in the current schema.
The view name must be distinct from the name of any other view, table,
sequence, or index in the same schema.
myschema.myview ...</>) then the view is created in the specified
schema. Otherwise it is created in the current schema. Temporary
views exist in a special schema, so a schema name may not be given
when creating a temporary view. The name of the view must be
distinct from the name of any other view, table, sequence, or index
in the same schema.
</para>
</refsect1>
......@@ -54,6 +56,28 @@ class="PARAMETER">column_name</replaceable> [, ...] ) ] AS <replaceable class="P
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>TEMPORARY</> or <literal>TEMP</></term>
<listitem>
<para>
If specified, the view is created as a temporary view.
Temporary views are automatically dropped at the end of the
current session. Temporary views are automatically placed in the
current backend's local temporary schema, so it is illegal to
specify a schema-qualified name for a temporary view. Existing
permanent relations with the same name are not visible to the
current session while the temporary view exists, unless they are
referenced with schema-qualified names.
</para>
<para>
If any of the base tables referenced by the view are temporary,
the view is created as a temporary view (whether
<literal>TEMPORARY</literal> is specified or not).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
......@@ -102,7 +126,8 @@ class="PARAMETER">column_name</replaceable> [, ...] ) ] AS <replaceable class="P
</para>
<para>
Use the <command>DROP VIEW</command> statement to drop views.
Use the <xref linkend="sql-dropview" endterm="sql-dropview-title">
statement to drop views.
</para>
<para>
......@@ -153,7 +178,7 @@ CREATE VIEW comedies AS
<synopsis>
CREATE VIEW <replaceable class="parameter">name</replaceable> [ ( <replaceable class="parameter">column</replaceable> [, ...] ) ]
AS query
[ WITH [ CASCADE | LOCAL ] CHECK OPTION ]
[ WITH [ CASCADED | LOCAL ] CHECK OPTION ]
</synopsis>
</para>
......@@ -184,12 +209,12 @@ CREATE VIEW <replaceable class="parameter">name</replaceable> [ ( <replaceable c
</varlistentry>
<varlistentry>
<term><literal>CASCADE</literal></term>
<term><literal>CASCADED</literal></term>
<listitem>
<para>
Check for integrity on this view and on any dependent
view. <literal>CASCADE</> is assumed if neither
<literal>CASCADE</> nor <literal>LOCAL</> is specified.
view. <literal>CASCADED</> is assumed if neither
<literal>CASCADED</> nor <literal>LOCAL</> is specified.
</para>
</listitem>
</varlistentry>
......
......@@ -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);
/*
......
......@@ -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 <viewname> '('target-list ')' AS <query>
* QUERY:
* CREATE [ OR REPLACE ] [ TEMP ] VIEW <viewname> '('target-list ')' AS <query>
*
*****************************************************************************/
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:
......
......@@ -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 */
This diff is collapsed.
......@@ -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;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment