CREATE TRIGGER
  SQL - Language Statements
 
 
  
   CREATE TRIGGER
  
  
   define a new trigger
  
 
 
  
   2000-03-25
  
  
CREATE TRIGGER name { BEFORE | AFTER } { event [ OR ... ] }
    ON table [ FOR [ EACH ] { ROW | STATEMENT } ]
    EXECUTE PROCEDURE func ( arguments )
  
  
  
   
    1998-09-21
   
   
    Inputs
   
   
    
     
      name
      
       
	The name to give the new trigger.  This must be distinct from the name
	of any other trigger for the same table.
       
      
     
     
      BEFORE
      AFTER
      
       
		Determines whether the function is called before or after the
		event.
       
      
     
     
      event
      
       
		One of INSERT, DELETE or
		UPDATE; this specifies the event that will
		fire the trigger. Multiple events can be specified using
		OR.
       
      
     
     
      table
      
       
		The name (optionally schema-qualified) of the table the
		trigger is for.
       
      
     
	 
	  FOR EACH ROW
	  FOR EACH STATEMENT
	  
	   
		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, FOR EACH
		STATEMENT is the default.
	   
	  
	 
     
      func
      
       
	A user-supplied function that is declared as taking no arguments
	and returning type trigger>.
       
      
     
     
      arguments
      
       
    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
	TG_ARGV array.
       
      
     
    
   
  
  
   
    1998-09-21
   
   
    Outputs
   
   
    
     
      
CREATE TRIGGER
       
      
       
	This message is returned if the trigger is successfully created.
       
      
     
    
   
  
 
 
 
  
   1998-09-21
  
  
   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.
  
  
   The trigger can be specified 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 (e.g., 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.
  
  
   A trigger that executes FOR EACH ROW of the
   specified operation is called once for every row that the operation
   modifies. For example, a DELETE that affects 10
   rows will cause any ON DELETE triggers on the
   target relation to be called 10 separate times, once for each
   deleted tuple. In contrast, a trigger that executes FOR
   EACH STATEMENT of the specified operation only executes
   once for any given operation, regardless of how many rows it
   modifies (in particular, an operation that modifies zero rows will
   still result in the execution of any applicable FOR EACH
   STATEMENT triggers).
  
  
   If multiple triggers of the same kind are defined for the same event,
   they will be fired in alphabetical order by name.
  
  
   SELECT does not modify any rows so you can not
   create SELECT triggers. Rules and views are more
   appropriate in such cases.
  
  
   Refer to  for more information.
  
 
 
  Notes
  
   To create a trigger on a table, the user must have the
   TRIGGER privilege on the table.
  
  
   In PostgreSQL versions before 7.3, it was
   necessary to declare trigger functions as returning the placeholder
   type opaque>, rather than trigger>.  To support loading
   of old dump files, CREATE TRIGGER> will accept a function
   declared as returning opaque>, but it will issue a NOTICE and
   change the function's declared return type to trigger>.
  
  
   Refer to the  command for
   information on how to remove triggers.
  
 
 
  Examples
  
   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 cancelling 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:
      
       
        
         SQL99 allows triggers to fire on updates to specific columns
         (e.g., AFTER UPDATE OF col1, col2).
        
       
       
        
         SQL99 allows you to define aliases for the old
         and new
 rows or tables for use in the definition
         of the triggered action (e.g., CREATE TRIGGER ... ON
         tablename REFERENCING OLD ROW AS somename NEW ROW AS
         othername ...).  Since
         PostgreSQL allows trigger
         procedures to be written in any number of user-defined
         languages, access to the data is handled in a
         language-specific way.
        
       
       
        
         PostgreSQL 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 CREATE TABLE as triggered action.
         This limitation is not hard to work around by creating a
         stored procedure that executes these commands.
        
       
      
     
     
      SQL99 specifies that multiple triggers should be fired in
      time-of-creation order.  PostgreSQL
      uses name order, which was judged more convenient to work with.
     
     
      The ability to specify multiple actions for a single trigger
      using OR is a PostgreSQL>
      extension of the SQL standard.
     
    
   
  
 
 
  See Also