PostgreSQL/doc/src/sgml/ref/create_trigger.sgml
2001-09-13 18:17:44 +00:00

294 lines
8.1 KiB
Plaintext

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_trigger.sgml,v 1.17 2001/09/13 18:17:44 petere Exp $
Postgres documentation
-->
<refentry id="SQL-CREATETRIGGER">
<docinfo>
<date>2001-09-13</date>
</docinfo>
<refmeta>
<refentrytitle id="SQL-CREATETRIGGER-TITLE">CREATE TRIGGER</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
CREATE TRIGGER
</refname>
<refpurpose>
define a new trigger
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<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 }
EXECUTE PROCEDURE <replaceable class="PARAMETER">func</replaceable> ( <replaceable class="PARAMETER">arguments</replaceable> )
</synopsis>
<refsect2 id="R2-SQL-CREATETRIGGER-1">
<refsect2info>
<date>1998-09-21</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The name of an existing trigger.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">table</replaceable></term>
<listitem>
<para>
The name of a table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">event</replaceable></term>
<listitem>
<para>
One of INSERT, DELETE or UPDATE.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">func</replaceable></term>
<listitem>
<para>
A user-supplied function.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-CREATETRIGGER-2">
<refsect2info>
<date>1998-09-21</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CREATE
</computeroutput></term>
<listitem>
<para>
This message is returned if the trigger is successfully created.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-CREATETRIGGER-1">
<refsect1info>
<date>1998-09-21</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>CREATE TRIGGER</command> will enter a new trigger into the current
data base. 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>
<para>
The trigger can be specified to fire either before BEFORE the
operation is attempted on a tuple (before constraints
are checked and the <command>INSERT</command>, <command>UPDATE</command> or
<command>DELETE</command> is attempted) or
AFTER the operation has been attempted (e.g., 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 may
skip the operation for the current tuple, or change the tuple
being inserted (for <command>INSERT</command> and
<command>UPDATE</command> operations only). If
the trigger fires after the event, all changes, including the
last insertion, update, or deletion, are <quote>visible</quote> to the trigger.
</para>
<para>
Refer to the chapters on SPI and Triggers in the
<citetitle>PostgreSQL Programmer's Guide</citetitle> for more
information.
</para>
</refsect1>
<refsect1 id="SQL-CREATETRIGGER-notes">
<title>Notes</title>
<para>
To create a trigger on a table, the user must have the
<literal>TRIGGER</literal> privilege on the table.
</para>
<para>
As of the current release, <literal>STATEMENT</literal> triggers are not implemented.
</para>
<para>
Refer to the <xref linkend="sql-droptrigger"> command for
information on how to remove triggers.
</para>
</refsect1>
<refsect1 id="R1-SQL-CREATETRIGGER-2">
<title>Examples</title>
<para>
Check if the specified distributor code exists in the distributors
table before appending or updating a row in the table films:
<programlisting>
CREATE TRIGGER if_dist_exists
BEFORE INSERT OR UPDATE ON films FOR EACH ROW
EXECUTE PROCEDURE check_primary_key ('did', 'distributors', 'did');
</programlisting>
</para>
<para>
Before cancelling a distributor or updating its code, remove every
reference to the table films:
<programlisting>
CREATE TRIGGER if_film_exists
BEFORE DELETE OR UPDATE ON distributors FOR EACH ROW
EXECUTE PROCEDURE check_foreign_key (1, 'CASCADE', 'did', 'films', 'did');
</programlisting>
</para>
<para>
The second example can also be done by using a foreign key,
constraint as in:
<programlisting>
CREATE TABLE distributors (
did DECIMAL(3),
name VARCHAR(40),
CONSTRAINT if_film_exists
FOREIGN KEY(did) REFERENCES films
ON UPDATE CASCADE ON DELETE CASCADE
);
</programlisting>
</para>
</refsect1>
<refsect1 id="SQL-CREATETRIGGER-compatibility">
<title>Compatibility</title>
<variablelist>
<varlistentry>
<term>SQL92</term>
<listitem>
<para>
There is no <command>CREATE TRIGGER</command> statement in <acronym>SQL92</acronym>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SQL99</term>
<listitem>
<para>
The <command>CREATE TRIGGER</command> statement in
<productname>PostgreSQL</productname> implements a subset of the
SQL99 standard. The following functionality is missing:
<itemizedlist>
<listitem>
<para>
SQL99 allows triggers to fire on updates to specific columns
(e.g., <literal>AFTER UPDATE OF col1, col2</literal>).
</para>
</listitem>
<listitem>
<para>
SQL99 allows you to define aliases for the <quote>old</quote>
and <quote>new</quote> rows or tables for use in the definiton
of the triggered action (e.g., <literal>CREATE TRIGGER ... ON
tablename REFERENCING OLD ROW AS somename NEW ROW AS
othername ...</literal>). Since
<productname>PostgreSQL</productname> allows trigger
procedures to be written in any number of user-defined
languages, access to the data is handled in a
language-specific way.
</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
execution of a stored procedure for the triggered action.
SQL99 allows the execution of a number of other SQL commands,
such as <command>CREATE TABLE</command> as triggered action.
This limitation is not hard to work around by creating a
stored procedure that executes these commands.
</para>
</listitem>
</itemizedlist>
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-createfunction"></member>
<member><xref linkend="sql-droptrigger"></member>
<member><citetitle>PostgreSQL Programmer's Guide</citetitle></member>
</simplelist>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->