New multiple-event triggers can simplify your SQL trigger development and management.
As the utilization of SQL triggers continues to rise, some developers are being challenged by the fact that they must define a separate SQL trigger for each database event they want to associate with a trigger. Consider a developer who wants to use SQL triggers to ensure that any Insert or Update operation against the customer table always stores the company name value with all uppercase characters. In this situation, the developer would have to create two triggers: one trigger for the Insert event and one for the Update event.
CREATE TRIGGER upper_name_insert
BEFORE INSERT ON customer
REFERENCING NEW AS n
FOR EACH ROW
SET n.company_name = UPPER(n.company_name);
CREATE TRIGGER upper_name_update
BEFORE UPDATE ON customer
REFERENCING NEW AS n
FOR EACH ROW
SET n.company_name = UPPER(n.company_name);
Because a single SQL trigger cannot be shared for different events, developers had to code and manage the source code for each trigger separately. This limitation often resulted in the same logic being duplicated in multiple places. In addition, this limitation bogged down the installation and administration of triggers because each trigger would have to be separately added to the DB2 table (or physical file). Adding a trigger to a table requires DB2 to hold an exclusive lock while the new trigger is linked to the table object. Thus, more triggers means there are more times that DB2 needs to acquire an exclusive lock on your production tables. Extra exclusive lock requests are usually not a good thing for shops that are striving to provide 24x7 availability of their applications and databases.
Now that you understand the limitations of the existing SQL trigger support, let's look at how the new multiple-event SQL trigger support in Technology Refresh 6 for IBM i 7.1 provides a solution to these limitations. This enhancement also catches SQL trigger functionality up with the multiple-event support provided by external triggers (Add Physical File Trigger command) for many releases.
As the name implies, a single SQL trigger can be defined to process more than one database event. The following trigger utilizes the multiple-event support to combine the two previous Insert and Update triggers into a single trigger definition.
CREATE TRIGGER upper_name_trigger
BEFORE INSERT OR UPDATE OR DELETE ON customer
REFERENCING NEW AS n
FOR EACH ROW
BEGIN
IF INSERTING OR UPDATING THEN
SET n.company_name = UPPER(n.company_name);
ELSE
/* Customer being dropped */
CALL Check_For_Unpaid_Bills(n.company_name);
END IF;
END;
The new OR keyword on the BEFORE clause enables a developer to define multiple events for the SQL trigger to process. In this example, the SQL trigger is defined for all of the available events: Insert, Update, and Delete. A multiple-event trigger is not allowed to mix the trigger time. For example, this means that a single multiple-event SQL trigger cannot handle both Before and After events. Only a single trigger time value of Before, After, or Instead Of can be specified on a multiple-event SQL trigger definition.
The multiple-event trigger feature also includes new DB2 predicate support so that the trigger logic can determine whether the trigger is being called to process an insert, update, or delete event. The names of the new predicates are INSERTING, UPDATING, and DELETING. These predicates are Boolean variables that can be referenced on any conditional construct. The previous example references the INSERTING and UPDATING predicates so that the uppercasing of the company_name column is performed only for insert and update events. When a customer is deleted, the trigger invokes a stored procedure to determine whether the customer being deleted has any unpaid bills or not.
This usage of stored procedure calls within an SQL trigger is not unique to multiple-event SQL triggers, but it is a technique that can be combined with multiple-event SQL triggers to minimize how often an SQL trigger must be recreated. As discussed earlier, avoiding the recreation of an SQL trigger means that you reduce the number of times that DB2 must obtain an exclusive lock to add the trigger back.
The process_parts trigger below is an example of a multiple-event SQL trigger that utilizes stored procedure calls for the processing of all event types: insert, update, and delete. By embedding the trigger logic into the stored procedure, the developer has the flexibility of changing the logic in the stored procedure without having to touch the SQL trigger. This assumes that the stored procedure logic changes don't require the SQL trigger to pass additional parameters.
CREATE TRIGGER process_parts
AFTER INSERT OR DELETE OR UPDATE ON parts
REFERENCING NEW AS n OLD AS o
FOR EACH ROW
BEGIN
IF INSERTING THEN
CALL partsAdd(n.partid,n.parttype,n.partqty);
ELSEIF DELETING THEN
CALL partsRmv(o.partid);
ELSE /* Updating parts table */
CALL partsChg(n.partid,n.parttype,n.partqty,
o.partid,o.parttype,o.partqty);
END IF;
END
As with most programming techniques, there's a performance tradeoff to using this approach. The usage of stored procedures means that there will be an extra program call in addition to the call to the SQL trigger. Thus, you will need to understand the performance requirements of the application before choosing this approach.
One side benefit of the multiple-event SQL trigger enhancement is that IBM has also eliminated the data modification restrictions for SQL Before triggers. Thus, once you load IBM i 7.1 Database Group PTF level 22 on your system, there's no need to use the SQL_MODIFIES_SQL_DATA QAQQINI parameter detailed in a previous TechTip I wrote.
Hopefully, the benefits of defining multiple-event SQL triggers are clear to you. All you need to do is get your IBM i 7.1 Database Group PTF level to 22 on your system. Then, you'll be able to experience the simplified development and management that multiple-event SQL triggers offer.
LATEST COMMENTS
MC Press Online