Sidebar

TechTip: Use a Stored Procedure as Your Data Source in DB2 Web Query for i

DB2
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

Build queries with optional input parameters using existing business logic.

 

Do you need the ability to build queries with optional input parameters? Do you need your queries to use existing business logic? Did you know you can accomplish both goals by using a stored procedure as your data source in DB2 Web Query?

 

When we purchased DB2 Web Query, our shop needed to create new reports for a department that reports   accounting transactions to various state agencies and banking institutions. The business logic for the reports would be the same regardless of what state or bank was requesting the data, but the level of detail, the columns included, and the filtering could be different each run. Some states wanted details; some only summary. Some required information monthly; some quarterly. Some states wanted us to include beginning and ending balances along with the totals for the period being reported; others wanted information related only to period. The legacy reports that we were replacing were written in RPG and had no input parameters other than Month. They provided no ability to filter data. They had no ability to drop unwanted columns, nor did they let the users choose detail or summary output.

 

We knew that DB2 Web Query would give us what we needed. We also realized that we could "front end" multiple DB2 Web Queries with one stored procedure that could dynamically build an SQL SELECT statement that would allow us to provide optional input parameters. Additionally, by keeping the business logic in one stored procedure, we could eliminate duplicating/cloning it in multiple queries.

 

In this TechTip, I'll discuss writing a free-format SQLRPGLE program that receives parameters and dynamically builds a SELECT statement with a WHERE clause that includes only the optional parameters that the user populated. I'll discuss registering the SQLRPGLE program as a stored procedure and building a synonym over it. I'll show you how to build a summary query and a drill-down query that both use the same stored procedure's synonym.

Step 1: Creating Your Stored Procedure

If you are new to creating stored procedures in the System i, don't be intimidated. A stored procedure is only a program that you call from within SQL. You can write a stored procedure in languages you are already fluent in: RPG, CL, SQL, and others. Your stored procedure will select the records that match the selection criteria in your parameters. If applicable, your stored procedure can use existing business logic to segment your data. The stored procedure will then return your data as a result set to DB2 Web Query.

 

In our case, we have existing business logic that evaluates records in a large accounting transaction file. In addition to State, Location, and Contract#, each record carries a transaction code, period, and amount. The transaction code defines whether the transaction amount should be classified as Servicing$, Adjustment$, or Receipts$. Our stored procedure (STOREDPROC) uses that business logic to segment the transactions into the appropriate column. Additionally, STOREDPROC is using the parameters to filter the data in the file. The Start period and End period parameters are mandatory. The State, Location, and Contract# parameters are optional, and the SELECT statement built by STOREDPROC includes them in the WHERE clause only if they have a value.

 

Our parameters are defined in prototype STOREDPROC

 

  //- - - - - - - - - - - - - - - - - - - - - - - - - - - -

  // Input parms                                          

  //- - - - - - - - - - - - - - - - - - - - - - - - - - - -

                                                          

d inputparm       pr                  extpgm('STOREDPROC')

d  iState                        2                        

d  iLocation                     3                        

d  iContract                     9                        

d  isPeriod                      6                        

d  iePeriod                      6                        

                                                          

d inputparm       pi                                      

d  pState                        2                        

d  pLocation                     3                         

d  pContract                     9                        

d  psPeriod                      6                        

d  pePeriod                      6                        

 

The mainline code of STOREDPROC is very simple. Subroutine @build_select builds the dynamic SQL SELECT statement. Subroutine @open_cursor uses the SELECT statement to prepare and open the cursor for return to DB2 Web Query.

 

  //- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -      

  //  work fields                                                      

  //- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -      

d stm1            s           1000a                                    

