23
Sat, Nov
1 New Articles

TechTip: DB2 for i Optimization Strategies, Part 2

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

Avoid common SQL programming mistakes that can change your query speed from a cheetah to a tortoise.

This tip continues the series started in Part 1 that discusses some common SQL coding styles that can be improved. While some examples may seem trivial, under a heavy load, saving CPU cycles and reducing data and journaling I/O can make a considerable impact on overall system performance.

Join Correlation with Inconsistent Data Types

Often there is a need to join data in tables on columns with incompatible data types, especially on systems that have applications written by different individuals or vendors. A common example is having an employee ID defined as DECIMAL(5,0) in an Employee table and the same ID defined as CHAR(9) in a transaction table (from another application).

In this situation, the following approach is common (the example assumes character column TransEmpNo contains valid decimal data):

SELECT *

FROM Transaction T

JOIN Employee e ON CHAR(e.EmployeeId)=p.TransEmpNo

WHERE T.TranDate BETWEEN @StartDate AND @EndDate;

Considering that the Employee table will likely be considered as the secondary table in the join order by DB2 (with a primary key on EmployeeId), the CHAR function will force DB2 to convert the EmployeeId column to character and thereby eliminate its ability to use the primary key. The correct way to code is to cast the character TransEmpNo column to DEC(5,0) so that DB2 can take advantage of the primary key on the Employee table.

SELECT *

FROM Transaction T

JOIN Employee e ON e.EmployeeId=DEC(p.TransEmpNo,5,0)

WHERE T.TranDate BETWEEN @StartDate AND @EndDate;

Since V5R3, the JOIN can be done without an explicit cast one way or the other; however, DB2 will follow the rules for implicit CASTing and may choose the suboptimal CAST.

It’s easy to see the significant difference in the plans built by DB2:

 

052016SansoterraFigure1a

Figure 1a: Query with the CHAR cast applied to the decimal employee ID

 

052016SansoterraFigure1b

Figure 1b: Query with the DECIMAL cast applied to the character employee ID

 

The one unfortunate case where the first query may be appropriate is when the TransEmpNo column contains strings that cannot be converted to a number (such as if it contains alphabetic characters). In that scenario, the second query would cause DB2 to choke because it cannot cast the data.

Use Care When Using Expressions in Predicates

A principle for SQL coding is to avoid using unnecessary expressions with columns that may be important to DB2 for index access or statistics. Index access is very important as it allows DB2 a shortcut to retrieve specific data without having to read the entire table. While not as important for performance as indexes, statistics help DB2 estimate how many rows a query might retrieve when it analyzes the query predicates. Accurate row count is important as it helps DB2 choose the join order of tables and allocate memory for the anticipated data volume.

Consider the SALESORDERDETAIL table, which has an index built on column ProductId. The following query, because of the COALESCE function, is suboptimal:

SELECT COUNT(*)

INTO @ProductCount

FROM SalesOrderDetail

WHERE COALESCE(ProductId,0)=@ProductId;

In this case, use of the COALESCE function prevents DB2 for i from using the available ProductId index, thereby causing DB2 to read the entire table. Many developers think the COALESCE function should be used to process a nullable column. However, DB2 works fine without it. If the application needs a count of rows where ProductId contains a NULL, then a separate query with a ProductId IS NULL predicate is appropriate.

For another simple example where using expressions can cause a performance problem, consider a sales order header table with an index on column OrderDate. When writing a query to get orders from the past two years, sometimes developers write code like this:

SELECT COUNT(*)

FROM SalesOrderHeaderEnlarged

WHERE OrderDate+2 YEARS>=CURRENT_DATE

Code like this just makes me go all to pieces. Using date math on the OrderDate column prevents DB2 from effectively using the index on this column. The correct way to code this is:

SELECT COUNT(*)

FROM SalesOrderHeaderEnlarged

WHERE OrderDate>=CURRENT_DATE-2 YEARS

The query plans look similar as they both use the OrderDate index for the simple query:

 

052016SansoterraFigure2a

Figure 2a: WHERE predicate contains an expression on ORDERDATE column (suboptimal)

 

052016SansoterraFigure2b

Figure 2b: WHERE predicate contains an expression on CURRENT_DATE special register (optimal)

Even though the operators are the same, the rows processed in the index scan are different. It turns out the second query ran about 20 percent faster during my testing. It’s possible that, in a future version of DB2 for i, the query engine will be smart enough to automatically rewrite the suboptimal ORDER_DATE predicate in the first example to match the second example.

For a final example, consider this search against the SalesOrderHeader table against indexed character column CREDITCARDAPPROVALCODE:

SELECT *

FROM SalesOrderHeader

WHERE TRIM(CREDITCARDAPPROVALCODE)='55680Vi53503';

The TRIM function in this example removes leading and trailing spaces before doing the comparison (but preventing DB2 from using the column’s index). I see developers using this type of defensive code because they’re trying to make sure nothing slips through the cracks.

If column CREDITCARDAPPROVALCODE is fixed width or contains trailing spaces, you don’t need to worry about trimming as DB2 automatically ignores trailing spaces when doing string comparisons. If there are leading spaces in this type of column, it is probably bad data that should be fixed (along with the code that allowed it in the database).

Incidentally, CHECK constraints should be used to prevent bad data from getting into the table in the first place (so queries won’t have to check for these kinds of invalid data conditions). Also, in languages like C# and Java, trailing spaces are not ignored when doing string comparisons, which makes developers assume database code is written the same way. However, unnecessary defensive DB2 code like this can slow down a query.

While normally I do not advocate using a function in a predicate, there are some exceptions. For example, in the following code example, the SUBSTRING search performs as well as the LIKE:

SELECT *

FROM SALESORDERDETAIL d

WHERE CARRIERTRACKINGNUMBER LIKE '4E%'

SELECT *

FROM SALESORDERDETAIL d

WHERE SUBSTRING(CARRIERTRACKINGNUMBER,1,2)='4E'

 

NOTE: Visual Explain’s (actual runtime ms) consistently showed the SUBSTRING version edging out the LIKE version in performance. However, in the analysis of the same SQL statement using the monitor “show statements,” the average and run time columns showed the two statements as equals in performance (judged by statement duration). I’m not sure why that discrepancy exists between the two tools.

The only way to check whether or not DB2 for i is smart enough to allow for an expression on a column in a predicate is to test.  

Finally, the benefit of this coding tip applies to columns that provide the primary filter criteria for a query. If other predicates in a query do the majority of the WHERE/JOIN filtering, then the impact is lessened when using an expression on a column that doesn’t do much filtering.

No Speed Limit

This tip demonstrated that care should be taken when joining data with different data types and when using expressions on columns in a predicate. Incorrect coding can prevent DB2 from using an available index. Further, an expression that unnecessarily masks a column comparison due to an expression (such as in the TRIM example) may prevent DB2 from using statistics on the column, potentially leading to a suboptimal cardinality estimate, which in turn can lead to an inefficient access plan.

Michael Sansoterra is a DBA for Broadway Systems in Grand Rapids, Michigan. He can be contacted at This email address is being protected from spambots. You need JavaScript enabled to view it..


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: