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