04
Sat, May
5 New Articles

TechTip: It's Easy to Join If You Know How to Chain

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

RPG programmers are quite familiar with the CHAIN op code. COBOL programmers are equally as familiar with the random READ by key. However, many iSeries programmers are not so familiar with SQL's ability to join files. Recent conversations with other professional programmers have shown me that joins can be confusing. There are several types of joins, and sometimes programmers are not sure which type to use under what circumstances. My conviction is this: If you can understand RPG's CHAIN operation (or COBOL's READ by key), you can understand joins.

Join Types

SQL supports several types of joins, depending on the implementation. For the iSeries, joins can be divided into three broad categories.

  • Inner joins produce results only when the values of the join fields of the primary file match the values of the join fields of at least one record in the secondary file.
  • Outer joins return the records from the primary file, even if there are no matching records in the secondary file.
  • Exception joins return the records from the primary file that do not have matching values in the secondary file.

Matches are usually based on equality (e.g., the customer number in an invoice file matches the customer number in the customer master file), but you may use any relational operator.

The Decision

When you program with record-oriented op codes, the question you must ask yourself is "What do I want to do if a CHAIN (random READ) fails?" You have two options: You can abort the processing of the primary record, or you can continue processing the primary file record but without valid data from the secondary file. For example, suppose you are reading a file of invoices. Each time you read an invoice record, you CHAIN to a customer master file to retrieve the customer's name and address. If the CHAIN fails, you may immediately skip to the next invoice or you may continue to process the invoice without valid customer data.

This is the same decision you must make when you join files. What do you want to do if no matching secondary file record is found? The answer to that question determines the type of join you must use.

If you want to abort processing of the current primary record, use an inner join. If you want to continue to process the current primary record without valid data from the secondary file, use a left outer join. If you want to process primary records only when the CHAIN fails, use an exception join.

I can illustrate the three joins with RPG programs and SQL commands that provide equivalent functions. First, however, here are the three tables (database files) that these examples use.

Orders
ID  CUSTID
O1    C1
O2    C3
O3    C4
O4    C1
O5    C1
O6    C3
O7    C1

Customers
ID  NAME
C1  CUST ONE
C2  CUST TWO
C3  CUST THREE

Omissions
ORDERID
  O4
  O6

In the following short RPG example, order records (from the primary file) print only if the customer number associated with an order matches a record in the customer master file (the secondary file).

 H AlwNull(*UsrCtl)

 FOrders    IF   E           K Disk    Prefix(O_)
 F                                     Rename(orders: OrderRec)
 FCustomers IF   E           K Disk    Prefix(C_)
 F                                     Rename(Customers: CustRec)
 FMCPReport O    E             Printer Prefix(R_)

 C                   Dow       '1'               
 C                   Read      OrderRec          
 C                   If        %EOF()            
 C                   Leave                       
 C                   EndIf                       
 C     O_CustID      Chain     CustRec           
 C                   If        not %found()      
 C                   Iter                        
 C                   EndIf                       
 C                   Eval      R_Order = O_ID    
 C                   Eval      R_Cust = O_CustID 
 C                   Eval      R_Name = C_Name   
 C                   Write     Detail            
 C                   EndDo                       
 C                   Eval      *InLR = *on

Here's the equivalent SQL inner join.

select o.id, o.custid, c.name
    from orders as o
    inner join customers as c
    on o.custid = c.id

And these are the results from the RPG program and the SQL query.

ID  CUSTID  NAME
O1    C1    CUST ONE
O2    C3    CUST THREE
O4    C1    CUST ONE
O5    C1    CUST ONE
O6    C3    CUST THREE
O7    C1    CUST ONE

Notice that order O3 was not included in the output because customer C4 was not found in the customers file.

In the second example, each order prints whether the customer number is found in the customer master file or not.

 H AlwNull(*UsrCtl)

 FOrders    IF   E           K Disk    Prefix(O_)
 F                                     Rename(orders: OrderRec)
 FCustomers IF   E           K Disk    Prefix(C_)
 F                                     Rename(Customers: CustRec)
 FMCPReport O    E             Printer Prefix(R_)

 C                   Dow       '1'                    
 C                   Read      OrderRec               
 C                   If        %EOF()                 
 C                   Leave                            
 C                   EndIf                            
 C     O_CustID      Chain     CustRec                
 C                   If        not %found()           
 C                   Eval      C_Name = '**UNKNOWN**' 
 C                   EndIf                            
 C                   Eval      R_Order = O_ID         
 C                   Eval      R_Cust = O_CustID      
 C                   Eval      R_Name = C_Name        
 C                   Write     Detail                 
 C                   EndDo                            
 C                   Eval      *InLR = *on

Since all records from the primary file should print, use a left outer join in SQL.

select o.id, o.custid,
       ifnull(c.name, '**UNKNOWN**')
   from orders as o
   left outer join customers as c
   on o.custid = c.id

Here are the results:

 ID  CUSTID  IFNULL
 O1    C1    CUST ONE
 O2    C3    CUST THREE
 O3    C4    **UNKNOWN**
 O4    C1    CUST ONE
 O5    C1    CUST ONE
 O6    C3    CUST THREE
 O7    C1    CUST ONE

Order O3 was included. Since there was no valid data for customer C4 in the customers file, both the RPG program and the SQL query used the value **UNKNOWN** in place of a customer name.

In the final example, we include a file of omissions--orders that are not to be printed on the report. That is, an order is selected for print only if the CHAIN to the omissions file fails.

 H AlwNull(*UsrCtl)

 FOrders    IF   E           K Disk    Prefix(O_)
 F                                     Rename(orders: OrderRec)
 FCustomers IF   E           K Disk    Prefix(C_)
 F                                     Rename(Customers: CustRec)
 FOmissions IF   E           K Disk    Prefix(M_)
 F                                     Rename(Omissions: OmitRec)
 FMCPReport O    E             Printer Prefix(R_)


 C                   Dow       '1'                    
 C                   Read      OrderRec               
 C                   If        %eof()                 
 C                   Leave                            
 C                   EndIf                            
 C     O_ID          Chain     OmitRec                
 C                   If        %found()               
 C                   Iter                             
 C                   EndIf                            
 C     O_CustID      Chain     CustRec                
 C                   If        not %found()           
 C                   Eval      C_Name = '**UNKNOWN**' 
 C                   EndIf                            
 C                   Eval      R_Order = O_ID         
 C                   Eval      R_Cust = O_CustID      
 C                   Eval      R_Name = C_Name        
 C                   Write     Detail                 
 C                   EndDo
 C                   Eval      *InLR = *on

This calls for an exception join in SQL.

select o.id, o.custid,
       ifnull(c.name, '**UNKNOWN**')
   from orders as o
   exception join omissions as m
   on o.id = m.orderid
   left outer join customers as c
   on o.custid = c.id

And these are the results of the program and the SQL query:

 ID  CUSTID  IFNULL
 O1    C1    CUST ONE
 O2    C3    CUST THREE
 O3    C4    **UNKNOWN**
 O5    C1    CUST ONE
 O7    C1    CUST ONE

Notice that there are two different joins--an exception join and a left outer join--in this query. We only print orders that do not appear in the Omissions file, but once we have selected an order record, we print it even if the customer number is unmatched.

Rule of Thumb

When trying to decide which type of join to use, think about what you would do if you were using RPG or COBOL and a random read operation were to fail.

James Gates has spent most of the past 15 years working with AS/400 and iSeries systems.

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$0.00 Raised:
$

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: