mirror of
https://github.com/postgres/postgres.git
synced 2025-07-28 23:42:10 +03:00
Support MERGE into updatable views.
This allows the target relation of MERGE to be an auto-updatable or trigger-updatable view, and includes support for WITH CHECK OPTION, security barrier views, and security invoker views. A trigger-updatable view must have INSTEAD OF triggers for every type of action (INSERT, UPDATE, and DELETE) mentioned in the MERGE command. An auto-updatable view must not have any INSTEAD OF triggers. Mixing auto-update and trigger-update actions (i.e., having a partial set of INSTEAD OF triggers) is not supported. Rule-updatable views are also not supported, since there is no rewriter support for non-SELECT rules with MERGE operations. Dean Rasheed, reviewed by Jian He and Alvaro Herrera. Discussion: https://postgr.es/m/CAEZATCVcB1g0nmxuEc-A+gGB0HnfcGQNGYH7gS=7rq0u0zOBXA@mail.gmail.com
This commit is contained in:
@ -192,12 +192,14 @@ CREATE VIEW [ <replaceable>schema</replaceable> . ] <replaceable>view_name</repl
|
||||
<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:
|
||||
|
||||
@ -247,7 +249,8 @@ CREATE VIEW [ <replaceable>schema</replaceable> . ] <replaceable>view_name</repl
|
||||
<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>
|
||||
@ -360,7 +363,8 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
|
||||
|
||||
<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:
|
||||
|
||||
@ -400,13 +404,15 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
|
||||
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.
|
||||
@ -415,17 +421,21 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
|
||||
<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>
|
||||
@ -443,14 +453,16 @@ CREATE VIEW vista AS SELECT text 'Hello World' AS hello;
|
||||
|
||||
<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>
|
||||
|
@ -132,9 +132,9 @@ DELETE
|
||||
<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
|
||||
@ -142,6 +142,16 @@ DELETE
|
||||
<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>
|
||||
|
||||
@ -486,7 +496,11 @@ MERGE <replaceable class="parameter">total_count</replaceable>
|
||||
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>
|
||||
|
@ -797,9 +797,9 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
|
||||
|
||||
<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.
|
||||
@ -813,11 +813,12 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
|
||||
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>
|
||||
@ -827,10 +828,10 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
|
||||
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>
|
||||
@ -842,13 +843,13 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
|
||||
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>
|
||||
@ -857,7 +858,8 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
|
||||
<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>
|
||||
|
Reference in New Issue
Block a user