21
Sat, Dec
3 New Articles

TechTip: Simplify and Centralize Your SQL Triggers

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

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.

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: