From a99c42f291421572aef2b0a9360294c7d89b8bc7 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Sat, 8 Dec 2012 18:25:48 -0500 Subject: [PATCH] Support automatically-updatable views. This patch makes "simple" views automatically updatable, without the need to create either INSTEAD OF triggers or INSTEAD rules. "Simple" views are those classified as updatable according to SQL-92 rules. The rewriter transforms INSERT/UPDATE/DELETE commands on such views directly into an equivalent command on the underlying table, which will generally have noticeably better performance than is possible with either triggers or user-written rules. A view that has INSTEAD OF triggers or INSTEAD rules continues to operate the same as before. For the moment, security_barrier views are not considered simple. Also, we do not support WITH CHECK OPTION. These features may be added in future. Dean Rasheed, reviewed by Amit Kapila --- doc/src/sgml/intro.sgml | 2 +- doc/src/sgml/ref/alter_table.sgml | 8 +- doc/src/sgml/ref/alter_view.sgml | 9 +- doc/src/sgml/ref/create_rule.sgml | 25 +- doc/src/sgml/ref/create_view.sgml | 125 +- doc/src/sgml/rules.sgml | 47 +- src/backend/catalog/information_schema.sql | 18 +- src/backend/executor/execMain.c | 20 +- src/backend/rewrite/rewriteHandler.c | 684 ++++++++++- src/backend/utils/adt/misc.c | 31 + src/include/catalog/catversion.h | 2 +- src/include/catalog/pg_proc.h | 5 + src/include/rewrite/rewriteHandler.h | 2 + src/include/utils/builtins.h | 2 + src/test/regress/expected/triggers.out | 14 - src/test/regress/expected/updatable_views.out | 1069 +++++++++++++++++ src/test/regress/parallel_schedule | 2 +- src/test/regress/serial_schedule | 1 + src/test/regress/sql/triggers.sql | 7 - src/test/regress/sql/updatable_views.sql | 511 ++++++++ 20 files changed, 2491 insertions(+), 93 deletions(-) create mode 100644 src/test/regress/expected/updatable_views.out create mode 100644 src/test/regress/sql/updatable_views.sql diff --git a/doc/src/sgml/intro.sgml b/doc/src/sgml/intro.sgml index 4d3f93f317415..f0dba6f56fb48 100644 --- a/doc/src/sgml/intro.sgml +++ b/doc/src/sgml/intro.sgml @@ -110,7 +110,7 @@ triggers - views + updatable views transactional integrity diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml index 356419e2d08d1..5437626c3fe0e 100644 --- a/doc/src/sgml/ref/alter_table.sgml +++ b/doc/src/sgml/ref/alter_table.sgml @@ -147,11 +147,9 @@ ALTER TABLE [ IF EXISTS ] name These forms set or remove the default value for a column. - The default values only apply to subsequent INSERT - commands; they do not cause rows already in the table to change. - Defaults can also be created for views, in which case they are - inserted into INSERT statements on the view before - the view's ON INSERT rule is applied. + Default values only apply in subsequent INSERT + or UPDATE commands; they do not cause rows already in the + table to change. diff --git a/doc/src/sgml/ref/alter_view.sgml b/doc/src/sgml/ref/alter_view.sgml index 521f05b84a1c9..0e2b140241e3a 100644 --- a/doc/src/sgml/ref/alter_view.sgml +++ b/doc/src/sgml/ref/alter_view.sgml @@ -80,10 +80,11 @@ ALTER VIEW [ IF EXISTS ] name RESET These forms set or remove the default value for a column. - A default value associated with a view column is - inserted into INSERT statements on the view before - the view's ON INSERT rule is applied, if - the INSERT does not specify a value for the column. + A view column's default value is substituted into any + INSERT or UPDATE command whose target is the + view, before applying any rules or triggers for the view. The view's + default will therefore take precedence over any default values from + underlying relations. diff --git a/doc/src/sgml/ref/create_rule.sgml b/doc/src/sgml/ref/create_rule.sgml index d4c3392129035..381ea3ed6b4d2 100644 --- a/doc/src/sgml/ref/create_rule.sgml +++ b/doc/src/sgml/ref/create_rule.sgml @@ -45,10 +45,10 @@ CREATE [ OR REPLACE ] RULE name AS additional commands to be executed when a given command on a given table is executed. Alternatively, an INSTEAD rule can replace a given command by another, or cause a command - not to be executed at all. Rules are used to implement table + not to be executed at all. Rules are used to implement SQL views as well. It is important to realize that a rule is really a command transformation mechanism, or command macro. The - transformation happens before the execution of the commands starts. + transformation happens before the execution of the command starts. If you actually want an operation that fires independently for each physical row, you probably want to use a trigger, not a rule. More information about the rules system is in . @@ -73,13 +73,11 @@ CREATE [ OR REPLACE ] RULE name AS sufficient for your purposes) to replace update actions on the view with appropriate updates on other tables. If you want to support INSERT RETURNING and so on, then be sure to put a suitable - RETURNING clause into each of these rules. Alternatively, - an updatable view can be implemented using INSTEAD OF - triggers (see ). + RETURNING clause into each of these rules. - There is a catch if you try to use conditional rules for view + There is a catch if you try to use conditional rules for complex view updates: there must be an unconditional INSTEAD rule for each action you wish to allow on the view. If the rule is conditional, or is not @@ -95,6 +93,21 @@ CREATE [ OR REPLACE ] RULE name AS INSTEAD NOTHING action. (This method does not currently work to support RETURNING queries, however.) + + + + A view that is simple enough to be automatically updatable (see ) does not require a user-created rule in + order to be updatable. While you can create an explicit rule anyway, + the automatic update transformation will generally outperform an + explicit rule. + + + + Another alternative worth considering is to use INSTEAD OF + triggers (see ) in place of rules. + + diff --git a/doc/src/sgml/ref/create_view.sgml b/doc/src/sgml/ref/create_view.sgml index 9e3bc2954f2de..abbde94772c8d 100644 --- a/doc/src/sgml/ref/create_view.sgml +++ b/doc/src/sgml/ref/create_view.sgml @@ -127,17 +127,6 @@ CREATE [ OR REPLACE ] [ TEMP | TEMPORARY ] VIEW n Notes - - 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 INSTEAD triggers on the view, which - must convert attempted inserts, etc. on the view into - appropriate actions on other tables. For more information see - . Another possibility is to create - rules (see ), but in practice triggers - are easier to understand and use correctly. - - Use the statement to drop views. @@ -175,6 +164,105 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello; to replace it (this includes being a member of the owning role). + + Updatable Views + + + updatable views + + + + Simple views are automatically updatable: the system will allow + INSERT, UPDATE and DELETE statements + to be used on the view in the same way as on a regular table. A view is + automatically updatable if it satisfies all of the following conditions: + + + + + The view must have exactly one entry in its FROM list, + which must be a table or another updatable view. + + + + + + The view definition must not contain WITH, + DISTINCT, GROUP BY, HAVING, + LIMIT, or OFFSET clauses at the top level. + + + + + + The view definition must not contain set operations (UNION, + INTERSECT or EXCEPT) at the top level. + + + + + + All columns in the view's select list must be simple references to + columns of the underlying relation. They cannot be expressions, + literals or functions. System columns cannot be referenced, either. + + + + + + No column of the underlying relation can appear more than once in + the view's select list. + + + + + + The view must not have the security_barrier property. + + + + + + + If the view is automatically updatable the system will convert any + INSERT, UPDATE or DELETE statement + on the view into the corresponding statement on the underlying base + relation. + + + + If an automatically updatable view contains a WHERE + condition, the condition restricts which rows of the base relation are + available to be modified by UPDATE and DELETE + statements on the view. However, an UPDATE is allowed to + change a row so that it no longer satisfies the WHERE + condition, and thus is no longer visible through the view. Similarly, + an INSERT command can potentially insert base-relation rows + that do not satisfy the WHERE condition and thus are not + visible through the view. + + + + A more complex view that does not satisfy all these conditions is + read-only by default: the system will not allow an insert, update, or + delete on the view. You can get the effect of an updatable view by + creating INSTEAD OF triggers on the view, which must + convert attempted inserts, etc. on the view into appropriate actions + on other tables. For more information see . Another possibility is to create rules + (see ), but in practice triggers are + easier to understand and use correctly. + + + + Note that the user performing the insert, update or delete on the view + must have the corresponding insert, update or delete privilege on the + view. In addition the view's owner must have the relevant privileges on + the underlying base relations, but the user performing the update does + not need any permissions on the underlying base relations (see + ). + + @@ -217,11 +305,15 @@ CREATE VIEW name [ ( CHECK OPTION - This option has to do with updatable views. All - INSERT and UPDATE commands on the view - will be checked to ensure data satisfy the view-defining - condition (that is, the new data would be visible through the - view). If they do not, the update will be rejected. + This option controls the behavior of automatically updatable views. + When given, INSERT and UPDATE commands on + the view will be checked to ensure new rows satisfy the + view-defining condition (that is, the new rows would be visible + through the view). If they do not, the update will be rejected. + Without CHECK OPTION, INSERT and + UPDATE commands on the view are allowed to create rows + that are not visible through the view. (The latter behavior is the + only one currently provided by PostgreSQL.) @@ -252,6 +344,7 @@ CREATE VIEW name [ ( CREATE OR REPLACE VIEW is a PostgreSQL language extension. So is the concept of a temporary view. + The WITH clause is an extension as well. diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml index cc02ada7c715c..5811de7942f6a 100644 --- a/doc/src/sgml/rules.sgml +++ b/doc/src/sgml/rules.sgml @@ -808,13 +808,28 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; What happens if a view is named as the target relation for an INSERT, UPDATE, or - DELETE? Simply doing the substitutions + DELETE? Doing the substitutions described above would give a query tree in which the result relation points at a subquery range-table entry, which will not - work. Instead, the rewriter assumes that the operation will be - handled by an INSTEAD OF trigger on the view. - (If there is no such trigger, the executor will throw an error - when execution starts.) Rewriting works slightly differently + work. There are several ways in which PostgreSQL + can support the appearance of updating a view, however. + + + + If the subquery selects from a single base relation and is simple + enough, the rewriter can automatically replace the subquery with the + underlying base relation so that the INSERT, + UPDATE, or DELETE is applied to + the base relation in the appropriate way. Views that are + simple enough for this are called automatically + updatable. For detailed information on the kinds of view that can + be automatically updated, see . + + + + Alternatively, the operation may be handled by a user-provided + INSTEAD OF trigger on the view. + Rewriting works slightly differently in this case. For INSERT, the rewriter does nothing at all with the view, leaving it as the result relation for the query. For UPDATE and @@ -842,10 +857,8 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; - If there are no INSTEAD OF triggers to update the view, - the executor will throw an error, because it cannot automatically - update a view by itself. To change this, we can define rules that - modify the behavior of INSERT, + Another possibility is for the user to define INSTEAD + rules that specify substitute actions for INSERT, UPDATE, and DELETE commands on a view. These rules will rewrite the command, typically into a command that updates one or more tables, rather than views. That is the topic @@ -860,6 +873,22 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a; evaluated first, and depending on the result, the triggers may not be used at all. + + + Automatic rewriting of an INSERT, + UPDATE, or DELETE query on a + simple view is always tried last. Therefore, if a view has rules or + triggers, they will override the default behavior of automatically + updatable views. + + + + If there are no INSTEAD rules or INSTEAD OF + triggers for the view, and the rewriter cannot automatically rewrite + the query as an update on the underlying base relation, an error will + be thrown because the executor cannot update a view as such. + + diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql index 4bd942fb6d5c5..fcac07ae485a9 100644 --- a/src/backend/catalog/information_schema.sql +++ b/src/backend/catalog/information_schema.sql @@ -730,10 +730,8 @@ CREATE VIEW columns AS CAST('NEVER' AS character_data) AS is_generated, CAST(null AS character_data) AS generation_expression, - CAST(CASE WHEN c.relkind = 'r' - OR (c.relkind = 'v' - AND EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '2' AND is_instead) - AND EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '4' AND is_instead)) + CAST(CASE WHEN c.relkind = 'r' OR + (c.relkind = 'v' AND pg_view_is_updatable(c.oid)) THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_updatable FROM (pg_attribute a LEFT JOIN pg_attrdef ad ON attrelid = adrelid AND attnum = adnum) @@ -1896,9 +1894,8 @@ CREATE VIEW tables AS CAST(nt.nspname AS sql_identifier) AS user_defined_type_schema, CAST(t.typname AS sql_identifier) AS user_defined_type_name, - CAST(CASE WHEN c.relkind = 'r' - OR (c.relkind = 'v' - AND EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '3' AND is_instead)) + CAST(CASE WHEN c.relkind = 'r' OR + (c.relkind = 'v' AND pg_view_is_insertable(c.oid)) THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_insertable_into, CAST(CASE WHEN t.typname IS NOT NULL THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_typed, @@ -2497,14 +2494,11 @@ CREATE VIEW views AS CAST('NONE' AS character_data) AS check_option, CAST( - CASE WHEN EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '2' AND is_instead) - AND EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '4' AND is_instead) - THEN 'YES' ELSE 'NO' END + CASE WHEN pg_view_is_updatable(c.oid) THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_updatable, CAST( - CASE WHEN EXISTS (SELECT 1 FROM pg_rewrite WHERE ev_class = c.oid AND ev_type = '3' AND is_instead) - THEN 'YES' ELSE 'NO' END + CASE WHEN pg_view_is_insertable(c.oid) THEN 'YES' ELSE 'NO' END AS yes_or_no) AS is_insertable_into, CAST( diff --git a/src/backend/executor/execMain.c b/src/backend/executor/execMain.c index dbd3755b1b5e2..0222d40b496d5 100644 --- a/src/backend/executor/execMain.c +++ b/src/backend/executor/execMain.c @@ -923,9 +923,8 @@ InitPlan(QueryDesc *queryDesc, int eflags) /* * Check that a proposed result relation is a legal target for the operation * - * In most cases parser and/or planner should have noticed this already, but - * let's make sure. In the view case we do need a test here, because if the - * view wasn't rewritten by a rule, it had better have an INSTEAD trigger. + * Generally the parser and/or planner should have noticed any such mistake + * already, but let's make sure. * * Note: when changing this function, you probably also need to look at * CheckValidRowMarkRel. @@ -953,6 +952,13 @@ CheckValidResultRel(Relation resultRel, CmdType operation) RelationGetRelationName(resultRel)))); break; case RELKIND_VIEW: + /* + * Okay only if there's a suitable INSTEAD OF trigger. Messages + * here should match rewriteHandler.c's rewriteTargetView, except + * that we omit errdetail because we haven't got the information + * handy (and given that we really shouldn't get here anyway, + * it's not worth great exertion to get). + */ switch (operation) { case CMD_INSERT: @@ -961,7 +967,7 @@ CheckValidResultRel(Relation resultRel, CmdType operation) (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), errmsg("cannot insert into view \"%s\"", RelationGetRelationName(resultRel)), - errhint("You need an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger."))); + errhint("To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger."))); break; case CMD_UPDATE: if (!trigDesc || !trigDesc->trig_update_instead_row) @@ -969,7 +975,7 @@ CheckValidResultRel(Relation resultRel, CmdType operation) (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), errmsg("cannot update view \"%s\"", RelationGetRelationName(resultRel)), - errhint("You need an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger."))); + errhint("To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger."))); break; case CMD_DELETE: if (!trigDesc || !trigDesc->trig_delete_instead_row) @@ -977,7 +983,7 @@ CheckValidResultRel(Relation resultRel, CmdType operation) (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), errmsg("cannot delete from view \"%s\"", RelationGetRelationName(resultRel)), - errhint("You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger."))); + errhint("To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger."))); break; default: elog(ERROR, "unrecognized CmdType: %d", (int) operation); @@ -1028,7 +1034,7 @@ CheckValidRowMarkRel(Relation rel, RowMarkType markType) RelationGetRelationName(rel)))); break; case RELKIND_VIEW: - /* Should not get here */ + /* Should not get here; planner should have expanded the view */ ereport(ERROR, (errcode(ERRCODE_WRONG_OBJECT_TYPE), errmsg("cannot lock rows in view \"%s\"", diff --git a/src/backend/rewrite/rewriteHandler.c b/src/backend/rewrite/rewriteHandler.c index b785c269a034c..990ca346816dc 100644 --- a/src/backend/rewrite/rewriteHandler.c +++ b/src/backend/rewrite/rewriteHandler.c @@ -1833,6 +1833,633 @@ fireRules(Query *parsetree, } +/* + * get_view_query - get the Query from a view's _RETURN rule. + * + * Caller should have verified that the relation is a view, and therefore + * we should find an ON SELECT action. + */ +static Query * +get_view_query(Relation view) +{ + int i; + + Assert(view->rd_rel->relkind == RELKIND_VIEW); + + for (i = 0; i < view->rd_rules->numLocks; i++) + { + RewriteRule *rule = view->rd_rules->rules[i]; + + if (rule->event == CMD_SELECT) + { + /* A _RETURN rule should have only one action */ + if (list_length(rule->actions) != 1) + elog(ERROR, "invalid _RETURN rule action specification"); + + return (Query *) linitial(rule->actions); + } + } + + elog(ERROR, "failed to find _RETURN rule for view"); + return NULL; /* keep compiler quiet */ +} + + +/* + * view_has_instead_trigger - does view have an INSTEAD OF trigger for event? + * + * If it does, we don't want to treat it as auto-updatable. This test can't + * be folded into view_is_auto_updatable because it's not an error condition. + */ +static bool +view_has_instead_trigger(Relation view, CmdType event) +{ + TriggerDesc *trigDesc = view->trigdesc; + + switch (event) + { + case CMD_INSERT: + if (trigDesc && trigDesc->trig_insert_instead_row) + return true; + break; + case CMD_UPDATE: + if (trigDesc && trigDesc->trig_update_instead_row) + return true; + break; + case CMD_DELETE: + if (trigDesc && trigDesc->trig_delete_instead_row) + return true; + break; + default: + elog(ERROR, "unrecognized CmdType: %d", (int) event); + break; + } + return false; +} + + +/* + * view_is_auto_updatable - + * Test if the specified view can be automatically updated. This will + * either return NULL (if the view can be updated) or a message string + * giving the reason that it cannot be. + * + * Caller must have verified that relation is a view! + * + * Note that the checks performed here are local to this view. We do not + * check whether the view's underlying base relation is updatable; that + * will be dealt with in later, recursive processing. + * + * Also note that we don't check for INSTEAD triggers or rules here; those + * also prevent auto-update, but they must be checked for by the caller. + */ +static const char * +view_is_auto_updatable(Relation view) +{ + Query *viewquery = get_view_query(view); + RangeTblRef *rtr; + RangeTblEntry *base_rte; + Bitmapset *bms; + ListCell *cell; + + /*---------- + * Check if the view is simply updatable. According to SQL-92 this means: + * - No DISTINCT clause. + * - Each TLE is a column reference, and each column appears at most once. + * - FROM contains exactly one base relation. + * - No GROUP BY or HAVING clauses. + * - No set operations (UNION, INTERSECT or EXCEPT). + * - No sub-queries in the WHERE clause that reference the target table. + * + * We ignore that last restriction since it would be complex to enforce + * and there isn't any actual benefit to disallowing sub-queries. (The + * semantic issues that the standard is presumably concerned about don't + * arise in Postgres, since any such sub-query will not see any updates + * executed by the outer query anyway, thanks to MVCC snapshotting.) + * + * In addition we impose these constraints, involving features that are + * not part of SQL-92: + * - No CTEs (WITH clauses). + * - No OFFSET or LIMIT clauses (this matches a SQL:2008 restriction). + * - No system columns (including whole-row references) in the tlist. + * + * Note that we do these checks without recursively expanding the view. + * If the base relation is a view, we'll recursively deal with it later. + *---------- + */ + if (viewquery->distinctClause != NIL) + return gettext_noop("Views containing DISTINCT are not automatically updatable."); + + if (viewquery->groupClause != NIL) + return gettext_noop("Views containing GROUP BY are not automatically updatable."); + + if (viewquery->havingQual != NULL) + return gettext_noop("Views containing HAVING are not automatically updatable."); + + if (viewquery->setOperations != NULL) + return gettext_noop("Views containing UNION, INTERSECT or EXCEPT are not automatically updatable."); + + if (viewquery->cteList != NIL) + return gettext_noop("Views containing WITH are not automatically updatable."); + + if (viewquery->limitOffset != NULL || viewquery->limitCount != NULL) + return gettext_noop("Views containing LIMIT or OFFSET are not automatically updatable."); + + /* + * For now, we also don't support security-barrier views, because of the + * difficulty of keeping upper-level qual expressions away from + * lower-level data. This might get relaxed in future. + */ + if (RelationIsSecurityView(view)) + return gettext_noop("Security-barrier views are not automatically updatable."); + + /* + * The view query should select from a single base relation, which must be + * a table or another view. + */ + if (list_length(viewquery->jointree->fromlist) != 1) + return gettext_noop("Views that do not select from a single table or view are not automatically updatable."); + + rtr = (RangeTblRef *) linitial(viewquery->jointree->fromlist); + if (!IsA(rtr, RangeTblRef)) + return gettext_noop("Views that do not select from a single table or view are not automatically updatable."); + + base_rte = rt_fetch(rtr->rtindex, viewquery->rtable); + if (base_rte->rtekind != RTE_RELATION || + (base_rte->relkind != RELKIND_RELATION && + base_rte->relkind != RELKIND_VIEW)) + return gettext_noop("Views that do not select from a single table or view are not automatically updatable."); + + /* + * The view's targetlist entries should all be Vars referring to user + * columns of the base relation, and no two should refer to the same + * column. + * + * Note however that we should ignore resjunk entries. This proviso is + * relevant because ORDER BY is not disallowed, and we shouldn't reject a + * view defined like "SELECT * FROM t ORDER BY a+b". + */ + bms = NULL; + foreach(cell, viewquery->targetList) + { + TargetEntry *tle = (TargetEntry *) lfirst(cell); + Var *var = (Var *) tle->expr; + + if (tle->resjunk) + continue; + + if (!IsA(var, Var) || + var->varno != rtr->rtindex || + var->varlevelsup != 0) + return gettext_noop("Views that return columns that are not columns of their base relation are not automatically updatable."); + + if (var->varattno < 0) + return gettext_noop("Views that return system columns are not automatically updatable."); + + if (var->varattno == 0) + return gettext_noop("Views that return whole-row references are not automatically updatable."); + + if (bms_is_member(var->varattno, bms)) + return gettext_noop("Views that return the same column more than once are not automatically updatable."); + + bms = bms_add_member(bms, var->varattno); + } + bms_free(bms); /* just for cleanliness */ + + return NULL; /* the view is simply updatable */ +} + + +/* + * relation_is_updatable - test if the specified relation is updatable. + * + * This is used for the information_schema views, which have separate concepts + * of "updatable" and "trigger updatable". A relation is "updatable" if it + * can be updated without the need for triggers (either because it has a + * suitable RULE, or because it is simple enough to be automatically updated). + * + * A relation is "trigger updatable" if it has a suitable INSTEAD OF trigger. + * The SQL standard regards this as not necessarily updatable, presumably + * because there is no way of knowing what the trigger will actually do. + * That's currently handled directly in the information_schema views, so + * need not be considered here. + * + * In the case of an automatically updatable view, the base relation must + * also be updatable. + * + * reloid is the pg_class OID to examine. req_events is a bitmask of + * rule event numbers; the relation is considered rule-updatable if it has + * all the specified rules. (We do it this way so that we can test for + * UPDATE plus DELETE rules in a single call.) + */ +bool +relation_is_updatable(Oid reloid, int req_events) +{ + Relation rel; + RuleLock *rulelocks; + + rel = try_relation_open(reloid, AccessShareLock); + + /* + * If the relation doesn't exist, say "false" rather than throwing an + * error. This is helpful since scanning an information_schema view + * under MVCC rules can result in referencing rels that were just + * deleted according to a SnapshotNow probe. + */ + if (rel == NULL) + return false; + + /* Look for unconditional DO INSTEAD rules, and note supported events */ + rulelocks = rel->rd_rules; + if (rulelocks != NULL) + { + int events = 0; + int i; + + for (i = 0; i < rulelocks->numLocks; i++) + { + if (rulelocks->rules[i]->isInstead && + rulelocks->rules[i]->qual == NULL) + { + events |= 1 << rulelocks->rules[i]->event; + } + } + + /* If we have all rules needed, say "yes" */ + if ((events & req_events) == req_events) + { + relation_close(rel, AccessShareLock); + return true; + } + } + + /* Check if this is an automatically updatable view */ + if (rel->rd_rel->relkind == RELKIND_VIEW && + view_is_auto_updatable(rel) == NULL) + { + Query *viewquery; + RangeTblRef *rtr; + RangeTblEntry *base_rte; + Oid baseoid; + + /* The base relation must also be updatable */ + viewquery = get_view_query(rel); + rtr = (RangeTblRef *) linitial(viewquery->jointree->fromlist); + base_rte = rt_fetch(rtr->rtindex, viewquery->rtable); + + if (base_rte->relkind == RELKIND_RELATION) + { + /* Tables are always updatable */ + relation_close(rel, AccessShareLock); + return true; + } + else + { + /* Do a recursive check for any other kind of base relation */ + baseoid = base_rte->relid; + relation_close(rel, AccessShareLock); + return relation_is_updatable(baseoid, req_events); + } + } + + /* If we reach here, the relation is not updatable */ + relation_close(rel, AccessShareLock); + return false; +} + + +/* + * adjust_view_column_set - map a set of column numbers according to targetlist + * + * This is used with simply-updatable views to map column-permissions sets for + * the view columns onto the matching columns in the underlying base relation. + * The targetlist is expected to be a list of plain Vars of the underlying + * relation (as per the checks above in view_is_auto_updatable). + */ +static Bitmapset * +adjust_view_column_set(Bitmapset *cols, List *targetlist) +{ + Bitmapset *result = NULL; + Bitmapset *tmpcols; + AttrNumber col; + + tmpcols = bms_copy(cols); + while ((col = bms_first_member(tmpcols)) >= 0) + { + /* bit numbers are offset by FirstLowInvalidHeapAttributeNumber */ + AttrNumber attno = col + FirstLowInvalidHeapAttributeNumber; + + if (attno == InvalidAttrNumber) + { + /* + * There's a whole-row reference to the view. For permissions + * purposes, treat it as a reference to each column available from + * the view. (We should *not* convert this to a whole-row + * reference to the base relation, since the view may not touch + * all columns of the base relation.) + */ + ListCell *lc; + + foreach(lc, targetlist) + { + TargetEntry *tle = (TargetEntry *) lfirst(lc); + Var *var; + + if (tle->resjunk) + continue; + var = (Var *) tle->expr; + Assert(IsA(var, Var)); + result = bms_add_member(result, + var->varattno - FirstLowInvalidHeapAttributeNumber); + } + } + else + { + /* + * Views do not have system columns, so we do not expect to see + * any other system attnos here. If we do find one, the error + * case will apply. + */ + TargetEntry *tle = get_tle_by_resno(targetlist, attno); + + if (tle != NULL && !tle->resjunk && IsA(tle->expr, Var)) + { + Var *var = (Var *) tle->expr; + + result = bms_add_member(result, + var->varattno - FirstLowInvalidHeapAttributeNumber); + } + else + elog(ERROR, "attribute number %d not found in view targetlist", + attno); + } + } + bms_free(tmpcols); + + return result; +} + + +/* + * rewriteTargetView - + * Attempt to rewrite a query where the target relation is a view, so that + * the view's base relation becomes the target relation. + * + * Note that the base relation here may itself be a view, which may or may not + * have INSTEAD OF triggers or rules to handle the update. That is handled by + * the recursion in RewriteQuery. + */ +static Query * +rewriteTargetView(Query *parsetree, Relation view) +{ + const char *auto_update_detail; + Query *viewquery; + RangeTblRef *rtr; + int base_rt_index; + int new_rt_index; + RangeTblEntry *base_rte; + RangeTblEntry *view_rte; + RangeTblEntry *new_rte; + Relation base_rel; + List *view_targetlist; + ListCell *lc; + + /* The view must be simply updatable, else fail */ + auto_update_detail = view_is_auto_updatable(view); + if (auto_update_detail) + { + /* messages here should match execMain.c's CheckValidResultRel */ + switch (parsetree->commandType) + { + case CMD_INSERT: + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("cannot insert into view \"%s\"", + RelationGetRelationName(view)), + errdetail_internal("%s", _(auto_update_detail)), + errhint("To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger."))); + break; + case CMD_UPDATE: + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("cannot update view \"%s\"", + RelationGetRelationName(view)), + errdetail_internal("%s", _(auto_update_detail)), + errhint("To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger."))); + break; + case CMD_DELETE: + ereport(ERROR, + (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("cannot delete from view \"%s\"", + RelationGetRelationName(view)), + errdetail_internal("%s", _(auto_update_detail)), + errhint("To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger."))); + break; + default: + elog(ERROR, "unrecognized CmdType: %d", + (int) parsetree->commandType); + break; + } + } + + /* Locate RTE describing the view in the outer query */ + view_rte = rt_fetch(parsetree->resultRelation, parsetree->rtable); + + /* + * If we get here, view_is_auto_updatable() has verified that the view + * contains a single base relation. + */ + viewquery = get_view_query(view); + + Assert(list_length(viewquery->jointree->fromlist) == 1); + rtr = (RangeTblRef *) linitial(viewquery->jointree->fromlist); + Assert(IsA(rtr, RangeTblRef)); + + base_rt_index = rtr->rtindex; + base_rte = rt_fetch(base_rt_index, viewquery->rtable); + Assert(base_rte->rtekind == RTE_RELATION); + + /* + * Up to now, the base relation hasn't been touched at all in our query. + * We need to acquire lock on it before we try to do anything with it. + * (The subsequent recursive call of RewriteQuery will suppose that we + * already have the right lock!) Since it will become the query target + * relation, RowExclusiveLock is always the right thing. + */ + base_rel = heap_open(base_rte->relid, RowExclusiveLock); + + /* + * While we have the relation open, update the RTE's relkind, just in case + * it changed since this view was made (cf. AcquireRewriteLocks). + */ + base_rte->relkind = base_rel->rd_rel->relkind; + + heap_close(base_rel, NoLock); + + /* + * Create a new target RTE describing the base relation, and add it to the + * outer query's rangetable. (What's happening in the next few steps is + * very much like what the planner would do to "pull up" the view into the + * outer query. Perhaps someday we should refactor things enough so that + * we can share code with the planner.) + */ + new_rte = (RangeTblEntry *) copyObject(base_rte); + parsetree->rtable = lappend(parsetree->rtable, new_rte); + new_rt_index = list_length(parsetree->rtable); + + /* + * Make a copy of the view's targetlist, adjusting its Vars to reference + * the new target RTE, ie make their varnos be new_rt_index instead of + * base_rt_index. There can be no Vars for other rels in the tlist, so + * this is sufficient to pull up the tlist expressions for use in the + * outer query. The tlist will provide the replacement expressions used + * by ReplaceVarsFromTargetList below. + */ + view_targetlist = copyObject(viewquery->targetList); + + ChangeVarNodes((Node *) view_targetlist, + base_rt_index, + new_rt_index, + 0); + + /* + * Mark the new target RTE for the permissions checks that we want to + * enforce against the view owner, as distinct from the query caller. At + * the relation level, require the same INSERT/UPDATE/DELETE permissions + * that the query caller needs against the view. We drop the ACL_SELECT + * bit that is presumably in new_rte->requiredPerms initially. + * + * Note: the original view RTE remains in the query's rangetable list. + * Although it will be unused in the query plan, we need it there so that + * the executor still performs appropriate permissions checks for the + * query caller's use of the view. + */ + new_rte->checkAsUser = view->rd_rel->relowner; + new_rte->requiredPerms = view_rte->requiredPerms; + + /* + * Now for the per-column permissions bits. + * + * Initially, new_rte contains selectedCols permission check bits for all + * base-rel columns referenced by the view, but since the view is a SELECT + * query its modifiedCols is empty. We set modifiedCols to include all + * the columns the outer query is trying to modify, adjusting the column + * numbers as needed. But we leave selectedCols as-is, so the view owner + * must have read permission for all columns used in the view definition, + * even if some of them are not read by the outer query. We could try to + * limit selectedCols to only columns used in the transformed query, but + * that does not correspond to what happens in ordinary SELECT usage of a + * view: all referenced columns must have read permission, even if + * optimization finds that some of them can be discarded during query + * transformation. The flattening we're doing here is an optional + * optimization, too. (If you are unpersuaded and want to change this, + * note that applying adjust_view_column_set to view_rte->selectedCols is + * clearly *not* the right answer, since that neglects base-rel columns + * used in the view's WHERE quals.) + * + * This step needs the modified view targetlist, so we have to do things + * in this order. + */ + Assert(bms_is_empty(new_rte->modifiedCols)); + new_rte->modifiedCols = adjust_view_column_set(view_rte->modifiedCols, + view_targetlist); + + /* + * For UPDATE/DELETE, rewriteTargetListUD will have added a wholerow junk + * TLE for the view to the end of the targetlist, which we no longer need. + * Remove it to avoid unnecessary work when we process the targetlist. + * Note that when we recurse through rewriteQuery a new junk TLE will be + * added to allow the executor to find the proper row in the new target + * relation. (So, if we failed to do this, we might have multiple junk + * TLEs with the same name, which would be disastrous.) + */ + if (parsetree->commandType != CMD_INSERT) + { + TargetEntry *tle = (TargetEntry *) llast(parsetree->targetList); + + Assert(tle->resjunk); + Assert(IsA(tle->expr, Var) && + ((Var *) tle->expr)->varno == parsetree->resultRelation && + ((Var *) tle->expr)->varattno == 0); + parsetree->targetList = list_delete_ptr(parsetree->targetList, tle); + } + + /* + * Now update all Vars in the outer query that reference the view to + * reference the appropriate column of the base relation instead. + */ + parsetree = (Query *) + ReplaceVarsFromTargetList((Node *) parsetree, + parsetree->resultRelation, + 0, + view_rte, + view_targetlist, + REPLACEVARS_REPORT_ERROR, + 0, + &parsetree->hasSubLinks); + + /* + * Update all other RTI references in the query that point to the view + * (for example, parsetree->resultRelation itself) to point to the new + * base relation instead. Vars will not be affected since none of them + * reference parsetree->resultRelation any longer. + */ + ChangeVarNodes((Node *) parsetree, + parsetree->resultRelation, + new_rt_index, + 0); + Assert(parsetree->resultRelation == new_rt_index); + + /* + * For INSERT/UPDATE we must also update resnos in the targetlist to refer + * to columns of the base relation, since those indicate the target + * columns to be affected. + * + * Note that this destroys the resno ordering of the targetlist, but that + * will be fixed when we recurse through rewriteQuery, which will invoke + * rewriteTargetListIU again on the updated targetlist. + */ + if (parsetree->commandType != CMD_DELETE) + { + foreach(lc, parsetree->targetList) + { + TargetEntry *tle = (TargetEntry *) lfirst(lc); + TargetEntry *view_tle; + + if (tle->resjunk) + continue; + + view_tle = get_tle_by_resno(view_targetlist, tle->resno); + if (view_tle != NULL && !view_tle->resjunk && IsA(view_tle->expr, Var)) + tle->resno = ((Var *) view_tle->expr)->varattno; + else + elog(ERROR, "attribute number %d not found in view targetlist", + tle->resno); + } + } + + /* + * For UPDATE/DELETE, pull up any WHERE quals from the view. We know that + * any Vars in the quals must reference the one base relation, so we need + * only adjust their varnos to reference the new target (just the same as + * we did with the view targetlist). + * + * For INSERT, the view's quals can be ignored for now. When we implement + * WITH CHECK OPTION, this might be a good place to collect them. + */ + if (parsetree->commandType != CMD_INSERT && + viewquery->jointree->quals != NULL) + { + Node *viewqual = (Node *) copyObject(viewquery->jointree->quals); + + ChangeVarNodes(viewqual, base_rt_index, new_rt_index, 0); + AddQual(parsetree, (Node *) viewqual); + } + + return parsetree; +} + + /* * RewriteQuery - * rewrites the query and apply the rules again on the queries rewritten @@ -1927,6 +2554,7 @@ RewriteQuery(Query *parsetree, List *rewrite_events) RangeTblEntry *rt_entry; Relation rt_entry_relation; List *locks; + List *product_queries; result_relation = parsetree->resultRelation; Assert(result_relation != 0); @@ -1997,17 +2625,54 @@ RewriteQuery(Query *parsetree, List *rewrite_events) locks = matchLocks(event, rt_entry_relation->rd_rules, result_relation, parsetree); - if (locks != NIL) + product_queries = fireRules(parsetree, + result_relation, + event, + locks, + &instead, + &returning, + &qual_product); + + /* + * If there were no INSTEAD rules, and the target relation is a view + * without any INSTEAD OF triggers, see if the view can be + * automatically updated. If so, we perform the necessary query + * transformation here and add the resulting query to the + * product_queries list, so that it gets recursively rewritten if + * necessary. + */ + if (!instead && qual_product == NULL && + rt_entry_relation->rd_rel->relkind == RELKIND_VIEW && + !view_has_instead_trigger(rt_entry_relation, event)) { - List *product_queries; + /* + * This throws an error if the view can't be automatically + * updated, but that's OK since the query would fail at runtime + * anyway. + */ + parsetree = rewriteTargetView(parsetree, rt_entry_relation); - product_queries = fireRules(parsetree, - result_relation, - event, - locks, - &instead, - &returning, - &qual_product); + /* + * At this point product_queries contains any DO ALSO rule actions. + * Add the rewritten query before or after those. This must match + * the handling the original query would have gotten below, if + * we allowed it to be included again. + */ + if (parsetree->commandType == CMD_INSERT) + product_queries = lcons(parsetree, product_queries); + else + product_queries = lappend(product_queries, parsetree); + + /* + * Set the "instead" flag, as if there had been an unqualified + * INSTEAD, to prevent the original query from being included a + * second time below. The transformation will have rewritten any + * RETURNING list, so we can also set "returning" to forestall + * throwing an error below. + */ + instead = true; + returning = true; + } /* * If we got any product queries, recursively rewrite them --- but @@ -2045,7 +2710,6 @@ RewriteQuery(Query *parsetree, List *rewrite_events) rewrite_events = list_delete_first(rewrite_events); } - } /* * If there is an INSTEAD, and the original query has a RETURNING, we diff --git a/src/backend/utils/adt/misc.c b/src/backend/utils/adt/misc.c index cd20b83841683..407946715e255 100644 --- a/src/backend/utils/adt/misc.c +++ b/src/backend/utils/adt/misc.c @@ -28,6 +28,7 @@ #include "miscadmin.h" #include "parser/keywords.h" #include "postmaster/syslogger.h" +#include "rewrite/rewriteHandler.h" #include "storage/fd.h" #include "storage/pmsignal.h" #include "storage/proc.h" @@ -523,3 +524,33 @@ pg_collation_for(PG_FUNCTION_ARGS) PG_RETURN_NULL(); PG_RETURN_TEXT_P(cstring_to_text(generate_collation_name(collid))); } + + +/* + * information_schema support functions + * + * Test whether a view (identified by pg_class OID) is insertable-into or + * updatable. The latter requires delete capability too. This is an + * artifact of the way the SQL standard defines the information_schema views: + * if we defined separate functions for update and delete, we'd double the + * work required to compute the view columns. + * + * These rely on relation_is_updatable(), which is in rewriteHandler.c. + */ +Datum +pg_view_is_insertable(PG_FUNCTION_ARGS) +{ + Oid viewoid = PG_GETARG_OID(0); + int req_events = (1 << CMD_INSERT); + + PG_RETURN_BOOL(relation_is_updatable(viewoid, req_events)); +} + +Datum +pg_view_is_updatable(PG_FUNCTION_ARGS) +{ + Oid viewoid = PG_GETARG_OID(0); + int req_events = (1 << CMD_UPDATE) | (1 << CMD_DELETE); + + PG_RETURN_BOOL(relation_is_updatable(viewoid, req_events)); +} diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index 9622356a6376e..e98a225fbca9a 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -53,6 +53,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 201211281 +#define CATALOG_VERSION_NO 201212081 #endif diff --git a/src/include/catalog/pg_proc.h b/src/include/catalog/pg_proc.h index f935eb1df825e..d1b22d172daa4 100644 --- a/src/include/catalog/pg_proc.h +++ b/src/include/catalog/pg_proc.h @@ -1976,6 +1976,11 @@ DESCR("type of the argument"); DATA(insert OID = 3162 ( pg_collation_for PGNSP PGUID 12 1 0 0 0 f f f f f f s 1 0 25 "2276" _null_ _null_ _null_ _null_ pg_collation_for _null_ _null_ _null_ )); DESCR("collation of the argument; implementation of the COLLATION FOR expression"); +DATA(insert OID = 3842 ( pg_view_is_insertable PGNSP PGUID 12 10 0 0 0 f f f f t f s 1 0 16 "26" _null_ _null_ _null_ _null_ pg_view_is_insertable _null_ _null_ _null_ )); +DESCR("is a view insertable-into"); +DATA(insert OID = 3843 ( pg_view_is_updatable PGNSP PGUID 12 10 0 0 0 f f f f t f s 1 0 16 "26" _null_ _null_ _null_ _null_ pg_view_is_updatable _null_ _null_ _null_ )); +DESCR("is a view updatable"); + /* Deferrable unique constraint trigger */ DATA(insert OID = 1250 ( unique_key_recheck PGNSP PGUID 12 1 0 0 0 f f f f t f v 0 0 2279 "" _null_ _null_ _null_ _null_ unique_key_recheck _null_ _null_ _null_ )); DESCR("deferred UNIQUE constraint check"); diff --git a/src/include/rewrite/rewriteHandler.h b/src/include/rewrite/rewriteHandler.h index 50625d4c37196..3540e1b034888 100644 --- a/src/include/rewrite/rewriteHandler.h +++ b/src/include/rewrite/rewriteHandler.h @@ -19,6 +19,8 @@ extern List *QueryRewrite(Query *parsetree); extern void AcquireRewriteLocks(Query *parsetree, bool forUpdatePushedDown); + extern Node *build_column_default(Relation rel, int attrno); +extern bool relation_is_updatable(Oid reloid, int req_events); #endif /* REWRITEHANDLER_H */ diff --git a/src/include/utils/builtins.h b/src/include/utils/builtins.h index 5bc3a75856d8e..ad82dcc209397 100644 --- a/src/include/utils/builtins.h +++ b/src/include/utils/builtins.h @@ -482,6 +482,8 @@ extern Datum pg_sleep(PG_FUNCTION_ARGS); extern Datum pg_get_keywords(PG_FUNCTION_ARGS); extern Datum pg_typeof(PG_FUNCTION_ARGS); extern Datum pg_collation_for(PG_FUNCTION_ARGS); +extern Datum pg_view_is_insertable(PG_FUNCTION_ARGS); +extern Datum pg_view_is_updatable(PG_FUNCTION_ARGS); /* oid.c */ extern Datum oidin(PG_FUNCTION_ARGS); diff --git a/src/test/regress/expected/triggers.out b/src/test/regress/expected/triggers.out index 94ea61f80c74a..5140575f2a101 100644 --- a/src/test/regress/expected/triggers.out +++ b/src/test/regress/expected/triggers.out @@ -820,20 +820,6 @@ DROP TABLE min_updates_test_oids; -- Test triggers on views -- CREATE VIEW main_view AS SELECT a, b FROM main_table; --- Updates should fail without rules or triggers -INSERT INTO main_view VALUES (1,2); -ERROR: cannot insert into view "main_view" -HINT: You need an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. -UPDATE main_view SET b = 20 WHERE a = 50; -ERROR: cannot update view "main_view" -HINT: You need an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. -DELETE FROM main_view WHERE a = 50; -ERROR: cannot delete from view "main_view" -HINT: You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. --- Should fail even when there are no matching rows -DELETE FROM main_view WHERE a = 51; -ERROR: cannot delete from view "main_view" -HINT: You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. -- VIEW trigger function CREATE OR REPLACE FUNCTION view_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ diff --git a/src/test/regress/expected/updatable_views.out b/src/test/regress/expected/updatable_views.out new file mode 100644 index 0000000000000..ead08d69b10fd --- /dev/null +++ b/src/test/regress/expected/updatable_views.out @@ -0,0 +1,1069 @@ +-- +-- UPDATABLE VIEWS +-- +-- check that non-updatable views are rejected with useful error messages +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW ro_view1 AS SELECT DISTINCT a, b FROM base_tbl; -- DISTINCT not supported +CREATE VIEW ro_view2 AS SELECT a, b FROM base_tbl GROUP BY a, b; -- GROUP BY not supported +CREATE VIEW ro_view3 AS SELECT 1 FROM base_tbl HAVING max(a) > 0; -- HAVING not supported +CREATE VIEW ro_view4 AS SELECT count(*) FROM base_tbl; -- Aggregate functions not supported +CREATE VIEW ro_view5 AS SELECT a, rank() OVER() FROM base_tbl; -- Window functions not supported +CREATE VIEW ro_view6 AS SELECT a, b FROM base_tbl UNION SELECT -a, b FROM base_tbl; -- Set ops not supported +CREATE VIEW ro_view7 AS WITH t AS (SELECT a, b FROM base_tbl) SELECT * FROM t; -- WITH not supported +CREATE VIEW ro_view8 AS SELECT a, b FROM base_tbl ORDER BY a OFFSET 1; -- OFFSET not supported +CREATE VIEW ro_view9 AS SELECT a, b FROM base_tbl ORDER BY a LIMIT 1; -- LIMIT not supported +CREATE VIEW ro_view10 AS SELECT 1 AS a; -- No base relations +CREATE VIEW ro_view11 AS SELECT b1.a, b2.b FROM base_tbl b1, base_tbl b2; -- Multiple base relations +CREATE VIEW ro_view12 AS SELECT * FROM generate_series(1, 10) AS g(a); -- SRF in rangetable +CREATE VIEW ro_view13 AS SELECT a, b FROM (SELECT * FROM base_tbl) AS t; -- Subselect in rangetable +CREATE VIEW ro_view14 AS SELECT ctid FROM base_tbl; -- System columns not supported +CREATE VIEW ro_view15 AS SELECT a, upper(b) FROM base_tbl; -- Expression/function in targetlist +CREATE VIEW ro_view16 AS SELECT a, b, a AS aa FROM base_tbl; -- Repeated column +CREATE VIEW ro_view17 AS SELECT * FROM ro_view1; -- Base relation not updatable +CREATE VIEW ro_view18 WITH (security_barrier = true) + AS SELECT * FROM base_tbl; -- Security barrier views not updatable +CREATE VIEW ro_view19 AS SELECT * FROM (VALUES(1)) AS tmp(a); -- VALUES in rangetable +CREATE SEQUENCE seq; +CREATE VIEW ro_view20 AS SELECT * FROM seq; -- View based on a sequence +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + ro_view1 | NO + ro_view10 | NO + ro_view11 | NO + ro_view12 | NO + ro_view13 | NO + ro_view14 | NO + ro_view15 | NO + ro_view16 | NO + ro_view17 | NO + ro_view18 | NO + ro_view19 | NO + ro_view2 | NO + ro_view20 | NO + ro_view3 | NO + ro_view4 | NO + ro_view5 | NO + ro_view6 | NO + ro_view7 | NO + ro_view8 | NO + ro_view9 | NO +(20 rows) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + ro_view1 | NO | NO + ro_view10 | NO | NO + ro_view11 | NO | NO + ro_view12 | NO | NO + ro_view13 | NO | NO + ro_view14 | NO | NO + ro_view15 | NO | NO + ro_view16 | NO | NO + ro_view17 | NO | NO + ro_view18 | NO | NO + ro_view19 | NO | NO + ro_view2 | NO | NO + ro_view20 | NO | NO + ro_view3 | NO | NO + ro_view4 | NO | NO + ro_view5 | NO | NO + ro_view6 | NO | NO + ro_view7 | NO | NO + ro_view8 | NO | NO + ro_view9 | NO | NO +(20 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+---------------+-------------- + ro_view1 | a | NO + ro_view1 | b | NO + ro_view10 | a | NO + ro_view11 | a | NO + ro_view11 | b | NO + ro_view12 | a | NO + ro_view13 | a | NO + ro_view13 | b | NO + ro_view14 | ctid | NO + ro_view15 | a | NO + ro_view15 | upper | NO + ro_view16 | a | NO + ro_view16 | b | NO + ro_view16 | aa | NO + ro_view17 | a | NO + ro_view17 | b | NO + ro_view18 | a | NO + ro_view18 | b | NO + ro_view19 | a | NO + ro_view2 | a | NO + ro_view2 | b | NO + ro_view20 | sequence_name | NO + ro_view20 | last_value | NO + ro_view20 | start_value | NO + ro_view20 | increment_by | NO + ro_view20 | max_value | NO + ro_view20 | min_value | NO + ro_view20 | cache_value | NO + ro_view20 | log_cnt | NO + ro_view20 | is_cycled | NO + ro_view20 | is_called | NO + ro_view3 | ?column? | NO + ro_view4 | count | NO + ro_view5 | a | NO + ro_view5 | rank | NO + ro_view6 | a | NO + ro_view6 | b | NO + ro_view7 | a | NO + ro_view7 | b | NO + ro_view8 | a | NO + ro_view8 | b | NO + ro_view9 | a | NO + ro_view9 | b | NO +(43 rows) + +DELETE FROM ro_view1; +ERROR: cannot delete from view "ro_view1" +DETAIL: Views containing DISTINCT are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +DELETE FROM ro_view2; +ERROR: cannot delete from view "ro_view2" +DETAIL: Views containing GROUP BY are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +DELETE FROM ro_view3; +ERROR: cannot delete from view "ro_view3" +DETAIL: Views containing HAVING are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +DELETE FROM ro_view4; +ERROR: cannot delete from view "ro_view4" +DETAIL: Views that return columns that are not columns of their base relation are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +DELETE FROM ro_view5; +ERROR: cannot delete from view "ro_view5" +DETAIL: Views that return columns that are not columns of their base relation are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +DELETE FROM ro_view6; +ERROR: cannot delete from view "ro_view6" +DETAIL: Views containing UNION, INTERSECT or EXCEPT are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +UPDATE ro_view7 SET a=a+1; +ERROR: cannot update view "ro_view7" +DETAIL: Views containing WITH are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +UPDATE ro_view8 SET a=a+1; +ERROR: cannot update view "ro_view8" +DETAIL: Views containing LIMIT or OFFSET are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +UPDATE ro_view9 SET a=a+1; +ERROR: cannot update view "ro_view9" +DETAIL: Views containing LIMIT or OFFSET are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +UPDATE ro_view10 SET a=a+1; +ERROR: cannot update view "ro_view10" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +UPDATE ro_view11 SET a=a+1; +ERROR: cannot update view "ro_view11" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +UPDATE ro_view12 SET a=a+1; +ERROR: cannot update view "ro_view12" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +INSERT INTO ro_view13 VALUES (3, 'Row 3'); +ERROR: cannot insert into view "ro_view13" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +INSERT INTO ro_view14 VALUES (null); +ERROR: cannot insert into view "ro_view14" +DETAIL: Views that return system columns are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +INSERT INTO ro_view15 VALUES (3, 'ROW 3'); +ERROR: cannot insert into view "ro_view15" +DETAIL: Views that return columns that are not columns of their base relation are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +INSERT INTO ro_view16 VALUES (3, 'Row 3', 3); +ERROR: cannot insert into view "ro_view16" +DETAIL: Views that return the same column more than once are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +INSERT INTO ro_view17 VALUES (3, 'ROW 3'); +ERROR: cannot insert into view "ro_view1" +DETAIL: Views containing DISTINCT are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +INSERT INTO ro_view18 VALUES (3, 'ROW 3'); +ERROR: cannot insert into view "ro_view18" +DETAIL: Security-barrier views are not automatically updatable. +HINT: To make the view insertable, provide an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger. +DELETE FROM ro_view19; +ERROR: cannot delete from view "ro_view19" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger. +UPDATE ro_view20 SET max_value=1000; +ERROR: cannot update view "ro_view20" +DETAIL: Views that do not select from a single table or view are not automatically updatable. +HINT: To make the view updatable, provide an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger. +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 16 other objects +DETAIL: drop cascades to view ro_view1 +drop cascades to view ro_view17 +drop cascades to view ro_view2 +drop cascades to view ro_view3 +drop cascades to view ro_view5 +drop cascades to view ro_view6 +drop cascades to view ro_view7 +drop cascades to view ro_view8 +drop cascades to view ro_view9 +drop cascades to view ro_view11 +drop cascades to view ro_view13 +drop cascades to view ro_view15 +drop cascades to view ro_view16 +drop cascades to view ro_view18 +drop cascades to view ro_view4 +drop cascades to view ro_view14 +DROP VIEW ro_view10, ro_view12, ro_view19; +DROP SEQUENCE seq CASCADE; +NOTICE: drop cascades to view ro_view20 +-- simple updatable view +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name = 'rw_view1'; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | YES +(1 row) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name = 'rw_view1'; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view1 | YES | YES +(1 row) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name = 'rw_view1' + ORDER BY ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | YES + rw_view1 | b | YES +(2 rows) + +INSERT INTO rw_view1 VALUES (3, 'Row 3'); +INSERT INTO rw_view1 (a) VALUES (4); +UPDATE rw_view1 SET a=5 WHERE a=4; +DELETE FROM rw_view1 WHERE b='Row 2'; +SELECT * FROM base_tbl; + a | b +----+------------- + -2 | Row -2 + -1 | Row -1 + 0 | Row 0 + 1 | Row 1 + 3 | Row 3 + 5 | Unspecified +(6 rows) + +EXPLAIN (costs off) UPDATE rw_view1 SET a=6 WHERE a=5; + QUERY PLAN +-------------------------------------------------- + Update on base_tbl + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: ((a > 0) AND (a = 5)) +(3 rows) + +EXPLAIN (costs off) DELETE FROM rw_view1 WHERE a=5; + QUERY PLAN +-------------------------------------------------- + Delete on base_tbl + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: ((a > 0) AND (a = 5)) +(3 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to view rw_view1 +-- view on top of view +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW rw_view1 AS SELECT b AS bb, a AS aa FROM base_tbl WHERE a>0; +CREATE VIEW rw_view2 AS SELECT aa AS aaa, bb AS bbb FROM rw_view1 WHERE aa<10; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name = 'rw_view2'; + table_name | is_insertable_into +------------+-------------------- + rw_view2 | YES +(1 row) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name = 'rw_view2'; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view2 | YES | YES +(1 row) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name = 'rw_view2' + ORDER BY ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view2 | aaa | YES + rw_view2 | bbb | YES +(2 rows) + +INSERT INTO rw_view2 VALUES (3, 'Row 3'); +INSERT INTO rw_view2 (aaa) VALUES (4); +SELECT * FROM rw_view2; + aaa | bbb +-----+------------- + 1 | Row 1 + 2 | Row 2 + 3 | Row 3 + 4 | Unspecified +(4 rows) + +UPDATE rw_view2 SET bbb='Row 4' WHERE aaa=4; +DELETE FROM rw_view2 WHERE aaa=2; +SELECT * FROM rw_view2; + aaa | bbb +-----+------- + 1 | Row 1 + 3 | Row 3 + 4 | Row 4 +(3 rows) + +EXPLAIN (costs off) UPDATE rw_view2 SET aaa=5 WHERE aaa=4; + QUERY PLAN +-------------------------------------------------------- + Update on base_tbl + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: ((a < 10) AND (a > 0) AND (a = 4)) +(3 rows) + +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE aaa=4; + QUERY PLAN +-------------------------------------------------------- + Delete on base_tbl + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: ((a < 10) AND (a > 0) AND (a = 4)) +(3 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to view rw_view1 +drop cascades to view rw_view2 +-- view on top of view with rules +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0 OFFSET 0; -- not updatable without rules/triggers +CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a<10; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | NO + rw_view2 | NO +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view1 | NO | NO + rw_view2 | NO | NO +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE RULE rw_view1_ins_rule AS ON INSERT TO rw_view1 + DO INSTEAD INSERT INTO base_tbl VALUES (NEW.a, NEW.b) RETURNING *; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | YES + rw_view2 | YES +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view1 | NO | YES + rw_view2 | NO | YES +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE RULE rw_view1_upd_rule AS ON UPDATE TO rw_view1 + DO INSTEAD UPDATE base_tbl SET b=NEW.b WHERE a=OLD.a RETURNING NEW.*; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | YES + rw_view2 | YES +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view1 | NO | YES + rw_view2 | NO | YES +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE RULE rw_view1_del_rule AS ON DELETE TO rw_view1 + DO INSTEAD DELETE FROM base_tbl WHERE a=OLD.a RETURNING OLD.*; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | YES + rw_view2 | YES +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into +------------+--------------+-------------------- + rw_view1 | YES | YES + rw_view2 | YES | YES +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | YES + rw_view1 | b | YES + rw_view2 | a | YES + rw_view2 | b | YES +(4 rows) + +INSERT INTO rw_view2 VALUES (3, 'Row 3') RETURNING *; + a | b +---+------- + 3 | Row 3 +(1 row) + +UPDATE rw_view2 SET b='Row three' WHERE a=3 RETURNING *; + a | b +---+----------- + 3 | Row three +(1 row) + +SELECT * FROM rw_view2; + a | b +---+----------- + 1 | Row 1 + 2 | Row 2 + 3 | Row three +(3 rows) + +DELETE FROM rw_view2 WHERE a=3 RETURNING *; + a | b +---+----------- + 3 | Row three +(1 row) + +SELECT * FROM rw_view2; + a | b +---+------- + 1 | Row 1 + 2 | Row 2 +(2 rows) + +EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2; + QUERY PLAN +------------------------------------------------------------------ + Update on base_tbl + -> Nested Loop + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: (a = 2) + -> Subquery Scan on rw_view1 + Filter: ((rw_view1.a < 10) AND (rw_view1.a = 2)) + -> Limit + -> Bitmap Heap Scan on base_tbl base_tbl_1 + Recheck Cond: (a > 0) + -> Bitmap Index Scan on base_tbl_pkey + Index Cond: (a > 0) +(11 rows) + +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2; + QUERY PLAN +------------------------------------------------------------------ + Delete on base_tbl + -> Nested Loop + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: (a = 2) + -> Subquery Scan on rw_view1 + Filter: ((rw_view1.a < 10) AND (rw_view1.a = 2)) + -> Limit + -> Bitmap Heap Scan on base_tbl base_tbl_1 + Recheck Cond: (a > 0) + -> Bitmap Index Scan on base_tbl_pkey + Index Cond: (a > 0) +(11 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to view rw_view1 +drop cascades to view rw_view2 +-- view on top of view with triggers +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0 OFFSET 0; -- not updatable without rules/triggers +CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a<10; +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | NO + rw_view2 | NO +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into | is_trigger_updatable | is_trigger_deletable | is_trigger_insertable_into +------------+--------------+--------------------+----------------------+----------------------+---------------------------- + rw_view1 | NO | NO | NO | NO | NO + rw_view2 | NO | NO | NO | NO | NO +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE FUNCTION rw_view1_trig_fn() +RETURNS trigger AS +$$ +BEGIN + IF TG_OP = 'INSERT' THEN + INSERT INTO base_tbl VALUES (NEW.a, NEW.b); + RETURN NEW; + ELSIF TG_OP = 'UPDATE' THEN + UPDATE base_tbl SET b=NEW.b WHERE a=OLD.a; + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + DELETE FROM base_tbl WHERE a=OLD.a; + RETURN OLD; + END IF; +END; +$$ +LANGUAGE plpgsql; +CREATE TRIGGER rw_view1_ins_trig INSTEAD OF INSERT ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | NO + rw_view2 | NO +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into | is_trigger_updatable | is_trigger_deletable | is_trigger_insertable_into +------------+--------------+--------------------+----------------------+----------------------+---------------------------- + rw_view1 | NO | NO | NO | NO | YES + rw_view2 | NO | NO | NO | NO | NO +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE TRIGGER rw_view1_upd_trig INSTEAD OF UPDATE ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | NO + rw_view2 | NO +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into | is_trigger_updatable | is_trigger_deletable | is_trigger_insertable_into +------------+--------------+--------------------+----------------------+----------------------+---------------------------- + rw_view1 | NO | NO | YES | NO | YES + rw_view2 | NO | NO | NO | NO | NO +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +CREATE TRIGGER rw_view1_del_trig INSTEAD OF DELETE ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_insertable_into +------------+-------------------- + rw_view1 | NO + rw_view2 | NO +(2 rows) + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + table_name | is_updatable | is_insertable_into | is_trigger_updatable | is_trigger_deletable | is_trigger_insertable_into +------------+--------------+--------------------+----------------------+----------------------+---------------------------- + rw_view1 | NO | NO | YES | YES | YES + rw_view2 | NO | NO | NO | NO | NO +(2 rows) + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + table_name | column_name | is_updatable +------------+-------------+-------------- + rw_view1 | a | NO + rw_view1 | b | NO + rw_view2 | a | NO + rw_view2 | b | NO +(4 rows) + +INSERT INTO rw_view2 VALUES (3, 'Row 3') RETURNING *; + a | b +---+------- + 3 | Row 3 +(1 row) + +UPDATE rw_view2 SET b='Row three' WHERE a=3 RETURNING *; + a | b +---+----------- + 3 | Row three +(1 row) + +SELECT * FROM rw_view2; + a | b +---+----------- + 1 | Row 1 + 2 | Row 2 + 3 | Row three +(3 rows) + +DELETE FROM rw_view2 WHERE a=3 RETURNING *; + a | b +---+----------- + 3 | Row three +(1 row) + +SELECT * FROM rw_view2; + a | b +---+------- + 1 | Row 1 + 2 | Row 2 +(2 rows) + +EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2; + QUERY PLAN +------------------------------------------------------------ + Update on rw_view1 rw_view1_1 + -> Subquery Scan on rw_view1 + Filter: ((rw_view1.a < 10) AND (rw_view1.a = 2)) + -> Limit + -> Bitmap Heap Scan on base_tbl + Recheck Cond: (a > 0) + -> Bitmap Index Scan on base_tbl_pkey + Index Cond: (a > 0) +(8 rows) + +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2; + QUERY PLAN +------------------------------------------------------------ + Delete on rw_view1 rw_view1_1 + -> Subquery Scan on rw_view1 + Filter: ((rw_view1.a < 10) AND (rw_view1.a = 2)) + -> Limit + -> Bitmap Heap Scan on base_tbl + Recheck Cond: (a > 0) + -> Bitmap Index Scan on base_tbl_pkey + Index Cond: (a > 0) +(8 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to view rw_view1 +drop cascades to view rw_view2 +DROP FUNCTION rw_view1_trig_fn(); +-- update using whole row from view +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); +CREATE VIEW rw_view1 AS SELECT b AS bb, a AS aa FROM base_tbl; +CREATE FUNCTION rw_view1_aa(x rw_view1) + RETURNS int AS $$ SELECT x.aa $$ LANGUAGE sql; +UPDATE rw_view1 v SET bb='Updated row 2' WHERE rw_view1_aa(v)=2 + RETURNING rw_view1_aa(v), v.bb; + rw_view1_aa | bb +-------------+--------------- + 2 | Updated row 2 +(1 row) + +SELECT * FROM base_tbl; + a | b +----+--------------- + -2 | Row -2 + -1 | Row -1 + 0 | Row 0 + 1 | Row 1 + 2 | Updated row 2 +(5 rows) + +EXPLAIN (costs off) +UPDATE rw_view1 v SET bb='Updated row 2' WHERE rw_view1_aa(v)=2 + RETURNING rw_view1_aa(v), v.bb; + QUERY PLAN +-------------------------------------------------- + Update on base_tbl + -> Index Scan using base_tbl_pkey on base_tbl + Index Cond: (a = 2) +(3 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to view rw_view1 +drop cascades to function rw_view1_aa(rw_view1) +-- permissions checks +CREATE USER view_user1; +CREATE USER view_user2; +SET SESSION AUTHORIZATION view_user1; +CREATE TABLE base_tbl(a int, b text, c float); +INSERT INTO base_tbl VALUES (1, 'Row 1', 1.0); +CREATE VIEW rw_view1 AS SELECT b AS bb, c AS cc, a AS aa FROM base_tbl; +INSERT INTO rw_view1 VALUES ('Row 2', 2.0, 2); +GRANT SELECT ON base_tbl TO view_user2; +GRANT SELECT ON rw_view1 TO view_user2; +GRANT UPDATE (a,c) ON base_tbl TO view_user2; +GRANT UPDATE (bb,cc) ON rw_view1 TO view_user2; +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION view_user2; +CREATE VIEW rw_view2 AS SELECT b AS bb, c AS cc, a AS aa FROM base_tbl; +SELECT * FROM base_tbl; -- ok + a | b | c +---+-------+--- + 1 | Row 1 | 1 + 2 | Row 2 | 2 +(2 rows) + +SELECT * FROM rw_view1; -- ok + bb | cc | aa +-------+----+---- + Row 1 | 1 | 1 + Row 2 | 2 | 2 +(2 rows) + +SELECT * FROM rw_view2; -- ok + bb | cc | aa +-------+----+---- + Row 1 | 1 | 1 + Row 2 | 2 | 2 +(2 rows) + +INSERT INTO base_tbl VALUES (3, 'Row 3', 3.0); -- not allowed +ERROR: permission denied for relation base_tbl +INSERT INTO rw_view1 VALUES ('Row 3', 3.0, 3); -- not allowed +ERROR: permission denied for relation rw_view1 +INSERT INTO rw_view2 VALUES ('Row 3', 3.0, 3); -- not allowed +ERROR: permission denied for relation base_tbl +UPDATE base_tbl SET a=a, c=c; -- ok +UPDATE base_tbl SET b=b; -- not allowed +ERROR: permission denied for relation base_tbl +UPDATE rw_view1 SET bb=bb, cc=cc; -- ok +UPDATE rw_view1 SET aa=aa; -- not allowed +ERROR: permission denied for relation rw_view1 +UPDATE rw_view2 SET aa=aa, cc=cc; -- ok +UPDATE rw_view2 SET bb=bb; -- not allowed +ERROR: permission denied for relation base_tbl +DELETE FROM base_tbl; -- not allowed +ERROR: permission denied for relation base_tbl +DELETE FROM rw_view1; -- not allowed +ERROR: permission denied for relation rw_view1 +DELETE FROM rw_view2; -- not allowed +ERROR: permission denied for relation base_tbl +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION view_user1; +GRANT INSERT, DELETE ON base_tbl TO view_user2; +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION view_user2; +INSERT INTO base_tbl VALUES (3, 'Row 3', 3.0); -- ok +INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- not allowed +ERROR: permission denied for relation rw_view1 +INSERT INTO rw_view2 VALUES ('Row 4', 4.0, 4); -- ok +DELETE FROM base_tbl WHERE a=1; -- ok +DELETE FROM rw_view1 WHERE aa=2; -- not allowed +ERROR: permission denied for relation rw_view1 +DELETE FROM rw_view2 WHERE aa=2; -- ok +SELECT * FROM base_tbl; + a | b | c +---+-------+--- + 3 | Row 3 | 3 + 4 | Row 4 | 4 +(2 rows) + +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION view_user1; +REVOKE INSERT, DELETE ON base_tbl FROM view_user2; +GRANT INSERT, DELETE ON rw_view1 TO view_user2; +RESET SESSION AUTHORIZATION; +SET SESSION AUTHORIZATION view_user2; +INSERT INTO base_tbl VALUES (5, 'Row 5', 5.0); -- not allowed +ERROR: permission denied for relation base_tbl +INSERT INTO rw_view1 VALUES ('Row 5', 5.0, 5); -- ok +INSERT INTO rw_view2 VALUES ('Row 6', 6.0, 6); -- not allowed +ERROR: permission denied for relation base_tbl +DELETE FROM base_tbl WHERE a=3; -- not allowed +ERROR: permission denied for relation base_tbl +DELETE FROM rw_view1 WHERE aa=3; -- ok +DELETE FROM rw_view2 WHERE aa=4; -- not allowed +ERROR: permission denied for relation base_tbl +SELECT * FROM base_tbl; + a | b | c +---+-------+--- + 4 | Row 4 | 4 + 5 | Row 5 | 5 +(2 rows) + +RESET SESSION AUTHORIZATION; +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to view rw_view1 +drop cascades to view rw_view2 +DROP USER view_user1; +DROP USER view_user2; +-- column defaults +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified', c serial); +INSERT INTO base_tbl VALUES (1, 'Row 1'); +INSERT INTO base_tbl VALUES (2, 'Row 2'); +INSERT INTO base_tbl VALUES (3); +CREATE VIEW rw_view1 AS SELECT a AS aa, b AS bb FROM base_tbl; +ALTER VIEW rw_view1 ALTER COLUMN bb SET DEFAULT 'View default'; +INSERT INTO rw_view1 VALUES (4, 'Row 4'); +INSERT INTO rw_view1 (aa) VALUES (5); +SELECT * FROM base_tbl; + a | b | c +---+--------------+--- + 1 | Row 1 | 1 + 2 | Row 2 | 2 + 3 | Unspecified | 3 + 4 | Row 4 | 4 + 5 | View default | 5 +(5 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to view rw_view1 +-- Table having triggers +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl VALUES (1, 'Row 1'); +INSERT INTO base_tbl VALUES (2, 'Row 2'); +CREATE FUNCTION rw_view1_trig_fn() +RETURNS trigger AS +$$ +BEGIN + IF TG_OP = 'INSERT' THEN + UPDATE base_tbl SET b=NEW.b WHERE a=1; + RETURN NULL; + END IF; + RETURN NULL; +END; +$$ +LANGUAGE plpgsql; +CREATE TRIGGER rw_view1_ins_trig AFTER INSERT ON base_tbl + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); +CREATE VIEW rw_view1 AS SELECT a AS aa, b AS bb FROM base_tbl; +INSERT INTO rw_view1 VALUES (3, 'Row 3'); +select * from base_tbl; + a | b +---+------- + 2 | Row 2 + 3 | Row 3 + 1 | Row 3 +(3 rows) + +DROP VIEW rw_view1; +DROP TRIGGER rw_view1_ins_trig on base_tbl; +DROP FUNCTION rw_view1_trig_fn(); +DROP TABLE base_tbl; +-- view with ORDER BY +CREATE TABLE base_tbl (a int, b int); +INSERT INTO base_tbl VALUES (1,2), (4,5), (3,-3); +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl ORDER BY a+b; +SELECT * FROM rw_view1; + a | b +---+---- + 3 | -3 + 1 | 2 + 4 | 5 +(3 rows) + +INSERT INTO rw_view1 VALUES (7,-8); +SELECT * FROM rw_view1; + a | b +---+---- + 7 | -8 + 3 | -3 + 1 | 2 + 4 | 5 +(4 rows) + +EXPLAIN (verbose, costs off) UPDATE rw_view1 SET b = b + 1 RETURNING *; + QUERY PLAN +------------------------------------------------------------- + Update on public.base_tbl + Output: base_tbl.a, base_tbl.b + -> Seq Scan on public.base_tbl + Output: base_tbl.a, (base_tbl.b + 1), base_tbl.ctid +(4 rows) + +UPDATE rw_view1 SET b = b + 1 RETURNING *; + a | b +---+---- + 1 | 3 + 4 | 6 + 3 | -2 + 7 | -7 +(4 rows) + +SELECT * FROM rw_view1; + a | b +---+---- + 7 | -7 + 3 | -2 + 1 | 3 + 4 | 6 +(4 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to view rw_view1 +-- multiple array-column updates +CREATE TABLE base_tbl (a int, arr int[]); +INSERT INTO base_tbl VALUES (1,ARRAY[2]), (3,ARRAY[4]); +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl; +UPDATE rw_view1 SET arr[1] = 42, arr[2] = 77 WHERE a = 3; +SELECT * FROM rw_view1; + a | arr +---+--------- + 1 | {2} + 3 | {42,77} +(2 rows) + +DROP TABLE base_tbl CASCADE; +NOTICE: drop cascades to view rw_view1 diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index 663bf8ac56bd1..bdcf3a6a55919 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -59,7 +59,7 @@ test: create_index create_view # ---------- # Another group of parallel tests # ---------- -test: create_aggregate create_function_3 create_cast constraints triggers inherit create_table_like typed_table vacuum drop_if_exists +test: create_aggregate create_function_3 create_cast constraints triggers inherit create_table_like typed_table vacuum drop_if_exists updatable_views # ---------- # sanity_check does a vacuum, affecting the sort order of SELECT * diff --git a/src/test/regress/serial_schedule b/src/test/regress/serial_schedule index be789e3f44252..c7c2ed0f6a0c4 100644 --- a/src/test/regress/serial_schedule +++ b/src/test/regress/serial_schedule @@ -67,6 +67,7 @@ test: create_table_like test: typed_table test: vacuum test: drop_if_exists +test: updatable_views test: sanity_check test: errors test: select diff --git a/src/test/regress/sql/triggers.sql b/src/test/regress/sql/triggers.sql index 78c5407560a06..0ea2c314dee49 100644 --- a/src/test/regress/sql/triggers.sql +++ b/src/test/regress/sql/triggers.sql @@ -611,13 +611,6 @@ DROP TABLE min_updates_test_oids; CREATE VIEW main_view AS SELECT a, b FROM main_table; --- Updates should fail without rules or triggers -INSERT INTO main_view VALUES (1,2); -UPDATE main_view SET b = 20 WHERE a = 50; -DELETE FROM main_view WHERE a = 50; --- Should fail even when there are no matching rows -DELETE FROM main_view WHERE a = 51; - -- VIEW trigger function CREATE OR REPLACE FUNCTION view_trigger() RETURNS trigger LANGUAGE plpgsql AS $$ diff --git a/src/test/regress/sql/updatable_views.sql b/src/test/regress/sql/updatable_views.sql new file mode 100644 index 0000000000000..49dfedd3a6bc7 --- /dev/null +++ b/src/test/regress/sql/updatable_views.sql @@ -0,0 +1,511 @@ +-- +-- UPDATABLE VIEWS +-- + +-- check that non-updatable views are rejected with useful error messages + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW ro_view1 AS SELECT DISTINCT a, b FROM base_tbl; -- DISTINCT not supported +CREATE VIEW ro_view2 AS SELECT a, b FROM base_tbl GROUP BY a, b; -- GROUP BY not supported +CREATE VIEW ro_view3 AS SELECT 1 FROM base_tbl HAVING max(a) > 0; -- HAVING not supported +CREATE VIEW ro_view4 AS SELECT count(*) FROM base_tbl; -- Aggregate functions not supported +CREATE VIEW ro_view5 AS SELECT a, rank() OVER() FROM base_tbl; -- Window functions not supported +CREATE VIEW ro_view6 AS SELECT a, b FROM base_tbl UNION SELECT -a, b FROM base_tbl; -- Set ops not supported +CREATE VIEW ro_view7 AS WITH t AS (SELECT a, b FROM base_tbl) SELECT * FROM t; -- WITH not supported +CREATE VIEW ro_view8 AS SELECT a, b FROM base_tbl ORDER BY a OFFSET 1; -- OFFSET not supported +CREATE VIEW ro_view9 AS SELECT a, b FROM base_tbl ORDER BY a LIMIT 1; -- LIMIT not supported +CREATE VIEW ro_view10 AS SELECT 1 AS a; -- No base relations +CREATE VIEW ro_view11 AS SELECT b1.a, b2.b FROM base_tbl b1, base_tbl b2; -- Multiple base relations +CREATE VIEW ro_view12 AS SELECT * FROM generate_series(1, 10) AS g(a); -- SRF in rangetable +CREATE VIEW ro_view13 AS SELECT a, b FROM (SELECT * FROM base_tbl) AS t; -- Subselect in rangetable +CREATE VIEW ro_view14 AS SELECT ctid FROM base_tbl; -- System columns not supported +CREATE VIEW ro_view15 AS SELECT a, upper(b) FROM base_tbl; -- Expression/function in targetlist +CREATE VIEW ro_view16 AS SELECT a, b, a AS aa FROM base_tbl; -- Repeated column +CREATE VIEW ro_view17 AS SELECT * FROM ro_view1; -- Base relation not updatable +CREATE VIEW ro_view18 WITH (security_barrier = true) + AS SELECT * FROM base_tbl; -- Security barrier views not updatable +CREATE VIEW ro_view19 AS SELECT * FROM (VALUES(1)) AS tmp(a); -- VALUES in rangetable +CREATE SEQUENCE seq; +CREATE VIEW ro_view20 AS SELECT * FROM seq; -- View based on a sequence + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'ro_view%' + ORDER BY table_name, ordinal_position; + +DELETE FROM ro_view1; +DELETE FROM ro_view2; +DELETE FROM ro_view3; +DELETE FROM ro_view4; +DELETE FROM ro_view5; +DELETE FROM ro_view6; +UPDATE ro_view7 SET a=a+1; +UPDATE ro_view8 SET a=a+1; +UPDATE ro_view9 SET a=a+1; +UPDATE ro_view10 SET a=a+1; +UPDATE ro_view11 SET a=a+1; +UPDATE ro_view12 SET a=a+1; +INSERT INTO ro_view13 VALUES (3, 'Row 3'); +INSERT INTO ro_view14 VALUES (null); +INSERT INTO ro_view15 VALUES (3, 'ROW 3'); +INSERT INTO ro_view16 VALUES (3, 'Row 3', 3); +INSERT INTO ro_view17 VALUES (3, 'ROW 3'); +INSERT INTO ro_view18 VALUES (3, 'ROW 3'); +DELETE FROM ro_view19; +UPDATE ro_view20 SET max_value=1000; + +DROP TABLE base_tbl CASCADE; +DROP VIEW ro_view10, ro_view12, ro_view19; +DROP SEQUENCE seq CASCADE; + +-- simple updatable view + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name = 'rw_view1'; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name = 'rw_view1'; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name = 'rw_view1' + ORDER BY ordinal_position; + +INSERT INTO rw_view1 VALUES (3, 'Row 3'); +INSERT INTO rw_view1 (a) VALUES (4); +UPDATE rw_view1 SET a=5 WHERE a=4; +DELETE FROM rw_view1 WHERE b='Row 2'; +SELECT * FROM base_tbl; + +EXPLAIN (costs off) UPDATE rw_view1 SET a=6 WHERE a=5; +EXPLAIN (costs off) DELETE FROM rw_view1 WHERE a=5; + +DROP TABLE base_tbl CASCADE; + +-- view on top of view + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW rw_view1 AS SELECT b AS bb, a AS aa FROM base_tbl WHERE a>0; +CREATE VIEW rw_view2 AS SELECT aa AS aaa, bb AS bbb FROM rw_view1 WHERE aa<10; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name = 'rw_view2'; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name = 'rw_view2'; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name = 'rw_view2' + ORDER BY ordinal_position; + +INSERT INTO rw_view2 VALUES (3, 'Row 3'); +INSERT INTO rw_view2 (aaa) VALUES (4); +SELECT * FROM rw_view2; +UPDATE rw_view2 SET bbb='Row 4' WHERE aaa=4; +DELETE FROM rw_view2 WHERE aaa=2; +SELECT * FROM rw_view2; + +EXPLAIN (costs off) UPDATE rw_view2 SET aaa=5 WHERE aaa=4; +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE aaa=4; + +DROP TABLE base_tbl CASCADE; + +-- view on top of view with rules + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0 OFFSET 0; -- not updatable without rules/triggers +CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a<10; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE RULE rw_view1_ins_rule AS ON INSERT TO rw_view1 + DO INSTEAD INSERT INTO base_tbl VALUES (NEW.a, NEW.b) RETURNING *; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE RULE rw_view1_upd_rule AS ON UPDATE TO rw_view1 + DO INSTEAD UPDATE base_tbl SET b=NEW.b WHERE a=OLD.a RETURNING NEW.*; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE RULE rw_view1_del_rule AS ON DELETE TO rw_view1 + DO INSTEAD DELETE FROM base_tbl WHERE a=OLD.a RETURNING OLD.*; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +INSERT INTO rw_view2 VALUES (3, 'Row 3') RETURNING *; +UPDATE rw_view2 SET b='Row three' WHERE a=3 RETURNING *; +SELECT * FROM rw_view2; +DELETE FROM rw_view2 WHERE a=3 RETURNING *; +SELECT * FROM rw_view2; + +EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2; +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2; + +DROP TABLE base_tbl CASCADE; + +-- view on top of view with triggers + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl WHERE a>0 OFFSET 0; -- not updatable without rules/triggers +CREATE VIEW rw_view2 AS SELECT * FROM rw_view1 WHERE a<10; + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE FUNCTION rw_view1_trig_fn() +RETURNS trigger AS +$$ +BEGIN + IF TG_OP = 'INSERT' THEN + INSERT INTO base_tbl VALUES (NEW.a, NEW.b); + RETURN NEW; + ELSIF TG_OP = 'UPDATE' THEN + UPDATE base_tbl SET b=NEW.b WHERE a=OLD.a; + RETURN NEW; + ELSIF TG_OP = 'DELETE' THEN + DELETE FROM base_tbl WHERE a=OLD.a; + RETURN OLD; + END IF; +END; +$$ +LANGUAGE plpgsql; + +CREATE TRIGGER rw_view1_ins_trig INSTEAD OF INSERT ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE TRIGGER rw_view1_upd_trig INSTEAD OF UPDATE ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +CREATE TRIGGER rw_view1_del_trig INSTEAD OF DELETE ON rw_view1 + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); + +SELECT table_name, is_insertable_into + FROM information_schema.tables + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, is_updatable, is_insertable_into, + is_trigger_updatable, is_trigger_deletable, + is_trigger_insertable_into + FROM information_schema.views + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name; + +SELECT table_name, column_name, is_updatable + FROM information_schema.columns + WHERE table_name LIKE 'rw_view%' + ORDER BY table_name, ordinal_position; + +INSERT INTO rw_view2 VALUES (3, 'Row 3') RETURNING *; +UPDATE rw_view2 SET b='Row three' WHERE a=3 RETURNING *; +SELECT * FROM rw_view2; +DELETE FROM rw_view2 WHERE a=3 RETURNING *; +SELECT * FROM rw_view2; + +EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2; +EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2; + +DROP TABLE base_tbl CASCADE; +DROP FUNCTION rw_view1_trig_fn(); + +-- update using whole row from view + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl SELECT i, 'Row ' || i FROM generate_series(-2, 2) g(i); + +CREATE VIEW rw_view1 AS SELECT b AS bb, a AS aa FROM base_tbl; + +CREATE FUNCTION rw_view1_aa(x rw_view1) + RETURNS int AS $$ SELECT x.aa $$ LANGUAGE sql; + +UPDATE rw_view1 v SET bb='Updated row 2' WHERE rw_view1_aa(v)=2 + RETURNING rw_view1_aa(v), v.bb; +SELECT * FROM base_tbl; + +EXPLAIN (costs off) +UPDATE rw_view1 v SET bb='Updated row 2' WHERE rw_view1_aa(v)=2 + RETURNING rw_view1_aa(v), v.bb; + +DROP TABLE base_tbl CASCADE; + +-- permissions checks + +CREATE USER view_user1; +CREATE USER view_user2; + +SET SESSION AUTHORIZATION view_user1; +CREATE TABLE base_tbl(a int, b text, c float); +INSERT INTO base_tbl VALUES (1, 'Row 1', 1.0); +CREATE VIEW rw_view1 AS SELECT b AS bb, c AS cc, a AS aa FROM base_tbl; +INSERT INTO rw_view1 VALUES ('Row 2', 2.0, 2); + +GRANT SELECT ON base_tbl TO view_user2; +GRANT SELECT ON rw_view1 TO view_user2; +GRANT UPDATE (a,c) ON base_tbl TO view_user2; +GRANT UPDATE (bb,cc) ON rw_view1 TO view_user2; +RESET SESSION AUTHORIZATION; + +SET SESSION AUTHORIZATION view_user2; +CREATE VIEW rw_view2 AS SELECT b AS bb, c AS cc, a AS aa FROM base_tbl; +SELECT * FROM base_tbl; -- ok +SELECT * FROM rw_view1; -- ok +SELECT * FROM rw_view2; -- ok + +INSERT INTO base_tbl VALUES (3, 'Row 3', 3.0); -- not allowed +INSERT INTO rw_view1 VALUES ('Row 3', 3.0, 3); -- not allowed +INSERT INTO rw_view2 VALUES ('Row 3', 3.0, 3); -- not allowed + +UPDATE base_tbl SET a=a, c=c; -- ok +UPDATE base_tbl SET b=b; -- not allowed +UPDATE rw_view1 SET bb=bb, cc=cc; -- ok +UPDATE rw_view1 SET aa=aa; -- not allowed +UPDATE rw_view2 SET aa=aa, cc=cc; -- ok +UPDATE rw_view2 SET bb=bb; -- not allowed + +DELETE FROM base_tbl; -- not allowed +DELETE FROM rw_view1; -- not allowed +DELETE FROM rw_view2; -- not allowed +RESET SESSION AUTHORIZATION; + +SET SESSION AUTHORIZATION view_user1; +GRANT INSERT, DELETE ON base_tbl TO view_user2; +RESET SESSION AUTHORIZATION; + +SET SESSION AUTHORIZATION view_user2; +INSERT INTO base_tbl VALUES (3, 'Row 3', 3.0); -- ok +INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- not allowed +INSERT INTO rw_view2 VALUES ('Row 4', 4.0, 4); -- ok +DELETE FROM base_tbl WHERE a=1; -- ok +DELETE FROM rw_view1 WHERE aa=2; -- not allowed +DELETE FROM rw_view2 WHERE aa=2; -- ok +SELECT * FROM base_tbl; +RESET SESSION AUTHORIZATION; + +SET SESSION AUTHORIZATION view_user1; +REVOKE INSERT, DELETE ON base_tbl FROM view_user2; +GRANT INSERT, DELETE ON rw_view1 TO view_user2; +RESET SESSION AUTHORIZATION; + +SET SESSION AUTHORIZATION view_user2; +INSERT INTO base_tbl VALUES (5, 'Row 5', 5.0); -- not allowed +INSERT INTO rw_view1 VALUES ('Row 5', 5.0, 5); -- ok +INSERT INTO rw_view2 VALUES ('Row 6', 6.0, 6); -- not allowed +DELETE FROM base_tbl WHERE a=3; -- not allowed +DELETE FROM rw_view1 WHERE aa=3; -- ok +DELETE FROM rw_view2 WHERE aa=4; -- not allowed +SELECT * FROM base_tbl; +RESET SESSION AUTHORIZATION; + +DROP TABLE base_tbl CASCADE; + +DROP USER view_user1; +DROP USER view_user2; + +-- column defaults + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified', c serial); +INSERT INTO base_tbl VALUES (1, 'Row 1'); +INSERT INTO base_tbl VALUES (2, 'Row 2'); +INSERT INTO base_tbl VALUES (3); + +CREATE VIEW rw_view1 AS SELECT a AS aa, b AS bb FROM base_tbl; +ALTER VIEW rw_view1 ALTER COLUMN bb SET DEFAULT 'View default'; + +INSERT INTO rw_view1 VALUES (4, 'Row 4'); +INSERT INTO rw_view1 (aa) VALUES (5); + +SELECT * FROM base_tbl; + +DROP TABLE base_tbl CASCADE; + +-- Table having triggers + +CREATE TABLE base_tbl (a int PRIMARY KEY, b text DEFAULT 'Unspecified'); +INSERT INTO base_tbl VALUES (1, 'Row 1'); +INSERT INTO base_tbl VALUES (2, 'Row 2'); + +CREATE FUNCTION rw_view1_trig_fn() +RETURNS trigger AS +$$ +BEGIN + IF TG_OP = 'INSERT' THEN + UPDATE base_tbl SET b=NEW.b WHERE a=1; + RETURN NULL; + END IF; + RETURN NULL; +END; +$$ +LANGUAGE plpgsql; + +CREATE TRIGGER rw_view1_ins_trig AFTER INSERT ON base_tbl + FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn(); + +CREATE VIEW rw_view1 AS SELECT a AS aa, b AS bb FROM base_tbl; + +INSERT INTO rw_view1 VALUES (3, 'Row 3'); +select * from base_tbl; + +DROP VIEW rw_view1; +DROP TRIGGER rw_view1_ins_trig on base_tbl; +DROP FUNCTION rw_view1_trig_fn(); +DROP TABLE base_tbl; + +-- view with ORDER BY + +CREATE TABLE base_tbl (a int, b int); +INSERT INTO base_tbl VALUES (1,2), (4,5), (3,-3); + +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl ORDER BY a+b; + +SELECT * FROM rw_view1; + +INSERT INTO rw_view1 VALUES (7,-8); +SELECT * FROM rw_view1; + +EXPLAIN (verbose, costs off) UPDATE rw_view1 SET b = b + 1 RETURNING *; +UPDATE rw_view1 SET b = b + 1 RETURNING *; +SELECT * FROM rw_view1; + +DROP TABLE base_tbl CASCADE; + +-- multiple array-column updates + +CREATE TABLE base_tbl (a int, arr int[]); +INSERT INTO base_tbl VALUES (1,ARRAY[2]), (3,ARRAY[4]); + +CREATE VIEW rw_view1 AS SELECT * FROM base_tbl; + +UPDATE rw_view1 SET arr[1] = 42, arr[2] = 77 WHERE a = 3; + +SELECT * FROM rw_view1; + +DROP TABLE base_tbl CASCADE;