<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_rule.sgml,v 1.36 2002/05/18 15:44:47 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_rule.sgml,v 1.37 2002/09/02 20:04:39 tgl Exp $
PostgreSQL documentation
-->
<date>2001-01-05</date>
</refsynopsisdivinfo>
<synopsis>
-CREATE RULE <replaceable class="parameter">name</replaceable> AS ON <replaceable class="parameter">event</replaceable>
+CREATE [ OR REPLACE ] RULE <replaceable class="parameter">name</replaceable> AS ON <replaceable class="parameter">event</replaceable>
TO <replaceable class="parameter">table</replaceable> [ WHERE <replaceable class="parameter">condition</replaceable> ]
DO [ INSTEAD ] <replaceable class="parameter">action</replaceable>
where <replaceable class="PARAMETER">action</replaceable> can be:
NOTHING
-|
-<replaceable class="parameter">query</replaceable>
-|
-( <replaceable class="parameter">query</replaceable> ; <replaceable class="parameter">query</replaceable> ... )
+| <replaceable class="parameter">query</replaceable>
+| ( <replaceable class="parameter">query</replaceable> ; <replaceable class="parameter">query</replaceable> ... )
</synopsis>
<refsect2 id="R2-SQL-CREATERULE-1">
<term><replaceable class="parameter">condition</replaceable></term>
<listitem>
<para>
- Any SQL conditional expression (returning <type>boolean</type>). The condition expression may not
+ Any SQL conditional expression (returning <type>boolean</type>).
+ The condition expression may not
refer to any tables except <literal>new</literal> and
- <literal>old</literal>.
+ <literal>old</literal>, and may not contain aggregate functions.
</para>
</listitem>
</varlistentry>
Description
</title>
+ <para>
+ <command>CREATE RULE</command> defines a new rule applying to a specified
+ table or view.
+ <command>CREATE OR REPLACE RULE</command> will either create a
+ new rule, or replace an existing rule of the same name for the same
+ table.
+ </para>
+
<para>
The <productname>PostgreSQL</productname>
<firstterm>rule system</firstterm> allows one to define an
</title>
<para>
- <command>CREATE RULE</command> statement is a <productname>PostgreSQL</productname>
+ <command>CREATE RULE</command> is a <productname>PostgreSQL</productname>
language extension.
There is no <command>CREATE RULE</command> statement in <acronym>SQL92</acronym>.
</para>
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_view.sgml,v 1.18 2002/05/18 15:44:47 petere Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_view.sgml,v 1.19 2002/09/02 20:04:39 tgl Exp $
PostgreSQL documentation
-->
<date>2000-03-25</date>
</refsynopsisdivinfo>
<synopsis>
-CREATE VIEW <replaceable class="PARAMETER">view</replaceable> [ ( <replaceable
+CREATE [ OR REPLACE ] VIEW <replaceable class="PARAMETER">view</replaceable> [ ( <replaceable
class="PARAMETER">column name list</replaceable> ) ] AS SELECT <replaceable class="PARAMETER">query</replaceable>
</synopsis>
<title>
Description
</title>
+
<para>
- <command>CREATE VIEW</command> will define a view of a query.
+ <command>CREATE VIEW</command> defines a view of a query.
The view is not physically materialized. Instead, a query
rewrite rule (an <literal>ON SELECT</> rule) is automatically generated to
support SELECT operations on views.
</para>
+ <para>
+ <command>CREATE OR REPLACE VIEW</command> is similar, but if a view
+ of the same name already exists, it is replaced. You can only replace
+ a view with a new query that generates the identical set of columns
+ (i.e., same column names and data types).
+ </para>
+
<para>
If a schema name is given (for example, <literal>CREATE VIEW
myschema.myview ...</>) then the view is created in the
<title>
SQL92
</title>
+
<para>
SQL92 specifies some additional capabilities for the
<command>CREATE VIEW</command> statement:
</varlistentry>
</variablelist>
</para>
+
+ <para>
+ <command>CREATE OR REPLACE VIEW</command> is a
+ <productname>PostgreSQL</productname> language extension.
+ </para>
+
</refsect2>
</refsect1>
</refentry>
<!--
-$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.156 2002/08/30 22:18:05 tgl Exp $
+$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.157 2002/09/02 20:04:39 tgl Exp $
-->
<appendix id="release">
worries about funny characters.
-->
<literallayout><![CDATA[
+CREATE OR REPLACE VIEW, CREATE OR REPLACE RULE are available
No-autocommit mode is available (set autocommit to off)
Substantial improvements in functionality for functions returning sets
Client libraries older than 6.3 no longer supported (version 0 protocol removed)
*
*
* IDENTIFICATION
- * $Header: /cvsroot/pgsql/src/backend/commands/view.c,v 1.69 2002/09/02 02:13:01 tgl Exp $
+ * $Header: /cvsroot/pgsql/src/backend/commands/view.c,v 1.70 2002/09/02 20:04:40 tgl Exp $
*
*-------------------------------------------------------------------------
*/
#include "utils/lsyscache.h"
+static void checkViewTupleDesc(TupleDesc newdesc, TupleDesc olddesc);
+
+
/*---------------------------------------------------------------------
* DefineVirtualRelation
*
/*
* Create a tuple descriptor to compare against the existing view,
* and verify it matches.
- *
- * XXX the error message is a bit cheesy here: would be useful to
- * give a more specific complaint about the difference in the
- * descriptors. No time for it at the moment though.
*/
descriptor = BuildDescForRelation(attrList);
- if (!equalTupleDescs(descriptor, rel->rd_att))
- elog(ERROR, "Cannot change column set of existing view %s",
- RelationGetRelationName(rel));
+ checkViewTupleDesc(descriptor, rel->rd_att);
/*
* Seems okay, so return the OID of the pre-existing view.
}
}
+/*
+ * Verify that tupledesc associated with proposed new view definition
+ * matches tupledesc of old view. This is basically a cut-down version
+ * of equalTupleDescs(), with code added to generate specific complaints.
+ */
+static void
+checkViewTupleDesc(TupleDesc newdesc, TupleDesc olddesc)
+{
+ int i;
+
+ if (newdesc->natts != olddesc->natts)
+ elog(ERROR, "Cannot change number of columns in view");
+ /* we can ignore tdhasoid */
+
+ for (i = 0; i < newdesc->natts; i++)
+ {
+ Form_pg_attribute newattr = newdesc->attrs[i];
+ Form_pg_attribute oldattr = olddesc->attrs[i];
+
+ /* XXX not right, but we don't support DROP COL on view anyway */
+ if (newattr->attisdropped != oldattr->attisdropped)
+ elog(ERROR, "Cannot change number of columns in view");
+
+ if (strcmp(NameStr(newattr->attname), NameStr(oldattr->attname)) != 0)
+ elog(ERROR, "Cannot change name of view column \"%s\"",
+ NameStr(oldattr->attname));
+ /* XXX would it be safe to allow atttypmod to change? Not sure */
+ if (newattr->atttypid != oldattr->atttypid ||
+ newattr->atttypmod != oldattr->atttypmod)
+ elog(ERROR, "Cannot change datatype of view column \"%s\"",
+ NameStr(oldattr->attname));
+ /* We can ignore the remaining attributes of an attribute... */
+ }
+ /*
+ * We ignore the constraint fields. The new view desc can't have any
+ * constraints, and the only ones that could be on the old view are
+ * defaults, which we are happy to leave in place.
+ */
+}
+
static RuleStmt *
FormViewRetrieveRule(const RangeVar *view, Query *viewParse, bool replace)
{
-- should fail
CREATE OR REPLACE VIEW viewtest AS
SELECT a FROM viewtest_tbl WHERE a <> 20;
-ERROR: Cannot change column set of existing view viewtest
+ERROR: Cannot change number of columns in view
-- should fail
CREATE OR REPLACE VIEW viewtest AS
SELECT 1, * FROM viewtest_tbl;
-ERROR: Cannot change column set of existing view viewtest
+ERROR: Cannot change number of columns in view
-- should fail
CREATE OR REPLACE VIEW viewtest AS
SELECT a, b::numeric FROM viewtest_tbl;
-ERROR: Cannot change column set of existing view viewtest
+ERROR: Cannot change datatype of view column "b"
DROP VIEW viewtest;
DROP TABLE viewtest_tbl;