02
Sat, Nov
2 New Articles

TechTip: More-Flexible SQL Triggers

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

Do you realize how much simpler your life can be with SQL triggers?

 

SQL triggers have been available on DB2 for i since V5R1. The SQL trigger support provides a fast and easy way to create triggers without the extra steps of compiling a program object. In addition, the SQL trigger syntax insulates programmers from having to navigate the trigger buffer associated with external (i.e., non-SQL) triggers.

 

This simplicity is demonstrated in the trigger example found in Figure 1. This SQL trigger intercepts insertions into the travel expenses table to guarantee that the employee's first and last names are always in uppercase when written to the DB2 table. You simply prefix the names of the columns with the correlation identifier (n) specified on the reference clause to access the values in the new row being inserted. This SQL logic is much simpler than writing complex code to extract and change the employee name values in the trigger buffer associated with external triggers. 

 

CREATE TRIGGER auditSpending1

  BEFORE INSERT ON expenses                                  

  REFERENCING NEW AS n                                       

  FOR EACH ROW MODE DB2ROW

 BEGIN                            

             

   SET n.firstname=UPPER(n.firstname);

   SET n.lastname =UPPER(n.lastname);

                        

END                      

Figure 1: This SQL trigger example ensures that the employee's name is in uppercase when written to the DB2 table.

 

As this example demonstrates, you can use SQL Before triggers to change column values before DB2 writes them to the table. However, SQL Before triggers are not allowed, by default, to make changes to other tables. This behavior is dictated by the SQL standards. As an example, let's add logic to the previous trigger to write data to an audit table for large expense submissions. The enhanced trigger is shown in Figure 2.

 

CREATE TRIGGER auditSpending2

  BEFORE INSERT ON expenses                                  

  REFERENCING NEW AS n                                       

  FOR EACH ROW MODE DB2ROW

 BEGIN                            

            

   SET n.firstname=UPPER(n.firstname);

   SET n.lastname =UPPER(n.lastname);

                        

   IF (n.totalamount > 10000)  THEN                       

           INSERT INTO travel_audit                          

              VALUES(n.empno, n.deptno, n.totalamount, n.enddate);

   END IF;                                               

END                            

Figure 2: This SQL trigger example writes data to an audit table for expense submissions.

 

This Before Trigger will not be allowed to create since it contains a statement (i.e., INSERT) that modifies data. The DB2 for i SQL Reference contains a section detailing the data access classification for each SQL statement. SQL statements falling under the Modifies SQL Data classification include INSERT, UPDATE, DELETE, and CREATE.

 

SQL After Triggers don't have this restriction, so the problem could be solved by moving the audit data logic to an After Trigger. However, that would require you to code and maintain two separate Insert triggers for the expenses table.

 

IBM recently delivered a new QAQQINI option in V5R4 and V6R1 that eliminates the need to move this "modify" logic to After triggers. The new SQL_MODIFIES_SQL_DATA QAQQINI parameter enables you to disable this restriction for SQL triggers. Specifying *YES for the  SQL_MODIFIES_SQL_DATA QAQQINI parameter will allow the trigger in Figure 2 to be successfully created on V5R4 and V6R1. This assumes the following PTFs have been applied on the system:

 

•    V5R4: SI29678  (or Database Group PTF #15)

•    V6R1: SI30657  (or Database Group PTF #4)

 

The QAQQINI parameter only has to be specified at the time that the SQL trigger is created in order to allow SQL Before triggers to perform data modification operations.

 

If you haven't used a QAQQINI file before, here's an example of the setup steps needed. 

 

1. First, create a QAQQINI file based on the master file that IBM provides in the QSYS library. The Create Duplicate Object (CRTDUPOBJ) command is used to make sure that triggers are copied from the master file.

 

CRTDUPOBJ OBJ(QAQQINI) FROMLIB(QSYS) OBJTYPE(*FILE) TOLIB(MYLIB)  

  

2. After the QAQQINI file is created, you need to populate the file with the new SQL_MODIFIES_SQL_DATA parameter. Any interface can be used to add a new row into this file, but SQL is probably the simplest.

 

    INSERT INTO mylib/qaqqini(qqparm, qqval)

                       VALUES('SQL_MODIFIES_SQL_DATA', '*YES')

 

3. The final step is to activate this new QAQQINI file for the job that will be creating the SQL triggers. If the QAQQINI file is created in the QUSRSYS library, activating the file is unnecessary because all jobs on the system look for a QAQQINI file in QUSRSYS. Assuming that the file has been created in a different library, the following Change Query Attribute (CHGQRYA) command will activate the QAQQINI file for the specified job.

 

   CHGQRYA QRYOPTLIB(mylib)

 

More information on QAQQINI files and SQL triggers can be found in the IBM Systems InfoCenter

 

SQL triggers can be a powerful programming tool. The new PTFs provide even more flexibility when using SQL Before triggers to enhance applications.

  

Kent Milligan
Kent Milligan is a Senior Db2 for i Consultant in the IBM Lab Services Power Systems Delivery Practice.  Kent has over 25 years of experience as a Db2 for IBM i consultant and developer working out of the IBM Rochester lab. Prior to re-joining the DB2 for i Lab Services practice in 2020, Kent spent 5 years working on healthcare solutions powered by IBM Watson technologies. Kent is a sought-after speaker and author on Db2 for i & SQL topics.
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: