• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • ON vs. WHERE

    November 14, 2007 Hey, Ted

    I need your help with an SQL query. I have two database files: a header file and a detail file. There may be many detail records for each header record, but I only want to see certain detail records. Here’s the rub. I want to retrieve all header records, even the headers for which I don’t select any corresponding detail. It seems to me this should be an easy query to write, but my efforts so far produce only the header records for the selected details.

    –Wayne

    There’s more to this query than meets the eye, Wayne. It is simple, once you understand the difference between WHERE and ON.

    Here’s an invoice header table we can play with:

    SELECT H.* FROM INVHDR AS H
    
    Invoice  Company   Customer      Date
    47566      1           44     2004-05-03
    47567      2            5     2004-05-03
    47568      1        10001     2004-05-03
    47569      7          777     2004-05-03
    47570      7          777     2004-05-04
    47571      2            5     2004-05-04
    

    Here’s the related details table:

    SELECT D.* FROM INVDTL AS D
    
    Invoice   Line   Item      Price  Quantity
    47566      1     AB1441    25.00      3
    47566      2     JJ9999    20.00      4
    47567      1     DN0120      .35    800
    47569      1     DC2984    12.50      2
    47570      1     MI8830      .10     10
    47570      2     AB1441    24.00    100
    47571      1     AJ7644    15.00      1
    

    Here’s the query as Wayne was running it:

    SELECT H.INVOICE, H.COMPANY, H.CUSTNBR, H.INVDATE,
           D.LINE, D.ITEM, D.QTY                      
      FROM INVHDR AS H                                
      LEFT JOIN INVDTL AS D                           
        ON H.INVOICE = D.INVOICE                      
     WHERE D.ITEM = 'AB1441'                          
    
    Invoice Company Customer   Date     Line  Item   Quantity
    47566       1       44   2004-05-03   1   AB1441     3
    47570       7      777   2004-05-04   2   AB1441   100
    

    I’ve selected the details for item AB1441 only. The problem is that I only have header information for the orders that include those items. Wayne wants header information for all orders.

    The solution is to move the selection expression from the WHERE clause into the ON clause, like this:

    SELECT H.INVOICE, H.COMPANY, H.CUSTNBR, H.INVDATE,
           D.LINE, D.ITEM, D.QTY                      
      FROM INVHDR AS H                                
      LEFT JOIN INVDTL AS D                           
        ON H.INVOICE = D.INVOICE                      
       AND D.ITEM = 'AB1441'                          
    
    Invoice Company Customer   Date     Line  Item   Quantity
    47566       1       44   2004-05-03   1  AB1441      3 
    47567       2        5   2004-05-03   -  -           -
    47568       1    10001   2004-05-03   -  -           -
    47569       7      777   2004-05-03   -  -           -
    47570       7      777   2004-05-04   2  AB1441    100 
    47571       2        5   2004-05-04   -  -           -
    

    Why the difference? The WHERE clause runs after the join has taken place. That is, the database engine joins the tables to produce a result set, then applies the WHERE clause to select the joined records that contain item AB1441. This has the effect of turning an outer join into an inner join.

    The ON clause, on the other hand, runs during the join. It causes the database engine to select only the detail records that include item AB1441, then joins the selected detail records to the header records using a left outer join. The result is that we still get the left outer join we wanted, yet we only see the detail records we selected. Nifty, huh?

    Moving the detail record selection from WHERE to ON is not the only way to produce the desired results. You can explicitly select only the detail records you want by placing a SELECT clause inside the join, like this:

    SELECT H.INVOICE, H.COMPANY, H.CUSTNBR, H.INVDATE,
           D.LINE, D.ITEM, D.QTY                      
      FROM INVHDR AS H                                
      LEFT JOIN (SELECT *                             
                   FROM INVDTL                        
                  WHERE ITEM = 'AB1441') AS D         
        ON H.INVOICE = D.INVOICE                      
    



                         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
    New Generation Software

    “Fixing Your Data Supply Chain”

    FREE Webinar

    You’ve optimized your business processes, products and services, but is there still a logistics gap between your data and your managers and analysts?

    See how NGS-IQ simplifies query, reporting, data visualization, and analytics tasks. Enjoy Microsoft 365 integration, multidimensional modeling, built-in email, and FTP – with IBM i security and performance.

    October 23, 2025, 11am Pacific/2pm Eastern

    RSVP: https://ngsi.news/chain

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    ARCAD Software:  Dynamic, world-class ALM on and around the System i
    COMMON:  Join us at the annual 2008 conference, March 30 - April 3, in Nashville, Tennessee
    NowWhatJobs.net:  NowWhatJobs.net is the resource for job transitions after age 40

    IT Jungle Store Top Book Picks

    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 Developers' 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
    iSeries Express Web Implementer's Guide: List Price, $59.00
    Getting Started with WebSphere Development Studio for iSeries: List Price, $79.95
    Getting Started With WebSphere Development Studio Client for iSeries: List Price, $89.00
    Getting Started with WebSphere Express for iSeries: List Price, $49.00
    WebFacing Application Design and Development Guide: List Price, $55.00
    Can the AS/400 Survive IBM?: List Price, $49.00
    The All-Everything Machine: List Price, $29.95
    Chip Wars: List Price, $29.95

    Oracle Launches ‘Business Accelerator’ for J.D. Edwards EnterpriseOne Be My Guest

    Leave a Reply Cancel reply

Volume 7, Number 40 -- November 14, 2007
THIS ISSUE SPONSORED BY:

ProData Computer Services
COMMON
WorksRight Software

Table of Contents

  • ON vs. WHERE
  • Odds and Ends
  • Admin Alert: How Big is My IFS?

Content archive

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

Recent Posts

  • Positive News From The Kyndryl Mainframe Modernization Report
  • NAViGATE, inPower 2025 On Tap for September 2025
  • Guru: WCA4i And Granite – Because You’ve Got Bigger Things To Build
  • As I See It: Digital Coup
  • IBM i PTF Guide, Volume 27, Number 37
  • AI Is Coming for ERP. How Will IBM i Respond?
  • The Power And Storage Price Wiggling Continues – Again
  • LaserVault Adds Multi-Path Support To ViTL
  • As I See It: Spacing Out
  • IBM i PTF Guide, Volume 27, Numbers 34, 35, And 36

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