CREATE TRIGGER

Name

CREATE TRIGGER  --  Defines a new trigger

Synopsis

CREATE TRIGGER name { BEFORE | AFTER } { event [OR ...] }
    ON table FOR EACH { ROW | STATEMENT }
    EXECUTE PROCEDURE func ( arguments )
  

Inputs

name

The name of the new trigger.

table

The name of an existing table.

event

One of INSERT, DELETE, or UPDATE.

func

A user-supplied function.

Outputs

CREATE

This message is returned if the trigger is successfully created.

Description

CREATE TRIGGER will enter a new trigger into the current database. The trigger will be associated with the relation table and will execute the specified function func. Only the relation owner may create a trigger on this relation.

You can specify the trigger to fire either before BEFORE the operation is attempted on a tuple (before constraints are checked and the INSERT, UPDATE or DELETE is attempted) or AFTER the operation has been attempted (for example, after constraints are checked and the INSERT, UPDATE or DELETE 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 INSERT and UPDATE operations only). If the trigger fires after the event, all changes, including the last insertion, update, or deletion, are "visible" to the trigger.

SELECT does not modify any rows, so you cannot create SELECT triggers. Rules and views are more appropriate in such cases.

Notes

See DROP TRIGGER for information on how to remove triggers.

See CREATE FUNCTION for information on how to register a user-supplied function.

To create a trigger on a table, the user must have the TRIGGER privilege on the table.

As of the current release, STATEMENT triggers are not implemented.

Refer to the Red Hat Database Programmer's Guide for more information on trigger procedures.

Usage

Check if the specified distributor code exists in the distributors table before appending or updating a row in the table films:

CREATE TRIGGER if_dist_exists
   BEFORE INSERT OR UPDATE ON films FOR EACH ROW
   EXECUTE PROCEDURE check_primary_key ('did', 'distributors', 'did');

Before canceling a distributor or updating its code, remove every reference to the table films:

CREATE TRIGGER if_film_exists 
    BEFORE DELETE OR UPDATE ON distributors FOR EACH ROW
    EXECUTE PROCEDURE check_foreign_key 
    (1, 'CASCADE', 'did', 'films', 'did');

The second example can also be done by using a foreign key, constraint as in:
CREATE TABLE distributors (
    did      DECIMAL(3),
    name     VARCHAR(40),
    CONSTRAINT if_film_exists
    FOREIGN KEY(did) REFERENCES films
    ON UPDATE CASCADE ON DELETE CASCADE  
);

Compatibility

SQL92

There is no CREATE TRIGGER statement in SQL92.

SQL99

The CREATE TRIGGER statement in PostgreSQL implements a subset of the SQL99 standard. The following functionality is missing: