• The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
Menu
  • The Four Hundred
  • Subscribe
  • Media Kit
  • Contributors
  • About Us
  • Contact
  • Load a Spreadsheet from a DB2/400 Database: Part 3

    January 28, 2009 Michael Sansoterra

    Note: The code accompanying this article is available for download here.

    Part 1 and Part 2 of this little series on generating an Excel spreadsheet demonstrated how to use Visual Basic for Applications (VBA) code to retrieve data from DB2 on an AS/400 and place it in a spreadsheet. Additional refinements were offered on doing some fancier things to the spreadsheet, such as auto-sizing all the columns based on the loaded data, formatting date columns properly, etc. All of this was done in the name of programmatically creating a nice spreadsheet with current “DB2 for i” data. This tip is going to add one little tidbit to the mix. I want to address how to populate multiple worksheets within a single workbook.

    For example, say the purchasing department requests an Excel based report with the following information:

    1. The top 10 vendors who have the highest percentage of rejected received items
    2. The top 10 vendors who had the largest orders (in terms of quantity purchased)
    3. The top 10 products (in terms of quantity purchased)

    Following are three SQL queries to go with the above requests. (For the record, I exported Microsoft’s Adventure Works data to DB2 for this demo.)

    Query 1–Top Rejects

    Select PO.VendorId,AccountNumber,Name,OrderQty,RejectQty,
           AvgRejectRate
      From (
    Select VendorId,Sum(OrderQty) As OrderQty,
                    Sum(RejectedQty) As RejectQty,
                    Count(*)As Lines,
                    Sum(RejectedQty)/Count(*)As AvgRejectRate
      From PurchaseOrderDetail D
      Join PurchaseOrderHeader H On H.PurchaseOrderId=D.PurchaseOrderId
    Group By VendorId 
    ) PO
      Join Vendor PV On  PV.VendorId=PO.VendorId
      Order By AvgRejectRate Desc
    Fetch First 10 Rows Only
    

    Query 2–Top Vendor Purchases (in Qty terms)

    Select PO.VendorId,AccountNumber,Name,OrderQty
      From (
    Select VendorId,Sum(OrderQty) As OrderQty,
                    Count(*)As Lines
      From PurchaseOrderDetail D
      Join PurchaseOrderHeader H On H.PurchaseOrderId=D.PurchaseOrderId
    Group By VendorId 
    ) PO
      Join Vendor PV On PV.VendorId=PO.VendorId
    Order By OrderQty Desc
    Fetch First 10 Rows Only
    

    Query 3–Top Product Purchases

    Select PO.ProductId,Name,OrderQty,No_Orders
      From (
    Select ProductId,Sum(OrderQty) As OrderQty,
                     Count(*)As No_Orders
      From PurchaseOrderDetail D
    Group By ProductId 
    ) PO
      Join Product P On P.ProductId=PO.ProductId
    Order By OrderQty Desc
    Fetch First 10 Rows Only
    

    After doing a little code (expanding on the previous example) to allow multiple queries to be submitted, the figure below shows a snapshot of the results in Excel 2000 (2000 or higher will work). As evidenced by the worksheet tab, each query has its own worksheet:

    This multiple worksheet method allows us to compile the results into one convenient workbook to be delivered to the requestor.

    The linked VBA code demonstrates how to fetch data for multiple queries and place each result in its own worksheet. A reference to the ActiveX Data Object (ADO) library is required in your proejct. For the ADO plug-in, the code itself uses the IBMDA400 OLE DB provider that comes with System i Access (formerly known as Client Access and iSeries Access). The IBMDASQL or ODBC data providers could be used as well.

    The entry point subroutine to do the work is called CreateWorkbook and has the following parameter signature:

    Public Sub CreateWorkbook(SQLQueries() As String, SheetNames() As String)
    

    The concept is simple: Pass an array of SQL query definitions (which can be non-parameterized stored procedures and SELECT statements) and an array of worksheet names (assuming each array has the same number of elements) and you are done. Within the code an ADODB.Command object is used to process each query request and then dump the results to a worksheet within a single workbook. Of course, many improvements can be made, including allowing queries from multiple data sources, or parameterized stored procedure calls. But at least enough is there to get you started.

    An alternative approach to the method demonstrated here would be to call a single stored procedure that returns multiple result sets. (The NextRecordset method of the ADODB.Recordset object can be used to fetch each succesive result set from a stored procedure that returns more than one result set.) In this case, the CreateWorkbook subroutine would receive one stored procedure name and an array of worksheet names to match the number of expected stored procedure result sets.

    Finally, note that this code (as with the prior examples) is assumed to be running within an Excel environment. The code can be easily modified to work with other VBA environments (Word, Visio, Access, etc.) In order to do this, simply reference the Microsoft Excel library in your project and then create an instance of the Excel.Application object. The workbook and worksheet objects should be referenced from your top level Excel.Application object. In VB Script, likewise use the CreateObject function to create an instance of Excel.Application.

    I recently implemented this technique for a SQL Server project with very promising results. I needed to combine seven related result sets into a single workbook instead of creating individual workbooks. A little extra code can even do more for the user by creating links between the various worksheets if they exist or by creating charts and pivot tables. Building Excel spreadsheets programmatically is a powerful reporting tool that users love. Almost any shop can find a useful implementation for these techniques.

    Michael Sansoterra is a programmer/analyst for i3 Business Solutions, an IT services firm based in Grand Rapids, Michigan. Send your questions or comments for Mike to Ted Holt via the IT Jungle Contact page.

    RELATED STORIES

    Load a Spreadsheet from a DB2/400 Database

    Load a Spreadsheet from a DB2/400 Database: Part 2



                         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

    Vision Solutions:  Journaling for System i resilience. Learn more.
    looksoftware:  Tough economic times are the right times to modernize and REUSE!
    Profound Logic Software:  Learn how to pick the right modernization approach. FREE Webinar!

    IT Jungle Store Top Book Picks

    Easy Steps to Internet Programming for AS/400, iSeries, and System i: List Price, $49.95
    Getting Started with PHP for i5/OS: List Price, $59.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 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

    inFORM Commits to Reforestation Through Arbor Day Program Hogging the Ground Day

    Leave a Reply Cancel reply

Volume 9, Number 4 -- January 28, 2009
THIS ISSUE SPONSORED BY:

ProData Computer Services
PowerTech
Guild Companies

Table of Contents

  • How To Read A Program
  • Load a Spreadsheet from a DB2/400 Database: Part 3
  • Admin Alert: Four Things to Beware of During a System Upgrade

Content archive

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

Recent Posts

  • 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
  • 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

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