d q               c                   ''''                              

  //- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -      

                                                                       

 /free                                                                 

                                                                        

  // build dynamic SQL select statement and include those               

  // parms supplied by the user                                        

  exsr     @build_select;                                               

                                                                       

  // use the select statement to open a cursor and send back result set

  exsr     @open_cursor;                                               

                                                                        

  // all done

  *inlr = *on; 

  return;   

                                                          

 

The first subroutine, @build_select illustrates two things:

  • The use of the existing business logic to segment the data into the appropriate columns
  • The use of the optional parameters in the WHERE clause

 

// ------------------------------------------------------            

begsr @build_select;                                                  

// ------------------------------------------------------            

                                                                     

 stm1 = 'SELECT +                                                    

   state, +                                                           

   location, +                                                       

   contract, +                                                       

   sum(case when (period < ' + pSperiod+ ') then amount else 0 end) +

     as begBal$, +                                                   

   sum(case when (tranCode = 20) +                                   

     and (period >= ' + pSperiod+ ') then amount else 0 end) +       

     as periodSer$, +                                                 

   sum(case when (tranCode in(0,6,9)) +                              

     and (period >= ' + pSperiod+ ') then amount else 0 end) +       

     as periodAdj$, +                                                

   sum(case when (tranCode in(2,3,7)) + 

     and (period >= ' + pSperiod+ ') then amount else 0 end) +  

     as periodRcpt$, +                                          

   sum(amount) +                                                

     as EndBal$ +                                                

                                                                

  FROM ACCTGFILE +                                              

  WHERE tranCode in (0,2,3,6,7,9,20) +                          

    and period <= ' + q + pEperiod+ q;                          

                                                                

  if pState > *blank;                                           

    stm1 = %trimr(stm1) + ' and state = ' + q + pState + q;     

  endif;                                                         

                                                                

  if pLocation > *blank;                                        

    stm1 = %trimr(stm1) + ' and location = ' + q + pLocation + q;

  endif;

        

  if pContract > *zeros;                                             

    stm1 =  %trimr(stm1) +  ' and contract = ' + q  + pContract + q; 

  endif;                                                             

                                                                     

  stm1 =  %trimr(stm1) +                                             

   ' GROUP BY state, location, contract +                             

     ORDER BY state, location, contract';                             

                                                                       

 endsr;                                                               

                                                                                                                                                  

The second subroutine, @open_cursor, uses the string just built to prepare, declare, open, and return a cursor as a result set to DB2 Web Query.

 

  // ------------------------------------------------------     

  begsr @open_cursor;                                           

  // ------------------------------------------------------     

                                                                

   exec sql prepare stmt from :stm1;                            

   exec sql declare C1 cursor with return to client for stmt;   

   exec sql open C1;                                            

   exec sql set result sets cursor C1;                          

                                                                

  endsr;                                                        

                                                                

After a successful compile of your program, you can register it as a stored procedure using the following SQL command:

 

CREATE PROCEDURE STOREDPROC

(IN STATE    CHAR(2) , 

 IN LOCATION CHAR(3) , 

 IN CONTRACT CHAR(9) , 

 IN SPERIOD  CHAR(6) , 

 IN EPERIOD  CHAR(6) ) 

 DYNAMIC RESULT SETS 1 

 LANGUAGE RPGLE        

 SPECIFIC       STOREDPROC

     DETERMINISTIC     

 READS SQL DATA        

 CALLED ON NULL INPUT  

 PARAMETER STYLE SQL   

 

Step 2: Testing Your Stored Procedure

You are now ready to test your stored procedure. The steps are simple: you simply use the Run SQL Scripts tool in iSeries Navigator to call your stored procedure with your parameters. An excellent TechTip by Kevin Forsythe details how to use iSeries Navigator to test a stored procedure.

 

Make sure to pass a value to your mandatory parameters. Play around with passing some of your optional parameters, and check the result set returned by your stored procedure. When you have verified that your SQL SELECT statement in your stored procedure is passing back correct results, you are ready to create a synonym.

 

Step 3: Creating a Synonym over Your Stored Procedure

These instructions assume you are familiar with creating a synonym over a table. To create a synonym over a stored procedure, select Stored Procedures in the "Restrict object type to" drop-down box as shown in Figure 1.

 

72409Corcoranfigure1_crop 

Figure 1: Choose the Stored Procedures option for Select Synonym Candidates. (Click images to enlarge.)

 

The Step 3 page of the Create Synonym pages will display the input parameters you defined in your stored procedure. When you click the Create Synonym button, your stored procedure will be called, and if it runs successfully and returns a result set, your synonym will be created and will include the parameters and all the fields in the result set. If your stored procedure includes any parameters that are mandatory for a successful run, then key in a valid value for those parameters as shown in Figure 2 before clicking Create Synonym.

 

072409Corcoranfigure 2_crop 

Figure 2: Complete the Create Synonym process.

 

Step 4: Using the Stored Procedure's Synonym in a Summary and Drill-Down Set of Web Queries

You can select the synonym over your stored procedure in DB2 Web Query and use it like any other synonym. The only difference you will notice is that your field list will contain separate segments for your parameters (segment INPUT) and the fields in your result set (segment ANSWERSET1). See Figure 3.

 

072409Corcoranfigure 3_crop 

Figure 3: This is the field list in Web Query for synonym STOREDPROC.

 

To filter the data returned by the stored procedure, include all your parameters in the Selection Criteria Window, as shown in Figure 4.

 

 072409Corcoranfigure 4_crop

 Figure 4: Include your parameters in the Selection Criteria window.

 

An example of the resulting simple summary query is shown in Figure 5. Note that we passed values into only the mandatory parameters.

 

072409Corcoranfigure 5_crop

Figure 5: Here are the results of a simple summary query.

 

You can turn this simple report into the parent in a drill-down set by selecting one of the fields and drilling down to a Web Query that uses the same STOREDPROC as its data source. You can, as appropriate, use fields from the answer set as the value for the parameters to be passed to the drill-down query. In this example, shown in Figure 6, we are allowing the user to drill down on the Location field. We are passing to the drill-down query the values for State and Location in the answer set row selected. The remaining parameters passed are identical to the parameters on the parent Query.

 

072409Corcoranfigure 6_crop 

Figure 6:  Change the parameters used by the parent query when it executes the drill-down.

 

I hope this simple example will inspire you to try this in your own shop. In future TechTips, I'll expand this example to include the addition of the input parameter values, user, and run date/time in the DB2 Web Query header and footer. I'll also show you a way get your stored procedure's synonym to work with the user's library list.

 

 

Anita Corcoran

Anita Corcoran, who has worked on IBM midrange systems since 1980, is a Senior Systems Analyst at StoneMor Partners L.P. in Levittown, Pennsylvania. She can be reached at Anita.Corcoran@StoneMor.com.

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

RESOURCE CENTER

  • WHITE PAPERS

  • WEBCAST

  • TRIAL SOFTWARE

  • White Paper: Node.js for Enterprise IBM i Modernization

    SB Profound WP 5539

    If your business is thinking about modernizing your legacy IBM i (also known as AS/400 or iSeries) applications, you will want to read this white paper first!

    Download this paper and learn how Node.js can ensure that you:
    - Modernize on-time and budget - no more lengthy, costly, disruptive app rewrites!
    - Retain your IBM i systems of record
    - Find and hire new development talent
    - Integrate new Node.js applications with your existing RPG, Java, .Net, and PHP apps
    - Extend your IBM i capabilties to include Watson API, Cloud, and Internet of Things


    Read Node.js for Enterprise IBM i Modernization Now!

     

  • Profound Logic Solution Guide

    SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation.
    Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects.
    The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the companyare not aligned with the current IT environment.

    Get your copy of this important guide today!

     

  • 2022 IBM i Marketplace Survey Results

    Fortra2022 marks the eighth edition of the IBM i Marketplace Survey Results. Each year, Fortra captures data on how businesses use the IBM i platform and the IT and cybersecurity initiatives it supports.

    Over the years, this survey has become a true industry benchmark, revealing to readers the trends that are shaping and driving the market and providing insight into what the future may bring for this technology.

  • Brunswick bowls a perfect 300 with LANSA!

    FortraBrunswick is the leader in bowling products, services, and industry expertise for the development and renovation of new and existing bowling centers and mixed-use recreation facilities across the entertainment industry. However, the lifeblood of Brunswick’s capital equipment business was running on a 15-year-old software application written in Visual Basic 6 (VB6) with a SQL Server back-end. The application was at the end of its life and needed to be replaced.
    With the help of Visual LANSA, they found an easy-to-use, long-term platform that enabled their team to collaborate, innovate, and integrate with existing systems and databases within a single platform.
    Read the case study to learn how they achieved success and increased the speed of development by 30% with Visual LANSA.

     

  • Progressive Web Apps: Create a Universal Experience Across All Devices

    LANSAProgressive Web Apps allow you to reach anyone, anywhere, and on any device with a single unified codebase. This means that your applications—regardless of browser, device, or platform—instantly become more reliable and consistent. They are the present and future of application development, and more and more businesses are catching on.
    Download this whitepaper and learn:

    • How PWAs support fast application development and streamline DevOps
    • How to give your business a competitive edge using PWAs
    • What makes progressive web apps so versatile, both online and offline

     

     

  • The Power of Coding in a Low-Code Solution

    LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed.
    Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

    • Discover the benefits of Low-code's quick application creation
    • Understand the differences in model-based and language-based Low-Code platforms
    • Explore the strengths of LANSA's Low-Code Solution to Low-Code’s biggest drawbacks

     

     

  • Why Migrate When You Can Modernize?

    LANSABusiness users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.
    In this white paper, you’ll learn how to think of these issues as opportunities rather than problems. We’ll explore motivations to migrate or modernize, their risks and considerations you should be aware of before embarking on a (migration or modernization) project.
    Lastly, we’ll discuss how modernizing IBM i applications with optimized business workflows, integration with other technologies and new mobile and web user interfaces will enable IT – and the business – to experience time-added value and much more.

     

  • UPDATED: Developer Kit: Making a Business Case for Modernization and Beyond

    Profound Logic Software, Inc.Having trouble getting management approval for modernization projects? The problem may be you're not speaking enough "business" to them.

    This Developer Kit provides you study-backed data and a ready-to-use business case template to help get your very next development project approved!

  • What to Do When Your AS/400 Talent Retires

    FortraIT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators is small.

    This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn:

    • Why IBM i skills depletion is a top concern
    • How leading organizations are coping
    • Where automation will make the biggest impact

     

  • Node.js on IBM i Webinar Series Pt. 2: Setting Up Your Development Tools

    Profound Logic Software, Inc.Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. In Part 2, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Attend this webinar to learn:

    • Different tools to develop Node.js applications on IBM i
    • Debugging Node.js
    • The basics of Git and tools to help those new to it
    • Using NodeRun.com as a pre-built development environment

     

     

  • Expert Tips for IBM i Security: Beyond the Basics

    SB PowerTech WC GenericIn this session, IBM i security expert Robin Tatam provides a quick recap of IBM i security basics and guides you through some advanced cybersecurity techniques that can help you take data protection to the next level. Robin will cover:

    • Reducing the risk posed by special authorities
    • Establishing object-level security
    • Overseeing user actions and data access

    Don't miss this chance to take your knowledge of IBM i security beyond the basics.

     

     

  • 5 IBM i Security Quick Wins

    SB PowerTech WC GenericIn today’s threat landscape, upper management is laser-focused on cybersecurity. You need to make progress in securing your systems—and make it fast.
    There’s no shortage of actions you could take, but what tactics will actually deliver the results you need? And how can you find a security strategy that fits your budget and time constraints?
    Join top IBM i security expert Robin Tatam as he outlines the five fastest and most impactful changes you can make to strengthen IBM i security this year.
    Your system didn’t become unsecure overnight and you won’t be able to turn it around overnight either. But quick wins are possible with IBM i security, and Robin Tatam will show you how to achieve them.

  • Security Bulletin: Malware Infection Discovered on IBM i Server!

    SB PowerTech WC GenericMalicious programs can bring entire businesses to their knees—and IBM i shops are not immune. It’s critical to grasp the true impact malware can have on IBM i and the network that connects to it. Attend this webinar to gain a thorough understanding of the relationships between:

    • Viruses, native objects, and the integrated file system (IFS)
    • Power Systems and Windows-based viruses and malware
    • PC-based anti-virus scanning versus native IBM i scanning

    There are a number of ways you can minimize your exposure to viruses. IBM i security expert Sandi Moore explains the facts, including how to ensure you're fully protected and compliant with regulations such as PCI.

     

     

  • Encryption on IBM i Simplified

    SB PowerTech WC GenericDB2 Field Procedures (FieldProcs) were introduced in IBM i 7.1 and have greatly simplified encryption, often without requiring any application changes. Now you can quickly encrypt sensitive data on the IBM i including PII, PCI, PHI data in your physical files and tables.
    Watch this webinar to learn how you can quickly implement encryption on the IBM i. During the webinar, security expert Robin Tatam will show you how to:

    • Use Field Procedures to automate encryption and decryption
    • Restrict and mask field level access by user or group
    • Meet compliance requirements with effective key management and audit trails

     

  • Lessons Learned from IBM i Cyber Attacks

    SB PowerTech WC GenericDespite the many options IBM has provided to protect your systems and data, many organizations still struggle to apply appropriate security controls.
    In this webinar, you'll get insight into how the criminals accessed these systems, the fallout from these attacks, and how the incidents could have been avoided by following security best practices.

    • Learn which security gaps cyber criminals love most
    • Find out how other IBM i organizations have fallen victim
    • Get the details on policies and processes you can implement to protect your organization, even when staff works from home

    You will learn the steps you can take to avoid the mistakes made in these examples, as well as other inadequate and misconfigured settings that put businesses at risk.

     

     

  • The Power of Coding in a Low-Code Solution

    SB PowerTech WC GenericWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed.
    Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

    • Discover the benefits of Low-code's quick application creation
    • Understand the differences in model-based and language-based Low-Code platforms
    • Explore the strengths of LANSA's Low-Code Solution to Low-Code’s biggest drawbacks

     

     

  • Node Webinar Series Pt. 1: The World of Node.js on IBM i

    SB Profound WC GenericHave you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.
    Part 1 will teach you what Node.js is, why it's a great option for IBM i shops, and how to take advantage of the ecosystem surrounding Node.
    In addition to background information, our Director of Product Development Scott Klement will demonstrate applications that take advantage of the Node Package Manager (npm).
    Watch Now.

  • The Biggest Mistakes in IBM i Security

    SB Profound WC Generic The Biggest Mistakes in IBM i Security
    Here’s the harsh reality: cybersecurity pros have to get their jobs right every single day, while an attacker only has to succeed once to do incredible damage.
    Whether that’s thousands of exposed records, millions of dollars in fines and legal fees, or diminished share value, it’s easy to judge organizations that fall victim. IBM i enjoys an enviable reputation for security, but no system is impervious to mistakes.
    Join this webinar to learn about the biggest errors made when securing a Power Systems server.
    This knowledge is critical for ensuring integrity of your application data and preventing you from becoming the next Equifax. It’s also essential for complying with all formal regulations, including SOX, PCI, GDPR, and HIPAA
    Watch Now.

  • Comply in 5! Well, actually UNDER 5 minutes!!

    SB CYBRA PPL 5382

    TRY the one package that solves all your document design and printing challenges on all your platforms.

    Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product.

    Request your trial now!

  • Backup and Recovery on IBM i: Your Strategy for the Unexpected

    FortraRobot automates the routine tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:
    - Simplified backup procedures
    - Easy data encryption
    - Save media management
    - Guided restoration
    - Seamless product integration
    Make sure your data survives when catastrophe hits. Try the Robot Backup and Recovery Solution FREE for 30 days.

  • Manage IBM i Messages by Exception with Robot

    SB HelpSystems SC 5413Managing messages on your IBM i can be more than a full-time job if you have to do it manually. How can you be sure you won’t miss important system events?
    Automate your message center with the Robot Message Management Solution. Key features include:
    - Automated message management
    - Tailored notifications and automatic escalation
    - System-wide control of your IBM i partitions
    - Two-way system notifications from your mobile device
    - Seamless product integration
    Try the Robot Message Management Solution FREE for 30 days.

  • Easiest Way to Save Money? Stop Printing IBM i Reports

    FortraRobot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing.
    Manage your reports with the Robot Report Management Solution. Key features include:

    - Automated report distribution
    - View online without delay
    - Browser interface to make notes
    - Custom retention capabilities
    - Seamless product integration
    Rerun another report? Never again. Try the Robot Report Management Solution FREE for 30 days.

  • Hassle-Free IBM i Operations around the Clock

    SB HelpSystems SC 5413For over 30 years, Robot has been a leader in systems management for IBM i.
    Manage your job schedule with the Robot Job Scheduling Solution. Key features include:
    - Automated batch, interactive, and cross-platform scheduling
    - Event-driven dependency processing
    - Centralized monitoring and reporting
    - Audit log and ready-to-use reports
    - Seamless product integration
    Scale your software, not your staff. Try the Robot Job Scheduling Solution FREE for 30 days.