21
Sat, Dec
3 New Articles

TechTip: Streamline Your SQL Procedures, Functions, and Triggers

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

Learn why recreating your SQL routines can improve performance.

As a developer, it’s easy to operate by the motto “If it ain’t broke, don’t fix it.” That practice is understandable, given there’s usually not enough hours in the workday to get everything done. If you have SQL procedures, functions, or triggers that are frequently used, then you may be able to improve performance by making an exception to this practice.

You may not be aware that when an SQL routine object such as a user-defined function (UDF) is created with the SQL procedural language, the Db2 underneath the covers generates a C program object with embedded SQL statements. To maximize performance, Db2 does try to generate C code to implement some of the simpler SQL statements, such as SET and IF. An assignment statement like SET v1=’ABC’ will run much faster by using generated C code than by invoking the Db2 engine to copy 3 bytes of data into a variable.

The good news from an SQL performance perspective is that IBM has improved its C code generation over the years. The bad news is that your SQL routines must be recreated to reap the benefits of these C code generation improvements. These code generation improvements are most often delivered as part of a new IBM i release. Code gen enhancements are also delivered with Database Group PTFs as this Db2 website shows.

Based on these delivery vehicles, a good strategy to employ is to recreate all your SQL routines after installing a new release or Database Group PTF. If your shop uses a change management tool, then recreating all of your SQL procedures, functions, and triggers after these events should be an easy task.

Another strategy is focusing your recreate efforts on those SQL routines that haven’t been recreated in a while and that are frequently used. You might be thinking that will be difficult to figure out. However, the Db2 system catalog views make this task quite simple.

The catalog views that you will want to use for this task are the SYSPROGRAMTSTAT and SYSPROGRAMSTMTSTAT views in QSYS2. The SYSPROGRAMTSTAT view contains one row for every program that contains an embedded SQL statement on the system. As discussed earlier, SQL routines get implemented as a C program with embedded SQL, so this catalog view will contain a row for every SQL procedure, function, and trigger on your system. Correspondingly, the SYSPROGRAMSTMTSTAT view contains one row for every embedded SQL statement in the programs contained in the prior view. An SQL statement that gets implemented with generated code will not be represented in this view.

The code below contains an example of a query that can be run against these two catalog views to identify SQL routines that haven’t been recreated in over 12 months and that have been used in the last 6 months.

WITH Assignment_Count AS (SELECT program_schema, program_name,

   SUM( CASE WHEN Statement_Text like 'SET%' THEN 1 ELSE 0 END) Assignment_Stmts

     FROM qsys2.sysprogramstmtstat GROUP BY program_schema, program_name)

SELECT p.program_schema, p.program_name, routine_type, number_statements, assignment_stmts,

DATE(creation_timestamp) creation_date, DATE(last_used_timestamp) last_used_date, days_used_count FROM qsys2.sysprogramstat p INNER JOIN assignment_count a

ON p.program_schema = a.program_schema AND p.program_name = a.program_name

WHERE routine_body='SQL' AND routine_type IN ('PROCEDURE','FUNCTION','TRIGGER') AND

   MONTHS_BETWEEN(CURRENT_DATE, DATE(last_used_timestamp))<6 AND

   MONTHS_BETWEEN(CURRENT_DATE, DATE(creation_timestamp))>=12  

   ORDER BY last_used_timestamp DESC, creation_timestamp ;

The Assignment_Count common table expression is used on the SYSPROGRAMSTMTSTAT view to count the number of SET statements in each routine that are using SQL instead of C code since those are the easiest targets for C code generation to replace. The main SELECT statement joins SYSPROGRAMSTMT to this table expression and returns only those programs that are associated with SQL routines by filtering on routine_body and routine_type. The statement also specifies filtering criteria on the two timestamp columns to return only those routines used in the last 6 months that have not been recreated in over 12 months.  

Figure 1 contains a sample result set from this query. The catalog view query has returned three functions that meet the specified criteria. Notice that it returned one SQL procedure that was last recreated in 2014. That procedure and the SQL function in the list have the most potential for improved performance from a recreate since a high percentage of the SQL statements are assignment statements. You can easily customize this query to generate a more targeted list of routines.

TechTip: Streamline Your SQL Procedures, Functions, and Triggers - Figure 1 

Figure 1: Output from catalog view query to identify SQL routines to recreate

It should now be obvious how simple recreates of your SQL routines could improve performance. Once you’ve mastered regular recreates for performance, I’ll leave you with a challenge of reviewing this white paper to ensure that your SQL coding techniques are optimal for C code generation.

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: