A trigger procedure is an routine that can be executed only from the FOR EACH ROW section of a trigger. This procedure can use special record variable names to reference the old column value in the row when the trigger event occurred, or the new value of the column after the row was modified by the trigger.
Inheriting automatically all values new or old from a table affected by a trigger, simplifies how to pass arguments to functions executed by triggers.
This feature is fully supported in a similar way by Informix and PostgreSQL
1 Informix Example
The following example defines three tables and a trigger procedure that references one of these tables in its FOR clause:
CREATE TABLE tab1 (col1 INT,col2 INT); CREATE TABLE tab2 (col1 INT); CREATE TABLE temptab1 (old_col1 INT, new_col1 INT, old_col2 INT, new_col2 INT); /* The following procedure is invoked from an INSERT trigger in this example. */ CREATE PROCEDURE proc1() REFERENCING OLD AS o NEW AS n FOR tab1; IF (INSERTING) THEN -- INSERTING Boolean operator LET n.col1 = n.col1 + 1; -- You can modify new values. INSERT INTO temptab1 VALUES(0,n.col1,1,n.col2); END IF IF (UPDATING) THEN -- UPDATING Boolean operator -- you can access relevant old and new values. INSERT INTO temptab1 values(o.col1,n.col1,o.col2,n.col2); END IF IF (SELECTING) THEN -- SELECTING Boolean operator -- you can access relevant old values. INSERT INTO temptab1 VALUES(o.col1,0,o.col2,0); END IF IF (DELETING) THEN -- DELETING Boolean operator DELETE FROM temptab1 WHERE temptab1.col1 = o.col1; END IF END PROCEDURE;
This example illustrates that the triggered action can be a different DML operation from the triggering event. Although this procedure inserts a row when an Insert trigger calls it, and deletes a row when a Delete trigger calls it, it also performs INSERT operations if it is called by a Select trigger or by an Update trigger.
The proc1() trigger procedure in this example uses Boolean conditional operators that are valid only in trigger routines. The INSERTING operator returns true only if the procedure is called from the FOR EACH ROW action of an INSERT trigger. This procedure can also be called from other triggers whose trigger event is an UPDATE, SELECT, or DELETE. statement, because the UPDATING, SELECTING and DELETING operators return true ( t ) if the procedure is invoked in the triggered action of the corresponding type of triggering event.
The following statement defines an Insert trigger on tab1 that calls proc1() from the FOR EACH ROW section as its triggered action, and perform an INSERT operation that activates this trigger:
CREATE TRIGGER ins_trig_tab1 INSERT ON tab1 REFERENCING NEW AS post FOR EACH ROW( EXECUTE PROCEDURE proc1() WITH TRIGGER REFERENCES );
Note that the REFERENCING clause of the trigger declares a correlation name for the NEW value that is different from the correlation name that the trigger procedure declared. These names do not need to match, because the correlation name that was declared in the trigger procedure has that procedure as its scope of reference. The following statement activates the ins_trig_tab1 trigger, which executes the proc1() procedure.
INSERT INTO tab1 VALUES (111,222);
Because the trigger procedure increments the new value of col1 by 1, the value inserted is (112, 222), rather than the value that the triggering event specified.
2 PostgreSQL Example
The same previous Informix example can be easily defined in PostgreSQL without so much translation efforts.
CREATE TABLE tab1 (col1 integer,col2 integer); CREATE TABLE tab2 (col1 integer); CREATE TABLE temptab1 (old_col1 integer, new_col1 integer, old_col2 integer, new_col2 integer); CREATE OR REPLACE FUNCTION proc1() RETURNS TRIGGER AS $proc1$ BEGIN -- -- Create a row in emp_audit to reflect the operation performed on emp, -- make use of the special variable TG_OP to work out the operation. -- IF (TG_OP = 'INSERT') THEN NEW.col1 = NEW.col1 + 1; -- You can modify new values. INSERT INTO temptab1 VALUES(0,NEW.col1,1,NEW.col2); RETURN NEW; ELSIF (TG_OP = 'UPDATE') THEN INSERT INTO temptab1 values(OLD.col1,NEW.col1,OLD.col2,NEW.col2); RETURN NEW; ELSIF (TG_OP = 'DELETE') THEN DELETE FROM temptab1 WHERE temptab1.col1 = OLD.col1; RETURN OLD; END IF; RETURN NULL; -- result is ignored since this is an AFTER trigger END; $proc1$ LANGUAGE plpgsql; CREATE TRIGGER ins_trig_tab1 AFTER INSERT OR UPDATE OR DELETE ON tab1 FOR EACH ROW EXECUTE PROCEDURE proc1();
3 Oracle Example
Oracle doesn't support trigger procedures concept, but you can embed any procedure code inside a trigger and use it in a similar way than trigger procedures.
Previous example can be translated to Oracle this way:
CREATE TABLE tab1 (col1 integer,col2 integer); CREATE TABLE tab2 (col1 integer); CREATE TABLE temptab1 (old_col1 integer, new_col1 integer, old_col2 integer, new_col2 integer); CREATE OR REPLACE TRIGGER ins_trig_tab1 BEFORE INSERT ON tab1 REFERENCING NEW AS nxt FOR EACH ROW BEGIN IF INSERTING THEN :nxt.col1 = :nxt.col1 + 1; -- You can modify new values. INSERT INTO temptab1 VALUES(0,:nxt.col1,1,:nxt.col2); END IF; IF UPDATING THEN INSERT INTO temptab1 values(:prv.col1,:nxt.col1,:prv.col2,:nxt.col2); END IF; IF DELETING THEN DELETE FROM temptab1 WHERE temptab1.col1 = :prv.col1; END IF; END ins_trig_tab1;
Alternative method can be a manual assigment of data to record variable and passing that variable to a function.
create or replace procedure proc1(ChangeType in CHAR(1), row in out tab1%rowtype) is begin IF ( ChangeType = 'I' ) THEN row.col1 := row.col1 + 1; INSERT INTO temptab1 VALUES(0,row.col1,1,row.col2); END IF; end CREATE OR REPLACE TRIGGER ins_trig_tab1 BEFORE INSERT OR UPDATE ON tab1 FOR EACH ROW DECLARE n_tab1 tab1%rowtype; v_ChangeType CHAR(1); BEGIN IF INSERTING THEN v_ChangeType := 'I'; ELSIF UPDATING THEN v_ChangeType := 'U'; ELSE v_ChangeType := 'D'; END IF; n_tab1.col1 := :NEW.col1; n_tab1.col2 := :NEW.col2; proc1( v_ChangeType, n_tab1 ); :NEW.col1 := n_tab1.col1; :NEW.col2 := n_tab1.col2; END;