1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Support triggers on views.

This patch adds the SQL-standard concept of an INSTEAD OF trigger, which
is fired instead of performing a physical insert/update/delete.  The
trigger function is passed the entire old and/or new rows of the view,
and must figure out what to do to the underlying tables to implement
the update.  So this feature can be used to implement updatable views
using trigger programming style rather than rule hacking.

In passing, this patch corrects the names of some columns in the
information_schema.triggers view.  It seems the SQL committee renamed
them somewhere between SQL:99 and SQL:2003.

Dean Rasheed, reviewed by Bernd Helmle; some additional hacking by me.
This commit is contained in:
Tom Lane
2010-10-10 13:43:33 -04:00
parent f7b15b5098
commit 2ec993a7cb
47 changed files with 2815 additions and 759 deletions

View File

@ -4243,7 +4243,7 @@
<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>
@ -4795,7 +4795,8 @@
</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>
@ -4839,7 +4840,7 @@
<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>
@ -4956,7 +4957,7 @@
<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>

View File

@ -4885,8 +4885,8 @@ ORDER BY c.ordinal_position;
<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>
@ -4987,34 +4987,34 @@ ORDER BY c.ordinal_position;
</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>
@ -5032,9 +5032,9 @@ ORDER BY c.ordinal_position;
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
@ -5045,14 +5045,34 @@ ORDER BY c.ordinal_position;
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">
@ -5562,19 +5582,28 @@ ORDER BY c.ordinal_position;
<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>

View File

@ -999,7 +999,9 @@ $$ LANGUAGE plperl;
<term><literal>$_TD-&gt;{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>

View File

@ -3112,9 +3112,9 @@ RAISE unique_violation USING MESSAGE = 'Duplicate user ID: ' || user_id;
<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>
@ -3234,8 +3234,25 @@ RAISE unique_violation USING MESSAGE = 'Duplicate user ID: ' || user_id;
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>
@ -3354,6 +3371,85 @@ AFTER INSERT OR UPDATE OR DELETE ON emp
</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

View File

@ -609,7 +609,7 @@ CREATE TYPE greeting AS (
who text
);
</programlisting>
A set result can be returned from a:
<variablelist>
@ -751,8 +751,7 @@ $$ LANGUAGE plpythonu;
<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>
@ -761,8 +760,8 @@ $$ LANGUAGE plpythonu;
<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>
@ -771,8 +770,7 @@ $$ LANGUAGE plpythonu;
<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>
@ -838,12 +836,14 @@ $$ LANGUAGE plpythonu;
</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>

View File

@ -591,8 +591,8 @@ SELECT 'doesn''t' AS ret
<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>
@ -665,10 +665,14 @@ SELECT 'doesn''t' AS ret
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>

View File

@ -53,7 +53,7 @@ CREATE [ OR REPLACE ] RULE <replaceable class="parameter">name</replaceable> AS
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
@ -73,7 +73,9 @@ CREATE [ OR REPLACE ] RULE <replaceable class="parameter">name</replaceable> AS
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>
@ -232,12 +234,12 @@ CREATE [ OR REPLACE ] RULE <replaceable class="parameter">name</replaceable> AS
<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;

View File

@ -21,7 +21,7 @@ PostgreSQL documentation
<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> )
@ -33,21 +33,22 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
<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>
@ -68,11 +69,71 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
</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">&mdash;</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">&mdash;</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">&mdash;</entry>
</row>
<row>
<entry align="center"><command>TRUNCATE</></entry>
<entry align="center">&mdash;</entry>
<entry align="center">&mdash;</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
@ -116,10 +177,11 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
<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>
@ -143,6 +205,10 @@ UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</
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>
@ -150,7 +216,7 @@ UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</
<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>
@ -188,6 +254,11 @@ UPDATE OF <replaceable>column_name1</replaceable> [, <replaceable>column_name2</
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.
@ -326,6 +397,16 @@ CREATE TRIGGER log_update
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>
@ -396,7 +477,8 @@ CREATE TRIGGER log_update
<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>

View File

@ -76,7 +76,7 @@
</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
@ -132,11 +132,11 @@
</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>
@ -166,11 +166,13 @@
</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>
@ -189,10 +191,11 @@
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>
@ -283,7 +286,7 @@
<programlisting>
CREATE VIEW myview AS SELECT * FROM mytab;
</programlisting>
compared against the two commands:
<programlisting>
@ -291,7 +294,7 @@ CREATE TABLE myview (<replaceable>same column list as mytab</replaceable>);
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
@ -431,7 +434,7 @@ CREATE VIEW shoe_ready AS
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
@ -512,7 +515,7 @@ SELECT s.sl_name, s.sl_avail,
<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>
@ -578,7 +581,7 @@ SELECT shoe_ready.shoename, shoe_ready.sh_avail,
WHERE shoe_ready.total_avail &gt;= 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:
@ -656,7 +659,9 @@ SELECT shoe_ready.shoename, shoe_ready.sh_avail,
<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>
@ -718,22 +723,21 @@ UPDATE t1 SET a = t1.a, b = t2.b FROM t2 WHERE t1.a = t2.a;
</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>
@ -750,7 +754,7 @@ SELECT t1.a, t2.b FROM t1, t2 WHERE t1.a = t2.a;
<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>,
@ -759,7 +763,8 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
<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>
@ -803,16 +808,57 @@ SELECT t1.a, t2.b, t1.ctid FROM t1, t2 WHERE t1.a = t2.a;
<para>
What happens if a view is named as the target relation for an
<command>INSERT</command>, <command>UPDATE</command>, or
<command>DELETE</command>? 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>
@ -1383,7 +1429,7 @@ SELECT * FROM shoelace_arrive;
</programlisting>
Take a quick look at the current data:
<programlisting>
SELECT * FROM shoelace;
@ -1522,8 +1568,8 @@ SELECT s.sl_name,
AND shoelace_data.sl_name = s.sl_name
AND (s.sl_avail + shoelace_arrive.arr_quant) &lt;&gt; 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>
@ -1542,7 +1588,7 @@ SELECT s.sl_name,
WHERE s.sl_name = shoelace_arrive.arr_name
AND shoelace_data.sl_name = s.sl_name
AND s.sl_avail + shoelace_arrive.arr_quant &lt;&gt; s.sl_avail;
UPDATE shoelace_data
SET sl_avail = shoelace_data.sl_avail + shoelace_arrive.arr_quant
FROM shoelace_arrive shoelace_arrive,
@ -1675,7 +1721,7 @@ SELECT * FROM shoelace;
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>
@ -1783,12 +1829,13 @@ CREATE VIEW phone_number AS
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
@ -1796,6 +1843,7 @@ 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
@ -1803,8 +1851,8 @@ SELECT * FROM phone_number WHERE tricky(person, phone);
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>
@ -1906,19 +1954,21 @@ SELECT * FROM phone_number WHERE tricky(person, phone);
</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>
@ -1961,7 +2011,7 @@ CREATE RULE computer_del AS ON DELETE TO computer
<para>
Now we look at different types of deletes. In the case of a:
<programlisting>
DELETE FROM computer WHERE hostname = 'mypc.local.net';
</programlisting>

View File

@ -33,7 +33,11 @@
<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.
@ -45,6 +49,20 @@
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
@ -74,18 +92,29 @@
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>
@ -101,8 +130,8 @@
<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>
@ -117,14 +146,33 @@
</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</>.
@ -133,11 +181,12 @@
<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>
@ -146,31 +195,37 @@
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>
@ -237,7 +292,8 @@
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>
@ -245,14 +301,14 @@
<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
@ -263,7 +319,16 @@
<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>
@ -386,6 +451,15 @@ typedef struct TriggerData
</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>