02
Sat, Nov
2 New Articles

TechTip: DB2's CONNECT BY Simplifies Recursive Processing

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

At first glance, recursion appears to be a computer science method that's relevant only in the world of academia.

 

Recursion is a great for traversing linked lists or generating the numbers of a Fibonacci sequence, but recursion can't be applied to business problems…or can it? 


In reality, there are several industries where data elements have inherent relationships with other elements, and the best way to connect these data elements is with recursive (or hierarchical) processing. The classic example is the generation of a bill of materials explosion in the manufacturing industry. A bill of materials explosion breaks apart each assembly or sub-assembly into its component parts.

 

Now that you understand that recursion has applicability to the business world, why would a database like DB2 need to support recursion? The reason is that these data elements with inherent relationships are often stored in tables. Based on this fact, it makes sense for DB2 to provide functionality to make it easy to navigate these data relationships, as opposed to forcing programmers to write a program that manually navigates data hierarchies.

 

DB2 for i has actually provided this capability since the V5R4 release with an SQL feature known as "recursive common table expressions." The following code contains an example of a query using the recursive common table expression to navigate an organizational hierarchy. While recursive common table expressions have helped IBM i developers solve business problems, you can see from the example query below that the solution is complex.

 

  WITH emp_list (level, empid, name) AS

         SELECT 1, empid, name  FROM emp

             WHERE name = 'Carfino'

          UNION ALL

         SELECT o.level+1, next_layer.empid, next_layer.name

             FROM emp as next_layer, emp_list o

             WHERE o.empid = next_layer.mgrid )

   SELECT level, name FROM emp_list

 

The good news is that the DB2 for i 7.1 release addresses the complexity issue with a new CONNECT BY clause. The CONNECT BY clause enables a query to process recursive relationships and hierarchical data with much simpler syntax. Usage of the CONNECT BY support requires level 9 or greater of the IBM i 7.1 Database Group PTF to be installed. This requirement is documented in the DB2 for i Technology Updates wiki.

 

Let's walk through an example of traversing the organizational chart in Figure 1 to better understand the complexity of the CONNECT BY support. For this example, a program must return a list of the employees that are in the organization led by a manager named Carfino.

 

041312Milligan_CB_Fig2

Figure 1: This sample org chart helps to explain CONNECT BY support.

 

The organizational data from Figure 1 is stored in a DB2 table named EMP. The code below contains the table definition for the EMP table.

 

CREATE TABLE emp(

                   empid INTEGER PRIMARY KEY,

                   name  VARCHAR(10),

                   salary DECIMAL(9, 2),

                   mgrid INTEGER)

 

The first step when creating a recursive or hierarchical query is to identify the columns that logically link together two rows of a data. In this example, the columns are the empid and mgrid columns. The direct reports of Carfino will be found by finding those employees that have a mgrid value that is equal to the employee id value for Carfino. Once those linking or connecting columns are identified, those are the column names specified on the CONNECT BY clause, as you can see in this SELECT statement: 

 

SELECT LEVEL, name

   FROM emp

 START WITH name = 'Carfino'

 CONNECT BY mgrid = PRIOR empid

 

This CONNECT BY clause directs DB2 to find an employee row whose mgrid column matches the employee id value of the prior employee. The first prior employee is Carfino due to the search predicate specified on the START BY clause. Thus, the first pass of this recursive process would identify the employees named Davis and Payne. The second recursive iteration would then find the employees that work for Davis and Payne: Lohaus, Brookins, Horton, Bullard, Settles. The recursive processing would end with the list of employees that are managed by Davis and Payne because those employees are not managers. The employee id value for Lohaus would never show up in the mgrid column for any row in the EMP table.

 

The results produced by the SELECT statement are contained in Figure 2. The recursive query successfully returned the name of every employee who works in Carfino's section of the organizational chart. The Level value in the result set is produced by the LEVEL pseudo-column in the SELECT statement. The LEVEL pseudo-column returns the recursive step that produced the row. The rows produced by the START BY clause will always have a level value of 1, and then each recursive iteration increments the level value. The LEVEL pseudo-column can only be used in conjunction with the CONNECT BY clause. As you can see in the first bit of code in this TechTip, the level value has to be manually generated when using the recursive common table expression query.

 

041312Milligan_CB_Fig3 

Figure 2: This is the output of the recursive query.

 

The CONNECT BY support in IBM i 7.1 includes additional syntax and options that aren't discussed here. Consult the DB2 for i 7.1 SQL Reference for additional details.

 

Hopefully, this simple organizational chart example has demonstrated the relevance of recursion and shown how easy it is to process data hierarchies and relationships with the CONNECT BY clause.

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: