Among the uses are generating events and inserting records in tables.
Editor's note: This article is an excerpt from the book DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311): Certification Study Guide.
In DB2 10.1, you can create a multiple-event trigger to fire off a trigger action based on one of three possible triggering events—an INSERT, an UPDATE, or a DELETE statement—instead of creating a separate trigger for each event.
Multiple-event triggers are supported for both row-level triggers (FOR EACH ROW) and statement-level triggers (FOR EACH STATEMENT), which allows you to transform a complex business rule into sophisticated trigger logic. It also helps you greatly during the database migration process to migrate other database vendor products to DB2.
Consider an example where the HR department wants an audit log to be set for any insert, update, or delete operation on the EMPLOYEE table for the column SALARY. The code to do so looks something like this:
CREATE OR REPLACE TRIGGER employeeSalaryMulti
AFTER INSERT OR DELETE OR UPDATE OF salary ON employee
REFERENCING NEW AS N OLD AS O
FOR EACH ROW
MODE DB2SQL
BEGIN
INSERT INTO SALARY_AUDIT
(EMPNO, OLD_SALARY, NEW_SALARY, RATING) VALUES
(N.EMPID, O.SALARY, N.SALARY, N.RATING);--
END
DB20000I The SQL command completed successfully.
The EMPLOYEE and SALARY_AUDIT table data extracts before triggering the event are as follows:
SELECT * FROM employee
EMPID EMPNAME EMPPHONE EMPDEPT EMPADDRESS EMPSTARTDATE SALARY RATING
----- ------- ------------ ------- ----------------- ------------ ------ ------
1 MILAN 07584203037 IS VENUS, MANCHESTER 07/21/2014 600000 1
2 MOHAN 0161 6382409 IS VENUS, MANCHESTER 07/21/2014 100000 1
2 record(s) selected.
SELECT * FROM salary_audit
EMPNO OLD_SALARY NEW_SALARY RATING
----------- ----------- ----------- -----------
1 200000 600000 1
2 100000 300000 1
2 record(s) selected.
A new employee addition into the EMPLOYEE table, as below, will generate an event and trigger an action to insert a record in the SALARY_AUDIT table:
INSERT INTO employee VALUES (3, 'KENT', '8173520251','IS','USA', NULL, 200000, 1)
DB20000I The SQL command completed successfully.
SELECT * FROM salary_audit
EMPNO OLD_SALARY NEW_SALARY RATING
----------- ----------- ----------- -----------
1 200000 600000 1
2 100000 300000 1
3 - 200000 1
3 record(s) selected.
Likewise, deleting or updating an entry in the EMPLOYEE table will generate an event and insert a record in the SALARY_AUDIT table, something like:
DELETE FROM employee WHERE EMPID=2
DB20000I The SQL command completed successfully.
SELECT * FROM salary_audit
EMPNO OLD_SALARY NEW_SALARY RATING
----------- ----------- ----------- -----------
1 200000 600000 1
2 100000 300000 1
3 - 200000 1
- 100000 - -
4 record(s) selected.
UPDATE employee SET SALARY = SALARY * 2 WHERE EMPID=3
DB20000I The SQL command completed successfully.
SELECT * FROM salary_audit
EMPNO OLD_SALARY NEW_SALARY RATING
----------- ----------- ----------- -----------
1 200000 600000 1
2 100000 300000 1
3 - 200000 1
- 100000 - -
3 200000 400000 1
5 record(s) selected.
Learn more with the book DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311): Certification Study Guide.
LATEST COMMENTS
MC Press Online