The previous article introduced the concept of SQL triggers and showed some scenarios in which you can use them. Now let’s go over some practical scenarios.
Let me start by reminding you that triggers are very useful but can become a nightmare if you overuse them. For instance, when a trigger fires another trigger and that trigger fires another (and so on), serious performance issues may occur. Before adding a trigger, consider the global picture and not just the table in which you’re adding the trigger!
Enough theory; let’s get our hands dirty! Before we begin, let’s look at how a trigger works, step by step:
- A trigger is defined to monitor when an I/O operation over a table occurs.
- The trigger checks its definition to see if the operation that took place should make the trigger act.
- If it should, then the trigger’s “program” is executed. This could range from a simple INSERT or SELECT INTO statement to a complex PL/SQL program.
Let’s see how this translates to the CREATE TRIGGER structure:
CREATE TRIGGER <trigger name>
ON <table name>
FOR EACH ROW | FOR EACH STATEMENT
MODE DB2ROW | DB2SQL
WHEN (<condition>)
BEGIN
<trigger’s code>
END
Here’s a simple example that uses a single instruction (an UPDATE statement) as the trigger’s code:
CREATE TRIGGER MYSCHEMA.TRG_Upd_Order_Total
AFTER INSERT ON MYSCHEMA.TBL_Order_Master
FOR EACH ROW MODE DB2SQL
UPDATE MYSCHEMA.TBL_Pending_Orders
SET Tot_Month_Orders = Total_Month_Orders + 1
WHERE Order_Year = Year(Now()) And Order_Month = Month(Now())
In this example, I’m defining the TRG_Upd_Order_Total trigger to keep an eye on INSERT operations on table TBL_Order_Master. For each row that gets inserted into the table, the trigger updates the monthly total of orders via the UPDATE statement that spans over the last three lines of the trigger. This UPDATE statement is the “program” that the trigger executes. The execution occurs after the INSERT operation, as defined by this line:
AFTER INSERT ON MYSCHEMA.TBL_Order_Master
I’ll discuss the FOR EACH ROW line later, with another example. Regardless of the origin of the new order (RPG program, web application using ODBC, PC application using OLE DB, or some other way to “talk” to DB2’s database), this “code” will still run.
This is a rather simple example, so let’s complicate things a bit. Imagine I want to keep track of unusually large variations in my inventory. The company’s business rules define these variations as item quantity variations greater than 30 percent. Whenever such a variation is detected, a record should be written to an audit table. Let’s define a trigger to implement this, step by step, starting with the trigger’s name and event:
CREATE TRIGGER MYSCHEMA.TRG_Log_Unusual_Stock_Changes
AFTER UPDATE ON MYSCHEMA.TBL_Inventory_Master
Because I’ll want to determine the stock variation, I need to know the before and after update values, or more accurately, the OLD and NEW values. To do that, two additional lines are needed:
REFERENCING NEW ROW AS B_UPD
OLD ROW AS A_UPD
You’ll see how this is used later.
Then, I want the trigger to act once for each row that’s affected, and I want that action to occur immediately after each update to the inventory master table:
FOR EACH ROW MODE DB2SQL
The FOR EACH ROW definition tells the database manager to execute the trigger’s “program” once for each line affected by the update operation. The alternative definition is FOR EACH STATEMENT, which is (you guessed it) executed only once per statement, regardless of how many lines were affected by the statement. There’s also another, much more subtle difference: This second FOR EACH option is always executed, even if the update operation didn’t find any rows to update.
The MODE definition tells the database manager when to run the trigger’s “program.” The MODE DB2SQL defined here lets all the update operations take place and then runs the trigger code. The alternative, MODE DB2ROW, pauses after each update operation, runs the trigger code, and then moves on to the next update operation.
Let me try to make this clearer with a comparison of the two modes, starting with DB2SQL:
Update 1st row
Update 2nd row
...
Update nth row
Calls trigger for 1st row
Calls trigger for 2nd row
...
Calls trigger for nth row
Here’s how the DB2ROW mode functions:
Update 1st row
Calls trigger for 1st row
Update 2nd row
Calls trigger for 2nd row
...
Update nth row
Calls trigger for nth row
I can’t tell you that one mode is better than the other because it depends on the specific business needs of your situation. There will be times when DB2ROW reflects your business needs more accurately, and others when DB2SQL fits better. Most of the time, it probably does not make any difference. If this is the case for you, remember that DB2ROW performs better.
I’ve defined what the target for my trigger (table TBL_Inventory_Master) is, when it acts (AFTER UPDATE), and how it behaves (the FOR EACH line). The only thing missing is what it does: Whenever an “unusual” stock variation occurs, log it. I could include this condition in the trigger’s “program,” but that would mean the code would be checking the condition to decide if an action was needed. However, there’s an additional definition I can include before the trigger’s code that conditions the execution. It’s a WHEN clause, which is similar in every way to the WHERE clause you’ve seen in other SQL instructions. I specify one or more conditions, and the execution takes place only if they evaluate to true:
WHEN (((B_UPD.ItemQTY / A_UPD.ItemQTY) > 1,3)
OR (B_UPD.ItemQTY / A_UPD.ItemQTY) < 0,7))
This will keep the trigger’s code from being executed except when the variation in the item quantity is greater than 30 percent—the aforementioned unusual stock variation.
Finally, here’s the trigger’s code:
BEGIN
INSERT INTO MYSCHEMA.TBL_STOCK_CHANGES_LOG
(LAST_CHANGED, ITEM_ID, WHID, SHELF_ID, STOCK_VARIATION)
VALUES (NOW(), A_UPD.ITEM_ID, A_UPD.WHID, SHELF_ID,
(B_UPD.ItemQTY / A_UPD.ItemQTY));
END
In this example, the trigger code looks a bit more like a structured piece of code. It’s delimited by BEGIN and END statements, and the statement in between (only one, in this case) is terminated by a semicolon. Note how the columns are referenced, using the prefixes that were previously defined to identify the BEFORE UPDATE and AFTER UPDATE rows.
Finally, here’s the complete trigger code:
CREATE TRIGGER MYSCHEMA.TRG_Log_Unusual_Stock_Changes
AFTER UPDATE ON MYSCHEMA.TBL_Inventory_Master
REFERENCING NEW ROW AS B_UPD
OLD ROW AS A_UPD
FOR EACH ROW MODE DB2SQL
WHEN (((B_UPD.ItemQTY / A_UPD.ItemQTY) > 1,3)
OR (B_UPD.ItemQTY / A_UPD.ItemQTY) < 0,7))
BEGIN
INSERT INTO MYSCHEMA.TBL_STOCK_CHANGES_LOG
(LAST_CHANGED, ITEM_ID, WHID, SHELF_ID, STOCK_VARIATION)
VALUES (NOW(), A_UPD.ITEM_ID, A_UPD.WHID, SHELF_ID,
(B_UPD.ItemQTY / A_UPD.ItemQTY));
END
A trigger can also act before the I/O operation takes place. The possible I/O operations are INSERT, UPDATE, and DELETE. This means you can define a trigger to the following events:
- Before DELETE
- Before INSERT
- Before UPDATE
- After DELETE
- After INSERT
- After UPDATE
Note that the event chosen limits some of the other definitions. For instance, you can’t specify FOR EACH STATEMENT if you defined a BEFORE event.
What makes SQL triggers so special is the fact that they can be defined surgically, only to react to an event over a table’s column. Here’s an example, taken from the External Procedures, Triggers and User-Defined Functions on IBM DB2 for i Redbook:
CREATE TRIGGER SALARY_TRACK
AFTER UPDATE OF SALARY ON EMPLOYEE
REFERENCING NEW ROW AS NROW
OLD ROW AS OROW
FOR EACH ROW MODE DB2SQL
WHEN (NROW.SALARY < OROW.SALARY)
BEGIN
INSERT INTO SALARY_CTL (EMPNO, NEW_SALARY,
OLD_SALARY, UPDATE_TIMESTAMP)
VALUES (NROW.EMPNO, NROW.SALARY, OROW.SALARY,
CURRENT TIMESTAMP
);
END
For your convenience, I’ve highlighted the new code. In this example, the trigger targets update operations of the SALARY column in the EMPLOYEE table. Updates to this table that don’t change this column’s value are simply ignored. The rest of the code is similar to the previously presented examples.
The aforementioned Redbook contains detailed information about SQL and external triggers that go way beyond what you’ve read in the last couple of articles. This Redbook also covers stored procedures and user-defined functions in great depth, so it might be a good idea to read it at some point in the near future. Reading it now, though, might do more harm than good, especially if this is your first “serious” contact with DDL.
LATEST COMMENTS
MC Press Online