mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-01-06 15:24:56 +08:00
Automatic view update rules
Bernd Helmle
This commit is contained in:
parent
5841aa86eb
commit
dd7e54a17f
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.189 2009/01/16 13:27:23 heikki Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.190 2009/01/22 17:27:54 petere Exp $ -->
|
||||
<!--
|
||||
Documentation of the system catalogs, directed toward PostgreSQL developers
|
||||
-->
|
||||
@ -4144,6 +4144,13 @@
|
||||
<entry>True if the rule is an <literal>INSTEAD</literal> rule</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>is_auto</structfield></entry>
|
||||
<entry><type>bool</type></entry>
|
||||
<entry></entry>
|
||||
<entry>True if the rule was automatically generated</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>ev_qual</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
|
@ -1,4 +1,4 @@
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/intro.sgml,v 1.32 2007/01/31 20:56:17 momjian Exp $ -->
|
||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/intro.sgml,v 1.33 2009/01/22 17:27:54 petere Exp $ -->
|
||||
|
||||
<preface id="preface">
|
||||
<title>Preface</title>
|
||||
@ -110,7 +110,7 @@
|
||||
<simpara>triggers</simpara>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<simpara>views</simpara>
|
||||
<simpara>updatable views</simpara>
|
||||
</listitem>
|
||||
<listitem>
|
||||
<simpara>transactional integrity</simpara>
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.39 2008/12/15 21:35:31 tgl Exp $
|
||||
$PostgreSQL: pgsql/doc/src/sgml/ref/create_view.sgml,v 1.40 2009/01/22 17:27:54 petere Exp $
|
||||
PostgreSQL documentation
|
||||
-->
|
||||
|
||||
@ -115,11 +115,99 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW <replaceable class="PARAMETER">n
|
||||
<title>Notes</title>
|
||||
|
||||
<para>
|
||||
Currently, views are read only: the system will not allow an insert,
|
||||
update, or delete on a view. You can get the effect of an updatable
|
||||
view by creating rules that rewrite inserts, etc. on the view into
|
||||
appropriate actions on other tables. For more information see
|
||||
<xref linkend="sql-createrule" endterm="sql-createrule-title">.
|
||||
Some views are updatable, which means that the
|
||||
commands <command>INSERT</command>, <command>UPDATE</command>,
|
||||
and <command>DELETE</command> can be used on the view as if it
|
||||
were a regular table. A view is updatable if it
|
||||
does <emphasis>not</emphasis> contain:
|
||||
|
||||
<itemizedlist>
|
||||
<listitem>
|
||||
<para>
|
||||
more than one underlying table (joins) or no underlying table at all
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
underlying tables/views that are themselves not updatable,
|
||||
including table value constructors and table functions
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
subqueries in the <literal>FROM</literal> list
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
items in the select list that are not direct references to a
|
||||
column of the underlying table, such as literals or any
|
||||
nontrivial value expression
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
references to system columns in the select list
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
more than one reference to the same column in the select list
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>aggregate function calls</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>window function calls</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
<literal>WITH</literal> or <literal>WITH RECURSIVE</literal> clauses
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
<literal>DISTINCT</literal>, <literal>GROUP BY</literal>, or
|
||||
<literal>HAVING</literal> clauses
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
<literal>UNION</literal>, <literal>INTERSECT</literal>, or
|
||||
<literal>EXCEPT</literal> clauses
|
||||
</para>
|
||||
</listitem>
|
||||
|
||||
<listitem>
|
||||
<para>
|
||||
<literal>LIMIT</literal> or <literal>OFFSET</literal> clauses
|
||||
(or other equivalent spellings thereof)
|
||||
</para>
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The updatable views implementation is based on the rule system.
|
||||
Because of this, you can also make more complex views updatable or
|
||||
insertable by creating your own rules that rewrite
|
||||
the <command>INSERT</command>,
|
||||
<command>UPDATE</command>, and <command>DELETE</command> actions
|
||||
on the view into appropriate actions on other tables. You can
|
||||
also replace the automatically generated rules by your own rules.
|
||||
For more information on the rule system, refer
|
||||
to <xref linkend="sql-createrule" endterm="sql-createrule-title">.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/backend/commands/view.c,v 1.111 2009/01/01 17:23:40 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/backend/commands/view.c,v 1.112 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -27,7 +27,9 @@
|
||||
#include "parser/parse_relation.h"
|
||||
#include "rewrite/rewriteDefine.h"
|
||||
#include "rewrite/rewriteManip.h"
|
||||
#include "rewrite/rewriteRemove.h"
|
||||
#include "rewrite/rewriteSupport.h"
|
||||
#include "rewrite/viewUpdate.h"
|
||||
#include "utils/acl.h"
|
||||
#include "utils/builtins.h"
|
||||
#include "utils/lsyscache.h"
|
||||
@ -308,13 +310,28 @@ DefineViewRules(Oid viewOid, Query *viewParse, bool replace)
|
||||
viewOid,
|
||||
NULL,
|
||||
CMD_SELECT,
|
||||
true,
|
||||
true, /* is_instead */
|
||||
true, /* is_auto */
|
||||
replace,
|
||||
list_make1(viewParse));
|
||||
|
||||
/*
|
||||
* Someday: automatic ON INSERT, etc
|
||||
* Delete all implicit rules on replace. CreateViewUpdateRules()
|
||||
* below will re-create them if appropriate for the new view
|
||||
* definition.
|
||||
*/
|
||||
if (replace)
|
||||
{
|
||||
Relation rel = heap_open(viewOid, AccessExclusiveLock);
|
||||
RemoveAutomaticRulesOnEvent(rel, CMD_INSERT);
|
||||
RemoveAutomaticRulesOnEvent(rel, CMD_DELETE);
|
||||
RemoveAutomaticRulesOnEvent(rel, CMD_UPDATE);
|
||||
heap_close(rel, NoLock);
|
||||
}
|
||||
|
||||
CommandCounterIncrement();
|
||||
|
||||
CreateViewUpdateRules(viewOid, viewParse);
|
||||
}
|
||||
|
||||
/*---------------------------------------------------------------
|
||||
|
@ -4,7 +4,7 @@
|
||||
# Makefile for rewrite
|
||||
#
|
||||
# IDENTIFICATION
|
||||
# $PostgreSQL: pgsql/src/backend/rewrite/Makefile,v 1.17 2008/02/19 10:30:08 petere Exp $
|
||||
# $PostgreSQL: pgsql/src/backend/rewrite/Makefile,v 1.18 2009/01/22 17:27:54 petere Exp $
|
||||
#
|
||||
#-------------------------------------------------------------------------
|
||||
|
||||
@ -13,6 +13,7 @@ top_builddir = ../../..
|
||||
include $(top_builddir)/src/Makefile.global
|
||||
|
||||
OBJS = rewriteRemove.o rewriteDefine.o \
|
||||
rewriteHandler.o rewriteManip.o rewriteSupport.o
|
||||
rewriteHandler.o rewriteManip.o rewriteSupport.o \
|
||||
viewUpdate.o
|
||||
|
||||
include $(top_srcdir)/src/backend/common.mk
|
||||
|
@ -8,13 +8,14 @@
|
||||
*
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteDefine.c,v 1.134 2009/01/01 17:23:47 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteDefine.c,v 1.135 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
#include "postgres.h"
|
||||
|
||||
#include "access/heapam.h"
|
||||
#include "access/xact.h"
|
||||
#include "catalog/dependency.h"
|
||||
#include "catalog/indexing.h"
|
||||
#include "catalog/namespace.h"
|
||||
@ -25,6 +26,7 @@
|
||||
#include "parser/parse_utilcmd.h"
|
||||
#include "rewrite/rewriteDefine.h"
|
||||
#include "rewrite/rewriteManip.h"
|
||||
#include "rewrite/rewriteRemove.h"
|
||||
#include "rewrite/rewriteSupport.h"
|
||||
#include "utils/acl.h"
|
||||
#include "utils/builtins.h"
|
||||
@ -39,6 +41,7 @@ static void checkRuleResultList(List *targetList, TupleDesc resultDesc,
|
||||
bool isSelect);
|
||||
static bool setRuleCheckAsUser_walker(Node *node, Oid *context);
|
||||
static void setRuleCheckAsUser_Query(Query *qry, Oid userid);
|
||||
static const char *rule_event_string(CmdType evtype);
|
||||
|
||||
|
||||
/*
|
||||
@ -52,6 +55,7 @@ InsertRule(char *rulname,
|
||||
Oid eventrel_oid,
|
||||
AttrNumber evslot_index,
|
||||
bool evinstead,
|
||||
bool is_auto,
|
||||
Node *event_qual,
|
||||
List *action,
|
||||
bool replace)
|
||||
@ -84,6 +88,7 @@ InsertRule(char *rulname,
|
||||
values[i++] = CharGetDatum(evtype + '0'); /* ev_type */
|
||||
values[i++] = CharGetDatum(RULE_FIRES_ON_ORIGIN); /* ev_enabled */
|
||||
values[i++] = BoolGetDatum(evinstead); /* is_instead */
|
||||
values[i++] = BoolGetDatum(is_auto); /* is_auto */
|
||||
values[i++] = CStringGetTextDatum(evqual); /* ev_qual */
|
||||
values[i++] = CStringGetTextDatum(actiontree); /* ev_action */
|
||||
|
||||
@ -102,7 +107,11 @@ InsertRule(char *rulname,
|
||||
|
||||
if (HeapTupleIsValid(oldtup))
|
||||
{
|
||||
if (!replace)
|
||||
/*
|
||||
* If REPLACE was not used we still check if the old rule is
|
||||
* automatic: Then we replace it anyway.
|
||||
*/
|
||||
if (!replace && !((Form_pg_rewrite) GETSTRUCT(oldtup))->is_auto)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_DUPLICATE_OBJECT),
|
||||
errmsg("rule \"%s\" for relation \"%s\" already exists",
|
||||
@ -115,6 +124,7 @@ InsertRule(char *rulname,
|
||||
replaces[Anum_pg_rewrite_ev_attr - 1] = true;
|
||||
replaces[Anum_pg_rewrite_ev_type - 1] = true;
|
||||
replaces[Anum_pg_rewrite_is_instead - 1] = true;
|
||||
replaces[Anum_pg_rewrite_is_auto - 1] = true;
|
||||
replaces[Anum_pg_rewrite_ev_qual - 1] = true;
|
||||
replaces[Anum_pg_rewrite_ev_action - 1] = true;
|
||||
|
||||
@ -205,6 +215,7 @@ DefineRule(RuleStmt *stmt, const char *queryString)
|
||||
whereClause,
|
||||
stmt->event,
|
||||
stmt->instead,
|
||||
false, /* not is_auto */
|
||||
stmt->replace,
|
||||
actions);
|
||||
}
|
||||
@ -223,6 +234,7 @@ DefineQueryRewrite(char *rulename,
|
||||
Node *event_qual,
|
||||
CmdType event_type,
|
||||
bool is_instead,
|
||||
bool is_auto,
|
||||
bool replace,
|
||||
List *action)
|
||||
{
|
||||
@ -446,6 +458,42 @@ DefineQueryRewrite(char *rulename,
|
||||
RelationGetDescr(event_relation),
|
||||
false);
|
||||
}
|
||||
|
||||
/*
|
||||
* If defining a non-automatic DO INSTEAD rule, drop all
|
||||
* automatic rules on the same event.
|
||||
*/
|
||||
if (!is_auto && is_instead)
|
||||
{
|
||||
RemoveAutomaticRulesOnEvent(event_relation, event_type);
|
||||
CommandCounterIncrement();
|
||||
}
|
||||
|
||||
/*
|
||||
* If defining an automatic rule and there is a manual rule on
|
||||
* the same event, warn and don't do it.
|
||||
*/
|
||||
if (is_auto && event_relation->rd_rules != NULL)
|
||||
{
|
||||
int i;
|
||||
|
||||
for (i = 0; i < event_relation->rd_rules->numLocks; i++)
|
||||
{
|
||||
RewriteRule *rule = event_relation->rd_rules->rules[i];
|
||||
|
||||
if (rule->event == event_type && !rule->is_auto && rule->isInstead == is_instead)
|
||||
{
|
||||
ereport(WARNING,
|
||||
(errmsg("automatic %s rule not created because manually created %s rule exists",
|
||||
rule_event_string(event_type), rule_event_string(event_type)),
|
||||
errhint("If you prefer to have the automatic rule, drop the manually created rule and run CREATE OR REPLACE VIEW again.")));
|
||||
|
||||
heap_close(event_relation, NoLock);
|
||||
return;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
}
|
||||
|
||||
/*
|
||||
@ -461,6 +509,7 @@ DefineQueryRewrite(char *rulename,
|
||||
event_relid,
|
||||
event_attno,
|
||||
is_instead,
|
||||
is_auto,
|
||||
event_qual,
|
||||
action,
|
||||
replace);
|
||||
@ -754,3 +803,16 @@ RenameRewriteRule(Oid owningRel, const char *oldName,
|
||||
}
|
||||
|
||||
#endif
|
||||
|
||||
|
||||
static const char *
|
||||
rule_event_string(CmdType type)
|
||||
{
|
||||
if (type == CMD_INSERT)
|
||||
return "INSERT";
|
||||
if (type == CMD_UPDATE)
|
||||
return "UPDATE";
|
||||
if (type == CMD_DELETE)
|
||||
return "DELETE";
|
||||
return "???";
|
||||
}
|
||||
|
@ -7,7 +7,7 @@
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteHandler.c,v 1.182 2009/01/01 17:23:47 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteHandler.c,v 1.183 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -1895,20 +1895,20 @@ QueryRewrite(Query *parsetree)
|
||||
{
|
||||
case CMD_INSERT:
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot insert into a view"),
|
||||
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
|
||||
errmsg("view is not updatable"),
|
||||
errhint("You need an unconditional ON INSERT DO INSTEAD rule.")));
|
||||
break;
|
||||
case CMD_UPDATE:
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot update a view"),
|
||||
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
|
||||
errmsg("view is not updatable"),
|
||||
errhint("You need an unconditional ON UPDATE DO INSTEAD rule.")));
|
||||
break;
|
||||
case CMD_DELETE:
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot delete from a view"),
|
||||
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
|
||||
errmsg("view is not updatable"),
|
||||
errhint("You need an unconditional ON DELETE DO INSTEAD rule.")));
|
||||
break;
|
||||
default:
|
||||
|
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteRemove.c,v 1.75 2009/01/01 17:23:47 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/backend/rewrite/rewriteRemove.c,v 1.76 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -90,6 +90,39 @@ RemoveRewriteRule(Oid owningRel, const char *ruleName, DropBehavior behavior,
|
||||
performDeletion(&object, behavior);
|
||||
}
|
||||
|
||||
/*
|
||||
* RemoveAutomaticRulesOnEvent
|
||||
*
|
||||
* This will delete automatic rules, if any exist, on the event in the
|
||||
* relation.
|
||||
*/
|
||||
void
|
||||
RemoveAutomaticRulesOnEvent(Relation rel, CmdType event_type)
|
||||
{
|
||||
RuleLock *rulelocks = rel->rd_rules;
|
||||
int i;
|
||||
|
||||
/* If there are no rules on the relation, waste no more time. */
|
||||
if (rulelocks == NULL)
|
||||
return;
|
||||
|
||||
/*
|
||||
* Look at all rules looking for the ones that are on the event
|
||||
* and are automatic.
|
||||
*/
|
||||
for (i = 0; i < rulelocks->numLocks; i++)
|
||||
{
|
||||
RewriteRule *oneLock = rulelocks->rules[i];
|
||||
|
||||
if (oneLock->event == event_type && oneLock->is_auto)
|
||||
{
|
||||
RemoveRewriteRuleById(oneLock->ruleId);
|
||||
elog(DEBUG1, "removing automatic rule with OID %u\n",
|
||||
oneLock->ruleId);
|
||||
deleteDependencyRecordsFor(RewriteRelationId, oneLock->ruleId);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
* Guts of rule deletion.
|
||||
|
1401
src/backend/rewrite/viewUpdate.c
Normal file
1401
src/backend/rewrite/viewUpdate.c
Normal file
File diff suppressed because it is too large
Load Diff
5
src/backend/utils/cache/relcache.c
vendored
5
src/backend/utils/cache/relcache.c
vendored
@ -8,7 +8,7 @@
|
||||
*
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/backend/utils/cache/relcache.c,v 1.280 2009/01/01 17:23:50 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/backend/utils/cache/relcache.c,v 1.281 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -662,6 +662,7 @@ RelationBuildRuleLock(Relation relation)
|
||||
rule->attrno = rewrite_form->ev_attr;
|
||||
rule->enabled = rewrite_form->ev_enabled;
|
||||
rule->isInstead = rewrite_form->is_instead;
|
||||
rule->is_auto = rewrite_form->is_auto;
|
||||
|
||||
/*
|
||||
* Must use heap_getattr to fetch ev_action and ev_qual. Also, the
|
||||
@ -785,6 +786,8 @@ equalRuleLocks(RuleLock *rlock1, RuleLock *rlock2)
|
||||
return false;
|
||||
if (!equal(rule1->actions, rule2->actions))
|
||||
return false;
|
||||
if(rule1->is_auto != rule2->is_auto)
|
||||
return false;
|
||||
}
|
||||
}
|
||||
else if (rlock2 != NULL)
|
||||
|
@ -12,7 +12,7 @@
|
||||
* by PostgreSQL
|
||||
*
|
||||
* IDENTIFICATION
|
||||
* $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.c,v 1.514 2009/01/18 20:44:45 tgl Exp $
|
||||
* $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.c,v 1.515 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -4003,7 +4003,17 @@ getRules(int *numRules)
|
||||
/* Make sure we are in proper schema */
|
||||
selectSourceSchema("pg_catalog");
|
||||
|
||||
if (g_fout->remoteVersion >= 80300)
|
||||
if (g_fout->remoteVersion >= 80400)
|
||||
{
|
||||
appendPQExpBuffer(query, "SELECT "
|
||||
"tableoid, oid, rulename, "
|
||||
"ev_class as ruletable, ev_type, is_instead, "
|
||||
"ev_enabled "
|
||||
"FROM pg_rewrite "
|
||||
"WHERE NOT is_auto "
|
||||
"ORDER BY oid");
|
||||
}
|
||||
else if (g_fout->remoteVersion >= 80300)
|
||||
{
|
||||
appendPQExpBuffer(query, "SELECT "
|
||||
"tableoid, oid, rulename, "
|
||||
|
@ -6,7 +6,7 @@
|
||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.h,v 1.147 2009/01/18 20:44:45 tgl Exp $
|
||||
* $PostgreSQL: pgsql/src/bin/pg_dump/pg_dump.h,v 1.148 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -304,7 +304,6 @@ typedef struct _ruleInfo
|
||||
bool is_instead;
|
||||
char ev_enabled;
|
||||
bool separate; /* TRUE if must dump as separate item */
|
||||
/* separate is always true for non-ON SELECT rules */
|
||||
} RuleInfo;
|
||||
|
||||
typedef struct _triggerInfo
|
||||
|
@ -11,7 +11,7 @@
|
||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/include/catalog/pg_rewrite.h,v 1.31 2009/01/01 17:23:58 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/include/catalog/pg_rewrite.h,v 1.32 2009/01/22 17:27:54 petere Exp $
|
||||
*
|
||||
* NOTES
|
||||
* the genbki.sh script reads this file and generates .bki
|
||||
@ -40,6 +40,15 @@ CATALOG(pg_rewrite,2618)
|
||||
char ev_enabled;
|
||||
bool is_instead;
|
||||
|
||||
/*
|
||||
* is_auto: True if the rule was automatically generated (update
|
||||
* rules). This is tracked separately from the dependency system,
|
||||
* because we want to allow overwriting the automatic update
|
||||
* rules. So both automatically and manually generated rules have
|
||||
* dependency type AUTO.
|
||||
*/
|
||||
bool is_auto;
|
||||
|
||||
/* NB: remaining fields must be accessed via heap_getattr */
|
||||
text ev_qual;
|
||||
text ev_action;
|
||||
@ -56,14 +65,15 @@ typedef FormData_pg_rewrite *Form_pg_rewrite;
|
||||
* compiler constants for pg_rewrite
|
||||
* ----------------
|
||||
*/
|
||||
#define Natts_pg_rewrite 8
|
||||
#define Natts_pg_rewrite 9
|
||||
#define Anum_pg_rewrite_rulename 1
|
||||
#define Anum_pg_rewrite_ev_class 2
|
||||
#define Anum_pg_rewrite_ev_attr 3
|
||||
#define Anum_pg_rewrite_ev_type 4
|
||||
#define Anum_pg_rewrite_ev_enabled 5
|
||||
#define Anum_pg_rewrite_is_instead 6
|
||||
#define Anum_pg_rewrite_ev_qual 7
|
||||
#define Anum_pg_rewrite_ev_action 8
|
||||
#define Anum_pg_rewrite_is_auto 7
|
||||
#define Anum_pg_rewrite_ev_qual 8
|
||||
#define Anum_pg_rewrite_ev_action 9
|
||||
|
||||
#endif /* PG_REWRITE_H */
|
||||
|
@ -6,7 +6,7 @@
|
||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/prs2lock.h,v 1.25 2009/01/01 17:24:01 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/prs2lock.h,v 1.26 2009/01/22 17:27:55 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -30,6 +30,7 @@ typedef struct RewriteRule
|
||||
List *actions;
|
||||
char enabled;
|
||||
bool isInstead;
|
||||
bool is_auto;
|
||||
} RewriteRule;
|
||||
|
||||
/*
|
||||
|
@ -7,7 +7,7 @@
|
||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/rewriteDefine.h,v 1.31 2009/01/01 17:24:01 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/rewriteDefine.h,v 1.32 2009/01/22 17:27:55 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -29,6 +29,7 @@ extern void DefineQueryRewrite(char *rulename,
|
||||
Node *event_qual,
|
||||
CmdType event_type,
|
||||
bool is_instead,
|
||||
bool is_auto,
|
||||
bool replace,
|
||||
List *action);
|
||||
|
||||
|
@ -7,7 +7,7 @@
|
||||
* Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/rewriteRemove.h,v 1.25 2009/01/01 17:24:01 momjian Exp $
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/rewriteRemove.h,v 1.26 2009/01/22 17:27:55 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
@ -20,5 +20,6 @@
|
||||
extern void RemoveRewriteRule(Oid owningRel, const char *ruleName,
|
||||
DropBehavior behavior, bool missing_ok);
|
||||
extern void RemoveRewriteRuleById(Oid ruleOid);
|
||||
extern void RemoveAutomaticRulesOnEvent(Relation rel, CmdType event_type);
|
||||
|
||||
#endif /* REWRITEREMOVE_H */
|
||||
|
21
src/include/rewrite/viewUpdate.h
Normal file
21
src/include/rewrite/viewUpdate.h
Normal file
@ -0,0 +1,21 @@
|
||||
|
||||
/*-------------------------------------------------------------------------
|
||||
*
|
||||
* viewUpdate.h
|
||||
*
|
||||
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
|
||||
* Portions Copyright (c) 1994, Regents of the University of California
|
||||
*
|
||||
* $PostgreSQL: pgsql/src/include/rewrite/viewUpdate.h,v 1.1 2009/01/22 17:27:55 petere Exp $
|
||||
*
|
||||
*-------------------------------------------------------------------------
|
||||
*/
|
||||
#ifndef VIEW_UPDATE_H
|
||||
#define VIEW_UPDATE_H
|
||||
|
||||
#include "nodes/parsenodes.h"
|
||||
|
||||
extern void
|
||||
CreateViewUpdateRules(Oid viewOid, const Query *viewDef);
|
||||
|
||||
#endif /* VIEW_UPDATE_H */
|
@ -132,6 +132,7 @@ ALTER INDEX onek_unique1 RENAME TO tmp_onek_unique1;
|
||||
ALTER INDEX tmp_onek_unique1 RENAME TO onek_unique1;
|
||||
-- renaming views
|
||||
CREATE VIEW tmp_view (unique1) AS SELECT unique1 FROM tenk1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
ALTER TABLE tmp_view RENAME TO tmp_view_new;
|
||||
-- hack to ensure we get an indexscan here
|
||||
ANALYZE tenk1;
|
||||
@ -592,6 +593,7 @@ alter table atacc1 alter oid drop not null;
|
||||
ERROR: cannot alter system column "oid"
|
||||
-- try creating a view and altering that, should fail
|
||||
create view myview as select * from atacc1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
alter table myview alter column test drop not null;
|
||||
ERROR: "myview" is not a table
|
||||
alter table myview alter column test set not null;
|
||||
@ -659,6 +661,7 @@ ERROR: column "c3" of relation "def_test" does not exist
|
||||
-- to allow insertions into it, and then alter the view to add
|
||||
-- a default
|
||||
create view def_view_test as select * from def_test;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create rule def_view_test_ins as
|
||||
on insert to def_view_test
|
||||
do instead insert into def_test select new.*;
|
||||
@ -842,6 +845,7 @@ alter table atacc1 drop xmin;
|
||||
ERROR: cannot drop system column "xmin"
|
||||
-- try creating a view and altering that, should fail
|
||||
create view myview as select * from atacc1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
select * from myview;
|
||||
b | c | d
|
||||
---+---+---
|
||||
@ -1436,6 +1440,7 @@ create table alter1.t1(f1 serial primary key, f2 int check (f2 > 0));
|
||||
NOTICE: CREATE TABLE will create implicit sequence "t1_f1_seq" for serial column "t1.f1"
|
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "t1_pkey" for table "t1"
|
||||
create view alter1.v1 as select * from alter1.t1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create function alter1.plus1(int) returns int as 'select $1+1' language sql;
|
||||
create domain alter1.posint integer check (value > 0);
|
||||
create type alter1.ctype as (f1 int, f2 text);
|
||||
|
@ -27,8 +27,10 @@ CREATE TABLE viewtest_tbl (a int, b int);
|
||||
COPY viewtest_tbl FROM stdin;
|
||||
CREATE OR REPLACE VIEW viewtest AS
|
||||
SELECT * FROM viewtest_tbl;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE OR REPLACE VIEW viewtest AS
|
||||
SELECT * FROM viewtest_tbl WHERE a > 10;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT * FROM viewtest;
|
||||
a | b
|
||||
----+----
|
||||
@ -38,6 +40,7 @@ SELECT * FROM viewtest;
|
||||
|
||||
CREATE OR REPLACE VIEW viewtest AS
|
||||
SELECT a, b FROM viewtest_tbl WHERE a > 5 ORDER BY b DESC;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT * FROM viewtest;
|
||||
a | b
|
||||
----+----
|
||||
@ -71,13 +74,17 @@ 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;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- 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
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- should be created in temp object schema
|
||||
CREATE TEMP VIEW v2_temp AS SELECT * FROM base_table;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- should be created in temp_views schema
|
||||
CREATE VIEW temp_view_test.v2 AS SELECT * FROM base_table;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- should fail
|
||||
CREATE VIEW temp_view_test.v3_temp AS SELECT * FROM temp_table;
|
||||
NOTICE: view "v3_temp" will be a temporary view
|
||||
@ -107,18 +114,25 @@ CREATE VIEW v5_temp AS
|
||||
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);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
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);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW v7 AS SELECT * FROM base_table WHERE NOT EXISTS (SELECT 1 FROM base_table2);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW v8 AS SELECT * FROM base_table WHERE EXISTS (SELECT 1);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
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
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
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
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
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
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- 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
|
||||
@ -130,8 +144,10 @@ NOTICE: view "v12_temp" will be a temporary view
|
||||
CREATE SEQUENCE seq1;
|
||||
CREATE TEMPORARY SEQUENCE seq1_temp;
|
||||
CREATE VIEW v9 AS SELECT seq1.is_called FROM seq1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW v13_temp AS SELECT seq1_temp.is_called FROM seq1_temp;
|
||||
NOTICE: view "v13_temp" will be a temporary view
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT relname FROM pg_class
|
||||
WHERE relname LIKE 'v_'
|
||||
AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = 'temp_view_test')
|
||||
@ -219,6 +235,7 @@ CREATE TEMP TABLE tmptbl (i int, j int);
|
||||
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);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT count(*) FROM pg_class where relname = 'pubview'
|
||||
AND relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname = 'testviewschm2');
|
||||
count
|
||||
@ -232,6 +249,7 @@ 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
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT count(*) FROM pg_class where relname LIKE 'mytempview'
|
||||
And relnamespace IN (SELECT OID FROM pg_namespace WHERE nspname LIKE 'pg_temp%');
|
||||
count
|
||||
|
@ -13,6 +13,7 @@ ERROR: view "test_view_exists" does not exist
|
||||
DROP VIEW IF EXISTS test_view_exists;
|
||||
NOTICE: view "test_view_exists" does not exist, skipping
|
||||
CREATE VIEW test_view_exists AS select * from test_exists;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
DROP VIEW IF EXISTS test_view_exists;
|
||||
DROP VIEW test_view_exists;
|
||||
ERROR: view "test_view_exists" does not exist
|
||||
|
@ -79,6 +79,7 @@ EXECUTE prepstmt2(123);
|
||||
-- but should trigger invalidation anyway
|
||||
CREATE TEMP VIEW pcacheview AS
|
||||
SELECT * FROM pcachetest;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
PREPARE vprep AS SELECT * FROM pcacheview;
|
||||
EXECUTE vprep;
|
||||
q1 | q2
|
||||
@ -236,6 +237,9 @@ select cachebug();
|
||||
NOTICE: table "temptable" does not exist, skipping
|
||||
CONTEXT: SQL statement "drop table if exists temptable cascade"
|
||||
PL/pgSQL function "cachebug" line 3 at SQL statement
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CONTEXT: SQL statement "create temp view vv as select * from temptable"
|
||||
PL/pgSQL function "cachebug" line 5 at SQL statement
|
||||
NOTICE: 1
|
||||
NOTICE: 2
|
||||
NOTICE: 3
|
||||
@ -248,6 +252,9 @@ select cachebug();
|
||||
NOTICE: drop cascades to view vv
|
||||
CONTEXT: SQL statement "drop table if exists temptable cascade"
|
||||
PL/pgSQL function "cachebug" line 3 at SQL statement
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CONTEXT: SQL statement "create temp view vv as select * from temptable"
|
||||
PL/pgSQL function "cachebug" line 5 at SQL statement
|
||||
NOTICE: 1
|
||||
NOTICE: 2
|
||||
NOTICE: 3
|
||||
|
@ -1229,6 +1229,7 @@ ROLLBACK;
|
||||
-- WHERE CURRENT OF may someday work with views, but today is not that day.
|
||||
-- For now, just make sure it errors out cleanly.
|
||||
CREATE TEMP VIEW ucview AS SELECT * FROM uctest;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE RULE ucrule AS ON DELETE TO ucview DO INSTEAD
|
||||
DELETE FROM uctest WHERE f1 = OLD.f1;
|
||||
BEGIN;
|
||||
|
@ -189,9 +189,12 @@ DELETE FROM atest3; -- ok
|
||||
-- views
|
||||
SET SESSION AUTHORIZATION regressuser3;
|
||||
CREATE VIEW atestv1 AS SELECT * FROM atest1; -- ok
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
/* The next *should* fail, but it's not implemented that way yet. */
|
||||
CREATE VIEW atestv2 AS SELECT * FROM atest2;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW atestv3 AS SELECT * FROM atest3; -- ok
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT * FROM atestv1; -- ok
|
||||
a | b
|
||||
---+-----
|
||||
@ -219,6 +222,7 @@ SELECT * FROM atestv3; -- ok
|
||||
(0 rows)
|
||||
|
||||
CREATE VIEW atestv4 AS SELECT * FROM atestv3; -- nested view
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT * FROM atestv4; -- ok
|
||||
one | two | three
|
||||
-----+-----+-------
|
||||
|
@ -195,6 +195,7 @@ SELECT * FROM foochild;
|
||||
DROP TABLE foochild;
|
||||
-- Rules and views
|
||||
CREATE TEMP VIEW voo AS SELECT f1, f2 FROM foo;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE RULE voo_i AS ON INSERT TO voo DO INSTEAD
|
||||
INSERT INTO foo VALUES(new.*, 57);
|
||||
INSERT INTO voo VALUES(11,'zit');
|
||||
|
@ -10,6 +10,7 @@ create table rtest_t1 (a int4, b int4);
|
||||
create table rtest_t2 (a int4, b int4);
|
||||
create table rtest_t3 (a int4, b int4);
|
||||
create view rtest_v1 as select * from rtest_t1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create rule rtest_v1_ins as on insert to rtest_v1 do instead
|
||||
insert into rtest_t1 values (new.a, new.b);
|
||||
create rule rtest_v1_upd as on update to rtest_v1 do instead
|
||||
@ -755,9 +756,12 @@ create table rtest_view3 (a int4, b text);
|
||||
create table rtest_view4 (a int4, b text, c int4);
|
||||
create view rtest_vview1 as select a, b from rtest_view1 X
|
||||
where 0 < (select count(*) from rtest_view2 Y where Y.a = X.a);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create view rtest_vview2 as select a, b from rtest_view1 where v;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create view rtest_vview3 as select a, b from rtest_vview2 X
|
||||
where 0 < (select count(*) from rtest_view2 Y where Y.a = X.a);
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create view rtest_vview4 as select X.a, X.b, count(Y.a) as refcount
|
||||
from rtest_view1 X, rtest_view2 Y
|
||||
where X.a = Y.a
|
||||
@ -1333,8 +1337,8 @@ SELECT viewname, definition FROM pg_views WHERE schemaname <> 'information_schem
|
||||
|
||||
SELECT tablename, rulename, definition FROM pg_rules
|
||||
ORDER BY tablename, rulename;
|
||||
tablename | rulename | definition
|
||||
---------------+-----------------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
tablename | rulename | definition
|
||||
---------------+-----------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
pg_settings | pg_settings_n | CREATE RULE pg_settings_n AS ON UPDATE TO pg_settings DO INSTEAD NOTHING;
|
||||
pg_settings | pg_settings_u | CREATE RULE pg_settings_u AS ON UPDATE TO pg_settings WHERE (new.name = old.name) DO SELECT set_config(old.name, new.setting, false) AS set_config;
|
||||
rtest_emp | rtest_emp_del | CREATE RULE rtest_emp_del AS ON DELETE TO rtest_emp DO INSERT INTO rtest_emplog (ename, who, action, newsal, oldsal) VALUES (old.ename, "current_user"(), 'fired'::bpchar, '$0.00'::money, old.salary);
|
||||
@ -1359,12 +1363,21 @@ SELECT tablename, rulename, definition FROM pg_rules
|
||||
rtest_v1 | rtest_v1_del | CREATE RULE rtest_v1_del AS ON DELETE TO rtest_v1 DO INSTEAD DELETE FROM rtest_t1 WHERE (rtest_t1.a = old.a);
|
||||
rtest_v1 | rtest_v1_ins | CREATE RULE rtest_v1_ins AS ON INSERT TO rtest_v1 DO INSTEAD INSERT INTO rtest_t1 (a, b) VALUES (new.a, new.b);
|
||||
rtest_v1 | rtest_v1_upd | CREATE RULE rtest_v1_upd AS ON UPDATE TO rtest_v1 DO INSTEAD UPDATE rtest_t1 SET a = new.a, b = new.b WHERE (rtest_t1.a = old.a);
|
||||
rtest_vview1 | _DELETE | CREATE RULE "_DELETE" AS ON DELETE TO rtest_vview1 DO INSTEAD DELETE FROM rtest_view1 x WHERE ((((old.a IS NULL) AND (x.a IS NULL)) OR (old.a = x.a)) AND (((old.b IS NULL) AND (x.b IS NULL)) OR (old.b = x.b))) RETURNING old.a, old.b;
|
||||
rtest_vview1 | _INSERT | CREATE RULE "_INSERT" AS ON INSERT TO rtest_vview1 DO INSTEAD INSERT INTO rtest_view1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
rtest_vview1 | _UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO rtest_vview1 DO INSTEAD UPDATE rtest_view1 x SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (x.a IS NULL)) OR (old.a = x.a)) AND (((old.b IS NULL) AND (x.b IS NULL)) OR (old.b = x.b))) RETURNING new.a, new.b;
|
||||
rtest_vview2 | _DELETE | CREATE RULE "_DELETE" AS ON DELETE TO rtest_vview2 DO INSTEAD DELETE FROM rtest_view1 WHERE ((((old.a IS NULL) AND (rtest_view1.a IS NULL)) OR (old.a = rtest_view1.a)) AND (((old.b IS NULL) AND (rtest_view1.b IS NULL)) OR (old.b = rtest_view1.b))) RETURNING old.a, old.b;
|
||||
rtest_vview2 | _INSERT | CREATE RULE "_INSERT" AS ON INSERT TO rtest_vview2 DO INSTEAD INSERT INTO rtest_view1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
rtest_vview2 | _UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO rtest_vview2 DO INSTEAD UPDATE rtest_view1 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (rtest_view1.a IS NULL)) OR (old.a = rtest_view1.a)) AND (((old.b IS NULL) AND (rtest_view1.b IS NULL)) OR (old.b = rtest_view1.b))) RETURNING new.a, new.b;
|
||||
rtest_vview3 | _DELETE | CREATE RULE "_DELETE" AS ON DELETE TO rtest_vview3 DO INSTEAD DELETE FROM rtest_vview2 x WHERE ((((old.a IS NULL) AND (x.a IS NULL)) OR (old.a = x.a)) AND (((old.b IS NULL) AND (x.b IS NULL)) OR (old.b = x.b))) RETURNING old.a, old.b;
|
||||
rtest_vview3 | _INSERT | CREATE RULE "_INSERT" AS ON INSERT TO rtest_vview3 DO INSTEAD INSERT INTO rtest_vview2 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
rtest_vview3 | _UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO rtest_vview3 DO INSTEAD UPDATE rtest_vview2 x SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (x.a IS NULL)) OR (old.a = x.a)) AND (((old.b IS NULL) AND (x.b IS NULL)) OR (old.b = x.b))) RETURNING new.a, new.b;
|
||||
shoelace | shoelace_del | CREATE RULE shoelace_del AS ON DELETE TO shoelace DO INSTEAD DELETE FROM shoelace_data WHERE (shoelace_data.sl_name = old.sl_name);
|
||||
shoelace | shoelace_ins | CREATE RULE shoelace_ins AS ON INSERT TO shoelace DO INSTEAD INSERT INTO shoelace_data (sl_name, sl_avail, sl_color, sl_len, sl_unit) VALUES (new.sl_name, new.sl_avail, new.sl_color, new.sl_len, new.sl_unit);
|
||||
shoelace | shoelace_upd | CREATE RULE shoelace_upd AS ON UPDATE TO shoelace DO INSTEAD UPDATE shoelace_data SET sl_name = new.sl_name, sl_avail = new.sl_avail, sl_color = new.sl_color, sl_len = new.sl_len, sl_unit = new.sl_unit WHERE (shoelace_data.sl_name = old.sl_name);
|
||||
shoelace_data | log_shoelace | CREATE RULE log_shoelace AS ON UPDATE TO shoelace_data WHERE (new.sl_avail <> old.sl_avail) DO INSERT INTO shoelace_log (sl_name, sl_avail, log_who, log_when) VALUES (new.sl_name, new.sl_avail, 'Al Bundy'::name, 'Thu Jan 01 00:00:00 1970'::timestamp without time zone);
|
||||
shoelace_ok | shoelace_ok_ins | CREATE RULE shoelace_ok_ins AS ON INSERT TO shoelace_ok DO INSTEAD UPDATE shoelace SET sl_avail = (shoelace.sl_avail + new.ok_quant) WHERE (shoelace.sl_name = new.ok_name);
|
||||
(29 rows)
|
||||
(38 rows)
|
||||
|
||||
--
|
||||
-- CREATE OR REPLACE RULE
|
||||
@ -1466,6 +1479,7 @@ insert into test_2 (name) values ('Test 4');
|
||||
insert into test_3 (name) values ('Test 5');
|
||||
insert into test_3 (name) values ('Test 6');
|
||||
create view id_ordered as select * from id order by id;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create rule update_id_ordered as on update to id_ordered
|
||||
do instead update id set name = new.name where id = old.id;
|
||||
select * from id_ordered;
|
||||
|
@ -349,6 +349,7 @@ create temp table shipped (
|
||||
);
|
||||
create temp view shipped_view as
|
||||
select * from shipped where ttype = 'wt';
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
create rule shipped_view_insert as on insert to shipped_view do instead
|
||||
insert into shipped values('wt', new.ordnum, new.partnum, new.value);
|
||||
insert into parts (partnum, cost) values (1, 1234.56);
|
||||
|
370
src/test/regress/expected/view_update.out
Normal file
370
src/test/regress/expected/view_update.out
Normal file
@ -0,0 +1,370 @@
|
||||
CREATE TABLE vutest1 (a integer, b text);
|
||||
INSERT INTO vutest1 VALUES (1, 'one');
|
||||
INSERT INTO vutest1 VALUES (2, 'two');
|
||||
-- simple view updatability conditions
|
||||
CREATE VIEW vutestv1 AS SELECT a, b FROM vutest1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv2 AS SELECT * FROM vutest1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv3 AS SELECT b, a FROM vutest1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv4 AS SELECT a, b FROM vutest1 WHERE a < 5;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
-- not updatable tests:
|
||||
CREATE VIEW vutestv5 AS SELECT sum(a) FROM vutest1; -- aggregate function
|
||||
CREATE VIEW vutestv6 AS SELECT b FROM vutest1 GROUP BY b; -- GROUP BY
|
||||
CREATE VIEW vutestv7 AS SELECT l.b AS x, r.b AS y FROM vutest1 l, vutest1 r WHERE r.a = l.a; -- JOIN
|
||||
CREATE VIEW vutestv8 AS SELECT 42; -- no table
|
||||
CREATE VIEW vutestv9 AS SELECT a * 2 AS x, b || b AS y FROM vutest1; -- derived columns
|
||||
CREATE VIEW vutestv10 AS SELECT a AS x, a AS y FROM vutest1; -- column referenced more than once
|
||||
CREATE VIEW vutestv11 AS SELECT * FROM generate_series(1, 5); -- table function
|
||||
CREATE VIEW vutestv12 AS SELECT xmin, xmax, a, b FROM vutest1; -- system columns
|
||||
CREATE VIEW vutestv13 AS SELECT DISTINCT a, b FROM vutest1; -- DISTINCT
|
||||
CREATE VIEW vutestv14 AS SELECT a, b FROM vutest1 WHERE a > (SELECT avg(a) FROM vutest1); -- *is* updatable, but SQL standard disallows this
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv15 AS SELECT a, b FROM vutest1 UNION ALL SELECT a, b FROM vutest1; -- UNION
|
||||
CREATE VIEW vutestv16 AS SELECT x, y FROM (SELECT * FROM vutest1) AS foo (x, y); -- subquery ("derived table"); SQL standard allows this
|
||||
CREATE VIEW vutestv17 AS SELECT a, 5, b FROM vutest1; -- constant
|
||||
CREATE VIEW vutestv18 AS SELECT a, b FROM vutest1 LIMIT 1; -- LIMIT
|
||||
CREATE VIEW vutestv19 AS SELECT a, b FROM vutest1 OFFSET 1; -- OFFSET
|
||||
CREATE VIEW vutestv101 AS SELECT a, rank() OVER (PARTITION BY a ORDER BY b DESC) FROM vutest1; -- window function
|
||||
CREATE VIEW vutestv102 AS WITH foo AS (SELECT a, b FROM vutest1) SELECT * FROM foo; -- SQL standard allows this
|
||||
CREATE VIEW vutestv103 AS WITH RECURSIVE t(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM t) SELECT a FROM vutest1; -- recursive
|
||||
INSERT INTO vutestv1 VALUES (3, 'three');
|
||||
INSERT INTO vutestv2 VALUES (4, 'four');
|
||||
INSERT INTO vutestv3 VALUES (5, 'five'); -- fail
|
||||
ERROR: invalid input syntax for integer: "five"
|
||||
LINE 1: INSERT INTO vutestv3 VALUES (5, 'five');
|
||||
^
|
||||
INSERT INTO vutestv3 VALUES ('five', 5);
|
||||
INSERT INTO vutestv3 (a, b) VALUES (6, 'six');
|
||||
INSERT INTO vutestv4 VALUES (7, 'seven'); -- ok, but would be check option issue
|
||||
INSERT INTO vutestv5 VALUES (8); -- fail
|
||||
ERROR: view is not updatable
|
||||
HINT: You need an unconditional ON INSERT DO INSTEAD rule.
|
||||
SELECT * FROM vutest1;
|
||||
a | b
|
||||
---+-------
|
||||
1 | one
|
||||
2 | two
|
||||
3 | three
|
||||
4 | four
|
||||
5 | five
|
||||
6 | six
|
||||
7 | seven
|
||||
(7 rows)
|
||||
|
||||
SELECT * FROM vutestv1;
|
||||
a | b
|
||||
---+-------
|
||||
1 | one
|
||||
2 | two
|
||||
3 | three
|
||||
4 | four
|
||||
5 | five
|
||||
6 | six
|
||||
7 | seven
|
||||
(7 rows)
|
||||
|
||||
SELECT * FROM vutestv2;
|
||||
a | b
|
||||
---+-------
|
||||
1 | one
|
||||
2 | two
|
||||
3 | three
|
||||
4 | four
|
||||
5 | five
|
||||
6 | six
|
||||
7 | seven
|
||||
(7 rows)
|
||||
|
||||
SELECT * FROM vutestv3;
|
||||
b | a
|
||||
-------+---
|
||||
one | 1
|
||||
two | 2
|
||||
three | 3
|
||||
four | 4
|
||||
five | 5
|
||||
six | 6
|
||||
seven | 7
|
||||
(7 rows)
|
||||
|
||||
SELECT * FROM vutestv4;
|
||||
a | b
|
||||
---+-------
|
||||
1 | one
|
||||
2 | two
|
||||
3 | three
|
||||
4 | four
|
||||
(4 rows)
|
||||
|
||||
SELECT * FROM vutestv5;
|
||||
sum
|
||||
-----
|
||||
28
|
||||
(1 row)
|
||||
|
||||
UPDATE vutestv1 SET b = 'a lot' WHERE a = 7;
|
||||
DELETE FROM vutestv2 WHERE a = 1;
|
||||
UPDATE vutestv4 SET b = b || '!' WHERE a > 1;
|
||||
DELETE FROM vutestv4 WHERE a > 3;
|
||||
UPDATE vutestv6 SET b = 37; -- fail
|
||||
ERROR: view is not updatable
|
||||
HINT: You need an unconditional ON UPDATE DO INSTEAD rule.
|
||||
DELETE FROM vutestv5; -- fail
|
||||
ERROR: view is not updatable
|
||||
HINT: You need an unconditional ON DELETE DO INSTEAD rule.
|
||||
SELECT * FROM vutest1 ORDER BY a, b;
|
||||
a | b
|
||||
---+--------
|
||||
2 | two!
|
||||
3 | three!
|
||||
5 | five
|
||||
6 | six
|
||||
7 | a lot
|
||||
(5 rows)
|
||||
|
||||
SELECT * FROM vutestv1 ORDER BY a, b;
|
||||
a | b
|
||||
---+--------
|
||||
2 | two!
|
||||
3 | three!
|
||||
5 | five
|
||||
6 | six
|
||||
7 | a lot
|
||||
(5 rows)
|
||||
|
||||
SELECT * FROM vutestv2 ORDER BY a, b;
|
||||
a | b
|
||||
---+--------
|
||||
2 | two!
|
||||
3 | three!
|
||||
5 | five
|
||||
6 | six
|
||||
7 | a lot
|
||||
(5 rows)
|
||||
|
||||
SELECT * FROM vutestv4 ORDER BY a, b;
|
||||
a | b
|
||||
---+--------
|
||||
2 | two!
|
||||
3 | three!
|
||||
(2 rows)
|
||||
|
||||
TRUNCATE TABLE vutest1;
|
||||
-- views on views
|
||||
CREATE VIEW vutestv20 AS SELECT a AS x, b AS y FROM vutestv1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv21 AS SELECT x AS a FROM vutestv20 WHERE x % 2 = 0;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv22 AS SELECT sum(a) FROM vutestv21; -- not updatable
|
||||
CREATE VIEW vutestv23 AS SELECT * FROM vutestv12; -- not updatable
|
||||
INSERT INTO vutestv20 (x, y) VALUES (1, 'one');
|
||||
INSERT INTO vutestv20 (x, y) VALUES (3, 'three');
|
||||
INSERT INTO vutestv21 VALUES (2);
|
||||
SELECT * FROM vutest1;
|
||||
a | b
|
||||
---+-------
|
||||
1 | one
|
||||
3 | three
|
||||
2 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM vutestv20;
|
||||
x | y
|
||||
---+-------
|
||||
1 | one
|
||||
3 | three
|
||||
2 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM vutestv21;
|
||||
a
|
||||
---
|
||||
2
|
||||
(1 row)
|
||||
|
||||
UPDATE vutestv20 SET y = 'eins' WHERE x = 1;
|
||||
UPDATE vutestv21 SET a = 222;
|
||||
SELECT * FROM vutest1;
|
||||
a | b
|
||||
-----+-------
|
||||
3 | three
|
||||
1 | eins
|
||||
222 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM vutestv20;
|
||||
x | y
|
||||
-----+-------
|
||||
3 | three
|
||||
1 | eins
|
||||
222 |
|
||||
(3 rows)
|
||||
|
||||
SELECT * FROM vutestv21;
|
||||
a
|
||||
-----
|
||||
222
|
||||
(1 row)
|
||||
|
||||
DELETE FROM vutestv20 WHERE x = 3;
|
||||
SELECT * FROM vutest1;
|
||||
a | b
|
||||
-----+------
|
||||
1 | eins
|
||||
222 |
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM vutestv20;
|
||||
x | y
|
||||
-----+------
|
||||
1 | eins
|
||||
222 |
|
||||
(2 rows)
|
||||
|
||||
SELECT * FROM vutestv21;
|
||||
a
|
||||
-----
|
||||
222
|
||||
(1 row)
|
||||
|
||||
-- insert tests
|
||||
CREATE TABLE vutest2 (a int PRIMARY KEY, b text NOT NULL, c text NOT NULL DEFAULT 'foo');
|
||||
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "vutest2_pkey" for table "vutest2"
|
||||
CREATE VIEW vutestv30 AS SELECT a, b, c FROM vutest2;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv31 AS SELECT a, b FROM vutest2;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv32 AS SELECT a, c FROM vutest2;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
INSERT INTO vutestv30 VALUES (1, 'one', 'eins');
|
||||
INSERT INTO vutestv31 VALUES (2, 'two');
|
||||
INSERT INTO vutestv32 VALUES (3, 'drei'); -- fail
|
||||
ERROR: null value in column "b" violates not-null constraint
|
||||
UPDATE vutestv31 SET a = 22 WHERE a = 2;
|
||||
UPDATE vutestv32 SET c = 'drei!' WHERE a = 3;
|
||||
SELECT rulename, definition FROM pg_rules WHERE tablename LIKE 'vutestv%' ORDER BY tablename, rulename;
|
||||
rulename | definition
|
||||
----------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv1 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv1 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv1 DO INSTEAD UPDATE vutest1 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING new.a, new.b;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv14 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv14 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv14 DO INSTEAD UPDATE vutest1 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING new.a, new.b;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv2 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv2 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv2 DO INSTEAD UPDATE vutest1 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING new.a, new.b;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv20 DO INSTEAD DELETE FROM vutestv1 WHERE ((((old.x IS NULL) AND (vutestv1.a IS NULL)) OR (old.x = vutestv1.a)) AND (((old.y IS NULL) AND (vutestv1.b IS NULL)) OR (old.y = vutestv1.b))) RETURNING old.x, old.y;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv20 DO INSTEAD INSERT INTO vutestv1 (a, b) VALUES (new.x, new.y) RETURNING new.x AS a, new.y AS b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv20 DO INSTEAD UPDATE vutestv1 SET a = new.x, b = new.y WHERE ((((old.x IS NULL) AND (vutestv1.a IS NULL)) OR (old.x = vutestv1.a)) AND (((old.y IS NULL) AND (vutestv1.b IS NULL)) OR (old.y = vutestv1.b))) RETURNING new.x AS a, new.y AS b;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv21 DO INSTEAD DELETE FROM vutestv20 WHERE ((((old.a IS NULL) AND (vutestv20.x IS NULL)) OR (old.a = vutestv20.x))) RETURNING old.a;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv21 DO INSTEAD INSERT INTO vutestv20 (x) VALUES (new.a) RETURNING new.a AS x;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv21 DO INSTEAD UPDATE vutestv20 SET x = new.a WHERE ((((old.a IS NULL) AND (vutestv20.x IS NULL)) OR (old.a = vutestv20.x))) RETURNING new.a AS x;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv3 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b)) AND (((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a))) RETURNING old.b, old.a;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv3 DO INSTEAD INSERT INTO vutest1 (b, a) VALUES (new.b, new.a) RETURNING new.a AS b, new.b AS a;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv3 DO INSTEAD UPDATE vutest1 SET b = new.b, a = new.a WHERE ((((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b)) AND (((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a))) RETURNING new.a AS b, new.b AS a;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv30 DO INSTEAD DELETE FROM vutest2 WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.b IS NULL) AND (vutest2.b IS NULL)) OR (old.b = vutest2.b) OR (((old.c IS NULL) AND (vutest2.c IS NULL)) OR (old.c = vutest2.c)))) RETURNING old.a, old.b, old.c;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv30 DO INSTEAD INSERT INTO vutest2 (a, b, c) VALUES (new.a, new.b, new.c) RETURNING new.a, new.b, new.c;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv30 DO INSTEAD UPDATE vutest2 SET a = new.a, b = new.b, c = new.c WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.b IS NULL) AND (vutest2.b IS NULL)) OR (old.b = vutest2.b) OR (((old.c IS NULL) AND (vutest2.c IS NULL)) OR (old.c = vutest2.c)))) RETURNING new.a, new.b, new.c;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv31 DO INSTEAD DELETE FROM vutest2 WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.b IS NULL) AND (vutest2.b IS NULL)) OR (old.b = vutest2.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv31 DO INSTEAD INSERT INTO vutest2 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv31 DO INSTEAD UPDATE vutest2 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.b IS NULL) AND (vutest2.b IS NULL)) OR (old.b = vutest2.b))) RETURNING new.a, new.b;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv32 DO INSTEAD DELETE FROM vutest2 WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.c IS NULL) AND (vutest2.c IS NULL)) OR (old.c = vutest2.c))) RETURNING old.a, old.c;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv32 DO INSTEAD INSERT INTO vutest2 (a, c) VALUES (new.a, new.c) RETURNING new.a, new.c;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv32 DO INSTEAD UPDATE vutest2 SET a = new.a, c = new.c WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.c IS NULL) AND (vutest2.c IS NULL)) OR (old.c = vutest2.c))) RETURNING new.a, new.c;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv4 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv4 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv4 DO INSTEAD UPDATE vutest1 SET a = new.a, b = new.b WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING new.a, new.b;
|
||||
(30 rows)
|
||||
|
||||
-- interaction of manual and automatic rules, view replacement
|
||||
CREATE VIEW vutestv40 AS SELECT a, b FROM vutest1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv40 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE RULE "_INSERT" AS ON INSERT TO vutestv40 DO INSTEAD DELETE FROM vutest1; -- replaces automatic _INSERT rule
|
||||
CREATE RULE zmy_delete AS ON DELETE TO vutestv40 DO ALSO DELETE FROM vutest1; -- leaves automatic _DELETE rule (because of ALSO)
|
||||
CREATE VIEW vutestv41 AS SELECT a + 1 AS aa, b FROM vutest1; -- not updatable
|
||||
CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv41 DO INSTEAD UPDATE vutest1 SET a = new.aa - 1, b = new.b WHERE a = old.aa - 1 AND b = old.b;
|
||||
CREATE OR REPLACE VIEW vutestv41 AS SELECT a AS aa, b FROM vutest1; -- *now* updatable, manual _UPDATE rule stays
|
||||
WARNING: automatic UPDATE rule not created because manually created UPDATE rule exists
|
||||
HINT: If you prefer to have the automatic rule, drop the manually created rule and run CREATE OR REPLACE VIEW again.
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv42 AS SELECT a + 1 AS aa, b FROM vutest1; -- not updatable
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv42 DO INSTEAD UPDATE vutest1 SET a = new.aa - 1, b = new.b WHERE a = old.aa - 1 AND b = old.b;
|
||||
CREATE OR REPLACE VIEW vutestv42 AS SELECT a AS aa, b FROM vutest1; -- *now* updatable, zmy_update stays, no _UPDATE created
|
||||
WARNING: automatic UPDATE rule not created because manually created UPDATE rule exists
|
||||
HINT: If you prefer to have the automatic rule, drop the manually created rule and run CREATE OR REPLACE VIEW again.
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE VIEW vutestv43 AS SELECT a AS aa, b FROM vutest1; -- updatable
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv43 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE OR REPLACE VIEW vutestv43 AS SELECT a + 1 AS aa, b FROM vutest1; -- no longer updatable, automatic rules are deleted, manual rules kept
|
||||
CREATE VIEW vutestv44 AS SELECT a, b FROM vutest1; -- updatable
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv44 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE OR REPLACE VIEW vutestv44 AS SELECT a, b FROM vutest2; -- automatic update rules are updated, manual rules kept
|
||||
WARNING: automatic UPDATE rule not created because manually created UPDATE rule exists
|
||||
HINT: If you prefer to have the automatic rule, drop the manually created rule and run CREATE OR REPLACE VIEW again.
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
SELECT rulename, definition FROM pg_rules WHERE tablename LIKE 'vutestv4_' ORDER BY tablename, rulename;
|
||||
rulename | definition
|
||||
------------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv40 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.a IS NULL) AND (vutest1.a IS NULL)) OR (old.a = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv40 DO INSTEAD DELETE FROM vutest1;
|
||||
zmy_delete | CREATE RULE zmy_delete AS ON DELETE TO vutestv40 DO DELETE FROM vutest1;
|
||||
zmy_update | CREATE RULE zmy_update AS ON UPDATE TO vutestv40 DO INSTEAD DELETE FROM vutest1;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv41 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.aa IS NULL) AND (vutest1.a IS NULL)) OR (old.aa = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.aa, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv41 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.aa, new.b) RETURNING new.aa AS a, new.b;
|
||||
_UPDATE | CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv41 DO INSTEAD UPDATE vutest1 SET a = (new.aa - 1), b = new.b WHERE ((vutest1.a = (old.aa - 1)) AND (vutest1.b = old.b));
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv42 DO INSTEAD DELETE FROM vutest1 WHERE ((((old.aa IS NULL) AND (vutest1.a IS NULL)) OR (old.aa = vutest1.a)) AND (((old.b IS NULL) AND (vutest1.b IS NULL)) OR (old.b = vutest1.b))) RETURNING old.aa, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv42 DO INSTEAD INSERT INTO vutest1 (a, b) VALUES (new.aa, new.b) RETURNING new.aa AS a, new.b;
|
||||
zmy_update | CREATE RULE zmy_update AS ON UPDATE TO vutestv42 DO INSTEAD UPDATE vutest1 SET a = (new.aa - 1), b = new.b WHERE ((vutest1.a = (old.aa - 1)) AND (vutest1.b = old.b));
|
||||
zmy_update | CREATE RULE zmy_update AS ON UPDATE TO vutestv43 DO INSTEAD DELETE FROM vutest1;
|
||||
_DELETE | CREATE RULE "_DELETE" AS ON DELETE TO vutestv44 DO INSTEAD DELETE FROM vutest2 WHERE ((((old.a IS NULL) AND (vutest2.a IS NULL)) OR (old.a = vutest2.a)) AND (((old.b IS NULL) AND (vutest2.b IS NULL)) OR (old.b = vutest2.b))) RETURNING old.a, old.b;
|
||||
_INSERT | CREATE RULE "_INSERT" AS ON INSERT TO vutestv44 DO INSTEAD INSERT INTO vutest2 (a, b) VALUES (new.a, new.b) RETURNING new.a, new.b;
|
||||
zmy_update | CREATE RULE zmy_update AS ON UPDATE TO vutestv44 DO INSTEAD DELETE FROM vutest1;
|
||||
(14 rows)
|
||||
|
||||
-- ACL
|
||||
CREATE USER regressuser1;
|
||||
CREATE USER regressuser2;
|
||||
GRANT SELECT, INSERT, UPDATE ON vutest1 TO regressuser1;
|
||||
SET ROLE regressuser1;
|
||||
CREATE VIEW vutestv50 AS SELECT a, b FROM vutest1;
|
||||
NOTICE: CREATE VIEW has created automatic view update rules
|
||||
GRANT SELECT, UPDATE, DELETE ON vutestv50 TO regressuser2;
|
||||
SELECT * FROM vutestv50;
|
||||
a | b
|
||||
-----+------
|
||||
1 | eins
|
||||
222 |
|
||||
(2 rows)
|
||||
|
||||
INSERT INTO vutestv50 VALUES (0, 'zero');
|
||||
UPDATE vutestv50 SET a = 1;
|
||||
UPDATE vutestv50 SET a = 2 WHERE a = 1;
|
||||
DELETE FROM vutestv50; -- ERROR
|
||||
ERROR: permission denied for relation vutest1
|
||||
RESET ROLE;
|
||||
SET ROLE regressuser2;
|
||||
SELECT * FROM vutestv50;
|
||||
a | b
|
||||
---+------
|
||||
2 | eins
|
||||
2 |
|
||||
2 | zero
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO vutestv50 VALUES (0, 'zero'); -- ERROR
|
||||
ERROR: permission denied for relation vutestv50
|
||||
UPDATE vutestv50 SET a = 1;
|
||||
UPDATE vutestv50 SET a = 2 WHERE a = 1;
|
||||
DELETE FROM vutestv50; -- ERROR on vutest1
|
||||
ERROR: permission denied for relation vutest1
|
||||
RESET ROLE;
|
||||
DROP VIEW vutestv50;
|
||||
REVOKE ALL PRIVILEGES ON vutest1 FROM regressuser1;
|
||||
DROP USER regressuser1, regressuser2;
|
@ -1,5 +1,5 @@
|
||||
# ----------
|
||||
# $PostgreSQL: pgsql/src/test/regress/parallel_schedule,v 1.53 2008/12/30 17:11:26 tgl Exp $
|
||||
# $PostgreSQL: pgsql/src/test/regress/parallel_schedule,v 1.54 2009/01/22 17:27:55 petere Exp $
|
||||
#
|
||||
# By convention, we put no more than twenty tests in any one parallel group;
|
||||
# this limits the number of connections needed to run the tests.
|
||||
@ -79,6 +79,8 @@ test: misc
|
||||
# ----------
|
||||
test: select_views portals_p2 rules foreign_key cluster dependency guc bitmapops combocid tsearch tsdicts foreign_data window
|
||||
|
||||
test: view_update
|
||||
|
||||
# ----------
|
||||
# Another group of parallel tests
|
||||
# NB: temp.sql does a reconnect which transiently uses 2 connections,
|
||||
|
@ -1,4 +1,4 @@
|
||||
# $PostgreSQL: pgsql/src/test/regress/serial_schedule,v 1.50 2008/12/30 17:11:26 tgl Exp $
|
||||
# $PostgreSQL: pgsql/src/test/regress/serial_schedule,v 1.51 2009/01/22 17:27:55 petere Exp $
|
||||
# This should probably be in an order similar to parallel_schedule.
|
||||
test: boolean
|
||||
test: char
|
||||
@ -100,6 +100,7 @@ test: tsearch
|
||||
test: tsdicts
|
||||
test: foreign_data
|
||||
test: window
|
||||
test: view_update
|
||||
test: plancache
|
||||
test: limit
|
||||
test: plpgsql
|
||||
|
168
src/test/regress/sql/view_update.sql
Normal file
168
src/test/regress/sql/view_update.sql
Normal file
@ -0,0 +1,168 @@
|
||||
CREATE TABLE vutest1 (a integer, b text);
|
||||
INSERT INTO vutest1 VALUES (1, 'one');
|
||||
INSERT INTO vutest1 VALUES (2, 'two');
|
||||
|
||||
|
||||
-- simple view updatability conditions
|
||||
|
||||
CREATE VIEW vutestv1 AS SELECT a, b FROM vutest1;
|
||||
CREATE VIEW vutestv2 AS SELECT * FROM vutest1;
|
||||
CREATE VIEW vutestv3 AS SELECT b, a FROM vutest1;
|
||||
CREATE VIEW vutestv4 AS SELECT a, b FROM vutest1 WHERE a < 5;
|
||||
|
||||
-- not updatable tests:
|
||||
CREATE VIEW vutestv5 AS SELECT sum(a) FROM vutest1; -- aggregate function
|
||||
CREATE VIEW vutestv6 AS SELECT b FROM vutest1 GROUP BY b; -- GROUP BY
|
||||
CREATE VIEW vutestv7 AS SELECT l.b AS x, r.b AS y FROM vutest1 l, vutest1 r WHERE r.a = l.a; -- JOIN
|
||||
CREATE VIEW vutestv8 AS SELECT 42; -- no table
|
||||
CREATE VIEW vutestv9 AS SELECT a * 2 AS x, b || b AS y FROM vutest1; -- derived columns
|
||||
CREATE VIEW vutestv10 AS SELECT a AS x, a AS y FROM vutest1; -- column referenced more than once
|
||||
CREATE VIEW vutestv11 AS SELECT * FROM generate_series(1, 5); -- table function
|
||||
CREATE VIEW vutestv12 AS SELECT xmin, xmax, a, b FROM vutest1; -- system columns
|
||||
CREATE VIEW vutestv13 AS SELECT DISTINCT a, b FROM vutest1; -- DISTINCT
|
||||
CREATE VIEW vutestv14 AS SELECT a, b FROM vutest1 WHERE a > (SELECT avg(a) FROM vutest1); -- *is* updatable, but SQL standard disallows this
|
||||
CREATE VIEW vutestv15 AS SELECT a, b FROM vutest1 UNION ALL SELECT a, b FROM vutest1; -- UNION
|
||||
CREATE VIEW vutestv16 AS SELECT x, y FROM (SELECT * FROM vutest1) AS foo (x, y); -- subquery ("derived table"); SQL standard allows this
|
||||
CREATE VIEW vutestv17 AS SELECT a, 5, b FROM vutest1; -- constant
|
||||
CREATE VIEW vutestv18 AS SELECT a, b FROM vutest1 LIMIT 1; -- LIMIT
|
||||
CREATE VIEW vutestv19 AS SELECT a, b FROM vutest1 OFFSET 1; -- OFFSET
|
||||
CREATE VIEW vutestv101 AS SELECT a, rank() OVER (PARTITION BY a ORDER BY b DESC) FROM vutest1; -- window function
|
||||
CREATE VIEW vutestv102 AS WITH foo AS (SELECT a, b FROM vutest1) SELECT * FROM foo; -- SQL standard allows this
|
||||
CREATE VIEW vutestv103 AS WITH RECURSIVE t(n) AS (SELECT 1 UNION ALL SELECT n+1 FROM t) SELECT a FROM vutest1; -- recursive
|
||||
|
||||
INSERT INTO vutestv1 VALUES (3, 'three');
|
||||
INSERT INTO vutestv2 VALUES (4, 'four');
|
||||
INSERT INTO vutestv3 VALUES (5, 'five'); -- fail
|
||||
INSERT INTO vutestv3 VALUES ('five', 5);
|
||||
INSERT INTO vutestv3 (a, b) VALUES (6, 'six');
|
||||
INSERT INTO vutestv4 VALUES (7, 'seven'); -- ok, but would be check option issue
|
||||
INSERT INTO vutestv5 VALUES (8); -- fail
|
||||
|
||||
SELECT * FROM vutest1;
|
||||
SELECT * FROM vutestv1;
|
||||
SELECT * FROM vutestv2;
|
||||
SELECT * FROM vutestv3;
|
||||
SELECT * FROM vutestv4;
|
||||
SELECT * FROM vutestv5;
|
||||
|
||||
UPDATE vutestv1 SET b = 'a lot' WHERE a = 7;
|
||||
DELETE FROM vutestv2 WHERE a = 1;
|
||||
UPDATE vutestv4 SET b = b || '!' WHERE a > 1;
|
||||
DELETE FROM vutestv4 WHERE a > 3;
|
||||
UPDATE vutestv6 SET b = 37; -- fail
|
||||
DELETE FROM vutestv5; -- fail
|
||||
|
||||
SELECT * FROM vutest1 ORDER BY a, b;
|
||||
SELECT * FROM vutestv1 ORDER BY a, b;
|
||||
SELECT * FROM vutestv2 ORDER BY a, b;
|
||||
SELECT * FROM vutestv4 ORDER BY a, b;
|
||||
|
||||
TRUNCATE TABLE vutest1;
|
||||
|
||||
|
||||
-- views on views
|
||||
|
||||
CREATE VIEW vutestv20 AS SELECT a AS x, b AS y FROM vutestv1;
|
||||
CREATE VIEW vutestv21 AS SELECT x AS a FROM vutestv20 WHERE x % 2 = 0;
|
||||
CREATE VIEW vutestv22 AS SELECT sum(a) FROM vutestv21; -- not updatable
|
||||
CREATE VIEW vutestv23 AS SELECT * FROM vutestv12; -- not updatable
|
||||
|
||||
INSERT INTO vutestv20 (x, y) VALUES (1, 'one');
|
||||
INSERT INTO vutestv20 (x, y) VALUES (3, 'three');
|
||||
INSERT INTO vutestv21 VALUES (2);
|
||||
|
||||
SELECT * FROM vutest1;
|
||||
SELECT * FROM vutestv20;
|
||||
SELECT * FROM vutestv21;
|
||||
|
||||
UPDATE vutestv20 SET y = 'eins' WHERE x = 1;
|
||||
UPDATE vutestv21 SET a = 222;
|
||||
|
||||
SELECT * FROM vutest1;
|
||||
SELECT * FROM vutestv20;
|
||||
SELECT * FROM vutestv21;
|
||||
|
||||
DELETE FROM vutestv20 WHERE x = 3;
|
||||
|
||||
SELECT * FROM vutest1;
|
||||
SELECT * FROM vutestv20;
|
||||
SELECT * FROM vutestv21;
|
||||
|
||||
|
||||
-- insert tests
|
||||
|
||||
CREATE TABLE vutest2 (a int PRIMARY KEY, b text NOT NULL, c text NOT NULL DEFAULT 'foo');
|
||||
|
||||
CREATE VIEW vutestv30 AS SELECT a, b, c FROM vutest2;
|
||||
CREATE VIEW vutestv31 AS SELECT a, b FROM vutest2;
|
||||
CREATE VIEW vutestv32 AS SELECT a, c FROM vutest2;
|
||||
|
||||
INSERT INTO vutestv30 VALUES (1, 'one', 'eins');
|
||||
INSERT INTO vutestv31 VALUES (2, 'two');
|
||||
INSERT INTO vutestv32 VALUES (3, 'drei'); -- fail
|
||||
|
||||
UPDATE vutestv31 SET a = 22 WHERE a = 2;
|
||||
UPDATE vutestv32 SET c = 'drei!' WHERE a = 3;
|
||||
|
||||
|
||||
SELECT rulename, definition FROM pg_rules WHERE tablename LIKE 'vutestv%' ORDER BY tablename, rulename;
|
||||
|
||||
|
||||
-- interaction of manual and automatic rules, view replacement
|
||||
|
||||
CREATE VIEW vutestv40 AS SELECT a, b FROM vutest1;
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv40 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE RULE "_INSERT" AS ON INSERT TO vutestv40 DO INSTEAD DELETE FROM vutest1; -- replaces automatic _INSERT rule
|
||||
CREATE RULE zmy_delete AS ON DELETE TO vutestv40 DO ALSO DELETE FROM vutest1; -- leaves automatic _DELETE rule (because of ALSO)
|
||||
|
||||
CREATE VIEW vutestv41 AS SELECT a + 1 AS aa, b FROM vutest1; -- not updatable
|
||||
CREATE RULE "_UPDATE" AS ON UPDATE TO vutestv41 DO INSTEAD UPDATE vutest1 SET a = new.aa - 1, b = new.b WHERE a = old.aa - 1 AND b = old.b;
|
||||
CREATE OR REPLACE VIEW vutestv41 AS SELECT a AS aa, b FROM vutest1; -- *now* updatable, manual _UPDATE rule stays
|
||||
|
||||
CREATE VIEW vutestv42 AS SELECT a + 1 AS aa, b FROM vutest1; -- not updatable
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv42 DO INSTEAD UPDATE vutest1 SET a = new.aa - 1, b = new.b WHERE a = old.aa - 1 AND b = old.b;
|
||||
CREATE OR REPLACE VIEW vutestv42 AS SELECT a AS aa, b FROM vutest1; -- *now* updatable, zmy_update stays, no _UPDATE created
|
||||
|
||||
CREATE VIEW vutestv43 AS SELECT a AS aa, b FROM vutest1; -- updatable
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv43 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE OR REPLACE VIEW vutestv43 AS SELECT a + 1 AS aa, b FROM vutest1; -- no longer updatable, automatic rules are deleted, manual rules kept
|
||||
|
||||
CREATE VIEW vutestv44 AS SELECT a, b FROM vutest1; -- updatable
|
||||
CREATE RULE zmy_update AS ON UPDATE TO vutestv44 DO INSTEAD DELETE FROM vutest1; -- drops automatic _UPDATE rule
|
||||
CREATE OR REPLACE VIEW vutestv44 AS SELECT a, b FROM vutest2; -- automatic update rules are updated, manual rules kept
|
||||
|
||||
|
||||
SELECT rulename, definition FROM pg_rules WHERE tablename LIKE 'vutestv4_' ORDER BY tablename, rulename;
|
||||
|
||||
|
||||
-- ACL
|
||||
|
||||
CREATE USER regressuser1;
|
||||
CREATE USER regressuser2;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE ON vutest1 TO regressuser1;
|
||||
|
||||
SET ROLE regressuser1;
|
||||
CREATE VIEW vutestv50 AS SELECT a, b FROM vutest1;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON vutestv50 TO regressuser2;
|
||||
|
||||
SELECT * FROM vutestv50;
|
||||
INSERT INTO vutestv50 VALUES (0, 'zero');
|
||||
UPDATE vutestv50 SET a = 1;
|
||||
UPDATE vutestv50 SET a = 2 WHERE a = 1;
|
||||
DELETE FROM vutestv50; -- ERROR
|
||||
RESET ROLE;
|
||||
|
||||
SET ROLE regressuser2;
|
||||
SELECT * FROM vutestv50;
|
||||
INSERT INTO vutestv50 VALUES (0, 'zero'); -- ERROR
|
||||
UPDATE vutestv50 SET a = 1;
|
||||
UPDATE vutestv50 SET a = 2 WHERE a = 1;
|
||||
DELETE FROM vutestv50; -- ERROR on vutest1
|
||||
RESET ROLE;
|
||||
|
||||
DROP VIEW vutestv50;
|
||||
|
||||
REVOKE ALL PRIVILEGES ON vutest1 FROM regressuser1;
|
||||
DROP USER regressuser1, regressuser2;
|
Loading…
Reference in New Issue
Block a user