• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • Update One File Based on Another File

    April 14, 2010 Ted Holt

    It’s not uncommon to have to update one file based on data found in another file. In fact, it’s a very common requirement, due to the way that data is “normalized” in relational database management systems. When only one field links the two files–the file that is being updated and the file that contains the search criteria–the SQL syntax is simple. But joining on two or more fields requires more challenging syntax.

    Here’s an example of an update when only one field joins the two files. I add a week to the scheduled ship date of orders of type B customers.

    update salesordh
       set shipdate = shipdate + 7 days
     where customerno in
             (select customerno
                from customers
               where type = 'B')
    

    Since the sales order header file and customer master file share only one common field–customer number–a simple IN expression does the trick.

    But suppose the two files join on two fields–company number and customer number. What then?

    The traditional method is to use the EXISTS construct.

    update salesordh as h
       set shipdate = shipdate + 7 days
     where exists 
       (select *
          from customers as c
         where type = 'B'
           and c.companyno  = h.companyno
           and c.customerno = h.customerno)
    

    EXISTS proves true if the SELECT that follows it returns at least one row (record). For each row of the sales order header file, SALESORDH, the system looks to see if there is at least one type B customer with the same company number and customer number in the customer master file. If at least one row is found, the sales order header record is updated.

    If you are V5R4 or above, you have a simpler option–you can use a row value expression.

    update salesordh
       set shipdate = shipdate + 7 days
     where (companyno, customerno) in
              (select companyno, customerno
                 from customers
                where type = 'B')
    

    Row value expressions let you compare two lists of values to one another. In this example, the company number-customer number combination of a sales record are compared to the set of all company number-customer order combinations from the type B customers.

    Thanks to row value expressions, I have jettisoned the non-intuitive EXISTS and returned to the simple IN of the first example!



                         Post this story to del.icio.us
                   Post this story to Digg
        Post this story to Slashdot

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Tags:

    Sponsored by
    Computer Keyes

    Fax Directly from your IBM i

    KeyesFax is a full function automated IBM i fax system. Spooled files are burst by fax number and auto transmitted with overlays.  It combines both a send and receive facsimile processing system with a complete image package.

    The fax software will edit, send, receive, display, print, and track fax documents or images using any standard IBM i without additional expensive hardware, software or subscriptions.

    Computer Keyes has been developing Software Solutions since 1978!

    www.computerkeyes.com

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    BCD:  April 21 Webinar - Web enable your IBM i programs & satisfy end-users
    inFORM Decisions:  Paperless saves $$$. Learn more and get FREE white papers.
    COMMON:  Join us at the annual 2010 conference, May 3 - 6, in Orlando, Florida

    IT Jungle Store Top Book Picks

    Easy Steps to Internet Programming for AS/400, iSeries, and System i: List Price, $49.95
    The iSeries Express Web Implementer's Guide: List Price, $49.95
    The System i RPG & RPG IV Tutorial and Lab Exercises: List Price, $59.95
    The System i Pocket RPG & RPG IV Guide: List Price, $69.95
    The iSeries Pocket Database Guide: List Price, $59.00
    The iSeries Pocket SQL Guide: List Price, $59.00
    The iSeries Pocket Query Guide: List Price, $49.00
    The iSeries Pocket WebFacing Primer: List Price, $39.00
    Migrating to WebSphere Express for iSeries: List Price, $49.00
    Getting Started With WebSphere Development Studio Client for iSeries: List Price, $89.00
    Getting Started with WebSphere Express for iSeries: List Price, $49.00
    Can the AS/400 Survive IBM?: List Price, $49.00
    Chip Wars: List Price, $29.95

    Systems Director Express for X86 Keeps an Eye on Heat and Power Usage IBM’s Power7 Blades Pack a CPW Punch

    Leave a Reply Cancel reply

Volume 10, Number 13 -- April 14, 2010
THIS ISSUE SPONSORED BY:

SEQUEL Software
WorksRight Software
Halcyon Software

Table of Contents

  • Query Control
  • Update One File Based on Another File
  • Admin Alert: Some Simple Ideas for Getting the Best System i Lease

Content archive

  • The Four Hundred
  • Four Hundred Stuff
  • Four Hundred Guru

Recent Posts

  • With Power11, Power Systems “Go To Eleven”
  • With Subscription Price, IBM i P20 And P30 Tiers Get Bigger Bundles
  • Izzi Buys CNX, Eyes Valence Port To System Z
  • IBM i Shops “Attacking” Security Concerns, Study Shows
  • IBM i PTF Guide, Volume 27, Number 26
  • Liam Allan Shares What’s Coming Next With Code For IBM i
  • From Stable To Scalable: Visual LANSA 16 Powers IBM i Growth – Launching July 8
  • VS Code Will Be The Heart Of The Modern IBM i Platform
  • The AS/400: A 37-Year-Old Dog That Loves To Learn New Tricks
  • IBM i PTF Guide, Volume 27, Number 25

Subscribe

To get news from IT Jungle sent to your inbox every week, subscribe to our newsletter.

Pages

  • About Us
  • Contact
  • Contributors
  • Four Hundred Monitor
  • IBM i PTF Guide
  • Media Kit
  • Subscribe

Search

Copyright © 2025 IT Jungle