<listitem>
<para>
This option controls the behavior of automatically updatable views. When
- this option is specified, <command>INSERT</command> and <command>UPDATE</command>
+ this option is specified, <command>INSERT</command>,
+ <command>UPDATE</command>, and <command>MERGE</command>
commands on the view will be checked to ensure that new rows satisfy the
view-defining condition (that is, the new rows are checked to ensure that
they are visible through the view). If they are not, the update will be
rejected. If the <literal>CHECK OPTION</literal> is not specified,
- <command>INSERT</command> and <command>UPDATE</command> commands on the view are
+ <command>INSERT</command>, <command>UPDATE</command>, and
+ <command>MERGE</command> commands on the view are
allowed to create rows that are not visible through the view. The
following check options are supported:
<command>INSERT</command> or <command>UPDATE</command> command to be rewritten, then
all check options will be ignored in the rewritten query, including any
checks from automatically updatable views defined on top of the relation
- with the <literal>INSTEAD</literal> rule.
+ with the <literal>INSTEAD</literal> rule. <command>MERGE</command> is not
+ supported if the view or any of its base relations have rules.
</para>
</listitem>
</varlistentry>
<para>
Simple views are automatically updatable: the system will allow
- <command>INSERT</command>, <command>UPDATE</command> and <command>DELETE</command> statements
+ <command>INSERT</command>, <command>UPDATE</command>,
+ <command>DELETE</command>, and <command>MERGE</command> 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:
An automatically updatable view may contain a mix of updatable and
non-updatable columns. A column is updatable if it is a simple reference
to an updatable column of the underlying base relation; otherwise the
- column is read-only, and an error will be raised if an <command>INSERT</command>
- or <command>UPDATE</command> statement attempts to assign a value to it.
+ column is read-only, and an error will be raised if an
+ <command>INSERT</command>, <command>UPDATE</command>, or
+ <command>MERGE</command> statement attempts to assign a value to it.
</para>
<para>
If the view is automatically updatable the system will convert any
- <command>INSERT</command>, <command>UPDATE</command> or <command>DELETE</command> statement
+ <command>INSERT</command>, <command>UPDATE</command>,
+ <command>DELETE</command>, or <command>MERGE</command> statement
on the view into the corresponding statement on the underlying base
relation. <command>INSERT</command> statements that have an <literal>ON
CONFLICT UPDATE</literal> clause are fully supported.
<para>
If an automatically updatable view contains a <literal>WHERE</literal>
condition, the condition restricts which rows of the base relation are
- available to be modified by <command>UPDATE</command> and <command>DELETE</command>
- statements on the view. However, an <command>UPDATE</command> is allowed to
+ available to be modified by <command>UPDATE</command>,
+ <command>DELETE</command>, and <command>MERGE</command>
+ statements on the view. However, an <command>UPDATE</command> or
+ <command>MERGE</command> is allowed to
change a row so that it no longer satisfies the <literal>WHERE</literal>
condition, and thus is no longer visible through the view. Similarly,
- an <command>INSERT</command> command can potentially insert base-relation rows
+ an <command>INSERT</command> or <command>MERGE</command> command can
+ potentially insert base-relation rows
that do not satisfy the <literal>WHERE</literal> condition and thus are not
visible through the view (<literal>ON CONFLICT UPDATE</literal> may
similarly affect an existing row not visible through the view).
The <literal>CHECK OPTION</literal> may be used to prevent
- <command>INSERT</command> and <command>UPDATE</command> commands from creating
- such rows that are not visible through the view.
+ <command>INSERT</command>, <command>UPDATE</command>, and
+ <command>MERGE</command> commands from creating such rows that are not
+ visible through the view.
</para>
<para>
<para>
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
+ read-only by default: the system will not allow an <command>INSERT</command>,
+ <command>UPDATE</command>, <command>DELETE</command>, or <command>MERGE</command>
+ on the view. You can get the effect of an updatable view by
creating <literal>INSTEAD OF</literal> triggers on the view, which must
convert attempted inserts, etc. on the view into appropriate actions
on other tables. For more information see <xref
linkend="sql-createtrigger"/>. Another possibility is to create rules
(see <xref linkend="sql-createrule"/>), but in practice triggers are
- easier to understand and use correctly.
+ easier to understand and use correctly. Also note that <command>MERGE</command>
+ is not supported on relations with rules.
</para>
<para>
<term><replaceable class="parameter">target_table_name</replaceable></term>
<listitem>
<para>
- The name (optionally schema-qualified) of the target table to merge into.
- If <literal>ONLY</literal> is specified before the table name, matching
- rows are updated or deleted in the named table only. If
+ The name (optionally schema-qualified) of the target table or view to
+ merge into. If <literal>ONLY</literal> is specified before a table
+ name, matching rows are updated or deleted in the named table only. If
<literal>ONLY</literal> is not specified, matching rows are also updated
or deleted in any tables inheriting from the named table. Optionally,
<literal>*</literal> can be specified after the table name to explicitly
<literal>ONLY</literal> keyword and <literal>*</literal> option do not
affect insert actions, which always insert into the named table only.
</para>
+
+ <para>
+ If <replaceable class="parameter">target_table_name</replaceable> is a
+ view, it must either be automatically updatable with no
+ <literal>INSTEAD OF</literal> triggers, or it must have
+ <literal>INSTEAD OF</literal> triggers for every type of action
+ (<literal>INSERT</literal>, <literal>UPDATE</literal>, and
+ <literal>DELETE</literal>) specified in the <literal>WHEN</literal>
+ clauses. Views with rules are not supported.
+ </para>
</listitem>
</varlistentry>
the action's event type.
</para>
</listitem>
- </orderedlist></para>
+ </orderedlist>
+ If the target relation is a view with <literal>INSTEAD OF ROW</literal>
+ triggers for the action's event type, they are used to perform the
+ action instead.
+ </para>
</listitem>
</orderedlist></para>
</listitem>
<para>
What happens if a view is named as the target relation for an
- <command>INSERT</command>, <command>UPDATE</command>, or
- <command>DELETE</command>? Doing the substitutions
- described above would give a query tree in which the result
+ <command>INSERT</command>, <command>UPDATE</command>,
+ <command>DELETE</command>, or <command>MERGE</command>? 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. There are several ways in which <productname>PostgreSQL</productname>
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 <command>INSERT</command>,
- <command>UPDATE</command>, or <command>DELETE</command> is applied to
- the base relation in the appropriate way. Views that are
- <quote>simple enough</quote> for this are called <firstterm>automatically
- updatable</firstterm>. For detailed information on the kinds of view that can
- be automatically updated, see <xref linkend="sql-createview"/>.
+ <command>UPDATE</command>, <command>DELETE</command>, or
+ <command>MERGE</command> is applied to the base relation in the
+ appropriate way. Views that are <quote>simple enough</quote> for this
+ are called <firstterm>automatically updatable</firstterm>. For detailed
+ information on the kinds of view that can be automatically updated, see
+ <xref linkend="sql-createview"/>.
</para>
<para>
Rewriting works slightly differently
in this case. For <command>INSERT</command>, the rewriter does
nothing at all with the view, leaving it as the result relation
- for the query. For <command>UPDATE</command> and
- <command>DELETE</command>, it's still necessary to expand the
+ for the query. For <command>UPDATE</command>, <command>DELETE</command>,
+ and <command>MERGE</command>, it's still necessary to expand the
view query to produce the <quote>old</quote> rows that the command will
- attempt to update or delete. So the view is expanded as normal,
+ attempt to update, delete, or merge. So the view is expanded as normal,
but another unexpanded range-table entry is added to the query
to represent the view in its capacity as the result relation.
</para>
list to identify the physical locations of the rows to be updated.
This does not work if the result relation is a view, because a view
does not have any <acronym>CTID</acronym>, since its rows do not have
- actual physical locations. Instead, for an <command>UPDATE</command>
- or <command>DELETE</command> operation, a special <literal>wholerow</literal>
- entry is added to the target list, which expands to include all
- columns from the view. The executor uses this value to supply the
- <quote>old</quote> row to the <literal>INSTEAD OF</literal> trigger. It is
- up to the trigger to work out what to update based on the old and
- new row values.
+ actual physical locations. Instead, for an <command>UPDATE</command>,
+ <command>DELETE</command>, or <command>MERGE</command> operation, a
+ special <literal>wholerow</literal> entry is added to the target list,
+ which expands to include all columns from the view. The executor uses this
+ value to supply the <quote>old</quote> row to the
+ <literal>INSTEAD OF</literal> trigger. It is up to the trigger to work
+ out what to update based on the old and new row values.
</para>
<para>
<command>UPDATE</command>, and <command>DELETE</command> 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
- of <xref linkend="rules-update"/>.
+ of <xref linkend="rules-update"/>. Note that this will not work with
+ <command>MERGE</command>, which currently does not support rules.
</para>
<para>
ExecInitResultRelation(estate, resultRelInfo, 1);
/* Verify the named relation is a valid target for INSERT */
- CheckValidResultRel(resultRelInfo, CMD_INSERT);
+ CheckValidResultRel(resultRelInfo, CMD_INSERT, NIL);
ExecOpenIndices(resultRelInfo, false);
#include "miscadmin.h"
#include "parser/parse_relation.h"
#include "parser/parsetree.h"
+#include "rewrite/rewriteHandler.h"
#include "storage/bufmgr.h"
#include "storage/lmgr.h"
#include "tcop/utility.h"
* Generally the parser and/or planner should have noticed any such mistake
* already, but let's make sure.
*
+ * For MERGE, mergeActions is the list of actions that may be performed. The
+ * result relation is required to support every action, regardless of whether
+ * or not they are all executed.
+ *
* Note: when changing this function, you probably also need to look at
* CheckValidRowMarkRel.
*/
void
-CheckValidResultRel(ResultRelInfo *resultRelInfo, CmdType operation)
+CheckValidResultRel(ResultRelInfo *resultRelInfo, CmdType operation,
+ List *mergeActions)
{
Relation resultRel = resultRelInfo->ri_RelationDesc;
- TriggerDesc *trigDesc = resultRel->trigdesc;
FdwRoutine *fdwroutine;
switch (resultRel->rd_rel->relkind)
case RELKIND_VIEW:
/*
- * Okay only if there's a suitable INSTEAD OF trigger. Messages
- * here should match rewriteHandler.c's rewriteTargetView and
- * RewriteQuery, 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).
+ * Okay only if there's a suitable INSTEAD OF trigger. Otherwise,
+ * complain, but omit errdetail because we haven't got the
+ * information handy (and given that it really shouldn't happen,
+ * it's not worth great exertion to get).
*/
- switch (operation)
- {
- case CMD_INSERT:
- if (!trigDesc || !trigDesc->trig_insert_instead_row)
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot insert into view \"%s\"",
- RelationGetRelationName(resultRel)),
- errhint("To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.")));
- break;
- case CMD_UPDATE:
- if (!trigDesc || !trigDesc->trig_update_instead_row)
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot update view \"%s\"",
- RelationGetRelationName(resultRel)),
- errhint("To enable updating the view, provide an INSTEAD OF UPDATE trigger or an unconditional ON UPDATE DO INSTEAD rule.")));
- break;
- case CMD_DELETE:
- if (!trigDesc || !trigDesc->trig_delete_instead_row)
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot delete from view \"%s\"",
- RelationGetRelationName(resultRel)),
- errhint("To enable deleting from the view, provide an INSTEAD OF DELETE trigger or an unconditional ON DELETE DO INSTEAD rule.")));
- break;
- default:
- elog(ERROR, "unrecognized CmdType: %d", (int) operation);
- break;
- }
+ if (!view_has_instead_trigger(resultRel, operation, mergeActions))
+ error_view_not_updatable(resultRel, operation, mergeActions,
+ NULL);
break;
case RELKIND_MATVIEW:
if (!MatViewIncrementalMaintenanceIsEnabled())
if (rri)
{
/* Verify this ResultRelInfo allows INSERTs */
- CheckValidResultRel(rri, CMD_INSERT);
+ CheckValidResultRel(rri, CMD_INSERT, NIL);
/*
* Initialize information needed to insert this and
* partition-key becomes a DELETE+INSERT operation, so this check is still
* required when the operation is CMD_UPDATE.
*/
- CheckValidResultRel(leaf_part_rri, CMD_INSERT);
+ CheckValidResultRel(leaf_part_rri, CMD_INSERT, NIL);
/*
* Open partition indices. The user may have asked to check for conflicts
static TupleTableSlot *ExecMerge(ModifyTableContext *context,
ResultRelInfo *resultRelInfo,
ItemPointer tupleid,
+ HeapTuple oldtuple,
bool canSetTag);
static void ExecInitMerge(ModifyTableState *mtstate, EState *estate);
static bool ExecMergeMatched(ModifyTableContext *context,
ResultRelInfo *resultRelInfo,
ItemPointer tupleid,
+ HeapTuple oldtuple,
bool canSetTag);
static void ExecMergeNotMatched(ModifyTableContext *context,
ResultRelInfo *resultRelInfo,
*/
static TupleTableSlot *
ExecMerge(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
- ItemPointer tupleid, bool canSetTag)
+ ItemPointer tupleid, HeapTuple oldtuple, bool canSetTag)
{
bool matched;
/*-----
- * If we are dealing with a WHEN MATCHED case (tupleid is valid), we
- * execute the first action for which the additional WHEN MATCHED AND
+ * If we are dealing with a WHEN MATCHED case (tupleid or oldtuple is
+ * valid, depending on whether the result relation is a table or a view),
+ * we execute the first action for which the additional WHEN MATCHED AND
* quals pass. If an action without quals is found, that action is
* executed.
*
* from ExecMergeNotMatched to ExecMergeMatched, there is no risk of a
* livelock.
*/
- matched = tupleid != NULL;
+ matched = tupleid != NULL || oldtuple != NULL;
if (matched)
- matched = ExecMergeMatched(context, resultRelInfo, tupleid, canSetTag);
+ matched = ExecMergeMatched(context, resultRelInfo, tupleid, oldtuple,
+ canSetTag);
/*
* Either we were dealing with a NOT MATCHED tuple or ExecMergeMatched()
}
/*
- * Check and execute the first qualifying MATCHED action. The current target
- * tuple is identified by tupleid.
+ * Check and execute the first qualifying MATCHED action. If the target
+ * relation is a table, the current target tuple is identified by tupleid.
+ * Otherwise, if the target relation is a view, oldtuple is the current target
+ * tuple from the view.
*
* We start from the first WHEN MATCHED action and check if the WHEN quals
* pass, if any. If the WHEN quals for the first action do not pass, we
*/
static bool
ExecMergeMatched(ModifyTableContext *context, ResultRelInfo *resultRelInfo,
- ItemPointer tupleid, bool canSetTag)
+ ItemPointer tupleid, HeapTuple oldtuple, bool canSetTag)
{
ModifyTableState *mtstate = context->mtstate;
TupleTableSlot *newslot;
econtext->ecxt_innertuple = context->planSlot;
econtext->ecxt_outertuple = NULL;
+ /*
+ * This routine is only invoked for matched rows, so we should either have
+ * the tupleid of the target row, or an old tuple from the target wholerow
+ * junk attr.
+ */
+ Assert(tupleid != NULL || oldtuple != NULL);
+ if (oldtuple != NULL)
+ ExecForceStoreHeapTuple(oldtuple, resultRelInfo->ri_oldTupleSlot,
+ false);
+
lmerge_matched:
/*
- * This routine is only invoked for matched rows, and we must have found
- * the tupleid of the target row in that case; fetch that tuple.
+ * If passed a tupleid, use it to fetch the old target row.
*
* We use SnapshotAny for this because we might get called again after
* EvalPlanQual returns us a new tuple, which may not be visible to our
* MVCC snapshot.
*/
-
- if (!table_tuple_fetch_row_version(resultRelInfo->ri_RelationDesc,
- tupleid,
- SnapshotAny,
- resultRelInfo->ri_oldTupleSlot))
- elog(ERROR, "failed to fetch the target tuple");
+ if (tupleid != NULL)
+ {
+ if (!table_tuple_fetch_row_version(resultRelInfo->ri_RelationDesc,
+ tupleid,
+ SnapshotAny,
+ resultRelInfo->ri_oldTupleSlot))
+ elog(ERROR, "failed to fetch the target tuple");
+ }
foreach(l, resultRelInfo->ri_matchedMergeAction)
{
return true; /* "do nothing" */
break; /* concurrent update/delete */
}
- result = ExecUpdateAct(context, resultRelInfo, tupleid, NULL,
- newslot, canSetTag, &updateCxt);
- /*
- * As in ExecUpdate(), if ExecUpdateAct() reports that a
- * cross-partition update was done, then there's nothing else
- * for us to do --- the UPDATE has been turned into a DELETE
- * and an INSERT, and we must not perform any of the usual
- * post-update tasks.
- */
- if (updateCxt.crossPartUpdate)
+ /* INSTEAD OF ROW UPDATE Triggers */
+ if (resultRelInfo->ri_TrigDesc &&
+ resultRelInfo->ri_TrigDesc->trig_update_instead_row)
{
- mtstate->mt_merge_updated += 1;
- return true;
+ if (!ExecIRUpdateTriggers(estate, resultRelInfo,
+ oldtuple, newslot))
+ return true; /* "do nothing" */
+ }
+ else
+ {
+ result = ExecUpdateAct(context, resultRelInfo, tupleid,
+ NULL, newslot, canSetTag,
+ &updateCxt);
+
+ /*
+ * As in ExecUpdate(), if ExecUpdateAct() reports that a
+ * cross-partition update was done, then there's nothing
+ * else for us to do --- the UPDATE has been turned into a
+ * DELETE and an INSERT, and we must not perform any of
+ * the usual post-update tasks.
+ */
+ if (updateCxt.crossPartUpdate)
+ {
+ mtstate->mt_merge_updated += 1;
+ return true;
+ }
}
if (result == TM_Ok)
return true; /* "do nothing" */
break; /* concurrent update/delete */
}
- result = ExecDeleteAct(context, resultRelInfo, tupleid, false);
+
+ /* INSTEAD OF ROW DELETE Triggers */
+ if (resultRelInfo->ri_TrigDesc &&
+ resultRelInfo->ri_TrigDesc->trig_delete_instead_row)
+ {
+ if (!ExecIRDeleteTriggers(estate, resultRelInfo,
+ oldtuple))
+ return true; /* "do nothing" */
+ }
+ else
+ result = ExecDeleteAct(context, resultRelInfo, tupleid,
+ false);
+
if (result == TM_Ok)
{
ExecDeleteEpilogue(context, resultRelInfo, tupleid, NULL,
{
EvalPlanQualSetSlot(&node->mt_epqstate, context.planSlot);
- ExecMerge(&context, node->resultRelInfo, NULL, node->canSetTag);
+ ExecMerge(&context, node->resultRelInfo, NULL, NULL,
+ node->canSetTag);
continue; /* no RETURNING support yet */
}
{
EvalPlanQualSetSlot(&node->mt_epqstate, context.planSlot);
- ExecMerge(&context, node->resultRelInfo, NULL, node->canSetTag);
+ ExecMerge(&context, node->resultRelInfo, NULL, NULL,
+ node->canSetTag);
continue; /* no RETURNING support yet */
}
datum = ExecGetJunkAttribute(slot,
resultRelInfo->ri_RowIdAttNo,
&isNull);
- /* shouldn't ever get a null result... */
+
+ /*
+ * For commands other than MERGE, any tuples having a null row
+ * identifier are errors. For MERGE, we may need to handle
+ * them as WHEN NOT MATCHED clauses if any, so do that.
+ *
+ * Note that we use the node's toplevel resultRelInfo, not any
+ * specific partition's.
+ */
if (isNull)
+ {
+ if (operation == CMD_MERGE)
+ {
+ EvalPlanQualSetSlot(&node->mt_epqstate, context.planSlot);
+
+ ExecMerge(&context, node->resultRelInfo, NULL, NULL,
+ node->canSetTag);
+ continue; /* no RETURNING support yet */
+ }
+
elog(ERROR, "wholerow is NULL");
+ }
oldtupdata.t_data = DatumGetHeapTupleHeader(datum);
oldtupdata.t_len =
break;
case CMD_MERGE:
- slot = ExecMerge(&context, resultRelInfo, tupleid, node->canSetTag);
+ slot = ExecMerge(&context, resultRelInfo, tupleid, oldtuple,
+ node->canSetTag);
break;
default:
foreach(l, node->resultRelations)
{
Index resultRelation = lfirst_int(l);
+ List *mergeActions = NIL;
+
+ if (node->mergeActionLists)
+ mergeActions = list_nth(node->mergeActionLists, i);
if (resultRelInfo != mtstate->rootResultRelInfo)
{
/*
* Verify result relation is a valid target for the current operation
*/
- CheckValidResultRel(resultRelInfo, operation);
+ CheckValidResultRel(resultRelInfo, operation, mergeActions);
resultRelInfo++;
i++;
}
else
{
- /* No support for MERGE */
- Assert(operation != CMD_MERGE);
/* Other valid target relkinds must provide wholerow */
resultRelInfo->ri_RowIdAttNo =
ExecFindJunkAttributeInTlist(subplan->targetlist,
/*
* Create a JOIN between the target and the source relation.
+ *
+ * Here the target is identified by parse->mergeTargetRelation. For a
+ * regular table, this will equal parse->resultRelation, but for a
+ * trigger-updatable view, it will be the expanded view subquery that we
+ * need to pull data from.
*/
joinexpr = makeNode(JoinExpr);
joinexpr->jointype = jointype;
joinexpr->isNatural = false;
joinexpr->larg = (Node *) makeNode(RangeTblRef);
- ((RangeTblRef *) joinexpr->larg)->rtindex = parse->resultRelation;
+ ((RangeTblRef *) joinexpr->larg)->rtindex = parse->mergeTargetRelation;
joinexpr->rarg = linitial(parse->jointree->fromlist); /* original join */
joinexpr->usingClause = NIL;
joinexpr->join_using_alias = NULL;
/* Make the new join be the sole entry in the query's jointree */
parse->jointree->fromlist = list_make1(joinexpr);
parse->jointree->quals = NULL;
+
+ /*
+ * If necessary, mark parse->targetlist entries that refer to the target
+ * as nullable by the join. Normally the targetlist will be empty for a
+ * MERGE, but if the target is a trigger-updatable view, it will contain a
+ * whole-row Var referring to the expanded view query.
+ */
+ if (parse->targetList != NIL &&
+ (jointype == JOIN_RIGHT || jointype == JOIN_FULL))
+ parse->targetList = (List *)
+ add_nulling_relids((Node *) parse->targetList,
+ bms_make_singleton(parse->mergeTargetRelation),
+ bms_make_singleton(joinrti));
}
/*
Assert(commandType == CMD_UPDATE || commandType == CMD_DELETE || commandType == CMD_MERGE);
- if (commandType == CMD_MERGE ||
- relkind == RELKIND_RELATION ||
+ if (relkind == RELKIND_RELATION ||
relkind == RELKIND_MATVIEW ||
relkind == RELKIND_PARTITIONED_TABLE)
{
* Set up the MERGE target table. The target table is added to the
* namespace below and to joinlist in transform_MERGE_to_join, so don't do
* it here.
+ *
+ * Initially mergeTargetRelation is the same as resultRelation, so data is
+ * read from the table being updated. However, that might be changed by
+ * the rewriter, if the target is a trigger-updatable view, to allow
+ * target data to be read from the expanded view query while updating the
+ * original view relation.
*/
qry->resultRelation = setTargetTable(pstate, stmt->relation,
stmt->relation->inh,
false, targetPerms);
+ qry->mergeTargetRelation = qry->resultRelation;
- /*
- * MERGE is unsupported in various cases
- */
+ /* The target relation must be a table or a view */
if (pstate->p_target_relation->rd_rel->relkind != RELKIND_RELATION &&
- pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE)
+ pstate->p_target_relation->rd_rel->relkind != RELKIND_PARTITIONED_TABLE &&
+ pstate->p_target_relation->rd_rel->relkind != RELKIND_VIEW)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("cannot execute MERGE on relation \"%s\"",
RelationGetRelationName(pstate->p_target_relation)),
errdetail_relkind_not_supported(pstate->p_target_relation->rd_rel->relkind)));
- if (pstate->p_target_relation->rd_rules != NULL &&
- pstate->p_target_relation->rd_rules->numLocks > 0)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("cannot execute MERGE on relation \"%s\"",
- RelationGetRelationName(pstate->p_target_relation)),
- errdetail("MERGE is not supported for relations with rules.")));
/* Now transform the source relation to produce the source RTE. */
transformFromClause(pstate,
static void markQueryForLocking(Query *qry, Node *jtnode,
LockClauseStrength strength, LockWaitPolicy waitPolicy,
bool pushedDown);
-static List *matchLocks(CmdType event, RuleLock *rulelocks,
+static List *matchLocks(CmdType event, Relation relation,
int varno, Query *parsetree, bool *hasUpdate);
static Query *fireRIRrules(Query *parsetree, List *activeRIRs);
-static bool view_has_instead_trigger(Relation view, CmdType event);
static Bitmapset *adjust_view_column_set(Bitmapset *cols, List *targetlist);
*/
isAutoUpdatableView = false;
if (target_relation->rd_rel->relkind == RELKIND_VIEW &&
- !view_has_instead_trigger(target_relation, CMD_INSERT))
+ !view_has_instead_trigger(target_relation, CMD_INSERT, NIL))
{
List *locks;
bool hasUpdate;
ListCell *l;
/* Look for an unconditional DO INSTEAD rule */
- locks = matchLocks(CMD_INSERT, target_relation->rd_rules,
+ locks = matchLocks(CMD_INSERT, target_relation,
parsetree->resultRelation, parsetree, &hasUpdate);
found = false;
/*
* matchLocks -
- * match the list of locks and returns the matching rules
+ * match a relation's list of locks and returns the matching rules
*/
static List *
matchLocks(CmdType event,
- RuleLock *rulelocks,
+ Relation relation,
int varno,
Query *parsetree,
bool *hasUpdate)
{
+ RuleLock *rulelocks = relation->rd_rules;
List *matching_locks = NIL;
int nlocks;
int i;
if (rulelocks == NULL)
return NIL;
- /* No rule support for MERGE */
- if (parsetree->commandType == CMD_MERGE)
- return NIL;
-
if (parsetree->commandType != CMD_SELECT)
{
if (parsetree->resultRelation != varno)
/*
* Suppress ON INSERT/UPDATE/DELETE rules that are disabled or
- * configured to not fire during the current sessions replication
+ * configured to not fire during the current session's replication
* role. ON SELECT rules will always be applied in order to keep views
* working even in LOCAL or REPLICA role.
*/
oneLock->enabled == RULE_DISABLED)
continue;
}
+
+ /* Non-SELECT rules are not supported for MERGE */
+ if (parsetree->commandType == CMD_MERGE)
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot execute MERGE on relation \"%s\"",
+ RelationGetRelationName(relation)),
+ errdetail("MERGE is not supported for relations with rules."));
}
if (oneLock->event == event)
* For INSERT, we needn't do anything. The unmodified RTE will serve
* fine as the result relation.
*
- * For UPDATE/DELETE, we need to expand the view so as to have source
- * data for the operation. But we also need an unmodified RTE to
- * serve as the target. So, copy the RTE and add the copy to the
+ * For UPDATE/DELETE/MERGE, we need to expand the view so as to have
+ * source data for the operation. But we also need an unmodified RTE
+ * to serve as the target. So, copy the RTE and add the copy to the
* rangetable. Note that the copy does not get added to the jointree.
* Also note that there's a hack in fireRIRrules to avoid calling this
* function again when it arrives at the copied RTE.
if (parsetree->commandType == CMD_INSERT)
return parsetree;
else if (parsetree->commandType == CMD_UPDATE ||
- parsetree->commandType == CMD_DELETE)
+ parsetree->commandType == CMD_DELETE ||
+ parsetree->commandType == CMD_MERGE)
{
RangeTblEntry *newrte;
Var *var;
newrte = copyObject(rte);
parsetree->rtable = lappend(parsetree->rtable, newrte);
parsetree->resultRelation = list_length(parsetree->rtable);
+ /* parsetree->mergeTargetRelation unchanged (use expanded view) */
/*
* For the most part, Vars referencing the view should remain as
* If it does, we don't want to treat it as auto-updatable. This test can't
* be folded into view_query_is_auto_updatable because it's not an error
* condition.
+ *
+ * For MERGE, this will return true if there is an INSTEAD OF trigger for
+ * every action in mergeActionList, and false if there are any actions that
+ * lack an INSTEAD OF trigger. If there are no data-modifying MERGE actions
+ * (only DO NOTHING actions), true is returned so that the view is treated
+ * as trigger-updatable, rather than erroring out if it's not auto-updatable.
*/
-static bool
-view_has_instead_trigger(Relation view, CmdType event)
+bool
+view_has_instead_trigger(Relation view, CmdType event, List *mergeActionList)
{
TriggerDesc *trigDesc = view->trigdesc;
if (trigDesc && trigDesc->trig_delete_instead_row)
return true;
break;
+ case CMD_MERGE:
+ foreach_node(MergeAction, action, mergeActionList)
+ {
+ switch (action->commandType)
+ {
+ case CMD_INSERT:
+ if (!trigDesc || !trigDesc->trig_insert_instead_row)
+ return false;
+ break;
+ case CMD_UPDATE:
+ if (!trigDesc || !trigDesc->trig_update_instead_row)
+ return false;
+ break;
+ case CMD_DELETE:
+ if (!trigDesc || !trigDesc->trig_delete_instead_row)
+ return false;
+ break;
+ case CMD_NOTHING:
+ /* No trigger required */
+ break;
+ default:
+ elog(ERROR, "unrecognized commandType: %d", action->commandType);
+ break;
+ }
+ }
+ return true; /* no actions without an INSTEAD OF trigger */
default:
elog(ERROR, "unrecognized CmdType: %d", (int) event);
break;
}
+/*
+ * error_view_not_updatable -
+ * Report an error due to an attempt to update a non-updatable view.
+ *
+ * Generally this is expected to be called from the rewriter, with suitable
+ * error detail explaining why the view is not updatable. Note, however, that
+ * the executor also performs a just-in-case check that the target view is
+ * updatable. That check is expected to never fail, but if it does, it will
+ * call this function with NULL error detail --- see CheckValidResultRel().
+ *
+ * Note: for MERGE, at least one of the actions in mergeActionList is expected
+ * to lack a suitable INSTEAD OF trigger --- see view_has_instead_trigger().
+ */
+void
+error_view_not_updatable(Relation view,
+ CmdType command,
+ List *mergeActionList,
+ const char *detail)
+{
+ TriggerDesc *trigDesc = view->trigdesc;
+
+ switch (command)
+ {
+ case CMD_INSERT:
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot insert into view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule."));
+ break;
+ case CMD_UPDATE:
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot update view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable updating the view, provide an INSTEAD OF UPDATE trigger or an unconditional ON UPDATE DO INSTEAD rule."));
+ break;
+ case CMD_DELETE:
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot delete from view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable deleting from the view, provide an INSTEAD OF DELETE trigger or an unconditional ON DELETE DO INSTEAD rule."));
+ break;
+ case CMD_MERGE:
+
+ /*
+ * Note that the error hints here differ from above, since MERGE
+ * doesn't support rules.
+ */
+ foreach_node(MergeAction, action, mergeActionList)
+ {
+ switch (action->commandType)
+ {
+ case CMD_INSERT:
+ if (!trigDesc || !trigDesc->trig_insert_instead_row)
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot insert into view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable inserting into the view using MERGE, provide an INSTEAD OF INSERT trigger."));
+ break;
+ case CMD_UPDATE:
+ if (!trigDesc || !trigDesc->trig_update_instead_row)
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot update view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable updating the view using MERGE, provide an INSTEAD OF UPDATE trigger."));
+ break;
+ case CMD_DELETE:
+ if (!trigDesc || !trigDesc->trig_delete_instead_row)
+ ereport(ERROR,
+ errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
+ errmsg("cannot delete from view \"%s\"",
+ RelationGetRelationName(view)),
+ detail ? errdetail_internal("%s", _(detail)) : 0,
+ errhint("To enable deleting from the view using MERGE, provide an INSTEAD OF DELETE trigger."));
+ break;
+ case CMD_NOTHING:
+ break;
+ default:
+ elog(ERROR, "unrecognized commandType: %d", action->commandType);
+ break;
+ }
+ }
+ break;
+ default:
+ elog(ERROR, "unrecognized CmdType: %d", (int) command);
+ break;
+ }
+}
+
+
/*
* rewriteTargetView -
* Attempt to rewrite a query where the target relation is a view, so that
rewriteTargetView(Query *parsetree, Relation view)
{
Query *viewquery;
+ bool insert_or_update;
const char *auto_update_detail;
RangeTblRef *rtr;
int base_rt_index;
*/
viewquery = copyObject(get_view_query(view));
- /* The view must be updatable, else fail */
- auto_update_detail =
- view_query_is_auto_updatable(viewquery,
- parsetree->commandType != CMD_DELETE);
+ /*
+ * Are we doing INSERT/UPDATE, or MERGE containing INSERT/UPDATE? If so,
+ * various additional checks on the view columns need to be applied, and
+ * any view CHECK OPTIONs need to be enforced.
+ */
+ insert_or_update =
+ (parsetree->commandType == CMD_INSERT ||
+ parsetree->commandType == CMD_UPDATE);
- if (auto_update_detail)
+ if (parsetree->commandType == CMD_MERGE)
{
- /* messages here should match execMain.c's CheckValidResultRel */
- switch (parsetree->commandType)
+ foreach_node(MergeAction, action, parsetree->mergeActionList)
{
- 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 enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.")));
- 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 enable updating the view, provide an INSTEAD OF UPDATE trigger or an unconditional ON UPDATE DO INSTEAD rule.")));
- 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 enable deleting from the view, provide an INSTEAD OF DELETE trigger or an unconditional ON DELETE DO INSTEAD rule.")));
- break;
- default:
- elog(ERROR, "unrecognized CmdType: %d",
- (int) parsetree->commandType);
+ if (action->commandType == CMD_INSERT ||
+ action->commandType == CMD_UPDATE)
+ {
+ insert_or_update = true;
break;
+ }
}
}
/*
- * For INSERT/UPDATE the modified columns must all be updatable. Note that
- * we get the modified columns from the query's targetlist, not from the
- * result RTE's insertedCols and/or updatedCols set, since
- * rewriteTargetListIU may have added additional targetlist entries for
- * view defaults, and these must also be updatable.
+ * The view must be updatable, else fail.
+ *
+ * If we are doing INSERT/UPDATE (or MERGE containing INSERT/UPDATE), we
+ * also check that there is at least one updatable column.
*/
- if (parsetree->commandType != CMD_DELETE)
+ auto_update_detail =
+ view_query_is_auto_updatable(viewquery, insert_or_update);
+
+ if (auto_update_detail)
+ error_view_not_updatable(view,
+ parsetree->commandType,
+ parsetree->mergeActionList,
+ auto_update_detail);
+
+ /*
+ * For INSERT/UPDATE (or MERGE containing INSERT/UPDATE) the modified
+ * columns must all be updatable. Note that we get the modified columns
+ * from the query's targetlist, not from the result RTE's insertedCols
+ * and/or updatedCols set, since rewriteTargetListIU may have added
+ * additional targetlist entries for view defaults, and these must also be
+ * updatable.
+ */
+ if (insert_or_update)
{
Bitmapset *modified_cols = NULL;
char *non_updatable_col;
}
}
+ foreach_node(MergeAction, action, parsetree->mergeActionList)
+ {
+ if (action->commandType == CMD_INSERT ||
+ action->commandType == CMD_UPDATE)
+ {
+ foreach_node(TargetEntry, tle, action->targetList)
+ {
+ if (!tle->resjunk)
+ modified_cols = bms_add_member(modified_cols,
+ tle->resno - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ }
+
auto_update_detail = view_cols_are_auto_updatable(viewquery,
modified_cols,
NULL,
RelationGetRelationName(view)),
errdetail_internal("%s", _(auto_update_detail))));
break;
+ case CMD_MERGE:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot merge into column \"%s\" of view \"%s\"",
+ non_updatable_col,
+ RelationGetRelationName(view)),
+ errdetail_internal("%s", _(auto_update_detail))));
+ break;
default:
elog(ERROR, "unrecognized CmdType: %d",
(int) parsetree->commandType);
}
}
+ /*
+ * For MERGE, there must not be any INSTEAD OF triggers on an otherwise
+ * updatable view. The caller already checked that there isn't a full set
+ * of INSTEAD OF triggers, so this is to guard against having a partial
+ * set (mixing auto-update and trigger-update actions in a single command
+ * isn't supported).
+ */
+ if (parsetree->commandType == CMD_MERGE)
+ {
+ foreach_node(MergeAction, action, parsetree->mergeActionList)
+ {
+ if (action->commandType != CMD_NOTHING &&
+ view_has_instead_trigger(view, action->commandType, NIL))
+ ereport(ERROR,
+ errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("cannot merge into view \"%s\"",
+ RelationGetRelationName(view)),
+ errdetail("MERGE is not supported for views with INSTEAD OF triggers for some actions, but not others."),
+ errhint("To enable merging into the view, either provide a full set of INSTEAD OF triggers or drop the existing INSTEAD OF triggers."));
+ }
+ }
+
/* Locate RTE describing the view in the outer query */
view_rte = rt_fetch(parsetree->resultRelation, parsetree->rtable);
new_rt_index = list_length(parsetree->rtable);
/*
- * INSERTs never inherit. For UPDATE/DELETE, we use the view query's
- * inheritance flag for the base relation.
+ * INSERTs never inherit. For UPDATE/DELETE/MERGE, we use the view
+ * query's inheritance flag for the base relation.
*/
if (parsetree->commandType == CMD_INSERT)
new_rte->inh = false;
/*
* 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.
+ * columns to be affected. Similarly, for MERGE we must update the resnos
+ * in the merge action targetlists of any INSERT/UPDATE actions.
*
- * Note that this destroys the resno ordering of the targetlist, but that
+ * Note that this destroys the resno ordering of the targetlists, but that
* will be fixed when we recurse through RewriteQuery, which will invoke
- * rewriteTargetListIU again on the updated targetlist.
+ * rewriteTargetListIU again on the updated targetlists.
*/
if (parsetree->commandType != CMD_DELETE)
{
elog(ERROR, "attribute number %d not found in view targetlist",
tle->resno);
}
+
+ foreach_node(MergeAction, action, parsetree->mergeActionList)
+ {
+ if (action->commandType == CMD_INSERT ||
+ action->commandType == CMD_UPDATE)
+ {
+ foreach_node(TargetEntry, tle, action->targetList)
+ {
+ 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 UPDATE/DELETE/MERGE, 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).
*
* If it's a security-barrier view, its WHERE quals must be applied before
* quals from the outer query, so we attach them to the RTE as security
}
/*
- * For INSERT/UPDATE, if the view has the WITH CHECK OPTION, or any parent
- * view specified WITH CASCADED CHECK OPTION, add the quals from the view
- * to the query's withCheckOptions list.
+ * For INSERT/UPDATE (or MERGE containing INSERT/UPDATE), if the view has
+ * the WITH CHECK OPTION, or any parent view specified WITH CASCADED CHECK
+ * OPTION, add the quals from the view to the query's withCheckOptions
+ * list.
*/
- if (parsetree->commandType != CMD_DELETE)
+ if (insert_or_update)
{
bool has_wco = RelationHasCheckOption(view);
bool cascaded = RelationHasCascadedCheckOption(view);
ChangeVarNodes(wco->qual, base_rt_index, new_rt_index, 0);
/*
- * Make sure that the query is marked correctly if the added
- * qual has sublinks. We can skip this check if the query is
- * already marked, or if the command is an UPDATE, in which
- * case the same qual will have already been added, and this
- * check will already have been done.
+ * For INSERT, make sure that the query is marked correctly if
+ * the added qual has sublinks. This can be skipped for
+ * UPDATE/MERGE, since the same qual will have already been
+ * added above, and the check will already have been done.
*/
if (!parsetree->hasSubLinks &&
- parsetree->commandType != CMD_UPDATE)
+ parsetree->commandType == CMD_INSERT)
parsetree->hasSubLinks = checkExprHasSubLink(wco->qual);
}
}
/*
* Collect and apply the appropriate rules.
*/
- locks = matchLocks(event, rt_entry_relation->rd_rules,
+ locks = matchLocks(event, rt_entry_relation,
result_relation, parsetree, &hasUpdate);
product_orig_rt_length = list_length(parsetree->rtable);
* 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.
+ * necessary. For MERGE, the view must be automatically updatable if
+ * any of the merge actions lack a corresponding INSTEAD OF trigger.
*
* If the view cannot be automatically updated, we throw an error here
* which is OK since the query would fail at runtime anyway. Throwing
*/
if (!instead &&
rt_entry_relation->rd_rel->relkind == RELKIND_VIEW &&
- !view_has_instead_trigger(rt_entry_relation, event))
+ !view_has_instead_trigger(rt_entry_relation, event,
+ parsetree->mergeActionList))
{
/*
* If there were any qualified INSTEAD rules, don't allow the view
* to be automatically updated (an unqualified INSTEAD rule or
* INSTEAD OF trigger is required).
- *
- * The messages here should match execMain.c's CheckValidResultRel
- * and in principle make those checks in executor unnecessary, but
- * we keep them just in case.
*/
if (qual_product != NULL)
- {
- switch (parsetree->commandType)
- {
- case CMD_INSERT:
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot insert into view \"%s\"",
- RelationGetRelationName(rt_entry_relation)),
- errdetail("Views with conditional DO INSTEAD rules are not automatically updatable."),
- errhint("To enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.")));
- break;
- case CMD_UPDATE:
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot update view \"%s\"",
- RelationGetRelationName(rt_entry_relation)),
- errdetail("Views with conditional DO INSTEAD rules are not automatically updatable."),
- errhint("To enable updating the view, provide an INSTEAD OF UPDATE trigger or an unconditional ON UPDATE DO INSTEAD rule.")));
- break;
- case CMD_DELETE:
- ereport(ERROR,
- (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
- errmsg("cannot delete from view \"%s\"",
- RelationGetRelationName(rt_entry_relation)),
- errdetail("Views with conditional DO INSTEAD rules are not automatically updatable."),
- errhint("To enable deleting from the view, provide an INSTEAD OF DELETE trigger or an unconditional ON DELETE DO INSTEAD rule.")));
- break;
- default:
- elog(ERROR, "unrecognized CmdType: %d",
- (int) parsetree->commandType);
- break;
- }
- }
+ error_view_not_updatable(rt_entry_relation,
+ parsetree->commandType,
+ parsetree->mergeActionList,
+ gettext_noop("Views with conditional DO INSTEAD rules are not automatically updatable."));
/*
* Attempt to rewrite the query to automatically update the view.
/*
* If we are starting at a Query, and sublevels_up is zero, then we
* must also fix rangetable indexes in the Query itself --- namely
- * resultRelation, exclRelIndex and rowMarks entries. sublevels_up
- * cannot be zero when recursing into a subquery, so there's no need
- * to have the same logic inside OffsetVarNodes_walker.
+ * resultRelation, mergeTargetRelation, exclRelIndex and rowMarks
+ * entries. sublevels_up cannot be zero when recursing into a
+ * subquery, so there's no need to have the same logic inside
+ * OffsetVarNodes_walker.
*/
if (sublevels_up == 0)
{
if (qry->resultRelation)
qry->resultRelation += offset;
+ if (qry->mergeTargetRelation)
+ qry->mergeTargetRelation += offset;
+
if (qry->onConflict && qry->onConflict->exclRelIndex)
qry->onConflict->exclRelIndex += offset;
/*
* If we are starting at a Query, and sublevels_up is zero, then we
* must also fix rangetable indexes in the Query itself --- namely
- * resultRelation and rowMarks entries. sublevels_up cannot be zero
- * when recursing into a subquery, so there's no need to have the same
- * logic inside ChangeVarNodes_walker.
+ * resultRelation, mergeTargetRelation, exclRelIndex and rowMarks
+ * entries. sublevels_up cannot be zero when recursing into a
+ * subquery, so there's no need to have the same logic inside
+ * ChangeVarNodes_walker.
*/
if (sublevels_up == 0)
{
if (qry->resultRelation == rt_index)
qry->resultRelation = new_index;
+ if (qry->mergeTargetRelation == rt_index)
+ qry->mergeTargetRelation = new_index;
+
/* this is unlikely to ever be used, but ... */
if (qry->onConflict && qry->onConflict->exclRelIndex == rt_index)
qry->onConflict->exclRelIndex = new_index;
.catname = "pg_catalog.pg_class c",
.selcondition =
"c.relkind IN (" CppAsString2(RELKIND_RELATION) ", "
+ CppAsString2(RELKIND_VIEW) ", "
CppAsString2(RELKIND_PARTITIONED_TABLE) ") ",
.viscondition = "pg_catalog.pg_table_is_visible(c.oid)",
.namespace = "c.relnamespace",
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 202402142
+#define CATALOG_VERSION_NO 202402291
#endif
extern void ExecutorRewind(QueryDesc *queryDesc);
extern bool ExecCheckPermissions(List *rangeTable,
List *rteperminfos, bool ereport_on_violation);
-extern void CheckValidResultRel(ResultRelInfo *resultRelInfo, CmdType operation);
+extern void CheckValidResultRel(ResultRelInfo *resultRelInfo, CmdType operation,
+ List *mergeActions);
extern void InitResultRelInfo(ResultRelInfo *resultRelInfo,
Relation resultRelationDesc,
Index resultRelationIndex,
/* whether to use outer join */
bool mergeUseOuterJoin pg_node_attr(query_jumble_ignore);
+ /*
+ * rtable index of target relation for MERGE to pull data. Initially, this
+ * is the same as resultRelation, but after query rewriting, if the target
+ * relation is a trigger-updatable view, this is the index of the expanded
+ * view subquery, whereas resultRelation is the index of the target view.
+ */
+ int mergeTargetRelation pg_node_attr(query_jumble_ignore);
+
List *targetList; /* target list (of TargetEntry) */
/* OVERRIDING clause */
extern Node *build_column_default(Relation rel, int attrno);
extern Query *get_view_query(Relation view);
+extern bool view_has_instead_trigger(Relation view, CmdType event,
+ List *mergeActionList);
extern const char *view_query_is_auto_updatable(Query *viewquery,
bool check_cols);
extern int relation_is_updatable(Oid reloid,
List *outer_reloids,
bool include_triggers,
Bitmapset *include_cols);
+extern void error_view_not_updatable(Relation view,
+ CmdType command,
+ List *mergeActionList,
+ const char *detail);
#endif /* REWRITEHANDLER_H */
) TO stdout;
ERROR: MERGE not supported in COPY
-- unsupported relation types
--- view
-CREATE VIEW tv AS SELECT * FROM target;
-MERGE INTO tv t
-USING source s
-ON t.tid = s.sid
-WHEN NOT MATCHED THEN
- INSERT DEFAULT VALUES;
-ERROR: cannot execute MERGE on relation "tv"
-DETAIL: This operation is not supported for views.
-DROP VIEW tv;
-- materialized view
CREATE MATERIALIZED VIEW mv AS SELECT * FROM target;
MERGE INTO mv t
DELETE
WHEN NOT MATCHED THEN
INSERT VALUES (s.a, '');
+-- also ok if the rules are disabled
+ALTER TABLE rule_merge1 DISABLE RULE rule1;
+ALTER TABLE rule_merge1 DISABLE RULE rule2;
+ALTER TABLE rule_merge1 DISABLE RULE rule3;
+MERGE INTO rule_merge1 t USING (SELECT 1 AS a) s
+ ON t.a = s.a
+ WHEN MATCHED AND t.a < 2 THEN
+ UPDATE SET b = b || ' updated by merge'
+ WHEN MATCHED AND t.a > 2 THEN
+ DELETE
+ WHEN NOT MATCHED THEN
+ INSERT VALUES (s.a, '');
-- test deparsing
CREATE TABLE sf_target(id int, data text, filling int[]);
CREATE FUNCTION merge_sf_test()
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 enable inserting into the view, provide an INSTEAD OF INSERT trigger or an unconditional ON INSERT DO INSTEAD rule.
+MERGE INTO ro_view13 AS t USING (VALUES (1, 'Row 1')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DELETE;
+ERROR: cannot delete from view "ro_view13"
+DETAIL: Views that do not select from a single table or view are not automatically updatable.
+HINT: To enable deleting from the view using MERGE, provide an INSTEAD OF DELETE trigger.
+MERGE INTO ro_view13 AS t USING (VALUES (2, 'Row 2')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b;
+ERROR: cannot update view "ro_view13"
+DETAIL: Views that do not select from a single table or view are not automatically updatable.
+HINT: To enable updating the view using MERGE, provide an INSTEAD OF UPDATE trigger.
+MERGE INTO ro_view13 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b);
+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 enable inserting into the view using MERGE, provide an INSTEAD OF INSERT trigger.
+MERGE INTO ro_view13 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DO NOTHING
+ WHEN NOT MATCHED THEN DO NOTHING; -- should be OK to do nothing
-- Partially updatable view
INSERT INTO rw_view14 VALUES (null, 3, 'Row 3'); -- should fail
ERROR: cannot insert into column "ctid" of view "rw_view14"
(6 rows)
DELETE FROM rw_view14 WHERE a=3; -- should be OK
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Merged row 2'), (3, 'Merged row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b -- should be OK, except...
+ WHEN NOT MATCHED THEN INSERT VALUES (null, v.a, v.b); -- should fail
+ERROR: cannot merge into column "ctid" of view "rw_view14"
+DETAIL: View columns that refer to system columns are not updatable.
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Merged row 2'), (3, 'Merged row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b -- should be OK
+ WHEN NOT MATCHED THEN INSERT (a,b) VALUES (v.a, v.b); -- should be OK
+SELECT * FROM base_tbl ORDER BY a;
+ a | b
+----+--------------
+ -2 | Row -2
+ -1 | Row -1
+ 0 | Row 0
+ 1 | Row 1
+ 2 | Merged row 2
+ 3 | Merged row 3
+(6 rows)
+
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Row 2'), (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED AND t.a = 2 THEN UPDATE SET b = v.b -- should be OK
+ WHEN MATCHED AND t.a = 3 THEN DELETE; -- should be OK
+SELECT * FROM base_tbl ORDER BY a;
+ a | b
+----+--------
+ -2 | Row -2
+ -1 | Row -1
+ 0 | Row 0
+ 1 | Row 1
+ 2 | Row 2
+(5 rows)
+
-- Partially updatable view
INSERT INTO rw_view15 VALUES (3, 'ROW 3'); -- should fail
ERROR: cannot insert into column "upper" of view "rw_view15"
ERROR: cannot delete from view "rw_view16"
DETAIL: Views with conditional DO INSTEAD rules are not automatically updatable.
HINT: To enable deleting from the view, provide an INSTEAD OF DELETE trigger or an unconditional ON DELETE DO INSTEAD rule.
+MERGE INTO rw_view16 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b); -- should fail
+ERROR: cannot execute MERGE on relation "rw_view16"
+DETAIL: MERGE is not supported for relations with rules.
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 16 other objects
DETAIL: drop cascades to view ro_view1
5 | Unspecified
(6 rows)
+MERGE INTO rw_view1 t
+ USING (VALUES (0, 'ROW 0'), (1, 'ROW 1'),
+ (2, 'ROW 2'), (3, 'ROW 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED AND t.a <= 1 THEN UPDATE SET b = v.b
+ WHEN MATCHED THEN DELETE
+ WHEN NOT MATCHED AND a > 0 THEN INSERT (a) VALUES (v.a);
+SELECT * FROM base_tbl ORDER BY a;
+ a | b
+----+-------------
+ -2 | Row -2
+ -1 | Row -1
+ 0 | Row 0
+ 1 | ROW 1
+ 2 | Unspecified
+ 5 | Unspecified
+(6 rows)
+
EXPLAIN (costs off) UPDATE rw_view1 SET a=6 WHERE a=5;
QUERY PLAN
--------------------------------------------------
Index Cond: ((a > 0) AND (a = 5))
(3 rows)
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t USING (VALUES (5, 'X')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DELETE;
+ QUERY PLAN
+--------------------------------------------------
+ Merge on base_tbl
+ -> Index Scan using base_tbl_pkey on base_tbl
+ Index Cond: ((a > 0) AND (a = 5))
+(3 rows)
+
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (SELECT * FROM generate_series(1,5)) AS s(a) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = 'Updated';
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge on base_tbl
+ -> Hash Join
+ Hash Cond: (base_tbl.a = generate_series.generate_series)
+ -> Bitmap Heap Scan on base_tbl
+ Recheck Cond: (a > 0)
+ -> Bitmap Index Scan on base_tbl_pkey
+ Index Cond: (a > 0)
+ -> Hash
+ -> Function Scan on generate_series
+(9 rows)
+
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (SELECT * FROM generate_series(1,5)) AS s(a) ON t.a = s.a
+ WHEN NOT MATCHED THEN INSERT (a) VALUES (s.a);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Merge on base_tbl
+ -> Hash Right Join
+ Hash Cond: (base_tbl.a = generate_series.generate_series)
+ -> Bitmap Heap Scan on base_tbl
+ Recheck Cond: (a > 0)
+ -> Bitmap Index Scan on base_tbl_pkey
+ Index Cond: (a > 0)
+ -> Hash
+ -> Function Scan on generate_series
+(9 rows)
+
-- it's still updatable if we add a DO ALSO rule
CREATE TABLE base_tbl_hist(ts timestamptz default now(), a int, b text);
CREATE RULE base_tbl_log AS ON INSERT TO rw_view1 DO ALSO
4 | Row 4
(3 rows)
+MERGE INTO rw_view2 t
+ USING (VALUES (3, 'R3'), (4, 'R4'), (5, 'R5')) AS v(a,b) ON aaa = v.a
+ WHEN MATCHED AND aaa = 3 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET bbb = v.b
+ WHEN NOT MATCHED THEN INSERT (aaa) VALUES (v.a);
+SELECT * FROM rw_view2 ORDER BY aaa;
+ aaa | bbb
+-----+-------------
+ 1 | Row 1
+ 4 | R4
+ 5 | Unspecified
+(3 rows)
+
EXPLAIN (costs off) UPDATE rw_view2 SET aaa=5 WHERE aaa=4;
QUERY PLAN
--------------------------------------------------------
2 | Row 2
(2 rows)
+MERGE INTO rw_view2 t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b); -- should fail
+ERROR: cannot execute MERGE on relation "rw_view1"
+DETAIL: MERGE is not supported for relations with rules.
EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2;
QUERY PLAN
----------------------------------------------------------------
2 | Row 2
(2 rows)
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b);
+SELECT * FROM base_tbl ORDER BY a;
+ a | b
+----+--------
+ -2 | Row -2
+ -1 | Row -1
+ 0 | Row 0
+ 2 | R2
+ 3 | R3
+(5 rows)
+
EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2;
QUERY PLAN
----------------------------------------------------------
Index Cond: (a > 0)
(7 rows)
+EXPLAIN (costs off)
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b);
+ QUERY PLAN
+------------------------------------------------------------
+ Merge on rw_view1 rw_view1_1
+ -> Hash Right Join
+ Hash Cond: (rw_view1.a = x.x)
+ -> Subquery Scan on rw_view1
+ Filter: (rw_view1.a < 10)
+ -> Bitmap Heap Scan on base_tbl
+ Recheck Cond: (a > 0)
+ -> Bitmap Index Scan on base_tbl_pkey
+ Index Cond: (a > 0)
+ -> Hash
+ -> Function Scan on generate_series x
+(11 rows)
+
+-- MERGE with incomplete set of INSTEAD OF triggers
+DROP TRIGGER rw_view1_del_trig ON rw_view1;
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+ERROR: cannot delete from view "rw_view1"
+DETAIL: Views containing LIMIT or OFFSET are not automatically updatable.
+HINT: To enable deleting from the view using MERGE, provide an INSTEAD OF DELETE trigger.
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- ok
+DROP TRIGGER rw_view1_ins_trig ON rw_view1;
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+ERROR: cannot insert into view "rw_view1"
+DETAIL: Views containing LIMIT or OFFSET are not automatically updatable.
+HINT: To enable inserting into the view using MERGE, provide an INSTEAD OF INSERT trigger.
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b; -- ok
+-- MERGE with INSTEAD OF triggers on auto-updatable view
+CREATE TRIGGER rw_view2_upd_trig INSTEAD OF UPDATE ON rw_view2
+ FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn();
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+ERROR: cannot merge into view "rw_view2"
+DETAIL: MERGE is not supported for views with INSTEAD OF triggers for some actions, but not others.
+HINT: To enable merging into the view, either provide a full set of INSTEAD OF triggers or drop the existing INSTEAD OF triggers.
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b; -- ok
+SELECT * FROM base_tbl ORDER BY a;
+ a | b
+----+--------
+ -2 | Row -2
+ -1 | Row -1
+ 0 | Row 0
+ 1 | R1
+ 2 | R2
+ 3 | R3
+(6 rows)
+
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to view rw_view1
ERROR: permission denied for view rw_view1
INSERT INTO rw_view2 VALUES ('Row 3', 3.0, 3); -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t
+ USING (VALUES ('Row 3', 3.0, 3)) AS v(b,c,a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t
+ USING (VALUES ('Row 3', 3.0, 3)) AS v(b,c,a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- not allowed
+ERROR: permission denied for table base_tbl
UPDATE base_tbl SET a=a, c=c; -- ok
UPDATE base_tbl SET b=b; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET aa=aa, cc=cc; -- ok
UPDATE rw_view2 SET bb=bb; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb, cc = cc; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa, cc = cc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
+ERROR: permission denied for table base_tbl
DELETE FROM base_tbl; -- not allowed
ERROR: permission denied for table base_tbl
DELETE FROM rw_view1; -- not allowed
DELETE FROM rw_view1 WHERE aa=2; -- not allowed
ERROR: permission denied for view rw_view1
DELETE FROM rw_view2 WHERE aa=2; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- ok
SELECT * FROM base_tbl;
a | b | c
---+-------+---
DELETE FROM rw_view1 WHERE aa=3; -- ok
DELETE FROM rw_view2 WHERE aa=4; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- not allowed
+ERROR: permission denied for table base_tbl
SELECT * FROM base_tbl;
a | b | c
---+-------+---
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
CREATE VIEW rw_view2 AS SELECT * FROM rw_view1;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for view rw_view1
RESET SESSION AUTHORIZATION;
GRANT SELECT ON base_tbl TO regress_view_user1;
SET SESSION AUTHORIZATION regress_view_user1;
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for view rw_view1
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON rw_view1 TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for view rw_view1
RESET SESSION AUTHORIZATION;
GRANT UPDATE ON base_tbl TO regress_view_user1;
SET SESSION AUTHORIZATION regress_view_user1;
(1 row)
UPDATE rw_view1 SET b = 'foo' WHERE a = 1;
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo';
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2;
a | b | c
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'bar'; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user1;
GRANT UPDATE ON rw_view1 TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
(1 row)
UPDATE rw_view2 SET b = 'bar' WHERE a = 1;
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'fud';
RESET SESSION AUTHORIZATION;
REVOKE UPDATE ON base_tbl FROM regress_view_user1;
SET SESSION AUTHORIZATION regress_view_user1;
SELECT * FROM rw_view1;
a | b | c
---+-----+---
- 1 | bar | 1
+ 1 | fud | 1
(1 row)
SELECT * FROM rw_view1 FOR UPDATE; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2;
a | b | c
---+-----+---
- 1 | bar | 1
+ 1 | fud | 1
(1 row)
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
+ERROR: permission denied for table base_tbl
RESET SESSION AUTHORIZATION;
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 2 other objects
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET bb=bb, cc=cc; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
+ERROR: permission denied for table base_tbl
DELETE FROM base_tbl; -- not allowed
ERROR: permission denied for table base_tbl
DELETE FROM rw_view1; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON base_tbl TO regress_view_user2;
GRANT UPDATE (a,c) ON base_tbl TO regress_view_user2;
UPDATE base_tbl SET b=b; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET cc=cc; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET cc = cc; -- ok
UPDATE rw_view1 SET aa=aa; -- not allowed
ERROR: permission denied for view rw_view1
UPDATE rw_view1 SET bb=bb; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user1;
GRANT INSERT, DELETE ON base_tbl TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
DELETE FROM base_tbl WHERE a=1; -- ok
DELETE FROM rw_view1 WHERE aa=2; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user1;
REVOKE INSERT, DELETE ON base_tbl FROM regress_view_user2;
GRANT INSERT, DELETE ON rw_view1 TO regress_view_user2;
ERROR: permission denied for table base_tbl
DELETE FROM rw_view1 WHERE aa=2; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user1;
GRANT INSERT, DELETE ON base_tbl TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- ok
DELETE FROM rw_view1 WHERE aa=2; -- ok
+MERGE INTO rw_view1 t USING (VALUES (3)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- ok
SELECT * FROM base_tbl; -- ok
a | b | c
---+-------+---
- 3 | Row 3 | 3
4 | Row 4 | 4
-(2 rows)
+(1 row)
RESET SESSION AUTHORIZATION;
DROP TABLE base_tbl CASCADE;
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET aa=aa; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (2, 'Row 2', 2.0)) AS v(a,b,c) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
CREATE VIEW rw_view2 AS SELECT cc AS ccc, aa AS aaa, bb AS bbb FROM rw_view1;
GRANT SELECT, UPDATE ON rw_view2 TO regress_view_user3;
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET aaa=aaa; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (2, 'Row 2', 2.0)) AS v(a,b,c) ON t.aaa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.c, v.a, v.b); -- not allowed
+ERROR: permission denied for view rw_view1
RESET SESSION AUTHORIZATION;
GRANT SELECT ON base_tbl TO regress_view_user1;
GRANT UPDATE (a, b) ON base_tbl TO regress_view_user1;
UPDATE rw_view1 SET aa=aa, bb=bb; -- ok
UPDATE rw_view1 SET cc=cc; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa, bb = bb; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET cc = cc; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET aaa=aaa; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for view rw_view1
UPDATE rw_view2 SET aaa=aaa; -- not allowed
ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON rw_view1 TO regress_view_user2;
GRANT UPDATE (bb, cc) ON rw_view1 TO regress_view_user2;
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
RESET SESSION AUTHORIZATION;
GRANT SELECT ON base_tbl TO regress_view_user2;
GRANT UPDATE (a, c) ON base_tbl TO regress_view_user2;
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
ERROR: permission denied for table base_tbl
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- not allowed
+ERROR: permission denied for table base_tbl
RESET SESSION AUTHORIZATION;
GRANT SELECT ON base_tbl TO regress_view_user3;
GRANT UPDATE (a, c) ON base_tbl TO regress_view_user3;
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
REVOKE SELECT, UPDATE ON base_tbl FROM regress_view_user1;
SET SESSION AUTHORIZATION regress_view_user1;
ERROR: permission denied for table base_tbl
UPDATE rw_view1 SET aa=aa; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- ok
ccc | aaa | bbb
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- ok
ccc | aaa | bbb
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
REVOKE SELECT, UPDATE ON base_tbl FROM regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- not allowed
ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- not allowed
+ERROR: permission denied for table base_tbl
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- ok
ccc | aaa | bbb
UPDATE rw_view2 SET bbb=bbb; -- not allowed
ERROR: permission denied for table base_tbl
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+ERROR: permission denied for view rw_view1
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+ERROR: permission denied for table base_tbl
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 2 other objects
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);
+MERGE INTO rw_view1 t USING (VALUES (6)) AS v(a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT (aa) VALUES (v.a);
SELECT * FROM base_tbl;
a | b | c
---+--------------+---
3 | Unspecified | 3
4 | Row 4 | 4
5 | View default | 5
-(5 rows)
+ 6 | View default | 6
+(6 rows)
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to view rw_view1
20
(6 rows)
+MERGE INTO rw_view1 t USING (VALUES (-200), (10)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -199 and 11
+MERGE INTO ONLY rw_view1 t USING (VALUES (-100), (20)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -99 and 21
+MERGE INTO rw_view2 t USING (VALUES (-40), (3)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -39 only
+MERGE INTO ONLY rw_view2 t USING (VALUES (-30), (4)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -29 only
+SELECT * FROM ONLY base_tbl_parent ORDER BY a;
+ a
+------
+ -199
+ -99
+ -39
+ -29
+ -20
+ -10
+ 100
+ 200
+(8 rows)
+
+SELECT * FROM base_tbl_child ORDER BY a;
+ a
+----
+ 3
+ 4
+ 7
+ 8
+ 11
+ 21
+(6 rows)
+
CREATE TABLE other_tbl_parent (id int);
CREATE TABLE other_tbl_child () INHERITS (other_tbl_parent);
INSERT INTO other_tbl_parent VALUES (7),(200);
SELECT * FROM ONLY base_tbl_parent ORDER BY a;
a
------
- -200
- -100
- -40
- -30
+ -199
+ -99
+ -39
+ -29
-20
-10
1100
------
3
4
- 10
- 20
+ 11
+ 21
1007
1008
(6 rows)
INSERT INTO rw_view1(a) VALUES (10); -- should fail
ERROR: new row violates check option for view "rw_view1"
DETAIL: Failing row contains (10, 10).
-SELECT * FROM base_tbl;
+SELECT * FROM base_tbl ORDER BY a, b;
a | b
---+----
+ 1 | -1
1 | 2
2 | 3
- 1 | -1
3 | 5
9 | 10
(5 rows)
+MERGE INTO rw_view1 t USING (VALUES (10)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.a + 1); -- ok
+MERGE INTO rw_view1 t USING (VALUES (11)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.a - 1); -- should fail
+ERROR: new row violates check option for view "rw_view1"
+DETAIL: Failing row contains (11, 10).
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a - 1; -- ok
+MERGE INTO rw_view1 t USING (VALUES (2)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a + 1; -- should fail
+ERROR: new row violates check option for view "rw_view1"
+DETAIL: Failing row contains (3, 3).
+SELECT * FROM base_tbl ORDER BY a, b;
+ a | b
+----+----
+ 0 | 2
+ 1 | -1
+ 2 | 3
+ 3 | 5
+ 9 | 10
+ 10 | 11
+(6 rows)
+
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to view rw_view1
-- WITH LOCAL/CASCADED CHECK OPTION
INSERT INTO rw_view2 VALUES (-5); -- should fail
ERROR: new row violates check option for view "rw_view2"
DETAIL: Failing row contains (-5).
+MERGE INTO rw_view2 t USING (VALUES (-5)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- should fail
+ERROR: new row violates check option for view "rw_view2"
+DETAIL: Failing row contains (-5).
INSERT INTO rw_view2 VALUES (5); -- ok
+MERGE INTO rw_view2 t USING (VALUES (6)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- ok
INSERT INTO rw_view2 VALUES (50); -- ok, but not in view
+MERGE INTO rw_view2 t USING (VALUES (60)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- ok, but not in view
UPDATE rw_view2 SET a = a - 10; -- should fail
ERROR: new row violates check option for view "rw_view2"
DETAIL: Failing row contains (-5).
+MERGE INTO rw_view2 t USING (VALUES (6)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a - 10; -- should fail
+ERROR: new row violates check option for view "rw_view2"
+DETAIL: Failing row contains (-4).
SELECT * FROM base_tbl;
a | b
----+----
5 | 10
+ 6 | 10
50 | 10
-(2 rows)
+ 60 | 10
+(4 rows)
-- Check option won't cascade down to base view with INSTEAD OF triggers
ALTER VIEW rw_view2 SET (check_option=cascaded);
SELECT * FROM base_tbl;
a | b
-----+----
+ 6 | 10
50 | 10
+ 60 | 10
100 | 10
200 | 10
-(3 rows)
+(5 rows)
-- Neither local nor cascaded check options work with INSTEAD rules
DROP TRIGGER rw_view1_trig ON rw_view1;
SELECT * FROM base_tbl;
a | b
-----+----
+ 6 | 10
50 | 10
+ 60 | 10
100 | 10
200 | 10
-10 | 10
20 | 10
30 | 10
-5 | 10
-(7 rows)
+(9 rows)
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 2 other objects
DELETE FROM rw_view1 WHERE NOT snoop(person);
NOTICE: snooped value: Tom
NOTICE: snooped value: Harry
+MERGE INTO rw_view1 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
+NOTICE: snooped value: Tom
+NOTICE: snooped value: Harry
EXPLAIN (costs off) SELECT * FROM rw_view1 WHERE snoop(person);
QUERY PLAN
-----------------------------------------------
Filter: ((visibility = 'public'::text) AND (NOT snoop(person)))
(3 rows)
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
+ QUERY PLAN
+-------------------------------------------------------------
+ Merge on base_tbl
+ -> Nested Loop
+ Join Filter: (base_tbl.person = "*VALUES*".column1)
+ -> Seq Scan on base_tbl
+ Filter: (visibility = 'public'::text)
+ -> Materialize
+ -> Values Scan on "*VALUES*"
+(7 rows)
+
-- security barrier view on top of security barrier view
CREATE VIEW rw_view2 WITH (security_barrier = true) AS
SELECT * FROM rw_view1 WHERE snoop(person);
NOTICE: snooped value: Tom
NOTICE: snooped value: Harry
NOTICE: snooped value: Harry
+MERGE INTO rw_view2 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
+NOTICE: snooped value: Tom
+NOTICE: snooped value: Tom
+NOTICE: snooped value: Harry
+NOTICE: snooped value: Harry
EXPLAIN (costs off) SELECT * FROM rw_view2 WHERE snoop(person);
QUERY PLAN
-----------------------------------------------------
Filter: ((visibility = 'public'::text) AND snoop(person) AND (NOT snoop(person)))
(3 rows)
+EXPLAIN (costs off)
+MERGE INTO rw_view2 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Merge on base_tbl
+ -> Nested Loop
+ Join Filter: (base_tbl.person = "*VALUES*".column1)
+ -> Seq Scan on base_tbl
+ Filter: ((visibility = 'public'::text) AND snoop(person))
+ -> Values Scan on "*VALUES*"
+(6 rows)
+
DROP TABLE base_tbl CASCADE;
NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to view rw_view1
insert into uv_ptv_wco values (1, 2);
ERROR: new row violates check option for view "uv_ptv_wco"
DETAIL: Failing row contains (1, 2, null).
+merge into uv_ptv t
+ using (values (1,2), (1,4)) as v(a,b) on t.a = v.a -- fail: matches 2 src rows
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1);
+ERROR: MERGE command cannot affect row a second time
+HINT: Ensure that not more than one source row matches any one target row.
+merge into uv_ptv t
+ using (values (1,2), (1,4)) as v(a,b) on t.a = v.a and t.b = v.b
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1); -- fail: no partition for b=5
+ERROR: no partition of relation "uv_pt1" found for row
+DETAIL: Partition key of the failing row contains (b) = (5).
+merge into uv_ptv t
+ using (values (1,2), (1,3)) as v(a,b) on t.a = v.a and t.b = v.b
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1); -- ok
+select tableoid::regclass, * from uv_pt order by a, b;
+ tableoid | a | b | v
+----------+---+---+---
+ uv_pt11 | 1 | 3 |
+ uv_pt11 | 1 | 4 |
+(2 rows)
+
drop view uv_ptv, uv_ptv_wco;
drop table uv_pt, uv_pt1, uv_pt11;
-- check that wholerow vars appearing in WITH CHECK OPTION constraint expressions
) TO stdout;
-- unsupported relation types
--- view
-CREATE VIEW tv AS SELECT * FROM target;
-MERGE INTO tv t
-USING source s
-ON t.tid = s.sid
-WHEN NOT MATCHED THEN
- INSERT DEFAULT VALUES;
-DROP VIEW tv;
-
-- materialized view
CREATE MATERIALIZED VIEW mv AS SELECT * FROM target;
MERGE INTO mv t
WHEN NOT MATCHED THEN
INSERT VALUES (s.a, '');
+-- also ok if the rules are disabled
+ALTER TABLE rule_merge1 DISABLE RULE rule1;
+ALTER TABLE rule_merge1 DISABLE RULE rule2;
+ALTER TABLE rule_merge1 DISABLE RULE rule3;
+MERGE INTO rule_merge1 t USING (SELECT 1 AS a) s
+ ON t.a = s.a
+ WHEN MATCHED AND t.a < 2 THEN
+ UPDATE SET b = b || ' updated by merge'
+ WHEN MATCHED AND t.a > 2 THEN
+ DELETE
+ WHEN NOT MATCHED THEN
+ INSERT VALUES (s.a, '');
+
-- test deparsing
CREATE TABLE sf_target(id int, data text, filling int[]);
UPDATE ro_view11 SET a=a+1;
UPDATE ro_view12 SET a=a+1;
INSERT INTO ro_view13 VALUES (3, 'Row 3');
+MERGE INTO ro_view13 AS t USING (VALUES (1, 'Row 1')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DELETE;
+MERGE INTO ro_view13 AS t USING (VALUES (2, 'Row 2')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b;
+MERGE INTO ro_view13 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b);
+MERGE INTO ro_view13 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DO NOTHING
+ WHEN NOT MATCHED THEN DO NOTHING; -- should be OK to do nothing
-- Partially updatable view
INSERT INTO rw_view14 VALUES (null, 3, 'Row 3'); -- should fail
INSERT INTO rw_view14 (a, b) VALUES (3, 'Row 3'); -- should be OK
UPDATE rw_view14 SET b='ROW 3' WHERE a=3; -- should be OK
SELECT * FROM base_tbl;
DELETE FROM rw_view14 WHERE a=3; -- should be OK
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Merged row 2'), (3, 'Merged row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b -- should be OK, except...
+ WHEN NOT MATCHED THEN INSERT VALUES (null, v.a, v.b); -- should fail
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Merged row 2'), (3, 'Merged row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = v.b -- should be OK
+ WHEN NOT MATCHED THEN INSERT (a,b) VALUES (v.a, v.b); -- should be OK
+SELECT * FROM base_tbl ORDER BY a;
+MERGE INTO rw_view14 AS t
+ USING (VALUES (2, 'Row 2'), (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED AND t.a = 2 THEN UPDATE SET b = v.b -- should be OK
+ WHEN MATCHED AND t.a = 3 THEN DELETE; -- should be OK
+SELECT * FROM base_tbl ORDER BY a;
-- Partially updatable view
INSERT INTO rw_view15 VALUES (3, 'ROW 3'); -- should fail
INSERT INTO rw_view15 (a) VALUES (3); -- should be OK
INSERT INTO rw_view16 (a, b) VALUES (3, 'Row 3'); -- should fail
UPDATE rw_view16 SET b='ROW 2' WHERE a=2; -- should fail
DELETE FROM rw_view16 WHERE a=2; -- should fail
+MERGE INTO rw_view16 AS t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b); -- should fail
DROP TABLE base_tbl CASCADE;
DROP VIEW ro_view10, ro_view12, ro_view18;
DELETE FROM rw_view1 WHERE b='Row 2';
SELECT * FROM base_tbl;
+MERGE INTO rw_view1 t
+ USING (VALUES (0, 'ROW 0'), (1, 'ROW 1'),
+ (2, 'ROW 2'), (3, 'ROW 3')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED AND t.a <= 1 THEN UPDATE SET b = v.b
+ WHEN MATCHED THEN DELETE
+ WHEN NOT MATCHED AND a > 0 THEN INSERT (a) VALUES (v.a);
+SELECT * FROM base_tbl ORDER BY a;
+
EXPLAIN (costs off) UPDATE rw_view1 SET a=6 WHERE a=5;
EXPLAIN (costs off) DELETE FROM rw_view1 WHERE a=5;
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t USING (VALUES (5, 'X')) AS v(a,b) ON t.a = v.a
+ WHEN MATCHED THEN DELETE;
+
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (SELECT * FROM generate_series(1,5)) AS s(a) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = 'Updated';
+
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (SELECT * FROM generate_series(1,5)) AS s(a) ON t.a = s.a
+ WHEN NOT MATCHED THEN INSERT (a) VALUES (s.a);
+
-- it's still updatable if we add a DO ALSO rule
CREATE TABLE base_tbl_hist(ts timestamptz default now(), a int, b text);
DELETE FROM rw_view2 WHERE aaa=2;
SELECT * FROM rw_view2;
+MERGE INTO rw_view2 t
+ USING (VALUES (3, 'R3'), (4, 'R4'), (5, 'R5')) AS v(a,b) ON aaa = v.a
+ WHEN MATCHED AND aaa = 3 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET bbb = v.b
+ WHEN NOT MATCHED THEN INSERT (aaa) VALUES (v.a);
+SELECT * FROM rw_view2 ORDER BY aaa;
+
EXPLAIN (costs off) UPDATE rw_view2 SET aaa=5 WHERE aaa=4;
EXPLAIN (costs off) DELETE FROM rw_view2 WHERE aaa=4;
DELETE FROM rw_view2 WHERE a=3 RETURNING *;
SELECT * FROM rw_view2;
+MERGE INTO rw_view2 t USING (VALUES (3, 'Row 3')) AS v(a,b) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.b); -- should fail
+
EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2;
EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2;
DELETE FROM rw_view2 WHERE a=3 RETURNING *;
SELECT * FROM rw_view2;
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b);
+SELECT * FROM base_tbl ORDER BY a;
+
EXPLAIN (costs off) UPDATE rw_view2 SET a=3 WHERE a=2;
EXPLAIN (costs off) DELETE FROM rw_view2 WHERE a=2;
+EXPLAIN (costs off)
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b);
+
+-- MERGE with incomplete set of INSTEAD OF triggers
+DROP TRIGGER rw_view1_del_trig ON rw_view1;
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED AND t.a <= 1 THEN DELETE
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- ok
+
+DROP TRIGGER rw_view1_ins_trig ON rw_view1;
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b; -- ok
+
+-- MERGE with INSTEAD OF triggers on auto-updatable view
+CREATE TRIGGER rw_view2_upd_trig INSTEAD OF UPDATE ON rw_view2
+ FOR EACH ROW EXECUTE PROCEDURE rw_view1_trig_fn();
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b
+ WHEN NOT MATCHED AND s.a > 0 THEN INSERT VALUES (s.a, s.b); -- should fail
+MERGE INTO rw_view2 t
+ USING (SELECT x, 'R'||x FROM generate_series(0,3) x) AS s(a,b) ON t.a = s.a
+ WHEN MATCHED THEN UPDATE SET b = s.b; -- ok
+SELECT * FROM base_tbl ORDER BY a;
+
DROP TABLE base_tbl CASCADE;
DROP FUNCTION rw_view1_trig_fn();
INSERT INTO rw_view1 VALUES ('Row 3', 3.0, 3); -- not allowed
INSERT INTO rw_view2 VALUES ('Row 3', 3.0, 3); -- not allowed
+MERGE INTO rw_view1 t
+ USING (VALUES ('Row 3', 3.0, 3)) AS v(b,c,a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- not allowed
+MERGE INTO rw_view2 t
+ USING (VALUES ('Row 3', 3.0, 3)) AS v(b,c,a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- 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_view2 SET aa=aa, cc=cc; -- ok
UPDATE rw_view2 SET bb=bb; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb, cc = cc; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa, cc = cc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
+
DELETE FROM base_tbl; -- not allowed
DELETE FROM rw_view1; -- not allowed
DELETE FROM rw_view2; -- not allowed
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
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- ok
SELECT * FROM base_tbl;
RESET SESSION AUTHORIZATION;
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
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED AND bb = 'xxx' THEN DELETE; -- not allowed
SELECT * FROM base_tbl;
RESET SESSION AUTHORIZATION;
SELECT * FROM rw_view1; -- not allowed
SELECT * FROM rw_view1 FOR UPDATE; -- not allowed
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
CREATE VIEW rw_view2 AS SELECT * FROM rw_view1;
SELECT * FROM rw_view2; -- not allowed
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
RESET SESSION AUTHORIZATION;
GRANT SELECT ON base_tbl TO regress_view_user1;
SELECT * FROM rw_view1;
SELECT * FROM rw_view1 FOR UPDATE; -- not allowed
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- not allowed
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON rw_view1 TO regress_view_user2;
SELECT * FROM rw_view2;
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
RESET SESSION AUTHORIZATION;
GRANT UPDATE ON base_tbl TO regress_view_user1;
SELECT * FROM rw_view1;
SELECT * FROM rw_view1 FOR UPDATE;
UPDATE rw_view1 SET b = 'foo' WHERE a = 1;
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo';
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2;
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'bar'; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT UPDATE ON rw_view1 TO regress_view_user2;
SELECT * FROM rw_view2;
SELECT * FROM rw_view2 FOR UPDATE;
UPDATE rw_view2 SET b = 'bar' WHERE a = 1;
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'fud';
RESET SESSION AUTHORIZATION;
REVOKE UPDATE ON base_tbl FROM regress_view_user1;
SELECT * FROM rw_view1;
SELECT * FROM rw_view1 FOR UPDATE; -- not allowed
UPDATE rw_view1 SET b = 'foo' WHERE a = 1; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2;
SELECT * FROM rw_view2 FOR UPDATE; -- not allowed
UPDATE rw_view2 SET b = 'bar' WHERE a = 1; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET b = 'foo'; -- not allowed
RESET SESSION AUTHORIZATION;
INSERT INTO rw_view1 VALUES ('Row 3', 3.0, 3); -- not allowed
UPDATE base_tbl SET a=a; -- not allowed
UPDATE rw_view1 SET bb=bb, cc=cc; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
DELETE FROM base_tbl; -- not allowed
DELETE FROM rw_view1; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON base_tbl TO regress_view_user2;
UPDATE base_tbl SET a=a, c=c; -- ok
UPDATE base_tbl SET b=b; -- not allowed
UPDATE rw_view1 SET cc=cc; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET cc = cc; -- ok
UPDATE rw_view1 SET aa=aa; -- not allowed
UPDATE rw_view1 SET bb=bb; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET bb = bb; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT INSERT, DELETE ON base_tbl TO regress_view_user2;
INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- not allowed
DELETE FROM base_tbl WHERE a=1; -- ok
DELETE FROM rw_view1 WHERE aa=2; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
REVOKE INSERT, DELETE ON base_tbl FROM regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- not allowed
DELETE FROM rw_view1 WHERE aa=2; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT INSERT, DELETE ON base_tbl TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
INSERT INTO rw_view1 VALUES ('Row 4', 4.0, 4); -- ok
DELETE FROM rw_view1 WHERE aa=2; -- ok
+MERGE INTO rw_view1 t USING (VALUES (3)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN DELETE; -- ok
SELECT * FROM base_tbl; -- ok
RESET SESSION AUTHORIZATION;
ALTER VIEW rw_view1 SET (security_invoker = true);
SELECT * FROM rw_view1; -- not allowed
UPDATE rw_view1 SET aa=aa; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (2, 'Row 2', 2.0)) AS v(a,b,c) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.b, v.c, v.a); -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
CREATE VIEW rw_view2 AS SELECT cc AS ccc, aa AS aaa, bb AS bbb FROM rw_view1;
GRANT SELECT, UPDATE ON rw_view2 TO regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET aaa=aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (2, 'Row 2', 2.0)) AS v(a,b,c) ON t.aaa = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.c, v.a, v.b); -- not allowed
RESET SESSION AUTHORIZATION;
SELECT * FROM rw_view1; -- ok
UPDATE rw_view1 SET aa=aa, bb=bb; -- ok
UPDATE rw_view1 SET cc=cc; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa, bb = bb; -- ok
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET cc = cc; -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET aaa=aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET aaa=aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
SET SESSION AUTHORIZATION regress_view_user1;
GRANT SELECT ON rw_view1 TO regress_view_user2;
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
RESET SESSION AUTHORIZATION;
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- not allowed
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- not allowed
RESET SESSION AUTHORIZATION;
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
SET SESSION AUTHORIZATION regress_view_user1;
SELECT * FROM rw_view1; -- not allowed
UPDATE rw_view1 SET aa=aa; -- not allowed
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.aa = v.a
+ WHEN MATCHED THEN UPDATE SET aa = aa; -- not allowed
SET SESSION AUTHORIZATION regress_view_user2;
SELECT * FROM rw_view2; -- ok
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- ok
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- not allowed
SET SESSION AUTHORIZATION regress_view_user3;
SELECT * FROM rw_view2; -- ok
UPDATE rw_view2 SET aaa=aaa; -- not allowed
UPDATE rw_view2 SET bbb=bbb; -- not allowed
UPDATE rw_view2 SET ccc=ccc; -- ok
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET aaa = aaa; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET bbb = bbb; -- not allowed
+MERGE INTO rw_view2 t USING (VALUES (1)) AS v(a) ON t.aaa = v.a
+ WHEN MATCHED THEN UPDATE SET ccc = ccc; -- ok
RESET SESSION AUTHORIZATION;
INSERT INTO rw_view1 VALUES (4, 'Row 4');
INSERT INTO rw_view1 (aa) VALUES (5);
+MERGE INTO rw_view1 t USING (VALUES (6)) AS v(a) ON t.aa = v.a
+ WHEN NOT MATCHED THEN INSERT (aa) VALUES (v.a);
SELECT * FROM base_tbl;
SELECT * FROM ONLY base_tbl_parent ORDER BY a;
SELECT * FROM base_tbl_child ORDER BY a;
+MERGE INTO rw_view1 t USING (VALUES (-200), (10)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -199 and 11
+MERGE INTO ONLY rw_view1 t USING (VALUES (-100), (20)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -99 and 21
+MERGE INTO rw_view2 t USING (VALUES (-40), (3)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -39 only
+MERGE INTO ONLY rw_view2 t USING (VALUES (-30), (4)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a+1; -- Should produce -29 only
+
+SELECT * FROM ONLY base_tbl_parent ORDER BY a;
+SELECT * FROM base_tbl_child ORDER BY a;
+
CREATE TABLE other_tbl_parent (id int);
CREATE TABLE other_tbl_child () INHERITS (other_tbl_parent);
INSERT INTO other_tbl_parent VALUES (7),(200);
UPDATE rw_view1 SET b = -5 WHERE a = 3; -- should fail
INSERT INTO rw_view1(a) VALUES (9); -- ok
INSERT INTO rw_view1(a) VALUES (10); -- should fail
-SELECT * FROM base_tbl;
+SELECT * FROM base_tbl ORDER BY a, b;
+
+MERGE INTO rw_view1 t USING (VALUES (10)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.a + 1); -- ok
+MERGE INTO rw_view1 t USING (VALUES (11)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a, v.a - 1); -- should fail
+MERGE INTO rw_view1 t USING (VALUES (1)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a - 1; -- ok
+MERGE INTO rw_view1 t USING (VALUES (2)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a + 1; -- should fail
+SELECT * FROM base_tbl ORDER BY a, b;
DROP TABLE base_tbl CASCADE;
SELECT * FROM rw_view1 WHERE a > 0 WITH LOCAL CHECK OPTION;
INSERT INTO rw_view2 VALUES (-5); -- should fail
+MERGE INTO rw_view2 t USING (VALUES (-5)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- should fail
INSERT INTO rw_view2 VALUES (5); -- ok
+MERGE INTO rw_view2 t USING (VALUES (6)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- ok
INSERT INTO rw_view2 VALUES (50); -- ok, but not in view
+MERGE INTO rw_view2 t USING (VALUES (60)) AS v(a) ON t.a = v.a
+ WHEN NOT MATCHED THEN INSERT VALUES (v.a); -- ok, but not in view
UPDATE rw_view2 SET a = a - 10; -- should fail
+MERGE INTO rw_view2 t USING (VALUES (6)) AS v(a) ON t.a = v.a
+ WHEN MATCHED THEN UPDATE SET a = t.a - 10; -- should fail
SELECT * FROM base_tbl;
-- Check option won't cascade down to base view with INSTEAD OF triggers
SELECT * FROM rw_view1 WHERE snoop(person);
UPDATE rw_view1 SET person=person WHERE snoop(person);
DELETE FROM rw_view1 WHERE NOT snoop(person);
+MERGE INTO rw_view1 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
EXPLAIN (costs off) SELECT * FROM rw_view1 WHERE snoop(person);
EXPLAIN (costs off) UPDATE rw_view1 SET person=person WHERE snoop(person);
EXPLAIN (costs off) DELETE FROM rw_view1 WHERE NOT snoop(person);
+EXPLAIN (costs off)
+MERGE INTO rw_view1 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
-- security barrier view on top of security barrier view
SELECT * FROM rw_view2 WHERE snoop(person);
UPDATE rw_view2 SET person=person WHERE snoop(person);
DELETE FROM rw_view2 WHERE NOT snoop(person);
+MERGE INTO rw_view2 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
EXPLAIN (costs off) SELECT * FROM rw_view2 WHERE snoop(person);
EXPLAIN (costs off) UPDATE rw_view2 SET person=person WHERE snoop(person);
EXPLAIN (costs off) DELETE FROM rw_view2 WHERE NOT snoop(person);
+EXPLAIN (costs off)
+MERGE INTO rw_view2 t
+ USING (VALUES ('Tom'), ('Dick'), ('Harry')) AS v(person) ON t.person = v.person
+ WHEN MATCHED AND snoop(t.person) THEN UPDATE SET person = v.person;
DROP TABLE base_tbl CASCADE;
select tableoid::regclass, * from uv_pt;
create view uv_ptv_wco as select * from uv_pt where a = 0 with check option;
insert into uv_ptv_wco values (1, 2);
+merge into uv_ptv t
+ using (values (1,2), (1,4)) as v(a,b) on t.a = v.a -- fail: matches 2 src rows
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1);
+merge into uv_ptv t
+ using (values (1,2), (1,4)) as v(a,b) on t.a = v.a and t.b = v.b
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1); -- fail: no partition for b=5
+merge into uv_ptv t
+ using (values (1,2), (1,3)) as v(a,b) on t.a = v.a and t.b = v.b
+ when matched then update set b = t.b + 1
+ when not matched then insert values (v.a, v.b + 1); -- ok
+select tableoid::regclass, * from uv_pt order by a, b;
drop view uv_ptv, uv_ptv_wco;
drop table uv_pt, uv_pt1, uv_pt11;