drop down joomla login module

TechTip: DB2 for i Optimization Strategies, Part 1

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

Avoid common SQL programming mistakes that can drag application performance.

 

As databases grow larger over time, users and administrators often witness a decrease in performance. A query that once performed well when it was first written eventually becomes lethargic. In this series of tips, I will discuss some common goofs that can take the wind out of your database sails.

 

To begin, let’s look at some general SQL coding guidelines that need attention. They are given in no particular order, but they do reflect my experience in working with DB2 for i and SQL Server environments. The benefit you may get when following these recommendations will vary based on a number of factors, including the number of rows in a table, complexity of the overall query, indexes, DB2 version, number of query invocations, etc. Before making changes in a production environment, be sure to review and test thoroughly.

 

Use UNION ALL Instead of UNION Where Appropriate

The UNION and UNION ALL operators are very similar as they are both operators used to combine multiple row sets into one. The only difference is that UNION is shorthand for UNION DISTINCT, which means that when combining the rows of multiple queries, DB2 has to sort them and weed out the non-unique rows. However, if the row sets being combined will never have duplicate values between them, then it’s a waste of CPU and memory resources to have DB2 attempt to locate and filter out duplicates.

 

Consider the following query that combines two queries using UNION (TransactionHistory and TransactionHistoryArchive tables):

 

SELECT TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

FROM TRANSACTIONHISTORYARCHIVE

WHERE TRANSACTIONTYPE='S'

   AND TRANSACTIONDATE BETWEEN '2007-01-01' AND '2007-03-31'

UNION

SELECT TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

FROM TRANSACTIONHISTORY

WHERE TRANSACTIONTYPE='S'

   AND TRANSACTIONDATE BETWEEN '2008-01-01' AND '2008-03-31'

ORDER BY TRANSACTIONDATE,PRODUCTID

 

Assuming the TRANSACTIONID column is an identity column unique within each table, can you identify why the UNION (implied DISTINCT) operator is unnecessary? The answer is because the WHERE clause predicates guarantee that the transaction dates in the result sets will never overlap. Rows from the top query will be for Q1 2007, and rows from the bottom query are from Q1 2008. Therefore, UNION ALL should be used to save DB2 an unnecessary step in trying to identify and remove duplicate rows.

 

An amusingly simple way to determine if UNION ALL should be used instead of UNION is to observe different literal values between the queries that will guarantee the rows in the result sets will not overlap. In this example, a column expression named SOURCE is used to identify the source of the transactions (Open/Archive):

 

SELECT 'Archive' AS SOURCE,

       TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

   FROM TRANSACTIONHISTORYARCHIVE

WHERE TRANSACTIONDATE BETWEEN '2008-01-01' AND '2008-03-31'

UNION

SELECT 'Open' AS SOURCE,

       TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

   FROM TRANSACTIONHISTORY

WHERE TRANSACTIONDATE BETWEEN '2008-01-01' AND '2008-03-31'

ORDER BY TRANSACTIONDATE,PRODUCTID

 

To repeat, assuming that each query will return a unique set of rows (not having duplicates), there’s no need to have DB2 work to create distinct rows, because the differing literals will guarantee that there are no duplicate rows among the sets.

 

Sometimes it’s not as easy to identify whether or not UNION or UNION ALL should be used. If TRANSACTIONID is not an identity column and there is not a PRIMARY KEY/UNIQUE constraint on the table (or a SEQUENCE shared between the tables), it’s difficult to tell if there could be duplicate transaction rows among the queries:

 

SELECT TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

   FROM TRANSACTIONHISTORYARCHIVE

WHERE TRANSACTIONDATE>='2015-01-01'

UNION

SELECT TRANSACTIONID,TRANSACTIONDATE,PRODUCTID,

       TRANSACTIONTYPE,QUANTITY,ACTUALCOST

   FROM TRANSACTIONHISTORY

WHERE TRANSACTIONDATE>='2015-01-01'

ORDER BY TRANSACTIONDATE,PRODUCTID

 

In this case, some research is needed before changing UNION to UNION ALL. If you examine the code and find that a single SEQUENCE is used to populate the TransactionID columns in both tables (and confirm with a query), then you can conclude there are no duplicates and exchange the UNION with UNION ALL. Otherwise, it’s often safest to assume the original developer used UNION for a reason and leave it as is.

 

Where Possible, Avoid Changing the Same Data Multiple Times

Shown below is a common example of two UPDATE statements that do almost the same thing. ORDER_DETAIL information is aggregated for a single order and is used to update the ORDER_HEADER table:

 

UPDATE ORDER_HEADER OH

SET ORDER_AMOUNT=

(SELECT SUM(SALE_PRICE)

   FROM ORDER_DETAIL OD

WHERE OD.ORDER_ID=OH.ORDER_ID)

WHERE OH.ORDER_ID=@ORDER_ID;

UPDATE ORDER_HEADER OH

SET LAST_SHIP_DATE=

(SELECT MAX(SHIP_DATE)

   FROM ORDER_DETAIL OD

WHERE OD.ORDER_ID=OH.ORDER_ID)

WHERE OH.ORDER_ID=@ORDER_ID;

 

This code vexes my soul because the two statements can be combined into one using a row expression:

 

UPDATE ORDER_HEADER OH

SET (ORDER_AMOUNT,LAST_SHIP_DATE)=

   (SELECT SUM(SALE_PRICE),MAX(SHIP_DATE)

       FROM ORDER_DETAIL OD

     WHERE OD.ORDER_ID=OH.ORDER_ID)

WHERE OH.ORDER_ID=@ORDER_ID;

 

The benefit of this is that the data from ORDER_DETAIL is read only once, DB2 doesn’t need to acquire locks multiple times, only one entry is logged if journaling is active, and further if there is an update trigger on the ORDER_HEADER table, it is only executed once. Although this is a simple example, minimizing work for DB2 will yield performance benefits.

 

Examine Your Code

Many times, developers churn out code in a heartbeat, and because the data sets are often small, the database code appears to perform well. Over time, suboptimal queries can take their toll on the database engine. Therefore, it pays to review code to foster good coding habits and also to insure an application will perform well as time goes by.

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

  •  

  • 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.

  • 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

  • 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: