• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • Updating Through a Join with SQL, Take Two

    April 27, 2011 Hey, Ted

    I am studying your tip Updating through a Join with SQL, and something escapes me. I do not understand the redundancy in the first code example. Do all updates that involve joins have to have redundant code?

    –Ron

    I know it’s confusing, Ron. I can go into more detail for you.

    This is the example to which you refer:

    update customer as c
       set region =
          (select newregion
             from fixes
            where oldregion = c.region)
     where exists
          (select *
             from fixes
            where oldregion = c.region)
    

    You’re right that there is some redundancy. Both the SET and WHERE clauses of the UPDATE statement refer to the FIXES table.

             from fixes
            where oldregion = c.region)
    

    The direct answer to your question is “no”. Updates that involve joins do not necessarily have to have redundant code. It depends on what you wish to accomplish. If you want the UPDATE to change all records (rows) in the database file (table or view), then there is no need for a WHERE clause, because the purpose of the WHERE clause is to specify which rows are to be updated. But if you only want to update some of the rows, then yes, you must include a WHERE clause in the UPDATE statement.

    Let me illustrate.

    Suppose you have a master file of vendors that includes a vendor-type code. The code has never been loaded, but now you need to update the code based on a file that was created from a user’s spreadsheet. The master file is VENDORS. The file of updates is called VENDORUPDT, and it has two fields only: vendor ID number and type code. Let’s consider some scenarios.

    1. VENDORUPDT has a row for each vendor. All rows in VENDOR will be updated.

    In this case, there is no need for a WHERE clause in the UPDATE statement.

    update vendors as v1
       set v1.type =
             (select v2.type
                from vendorupdt as v2
               where v2.id = v1.id)
    

    2. VENDORUPDT does not have a row for some vendors. All rows in VENDOR will be updated. Vendors who are not referenced in VENDORUPDT will be given a null type code.

    Since all rows are to be updated, there is no WHERE clause in the UPDATE.

    update vendors as v1
       set v1.type =
             (select v2.type
                from vendorupdt as v2
               where v2.id = v1.id)
    

    3. VENDORUPDT does not have a row for some vendors. All rows in VENDOR will be updated. Vendors who are not referenced in VENDORUPDT will be given a type value of 2.

    Since all rows are to be updated, there is no WHERE clause in the UPDATE.

    update vendors as v1
       set v1.type = coalesce(
             (select v2.type
                from vendorupdt as v2
               where v2.id = v1.id), 2)
    

    4. VENDORUPDT does not have a row for some vendors. Rows in VENDOR will be updated only if they are found in VENDORUPDT.

    Since some rows will not be updated, the UPDATE needs a WHERE clause.

    update vendors as v1
       set v1.type = 
             (select v2.type
                from vendorupdt as v2
               where v2.id = v1.id)
     where v1.id in
           (select v3.id
              from vendorupdt as v3)
    

    5. VENDORUPDT does not have a row for some vendors. Rows in VENDOR will be updated only if they are found in VENDORUPDT and if they are located in the state of Mississippi.

    Since some rows will not be updated, the UPDATE needs a WHERE clause.

    update vendors as v1
       set v1.type = 
             (select v2.type
                from vendorupdt as v2
               where v2.id = v1.id)
     where v1.state = 'MS' 
       and v1.id in
           (select v3.id
              from vendorupdt as v3)
    

    Notice that the last two examples contain WHERE clauses, but not the redundancy you noticed in the example from the previous tip.

    To sum it up, the WHERE clause specifies which rows are to be updated. It may be redundant with the expression in SET, but it doesn’t have to be.

    –Ted

    RELATED STORIES

    Updating through a Join with SQL

    Update One File Based on Another File



                         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
    WorksRight Software

    Do you need area code information?
    Do you need ZIP Code information?
    Do you need ZIP+4 information?
    Do you need city name information?
    Do you need county information?
    Do you need a nearest dealer locator system?

    We can HELP! We have affordable AS/400 software and data to do all of the above. Whether you need a simple city name retrieval system or a sophisticated CASS postal coding system, we have it for you!

    The ZIP/CITY system is based on 5-digit ZIP Codes. You can retrieve city names, state names, county names, area codes, time zones, latitude, longitude, and more just by knowing the ZIP Code. We supply information on all the latest area code changes. A nearest dealer locator function is also included. ZIP/CITY includes software, data, monthly updates, and unlimited support. The cost is $495 per year.

    PER/ZIP4 is a sophisticated CASS certified postal coding system for assigning ZIP Codes, ZIP+4, carrier route, and delivery point codes. PER/ZIP4 also provides county names and FIPS codes. PER/ZIP4 can be used interactively, in batch, and with callable programs. PER/ZIP4 includes software, data, monthly updates, and unlimited support. The cost is $3,900 for the first year, and $1,950 for renewal.

    Just call us and we’ll arrange for 30 days FREE use of either ZIP/CITY or PER/ZIP4.

    WorksRight Software, Inc.
    Phone: 601-856-8337
    Fax: 601-856-9432
    Email: software@worksright.com
    Website: www.worksright.com

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    BCD:  FREE Webinar: New Presto 3 - The MOST flexible IBM i Web GUI for green screens. View NOW!
    Vision Solutions:  Real-Time Database Sharing: What Can It Do for Your Business? FREE White Paper!
    COMMON:  Join us at the 2011 Conference & Expo, May 1 - 4 in Minneapolis, MN

    IT Jungle Store Top Book Picks

    BACK IN STOCK: Easy Steps to Internet Programming for System i: List Price, $49.95

    The iSeries Express Web Implementer's Guide: List Price, $49.95
    The iSeries Pocket Database Guide: List Price, $59
    The iSeries Pocket SQL Guide: List Price, $59
    The iSeries Pocket WebFacing Primer: List Price, $39
    Migrating to WebSphere Express for iSeries: List Price, $49
    Getting Started with WebSphere Express for iSeries: List Price, $49
    The All-Everything Operating System: List Price, $35
    The Best Joomla! Tutorial Ever!: List Price, $19.95

    Jamaica Port Authority Revs IT Systems to Handle More Traffic IBM Is Prepping Power7+ and Pondering Power8

    One thought on “Updating Through a Join with SQL, Take Two”

    • John Patterson says:
      January 30, 2019 at 5:50 pm

      As a SQL Server loyalist, I’ve been struggling with DB2’s seeming inability to update a table with information from another table–the update with join that’s so easy in SSMS.

      I finally discovered a workaround that functions perfectly instead: the MERGE statement. I usually find IBM’s support data impenetrable, but the explanation at their MERGE website was actually quite clear: https://www.ibm.com/support/knowledgecenter/en/ssw_ibm_i_71/sqlp/rbafymerge.htm

      Hope this helps you as much as it did me.

      Reply

    Leave a Reply Cancel reply

Volume 11, Number 14 -- April 27, 2011
THIS ISSUE SPONSORED BY:

ProData Computer Services
SEQUEL Software
COMMON

Table of Contents

  • DDS Design with RD Power
  • Updating Through a Join with SQL, Take Two
  • Why is my i/OS Email Coming Back Undeliverable?

Content archive

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

Recent Posts

  • Meet The Next Gen Of IBMers Helping To Build IBM i
  • Looks Like IBM Is Building A Linux-Like PASE For IBM i After All
  • Will Independent IBM i Clouds Survive PowerVS?
  • Now, IBM Is Jacking Up Hardware Maintenance Prices
  • IBM i PTF Guide, Volume 27, Number 24
  • Big Blue Raises IBM i License Transfer Fees, Other Prices
  • Keep The IBM i Youth Movement Going With More Training, Better Tools
  • Remain Begins Migrating DevOps Tools To VS Code
  • IBM Readies LTO-10 Tape Drives And Libraries
  • IBM i PTF Guide, Volume 27, Number 23

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