<para>
The catalog <structname>pg_seclabel</structname> stores security
- labels on database objects. See the
+ labels on database objects. See the
<xref linkend="sql-security-label"> statement.
</para>
</indexterm>
<para>
- The catalog <structname>pg_trigger</structname> stores triggers on tables.
+ The catalog <structname>pg_trigger</structname> stores triggers on tables
+ and views.
See <xref linkend="sql-createtrigger">
for more information.
</para>
<entry><structfield>tgtype</structfield></entry>
<entry><type>int2</type></entry>
<entry></entry>
- <entry>Bit mask identifying trigger conditions</entry>
+ <entry>Bit mask identifying trigger firing conditions</entry>
</row>
<row>
<note>
<para>
<literal>pg_class.relhastriggers</literal>
- must be true if a table has any triggers in this catalog.
+ must be true if a relation has any triggers in this catalog.
</para>
</note>
<para>
The view <literal>triggers</literal> contains all triggers defined
- in the current database on tables that the current user owns or has
- some non-SELECT privilege on.
+ in the current database on tables and views that the current user owns
+ or has some non-SELECT privilege on.
</para>
<table>
</row>
<row>
- <entry><literal>condition_timing</literal></entry>
+ <entry><literal>action_timing</literal></entry>
<entry><type>character_data</type></entry>
<entry>
- Time at which the trigger fires (<literal>BEFORE</literal> or
- <literal>AFTER</literal>)
+ Time at which the trigger fires (<literal>BEFORE</literal>,
+ <literal>AFTER</literal>, or <literal>INSTEAD OF</literal>)
</entry>
</row>
<row>
- <entry><literal>condition_reference_old_table</literal></entry>
+ <entry><literal>action_reference_old_table</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
</row>
<row>
- <entry><literal>condition_reference_new_table</literal></entry>
+ <entry><literal>action_reference_new_table</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
</row>
<row>
- <entry><literal>condition_reference_old_row</literal></entry>
+ <entry><literal>action_reference_old_row</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
</row>
<row>
- <entry><literal>condition_reference_new_row</literal></entry>
+ <entry><literal>action_reference_new_row</literal></entry>
<entry><type>sql_identifier</type></entry>
<entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
</row>
Triggers in <productname>PostgreSQL</productname> have two
incompatibilities with the SQL standard that affect the
representation in the information schema. First, trigger names are
- local to the table in <productname>PostgreSQL</productname>, rather
+ local to each table in <productname>PostgreSQL</productname>, rather
than being independent schema objects. Therefore there can be duplicate
- trigger names defined in one schema, as long as they belong to
+ trigger names defined in one schema, so long as they belong to
different tables. (<literal>trigger_catalog</literal> and
<literal>trigger_schema</literal> are really the values pertaining
to the table that the trigger is defined on.) Second, triggers can
multiple rows in the information schema, one for each type of
event. As a consequence of these two issues, the primary key of
the view <literal>triggers</literal> is really
- <literal>(trigger_catalog, trigger_schema, trigger_name,
- event_object_table, event_manipulation)</literal> instead of
+ <literal>(trigger_catalog, trigger_schema, event_object_table,
+ trigger_name, event_manipulation)</literal> instead of
<literal>(trigger_catalog, trigger_schema, trigger_name)</literal>,
which is what the SQL standard specifies. Nonetheless, if you
define your triggers in a manner that conforms with the SQL
standard (trigger names unique in the schema and only one event
type per trigger), this will not affect you.
</para>
+
+ <note>
+ <para>
+ Prior to <productname>PostgreSQL</> 9.1, this view's columns
+ <structfield>action_timing</structfield>,
+ <structfield>action_reference_old_table</structfield>,
+ <structfield>action_reference_new_table</structfield>,
+ <structfield>action_reference_old_row</structfield>, and
+ <structfield>action_reference_new_row</structfield>
+ were named
+ <structfield>condition_timing</structfield>,
+ <structfield>condition_reference_old_table</structfield>,
+ <structfield>condition_reference_new_table</structfield>,
+ <structfield>condition_reference_old_row</structfield>, and
+ <structfield>condition_reference_new_row</structfield>
+ respectively.
+ That was how they were named in the SQL:1999 standard.
+ The new naming conforms to SQL:2003 and later.
+ </para>
+ </note>
</sect1>
<sect1 id="infoschema-usage-privileges">
<row>
<entry><literal>is_trigger_updatable</literal></entry>
<entry><type>yes_or_no</type></entry>
- <entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
+ <entry>
+ <literal>YES</> if the view has an <literal>INSTEAD OF</>
+ <command>UPDATE</> trigger defined on it, <literal>NO</> if not
+ </entry>
</row>
<row>
<entry><literal>is_trigger_deletable</literal></entry>
<entry><type>yes_or_no</type></entry>
- <entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
+ <entry>
+ <literal>YES</> if the view has an <literal>INSTEAD OF</>
+ <command>DELETE</> trigger defined on it, <literal>NO</> if not
+ </entry>
</row>
<row>
<entry><literal>is_trigger_insertable_into</literal></entry>
<entry><type>yes_or_no</type></entry>
- <entry>Applies to a feature not available in <productname>PostgreSQL</></entry>
+ <entry>
+ <literal>YES</> if the view has an <literal>INSTEAD OF</>
+ <command>INSERT</> trigger defined on it, <literal>NO</> if not
+ </entry>
</row>
</tbody>
</tgroup>
<term><literal>$_TD->{when}</literal></term>
<listitem>
<para>
- When the trigger was called: <literal>BEFORE</literal>, <literal>AFTER</literal>, or <literal>UNKNOWN</literal>
+ When the trigger was called: <literal>BEFORE</literal>,
+ <literal>AFTER</literal>, <literal>INSTEAD OF</literal>, or
+ <literal>UNKNOWN</literal>
</para>
</listitem>
</varlistentry>
<term><varname>TG_WHEN</varname></term>
<listitem>
<para>
- Data type <type>text</type>; a string of either
- <literal>BEFORE</literal> or <literal>AFTER</literal>
- depending on the trigger's definition.
+ Data type <type>text</type>; a string of
+ <literal>BEFORE</literal>, <literal>AFTER</literal>, or
+ <literal>INSTEAD OF</literal>, depending on the trigger's definition.
</para>
</listitem>
</varlistentry>
effect, but it has to be nonnull to allow the trigger action to
proceed. Note that <varname>NEW</varname> is null
in <command>DELETE</command> triggers, so returning that is
- usually not sensible. A useful idiom in <command>DELETE</command>
- triggers might be to return <varname>OLD</varname>.
+ usually not sensible. The usual idiom in <command>DELETE</command>
+ triggers is to return <varname>OLD</varname>.
+ </para>
+
+ <para>
+ <literal>INSTEAD OF</> triggers (which are always row-level triggers,
+ and may only be used on views) can return null to signal that they did
+ not perform any updates, and that the rest of the operation for this
+ row should be skipped (i.e., subsequent triggers are not fired, and the
+ row is not counted in the rows-affected status for the surrounding
+ <command>INSERT</>/<command>UPDATE</>/<command>DELETE</>).
+ Otherwise a nonnull value should be returned, to signal
+ that the trigger performed the requested operation. For
+ <command>INSERT</> and <command>UPDATE</> operations, the return value
+ should be <varname>NEW</>, which the trigger function may modify to
+ support <command>INSERT RETURNING</> and <command>UPDATE RETURNING</>
+ (this will also affect the row value passed to any subsequent triggers).
+ For <command>DELETE</> operations, the return value should be
+ <varname>OLD</>.
</para>
<para>
</programlisting>
</example>
+ <para>
+ A variation of the previous example uses a view joining the main table
+ to the audit table, to show when each entry was last modified. This
+ approach still records the full audit trail of changes to the table,
+ but also presents a simplified view of the audit trail, showing just
+ the last modified timestamp derived from the audit trail for each entry.
+ <xref linkend="plpgsql-view-trigger-audit-example"> shows an example
+ of an audit trigger on a view in <application>PL/pgSQL</application>.
+ </para>
+
+ <example id="plpgsql-view-trigger-audit-example">
+ <title>A <application>PL/pgSQL</application> View Trigger Procedure For Auditing</title>
+
+ <para>
+ This example uses a trigger on the view to make it updatable, and
+ ensure that any insert, update or delete of a row in the view is
+ recorded (i.e., audited) in the emp_audit table. The current time
+ and user name are recorded, together with the type of operation
+ performed, and the view displays the last modified time of each row.
+ </para>
+
+<programlisting>
+CREATE TABLE emp (
+ empname text PRIMARY KEY,
+ salary integer
+);
+
+CREATE TABLE emp_audit(
+ operation char(1) NOT NULL,
+ userid text NOT NULL,
+ empname text NOT NULL,
+ salary integer,
+ stamp timestamp NOT NULL
+);
+
+CREATE VIEW emp_view AS
+ SELECT e.empname,
+ e.salary,
+ max(ea.stamp) AS last_updated
+ FROM emp e
+ LEFT JOIN emp_audit ea ON ea.empname = e.empname
+ GROUP BY 1, 2;
+
+CREATE OR REPLACE FUNCTION update_emp_view() RETURNS TRIGGER AS $$
+ BEGIN
+ --
+ -- Perform the required operation on emp, and create a row in emp_audit
+ -- to reflect the change made to emp.
+ --
+ IF (TG_OP = 'DELETE') THEN
+ DELETE FROM emp WHERE empname = OLD.empname;
+ IF NOT FOUND THEN RETURN NULL; END IF;
+
+ OLD.last_updated = now();
+ INSERT INTO emp_audit VALUES('D', user, OLD.*);
+ RETURN OLD;
+ ELSIF (TG_OP = 'UPDATE') THEN
+ UPDATE emp SET salary = NEW.salary WHERE empname = OLD.empname;
+ IF NOT FOUND THEN RETURN NULL; END IF;
+
+ NEW.last_updated = now();
+ INSERT INTO emp_audit VALUES('U', user, NEW.*);
+ RETURN NEW;
+ ELSIF (TG_OP = 'INSERT') THEN
+ INSERT INTO emp VALUES(NEW.empname, NEW.salary);
+
+ NEW.last_updated = now();
+ INSERT INTO emp_audit VALUES('I', user, NEW.*);
+ RETURN NEW;
+ END IF;
+ END;
+$$ LANGUAGE plpgsql;
+
+CREATE TRIGGER emp_audit
+INSTEAD OF INSERT OR UPDATE OR DELETE ON emp_view
+ FOR EACH ROW EXECUTE PROCEDURE update_emp_view();
+</programlisting>
+ </example>
+
<para>
One use of triggers is to maintain a summary table
of another table. The resulting summary can be used in place of the
who text
);
</programlisting>
-
+
A set result can be returned from a:
<variablelist>
<para>
contains the event as a string:
<literal>INSERT</>, <literal>UPDATE</>,
- <literal>DELETE</>, <literal>TRUNCATE</>,
- or <literal>UNKNOWN</>.
+ <literal>DELETE</>, or <literal>TRUNCATE</>.
</para>
</listitem>
</varlistentry>
<term><literal>TD["when"]</></term>
<listitem>
<para>
- contains one of <literal>BEFORE</>, <literal>AFTER</>,
- or <literal>UNKNOWN</>.
+ contains one of <literal>BEFORE</>, <literal>AFTER</>, or
+ <literal>INSTEAD OF</>.
</para>
</listitem>
</varlistentry>
<term><literal>TD["level"]</></term>
<listitem>
<para>
- contains one of <literal>ROW</>,
- <literal>STATEMENT</>, or <literal>UNKNOWN</>.
+ contains <literal>ROW</> or <literal>STATEMENT</>.
</para>
</listitem>
</varlistentry>
</para>
<para>
- If <literal>TD["when"]</literal> is <literal>BEFORE</> and
+ If <literal>TD["when"]</literal> is <literal>BEFORE</> or
+ <literal>INSTEAD OF</> and
<literal>TD["level"]</literal> is <literal>ROW</>, you can
return <literal>None</literal> or <literal>"OK"</literal> from the
Python function to indicate the row is unmodified,
- <literal>"SKIP"</> to abort the event, or <literal>"MODIFY"</> to
- indicate you've modified the row.
+ <literal>"SKIP"</> to abort the event, or if <literal>TD["event"]</>
+ is <command>INSERT</> or <command>UPDATE</> you can return
+ <literal>"MODIFY"</> to indicate you've modified the new row.
Otherwise the return value is ignored.
</para>
</sect1>
<term><varname>$TG_when</varname></term>
<listitem>
<para>
- The string <literal>BEFORE</> or <literal>AFTER</> depending on the
- type of trigger event.
+ The string <literal>BEFORE</>, <literal>AFTER</>, or
+ <literal>INSTEAD OF</>, depending on the type of trigger event.
</para>
</listitem>
</varlistentry>
the operation (<command>INSERT</>/<command>UPDATE</>/<command>DELETE</>) that fired the trigger will proceed
normally. <literal>SKIP</> tells the trigger manager to silently suppress
the operation for this row. If a list is returned, it tells PL/Tcl to
- return a modified row to the trigger manager that will be inserted
- instead of the one given in <varname>$NEW</>. (This works for <command>INSERT</> and <command>UPDATE</>
- only.) Needless to say that all this is only meaningful when the trigger
- is <literal>BEFORE</> and <command>FOR EACH ROW</>; otherwise the return value is ignored.
+ return a modified row to the trigger manager. This is only meaningful
+ for row-level <literal>BEFORE</> <command>INSERT</> or <command>UPDATE</>
+ triggers for which the modified row will be inserted instead of the one
+ given in <varname>$NEW</>; or for row-level <literal>INSTEAD OF</>
+ <command>INSERT</> or <command>UPDATE</> triggers where the returned row
+ is used to support <command>INSERT RETURNING</> and
+ <command>UPDATE RETURNING</> commands. The return value is ignored for
+ other types of triggers.
</para>
<para>
physical row, you probably want to use a trigger, not a rule.
More information about the rules system is in <xref linkend="rules">.
</para>
-
+
<para>
Presently, <literal>ON SELECT</literal> rules must be unconditional
<literal>INSTEAD</literal> rules and must have actions that consist
sufficient for your purposes) to replace update actions on the view
with appropriate updates on other tables. If you want to support
<command>INSERT RETURNING</> and so on, then be sure to put a suitable
- <literal>RETURNING</> clause into each of these rules.
+ <literal>RETURNING</> clause into each of these rules. Alternatively,
+ an updatable view can be implemented using <literal>INSTEAD OF</>
+ triggers (see <xref linkend="sql-createtrigger">).
</para>
<para>
<programlisting>
CREATE RULE "_RETURN" AS
ON SELECT TO t1
- DO INSTEAD
+ DO INSTEAD
SELECT * FROM t2;
CREATE RULE "_RETURN" AS
ON SELECT TO t2
- DO INSTEAD
+ DO INSTEAD
SELECT * FROM t1;
SELECT * FROM t1;
<refsynopsisdiv>
<synopsis>
-CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTER } { <replaceable class="PARAMETER">event</replaceable> [ OR ... ] }
+CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTER | INSTEAD OF } { <replaceable class="PARAMETER">event</replaceable> [ OR ... ] }
ON <replaceable class="PARAMETER">table</replaceable> [ FOR [ EACH ] { ROW | STATEMENT } ]
[ WHEN ( <replaceable class="parameter">condition</replaceable> ) ]
EXECUTE PROCEDURE <replaceable class="PARAMETER">function_name</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
<para>
<command>CREATE TRIGGER</command> creates a new trigger. The
- trigger will be associated with the specified table and will
+ trigger will be associated with the specified table or view and will
execute the specified function <replaceable
class="parameter">function_name</replaceable> when certain events occur.
</para>
<para>
- The trigger can be specified to fire either before the
+ The trigger can be specified to fire before the
operation is attempted on a row (before constraints are checked and
the <command>INSERT</command>, <command>UPDATE</command>, or
- <command>DELETE</command> is attempted) or after the operation has
+ <command>DELETE</command> is attempted); or after the operation has
completed (after constraints are checked and the
<command>INSERT</command>, <command>UPDATE</command>, or
- <command>DELETE</command> has completed). If the trigger fires
- before the event, the trigger can skip the operation for the
- current row, or change the row being inserted (for
+ <command>DELETE</command> has completed); or instead of the operation
+ (in the case of inserts, updates or deletes on a view).
+ If the trigger fires before or instead of the event, the trigger can skip
+ the operation for the current row, or change the row being inserted (for
<command>INSERT</command> and <command>UPDATE</command> operations
only). If the trigger fires after the event, all changes, including
the effects of other triggers, are <quote>visible</quote>
</para>
<para>
- In addition, triggers may be defined to fire for a
+ Triggers that are specified to fire <literal>INSTEAD OF</> the trigger
+ event must be marked <literal>FOR EACH ROW</>, and can only be defined
+ on views. <literal>BEFORE</> and <literal>AFTER</> triggers on a view
+ must be marked as <literal>FOR EACH STATEMENT</>.
+ </para>
+
+ <para>
+ In addition, triggers may be defined to fire for
<command>TRUNCATE</command>, though only
<literal>FOR EACH STATEMENT</literal>.
</para>
+ <para>
+ The following table summarizes which types of triggers may be used on
+ tables and views:
+ </para>
+
+ <informaltable id="supported-trigger-types">
+ <tgroup cols="4">
+ <thead>
+ <row>
+ <entry>When</entry>
+ <entry>Event</entry>
+ <entry>Row-level</entry>
+ <entry>Statement-level</entry>
+ </row>
+ </thead>
+ <tbody>
+ <row>
+ <entry align="center" morerows="1"><literal>BEFORE</></entry>
+ <entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
+ <entry align="center">Tables</entry>
+ <entry align="center">Tables and views</entry>
+ </row>
+ <row>
+ <entry align="center"><command>TRUNCATE</></entry>
+ <entry align="center">—</entry>
+ <entry align="center">Tables</entry>
+ </row>
+ <row>
+ <entry align="center" morerows="1"><literal>AFTER</></entry>
+ <entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
+ <entry align="center">Tables</entry>
+ <entry align="center">Tables and views</entry>
+ </row>
+ <row>
+ <entry align="center"><command>TRUNCATE</></entry>
+ <entry align="center">—</entry>
+ <entry align="center">Tables</entry>
+ </row>
+ <row>
+ <entry align="center" morerows="1"><literal>INSTEAD OF</></entry>
+ <entry align="center"><command>INSERT</>/<command>UPDATE</>/<command>DELETE</></entry>
+ <entry align="center">Views</entry>
+ <entry align="center">—</entry>
+ </row>
+ <row>
+ <entry align="center"><command>TRUNCATE</></entry>
+ <entry align="center">—</entry>
+ <entry align="center">—</entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </informaltable>
+
<para>
Also, a trigger definition can specify a Boolean <literal>WHEN</>
condition, which will be tested to see whether the trigger should
<varlistentry>
<term><literal>BEFORE</literal></term>
<term><literal>AFTER</literal></term>
+ <term><literal>INSTEAD OF</literal></term>
<listitem>
<para>
- Determines whether the function is called before or after the
- event.
+ Determines whether the function is called before, after, or instead of
+ the event.
</para>
</listitem>
</varlistentry>
The trigger will only fire if at least one of the listed columns
is mentioned as a target of the update.
</para>
+
+ <para>
+ <literal>UPDATE INSTEAD OF</> triggers do not support lists of columns.
+ </para>
</listitem>
</varlistentry>
<term><replaceable class="parameter">table</replaceable></term>
<listitem>
<para>
- The name (optionally schema-qualified) of the table the trigger
+ The name (optionally schema-qualified) of the table or view the trigger
is for.
</para>
</listitem>
and <literal>DELETE</> triggers cannot refer to <literal>NEW</>.
</para>
+ <para>
+ <literal>INSTEAD OF</> triggers do not support <literal>WHEN</>
+ conditions.
+ </para>
+
<para>
Currently, <literal>WHEN</literal> expressions cannot contain
subqueries.
WHEN (OLD.* IS DISTINCT FROM NEW.*)
EXECUTE PROCEDURE log_account_update();
</programlisting>
+
+ Execute the function <function>view_insert_row</> for each row to insert
+ rows into the tables underlying a view:
+
+<programlisting>
+CREATE TRIGGER view_insert
+ INSTEAD OF INSERT ON my_view
+ FOR EACH ROW
+ EXECUTE PROCEDURE view_insert_row();
+</programlisting>
</para>
<para>
<para>
The ability to fire triggers for <command>TRUNCATE</command> is a
- <productname>PostgreSQL</> extension of the SQL standard.
+ <productname>PostgreSQL</> extension of the SQL standard, as is the
+ ability to define statement-level triggers on views.
</para>
</refsect1>
</para>
<para>
- When reading the <acronym>SQL</acronym> representations of the
+ When reading the <acronym>SQL</acronym> representations of the
query trees in this chapter it is necessary to be able to identify
the parts the statement is broken into when it is in the query tree
structure. The parts of a query tree are
</para>
<para>
- <command>SELECT</command> queries normally don't have a result
- relation. The special case of a <command>SELECT INTO</command> is
- mostly identical to a <command>CREATE TABLE</command> followed by a
- <literal>INSERT ... SELECT</literal> and is not discussed
- separately here.
+ <command>SELECT</command> queries don't have a result
+ relation. (The special case of <command>SELECT INTO</command> is
+ mostly identical to <command>CREATE TABLE</command> followed by
+ <literal>INSERT ... SELECT</literal>, and is not discussed
+ separately here.)
</para>
<para>
</para>
<para>
- <command>DELETE</command> commands don't need a target list
- because they don't produce any result. In fact, the planner will
- add a special <acronym>CTID</> entry to the empty target list, but
- this is after the rule system and will be discussed later; for the
- rule system, the target list is empty.
+ <command>DELETE</command> commands don't need a normal target list
+ because they don't produce any result. Instead, the rule system
+ adds a special <acronym>CTID</> entry to the empty target list,
+ to allow the executor to find the row to be deleted.
+ (<acronym>CTID</> is added when the result relation is an ordinary
+ table. If it is a view, a whole-row variable is added instead,
+ as described in <xref linkend="rules-views-update">.)
</para>
<para>
For <command>UPDATE</command> commands, the target list
describes the new rows that should replace the old ones. In the
rule system, it contains just the expressions from the <literal>SET
- column = expression</literal> part of the command. The planner will handle
- missing columns by inserting expressions that copy the values from
- the old row into the new one. And it will add the special
- <acronym>CTID</> entry just as for <command>DELETE</command>, too.
+ column = expression</literal> part of the command. The planner will
+ handle missing columns by inserting expressions that copy the values
+ from the old row into the new one. Just as for <command>DELETE</>,
+ the rule system adds a <acronym>CTID</> or whole-row variable so that
+ the executor can identify the old row to be updated.
</para>
<para>
<programlisting>
CREATE VIEW myview AS SELECT * FROM mytab;
</programlisting>
-
+
compared against the two commands:
<programlisting>
CREATE RULE "_RETURN" AS ON SELECT TO myview DO INSTEAD
SELECT * FROM mytab;
</programlisting>
-
+
because this is exactly what the <command>CREATE VIEW</command>
command does internally. This has some side effects. One of them
is that the information about a view in the
The action of the rule is one query tree that is a copy of the
<command>SELECT</command> statement in the view creation command.
</para>
-
+
<note>
<para>
The two extra range
<para>
To expand the view, the rewriter simply creates a subquery range-table
entry containing the rule's action query tree, and substitutes this
- range table entry for the original one that referenced the view. The
+ range table entry for the original one that referenced the view. The
resulting rewritten query tree is almost the same as if you had typed:
<programlisting>
WHERE shoe_ready.total_avail >= 2;
</programlisting>
- The first rule applied will be the one for the
+ The first rule applied will be the one for the
<literal>shoe_ready</literal> view and it results in the
query tree:
<para>
Two details of the query tree aren't touched in the description of
view rules above. These are the command type and the result relation.
- In fact, view rules don't need this information.
+ In fact, the command type is not needed by view rules, but the result
+ relation may affect the way in which the query rewriter works, because
+ special care needs to be taken if the result relation is a view.
</para>
<para>
</programlisting>
and thus the executor run over the join will produce exactly the
- same result set as a:
+ same result set as:
<programlisting>
SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a;
</programlisting>
-
- will do. But there is a little problem in
- <command>UPDATE</command>: The executor does not care what the
- results from the join it is doing are meant for. It just produces
- a result set of rows. The difference that one is a
- <command>SELECT</command> command and the other is an
- <command>UPDATE</command> is handled in the caller of the
- executor. The caller still knows (looking at the query tree) that
- this is an <command>UPDATE</command>, and it knows that this
- result should go into table <literal>t1</>. But which of the rows that are
- there has to be replaced by the new row?
+
+ But there is a little problem in
+ <command>UPDATE</command>: the part of the executor plan that does
+ the join does not care what the results from the join are
+ meant for. It just produces a result set of rows. The fact that
+ one is a <command>SELECT</command> command and the other is an
+ <command>UPDATE</command> is handled higher up in the executor, where
+ it knows that this is an <command>UPDATE</command>, and it knows that
+ this result should go into table <literal>t1</>. But which of the rows
+ that are there has to be replaced by the new row?
</para>
<para>
<programlisting>
SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
</programlisting>
-
+
Now another detail of <productname>PostgreSQL</productname> enters
the stage. Old table rows aren't overwritten, and this
is why <command>ROLLBACK</command> is fast. In an <command>UPDATE</command>,
<acronym>CTID</> pointed to, the <literal>cmax</> and
<literal>xmax</> entries are set to the current command counter
and current transaction ID. Thus the old row is hidden, and after
- the transaction commits the vacuum cleaner can really remove it.
+ the transaction commits the vacuum cleaner can eventually remove
+ the dead row.
</para>
<para>
<para>
What happens if a view is named as the target relation for an
<command>INSERT</command>, <command>UPDATE</command>, or
- <command>DELETE</command>? After doing the substitutions
- described above, we will have a query tree in which the result
- relation points at a subquery range-table entry. This will not
- work, so the rewriter throws an error if it sees it has produced
- such a thing.
+ <command>DELETE</command>? Simply doing the substitutions
+ described above would give a query tree in which the result
+ relation points at a subquery range-table entry, which will not
+ work. Instead, the rewriter assumes that the operation will be
+ handled by an <literal>INSTEAD OF</> trigger on the view.
+ (If there is no such trigger, the executor will throw an error
+ when execution starts.) Rewriting works slightly differently
+ 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
+ view query to produce the <quote>old</> rows that the command will
+ attempt to update or delete. 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>
<para>
- To change this, we can define rules that modify the behavior of
- these kinds of commands. This is the topic of the next section.
+ The problem that now arises is how to identify the rows to be
+ updated in the view. Recall that when the result relation
+ is a table, a special <acronym>CTID</> entry is added to the target
+ 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</>, since its rows do not have
+ actual physical locations. Instead, for an <command>UPDATE</command>
+ or <command>DELETE</command> operation, a special <literal>wholerow</>
+ 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</> row to the <literal>INSTEAD OF</> trigger. It is
+ up to the trigger to work out what to update based on the old and
+ new row values.
+</para>
+
+<para>
+ If there are no <literal>INSTEAD OF</> triggers to update the view,
+ the executor will throw an error, because it cannot automatically
+ update a view by itself. To change this, we can define rules that
+ modify the behavior of <command>INSERT</command>,
+ <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 the next section.
+</para>
+
+<para>
+ Note that rules are evaluated first, rewriting the original query
+ before it is planned and executed. Therefore, if a view has
+ <literal>INSTEAD OF</> triggers as well as rules on <command>INSERT</>,
+ <command>UPDATE</>, or <command>DELETE</>, then the rules will be
+ evaluated first, and depending on the result, the triggers may not be
+ used at all.
</para>
</sect2>
</programlisting>
Take a quick look at the current data:
-
+
<programlisting>
SELECT * FROM shoelace;
AND shoelace_data.sl_name = s.sl_name
AND (s.sl_avail + shoelace_arrive.arr_quant) <> s.sl_avail;
</programlisting>
-
- After that the rule system runs out of rules and returns the
+
+ After that the rule system runs out of rules and returns the
generated query trees.
</para>
WHERE s.sl_name = shoelace_arrive.arr_name
AND shoelace_data.sl_name = s.sl_name
AND s.sl_avail + shoelace_arrive.arr_quant <> s.sl_avail;
-
+
UPDATE shoelace_data
SET sl_avail = shoelace_data.sl_avail + shoelace_arrive.arr_quant
FROM shoelace_arrive shoelace_arrive,
in total uses 4 nesting/joined views, where one of them
itself has a subquery qualification containing a view
and where calculated view columns are used,
- gets rewritten into
+ gets rewritten into
one single query tree that deletes the requested data
from a real table.
</para>
SELECT person, phone FROM phone_data WHERE phone NOT LIKE '412%';
</programlisting>
This view might seem secure, since the rule system will rewrite any
- <command>SELECT</command> from <literal>phone_number</> into a
+ <command>SELECT</command> from <literal>phone_number</> into a
<command>SELECT</command> from <literal>phone_data</> and add the
qualification that only entries where <literal>phone</> does not begin
with 412 are wanted. But if the user can create his or her own functions,
it is not difficult to convince the planner to execute the user-defined
function prior to the <function>NOT LIKE</function> expression.
+ For example:
<programlisting>
CREATE FUNCTION tricky(text, text) RETURNS bool AS $$
BEGIN
RETURN true;
END
$$ LANGUAGE plpgsql COST 0.0000000000000000000001;
+
SELECT * FROM phone_number WHERE tricky(person, phone);
</programlisting>
Every person and phone number in the <literal>phone_data</> table will be
execute the inexpensive <function>tricky</function> function before the
more expensive <function>NOT LIKE</function>. Even if the user is
prevented from defining new functions, built-in functions can be used in
- similar attacks. (For example, casting functions include their inputs in
- the error messages they produce.)
+ similar attacks. (For example, most casting functions include their
+ input values in the error messages they produce.)
</para>
<para>
</para>
<para>
- On the other hand, a trigger cannot be created on views because
- there is no real data in a view relation; however INSERT, UPDATE,
- and DELETE rules can be created on views.
+ In this chapter, we focused on using rules to update views. All of
+ the update rule examples in this chapter can also be implemented
+ using <literal>INSTEAD OF</> triggers on the views. Writing such
+ triggers is often easier than writing rules, particularly if complex
+ logic is required to perform the update.
</para>
<para>
For the things that can be implemented by both, which is best
depends on the usage of the database.
- A trigger is fired for any affected row once. A rule manipulates
+ A trigger is fired once for each affected row. A rule modifies
the query or generates an additional query. So if many
rows are affected in one statement, a rule issuing one extra
command is likely to be faster than a trigger that is
- called for every single row and must execute its operations
+ called for every single row and must re-determine what to do
many times. However, the trigger approach is conceptually far
simpler than the rule approach, and is easier for novices to get right.
</para>
<para>
Now we look at different types of deletes. In the case of a:
-
+
<programlisting>
DELETE FROM computer WHERE hostname = 'mypc.local.net';
</programlisting>
<para>
A trigger is a specification that the database should automatically
execute a particular function whenever a certain type of operation is
- performed. Triggers can be defined to execute either before or after any
+ performed. Triggers can be attached to both tables and views.
+ </para>
+
+ <para>
+ On tables, triggers can be defined to execute either before or after any
<command>INSERT</command>, <command>UPDATE</command>, or
<command>DELETE</command> operation, either once per modified row,
or once per <acronym>SQL</acronym> statement.
appropriate time to handle the event.
</para>
+ <para>
+ On views, triggers can be defined to execute instead of
+ <command>INSERT</command>, <command>UPDATE</command>, or
+ <command>DELETE</command> operations. <literal>INSTEAD OF</> triggers
+ are fired once for each row that needs to be modified in the view.
+ It is the responsibility of the
+ trigger's function to perform the necessary modifications to the
+ underlying base tables and, where appropriate, return the modified
+ row as it will appear in the view. Triggers on views can also be defined
+ to execute once per <acronym>SQL</acronym> statement, before or after
+ <command>INSERT</command>, <command>UPDATE</command>, or
+ <command>DELETE</command> operations.
+ </para>
+
<para>
The trigger function must be defined before the trigger itself can be
created. The trigger function must be declared as a
two types of triggers are sometimes called <firstterm>row-level</>
triggers and <firstterm>statement-level</> triggers,
respectively. Triggers on <command>TRUNCATE</command> may only be
- defined at statement-level.
+ defined at statement level. On views, triggers that fire before or
+ after may only be defined at statement level, while triggers that fire
+ instead of an <command>INSERT</command>, <command>UPDATE</command>,
+ or <command>DELETE</command> may only be defined at row level.
</para>
<para>
- Triggers are also classified as <firstterm>before</> triggers and
- <firstterm>after</> triggers.
- Statement-level before triggers naturally fire before the
- statement starts to do anything, while statement-level after
- triggers fire at the very end of the statement. Row-level before
+ Triggers are also classified according to whether they fire
+ <firstterm>before</>, <firstterm>after</>, or
+ <firstterm>instead of</> the operation. These are referred to
+ as <literal>BEFORE</> triggers, <literal>AFTER</> triggers, and
+ <literal>INSTEAD OF</> triggers respectively.
+ Statement-level <literal>BEFORE</> triggers naturally fire before the
+ statement starts to do anything, while statement-level <literal>AFTER</>
+ triggers fire at the very end of the statement. These types of
+ triggers may be defined on tables or views. Row-level <literal>BEFORE</>
triggers fire immediately before a particular row is operated on,
- while row-level after triggers fire at the end of the statement
- (but before any statement-level after triggers).
+ while row-level <literal>AFTER</> triggers fire at the end of the
+ statement (but before any statement-level <literal>AFTER</> triggers).
+ These types of triggers may only be defined on tables. Row-level
+ <literal>INSTEAD OF</> triggers may only be defined on views, and fire
+ immediately as each row in the view is identified as needing to be
+ operated on.
</para>
<para>
<para>
It can return <symbol>NULL</> to skip the operation for the
current row. This instructs the executor to not perform the
- row-level operation that invoked the trigger (the insertion or
- modification of a particular table row).
+ row-level operation that invoked the trigger (the insertion,
+ modification, or deletion of a particular table row).
</para>
</listitem>
</listitem>
</itemizedlist>
- A row-level before trigger that does not intend to cause either of
- these behaviors must be careful to return as its result the same
+ A row-level <literal>BEFORE</> trigger that does not intend to cause
+ either of these behaviors must be careful to return as its result the same
row that was passed in (that is, the <varname>NEW</varname> row
for <command>INSERT</command> and <command>UPDATE</command>
triggers, the <varname>OLD</varname> row for
<command>DELETE</command> triggers).
</para>
+ <para>
+ A row-level <literal>INSTEAD OF</> trigger should either return
+ <symbol>NULL</> to indicate that it did not modify any data from
+ the view's underlying base tables, or it should return the view
+ row that was passed in (the <varname>NEW</varname> row
+ for <command>INSERT</command> and <command>UPDATE</command>
+ operations, or the <varname>OLD</varname> row for
+ <command>DELETE</command> operations). A nonnull return value is
+ used to signal that the trigger performed the necessary data
+ modifications in the view. This will cause the count of the number
+ of rows affected by the command to be incremented. For
+ <command>INSERT</> and <command>UPDATE</> operations, the trigger
+ may modify the <varname>NEW</> row before returning it. This will
+ change the data returned by
+ <command>INSERT RETURNING</> or <command>UPDATE RETURNING</>,
+ and is useful when the view will not show exactly the same data
+ that was provided.
+ </para>
+
<para>
The return value is ignored for row-level triggers fired after an
operation, and so they can return <symbol>NULL</>.
<para>
If more than one trigger is defined for the same event on the same
relation, the triggers will be fired in alphabetical order by
- trigger name. In the case of before triggers, the
- possibly-modified row returned by each trigger becomes the input
- to the next trigger. If any before trigger returns
+ trigger name. In the case of <literal>BEFORE</> and
+ <literal>INSTEAD OF</> triggers, the possibly-modified row returned by
+ each trigger becomes the input to the next trigger. If any
+ <literal>BEFORE</> or <literal>INSTEAD OF</> trigger returns
<symbol>NULL</>, the operation is abandoned for that row and subsequent
- triggers are not fired.
+ triggers are not fired (for that row).
</para>
<para>
be fired. In row-level triggers the <literal>WHEN</> condition can
examine the old and/or new values of columns of the row. (Statement-level
triggers can also have <literal>WHEN</> conditions, although the feature
- is not so useful for them.) In a before trigger, the <literal>WHEN</>
+ is not so useful for them.) In a <literal>BEFORE</> trigger, the
+ <literal>WHEN</>
condition is evaluated just before the function is or would be executed,
so using <literal>WHEN</> is not materially different from testing the
same condition at the beginning of the trigger function. However, in
- an after trigger, the <literal>WHEN</> condition is evaluated just after
- the row update occurs, and it determines whether an event is queued to
- fire the trigger at the end of statement. So when an after trigger's
+ an <literal>AFTER</> trigger, the <literal>WHEN</> condition is evaluated
+ just after the row update occurs, and it determines whether an event is
+ queued to fire the trigger at the end of statement. So when an
+ <literal>AFTER</> trigger's
<literal>WHEN</> condition does not return true, it is not necessary
to queue an event nor to re-fetch the row at end of statement. This
can result in significant speedups in statements that modify many
rows, if the trigger only needs to be fired for a few of the rows.
+ <literal>INSTEAD OF</> triggers do not support
+ <literal>WHEN</> conditions.
</para>
<para>
- Typically, row before triggers are used for checking or
+ Typically, row-level <literal>BEFORE</> triggers are used for checking or
modifying the data that will be inserted or updated. For example,
- a before trigger might be used to insert the current time into a
+ a <literal>BEFORE</> trigger might be used to insert the current time into a
<type>timestamp</type> column, or to check that two elements of the row are
- consistent. Row after triggers are most sensibly
+ consistent. Row-level <literal>AFTER</> triggers are most sensibly
used to propagate the updates to other tables, or make consistency
checks against other tables. The reason for this division of labor is
- that an after trigger can be certain it is seeing the final value of the
- row, while a before trigger cannot; there might be other before triggers
- firing after it. If you have no specific reason to make a trigger before
- or after, the before case is more efficient, since the information about
+ that an <literal>AFTER</> trigger can be certain it is seeing the final
+ value of the row, while a <literal>BEFORE</> trigger cannot; there might
+ be other <literal>BEFORE</> triggers firing after it. If you have no
+ specific reason to make a trigger <literal>BEFORE</> or
+ <literal>AFTER</>, the <literal>BEFORE</> case is more efficient, since
+ the information about
the operation doesn't have to be saved until end of statement.
</para>
Statement-level triggers follow simple visibility rules: none of
the changes made by a statement are visible to statement-level
triggers that are invoked before the statement, whereas all
- modifications are visible to statement-level after triggers.
+ modifications are visible to statement-level <literal>AFTER</>
+ triggers.
</para>
</listitem>
<para>
The data change (insertion, update, or deletion) causing the
trigger to fire is naturally <emphasis>not</emphasis> visible
- to SQL commands executed in a row-level before trigger, because
- it hasn't happened yet.
+ to SQL commands executed in a row-level <literal>BEFORE</> trigger,
+ because it hasn't happened yet.
</para>
</listitem>
<listitem>
<para>
- However, SQL commands executed in a row-level before
+ However, SQL commands executed in a row-level <literal>BEFORE</>
trigger <emphasis>will</emphasis> see the effects of data
changes for rows previously processed in the same outer
command. This requires caution, since the ordering of these
<listitem>
<para>
- When a row-level after trigger is fired, all data changes made
+ Similarly, a row-level <literal>INSTEAD OF</> trigger will see the
+ effects of data changes made by previous firings of <literal>INSTEAD
+ OF</> triggers in the same outer command.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ When a row-level <literal>AFTER</> trigger is fired, all data
+ changes made
by the outer command are already complete, and are visible to
the invoked trigger function.
</para>
</listitem>
</varlistentry>
+ <varlistentry>
+ <term><literal>TRIGGER_FIRED_INSTEAD(tg_event)</literal></term>
+ <listitem>
+ <para>
+ Returns true if the trigger fired instead of the operation.
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>TRIGGER_FIRED_FOR_ROW(tg_event)</literal></term>
<listitem>
trigger->relation = heapRel;
trigger->funcname = SystemFuncName("unique_key_recheck");
trigger->args = NIL;
- trigger->before = false;
trigger->row = true;
+ trigger->timing = TRIGGER_TYPE_AFTER;
trigger->events = TRIGGER_TYPE_INSERT | TRIGGER_TYPE_UPDATE;
trigger->columns = NIL;
trigger->whenClause = NULL;
position('EXECUTE PROCEDURE' in substring(pg_get_triggerdef(t.oid) from 48)) + 47)
AS character_data) AS action_statement,
CAST(
- CASE WHEN t.tgtype & 1 = 1 THEN 'ROW' ELSE 'STATEMENT' END
+ -- hard-wired reference to TRIGGER_TYPE_ROW
+ CASE t.tgtype & 1 WHEN 1 THEN 'ROW' ELSE 'STATEMENT' END
AS character_data) AS action_orientation,
CAST(
- CASE WHEN t.tgtype & 2 = 2 THEN 'BEFORE' ELSE 'AFTER' END
- AS character_data) AS condition_timing,
- CAST(null AS sql_identifier) AS condition_reference_old_table,
- CAST(null AS sql_identifier) AS condition_reference_new_table,
- CAST(null AS sql_identifier) AS condition_reference_old_row,
- CAST(null AS sql_identifier) AS condition_reference_new_row,
+ -- hard-wired refs to TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_INSTEAD
+ CASE t.tgtype & 66 WHEN 2 THEN 'BEFORE' WHEN 64 THEN 'INSTEAD OF' ELSE 'AFTER' END
+ AS character_data) AS action_timing,
+ CAST(null AS sql_identifier) AS action_reference_old_table,
+ CAST(null AS sql_identifier) AS action_reference_new_table,
+ CAST(null AS sql_identifier) AS action_reference_old_row,
+ CAST(null AS sql_identifier) AS action_reference_new_row,
CAST(null AS time_stamp) AS created
FROM pg_namespace n, pg_class c, pg_trigger t,
+ -- hard-wired refs to TRIGGER_TYPE_INSERT, TRIGGER_TYPE_DELETE,
+ -- TRIGGER_TYPE_UPDATE; we intentionally omit TRIGGER_TYPE_TRUNCATE
(VALUES (4, 'INSERT'),
(8, 'DELETE'),
(16, 'UPDATE')) AS em (num, text)
THEN 'YES' ELSE 'NO' END
AS yes_or_no) AS is_insertable_into,
- CAST('NO' AS yes_or_no) AS is_trigger_updatable,
- CAST('NO' AS yes_or_no) AS is_trigger_deletable,
- CAST('NO' AS yes_or_no) AS is_trigger_insertable_into
+ CAST(
+ -- TRIGGER_TYPE_ROW + TRIGGER_TYPE_INSTEAD + TRIGGER_TYPE_UPDATE
+ CASE WHEN EXISTS (SELECT 1 FROM pg_trigger WHERE tgrelid = c.oid AND tgtype & 81 = 81)
+ THEN 'YES' ELSE 'NO' END
+ AS yes_or_no) AS is_trigger_updatable,
+
+ CAST(
+ -- TRIGGER_TYPE_ROW + TRIGGER_TYPE_INSTEAD + TRIGGER_TYPE_DELETE
+ CASE WHEN EXISTS (SELECT 1 FROM pg_trigger WHERE tgrelid = c.oid AND tgtype & 73 = 73)
+ THEN 'YES' ELSE 'NO' END
+ AS yes_or_no) AS is_trigger_deletable,
+
+ CAST(
+ -- TRIGGER_TYPE_ROW + TRIGGER_TYPE_INSTEAD + TRIGGER_TYPE_INSERT
+ CASE WHEN EXISTS (SELECT 1 FROM pg_trigger WHERE tgrelid = c.oid AND tgtype & 69 = 69)
+ THEN 'YES' ELSE 'NO' END
+ AS yes_or_no) AS is_trigger_insertable_into
FROM pg_namespace nc, pg_class c
T211 Basic trigger capability 07 TRIGGER privilege YES
T211 Basic trigger capability 08 Multiple triggers for the same event are executed in the order in which they were created in the catalog NO intentionally omitted
T212 Enhanced trigger capability YES
-T213 INSTEAD OF triggers NO
+T213 INSTEAD OF triggers YES
T231 Sensitive cursors YES
T241 START TRANSACTION statement YES
T251 SET TRANSACTION statement: LOCAL option NO
/* BEFORE ROW INSERT Triggers */
if (resultRelInfo->ri_TrigDesc &&
- resultRelInfo->ri_TrigDesc->n_before_row[TRIGGER_EVENT_INSERT] > 0)
+ resultRelInfo->ri_TrigDesc->trig_insert_before_row)
{
HeapTuple newtuple;
fk_trigger = makeNode(CreateTrigStmt);
fk_trigger->trigname = "RI_ConstraintTrigger";
fk_trigger->relation = myRel;
- fk_trigger->before = false;
fk_trigger->row = true;
+ fk_trigger->timing = TRIGGER_TYPE_AFTER;
/* Either ON INSERT or ON UPDATE */
if (on_insert)
fk_trigger = makeNode(CreateTrigStmt);
fk_trigger->trigname = "RI_ConstraintTrigger";
fk_trigger->relation = fkconstraint->pktable;
- fk_trigger->before = false;
fk_trigger->row = true;
+ fk_trigger->timing = TRIGGER_TYPE_AFTER;
fk_trigger->events = TRIGGER_TYPE_DELETE;
fk_trigger->columns = NIL;
fk_trigger->whenClause = NULL;
fk_trigger = makeNode(CreateTrigStmt);
fk_trigger->trigname = "RI_ConstraintTrigger";
fk_trigger->relation = fkconstraint->pktable;
- fk_trigger->before = false;
fk_trigger->row = true;
+ fk_trigger->timing = TRIGGER_TYPE_AFTER;
fk_trigger->events = TRIGGER_TYPE_UPDATE;
fk_trigger->columns = NIL;
fk_trigger->whenClause = NULL;
/* Local function prototypes */
static void ConvertTriggerToFK(CreateTrigStmt *stmt, Oid funcoid);
-static void InsertTrigger(TriggerDesc *trigdesc, Trigger *trigger, int indx);
+static void SetTriggerFlags(TriggerDesc *trigdesc, Trigger *trigger);
static HeapTuple GetTupleForTrigger(EState *estate,
EPQState *epqstate,
ResultRelInfo *relinfo,
*/
rel = heap_openrv(stmt->relation, ShareRowExclusiveLock);
- if (rel->rd_rel->relkind != RELKIND_RELATION)
+ /*
+ * Triggers must be on tables or views, and there are additional
+ * relation-type-specific restrictions.
+ */
+ if (rel->rd_rel->relkind == RELKIND_RELATION)
+ {
+ /* Tables can't have INSTEAD OF triggers */
+ if (stmt->timing != TRIGGER_TYPE_BEFORE &&
+ stmt->timing != TRIGGER_TYPE_AFTER)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is a table",
+ RelationGetRelationName(rel)),
+ errdetail("Tables cannot have INSTEAD OF triggers.")));
+ }
+ else if (rel->rd_rel->relkind == RELKIND_VIEW)
+ {
+ /*
+ * Views can have INSTEAD OF triggers (which we check below are
+ * row-level), or statement-level BEFORE/AFTER triggers.
+ */
+ if (stmt->timing != TRIGGER_TYPE_INSTEAD && stmt->row)
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is a view",
+ RelationGetRelationName(rel)),
+ errdetail("Views cannot have row-level BEFORE or AFTER triggers.")));
+ /* Disallow TRUNCATE triggers on VIEWs */
+ if (TRIGGER_FOR_TRUNCATE(stmt->events))
+ ereport(ERROR,
+ (errcode(ERRCODE_WRONG_OBJECT_TYPE),
+ errmsg("\"%s\" is a view",
+ RelationGetRelationName(rel)),
+ errdetail("Views cannot have TRUNCATE triggers.")));
+ }
+ else
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not a table or view",
RelationGetRelationName(rel))));
if (!allowSystemTableMods && IsSystemRelation(rel))
/* Compute tgtype */
TRIGGER_CLEAR_TYPE(tgtype);
- if (stmt->before)
- TRIGGER_SETT_BEFORE(tgtype);
if (stmt->row)
TRIGGER_SETT_ROW(tgtype);
+ tgtype |= stmt->timing;
tgtype |= stmt->events;
/* Disallow ROW-level TRUNCATE triggers */
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("TRUNCATE FOR EACH ROW triggers are not supported")));
+ /* INSTEAD triggers must be row-level, and can't have WHEN or columns */
+ if (TRIGGER_FOR_INSTEAD(tgtype))
+ {
+ if (!TRIGGER_FOR_ROW(tgtype))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("INSTEAD OF triggers must be FOR EACH ROW")));
+ if (stmt->whenClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("INSTEAD OF triggers cannot have WHEN conditions")));
+ if (stmt->columns != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("INSTEAD OF triggers cannot have column lists")));
+ }
+
/*
* Parse the WHEN clause, if any
*/
rel = heap_open(relid, ShareRowExclusiveLock);
- if (rel->rd_rel->relkind != RELKIND_RELATION)
+ if (rel->rd_rel->relkind != RELKIND_RELATION &&
+ rel->rd_rel->relkind != RELKIND_VIEW)
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("\"%s\" is not a table",
+ errmsg("\"%s\" is not a table or view",
RelationGetRelationName(rel))));
if (!allowSystemTableMods && IsSystemRelation(rel))
trigdesc->triggers = triggers;
trigdesc->numtriggers = numtrigs;
for (i = 0; i < numtrigs; i++)
- InsertTrigger(trigdesc, &(triggers[i]), i);
+ SetTriggerFlags(trigdesc, &(triggers[i]));
/* Copy completed trigdesc into cache storage */
oldContext = MemoryContextSwitchTo(CacheMemoryContext);
}
/*
- * Insert the given trigger into the appropriate index list(s) for it
- *
- * To simplify storage management, we allocate each index list at the max
- * possible size (trigdesc->numtriggers) if it's used at all. This does
- * not waste space permanently since we're only building a temporary
- * trigdesc at this point.
+ * Update the TriggerDesc's hint flags to include the specified trigger
*/
static void
-InsertTrigger(TriggerDesc *trigdesc, Trigger *trigger, int indx)
+SetTriggerFlags(TriggerDesc *trigdesc, Trigger *trigger)
{
- uint16 *n;
- int **t,
- **tp;
-
- if (TRIGGER_FOR_ROW(trigger->tgtype))
- {
- /* ROW trigger */
- if (TRIGGER_FOR_BEFORE(trigger->tgtype))
- {
- n = trigdesc->n_before_row;
- t = trigdesc->tg_before_row;
- }
- else
- {
- n = trigdesc->n_after_row;
- t = trigdesc->tg_after_row;
- }
- }
- else
- {
- /* STATEMENT trigger */
- if (TRIGGER_FOR_BEFORE(trigger->tgtype))
- {
- n = trigdesc->n_before_statement;
- t = trigdesc->tg_before_statement;
- }
- else
- {
- n = trigdesc->n_after_statement;
- t = trigdesc->tg_after_statement;
- }
- }
-
- if (TRIGGER_FOR_INSERT(trigger->tgtype))
- {
- tp = &(t[TRIGGER_EVENT_INSERT]);
- if (*tp == NULL)
- *tp = (int *) palloc(trigdesc->numtriggers * sizeof(int));
- (*tp)[n[TRIGGER_EVENT_INSERT]] = indx;
- (n[TRIGGER_EVENT_INSERT])++;
- }
-
- if (TRIGGER_FOR_DELETE(trigger->tgtype))
- {
- tp = &(t[TRIGGER_EVENT_DELETE]);
- if (*tp == NULL)
- *tp = (int *) palloc(trigdesc->numtriggers * sizeof(int));
- (*tp)[n[TRIGGER_EVENT_DELETE]] = indx;
- (n[TRIGGER_EVENT_DELETE])++;
- }
-
- if (TRIGGER_FOR_UPDATE(trigger->tgtype))
- {
- tp = &(t[TRIGGER_EVENT_UPDATE]);
- if (*tp == NULL)
- *tp = (int *) palloc(trigdesc->numtriggers * sizeof(int));
- (*tp)[n[TRIGGER_EVENT_UPDATE]] = indx;
- (n[TRIGGER_EVENT_UPDATE])++;
- }
-
- if (TRIGGER_FOR_TRUNCATE(trigger->tgtype))
- {
- tp = &(t[TRIGGER_EVENT_TRUNCATE]);
- if (*tp == NULL)
- *tp = (int *) palloc(trigdesc->numtriggers * sizeof(int));
- (*tp)[n[TRIGGER_EVENT_TRUNCATE]] = indx;
- (n[TRIGGER_EVENT_TRUNCATE])++;
- }
+ int16 tgtype = trigger->tgtype;
+
+ trigdesc->trig_insert_before_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_INSERT);
+ trigdesc->trig_insert_after_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_INSERT);
+ trigdesc->trig_insert_instead_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD, TRIGGER_TYPE_INSERT);
+ trigdesc->trig_insert_before_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_INSERT);
+ trigdesc->trig_insert_after_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_INSERT);
+ trigdesc->trig_update_before_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_UPDATE);
+ trigdesc->trig_update_after_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_UPDATE);
+ trigdesc->trig_update_instead_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD, TRIGGER_TYPE_UPDATE);
+ trigdesc->trig_update_before_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_UPDATE);
+ trigdesc->trig_update_after_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_UPDATE);
+ trigdesc->trig_delete_before_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_DELETE);
+ trigdesc->trig_delete_after_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_DELETE);
+ trigdesc->trig_delete_instead_row |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD, TRIGGER_TYPE_DELETE);
+ trigdesc->trig_delete_before_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_DELETE);
+ trigdesc->trig_delete_after_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_DELETE);
+ /* there are no row-level truncate triggers */
+ trigdesc->trig_truncate_before_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE, TRIGGER_TYPE_TRUNCATE);
+ trigdesc->trig_truncate_after_statement |=
+ TRIGGER_TYPE_MATCHES(tgtype, TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_AFTER, TRIGGER_TYPE_TRUNCATE);
}
/*
CopyTriggerDesc(TriggerDesc *trigdesc)
{
TriggerDesc *newdesc;
- uint16 *n;
- int **t,
- *tnew;
Trigger *trigger;
int i;
trigger++;
}
- n = newdesc->n_before_statement;
- t = newdesc->tg_before_statement;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- {
- if (n[i] > 0)
- {
- tnew = (int *) palloc(n[i] * sizeof(int));
- memcpy(tnew, t[i], n[i] * sizeof(int));
- t[i] = tnew;
- }
- else
- t[i] = NULL;
- }
- n = newdesc->n_before_row;
- t = newdesc->tg_before_row;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- {
- if (n[i] > 0)
- {
- tnew = (int *) palloc(n[i] * sizeof(int));
- memcpy(tnew, t[i], n[i] * sizeof(int));
- t[i] = tnew;
- }
- else
- t[i] = NULL;
- }
- n = newdesc->n_after_row;
- t = newdesc->tg_after_row;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- {
- if (n[i] > 0)
- {
- tnew = (int *) palloc(n[i] * sizeof(int));
- memcpy(tnew, t[i], n[i] * sizeof(int));
- t[i] = tnew;
- }
- else
- t[i] = NULL;
- }
- n = newdesc->n_after_statement;
- t = newdesc->tg_after_statement;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- {
- if (n[i] > 0)
- {
- tnew = (int *) palloc(n[i] * sizeof(int));
- memcpy(tnew, t[i], n[i] * sizeof(int));
- t[i] = tnew;
- }
- else
- t[i] = NULL;
- }
-
return newdesc;
}
void
FreeTriggerDesc(TriggerDesc *trigdesc)
{
- int **t;
Trigger *trigger;
int i;
if (trigdesc == NULL)
return;
- t = trigdesc->tg_before_statement;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- if (t[i] != NULL)
- pfree(t[i]);
- t = trigdesc->tg_before_row;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- if (t[i] != NULL)
- pfree(t[i]);
- t = trigdesc->tg_after_row;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- if (t[i] != NULL)
- pfree(t[i]);
- t = trigdesc->tg_after_statement;
- for (i = 0; i < TRIGGER_NUM_EVENT_CLASSES; i++)
- if (t[i] != NULL)
- pfree(t[i]);
-
trigger = trigdesc->triggers;
for (i = 0; i < trigdesc->numtriggers; i++)
{
j;
/*
- * We need not examine the "index" data, just the trigger array itself; if
- * we have the same triggers with the same types, the derived index data
- * should match.
+ * We need not examine the hint flags, just the trigger array itself; if
+ * we have the same triggers with the same types, the flags should match.
*
* As of 7.3 we assume trigger set ordering is significant in the
* comparison; so we just compare corresponding slots of the two sets.
ExecBSInsertTriggers(EState *estate, ResultRelInfo *relinfo)
{
TriggerDesc *trigdesc;
- int ntrigs;
- int *tgindx;
int i;
TriggerData LocTriggerData;
if (trigdesc == NULL)
return;
-
- ntrigs = trigdesc->n_before_statement[TRIGGER_EVENT_INSERT];
- tgindx = trigdesc->tg_before_statement[TRIGGER_EVENT_INSERT];
-
- if (ntrigs == 0)
+ if (!trigdesc->trig_insert_before_statement)
return;
LocTriggerData.type = T_TriggerData;
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
HeapTuple newtuple;
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_INSERT))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
NULL, NULL, NULL))
continue;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_statement[TRIGGER_EVENT_INSERT] > 0)
+ if (trigdesc && trigdesc->trig_insert_after_statement)
AfterTriggerSaveEvent(estate, relinfo, TRIGGER_EVENT_INSERT,
false, NULL, NULL, NIL, NULL);
}
HeapTuple trigtuple)
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- int ntrigs = trigdesc->n_before_row[TRIGGER_EVENT_INSERT];
- int *tgindx = trigdesc->tg_before_row[TRIGGER_EVENT_INSERT];
HeapTuple newtuple = trigtuple;
HeapTuple oldtuple;
TriggerData LocTriggerData;
LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_INSERT))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
NULL, NULL, newtuple))
continue;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_row[TRIGGER_EVENT_INSERT] > 0)
+ if (trigdesc && trigdesc->trig_insert_after_row)
AfterTriggerSaveEvent(estate, relinfo, TRIGGER_EVENT_INSERT,
true, NULL, trigtuple, recheckIndexes, NULL);
}
+HeapTuple
+ExecIRInsertTriggers(EState *estate, ResultRelInfo *relinfo,
+ HeapTuple trigtuple)
+{
+ TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
+ HeapTuple newtuple = trigtuple;
+ HeapTuple oldtuple;
+ TriggerData LocTriggerData;
+ int i;
+
+ LocTriggerData.type = T_TriggerData;
+ LocTriggerData.tg_event = TRIGGER_EVENT_INSERT |
+ TRIGGER_EVENT_ROW |
+ TRIGGER_EVENT_INSTEAD;
+ LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
+ LocTriggerData.tg_newtuple = NULL;
+ LocTriggerData.tg_newtuplebuf = InvalidBuffer;
+ for (i = 0; i < trigdesc->numtriggers; i++)
+ {
+ Trigger *trigger = &trigdesc->triggers[i];
+
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD,
+ TRIGGER_TYPE_INSERT))
+ continue;
+ if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
+ NULL, NULL, newtuple))
+ continue;
+
+ LocTriggerData.tg_trigtuple = oldtuple = newtuple;
+ LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
+ LocTriggerData.tg_trigger = trigger;
+ newtuple = ExecCallTriggerFunc(&LocTriggerData,
+ i,
+ relinfo->ri_TrigFunctions,
+ relinfo->ri_TrigInstrument,
+ GetPerTupleMemoryContext(estate));
+ if (oldtuple != newtuple && oldtuple != trigtuple)
+ heap_freetuple(oldtuple);
+ if (newtuple == NULL)
+ break;
+ }
+ return newtuple;
+}
+
void
ExecBSDeleteTriggers(EState *estate, ResultRelInfo *relinfo)
{
TriggerDesc *trigdesc;
- int ntrigs;
- int *tgindx;
int i;
TriggerData LocTriggerData;
if (trigdesc == NULL)
return;
-
- ntrigs = trigdesc->n_before_statement[TRIGGER_EVENT_DELETE];
- tgindx = trigdesc->tg_before_statement[TRIGGER_EVENT_DELETE];
-
- if (ntrigs == 0)
+ if (!trigdesc->trig_delete_before_statement)
return;
LocTriggerData.type = T_TriggerData;
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
HeapTuple newtuple;
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_DELETE))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
NULL, NULL, NULL))
continue;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_statement[TRIGGER_EVENT_DELETE] > 0)
+ if (trigdesc && trigdesc->trig_delete_after_statement)
AfterTriggerSaveEvent(estate, relinfo, TRIGGER_EVENT_DELETE,
false, NULL, NULL, NIL, NULL);
}
ItemPointer tupleid)
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- int ntrigs = trigdesc->n_before_row[TRIGGER_EVENT_DELETE];
- int *tgindx = trigdesc->tg_before_row[TRIGGER_EVENT_DELETE];
bool result = true;
TriggerData LocTriggerData;
HeapTuple trigtuple;
LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_DELETE))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
NULL, trigtuple, NULL))
continue;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_row[TRIGGER_EVENT_DELETE] > 0)
+ if (trigdesc && trigdesc->trig_delete_after_row)
{
HeapTuple trigtuple = GetTupleForTrigger(estate, NULL, relinfo,
tupleid, NULL);
}
}
+bool
+ExecIRDeleteTriggers(EState *estate, ResultRelInfo *relinfo,
+ HeapTuple trigtuple)
+{
+ TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
+ TriggerData LocTriggerData;
+ HeapTuple rettuple;
+ int i;
+
+ LocTriggerData.type = T_TriggerData;
+ LocTriggerData.tg_event = TRIGGER_EVENT_DELETE |
+ TRIGGER_EVENT_ROW |
+ TRIGGER_EVENT_INSTEAD;
+ LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
+ LocTriggerData.tg_newtuple = NULL;
+ LocTriggerData.tg_newtuplebuf = InvalidBuffer;
+ for (i = 0; i < trigdesc->numtriggers; i++)
+ {
+ Trigger *trigger = &trigdesc->triggers[i];
+
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD,
+ TRIGGER_TYPE_DELETE))
+ continue;
+ if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
+ NULL, trigtuple, NULL))
+ continue;
+
+ LocTriggerData.tg_trigtuple = trigtuple;
+ LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
+ LocTriggerData.tg_trigger = trigger;
+ rettuple = ExecCallTriggerFunc(&LocTriggerData,
+ i,
+ relinfo->ri_TrigFunctions,
+ relinfo->ri_TrigInstrument,
+ GetPerTupleMemoryContext(estate));
+ if (rettuple == NULL)
+ return false; /* Delete was suppressed */
+ if (rettuple != trigtuple)
+ heap_freetuple(rettuple);
+ }
+ return true;
+}
+
void
ExecBSUpdateTriggers(EState *estate, ResultRelInfo *relinfo)
{
TriggerDesc *trigdesc;
- int ntrigs;
- int *tgindx;
int i;
TriggerData LocTriggerData;
Bitmapset *modifiedCols;
if (trigdesc == NULL)
return;
-
- ntrigs = trigdesc->n_before_statement[TRIGGER_EVENT_UPDATE];
- tgindx = trigdesc->tg_before_statement[TRIGGER_EVENT_UPDATE];
-
- if (ntrigs == 0)
+ if (!trigdesc->trig_update_before_statement)
return;
modifiedCols = GetModifiedColumns(relinfo, estate);
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
HeapTuple newtuple;
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_UPDATE))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
modifiedCols, NULL, NULL))
continue;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_statement[TRIGGER_EVENT_UPDATE] > 0)
+ if (trigdesc && trigdesc->trig_update_after_statement)
AfterTriggerSaveEvent(estate, relinfo, TRIGGER_EVENT_UPDATE,
false, NULL, NULL, NIL,
GetModifiedColumns(relinfo, estate));
ItemPointer tupleid, HeapTuple newtuple)
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- int ntrigs = trigdesc->n_before_row[TRIGGER_EVENT_UPDATE];
- int *tgindx = trigdesc->tg_before_row[TRIGGER_EVENT_UPDATE];
TriggerData LocTriggerData;
HeapTuple trigtuple;
HeapTuple oldtuple;
TRIGGER_EVENT_ROW |
TRIGGER_EVENT_BEFORE;
LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_UPDATE))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
modifiedCols, trigtuple, newtuple))
continue;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_row[TRIGGER_EVENT_UPDATE] > 0)
+ if (trigdesc && trigdesc->trig_update_after_row)
{
HeapTuple trigtuple = GetTupleForTrigger(estate, NULL, relinfo,
tupleid, NULL);
}
}
+HeapTuple
+ExecIRUpdateTriggers(EState *estate, ResultRelInfo *relinfo,
+ HeapTuple oldtuple, HeapTuple newtuple)
+{
+ TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
+ TriggerData LocTriggerData;
+ HeapTuple intuple = newtuple;
+ HeapTuple rettuple;
+ int i;
+
+ LocTriggerData.type = T_TriggerData;
+ LocTriggerData.tg_event = TRIGGER_EVENT_UPDATE |
+ TRIGGER_EVENT_ROW |
+ TRIGGER_EVENT_INSTEAD;
+ LocTriggerData.tg_relation = relinfo->ri_RelationDesc;
+ for (i = 0; i < trigdesc->numtriggers; i++)
+ {
+ Trigger *trigger = &trigdesc->triggers[i];
+
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_ROW,
+ TRIGGER_TYPE_INSTEAD,
+ TRIGGER_TYPE_UPDATE))
+ continue;
+ if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
+ NULL, oldtuple, newtuple))
+ continue;
+
+ LocTriggerData.tg_trigtuple = oldtuple;
+ LocTriggerData.tg_newtuple = newtuple;
+ LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
+ LocTriggerData.tg_newtuplebuf = InvalidBuffer;
+ LocTriggerData.tg_trigger = trigger;
+ rettuple = ExecCallTriggerFunc(&LocTriggerData,
+ i,
+ relinfo->ri_TrigFunctions,
+ relinfo->ri_TrigInstrument,
+ GetPerTupleMemoryContext(estate));
+ if (newtuple != rettuple && newtuple != intuple)
+ heap_freetuple(newtuple);
+ newtuple = rettuple;
+ if (newtuple == NULL)
+ break;
+ }
+ return newtuple;
+}
+
void
ExecBSTruncateTriggers(EState *estate, ResultRelInfo *relinfo)
{
TriggerDesc *trigdesc;
- int ntrigs;
- int *tgindx;
int i;
TriggerData LocTriggerData;
if (trigdesc == NULL)
return;
-
- ntrigs = trigdesc->n_before_statement[TRIGGER_EVENT_TRUNCATE];
- tgindx = trigdesc->tg_before_statement[TRIGGER_EVENT_TRUNCATE];
-
- if (ntrigs == 0)
+ if (!trigdesc->trig_truncate_before_statement)
return;
LocTriggerData.type = T_TriggerData;
LocTriggerData.tg_newtuple = NULL;
LocTriggerData.tg_trigtuplebuf = InvalidBuffer;
LocTriggerData.tg_newtuplebuf = InvalidBuffer;
- for (i = 0; i < ntrigs; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
HeapTuple newtuple;
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ TRIGGER_TYPE_STATEMENT,
+ TRIGGER_TYPE_BEFORE,
+ TRIGGER_TYPE_TRUNCATE))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, LocTriggerData.tg_event,
NULL, NULL, NULL))
continue;
LocTriggerData.tg_trigger = trigger;
newtuple = ExecCallTriggerFunc(&LocTriggerData,
- tgindx[i],
+ i,
relinfo->ri_TrigFunctions,
relinfo->ri_TrigInstrument,
GetPerTupleMemoryContext(estate));
{
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
- if (trigdesc && trigdesc->n_after_statement[TRIGGER_EVENT_TRUNCATE] > 0)
+ if (trigdesc && trigdesc->trig_truncate_after_statement)
AfterTriggerSaveEvent(estate, relinfo, TRIGGER_EVENT_TRUNCATE,
false, NULL, NULL, NIL, NULL);
}
TriggerDesc *trigdesc = relinfo->ri_TrigDesc;
AfterTriggerEventData new_event;
AfterTriggerSharedData new_shared;
+ int tgtype_event;
+ int tgtype_level;
int i;
- int ntriggers;
- int *tgindx;
/*
* Check state. We use normal tests not Asserts because it is possible to
switch (event)
{
case TRIGGER_EVENT_INSERT:
+ tgtype_event = TRIGGER_TYPE_INSERT;
if (row_trigger)
{
Assert(oldtup == NULL);
}
break;
case TRIGGER_EVENT_DELETE:
+ tgtype_event = TRIGGER_TYPE_DELETE;
if (row_trigger)
{
Assert(oldtup != NULL);
}
break;
case TRIGGER_EVENT_UPDATE:
+ tgtype_event = TRIGGER_TYPE_UPDATE;
if (row_trigger)
{
Assert(oldtup != NULL);
}
break;
case TRIGGER_EVENT_TRUNCATE:
+ tgtype_event = TRIGGER_TYPE_TRUNCATE;
Assert(oldtup == NULL);
Assert(newtup == NULL);
ItemPointerSetInvalid(&(new_event.ate_ctid1));
break;
default:
elog(ERROR, "invalid after-trigger event code: %d", event);
+ tgtype_event = 0; /* keep compiler quiet */
break;
}
- /*
- * Scan the appropriate set of triggers
- */
- if (row_trigger)
- {
- ntriggers = trigdesc->n_after_row[event];
- tgindx = trigdesc->tg_after_row[event];
- }
- else
- {
- ntriggers = trigdesc->n_after_statement[event];
- tgindx = trigdesc->tg_after_statement[event];
- }
+ tgtype_level = (row_trigger ? TRIGGER_TYPE_ROW : TRIGGER_TYPE_STATEMENT);
- for (i = 0; i < ntriggers; i++)
+ for (i = 0; i < trigdesc->numtriggers; i++)
{
- Trigger *trigger = &trigdesc->triggers[tgindx[i]];
+ Trigger *trigger = &trigdesc->triggers[i];
+ if (!TRIGGER_TYPE_MATCHES(trigger->tgtype,
+ tgtype_level,
+ TRIGGER_TYPE_AFTER,
+ tgtype_event))
+ continue;
if (!TriggerEnabled(estate, relinfo, trigger, event,
modifiedCols, oldtup, newtup))
continue;
CmdType operation,
int instrument_options)
{
+ TriggerDesc *trigDesc = resultRelationDesc->trigdesc;
+
/*
- * Check valid relkind ... parser and/or planner should have noticed this
- * already, but let's make sure.
+ * Check valid relkind ... in most cases parser and/or planner should have
+ * noticed this already, but let's make sure. In the view case we do need
+ * a test here, because if the view wasn't rewritten by a rule, it had
+ * better have an INSTEAD trigger.
*/
switch (resultRelationDesc->rd_rel->relkind)
{
RelationGetRelationName(resultRelationDesc))));
break;
case RELKIND_VIEW:
- ereport(ERROR,
- (errcode(ERRCODE_WRONG_OBJECT_TYPE),
- errmsg("cannot change view \"%s\"",
- RelationGetRelationName(resultRelationDesc))));
+ 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(resultRelationDesc)),
+ errhint("You need an unconditional ON INSERT DO INSTEAD rule or 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(resultRelationDesc)),
+ errhint("You need an unconditional ON UPDATE DO INSTEAD rule or 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(resultRelationDesc)),
+ errhint("You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger.")));
+ break;
+ default:
+ elog(ERROR, "unrecognized CmdType: %d", (int) operation);
+ break;
+ }
break;
default:
ereport(ERROR,
resultRelInfo->ri_IndexRelationDescs = NULL;
resultRelInfo->ri_IndexRelationInfo = NULL;
/* make a copy so as not to depend on relcache info not changing... */
- resultRelInfo->ri_TrigDesc = CopyTriggerDesc(resultRelationDesc->trigdesc);
+ resultRelInfo->ri_TrigDesc = CopyTriggerDesc(trigDesc);
if (resultRelInfo->ri_TrigDesc)
{
int n = resultRelInfo->ri_TrigDesc->numtriggers;
/* BEFORE ROW INSERT Triggers */
if (resultRelInfo->ri_TrigDesc &&
- resultRelInfo->ri_TrigDesc->n_before_row[TRIGGER_EVENT_INSERT] > 0)
+ resultRelInfo->ri_TrigDesc->trig_insert_before_row)
{
HeapTuple newtuple;
}
}
- /*
- * Check the constraints of the tuple
- */
- if (resultRelationDesc->rd_att->constr)
- ExecConstraints(resultRelInfo, slot, estate);
+ /* INSTEAD OF ROW INSERT Triggers */
+ if (resultRelInfo->ri_TrigDesc &&
+ resultRelInfo->ri_TrigDesc->trig_insert_instead_row)
+ {
+ HeapTuple newtuple;
- /*
- * insert the tuple
- *
- * Note: heap_insert returns the tid (location) of the new tuple in the
- * t_self field.
- */
- newId = heap_insert(resultRelationDesc, tuple,
- estate->es_output_cid, 0, NULL);
+ newtuple = ExecIRInsertTriggers(estate, resultRelInfo, tuple);
+
+ if (newtuple == NULL) /* "do nothing" */
+ return NULL;
+
+ if (newtuple != tuple) /* modified by Trigger(s) */
+ {
+ /*
+ * Put the modified tuple into a slot for convenience of routines
+ * below. We assume the tuple was allocated in per-tuple memory
+ * context, and therefore will go away by itself. The tuple table
+ * slot should not try to clear it.
+ */
+ TupleTableSlot *newslot = estate->es_trig_tuple_slot;
+ TupleDesc tupdesc = RelationGetDescr(resultRelationDesc);
+
+ if (newslot->tts_tupleDescriptor != tupdesc)
+ ExecSetSlotDescriptor(newslot, tupdesc);
+ ExecStoreTuple(newtuple, newslot, InvalidBuffer, false);
+ slot = newslot;
+ tuple = newtuple;
+ }
+
+ newId = InvalidOid;
+ }
+ else
+ {
+ /*
+ * Check the constraints of the tuple
+ */
+ if (resultRelationDesc->rd_att->constr)
+ ExecConstraints(resultRelInfo, slot, estate);
+
+ /*
+ * insert the tuple
+ *
+ * Note: heap_insert returns the tid (location) of the new tuple in
+ * the t_self field.
+ */
+ newId = heap_insert(resultRelationDesc, tuple,
+ estate->es_output_cid, 0, NULL);
+
+ /*
+ * insert index entries for tuple
+ */
+ if (resultRelInfo->ri_NumIndices > 0)
+ recheckIndexes = ExecInsertIndexTuples(slot, &(tuple->t_self),
+ estate);
+ }
(estate->es_processed)++;
estate->es_lastoid = newId;
setLastTid(&(tuple->t_self));
- /*
- * insert index entries for tuple
- */
- if (resultRelInfo->ri_NumIndices > 0)
- recheckIndexes = ExecInsertIndexTuples(slot, &(tuple->t_self),
- estate);
-
/* AFTER ROW INSERT Triggers */
ExecARInsertTriggers(estate, resultRelInfo, tuple, recheckIndexes);
* ExecDelete
*
* DELETE is like UPDATE, except that we delete the tuple and no
- * index modifications are needed
+ * index modifications are needed.
+ *
+ * When deleting from a table, tupleid identifies the tuple to
+ * delete and oldtuple is NULL. When deleting from a view,
+ * oldtuple is passed to the INSTEAD OF triggers and identifies
+ * what to delete, and tupleid is invalid.
*
* Returns RETURNING result if any, otherwise NULL.
* ----------------------------------------------------------------
*/
static TupleTableSlot *
ExecDelete(ItemPointer tupleid,
+ HeapTupleHeader oldtuple,
TupleTableSlot *planSlot,
EPQState *epqstate,
EState *estate)
/* BEFORE ROW DELETE Triggers */
if (resultRelInfo->ri_TrigDesc &&
- resultRelInfo->ri_TrigDesc->n_before_row[TRIGGER_EVENT_DELETE] > 0)
+ resultRelInfo->ri_TrigDesc->trig_delete_before_row)
{
bool dodelete;
return NULL;
}
- /*
- * delete the tuple
- *
- * Note: if es_crosscheck_snapshot isn't InvalidSnapshot, we check that
- * the row to be deleted is visible to that snapshot, and throw a can't-
- * serialize error if not. This is a special-case behavior needed for
- * referential integrity updates in transaction-snapshot mode transactions.
- */
-ldelete:;
- result = heap_delete(resultRelationDesc, tupleid,
- &update_ctid, &update_xmax,
- estate->es_output_cid,
- estate->es_crosscheck_snapshot,
- true /* wait for commit */ );
- switch (result)
+ /* INSTEAD OF ROW DELETE Triggers */
+ if (resultRelInfo->ri_TrigDesc &&
+ resultRelInfo->ri_TrigDesc->trig_delete_instead_row)
{
- case HeapTupleSelfUpdated:
- /* already deleted by self; nothing to do */
+ HeapTupleData tuple;
+ bool dodelete;
+
+ Assert(oldtuple != NULL);
+ tuple.t_data = oldtuple;
+ tuple.t_len = HeapTupleHeaderGetDatumLength(oldtuple);
+ ItemPointerSetInvalid(&(tuple.t_self));
+ tuple.t_tableOid = InvalidOid;
+
+ dodelete = ExecIRDeleteTriggers(estate, resultRelInfo, &tuple);
+
+ if (!dodelete) /* "do nothing" */
return NULL;
+ }
+ else
+ {
+ /*
+ * delete the tuple
+ *
+ * Note: if es_crosscheck_snapshot isn't InvalidSnapshot, we check
+ * that the row to be deleted is visible to that snapshot, and throw a
+ * can't-serialize error if not. This is a special-case behavior
+ * needed for referential integrity updates in transaction-snapshot
+ * mode transactions.
+ */
+ldelete:;
+ result = heap_delete(resultRelationDesc, tupleid,
+ &update_ctid, &update_xmax,
+ estate->es_output_cid,
+ estate->es_crosscheck_snapshot,
+ true /* wait for commit */ );
+ switch (result)
+ {
+ case HeapTupleSelfUpdated:
+ /* already deleted by self; nothing to do */
+ return NULL;
- case HeapTupleMayBeUpdated:
- break;
+ case HeapTupleMayBeUpdated:
+ break;
- case HeapTupleUpdated:
- if (IsolationUsesXactSnapshot())
- ereport(ERROR,
- (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE),
- errmsg("could not serialize access due to concurrent update")));
- if (!ItemPointerEquals(tupleid, &update_ctid))
- {
- TupleTableSlot *epqslot;
-
- epqslot = EvalPlanQual(estate,
- epqstate,
- resultRelationDesc,
- resultRelInfo->ri_RangeTableIndex,
- &update_ctid,
- update_xmax);
- if (!TupIsNull(epqslot))
+ case HeapTupleUpdated:
+ if (IsolationUsesXactSnapshot())
+ ereport(ERROR,
+ (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE),
+ errmsg("could not serialize access due to concurrent update")));
+ if (!ItemPointerEquals(tupleid, &update_ctid))
{
- *tupleid = update_ctid;
- goto ldelete;
+ TupleTableSlot *epqslot;
+
+ epqslot = EvalPlanQual(estate,
+ epqstate,
+ resultRelationDesc,
+ resultRelInfo->ri_RangeTableIndex,
+ &update_ctid,
+ update_xmax);
+ if (!TupIsNull(epqslot))
+ {
+ *tupleid = update_ctid;
+ goto ldelete;
+ }
}
- }
- /* tuple already deleted; nothing to do */
- return NULL;
+ /* tuple already deleted; nothing to do */
+ return NULL;
- default:
- elog(ERROR, "unrecognized heap_delete status: %u", result);
- return NULL;
+ default:
+ elog(ERROR, "unrecognized heap_delete status: %u", result);
+ return NULL;
+ }
+
+ /*
+ * Note: Normally one would think that we have to delete index tuples
+ * associated with the heap tuple now...
+ *
+ * ... but in POSTGRES, we have no need to do this because VACUUM will
+ * take care of it later. We can't delete index tuples immediately
+ * anyway, since the tuple is still visible to other transactions.
+ */
}
(estate->es_processed)++;
- /*
- * Note: Normally one would think that we have to delete index tuples
- * associated with the heap tuple now...
- *
- * ... but in POSTGRES, we have no need to do this because VACUUM will
- * take care of it later. We can't delete index tuples immediately
- * anyway, since the tuple is still visible to other transactions.
- */
-
/* AFTER ROW DELETE Triggers */
ExecARDeleteTriggers(estate, resultRelInfo, tupleid);
HeapTupleData deltuple;
Buffer delbuffer;
- deltuple.t_self = *tupleid;
- if (!heap_fetch(resultRelationDesc, SnapshotAny,
- &deltuple, &delbuffer, false, NULL))
- elog(ERROR, "failed to fetch deleted tuple for DELETE RETURNING");
+ if (oldtuple != NULL)
+ {
+ deltuple.t_data = oldtuple;
+ deltuple.t_len = HeapTupleHeaderGetDatumLength(oldtuple);
+ ItemPointerSetInvalid(&(deltuple.t_self));
+ deltuple.t_tableOid = InvalidOid;
+ delbuffer = InvalidBuffer;
+ }
+ else
+ {
+ deltuple.t_self = *tupleid;
+ if (!heap_fetch(resultRelationDesc, SnapshotAny,
+ &deltuple, &delbuffer, false, NULL))
+ elog(ERROR, "failed to fetch deleted tuple for DELETE RETURNING");
+ }
if (slot->tts_tupleDescriptor != RelationGetDescr(resultRelationDesc))
ExecSetSlotDescriptor(slot, RelationGetDescr(resultRelationDesc));
slot, planSlot);
ExecClearTuple(slot);
- ReleaseBuffer(delbuffer);
+ if (BufferIsValid(delbuffer))
+ ReleaseBuffer(delbuffer);
return rslot;
}
* is, we don't want to get stuck in an infinite loop
* which corrupts your database..
*
+ * When updating a table, tupleid identifies the tuple to
+ * update and oldtuple is NULL. When updating a view, oldtuple
+ * is passed to the INSTEAD OF triggers and identifies what to
+ * update, and tupleid is invalid.
+ *
* Returns RETURNING result if any, otherwise NULL.
* ----------------------------------------------------------------
*/
static TupleTableSlot *
ExecUpdate(ItemPointer tupleid,
+ HeapTupleHeader oldtuple,
TupleTableSlot *slot,
TupleTableSlot *planSlot,
EPQState *epqstate,
/* BEFORE ROW UPDATE Triggers */
if (resultRelInfo->ri_TrigDesc &&
- resultRelInfo->ri_TrigDesc->n_before_row[TRIGGER_EVENT_UPDATE] > 0)
+ resultRelInfo->ri_TrigDesc->trig_update_before_row)
{
HeapTuple newtuple;
}
}
- /*
- * Check the constraints of the tuple
- *
- * If we generate a new candidate tuple after EvalPlanQual testing, we
- * must loop back here and recheck constraints. (We don't need to redo
- * triggers, however. If there are any BEFORE triggers then trigger.c
- * will have done heap_lock_tuple to lock the correct tuple, so there's no
- * need to do them again.)
- */
-lreplace:;
- if (resultRelationDesc->rd_att->constr)
- ExecConstraints(resultRelInfo, slot, estate);
-
- /*
- * replace the heap tuple
- *
- * Note: if es_crosscheck_snapshot isn't InvalidSnapshot, we check that
- * the row to be updated is visible to that snapshot, and throw a can't-
- * serialize error if not. This is a special-case behavior needed for
- * referential integrity updates in transaction-snapshot mode transactions.
- */
- result = heap_update(resultRelationDesc, tupleid, tuple,
- &update_ctid, &update_xmax,
- estate->es_output_cid,
- estate->es_crosscheck_snapshot,
- true /* wait for commit */ );
- switch (result)
+ /* INSTEAD OF ROW UPDATE Triggers */
+ if (resultRelInfo->ri_TrigDesc &&
+ resultRelInfo->ri_TrigDesc->trig_update_instead_row)
{
- case HeapTupleSelfUpdated:
- /* already deleted by self; nothing to do */
+ HeapTupleData oldtup;
+ HeapTuple newtuple;
+
+ Assert(oldtuple != NULL);
+ oldtup.t_data = oldtuple;
+ oldtup.t_len = HeapTupleHeaderGetDatumLength(oldtuple);
+ ItemPointerSetInvalid(&(oldtup.t_self));
+ oldtup.t_tableOid = InvalidOid;
+
+ newtuple = ExecIRUpdateTriggers(estate, resultRelInfo,
+ &oldtup, tuple);
+
+ if (newtuple == NULL) /* "do nothing" */
return NULL;
- case HeapTupleMayBeUpdated:
- break;
+ if (newtuple != tuple) /* modified by Trigger(s) */
+ {
+ /*
+ * Put the modified tuple into a slot for convenience of routines
+ * below. We assume the tuple was allocated in per-tuple memory
+ * context, and therefore will go away by itself. The tuple table
+ * slot should not try to clear it.
+ */
+ TupleTableSlot *newslot = estate->es_trig_tuple_slot;
+ TupleDesc tupdesc = RelationGetDescr(resultRelationDesc);
- case HeapTupleUpdated:
- if (IsolationUsesXactSnapshot())
- ereport(ERROR,
- (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE),
- errmsg("could not serialize access due to concurrent update")));
- if (!ItemPointerEquals(tupleid, &update_ctid))
- {
- TupleTableSlot *epqslot;
-
- epqslot = EvalPlanQual(estate,
- epqstate,
- resultRelationDesc,
- resultRelInfo->ri_RangeTableIndex,
- &update_ctid,
- update_xmax);
- if (!TupIsNull(epqslot))
+ if (newslot->tts_tupleDescriptor != tupdesc)
+ ExecSetSlotDescriptor(newslot, tupdesc);
+ ExecStoreTuple(newtuple, newslot, InvalidBuffer, false);
+ slot = newslot;
+ tuple = newtuple;
+ }
+ }
+ else
+ {
+ /*
+ * Check the constraints of the tuple
+ *
+ * If we generate a new candidate tuple after EvalPlanQual testing, we
+ * must loop back here and recheck constraints. (We don't need to
+ * redo triggers, however. If there are any BEFORE triggers then
+ * trigger.c will have done heap_lock_tuple to lock the correct tuple,
+ * so there's no need to do them again.)
+ */
+lreplace:;
+ if (resultRelationDesc->rd_att->constr)
+ ExecConstraints(resultRelInfo, slot, estate);
+
+ /*
+ * replace the heap tuple
+ *
+ * Note: if es_crosscheck_snapshot isn't InvalidSnapshot, we check
+ * that the row to be updated is visible to that snapshot, and throw a
+ * can't-serialize error if not. This is a special-case behavior
+ * needed for referential integrity updates in transaction-snapshot
+ * mode transactions.
+ */
+ result = heap_update(resultRelationDesc, tupleid, tuple,
+ &update_ctid, &update_xmax,
+ estate->es_output_cid,
+ estate->es_crosscheck_snapshot,
+ true /* wait for commit */ );
+ switch (result)
+ {
+ case HeapTupleSelfUpdated:
+ /* already deleted by self; nothing to do */
+ return NULL;
+
+ case HeapTupleMayBeUpdated:
+ break;
+
+ case HeapTupleUpdated:
+ if (IsolationUsesXactSnapshot())
+ ereport(ERROR,
+ (errcode(ERRCODE_T_R_SERIALIZATION_FAILURE),
+ errmsg("could not serialize access due to concurrent update")));
+ if (!ItemPointerEquals(tupleid, &update_ctid))
{
- *tupleid = update_ctid;
- slot = ExecFilterJunk(resultRelInfo->ri_junkFilter, epqslot);
- tuple = ExecMaterializeSlot(slot);
- goto lreplace;
+ TupleTableSlot *epqslot;
+
+ epqslot = EvalPlanQual(estate,
+ epqstate,
+ resultRelationDesc,
+ resultRelInfo->ri_RangeTableIndex,
+ &update_ctid,
+ update_xmax);
+ if (!TupIsNull(epqslot))
+ {
+ *tupleid = update_ctid;
+ slot = ExecFilterJunk(resultRelInfo->ri_junkFilter, epqslot);
+ tuple = ExecMaterializeSlot(slot);
+ goto lreplace;
+ }
}
- }
- /* tuple already deleted; nothing to do */
- return NULL;
+ /* tuple already deleted; nothing to do */
+ return NULL;
- default:
- elog(ERROR, "unrecognized heap_update status: %u", result);
- return NULL;
- }
+ default:
+ elog(ERROR, "unrecognized heap_update status: %u", result);
+ return NULL;
+ }
- (estate->es_processed)++;
+ /*
+ * Note: instead of having to update the old index tuples associated
+ * with the heap tuple, all we do is form and insert new index
+ * tuples. This is because UPDATEs are actually DELETEs and INSERTs,
+ * and index tuple deletion is done later by VACUUM (see notes in
+ * ExecDelete). All we do here is insert new index tuples. -cim
+ * 9/27/89
+ */
- /*
- * Note: instead of having to update the old index tuples associated with
- * the heap tuple, all we do is form and insert new index tuples. This is
- * because UPDATEs are actually DELETEs and INSERTs, and index tuple
- * deletion is done later by VACUUM (see notes in ExecDelete). All we do
- * here is insert new index tuples. -cim 9/27/89
- */
+ /*
+ * insert index entries for tuple
+ *
+ * Note: heap_update returns the tid (location) of the new tuple in
+ * the t_self field.
+ *
+ * If it's a HOT update, we mustn't insert new index entries.
+ */
+ if (resultRelInfo->ri_NumIndices > 0 && !HeapTupleIsHeapOnly(tuple))
+ recheckIndexes = ExecInsertIndexTuples(slot, &(tuple->t_self),
+ estate);
+ }
- /*
- * insert index entries for tuple
- *
- * Note: heap_update returns the tid (location) of the new tuple in the
- * t_self field.
- *
- * If it's a HOT update, we mustn't insert new index entries.
- */
- if (resultRelInfo->ri_NumIndices > 0 && !HeapTupleIsHeapOnly(tuple))
- recheckIndexes = ExecInsertIndexTuples(slot, &(tuple->t_self),
- estate);
+ (estate->es_processed)++;
/* AFTER ROW UPDATE Triggers */
ExecARUpdateTriggers(estate, resultRelInfo, tupleid, tuple,
TupleTableSlot *planSlot;
ItemPointer tupleid = NULL;
ItemPointerData tuple_ctid;
+ HeapTupleHeader oldtuple = NULL;
/*
* On first call, fire BEFORE STATEMENT triggers before proceeding.
if (junkfilter != NULL)
{
/*
- * extract the 'ctid' junk attribute.
+ * extract the 'ctid' or 'wholerow' junk attribute.
*/
if (operation == CMD_UPDATE || operation == CMD_DELETE)
{
Datum datum;
bool isNull;
- datum = ExecGetJunkAttribute(slot, junkfilter->jf_junkAttNo,
- &isNull);
- /* shouldn't ever get a null result... */
- if (isNull)
- elog(ERROR, "ctid is NULL");
-
- tupleid = (ItemPointer) DatumGetPointer(datum);
- tuple_ctid = *tupleid; /* be sure we don't free the ctid!! */
- tupleid = &tuple_ctid;
+ if (estate->es_result_relation_info->ri_RelationDesc->rd_rel->relkind == RELKIND_RELATION)
+ {
+ datum = ExecGetJunkAttribute(slot,
+ junkfilter->jf_junkAttNo,
+ &isNull);
+ /* shouldn't ever get a null result... */
+ if (isNull)
+ elog(ERROR, "ctid is NULL");
+
+ tupleid = (ItemPointer) DatumGetPointer(datum);
+ tuple_ctid = *tupleid; /* be sure we don't free ctid!! */
+ tupleid = &tuple_ctid;
+ }
+ else
+ {
+ datum = ExecGetJunkAttribute(slot,
+ junkfilter->jf_junkAttNo,
+ &isNull);
+ /* shouldn't ever get a null result... */
+ if (isNull)
+ elog(ERROR, "wholerow is NULL");
+
+ oldtuple = DatumGetHeapTupleHeader(datum);
+ }
}
/*
slot = ExecInsert(slot, planSlot, estate);
break;
case CMD_UPDATE:
- slot = ExecUpdate(tupleid, slot, planSlot,
+ slot = ExecUpdate(tupleid, oldtuple, slot, planSlot,
&node->mt_epqstate, estate);
break;
case CMD_DELETE:
- slot = ExecDelete(tupleid, planSlot,
+ slot = ExecDelete(tupleid, oldtuple, planSlot,
&node->mt_epqstate, estate);
break;
default:
/*
* Initialize the junk filter(s) if needed. INSERT queries need a filter
* if there are any junk attrs in the tlist. UPDATE and DELETE always
- * need a filter, since there's always a junk 'ctid' attribute present ---
- * no need to look first.
+ * need a filter, since there's always a junk 'ctid' or 'wholerow'
+ * attribute present --- no need to look first.
*
* If there are multiple result relations, each one needs its own junk
* filter. Note multiple rels are only possible for UPDATE/DELETE, so we
if (operation == CMD_UPDATE || operation == CMD_DELETE)
{
- /* For UPDATE/DELETE, find the ctid junk attr now */
- j->jf_junkAttNo = ExecFindJunkAttribute(j, "ctid");
- if (!AttributeNumberIsValid(j->jf_junkAttNo))
- elog(ERROR, "could not find junk ctid column");
+ /* For UPDATE/DELETE, find the appropriate junk attr now */
+ if (resultRelInfo->ri_RelationDesc->rd_rel->relkind == RELKIND_RELATION)
+ {
+ j->jf_junkAttNo = ExecFindJunkAttribute(j, "ctid");
+ if (!AttributeNumberIsValid(j->jf_junkAttNo))
+ elog(ERROR, "could not find junk ctid column");
+ }
+ else
+ {
+ j->jf_junkAttNo = ExecFindJunkAttribute(j, "wholerow");
+ if (!AttributeNumberIsValid(j->jf_junkAttNo))
+ elog(ERROR, "could not find junk wholerow column");
+ }
}
resultRelInfo->ri_junkFilter = j;
COPY_NODE_FIELD(relation);
COPY_NODE_FIELD(funcname);
COPY_NODE_FIELD(args);
- COPY_SCALAR_FIELD(before);
COPY_SCALAR_FIELD(row);
+ COPY_SCALAR_FIELD(timing);
COPY_SCALAR_FIELD(events);
COPY_NODE_FIELD(columns);
COPY_NODE_FIELD(whenClause);
COMPARE_NODE_FIELD(relation);
COMPARE_NODE_FIELD(funcname);
COMPARE_NODE_FIELD(args);
- COMPARE_SCALAR_FIELD(before);
COMPARE_SCALAR_FIELD(row);
+ COMPARE_SCALAR_FIELD(timing);
COMPARE_SCALAR_FIELD(events);
COMPARE_NODE_FIELD(columns);
COMPARE_NODE_FIELD(whenClause);
* preptlist.c
* Routines to preprocess the parse tree target list
*
- * This module takes care of altering the query targetlist as needed for
- * INSERT, UPDATE, and DELETE queries. For INSERT and UPDATE queries,
- * the targetlist must contain an entry for each attribute of the target
- * relation in the correct order. For both UPDATE and DELETE queries,
- * we need a junk targetlist entry holding the CTID attribute --- the
- * executor relies on this to find the tuple to be replaced/deleted.
- * We may also need junk tlist entries for Vars used in the RETURNING list
- * and row ID information needed for EvalPlanQual checking.
+ * For INSERT and UPDATE queries, the targetlist must contain an entry for
+ * each attribute of the target relation in the correct order. For all query
+ * types, we may need to add junk tlist entries for Vars used in the RETURNING
+ * list and row ID information needed for EvalPlanQual checking.
+ *
+ * NOTE: the rewriter's rewriteTargetListIU and rewriteTargetListUD
+ * routines also do preprocessing of the targetlist. The division of labor
+ * between here and there is a bit arbitrary and historical.
*
*
* Portions Copyright (c) 1996-2010, PostgreSQL Global Development Group
tlist = expand_targetlist(tlist, command_type,
result_relation, range_table);
- /*
- * for "update" and "delete" queries, add ctid of the result relation into
- * the target list so that the ctid will propagate through execution and
- * ExecutePlan() will be able to identify the right tuple to replace or
- * delete. This extra field is marked "junk" so that it is not stored
- * back into the tuple.
- */
- if (command_type == CMD_UPDATE || command_type == CMD_DELETE)
- {
- TargetEntry *tle;
- Var *var;
-
- var = makeVar(result_relation, SelfItemPointerAttributeNumber,
- TIDOID, -1, 0);
-
- tle = makeTargetEntry((Expr *) var,
- list_length(tlist) + 1,
- pstrdup("ctid"),
- true);
-
- /*
- * For an UPDATE, expand_targetlist already created a fresh tlist. For
- * DELETE, better do a listCopy so that we don't destructively modify
- * the original tlist (is this really necessary?).
- */
- if (command_type == CMD_DELETE)
- tlist = list_copy(tlist);
-
- tlist = lappend(tlist, tle);
- }
-
/*
* Add necessary junk columns for rowmarked rels. These values are needed
* for locking of rels selected FOR UPDATE/SHARE, and to do EvalPlanQual
* Given a target list as generated by the parser and a result relation,
* add targetlist entries for any missing attributes, and ensure the
* non-junk attributes appear in proper field order.
- *
- * NOTE: if you are tempted to put more processing here, consider whether
- * it shouldn't go in the rewriter's rewriteTargetList() instead.
*/
static List *
expand_targetlist(List *tlist, int command_type,
%type <str> OptSchemaName
%type <list> OptSchemaEltList
-%type <boolean> TriggerActionTime TriggerForSpec opt_trusted opt_restart_seqs
-
+%type <boolean> TriggerForSpec TriggerForType
+%type <ival> TriggerActionTime
%type <list> TriggerEvents TriggerOneEvent
%type <value> TriggerFuncArg
%type <node> TriggerWhen
%type <fun_param_mode> arg_class
%type <typnam> func_return func_type
-%type <boolean> TriggerForType OptTemp
+%type <boolean> OptTemp opt_trusted opt_restart_seqs
%type <oncommit> OnCommitOption
%type <node> for_locking_item
n->relation = $7;
n->funcname = $12;
n->args = $14;
- n->before = $4;
n->row = $8;
+ n->timing = $4;
n->events = intVal(linitial($5));
n->columns = (List *) lsecond($5);
n->whenClause = $9;
n->relation = $8;
n->funcname = $17;
n->args = $19;
- n->before = FALSE;
n->row = TRUE;
+ n->timing = TRIGGER_TYPE_AFTER;
n->events = intVal(linitial($6));
n->columns = (List *) lsecond($6);
n->whenClause = $14;
;
TriggerActionTime:
- BEFORE { $$ = TRUE; }
- | AFTER { $$ = FALSE; }
+ BEFORE { $$ = TRIGGER_TYPE_BEFORE; }
+ | AFTER { $$ = TRIGGER_TYPE_AFTER; }
+ | INSTEAD OF { $$ = TRIGGER_TYPE_INSTEAD; }
;
TriggerEvents:
;
TriggerForSpec:
- FOR TriggerForOpt TriggerForType
+ FOR TriggerForOptEach TriggerForType
{
$$ = $3;
}
}
;
-TriggerForOpt:
+TriggerForOptEach:
EACH {}
| /*EMPTY*/ {}
;
#include "postgres.h"
#include "access/heapam.h"
+#include "access/sysattr.h"
#include "catalog/pg_type.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
CmdType event,
bool *returning_flag);
static List *adjustJoinTreeList(Query *parsetree, bool removert, int rt_index);
-static void rewriteTargetList(Query *parsetree, Relation target_relation,
- List **attrno_list);
+static void rewriteTargetListIU(Query *parsetree, Relation target_relation,
+ List **attrno_list);
static TargetEntry *process_matched_tle(TargetEntry *src_tle,
TargetEntry *prior_tle,
const char *attrName);
static Node *get_assignment_input(Node *node);
static void rewriteValuesRTE(RangeTblEntry *rte, Relation target_relation,
List *attrnos);
+static void rewriteTargetListUD(Query *parsetree, Relation target_relation);
static void markQueryForLocking(Query *qry, Node *jtnode,
bool forUpdate, bool noWait, bool pushedDown);
static List *matchLocks(CmdType event, RuleLock *rulelocks,
/*
- * rewriteTargetList - rewrite INSERT/UPDATE targetlist into standard form
+ * rewriteTargetListIU - rewrite INSERT/UPDATE targetlist into standard form
*
* This has the following responsibilities:
*
* and UPDATE, replace explicit DEFAULT specifications with column default
* expressions.
*
- * 2. Merge multiple entries for the same target attribute, or declare error
+ * 2. For an UPDATE on a view, add tlist entries for any unassigned-to
+ * attributes, assigning them their old values. These will later get
+ * expanded to the output values of the view. (This is equivalent to what
+ * the planner's expand_targetlist() will do for UPDATE on a regular table,
+ * but it's more convenient to do it here while we still have easy access
+ * to the view's original RT index.)
+ *
+ * 3. Merge multiple entries for the same target attribute, or declare error
* if we can't. Multiple entries are only allowed for INSERT/UPDATE of
* portions of an array or record field, for example
* UPDATE table SET foo[2] = 42, foo[4] = 43;
* the expression we want to produce in this case is like
* foo = array_set(array_set(foo, 2, 42), 4, 43)
*
- * 3. Sort the tlist into standard order: non-junk fields in order by resno,
+ * 4. Sort the tlist into standard order: non-junk fields in order by resno,
* then junk fields (these in no particular order).
*
- * We must do items 1 and 2 before firing rewrite rules, else rewritten
- * references to NEW.foo will produce wrong or incomplete results. Item 3
+ * We must do items 1,2,3 before firing rewrite rules, else rewritten
+ * references to NEW.foo will produce wrong or incomplete results. Item 4
* is not needed for rewriting, but will be needed by the planner, and we
- * can do it essentially for free while handling items 1 and 2.
+ * can do it essentially for free while handling the other items.
*
* If attrno_list isn't NULL, we return an additional output besides the
* rewritten targetlist: an integer list of the assigned-to attnums, in
* processing VALUES RTEs.
*/
static void
-rewriteTargetList(Query *parsetree, Relation target_relation,
- List **attrno_list)
+rewriteTargetListIU(Query *parsetree, Relation target_relation,
+ List **attrno_list)
{
CmdType commandType = parsetree->commandType;
TargetEntry **new_tles;
false);
}
+ /*
+ * For an UPDATE on a view, provide a dummy entry whenever there is
+ * no explicit assignment.
+ */
+ if (new_tle == NULL && commandType == CMD_UPDATE &&
+ target_relation->rd_rel->relkind == RELKIND_VIEW)
+ {
+ Node *new_expr;
+
+ new_expr = (Node *) makeVar(parsetree->resultRelation,
+ attrno,
+ att_tup->atttypid,
+ att_tup->atttypmod,
+ 0);
+
+ new_tle = makeTargetEntry((Expr *) new_expr,
+ attrno,
+ pstrdup(NameStr(att_tup->attname)),
+ false);
+ }
+
if (new_tle)
new_tlist = lappend(new_tlist, new_tle);
}
/*
* When processing INSERT ... VALUES with a VALUES RTE (ie, multiple VALUES
* lists), we have to replace any DEFAULT items in the VALUES lists with
- * the appropriate default expressions. The other aspects of rewriteTargetList
- * need be applied only to the query's targetlist proper.
+ * the appropriate default expressions. The other aspects of targetlist
+ * rewriting need be applied only to the query's targetlist proper.
*
* Note that we currently can't support subscripted or field assignment
* in the multi-VALUES case. The targetlist will contain simple Vars
}
+/*
+ * rewriteTargetListUD - rewrite UPDATE/DELETE targetlist as needed
+ *
+ * This function adds a "junk" TLE that is needed to allow the executor to
+ * find the original row for the update or delete. When the target relation
+ * is a regular table, the junk TLE emits the ctid attribute of the original
+ * row. When the target relation is a view, there is no ctid, so we instead
+ * emit a whole-row Var that will contain the "old" values of the view row.
+ *
+ * For UPDATE queries, this is applied after rewriteTargetListIU. The
+ * ordering isn't actually critical at the moment.
+ */
+static void
+rewriteTargetListUD(Query *parsetree, Relation target_relation)
+{
+ Var *var;
+ const char *attrname;
+ TargetEntry *tle;
+
+ if (target_relation->rd_rel->relkind == RELKIND_RELATION)
+ {
+ /*
+ * Emit CTID so that executor can find the row to update or delete.
+ */
+ var = makeVar(parsetree->resultRelation,
+ SelfItemPointerAttributeNumber,
+ TIDOID,
+ -1,
+ 0);
+
+ attrname = "ctid";
+ }
+ else
+ {
+ /*
+ * Emit whole-row Var so that executor will have the "old" view row
+ * to pass to the INSTEAD OF trigger.
+ */
+ var = makeVar(parsetree->resultRelation,
+ InvalidAttrNumber,
+ RECORDOID,
+ -1,
+ 0);
+
+ attrname = "wholerow";
+ }
+
+ tle = makeTargetEntry((Expr *) var,
+ list_length(parsetree->targetList) + 1,
+ pstrdup(attrname),
+ true);
+
+ parsetree->targetList = lappend(parsetree->targetList, tle);
+}
+
+
/*
* matchLocks -
* match the list of locks and returns the matching rules
if (!relation_level)
elog(ERROR, "cannot handle per-attribute ON SELECT rule");
+ if (rt_index == parsetree->resultRelation)
+ {
+ /*
+ * We have a view as the result relation of the query, and it wasn't
+ * rewritten by any rule. This case is supported if there is an
+ * INSTEAD OF trigger that will trap attempts to insert/update/delete
+ * view rows. The executor will check that; for the moment just plow
+ * ahead. We have two cases:
+ *
+ * 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
+ * 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)
+ {
+ RangeTblEntry *newrte;
+
+ rte = rt_fetch(rt_index, parsetree->rtable);
+ newrte = copyObject(rte);
+ parsetree->rtable = lappend(parsetree->rtable, newrte);
+ parsetree->resultRelation = list_length(parsetree->rtable);
+
+ /*
+ * There's no need to do permissions checks twice, so wipe out
+ * the permissions info for the original RTE (we prefer to keep
+ * the bits set on the result RTE).
+ */
+ rte->requiredPerms = 0;
+ rte->checkAsUser = InvalidOid;
+ rte->selectedCols = NULL;
+ rte->modifiedCols = NULL;
+
+ /*
+ * For the most part, Vars referencing the view should remain as
+ * they are, meaning that they implicitly represent OLD values.
+ * But in the RETURNING list if any, we want such Vars to
+ * represent NEW values, so change them to reference the new RTE.
+ *
+ * Since ChangeVarNodes scribbles on the tree in-place, copy the
+ * RETURNING list first for safety.
+ */
+ parsetree->returningList = copyObject(parsetree->returningList);
+ ChangeVarNodes((Node *) parsetree->returningList, rt_index,
+ parsetree->resultRelation, 0);
+
+ /* Now, continue with expanding the original view RTE */
+ }
+ else
+ elog(ERROR, "unrecognized commandType: %d",
+ (int) parsetree->commandType);
+ }
+
/*
* If FOR UPDATE/SHARE of view, be sure we get right initial lock on the
* relations it references.
rule_action = fireRIRrules(rule_action, activeRIRs, forUpdatePushedDown);
/*
- * VIEWs are really easy --- just plug the view query in as a subselect,
- * replacing the relation's original RTE.
+ * Now, plug the view query in as a subselect, replacing the relation's
+ * original RTE.
*/
rte = rt_fetch(rt_index, parsetree->rtable);
static Query *
fireRIRrules(Query *parsetree, List *activeRIRs, bool forUpdatePushedDown)
{
+ int origResultRelation = parsetree->resultRelation;
int rt_index;
ListCell *lc;
!rangeTableEntry_used((Node *) parsetree, rt_index, 0))
continue;
+ /*
+ * Also, if this is a new result relation introduced by
+ * ApplyRetrieveRule, we don't want to do anything more with it.
+ */
+ if (rt_index == parsetree->resultRelation &&
+ rt_index != origResultRelation)
+ continue;
+
/*
* We can use NoLock here since either the parser or
* AcquireRewriteLocks should have locked the rel already.
List *rewritten = NIL;
/*
- * If the statement is an update, insert or delete - fire rules on it.
+ * If the statement is an insert, update, or delete, adjust its targetlist
+ * as needed, and then fire INSERT/UPDATE/DELETE rules on it.
*
* SELECT rules are handled later when we have all the queries that should
* get executed. Also, utilities aren't rewritten at all (do we still
rt_entry_relation = heap_open(rt_entry->relid, NoLock);
/*
- * If it's an INSERT or UPDATE, rewrite the targetlist into standard
- * form. This will be needed by the planner anyway, and doing it now
- * ensures that any references to NEW.field will behave sanely.
+ * Rewrite the targetlist as needed for the command type.
*/
- if (event == CMD_UPDATE)
- rewriteTargetList(parsetree, rt_entry_relation, NULL);
- else if (event == CMD_INSERT)
+ if (event == CMD_INSERT)
{
RangeTblEntry *values_rte = NULL;
List *attrnos;
/* Process the main targetlist ... */
- rewriteTargetList(parsetree, rt_entry_relation, &attrnos);
+ rewriteTargetListIU(parsetree, rt_entry_relation, &attrnos);
/* ... and the VALUES expression lists */
rewriteValuesRTE(values_rte, rt_entry_relation, attrnos);
}
else
{
/* Process just the main targetlist */
- rewriteTargetList(parsetree, rt_entry_relation, NULL);
+ rewriteTargetListIU(parsetree, rt_entry_relation, NULL);
}
}
+ else if (event == CMD_UPDATE)
+ {
+ rewriteTargetListIU(parsetree, rt_entry_relation, NULL);
+ rewriteTargetListUD(parsetree, rt_entry_relation);
+ }
+ else if (event == CMD_DELETE)
+ {
+ rewriteTargetListUD(parsetree, rt_entry_relation);
+ }
+ else
+ elog(ERROR, "unrecognized commandType: %d", (int) event);
/*
* Collect and apply the appropriate rules.
QueryRewrite(Query *parsetree)
{
List *querylist;
- List *results = NIL;
+ List *results;
ListCell *l;
CmdType origCmdType;
bool foundOriginalQuery;
*
* Apply all the RIR rules on each query
*/
+ results = NIL;
foreach(l, querylist)
{
Query *query = (Query *) lfirst(l);
query = fireRIRrules(query, NIL, false);
-
- /*
- * If the query target was rewritten as a view, complain.
- */
- if (query->resultRelation)
- {
- RangeTblEntry *rte = rt_fetch(query->resultRelation,
- query->rtable);
-
- if (rte->rtekind == RTE_SUBQUERY)
- {
- switch (query->commandType)
- {
- case CMD_INSERT:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("cannot insert into a view"),
- errhint("You need an unconditional ON INSERT DO INSTEAD rule.")));
- break;
- case CMD_UPDATE:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("cannot update a view"),
- errhint("You need an unconditional ON UPDATE DO INSTEAD rule.")));
- break;
- case CMD_DELETE:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("cannot delete from a view"),
- errhint("You need an unconditional ON DELETE DO INSTEAD rule.")));
- break;
- default:
- elog(ERROR, "unrecognized commandType: %d",
- (int) query->commandType);
- break;
- }
- }
- }
-
results = lappend(results, query);
}
/* Normal case referencing one targetlist element */
tle = get_tle_by_resno(rcon->targetlist, var->varattno);
- if (tle == NULL)
+ if (tle == NULL || tle->resjunk)
{
/* Failed to find column in insert/update tlist */
if (rcon->event == CMD_UPDATE)
if (TRIGGER_FOR_BEFORE(trigrec->tgtype))
appendStringInfo(&buf, "BEFORE");
- else
+ else if (TRIGGER_FOR_AFTER(trigrec->tgtype))
appendStringInfo(&buf, "AFTER");
+ else if (TRIGGER_FOR_INSTEAD(trigrec->tgtype))
+ appendStringInfo(&buf, "INSTEAD OF");
+ else
+ elog(ERROR, "unexpected tgtype value: %d", trigrec->tgtype);
+
if (TRIGGER_FOR_INSERT(trigrec->tgtype))
{
appendStringInfo(&buf, " INSERT");
appendPQExpBuffer(query, "\n ");
/* Trigger type */
- findx = 0;
if (TRIGGER_FOR_BEFORE(tginfo->tgtype))
appendPQExpBuffer(query, "BEFORE");
- else
+ else if (TRIGGER_FOR_AFTER(tginfo->tgtype))
appendPQExpBuffer(query, "AFTER");
+ else if (TRIGGER_FOR_INSTEAD(tginfo->tgtype))
+ appendPQExpBuffer(query, "INSTEAD OF");
+ else
+ {
+ write_msg(NULL, "unexpected tgtype value: %d\n", tginfo->tgtype);
+ exit_nicely();
+ }
+
+ findx = 0;
if (TRIGGER_FOR_INSERT(tginfo->tgtype))
{
appendPQExpBuffer(query, " INSERT");
}
PQclear(result);
}
+ }
+
+ /*
+ * Print triggers next, if any (but only user-defined triggers). This
+ * could apply to either a table or a view.
+ */
+ if (tableinfo.hastriggers)
+ {
+ PGresult *result;
+ int tuples;
- /* print triggers (but only user-defined triggers) */
- if (tableinfo.hastriggers)
- {
printfPQExpBuffer(&buf,
"SELECT t.tgname, "
"pg_catalog.pg_get_triggerdef(t.oid%s), "
}
}
PQclear(result);
- }
+ }
+
+ /*
+ * Finish printing the footer information about a table.
+ */
+ if (tableinfo.relkind == 'r')
+ {
+ PGresult *result;
+ int tuples;
/* print inherited tables */
printfPQExpBuffer(&buf, "SELECT c.oid::pg_catalog.regclass FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i WHERE c.oid=i.inhparent AND i.inhrelid = '%s' ORDER BY inhseqno", oid);
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201009281
+#define CATALOG_VERSION_NO 201010101
#endif
Oid tgrelid; /* relation trigger is attached to */
NameData tgname; /* trigger's name */
Oid tgfoid; /* OID of function to be called */
- int2 tgtype; /* BEFORE/AFTER UPDATE/DELETE/INSERT
+ int2 tgtype; /* BEFORE/AFTER/INSTEAD, UPDATE/DELETE/INSERT,
* ROW/STATEMENT; see below */
char tgenabled; /* trigger's firing configuration WRT
* session_replication_role */
#define TRIGGER_TYPE_DELETE (1 << 3)
#define TRIGGER_TYPE_UPDATE (1 << 4)
#define TRIGGER_TYPE_TRUNCATE (1 << 5)
+#define TRIGGER_TYPE_INSTEAD (1 << 6)
+
+#define TRIGGER_TYPE_LEVEL_MASK (TRIGGER_TYPE_ROW)
+#define TRIGGER_TYPE_STATEMENT 0
+
+/* Note bits within TRIGGER_TYPE_TIMING_MASK aren't adjacent */
+#define TRIGGER_TYPE_TIMING_MASK \
+ (TRIGGER_TYPE_BEFORE | TRIGGER_TYPE_INSTEAD)
+#define TRIGGER_TYPE_AFTER 0
+
+#define TRIGGER_TYPE_EVENT_MASK \
+ (TRIGGER_TYPE_INSERT | TRIGGER_TYPE_DELETE | TRIGGER_TYPE_UPDATE | TRIGGER_TYPE_TRUNCATE)
/* Macros for manipulating tgtype */
#define TRIGGER_CLEAR_TYPE(type) ((type) = 0)
#define TRIGGER_SETT_ROW(type) ((type) |= TRIGGER_TYPE_ROW)
+#define TRIGGER_SETT_STATEMENT(type) ((type) |= TRIGGER_TYPE_STATEMENT)
#define TRIGGER_SETT_BEFORE(type) ((type) |= TRIGGER_TYPE_BEFORE)
+#define TRIGGER_SETT_AFTER(type) ((type) |= TRIGGER_TYPE_AFTER)
+#define TRIGGER_SETT_INSTEAD(type) ((type) |= TRIGGER_TYPE_INSTEAD)
#define TRIGGER_SETT_INSERT(type) ((type) |= TRIGGER_TYPE_INSERT)
#define TRIGGER_SETT_DELETE(type) ((type) |= TRIGGER_TYPE_DELETE)
#define TRIGGER_SETT_UPDATE(type) ((type) |= TRIGGER_TYPE_UPDATE)
#define TRIGGER_SETT_TRUNCATE(type) ((type) |= TRIGGER_TYPE_TRUNCATE)
#define TRIGGER_FOR_ROW(type) ((type) & TRIGGER_TYPE_ROW)
-#define TRIGGER_FOR_BEFORE(type) ((type) & TRIGGER_TYPE_BEFORE)
+#define TRIGGER_FOR_BEFORE(type) (((type) & TRIGGER_TYPE_TIMING_MASK) == TRIGGER_TYPE_BEFORE)
+#define TRIGGER_FOR_AFTER(type) (((type) & TRIGGER_TYPE_TIMING_MASK) == TRIGGER_TYPE_AFTER)
+#define TRIGGER_FOR_INSTEAD(type) (((type) & TRIGGER_TYPE_TIMING_MASK) == TRIGGER_TYPE_INSTEAD)
#define TRIGGER_FOR_INSERT(type) ((type) & TRIGGER_TYPE_INSERT)
#define TRIGGER_FOR_DELETE(type) ((type) & TRIGGER_TYPE_DELETE)
#define TRIGGER_FOR_UPDATE(type) ((type) & TRIGGER_TYPE_UPDATE)
#define TRIGGER_FOR_TRUNCATE(type) ((type) & TRIGGER_TYPE_TRUNCATE)
+/*
+ * Efficient macro for checking if tgtype matches a particular level
+ * (TRIGGER_TYPE_ROW or TRIGGER_TYPE_STATEMENT), timing (TRIGGER_TYPE_BEFORE,
+ * TRIGGER_TYPE_AFTER or TRIGGER_TYPE_INSTEAD), and event (TRIGGER_TYPE_INSERT,
+ * TRIGGER_TYPE_DELETE, TRIGGER_TYPE_UPDATE, or TRIGGER_TYPE_TRUNCATE). Note
+ * that a tgtype can match more than one event, but only one level or timing.
+ */
+#define TRIGGER_TYPE_MATCHES(type, level, timing, event) \
+ (((type) & (TRIGGER_TYPE_LEVEL_MASK | TRIGGER_TYPE_TIMING_MASK | (event))) == ((level) | (timing) | (event)))
+
#endif /* PG_TRIGGER_H */
#define TRIGGER_EVENT_UPDATE 0x00000002
#define TRIGGER_EVENT_TRUNCATE 0x00000003
#define TRIGGER_EVENT_OPMASK 0x00000003
+
#define TRIGGER_EVENT_ROW 0x00000004
+
#define TRIGGER_EVENT_BEFORE 0x00000008
+#define TRIGGER_EVENT_AFTER 0x00000000
+#define TRIGGER_EVENT_INSTEAD 0x00000010
+#define TRIGGER_EVENT_TIMINGMASK 0x00000018
/* More TriggerEvent flags, used only within trigger.c */
-#define AFTER_TRIGGER_DEFERRABLE 0x00000010
-#define AFTER_TRIGGER_INITDEFERRED 0x00000020
+#define AFTER_TRIGGER_DEFERRABLE 0x00000020
+#define AFTER_TRIGGER_INITDEFERRED 0x00000040
-#define TRIGGER_FIRED_BY_INSERT(event) \
- (((TriggerEvent) (event) & TRIGGER_EVENT_OPMASK) == \
- TRIGGER_EVENT_INSERT)
+#define TRIGGER_FIRED_BY_INSERT(event) \
+ (((event) & TRIGGER_EVENT_OPMASK) == TRIGGER_EVENT_INSERT)
-#define TRIGGER_FIRED_BY_DELETE(event) \
- (((TriggerEvent) (event) & TRIGGER_EVENT_OPMASK) == \
- TRIGGER_EVENT_DELETE)
+#define TRIGGER_FIRED_BY_DELETE(event) \
+ (((event) & TRIGGER_EVENT_OPMASK) == TRIGGER_EVENT_DELETE)
-#define TRIGGER_FIRED_BY_UPDATE(event) \
- (((TriggerEvent) (event) & TRIGGER_EVENT_OPMASK) == \
- TRIGGER_EVENT_UPDATE)
+#define TRIGGER_FIRED_BY_UPDATE(event) \
+ (((event) & TRIGGER_EVENT_OPMASK) == TRIGGER_EVENT_UPDATE)
#define TRIGGER_FIRED_BY_TRUNCATE(event) \
- (((TriggerEvent) (event) & TRIGGER_EVENT_OPMASK) == \
- TRIGGER_EVENT_TRUNCATE)
+ (((event) & TRIGGER_EVENT_OPMASK) == TRIGGER_EVENT_TRUNCATE)
+
+#define TRIGGER_FIRED_FOR_ROW(event) \
+ ((event) & TRIGGER_EVENT_ROW)
-#define TRIGGER_FIRED_FOR_ROW(event) \
- ((TriggerEvent) (event) & TRIGGER_EVENT_ROW)
+#define TRIGGER_FIRED_FOR_STATEMENT(event) \
+ (!TRIGGER_FIRED_FOR_ROW(event))
-#define TRIGGER_FIRED_FOR_STATEMENT(event) \
- (!TRIGGER_FIRED_FOR_ROW (event))
+#define TRIGGER_FIRED_BEFORE(event) \
+ (((event) & TRIGGER_EVENT_TIMINGMASK) == TRIGGER_EVENT_BEFORE)
-#define TRIGGER_FIRED_BEFORE(event) \
- ((TriggerEvent) (event) & TRIGGER_EVENT_BEFORE)
+#define TRIGGER_FIRED_AFTER(event) \
+ (((event) & TRIGGER_EVENT_TIMINGMASK) == TRIGGER_EVENT_AFTER)
-#define TRIGGER_FIRED_AFTER(event) \
- (!TRIGGER_FIRED_BEFORE (event))
+#define TRIGGER_FIRED_INSTEAD(event) \
+ (((event) & TRIGGER_EVENT_TIMINGMASK) == TRIGGER_EVENT_INSTEAD)
/*
- * Definitions for the replication role based firing.
+ * Definitions for replication role based firing.
*/
#define SESSION_REPLICATION_ROLE_ORIGIN 0
#define SESSION_REPLICATION_ROLE_REPLICA 1
ResultRelInfo *relinfo,
HeapTuple trigtuple,
List *recheckIndexes);
+extern HeapTuple ExecIRInsertTriggers(EState *estate,
+ ResultRelInfo *relinfo,
+ HeapTuple trigtuple);
extern void ExecBSDeleteTriggers(EState *estate,
ResultRelInfo *relinfo);
extern void ExecASDeleteTriggers(EState *estate,
extern void ExecARDeleteTriggers(EState *estate,
ResultRelInfo *relinfo,
ItemPointer tupleid);
+extern bool ExecIRDeleteTriggers(EState *estate,
+ ResultRelInfo *relinfo,
+ HeapTuple trigtuple);
extern void ExecBSUpdateTriggers(EState *estate,
ResultRelInfo *relinfo);
extern void ExecASUpdateTriggers(EState *estate,
ItemPointer tupleid,
HeapTuple newtuple,
List *recheckIndexes);
+extern HeapTuple ExecIRUpdateTriggers(EState *estate,
+ ResultRelInfo *relinfo,
+ HeapTuple oldtuple,
+ HeapTuple newtuple);
extern void ExecBSTruncateTriggers(EState *estate,
ResultRelInfo *relinfo);
extern void ExecASTruncateTriggers(EState *estate,
RangeVar *relation; /* relation trigger is on */
List *funcname; /* qual. name of function to call */
List *args; /* list of (T_String) Values or NIL */
- bool before; /* BEFORE/AFTER */
bool row; /* ROW/STATEMENT */
+ /* timing uses the TRIGGER_TYPE bits defined in catalog/pg_trigger.h */
+ int16 timing; /* BEFORE, AFTER, or INSTEAD */
/* events uses the TRIGGER_TYPE bits defined in catalog/pg_trigger.h */
- int16 events; /* INSERT/UPDATE/DELETE/TRUNCATE */
+ int16 events; /* "OR" of INSERT/UPDATE/DELETE/TRUNCATE */
List *columns; /* column names, or NIL for all columns */
Node *whenClause; /* qual expression, or NULL if none */
bool isconstraint; /* This is a constraint trigger */
typedef struct TriggerDesc
{
+ Trigger *triggers; /* array of Trigger structs */
+ int numtriggers; /* number of array entries */
+
/*
- * Index data to identify which triggers are which. Since each trigger
- * can appear in more than one class, for each class we provide a list of
- * integer indexes into the triggers array. The class codes are defined
- * by TRIGGER_EVENT_xxx macros in commands/trigger.h.
+ * These flags indicate whether the array contains at least one of each
+ * type of trigger. We use these to skip searching the array if not.
*/
-#define TRIGGER_NUM_EVENT_CLASSES 4
-
- uint16 n_before_statement[TRIGGER_NUM_EVENT_CLASSES];
- uint16 n_before_row[TRIGGER_NUM_EVENT_CLASSES];
- uint16 n_after_row[TRIGGER_NUM_EVENT_CLASSES];
- uint16 n_after_statement[TRIGGER_NUM_EVENT_CLASSES];
- int *tg_before_statement[TRIGGER_NUM_EVENT_CLASSES];
- int *tg_before_row[TRIGGER_NUM_EVENT_CLASSES];
- int *tg_after_row[TRIGGER_NUM_EVENT_CLASSES];
- int *tg_after_statement[TRIGGER_NUM_EVENT_CLASSES];
-
- /* The actual array of triggers is here */
- Trigger *triggers;
- int numtriggers;
+ bool trig_insert_before_row;
+ bool trig_insert_after_row;
+ bool trig_insert_instead_row;
+ bool trig_insert_before_statement;
+ bool trig_insert_after_statement;
+ bool trig_update_before_row;
+ bool trig_update_after_row;
+ bool trig_update_instead_row;
+ bool trig_update_before_statement;
+ bool trig_update_after_statement;
+ bool trig_delete_before_row;
+ bool trig_delete_after_row;
+ bool trig_delete_instead_row;
+ bool trig_delete_before_statement;
+ bool trig_delete_after_statement;
+ /* there are no row-level truncate triggers */
+ bool trig_truncate_before_statement;
+ bool trig_truncate_after_statement;
} TriggerDesc;
CONTEXT: PL/Perl function "trigger_data"
DROP TRIGGER show_trigger_data_trig on trigger_test;
+insert into trigger_test values(1,'insert');
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
+CREATE TRIGGER show_trigger_data_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
+insert into trigger_test_view values(2,'insert');
+NOTICE: $_TD->{argc} = '2'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{args} = ['24', 'skidoo view']
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{event} = 'INSERT'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{level} = 'ROW'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{name} = 'show_trigger_data_trig'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{new} = {'i' => '2', 'v' => 'insert'}
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relid} = 'bogus:12345'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relname} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_name} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_schema} = 'public'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{when} = 'INSTEAD OF'
+CONTEXT: PL/Perl function "trigger_data"
+update trigger_test_view set v = 'update' where i = 1;
+NOTICE: $_TD->{argc} = '2'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{args} = ['24', 'skidoo view']
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{event} = 'UPDATE'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{level} = 'ROW'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{name} = 'show_trigger_data_trig'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{new} = {'i' => '1', 'v' => 'update'}
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{old} = {'i' => '1', 'v' => 'insert'}
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relid} = 'bogus:12345'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relname} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_name} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_schema} = 'public'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{when} = 'INSTEAD OF'
+CONTEXT: PL/Perl function "trigger_data"
+delete from trigger_test_view;
+NOTICE: $_TD->{argc} = '2'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{args} = ['24', 'skidoo view']
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{event} = 'DELETE'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{level} = 'ROW'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{name} = 'show_trigger_data_trig'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{old} = {'i' => '1', 'v' => 'insert'}
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relid} = 'bogus:12345'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{relname} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_name} = 'trigger_test_view'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{table_schema} = 'public'
+CONTEXT: PL/Perl function "trigger_data"
+NOTICE: $_TD->{when} = 'INSTEAD OF'
+CONTEXT: PL/Perl function "trigger_data"
+DROP VIEW trigger_test_view;
+delete from trigger_test;
DROP FUNCTION trigger_data();
CREATE OR REPLACE FUNCTION valid_id() RETURNS trigger AS $$
when = "BEFORE";
else if (TRIGGER_FIRED_AFTER(tdata->tg_event))
when = "AFTER";
+ else if (TRIGGER_FIRED_INSTEAD(tdata->tg_event))
+ when = "INSTEAD OF";
else
when = "UNKNOWN";
hv_store_string(hv, "when", newSVstring(when));
delete from trigger_test;
DROP TRIGGER show_trigger_data_trig on trigger_test;
+
+insert into trigger_test values(1,'insert');
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
+
+CREATE TRIGGER show_trigger_data_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
+
+insert into trigger_test_view values(2,'insert');
+update trigger_test_view set v = 'update' where i = 1;
+delete from trigger_test_view;
+
+DROP VIEW trigger_test_view;
+delete from trigger_test;
DROP FUNCTION trigger_data();
var->value = CStringGetTextDatum("BEFORE");
else if (TRIGGER_FIRED_AFTER(trigdata->tg_event))
var->value = CStringGetTextDatum("AFTER");
+ else if (TRIGGER_FIRED_INSTEAD(trigdata->tg_event))
+ var->value = CStringGetTextDatum("INSTEAD OF");
else
- elog(ERROR, "unrecognized trigger execution time: not BEFORE or AFTER");
+ elog(ERROR, "unrecognized trigger execution time: not BEFORE, AFTER, or INSTEAD OF");
var->isnull = false;
var->freeval = true;
CONTEXT: PL/Python function "trigger_data"
NOTICE: TD[when] => BEFORE
CONTEXT: PL/Python function "trigger_data"
+DROP TRIGGER show_trigger_data_trig_stmt on trigger_test;
+DROP TRIGGER show_trigger_data_trig_before on trigger_test;
+DROP TRIGGER show_trigger_data_trig_after on trigger_test;
+insert into trigger_test values(1,'insert');
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
+CREATE TRIGGER show_trigger_data_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
+insert into trigger_test_view values(2,'insert');
+NOTICE: TD[args] => ['24', 'skidoo view']
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[event] => INSERT
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[level] => ROW
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[name] => show_trigger_data_trig
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[new] => {'i': 2, 'v': 'insert'}
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[old] => None
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[relid] => bogus:12345
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_name] => trigger_test_view
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_schema] => public
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[when] => INSTEAD OF
+CONTEXT: PL/Python function "trigger_data"
+update trigger_test_view set v = 'update' where i = 1;
+NOTICE: TD[args] => ['24', 'skidoo view']
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[event] => UPDATE
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[level] => ROW
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[name] => show_trigger_data_trig
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[new] => {'i': 1, 'v': 'update'}
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[old] => {'i': 1, 'v': 'insert'}
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[relid] => bogus:12345
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_name] => trigger_test_view
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_schema] => public
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[when] => INSTEAD OF
+CONTEXT: PL/Python function "trigger_data"
+delete from trigger_test_view;
+NOTICE: TD[args] => ['24', 'skidoo view']
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[event] => DELETE
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[level] => ROW
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[name] => show_trigger_data_trig
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[new] => None
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[old] => {'i': 1, 'v': 'insert'}
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[relid] => bogus:12345
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_name] => trigger_test_view
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[table_schema] => public
+CONTEXT: PL/Python function "trigger_data"
+NOTICE: TD[when] => INSTEAD OF
+CONTEXT: PL/Python function "trigger_data"
DROP FUNCTION trigger_data() CASCADE;
-NOTICE: drop cascades to 3 other objects
-DETAIL: drop cascades to trigger show_trigger_data_trig_before on table trigger_test
-drop cascades to trigger show_trigger_data_trig_after on table trigger_test
-drop cascades to trigger show_trigger_data_trig_stmt on table trigger_test
+NOTICE: drop cascades to trigger show_trigger_data_trig on view trigger_test_view
+DROP VIEW trigger_test_view;
+delete from trigger_test;
--
-- trigger error handling
--
pltwhen = PyString_FromString("BEFORE");
else if (TRIGGER_FIRED_AFTER(tdata->tg_event))
pltwhen = PyString_FromString("AFTER");
+ else if (TRIGGER_FIRED_INSTEAD(tdata->tg_event))
+ pltwhen = PyString_FromString("INSTEAD OF");
else
{
elog(ERROR, "unrecognized WHEN tg_event: %u", tdata->tg_event);
delete from trigger_test;
truncate table trigger_test;
+DROP TRIGGER show_trigger_data_trig_stmt on trigger_test;
+DROP TRIGGER show_trigger_data_trig_before on trigger_test;
+DROP TRIGGER show_trigger_data_trig_after on trigger_test;
+
+insert into trigger_test values(1,'insert');
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
+
+CREATE TRIGGER show_trigger_data_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
+
+insert into trigger_test_view values(2,'insert');
+update trigger_test_view set v = 'update' where i = 1;
+delete from trigger_test_view;
+
DROP FUNCTION trigger_data() CASCADE;
+DROP VIEW trigger_test_view;
+delete from trigger_test;
--
NOTICE: TG_table_schema: public
NOTICE: TG_when: BEFORE
NOTICE: args: {23 skidoo}
+insert into trigger_test_view values(2,'insert');
+NOTICE: NEW: {i: 2, v: insert}
+NOTICE: OLD: {}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: INSERT
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
+update trigger_test_view set v = 'update' where i=1;
+NOTICE: NEW: {i: 1, v: update}
+NOTICE: OLD: {i: 1, v: insert}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: UPDATE
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
+delete from trigger_test_view;
+NOTICE: NEW: {}
+NOTICE: OLD: {i: 1, v: insert}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: DELETE
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
update trigger_test set v = 'update' where i = 1;
NOTICE: NEW: {i: 1, v: update}
NOTICE: OLD: {i: 1, v: insert}
NOTICE: TG_table_schema: public
NOTICE: TG_when: BEFORE
NOTICE: args: {23 skidoo}
+insert into trigger_test_view values(2,'insert');
+NOTICE: NEW: {i: 2, v: insert}
+NOTICE: OLD: {}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: INSERT
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
+update trigger_test_view set v = 'update' where i=1;
+NOTICE: NEW: {i: 1, v: update}
+NOTICE: OLD: {i: 1, v: insert}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: UPDATE
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
+delete from trigger_test_view;
+NOTICE: NEW: {}
+NOTICE: OLD: {i: 1, v: insert}
+NOTICE: TG_level: ROW
+NOTICE: TG_name: show_trigger_data_view_trig
+NOTICE: TG_op: DELETE
+NOTICE: TG_relatts: {{} i v}
+NOTICE: TG_relid: bogus:12345
+NOTICE: TG_table_name: trigger_test_view
+NOTICE: TG_table_schema: public
+NOTICE: TG_when: {INSTEAD OF}
+NOTICE: args: {24 {skidoo view}}
update trigger_test set v = 'update' where i = 1;
NOTICE: NEW: {i: 1, v: update}
NOTICE: OLD: {i: 1, v: insert}
-- dump trigger data
CREATE TABLE trigger_test
(i int, v text );
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
CREATE FUNCTION trigger_data() returns trigger language pltcl as $_$
if { [info exists TG_relid] } {
CREATE TRIGGER show_trigger_data_trig
BEFORE INSERT OR UPDATE OR DELETE ON trigger_test
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER show_trigger_data_view_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
--
-- Trigger function on every change to T_pkey1
--
Tcl_DStringAppendElement(&tcl_cmd, "BEFORE");
else if (TRIGGER_FIRED_AFTER(trigdata->tg_event))
Tcl_DStringAppendElement(&tcl_cmd, "AFTER");
+ else if (TRIGGER_FIRED_INSTEAD(trigdata->tg_event))
+ Tcl_DStringAppendElement(&tcl_cmd, "INSTEAD OF");
else
elog(ERROR, "unrecognized WHEN tg_event: %u", trigdata->tg_event);
select * from T_pkey1 order by key1 using @<, key2;
select * from T_pkey2 order by key1 using @<, key2;
-
-- show dump of trigger data
insert into trigger_test values(1,'insert');
+
+insert into trigger_test_view values(2,'insert');
+update trigger_test_view set v = 'update' where i=1;
+delete from trigger_test_view;
+
update trigger_test set v = 'update' where i = 1;
delete from trigger_test;
CREATE TABLE trigger_test
(i int, v text );
+CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
+
CREATE FUNCTION trigger_data() returns trigger language pltcl as $_$
if { [info exists TG_relid] } {
BEFORE INSERT OR UPDATE OR DELETE ON trigger_test
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER show_trigger_data_view_trig
+INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
--
-- Trigger function on every change to T_pkey1
DROP TABLE min_updates_test;
DROP TABLE min_updates_test_oids;
+--
+-- Test triggers on views
+--
+CREATE VIEW main_view AS SELECT a, b FROM main_table;
+-- Updates should fail without rules or triggers
+INSERT INTO main_view VALUES (1,2);
+ERROR: cannot insert into view "main_view"
+HINT: You need an unconditional ON INSERT DO INSTEAD rule or an INSTEAD OF INSERT trigger.
+UPDATE main_view SET b = 20 WHERE a = 50;
+ERROR: cannot update view "main_view"
+HINT: You need an unconditional ON UPDATE DO INSTEAD rule or an INSTEAD OF UPDATE trigger.
+DELETE FROM main_view WHERE a = 50;
+ERROR: cannot delete from view "main_view"
+HINT: You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger.
+-- Should fail even when there are no matching rows
+DELETE FROM main_view WHERE a = 51;
+ERROR: cannot delete from view "main_view"
+HINT: You need an unconditional ON DELETE DO INSTEAD rule or an INSTEAD OF DELETE trigger.
+-- VIEW trigger function
+CREATE OR REPLACE FUNCTION view_trigger() RETURNS trigger
+LANGUAGE plpgsql AS $$
+declare
+ argstr text := '';
+begin
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ raise notice '% % % % (%)', TG_RELNAME, TG_WHEN, TG_OP, TG_LEVEL, argstr;
+
+ if TG_LEVEL = 'ROW' then
+ if TG_OP = 'INSERT' then
+ raise NOTICE 'NEW: %', NEW;
+ INSERT INTO main_table VALUES (NEW.a, NEW.b);
+ RETURN NEW;
+ end if;
+
+ if TG_OP = 'UPDATE' then
+ raise NOTICE 'OLD: %, NEW: %', OLD, NEW;
+ UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN NEW;
+ end if;
+
+ if TG_OP = 'DELETE' then
+ raise NOTICE 'OLD: %', OLD;
+ DELETE FROM main_table WHERE a = OLD.a AND b = OLD.b;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN OLD;
+ end if;
+ end if;
+
+ RETURN NULL;
+end;
+$$;
+-- Before row triggers aren't allowed on views
+CREATE TRIGGER invalid_trig BEFORE INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+CREATE TRIGGER invalid_trig BEFORE UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+CREATE TRIGGER invalid_trig BEFORE DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+-- After row triggers aren't allowed on views
+CREATE TRIGGER invalid_trig AFTER INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+CREATE TRIGGER invalid_trig AFTER UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+CREATE TRIGGER invalid_trig AFTER DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have row-level BEFORE or AFTER triggers.
+-- Truncate triggers aren't allowed on views
+CREATE TRIGGER invalid_trig BEFORE TRUNCATE ON main_view
+EXECUTE PROCEDURE trigger_func('before_tru_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have TRUNCATE triggers.
+CREATE TRIGGER invalid_trig AFTER TRUNCATE ON main_view
+EXECUTE PROCEDURE trigger_func('before_tru_row');
+ERROR: "main_view" is a view
+DETAIL: Views cannot have TRUNCATE triggers.
+-- INSTEAD OF triggers aren't allowed on tables
+CREATE TRIGGER invalid_trig INSTEAD OF INSERT ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
+ERROR: "main_table" is a table
+DETAIL: Tables cannot have INSTEAD OF triggers.
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+ERROR: "main_table" is a table
+DETAIL: Tables cannot have INSTEAD OF triggers.
+CREATE TRIGGER invalid_trig INSTEAD OF DELETE ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
+ERROR: "main_table" is a table
+DETAIL: Tables cannot have INSTEAD OF triggers.
+-- Don't support WHEN clauses with INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
+FOR EACH ROW WHEN (OLD.a <> NEW.a) EXECUTE PROCEDURE view_trigger('instead_of_upd');
+ERROR: INSTEAD OF triggers cannot have WHEN conditions
+-- Don't support column-level INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE OF a ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+ERROR: INSTEAD OF triggers cannot have column lists
+-- Don't support statement-level INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
+EXECUTE PROCEDURE view_trigger('instead_of_upd');
+ERROR: INSTEAD OF triggers must be FOR EACH ROW
+-- Valid INSTEAD OF triggers
+CREATE TRIGGER instead_of_insert_trig INSTEAD OF INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
+CREATE TRIGGER instead_of_update_trig INSTEAD OF UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+CREATE TRIGGER instead_of_delete_trig INSTEAD OF DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
+-- Valid BEFORE statement VIEW triggers
+CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_ins_stmt');
+CREATE TRIGGER before_upd_stmt_trig BEFORE UPDATE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_upd_stmt');
+CREATE TRIGGER before_del_stmt_trig BEFORE DELETE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_del_stmt');
+-- Valid AFTER statement VIEW triggers
+CREATE TRIGGER after_ins_stmt_trig AFTER INSERT ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_ins_stmt');
+CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_upd_stmt');
+CREATE TRIGGER after_del_stmt_trig AFTER DELETE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_del_stmt');
+\set QUIET false
+-- Insert into view using trigger
+INSERT INTO main_view VALUES (20, 30);
+NOTICE: main_view BEFORE INSERT STATEMENT (before_view_ins_stmt)
+NOTICE: main_view INSTEAD OF INSERT ROW (instead_of_ins)
+NOTICE: NEW: (20,30)
+NOTICE: trigger_func(before_ins_stmt) called: action = INSERT, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "INSERT INTO main_table VALUES (NEW.a, NEW.b)"
+PL/pgSQL function "view_trigger" line 17 at SQL statement
+NOTICE: trigger_func(after_ins_stmt) called: action = INSERT, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "INSERT INTO main_table VALUES (NEW.a, NEW.b)"
+PL/pgSQL function "view_trigger" line 17 at SQL statement
+NOTICE: main_view AFTER INSERT STATEMENT (after_view_ins_stmt)
+INSERT 0 1
+INSERT INTO main_view VALUES (21, 31) RETURNING a, b;
+NOTICE: main_view BEFORE INSERT STATEMENT (before_view_ins_stmt)
+NOTICE: main_view INSTEAD OF INSERT ROW (instead_of_ins)
+NOTICE: NEW: (21,31)
+NOTICE: trigger_func(before_ins_stmt) called: action = INSERT, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "INSERT INTO main_table VALUES (NEW.a, NEW.b)"
+PL/pgSQL function "view_trigger" line 17 at SQL statement
+NOTICE: trigger_func(after_ins_stmt) called: action = INSERT, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "INSERT INTO main_table VALUES (NEW.a, NEW.b)"
+PL/pgSQL function "view_trigger" line 17 at SQL statement
+NOTICE: main_view AFTER INSERT STATEMENT (after_view_ins_stmt)
+ a | b
+----+----
+ 21 | 31
+(1 row)
+
+INSERT 0 1
+-- Table trigger will prevent updates
+UPDATE main_view SET b = 31 WHERE a = 20;
+NOTICE: main_view BEFORE UPDATE STATEMENT (before_view_upd_stmt)
+NOTICE: main_view INSTEAD OF UPDATE ROW (instead_of_upd)
+NOTICE: OLD: (20,30), NEW: (20,31)
+NOTICE: trigger_func(before_upd_a_stmt) called: action = UPDATE, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(before_upd_a_row) called: action = UPDATE, when = BEFORE, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: main_view AFTER UPDATE STATEMENT (after_view_upd_stmt)
+UPDATE 0
+UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
+NOTICE: main_view BEFORE UPDATE STATEMENT (before_view_upd_stmt)
+NOTICE: main_view INSTEAD OF UPDATE ROW (instead_of_upd)
+NOTICE: OLD: (21,31), NEW: (21,32)
+NOTICE: trigger_func(before_upd_a_stmt) called: action = UPDATE, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(before_upd_a_row) called: action = UPDATE, when = BEFORE, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: main_view AFTER UPDATE STATEMENT (after_view_upd_stmt)
+ a | b
+---+---
+(0 rows)
+
+UPDATE 0
+-- Remove table trigger to allow updates
+DROP TRIGGER before_upd_a_row_trig ON main_table;
+DROP TRIGGER
+UPDATE main_view SET b = 31 WHERE a = 20;
+NOTICE: main_view BEFORE UPDATE STATEMENT (before_view_upd_stmt)
+NOTICE: main_view INSTEAD OF UPDATE ROW (instead_of_upd)
+NOTICE: OLD: (20,30), NEW: (20,31)
+NOTICE: trigger_func(before_upd_a_stmt) called: action = UPDATE, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_a_b_row) called: action = UPDATE, when = AFTER, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_row) called: action = UPDATE, when = AFTER, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: main_view AFTER UPDATE STATEMENT (after_view_upd_stmt)
+UPDATE 1
+UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
+NOTICE: main_view BEFORE UPDATE STATEMENT (before_view_upd_stmt)
+NOTICE: main_view INSTEAD OF UPDATE ROW (instead_of_upd)
+NOTICE: OLD: (21,31), NEW: (21,32)
+NOTICE: trigger_func(before_upd_a_stmt) called: action = UPDATE, when = BEFORE, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_a_b_row) called: action = UPDATE, when = AFTER, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_row) called: action = UPDATE, when = AFTER, level = ROW
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_b_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: trigger_func(after_upd_stmt) called: action = UPDATE, when = AFTER, level = STATEMENT
+CONTEXT: SQL statement "UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b"
+PL/pgSQL function "view_trigger" line 23 at SQL statement
+NOTICE: main_view AFTER UPDATE STATEMENT (after_view_upd_stmt)
+ a | b
+----+----
+ 21 | 32
+(1 row)
+
+UPDATE 1
+-- Before and after stmt triggers should fire even when no rows are affected
+UPDATE main_view SET b = 0 WHERE false;
+NOTICE: main_view BEFORE UPDATE STATEMENT (before_view_upd_stmt)
+NOTICE: main_view AFTER UPDATE STATEMENT (after_view_upd_stmt)
+UPDATE 0
+-- Delete from view using trigger
+DELETE FROM main_view WHERE a IN (20,21);
+NOTICE: main_view BEFORE DELETE STATEMENT (before_view_del_stmt)
+NOTICE: main_view INSTEAD OF DELETE ROW (instead_of_del)
+NOTICE: OLD: (21,10)
+NOTICE: main_view INSTEAD OF DELETE ROW (instead_of_del)
+NOTICE: OLD: (20,31)
+NOTICE: main_view INSTEAD OF DELETE ROW (instead_of_del)
+NOTICE: OLD: (21,32)
+NOTICE: main_view AFTER DELETE STATEMENT (after_view_del_stmt)
+DELETE 3
+DELETE FROM main_view WHERE a = 31 RETURNING a, b;
+NOTICE: main_view BEFORE DELETE STATEMENT (before_view_del_stmt)
+NOTICE: main_view INSTEAD OF DELETE ROW (instead_of_del)
+NOTICE: OLD: (31,10)
+NOTICE: main_view AFTER DELETE STATEMENT (after_view_del_stmt)
+ a | b
+----+----
+ 31 | 10
+(1 row)
+
+DELETE 1
+\set QUIET true
+-- Describe view should list triggers
+\d main_view
+ View "public.main_view"
+ Column | Type | Modifiers
+--------+---------+-----------
+ a | integer |
+ b | integer |
+Triggers:
+ after_del_stmt_trig AFTER DELETE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_del_stmt')
+ after_ins_stmt_trig AFTER INSERT ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_ins_stmt')
+ after_upd_stmt_trig AFTER UPDATE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_upd_stmt')
+ before_del_stmt_trig BEFORE DELETE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_del_stmt')
+ before_ins_stmt_trig BEFORE INSERT ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_ins_stmt')
+ before_upd_stmt_trig BEFORE UPDATE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_upd_stmt')
+ instead_of_delete_trig INSTEAD OF DELETE ON main_view FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del')
+ instead_of_insert_trig INSTEAD OF INSERT ON main_view FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins')
+ instead_of_update_trig INSTEAD OF UPDATE ON main_view FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd')
+
+-- Test dropping view triggers
+DROP TRIGGER instead_of_insert_trig ON main_view;
+DROP TRIGGER instead_of_delete_trig ON main_view;
+\d+ main_view
+ View "public.main_view"
+ Column | Type | Modifiers | Storage | Description
+--------+---------+-----------+---------+-------------
+ a | integer | | plain |
+ b | integer | | plain |
+View definition:
+ SELECT main_table.a, main_table.b
+ FROM main_table;
+Triggers:
+ after_del_stmt_trig AFTER DELETE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_del_stmt')
+ after_ins_stmt_trig AFTER INSERT ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_ins_stmt')
+ after_upd_stmt_trig AFTER UPDATE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_upd_stmt')
+ before_del_stmt_trig BEFORE DELETE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_del_stmt')
+ before_ins_stmt_trig BEFORE INSERT ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_ins_stmt')
+ before_upd_stmt_trig BEFORE UPDATE ON main_view FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_upd_stmt')
+ instead_of_update_trig INSTEAD OF UPDATE ON main_view FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd')
+
+DROP VIEW main_view;
+--
+-- Test triggers on a join view
+--
+CREATE TABLE country_table (
+ country_id serial primary key,
+ country_name text unique not null,
+ continent text not null
+);
+NOTICE: CREATE TABLE will create implicit sequence "country_table_country_id_seq" for serial column "country_table.country_id"
+NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "country_table_pkey" for table "country_table"
+NOTICE: CREATE TABLE / UNIQUE will create implicit index "country_table_country_name_key" for table "country_table"
+INSERT INTO country_table (country_name, continent)
+ VALUES ('Japan', 'Asia'),
+ ('UK', 'Europe'),
+ ('USA', 'North America')
+ RETURNING *;
+ country_id | country_name | continent
+------------+--------------+---------------
+ 1 | Japan | Asia
+ 2 | UK | Europe
+ 3 | USA | North America
+(3 rows)
+
+CREATE TABLE city_table (
+ city_id serial primary key,
+ city_name text not null,
+ population bigint,
+ country_id int references country_table
+);
+NOTICE: CREATE TABLE will create implicit sequence "city_table_city_id_seq" for serial column "city_table.city_id"
+NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "city_table_pkey" for table "city_table"
+CREATE VIEW city_view AS
+ SELECT city_id, city_name, population, country_name, continent
+ FROM city_table ci
+ LEFT JOIN country_table co ON co.country_id = ci.country_id;
+CREATE FUNCTION city_insert() RETURNS trigger LANGUAGE plpgsql AS $$
+declare
+ ctry_id int;
+begin
+ if NEW.country_name IS NOT NULL then
+ SELECT country_id, continent INTO ctry_id, NEW.continent
+ FROM country_table WHERE country_name = NEW.country_name;
+ if NOT FOUND then
+ raise exception 'No such country: "%"', NEW.country_name;
+ end if;
+ else
+ NEW.continent := NULL;
+ end if;
+
+ if NEW.city_id IS NOT NULL then
+ INSERT INTO city_table
+ VALUES(NEW.city_id, NEW.city_name, NEW.population, ctry_id);
+ else
+ INSERT INTO city_table(city_name, population, country_id)
+ VALUES(NEW.city_name, NEW.population, ctry_id)
+ RETURNING city_id INTO NEW.city_id;
+ end if;
+
+ RETURN NEW;
+end;
+$$;
+CREATE TRIGGER city_insert_trig INSTEAD OF INSERT ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_insert();
+CREATE FUNCTION city_delete() RETURNS trigger LANGUAGE plpgsql AS $$
+begin
+ DELETE FROM city_table WHERE city_id = OLD.city_id;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN OLD;
+end;
+$$;
+CREATE TRIGGER city_delete_trig INSTEAD OF DELETE ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_delete();
+CREATE FUNCTION city_update() RETURNS trigger LANGUAGE plpgsql AS $$
+declare
+ ctry_id int;
+begin
+ if NEW.country_name IS DISTINCT FROM OLD.country_name then
+ SELECT country_id, continent INTO ctry_id, NEW.continent
+ FROM country_table WHERE country_name = NEW.country_name;
+ if NOT FOUND then
+ raise exception 'No such country: "%"', NEW.country_name;
+ end if;
+
+ UPDATE city_table SET city_name = NEW.city_name,
+ population = NEW.population,
+ country_id = ctry_id
+ WHERE city_id = OLD.city_id;
+ else
+ UPDATE city_table SET city_name = NEW.city_name,
+ population = NEW.population
+ WHERE city_id = OLD.city_id;
+ NEW.continent := OLD.continent;
+ end if;
+
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN NEW;
+end;
+$$;
+CREATE TRIGGER city_update_trig INSTEAD OF UPDATE ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_update();
+\set QUIET false
+-- INSERT .. RETURNING
+INSERT INTO city_view(city_name) VALUES('Tokyo') RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 1 | Tokyo | | |
+(1 row)
+
+INSERT 0 1
+INSERT INTO city_view(city_name, population) VALUES('London', 7556900) RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 2 | London | 7556900 | |
+(1 row)
+
+INSERT 0 1
+INSERT INTO city_view(city_name, country_name) VALUES('Washington DC', 'USA') RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+---------------+------------+--------------+---------------
+ 3 | Washington DC | | USA | North America
+(1 row)
+
+INSERT 0 1
+INSERT INTO city_view(city_id, city_name) VALUES(123456, 'New York') RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 123456 | New York | | |
+(1 row)
+
+INSERT 0 1
+INSERT INTO city_view VALUES(234567, 'Birmingham', 1016800, 'UK', 'EU') RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+------------+------------+--------------+-----------
+ 234567 | Birmingham | 1016800 | UK | Europe
+(1 row)
+
+INSERT 0 1
+-- UPDATE .. RETURNING
+UPDATE city_view SET country_name = 'Japon' WHERE city_name = 'Tokyo'; -- error
+ERROR: No such country: "Japon"
+UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Takyo'; -- no match
+UPDATE 0
+UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Tokyo' RETURNING *; -- OK
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 1 | Tokyo | | Japan | Asia
+(1 row)
+
+UPDATE 1
+UPDATE city_view SET population = 13010279 WHERE city_name = 'Tokyo' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 1 | Tokyo | 13010279 | Japan | Asia
+(1 row)
+
+UPDATE 1
+UPDATE city_view SET country_name = 'UK' WHERE city_name = 'New York' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 123456 | New York | | UK | Europe
+(1 row)
+
+UPDATE 1
+UPDATE city_view SET country_name = 'USA', population = 8391881 WHERE city_name = 'New York' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+---------------
+ 123456 | New York | 8391881 | USA | North America
+(1 row)
+
+UPDATE 1
+UPDATE city_view SET continent = 'EU' WHERE continent = 'Europe' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+------------+------------+--------------+-----------
+ 234567 | Birmingham | 1016800 | UK | Europe
+(1 row)
+
+UPDATE 1
+UPDATE city_view v1 SET country_name = v2.country_name FROM city_view v2
+ WHERE v2.city_name = 'Birmingham' AND v1.city_name = 'London' RETURNING *;
+ city_id | city_name | population | country_name | continent | city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------+---------+------------+------------+--------------+-----------
+ 2 | London | 7556900 | UK | Europe | 234567 | Birmingham | 1016800 | UK | Europe
+(1 row)
+
+UPDATE 1
+-- DELETE .. RETURNING
+DELETE FROM city_view WHERE city_name = 'Birmingham' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+------------+------------+--------------+-----------
+ 234567 | Birmingham | 1016800 | UK | Europe
+(1 row)
+
+DELETE 1
+\set QUIET true
+-- read-only view with WHERE clause
+CREATE VIEW european_city_view AS
+ SELECT * FROM city_view WHERE continent = 'Europe';
+SELECT count(*) FROM european_city_view;
+ count
+-------
+ 1
+(1 row)
+
+CREATE FUNCTION no_op_trig_fn() RETURNS trigger LANGUAGE plpgsql
+AS 'begin RETURN NULL; end';
+CREATE TRIGGER no_op_trig INSTEAD OF INSERT OR UPDATE OR DELETE
+ON european_city_view FOR EACH ROW EXECUTE PROCEDURE no_op_trig_fn();
+\set QUIET false
+INSERT INTO european_city_view VALUES (0, 'x', 10000, 'y', 'z');
+INSERT 0 0
+UPDATE european_city_view SET population = 10000;
+UPDATE 0
+DELETE FROM european_city_view;
+DELETE 0
+\set QUIET true
+-- rules bypassing no-op triggers
+CREATE RULE european_city_insert_rule AS ON INSERT TO european_city_view
+DO INSTEAD INSERT INTO city_view
+VALUES (NEW.city_id, NEW.city_name, NEW.population, NEW.country_name, NEW.continent)
+RETURNING *;
+CREATE RULE european_city_update_rule AS ON UPDATE TO european_city_view
+DO INSTEAD UPDATE city_view SET
+ city_name = NEW.city_name,
+ population = NEW.population,
+ country_name = NEW.country_name
+WHERE city_id = OLD.city_id
+RETURNING NEW.*;
+CREATE RULE european_city_delete_rule AS ON DELETE TO european_city_view
+DO INSTEAD DELETE FROM city_view WHERE city_id = OLD.city_id RETURNING *;
+\set QUIET false
+-- INSERT not limited by view's WHERE clause, but UPDATE AND DELETE are
+INSERT INTO european_city_view(city_name, country_name)
+ VALUES ('Cambridge', 'USA') RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+---------------
+ 4 | Cambridge | | USA | North America
+(1 row)
+
+INSERT 0 1
+UPDATE european_city_view SET country_name = 'UK'
+ WHERE city_name = 'Cambridge';
+UPDATE 0
+DELETE FROM european_city_view WHERE city_name = 'Cambridge';
+DELETE 0
+-- UPDATE and DELETE via rule and trigger
+UPDATE city_view SET country_name = 'UK'
+ WHERE city_name = 'Cambridge' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 4 | Cambridge | | UK | Europe
+(1 row)
+
+UPDATE 1
+UPDATE european_city_view SET population = 122800
+ WHERE city_name = 'Cambridge' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 4 | Cambridge | 122800 | UK | Europe
+(1 row)
+
+UPDATE 1
+DELETE FROM european_city_view WHERE city_name = 'Cambridge' RETURNING *;
+ city_id | city_name | population | country_name | continent
+---------+-----------+------------+--------------+-----------
+ 4 | Cambridge | 122800 | UK | Europe
+(1 row)
+
+DELETE 1
+-- join UPDATE test
+UPDATE city_view v SET population = 599657
+ FROM city_table ci, country_table co
+ WHERE ci.city_name = 'Washington DC' and co.country_name = 'USA'
+ AND v.city_id = ci.city_id AND v.country_name = co.country_name
+ RETURNING co.country_id, v.country_name,
+ v.city_id, v.city_name, v.population;
+ country_id | country_name | city_id | city_name | population
+------------+--------------+---------+---------------+------------
+ 3 | USA | 3 | Washington DC | 599657
+(1 row)
+
+UPDATE 1
+\set QUIET true
+SELECT * FROM city_view;
+ city_id | city_name | population | country_name | continent
+---------+---------------+------------+--------------+---------------
+ 1 | Tokyo | 13010279 | Japan | Asia
+ 123456 | New York | 8391881 | USA | North America
+ 2 | London | 7556900 | UK | Europe
+ 3 | Washington DC | 599657 | USA | North America
+(4 rows)
+
+DROP TABLE city_table CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to view city_view
+drop cascades to view european_city_view
+DROP TABLE country_table;
DROP TABLE min_updates_test;
DROP TABLE min_updates_test_oids;
+
+--
+-- Test triggers on views
+--
+
+CREATE VIEW main_view AS SELECT a, b FROM main_table;
+
+-- Updates should fail without rules or triggers
+INSERT INTO main_view VALUES (1,2);
+UPDATE main_view SET b = 20 WHERE a = 50;
+DELETE FROM main_view WHERE a = 50;
+-- Should fail even when there are no matching rows
+DELETE FROM main_view WHERE a = 51;
+
+-- VIEW trigger function
+CREATE OR REPLACE FUNCTION view_trigger() RETURNS trigger
+LANGUAGE plpgsql AS $$
+declare
+ argstr text := '';
+begin
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ raise notice '% % % % (%)', TG_RELNAME, TG_WHEN, TG_OP, TG_LEVEL, argstr;
+
+ if TG_LEVEL = 'ROW' then
+ if TG_OP = 'INSERT' then
+ raise NOTICE 'NEW: %', NEW;
+ INSERT INTO main_table VALUES (NEW.a, NEW.b);
+ RETURN NEW;
+ end if;
+
+ if TG_OP = 'UPDATE' then
+ raise NOTICE 'OLD: %, NEW: %', OLD, NEW;
+ UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN NEW;
+ end if;
+
+ if TG_OP = 'DELETE' then
+ raise NOTICE 'OLD: %', OLD;
+ DELETE FROM main_table WHERE a = OLD.a AND b = OLD.b;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN OLD;
+ end if;
+ end if;
+
+ RETURN NULL;
+end;
+$$;
+
+-- Before row triggers aren't allowed on views
+CREATE TRIGGER invalid_trig BEFORE INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
+
+CREATE TRIGGER invalid_trig BEFORE UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
+
+CREATE TRIGGER invalid_trig BEFORE DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
+
+-- After row triggers aren't allowed on views
+CREATE TRIGGER invalid_trig AFTER INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
+
+CREATE TRIGGER invalid_trig AFTER UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
+
+CREATE TRIGGER invalid_trig AFTER DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
+
+-- Truncate triggers aren't allowed on views
+CREATE TRIGGER invalid_trig BEFORE TRUNCATE ON main_view
+EXECUTE PROCEDURE trigger_func('before_tru_row');
+
+CREATE TRIGGER invalid_trig AFTER TRUNCATE ON main_view
+EXECUTE PROCEDURE trigger_func('before_tru_row');
+
+-- INSTEAD OF triggers aren't allowed on tables
+CREATE TRIGGER invalid_trig INSTEAD OF INSERT ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
+
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+
+CREATE TRIGGER invalid_trig INSTEAD OF DELETE ON main_table
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
+
+-- Don't support WHEN clauses with INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
+FOR EACH ROW WHEN (OLD.a <> NEW.a) EXECUTE PROCEDURE view_trigger('instead_of_upd');
+
+-- Don't support column-level INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE OF a ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+
+-- Don't support statement-level INSTEAD OF triggers
+CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
+EXECUTE PROCEDURE view_trigger('instead_of_upd');
+
+-- Valid INSTEAD OF triggers
+CREATE TRIGGER instead_of_insert_trig INSTEAD OF INSERT ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
+
+CREATE TRIGGER instead_of_update_trig INSTEAD OF UPDATE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
+
+CREATE TRIGGER instead_of_delete_trig INSTEAD OF DELETE ON main_view
+FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
+
+-- Valid BEFORE statement VIEW triggers
+CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_ins_stmt');
+
+CREATE TRIGGER before_upd_stmt_trig BEFORE UPDATE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_upd_stmt');
+
+CREATE TRIGGER before_del_stmt_trig BEFORE DELETE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_del_stmt');
+
+-- Valid AFTER statement VIEW triggers
+CREATE TRIGGER after_ins_stmt_trig AFTER INSERT ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_ins_stmt');
+
+CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_upd_stmt');
+
+CREATE TRIGGER after_del_stmt_trig AFTER DELETE ON main_view
+FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_del_stmt');
+
+\set QUIET false
+
+-- Insert into view using trigger
+INSERT INTO main_view VALUES (20, 30);
+INSERT INTO main_view VALUES (21, 31) RETURNING a, b;
+
+-- Table trigger will prevent updates
+UPDATE main_view SET b = 31 WHERE a = 20;
+UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
+
+-- Remove table trigger to allow updates
+DROP TRIGGER before_upd_a_row_trig ON main_table;
+UPDATE main_view SET b = 31 WHERE a = 20;
+UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
+
+-- Before and after stmt triggers should fire even when no rows are affected
+UPDATE main_view SET b = 0 WHERE false;
+
+-- Delete from view using trigger
+DELETE FROM main_view WHERE a IN (20,21);
+DELETE FROM main_view WHERE a = 31 RETURNING a, b;
+
+\set QUIET true
+
+-- Describe view should list triggers
+\d main_view
+
+-- Test dropping view triggers
+DROP TRIGGER instead_of_insert_trig ON main_view;
+DROP TRIGGER instead_of_delete_trig ON main_view;
+\d+ main_view
+DROP VIEW main_view;
+
+--
+-- Test triggers on a join view
+--
+CREATE TABLE country_table (
+ country_id serial primary key,
+ country_name text unique not null,
+ continent text not null
+);
+
+INSERT INTO country_table (country_name, continent)
+ VALUES ('Japan', 'Asia'),
+ ('UK', 'Europe'),
+ ('USA', 'North America')
+ RETURNING *;
+
+CREATE TABLE city_table (
+ city_id serial primary key,
+ city_name text not null,
+ population bigint,
+ country_id int references country_table
+);
+
+CREATE VIEW city_view AS
+ SELECT city_id, city_name, population, country_name, continent
+ FROM city_table ci
+ LEFT JOIN country_table co ON co.country_id = ci.country_id;
+
+CREATE FUNCTION city_insert() RETURNS trigger LANGUAGE plpgsql AS $$
+declare
+ ctry_id int;
+begin
+ if NEW.country_name IS NOT NULL then
+ SELECT country_id, continent INTO ctry_id, NEW.continent
+ FROM country_table WHERE country_name = NEW.country_name;
+ if NOT FOUND then
+ raise exception 'No such country: "%"', NEW.country_name;
+ end if;
+ else
+ NEW.continent := NULL;
+ end if;
+
+ if NEW.city_id IS NOT NULL then
+ INSERT INTO city_table
+ VALUES(NEW.city_id, NEW.city_name, NEW.population, ctry_id);
+ else
+ INSERT INTO city_table(city_name, population, country_id)
+ VALUES(NEW.city_name, NEW.population, ctry_id)
+ RETURNING city_id INTO NEW.city_id;
+ end if;
+
+ RETURN NEW;
+end;
+$$;
+
+CREATE TRIGGER city_insert_trig INSTEAD OF INSERT ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_insert();
+
+CREATE FUNCTION city_delete() RETURNS trigger LANGUAGE plpgsql AS $$
+begin
+ DELETE FROM city_table WHERE city_id = OLD.city_id;
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN OLD;
+end;
+$$;
+
+CREATE TRIGGER city_delete_trig INSTEAD OF DELETE ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_delete();
+
+CREATE FUNCTION city_update() RETURNS trigger LANGUAGE plpgsql AS $$
+declare
+ ctry_id int;
+begin
+ if NEW.country_name IS DISTINCT FROM OLD.country_name then
+ SELECT country_id, continent INTO ctry_id, NEW.continent
+ FROM country_table WHERE country_name = NEW.country_name;
+ if NOT FOUND then
+ raise exception 'No such country: "%"', NEW.country_name;
+ end if;
+
+ UPDATE city_table SET city_name = NEW.city_name,
+ population = NEW.population,
+ country_id = ctry_id
+ WHERE city_id = OLD.city_id;
+ else
+ UPDATE city_table SET city_name = NEW.city_name,
+ population = NEW.population
+ WHERE city_id = OLD.city_id;
+ NEW.continent := OLD.continent;
+ end if;
+
+ if NOT FOUND then RETURN NULL; end if;
+ RETURN NEW;
+end;
+$$;
+
+CREATE TRIGGER city_update_trig INSTEAD OF UPDATE ON city_view
+FOR EACH ROW EXECUTE PROCEDURE city_update();
+
+\set QUIET false
+
+-- INSERT .. RETURNING
+INSERT INTO city_view(city_name) VALUES('Tokyo') RETURNING *;
+INSERT INTO city_view(city_name, population) VALUES('London', 7556900) RETURNING *;
+INSERT INTO city_view(city_name, country_name) VALUES('Washington DC', 'USA') RETURNING *;
+INSERT INTO city_view(city_id, city_name) VALUES(123456, 'New York') RETURNING *;
+INSERT INTO city_view VALUES(234567, 'Birmingham', 1016800, 'UK', 'EU') RETURNING *;
+
+-- UPDATE .. RETURNING
+UPDATE city_view SET country_name = 'Japon' WHERE city_name = 'Tokyo'; -- error
+UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Takyo'; -- no match
+UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Tokyo' RETURNING *; -- OK
+
+UPDATE city_view SET population = 13010279 WHERE city_name = 'Tokyo' RETURNING *;
+UPDATE city_view SET country_name = 'UK' WHERE city_name = 'New York' RETURNING *;
+UPDATE city_view SET country_name = 'USA', population = 8391881 WHERE city_name = 'New York' RETURNING *;
+UPDATE city_view SET continent = 'EU' WHERE continent = 'Europe' RETURNING *;
+UPDATE city_view v1 SET country_name = v2.country_name FROM city_view v2
+ WHERE v2.city_name = 'Birmingham' AND v1.city_name = 'London' RETURNING *;
+
+-- DELETE .. RETURNING
+DELETE FROM city_view WHERE city_name = 'Birmingham' RETURNING *;
+
+\set QUIET true
+
+-- read-only view with WHERE clause
+CREATE VIEW european_city_view AS
+ SELECT * FROM city_view WHERE continent = 'Europe';
+SELECT count(*) FROM european_city_view;
+
+CREATE FUNCTION no_op_trig_fn() RETURNS trigger LANGUAGE plpgsql
+AS 'begin RETURN NULL; end';
+
+CREATE TRIGGER no_op_trig INSTEAD OF INSERT OR UPDATE OR DELETE
+ON european_city_view FOR EACH ROW EXECUTE PROCEDURE no_op_trig_fn();
+
+\set QUIET false
+
+INSERT INTO european_city_view VALUES (0, 'x', 10000, 'y', 'z');
+UPDATE european_city_view SET population = 10000;
+DELETE FROM european_city_view;
+
+\set QUIET true
+
+-- rules bypassing no-op triggers
+CREATE RULE european_city_insert_rule AS ON INSERT TO european_city_view
+DO INSTEAD INSERT INTO city_view
+VALUES (NEW.city_id, NEW.city_name, NEW.population, NEW.country_name, NEW.continent)
+RETURNING *;
+
+CREATE RULE european_city_update_rule AS ON UPDATE TO european_city_view
+DO INSTEAD UPDATE city_view SET
+ city_name = NEW.city_name,
+ population = NEW.population,
+ country_name = NEW.country_name
+WHERE city_id = OLD.city_id
+RETURNING NEW.*;
+
+CREATE RULE european_city_delete_rule AS ON DELETE TO european_city_view
+DO INSTEAD DELETE FROM city_view WHERE city_id = OLD.city_id RETURNING *;
+
+\set QUIET false
+
+-- INSERT not limited by view's WHERE clause, but UPDATE AND DELETE are
+INSERT INTO european_city_view(city_name, country_name)
+ VALUES ('Cambridge', 'USA') RETURNING *;
+UPDATE european_city_view SET country_name = 'UK'
+ WHERE city_name = 'Cambridge';
+DELETE FROM european_city_view WHERE city_name = 'Cambridge';
+
+-- UPDATE and DELETE via rule and trigger
+UPDATE city_view SET country_name = 'UK'
+ WHERE city_name = 'Cambridge' RETURNING *;
+UPDATE european_city_view SET population = 122800
+ WHERE city_name = 'Cambridge' RETURNING *;
+DELETE FROM european_city_view WHERE city_name = 'Cambridge' RETURNING *;
+
+-- join UPDATE test
+UPDATE city_view v SET population = 599657
+ FROM city_table ci, country_table co
+ WHERE ci.city_name = 'Washington DC' and co.country_name = 'USA'
+ AND v.city_id = ci.city_id AND v.country_name = co.country_name
+ RETURNING co.country_id, v.country_name,
+ v.city_id, v.city_name, v.population;
+
+\set QUIET true
+
+SELECT * FROM city_view;
+
+DROP TABLE city_table CASCADE;
+DROP TABLE country_table;