1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-28 23:42:10 +03:00

This patch implements FOR EACH STATEMENT triggers, per my email to

-hackers a couple days ago.

Notes/caveats:

        - added regression tests for the new functionality, all
          regression tests pass on my machine

        - added pg_dump support

        - updated PL/PgSQL to support per-statement triggers; didn't
          look at the other procedural languages.

        - there's (even) more code duplication in trigger.c than there
          was previously. Any suggestions on how to refactor the
          ExecXXXTriggers() functions to reuse more code would be
          welcome -- I took a brief look at it, but couldn't see an
          easy way to do it (there are several subtly-different
          versions of the code in question)

        - updated the documentation. I also took the liberty of
          removing a big chunk of duplicated syntax documentation in
          the Programmer's Guide on triggers, and moving that
          information to the CREATE TRIGGER reference page.

        - I also included some spelling fixes and similar small
          cleanups I noticed while making the changes. If you'd like
          me to split those into a separate patch, let me know.

Neil Conway
This commit is contained in:
Bruce Momjian
2002-11-23 03:59:09 +00:00
parent ea29b32758
commit 1b7f3cc02d
24 changed files with 702 additions and 411 deletions

View File

@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.11 2002/11/15 03:22:30 momjian Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/plpgsql.sgml,v 1.12 2002/11/23 03:59:05 momjian Exp $
-->
<chapter id="plpgsql">
@ -674,24 +674,25 @@ RENAME this_var TO that_var;
<title>Expressions</title>
<para>
All expressions used in <application>PL/pgSQL</application> statements
are processed using the server's regular SQL executor. Expressions that
appear to contain
constants may in fact require run-time evaluation
(e.g. <literal>'now'</literal> for the
<type>timestamp</type> type) so
it is impossible for the <application>PL/pgSQL</application> parser
to identify real constant values other than the NULL keyword. All
expressions are evaluated internally by executing a query
All expressions used in <application>PL/pgSQL</application>
statements are processed using the server's regular
<acronym>SQL</acronym> executor. Expressions that appear to
contain constants may in fact require run-time evaluation
(e.g. <literal>'now'</literal> for the <type>timestamp</type>
type) so it is impossible for the
<application>PL/pgSQL</application> parser to identify real
constant values other than the NULL keyword. All expressions are
evaluated internally by executing a query
<synopsis>
SELECT <replaceable>expression</replaceable>
</synopsis>
using the <acronym>SPI</acronym> manager. In the expression, occurrences
of <application>PL/pgSQL</application> variable
using the <acronym>SPI</acronym> manager. In the expression,
occurrences of <application>PL/pgSQL</application> variable
identifiers are replaced by parameters and the actual values from
the variables are passed to the executor in the parameter array.
This allows the query plan for the SELECT to be prepared just once
and then re-used for subsequent evaluations.
This allows the query plan for the <command>SELECT</command> to
be prepared just once and then re-used for subsequent
evaluations.
</para>
<para>
@ -1100,41 +1101,43 @@ GET DIAGNOSTICS <replaceable>variable</replaceable> = <replaceable>item</replace
<itemizedlist>
<listitem>
<para>
A SELECT INTO statement sets <literal>FOUND</literal>
true if it returns a row, false if no row is returned.
A <command>SELECT INTO</command> statement sets
<literal>FOUND</literal> true if it returns a row, false if no
row is returned.
</para>
</listitem>
<listitem>
<para>
A PERFORM statement sets <literal>FOUND</literal>
A <command>PERFORM</> statement sets <literal>FOUND</literal>
true if it produces (discards) a row, false if no row is
produced.
</para>
</listitem>
<listitem>
<para>
UPDATE, INSERT, and DELETE statements set
<literal>FOUND</literal> true if at least one row is
affected, false if no row is affected.
<command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
statements set <literal>FOUND</literal> true if at least one
row is affected, false if no row is affected.
</para>
</listitem>
<listitem>
<para>
A FETCH statement sets <literal>FOUND</literal>
A <command>FETCH</> statement sets <literal>FOUND</literal>
true if it returns a row, false if no row is returned.
</para>
</listitem>
<listitem>
<para>
A FOR statement sets <literal>FOUND</literal>
true if it iterates one or more times, else false.
This applies to all three variants of the FOR statement
(integer FOR loops, record-set FOR loops, and dynamic
record-set FOR loops). <literal>FOUND</literal> is only set
when the FOR loop exits: inside the execution of the loop,
<literal>FOUND</literal> is not modified by the FOR statement,
although it may be changed by the execution of other
statements within the loop body.
A <command>FOR</> statement sets <literal>FOUND</literal> true
if it iterates one or more times, else false. This applies to
all three variants of the <command>FOR</> statement (integer
<command>FOR</> loops, record-set <command>FOR</> loops, and
dynamic record-set <command>FOR</>
loops). <literal>FOUND</literal> is only set when the
<command>FOR</> loop exits: inside the execution of the loop,
<literal>FOUND</literal> is not modified by the
<command>FOR</> statement, although it may be changed by the
execution of other statements within the loop body.
</para>
</listitem>
</itemizedlist>
@ -1975,7 +1978,7 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
<application>PL/pgSQL</application> can be used to define trigger
procedures. A trigger procedure is created with the
<command>CREATE FUNCTION</> command as a function with no
arguments and a return type of <type>TRIGGER</type>. Note that
arguments and a return type of <type>trigger</type>. Note that
the function must be declared with no arguments even if it expects
to receive arguments specified in <command>CREATE TRIGGER</> ---
trigger arguments are passed via <varname>TG_ARGV</>, as described
@ -1992,8 +1995,9 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
<term><varname>NEW</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the new database row for INSERT/UPDATE
operations in ROW level triggers.
Data type <type>RECORD</type>; variable holding the new
database row for INSERT/UPDATE operations in ROW level
triggers. This variable is NULL in STATEMENT level triggers.
</para>
</listitem>
</varlistentry>
@ -2002,8 +2006,9 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
<term><varname>OLD</varname></term>
<listitem>
<para>
Data type <type>RECORD</type>; variable holding the old database row for UPDATE/DELETE
operations in ROW level triggers.
Data type <type>RECORD</type>; variable holding the old
database row for UPDATE/DELETE operations in ROW level
triggers. This variable is NULL in STATEMENT level triggers.
</para>
</listitem>
</varlistentry>
@ -2098,22 +2103,23 @@ RAISE EXCEPTION ''Inexistent ID --> %'',user_id;
<para>
A trigger function must return either NULL or a record/row value
having exactly the structure of the table the trigger was fired for.
Triggers fired BEFORE may return NULL to signal the trigger manager
to skip the rest of the operation for this row (ie, subsequent triggers
are not fired, and the INSERT/UPDATE/DELETE does not occur for this
row). If a non-NULL value is returned then the operation proceeds with
that row value. Note that returning a row value different from the
original value of NEW alters the row that will be inserted or updated.
It is possible to replace single values directly
in NEW and return that, or to build a complete new record/row to
return.
having exactly the structure of the table the trigger was fired
for. The return value of a BEFORE or AFTER STATEMENT level
trigger, or an AFTER ROW level trigger is ignored; it may as well
return NULL. However, any of these types of triggers can still
abort the entire trigger operation by raising an error.
</para>
<para>
The return value of a trigger fired AFTER is ignored; it may as well
always return a NULL value. But an AFTER trigger can still abort the
operation by raising an error.
ROW level triggers fired BEFORE may return NULL to signal the
trigger manager to skip the rest of the operation for this row
(ie, subsequent triggers are not fired, and the
INSERT/UPDATE/DELETE does not occur for this row). If a non-NULL
value is returned then the operation proceeds with that row value.
Note that returning a row value different from the original value
of NEW alters the row that will be inserted or updated. It is
possible to replace single values directly in NEW and return that,
or to build a complete new record/row to return.
</para>
<example>
@ -2143,7 +2149,7 @@ CREATE FUNCTION emp_stamp () RETURNS TRIGGER AS '
RAISE EXCEPTION ''% cannot have NULL salary'', NEW.empname;
END IF;
-- Who works for us when she must pay for?
-- Who works for us when she must pay for it?
IF NEW.salary < 0 THEN
RAISE EXCEPTION ''% cannot have a negative salary'', NEW.empname;
END IF;

View File

@ -153,8 +153,8 @@ ALTER TRIGGER emp_stamp ON emp RENAME TO emp_track_chgs;
</refsect2info>
<title>SQL92</title>
<para>
The clause to rename triggers is a
<productname>PostgreSQL</productname> extension from SQL92.
<command>ALTER TRIGGER</command> is a <productname>PostgreSQL</>
extension of SQL92.
</para>
</refsect2>
</refsect1>

View File

@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_trigger.sgml,v 1.29 2002/11/21 23:34:43 petere Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_trigger.sgml,v 1.30 2002/11/23 03:59:06 momjian Exp $
PostgreSQL documentation
-->
@ -21,8 +21,9 @@ PostgreSQL documentation
<date>2000-03-25</date>
</refsynopsisdivinfo>
<synopsis>
CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTER } { <replaceable class="PARAMETER">event</replaceable> [OR ...] }
ON <replaceable class="PARAMETER">table</replaceable> FOR EACH { ROW | STATEMENT }
CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> {
BEFORE | AFTER } { <replaceable class="PARAMETER">event</replaceable> [ OR ... ] }
ON <replaceable class="PARAMETER">table</replaceable> [ FOR EACH { ROW | STATEMENT } ]
EXECUTE PROCEDURE <replaceable class="PARAMETER">func</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
</synopsis>
@ -45,11 +46,26 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>BEFORE</term>
<term>AFTER</term>
<listitem>
<para>
Determines whether the function is called before or after the
event.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">event</replaceable></term>
<listitem>
<para>
One of INSERT, DELETE or UPDATE.
One of <command>INSERT</command>, <command>DELETE</command> or
<command>UPDATE</command>; this specifies the event that will
fire the trigger. Multiple events can be specified using
<literal>OR</literal>.
</para>
</listitem>
</varlistentry>
@ -57,10 +73,26 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
<term><replaceable class="parameter">table</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of the table the trigger is for.
The name (optionally schema-qualified) of the table the
trigger is for.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>FOR EACH ROW</term>
<term>FOR EACH STATEMENT</term>
<listitem>
<para>
This specifies whether the trigger procedure should be fired
once for every row affected by the trigger event, or just once
per SQL statement. If neither is specified, <literal>FOR EACH
STATEMENT</literal> is the default.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">func</replaceable></term>
<listitem>
@ -74,11 +106,15 @@ CREATE TRIGGER <replaceable class="PARAMETER">name</replaceable> { BEFORE | AFTE
<term><replaceable class="parameter">arguments</replaceable></term>
<listitem>
<para>
An optional comma-separated list of arguments to be provided to the
function when the trigger is executed, along with the standard trigger
data such as old and new tuple contents. The arguments are literal
string constants. Simple names and numeric constants may be written
here too, but they will all be converted to strings.
An optional comma-separated list of arguments to be provided to
the function when the trigger is executed, along with the standard
trigger data such as old and new tuple contents. The arguments
are literal string constants. Simple names and numeric constants
may be written here too, but they will all be converted to
strings. Note that these arguments are not provided as normal
function parameters (since a trigger procedure must be declared to
take zero parameters), but are instead accessed through the
<literal>TG_ARGV</literal> array.
</para>
</listitem>
</varlistentry>
@ -121,7 +157,7 @@ CREATE TRIGGER
<para>
<command>CREATE TRIGGER</command> will enter a new trigger into the current
data base. The trigger will be associated with the relation
database. The trigger will be associated with the relation
<replaceable class="parameter">table</replaceable> and will execute
the specified function <replaceable class="parameter">func</replaceable>.
</para>
@ -141,15 +177,27 @@ CREATE TRIGGER
or deletion, are <quote>visible</quote> to the trigger.
</para>
<para>
A trigger that executes <literal>FOR EACH ROW</literal> of the
specified operation is called once for every row that the operation
modifies. For example, a <command>DELETE</command> that affects 10
rows will cause any <literal>ON DELETE</literal> triggers on the
target relation to be called 10 separate times, once for each
deleted tuple. In contrast, a trigger that executes <literal>FOR
EACH STATEMENT</literal> of the specified operation only executes
once for any given operation, regardless of how many rows it
modifies.
</para>
<para>
If multiple triggers of the same kind are defined for the same event,
they will be fired in alphabetical order by name.
</para>
<para>
<command>SELECT</command> does not modify any rows so you can not
create <command>SELECT</command> triggers. Rules and views are more
appropriate in such cases.
<command>SELECT</command> does not modify any rows so you can not
create <command>SELECT</command> triggers. Rules and views are more
appropriate in such cases.
</para>
<para>
@ -176,10 +224,6 @@ CREATE TRIGGER
change the function's declared return type to <type>trigger</>.
</para>
<para>
As of the current release, <literal>STATEMENT</literal> triggers are not implemented.
</para>
<para>
Refer to the <xref linkend="sql-droptrigger" endterm="sql-droptrigger-title"> command for
information on how to remove triggers.
@ -268,13 +312,6 @@ CREATE TABLE distributors (
</para>
</listitem>
<listitem>
<para>
<productname>PostgreSQL</productname> only has row-level
triggers, no statement-level triggers.
</para>
</listitem>
<listitem>
<para>
<productname>PostgreSQL</productname> only allows the

View File

@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.166 2002/11/23 02:41:03 tgl Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/release.sgml,v 1.167 2002/11/23 03:59:06 momjian Exp $
-->
<appendix id="release">
@ -4619,7 +4619,7 @@ Enhancements
* pg_dump now output the schema and/or the data, with many fixes to
enhance completeness.
* psql used in place of monitor in administration shell scripts.
monitor to be depreciated in next release.
monitor to be deprecated in next release.
* date/time functions enhanced
* NULL insert/update/comparison fixed/enhanced
* TCL/TK lib and shell fixed to work with both tck7.4/tk4.0 and tcl7.5/tk4.1

View File

@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.25 2002/09/21 18:32:54 petere Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.26 2002/11/23 03:59:06 momjian Exp $
-->
<chapter id="triggers">
@ -7,21 +7,24 @@ $Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.25 2002/09/21 18:32:54 pet
<para>
<productname>PostgreSQL</productname> has various server-side
function interfaces. Server-side functions can be written in SQL,
C, or any defined procedural language. Trigger functions can be
written in C and most procedural languages, but not in SQL. Note that
statement-level trigger events are not supported in the current
version. You can currently specify BEFORE or AFTER on INSERT,
DELETE or UPDATE of a tuple as a trigger event.
function interfaces. Server-side functions can be written in
<acronym>SQL</acronym>, C, or any defined procedural
language. Trigger functions can be written in C and most procedural
languages, but not in <acronym>SQL</acronym>. Both per-row and
per-statement triggers are supported. A trigger procedure can
execute BEFORE or AFTER a <command>INSERT</command>,
<command>DELETE</command> or <command>UPDATE</command>, either once
per modified row, or once per <acronym>SQL</acronym> statement.
</para>
<sect1 id="trigger-definition">
<title>Trigger Definition</title>
<para>
If a trigger event occurs, the trigger manager (called by the Executor)
sets up a <structname>TriggerData</> information structure (described below) and calls
the trigger function to handle the event.
If a trigger event occurs, the trigger manager (called by the
Executor) sets up a <structname>TriggerData</> information
structure (described below) and calls the trigger function to
handle the event.
</para>
<para>
@ -35,116 +38,13 @@ $Header: /cvsroot/pgsql/doc/src/sgml/trigger.sgml,v 1.25 2002/09/21 18:32:54 pet
</para>
<para>
The syntax for creating triggers is:
<programlisting>
CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT | DELETE | UPDATE [ OR ... ] ]
ON <replaceable>relation</replaceable> FOR EACH [ ROW | STATEMENT ]
EXECUTE PROCEDURE <replaceable>procedure</replaceable>
(<replaceable>args</replaceable>);
</programlisting>
where the arguments are:
<variablelist>
<varlistentry>
<term>
<replaceable>trigger</replaceable>
</term>
<listitem>
<para>
The trigger must have a name distinct from all other triggers on
the same table. The name is needed
if you ever have to delete the trigger.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>BEFORE</term>
<term>AFTER</term>
<listitem>
<para>
Determines whether the function is called before or after
the event.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>INSERT</term>
<term>DELETE</term>
<term>UPDATE</term>
<listitem>
<para>
The next element of the command determines what event(s) will trigger
the function. Multiple events can be specified separated by OR.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>relation</replaceable></term>
<listitem>
<para>
The relation name indicates which table the event applies to.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ROW</term>
<term>STATEMENT</term>
<listitem>
<para>
The FOR EACH clause determines whether the trigger is fired for each
affected row or before (or after) the entire statement has completed.
Currently only the ROW case is supported.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>procedure</replaceable></term>
<listitem>
<para>
The procedure name is the function to be called.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable>args</replaceable></term>
<listitem>
<para>
The arguments passed to the function in the <structname>TriggerData</> structure.
This is either empty or a list of one or more simple literal
constants (which will be passed to the function as strings).
</para>
<para>
The purpose of including arguments in the trigger definition
is to allow different
triggers with similar requirements to call the same function.
As an example, there could be a generalized trigger
function that takes as its arguments two field names and puts the
current user in one and the current time stamp in the other.
Properly written, this trigger function would be independent of
the specific table it is triggering on. So the same function
could be used for INSERT events on any table with suitable fields,
to automatically track creation of records in a transaction table for
example. It could also be used to track last-update events if
defined as an UPDATE trigger.
</para>
</listitem>
</varlistentry>
</variablelist>
The syntax for creating triggers is described in &cite-reference;.
</para>
<para>
Trigger functions return a <structname>HeapTuple</> to the calling executor. The return
value is ignored for triggers fired AFTER an operation,
but it allows BEFORE triggers to:
Trigger functions return a <structname>HeapTuple</> to the calling
executor. The return value is ignored for triggers fired AFTER an
operation, but it allows BEFORE triggers to:
<itemizedlist>
<listitem>
@ -157,9 +57,10 @@ CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT |
<listitem>
<para>
For INSERT and UPDATE triggers only, the returned tuple becomes the
tuple which will be inserted or will replace the tuple being updated.
This allows the trigger function to modify the row being inserted or
For <command>INSERT</command> and <command>UPDATE</command>
triggers only, the returned tuple becomes the tuple which will
be inserted or will replace the tuple being updated. This
allows the trigger function to modify the row being inserted or
updated.
</para>
</listitem>
@ -170,8 +71,9 @@ CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT |
</para>
<para>
Note that there is no initialization performed by the CREATE TRIGGER
handler. This may be changed in the future.
Note that there is no initialization performed by the
<command>CREATE TRIGGER</command> handler. This may be changed in
the future.
</para>
<para>
@ -184,15 +86,34 @@ CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT |
</para>
<para>
If a trigger function executes SQL-queries (using SPI) then these queries
may fire triggers again. This is known as cascading triggers. There is no
direct limitation on the number of cascade levels. It is possible for
cascades to cause recursive invocation of the same trigger --- for
example, an INSERT trigger might execute a query that inserts an
additional tuple into the same table, causing the INSERT trigger to be
fired again. It is the trigger programmer's
responsibility to avoid infinite recursion in such scenarios.
If a trigger function executes SQL-queries (using SPI) then these
queries may fire triggers again. This is known as cascading
triggers. There is no direct limitation on the number of cascade
levels. It is possible for cascades to cause recursive invocation
of the same trigger --- for example, an <command>INSERT</command>
trigger might execute a query that inserts an additional tuple
into the same table, causing the <command>INSERT</command> trigger
to be fired again. It is the trigger programmer's responsibility
to avoid infinite recursion in such scenarios.
</para>
<para>
When a trigger is defined, a number of arguments can be
specified. The purpose of including arguments in the trigger
definition is to allow different triggers with similar
requirements to call the same function. As an example, there
could be a generalized trigger function that takes as its
arguments two field names and puts the current user in one and the
current time stamp in the other. Properly written, this trigger
function would be independent of the specific table it is
triggering on. So the same function could be used for
<command>INSERT</command> events on any table with suitable
fields, to automatically track creation of records in a
transaction table for example. It could also be used to track
last-update events if defined as an <command>UPDATE</command>
trigger.
</para>
</sect1>
<sect1 id="trigger-manager">
@ -215,18 +136,20 @@ CREATE TRIGGER <replaceable>trigger</replaceable> [ BEFORE | AFTER ] [ INSERT |
</note>
<para>
When a function is called by the trigger manager, it is not passed any
normal parameters, but it is passed a <quote>context</> pointer pointing to a
<structname>TriggerData</> structure. C functions can check whether they were called
from the trigger manager or not by executing the macro
When a function is called by the trigger manager, it is not passed
any normal parameters, but it is passed a <quote>context</>
pointer pointing to a <structname>TriggerData</> structure. C
functions can check whether they were called from the trigger
manager or not by executing the macro
<literal>CALLED_AS_TRIGGER(fcinfo)</literal>, which expands to
<programlisting>
((fcinfo)->context != NULL && IsA((fcinfo)->context, TriggerData))
</programlisting>
If this returns true, then it is safe to cast <literal>fcinfo->context</> to type
<literal>TriggerData *</literal> and make use of the pointed-to
<structname>TriggerData</> structure.
The function must <emphasis>not</emphasis> alter the <structname>TriggerData</>
If this returns true, then it is safe to cast
<literal>fcinfo->context</> to type <literal>TriggerData
*</literal> and make use of the pointed-to
<structname>TriggerData</> structure. The function must
<emphasis>not</emphasis> alter the <structname>TriggerData</>
structure or any of the data it points to.
</para>
@ -288,8 +211,7 @@ typedef struct TriggerData
<term>TRIGGER_FIRED_FOR_ROW(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired for
a ROW-level event.
Returns TRUE if trigger fired for a ROW-level event.
</para>
</listitem>
</varlistentry>
@ -298,8 +220,7 @@ typedef struct TriggerData
<term>TRIGGER_FIRED_FOR_STATEMENT(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired for
STATEMENT-level event.
Returns TRUE if trigger fired for STATEMENT-level event.
</para>
</listitem>
</varlistentry>
@ -308,7 +229,7 @@ typedef struct TriggerData
<term>TRIGGER_FIRED_BY_INSERT(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by INSERT.
Returns TRUE if trigger fired by <command>INSERT</command>.
</para>
</listitem>
</varlistentry>
@ -317,7 +238,7 @@ typedef struct TriggerData
<term>TRIGGER_FIRED_BY_DELETE(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by DELETE.
Returns TRUE if trigger fired by <command>DELETE</command>.
</para>
</listitem>
</varlistentry>
@ -326,7 +247,7 @@ typedef struct TriggerData
<term>TRIGGER_FIRED_BY_UPDATE(event)</term>
<listitem>
<para>
Returns TRUE if trigger fired by UPDATE.
Returns TRUE if trigger fired by <command>UPDATE</command>.
</para>
</listitem>
</varlistentry>
@ -356,11 +277,15 @@ typedef struct TriggerData
<term><structfield>tg_trigtuple</></term>
<listitem>
<para>
is a pointer to the tuple for which the trigger is fired. This is the tuple
being inserted (if INSERT), deleted (if DELETE) or updated (if UPDATE).
If INSERT/DELETE then this is what you are to return to Executor if
you don't want to replace tuple with another one (INSERT) or skip the
operation.
is a pointer to the tuple for which the trigger is fired. This is
the tuple being inserted (if <command>INSERT</command>), deleted
(if <command>DELETE</command>) or updated (if
<command>UPDATE</command>). If this trigger was fired for an
<command>INSERT</command> or <command>DELETE</command> then this
is what you should return to the Executor if you don't want to
replace the tuple with a different one (in the case of
<command>INSERT</command>) or skip the operation (in the case of
<command>DELETE</command>).
</para>
</listitem>
</varlistentry>
@ -369,9 +294,11 @@ typedef struct TriggerData
<term><structfield>tg_newtuple</></term>
<listitem>
<para>
is a pointer to the new version of tuple if UPDATE and <symbol>NULL</> if this is
for an INSERT or a DELETE. This is what you are to return to Executor if
UPDATE and you don't want to replace this tuple with another one or skip
is a pointer to the new version of tuple if
<command>UPDATE</command> and <symbol>NULL</> if this is for an
<command>INSERT</command> or a <command>DELETE</command>. This is
what you are to return to Executor if <command>UPDATE</command>
and you don't want to replace this tuple with another one or skip
the operation.
</para>
</listitem>
@ -404,8 +331,9 @@ typedef struct Trigger
where <structfield>tgname</> is the trigger's name,
<structfield>tgnargs</> is number of arguments in
<structfield>tgargs</>, <structfield>tgargs</> is an array of
pointers to the arguments specified in the CREATE TRIGGER
statement. Other members are for internal use only.
pointers to the arguments specified in the <command>CREATE
TRIGGER</command> statement. Other members are for internal use
only.
</para>
</listitem>
</varlistentry>
@ -460,10 +388,12 @@ execution of Q) or after Q is done.
</para>
<para>
Here is a very simple example of trigger usage. Function <function>trigf</> reports
the number of tuples in the triggered relation <literal>ttest</> and skips the
operation if the query attempts to insert a null value into x (i.e - it acts as a
not-null constraint but doesn't abort the transaction).
Here is a very simple example of trigger usage. Function
<function>trigf</> reports the number of tuples in the triggered
relation <literal>ttest</> and skips the operation if the query
attempts to insert a null value into x (i.e - it acts as a
<literal>NOT NULL</literal> constraint but doesn't abort the
transaction).
<programlisting>
#include "executor/spi.h" /* this is what you need to work with SPI */