• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • The Case of the Missing Logical File

    May 18, 2011 Hey, Mike

    I created a logical file that combines multiple tables into a single result set (similar to a SQL UNION.) However, when Microsoft Excel’s Query Wizard presents a list of available tables and views to query, this logical file does not show up in the list. What is the problem?

    Suzy

    Hi, Suzy:

    The problem is that DB2 for i is classifying your logical file as a non-relational file. It turns out that the Microsoft Excel Query Wizard uses ODBC (or OLE DB for Excel 2007 and later) to access DB2 for i. When tools like the Query Wizard and Crystal Reports ask DB2 for i for a list of available “tables” it can use, the results are retrieved from the QSYS2.SYSTABLES catalog. The special type of “union” logical files you mention are not included in this catalog. I’m guessing part of the reason for this exclusion is that these hierarchical logical files can potentially have multiple record types (which SQL doesn’t handle).

    For readers unfamiliar with the syntax, here is a simple source code example of how to create a logical file that spans multiple tables (this example assumes that the field names are the same in both files):

    R PRODUCT                   PFILE(PRODUCT PRODUCT2)
    K NAME
    

    The best way to combine multiple tables into a single result set is to use SQL to create a VIEW with the UNION ALL operator. UNION ALL will do the same thing you are trying to accomplish with your logical file by combining two underlying tables in a single result.

    Here is a sample view:

    CREATE VIEW MYLIB/PRODUCTS AS
    (SELECT * FROM MYLIB/PRODUCT
     UNION ALL
     SELECT * FROM MYLIB/PRODUCT2)
    

    The one thing that the logical file can provide that the view can’t is a keyed access path. If the underlying tables in the view already have indexes on the proper columns, SQL will be smart enough to use them when it queries the view. If the underlying tables do not have an index on the desired columns and if there is a sufficiently large number of rows, you’ll want to build indexes on these columns (for each table in the view) using the SQL CREATE INDEX statement.

    In the LF example above, the logical file created an access path on the NAME column across both tables. In SQL, the approximate equivalent would be to create indexes on the NAME column for each underlying table:

    CREATE INDEX MYLIB/IDX_PRODUCT_NAME ON MYLIB/PRODUCT (NAME)
    CREATE INDEX MYLIB/IDX_PRODUCT2_NAME ON MYLIB/PRODUCT2 (NAME)
    

    Functionally the view and the LF will be about the same. However, SQL is the way of the future and the VIEW will be available in the list of tables and views that Microsoft Query and other tools present to users. Further, queries that use this view can also potentially be routed for processing to the newer SQL Query Engine (SQE).

    –Mike

    Michael Sansoterra is a DBA for Broadway Systems in Grand Rapids, Michigan. Send your questions or comments for Mike via the IT Jungle Contact page.



                         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
    Midrange Dynamics North America

    Git up to speed with MDChange!

    Git can be lightning-fast when dealing with just a few hundred items in a repository. But when dealing with tens of thousands of items, transaction wait times can take minutes.

    MDChange offers an elegant solution that enables you to work efficiently any size Git repository while making your Git experience seamless and highly responsive.

    Learn more.

    Share this:

    • Reddit
    • Facebook
    • LinkedIn
    • Twitter
    • Email

    Sponsored Links

    SEQUEL Software:  View the recorded Webinar: 10 Ways SEQUEL Makes Developers More Productive
    CNX:  Ready to develop true Web 2.0 applications? Valence Version 3.0 BETA 1 is now available
    looksoftware:  FREE Webcast: RPG Open Access Demystified. June 7 (Europe) & June 8 (USA)

    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

    Magic Kicks Off Mobile Application Push IBM i Chief Architect Tells Us Where We’re At

    Leave a Reply Cancel reply

Volume 11, Number 16 -- May 18, 2011
THIS ISSUE SPONSORED BY:

WorksRight Software
CNX
Botz & Associates, Inc.

Table of Contents

  • An Introduction to Python on IBM i, Part 3
  • The Case of the Missing Logical File
  • Admin Alert: Running System i Cleanup Manually

Content archive

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

Recent Posts

  • Public Preview For Watson Code Assistant for i Available Soon
  • COMMON Youth Movement Continues at POWERUp 2025
  • IBM Preserves Memory Investments Across Power10 And Power11
  • Eradani Uses AI For New EDI And API Service
  • Picking Apart IBM’s $150 Billion In US Manufacturing And R&D
  • FAX/400 And CICS For i Are Dead. What Will IBM Kill Next?
  • Fresche Overhauls X-Analysis With Web UI, AI Smarts
  • Is It Time To Add The Rust Programming Language To IBM i?
  • Is IBM Going To Raise Prices On Power10 Expert Care?
  • IBM i PTF Guide, Volume 27, Number 20

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