14
Mon, Oct
6 New Articles

Format and Compile RPG to Use Embedded SQL

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

Let's explore the nuts and bolts of using embedded SQL: file type, syntax, and compiling.

 

In a previous article, "Why Use Embedded SQL Within RPG?," I talked about why you would use embedded SQL in RPG. In this article, I will talk about how you could use embedded SQL within RPG. We'll start with an existing RPG program that is written with CHAIN and READ, and then we'll convert it to use embedded SQL.

Source Member Type SQLRPGLE

First things first. We need to make sure we are using the new type for your source member, which is SQLRPGLE.

 

111710TomSnyder_RPGEmbeddedSQL_figure01

Figure 1: Here's a list of my SQLRPGLE and RPGLE source member types. (Click images to enlarge.)

 

Why does the type of member matter? Well, it doesn't matter to the compiler; you can keep it as RPGLE, and it will compile just fine, but PDM won't be happy about it when you're trying to create the code. Here is what will happen if you try to put embedded SQL in a member of type RPGLE.

 

111710TomSnyder_RPGEmbeddedSQL_figure02

Figure 2: This is an example of what you'll see in PDM if you attempt SQL in an RPGLE source member.

 

PDM thinks it's an invalid EVAL operation. What if I'm using IBM Rational Developer for Power Systems Software?

 

111710TomSnyder_RPGEmbeddedSQL_figure03

Figure 3: And this is what you'll see in IBM Rational Developer for Power Systems Software if you attempt SQL in an RPGLE source member.

 

With IBM Rational Developer for Power Systems Software, you will get the same results as you would using an RPGLE source member type. So, in order to be able to code your embedded SQL using either of these tools, you will want to use the SQLRPGLE source member type to keep your editor happy.

Physical File Descriptions

For our example, we will determine the year-to-date amount that was paid to employee 400. We will be using two simple files for our example.

 

EMPLOYEE contains account number and name.

 

     A          R MCFMT

     A            MCACCT         6S 0       COLHDG('Account Number')

     A            MCFNAME       32A         COLHDG('First Name')

     A            MCLNAME       32A         COLHDG('Last Name')

     A          K MCACCT

 

111710TomSnyder_RPGEmbeddedSQL_figure04

Figure 4: Here's a DBU view of an employee record for account 400.

 

EMPHIST contains account number, date of pay, and net amount of pay.

 

     A          R MHFMT

     A            MHACCT         6S 0       COLHDG('Account Number')

     A            MHDATE          L         COLHDG('Pay Date')

     A            MHNET          9S 2       COLHDG('Pay Net Amount')

     A          K MHACCT

     A          K MHDATE

 

111710TomSnyder_RPGEmbeddedSQL_figure05 

Figure 5: Here's the DBU view of the employee history for account 400 for the first day of the year.

 

For our data, the account, Eibeamma Ausfurhundrid, will have an account key of 400, and her net pay will be $1,000 per week.

Straight-Up RPG Without Embedded SQL

For our RPG code without embedded SQL, we will chain into the EMPLOYEE file to retrieve the employee name, and then we will loop through the EMPHIST file using the account number key to accumulate the year-to-date total for the employee.

 

     FEMPLOYEE  IF   E           K DISK

     FEMPHIST   IF   E           K DISK

     F*

     D xEMPLOYEE     E DS                  ExtName(EMPLOYEE)

     D xEMPHIST      E DS                  ExtName(EMPHIST)

     D currentKey      S              6S 0

     D ytdNet          S              9S 2

     D displayBytes    S             52A

      /free

       currentKey = 400;

       ytdNet = *ZEROS;

       chain currentKey EMPLOYEE;

       displayBytes = 'Acct('

                    + %trim(%editc(currentKey: '3')) + ')';

       if %found();

         chain currentKey EMPHIST;

         dou %eof();

           ytdNet = ytdNet + MHNET;

           reade currentKey EMPHIST;

         enddo;

         displayBytes = %trim(displayBytes) + ' '

                      + %trim(MCLNAME) + ', '

                      + %trim(MCFNAME)

                      + ' Net: ' + %trim(%editc(ytdNet: '1'));

       else;

         displayBytes = %trim(displayBytes) + ': '

                      + ' NOT FOUND!';

       endif;

       // Display the Results

       dsply displayBytes;

       *inlr = *ON;

      /end-free

 

Fixed-Formatted RPG with Embedded SQL

Now we will write an embedded SQL program to generate the same results:

 

     D xEMPLOYEE     E DS                  ExtName(EMPLOYEE)

     D xEMPHIST      E DS                  ExtName(EMPHIST)

     D currentKey      S              6S 0

     D ytdNet          S              9S 2

     D displayBytes    S             52A

     C                   eval      currentKey = 400

     C                   eval      ytdNet = *ZEROS

     C                   eval      displayBytes = 'Acct('

     C                             + %trim(%editc(currentKey:'3'))

     C                             + ')'

     C*// Run the Query

     C/EXEC SQL

     C+ select MCACCT,  MCFNAME,  MCLNAME,  sum(mhnet)

     C+        into :MCACCT, :MCFNAME, :MCLNAME, :ytdNet

     C+  from EMPLOYEE

     C+    join EMPHIST on MCACCT = MHACCT

     C+      where MCACCT = :currentKey

     C+  group by MCACCT, MCFNAME, MCLNAME

     C/END-EXEC

     C*// Display the Results

     C                   if        sqlState = *ZEROS

     C                   eval      displayBytes = %trim(displayBytes)

     C                                  + ' ' + %trim(MCLNAME)

     C                                  + ', ' + %trim(MCFNAME)

     C                                  + ' Net: '

     C                                  + %trim(%editc(ytdNet: '1'))

     C                   else

     C                   eval      displayBytes = %trim(displayBytes)

     C                                  + ': ' + ' NOT FOUND!'

     C                   endif

     C     displayBytes  dsply

     C                   eval      *inlr = *ON

 

Free-Formatted RPG with Embedded SQL

And here is the free-formatted version of the same code:

 

     D xEMPLOYEE     E DS                  ExtName(EMPLOYEE)

     D xEMPHIST      E DS                  ExtName(EMPHIST)

     D currentKey      S              6S 0

     D ytdNet          S              9S 2

     D displayBytes    S             52A

      /free

       currentKey = 400;

       ytdNet = *ZEROS;

       displayBytes = 'Acct('

                    + %trim(%editc(currentKey: '3')) + ')';

       // Run the Query

       exec sql select MCACCT,  MCFNAME,  MCLNAME,  sum(mhnet)

                 into :MCACCT, :MCFNAME, :MCLNAME, :ytdNet

         from EMPLOYEE

           join EMPHIST on MCACCT = MHACCT

             where MCACCT = :currentKey

         group by MCACCT, MCFNAME, MCLNAME;

       // Display the Results

       if sqlState = *ZEROS;

         displayBytes = %trim(displayBytes) + ' '

                      + %trim(MCLNAME) + ', '

                      + %trim(MCFNAME)

                      + ' Net: ' + %trim(%editc(ytdNet: '1'));

       else;

         displayBytes = %trim(displayBytes) + ': '

                      + ' NOT FOUND!';

       endif;

       dsply displayBytes;

       *inlr = *ON;

      /end-free

 

Now let's review the differences.

No File Specifications

I discussed this in my previous article, and you can see that we are not using any F-specs in this program. This is because we are using SQL, and we are specifying the file to use in the SQL statement.

Using Both Files at the Same Time

There is no need to CHAIN into the EMPLOYEE file and then READ through the EMPHIST file. You can JOIN the two files together and use them to create the results. This might seem nice here, but it is a simple example and is only being used for one account. This gets to be really nice when you are processing all of the accounts in the file.

/EXEC SQL, /END-EXEC, and exec sql

/EXEC SQL indicates that some SQL code is about to begin, and /END-EXEC marks the end. This is similar to /free and /end-free to indicate the beginning and ending of segments of code that are free-formatted RPG.

 

"exec sql" is the free-formatted alternative to /EXEC SQL and /END-EXEC.

Colons in Front of the Variables

The colons (:) indicate variables inside of the SQL statement, which are referred to as host variables in SQL. These are used for both input and output in this example. The "into :MCACCT, :MCFNAME, :MCLNAME, :ytdNet" portion is used as output for the results to be put into when the statement is executed. The "where mcacct = :currentKey" is the input version that allows a variable value to be used to filter the data.

No Loop?

You don't need to loop through the records when you are using "group by" in your SQL statement. SQL will automatically "group" all of the records specified to be grouped together, and the "sum" used on the MHNET field will sum the total for the group.

Where Did sqlState Come From?

You can see the complete code above, and there are no variables declared for sqlState. This is made available automatically by the compiler. If you look at your compiler spool file, you will see the SQLCA data structure, which contains the SQLSTATE/SQLSTT variable.

 

111710TomSnyder_RPGEmbeddedSQL_figure06

Figure 6: You'll see the SQLCA data structure in the compiler spool file.

 

In my quest for simplistic code, and in the process of breaking my own bad habits, my previous version of this program was using sqlCode, which is discouraged from usage for the purpose of portability, and I don't want to pass along my own bad habits, so I updated this version of the code to use SQLSTATE instead. You can get a lot more resolution by expanding your code and looking for more codes that are available for SQLSTATE.

 

You can find a list of SQLSTATE values on the IBM site by clicking here.

Compiling the Embedded SQL Program/Module

To compile RPG programs using embedded SQL, you'll need to use a new command. You can choose either CRTSQLRPG or CRTSQLRPGI if you are creating a program. The difference between the two is that you do not have the option to determine the compile type when using CRTSQLRPG because it creates only *PGM objects. With CRTSQLRPGI, you can create *PGM, *SRVPGM, or *MODULE. I usually just use CRTSQLRPGI because you can do everything with it.

 

Here is the command I used to compile this program:

 

CRTSQLRPGI OBJ(MyLib/MCP035SQL) SRCFILE(MyLib/MySrc) COMMIT(*NONE) DBGVIEW(*SOURCE)

 

You options may vary, depending upon whether or not you are using commitment control and what your debugging preferences are.

The Output

There is no special way to call an SQLRPGLE program. You call it just the same as you would call any other RPG program, using the CALL command. Whether you run the straight RPG program or the one using embedded SQL, you will get the same results. This would be a year-to-date amount into November.

 

111710TomSnyder_RPGEmbeddedSQL_figure07

Figure 7: This output is generated when calling both versions of the program.

 

And that's all you need to do to create an RPG program with embedded SQL. You can download the code, create the files, compile the code, and run it.

Download the Code

You can download the RPG and DDS source used in this article by clicking here.

as/400, os/400, iseries, system i, i5/os, ibm i, power systems, 6.1, 7.1, V7,

Thomas Snyder

Thomas Snyder has a diverse spectrum of programming experience encompassing IBM technologies, open source, Apple, and Microsoft and using these technologies with applications on the server, on the web, or on mobile devices.

Tom has more than 20 years' experience as a software developer in various environments, primarily in RPG, Java, C#, and PHP. He holds certifications in Java from Sun and PHP from Zend. Prior to software development, Tom worked as a hardware engineer at Intel. He is a proud United States Naval Veteran Submariner who served aboard the USS Whale SSN638 submarine.

Tom is the bestselling author of Advanced, Integrated RPG, which covers the latest programming techniques for RPG ILE and Java to use open-source technologies. His latest book, co-written with Vedish Shah, is Extract, Transform, and Load with SQL Server Integration Services.

Originally from and currently residing in Scranton, Pennsylvania, Tom is currently involved in a mobile application startup company, JoltRabbit LLC.


MC Press books written by Thomas Snyder available now on the MC Press Bookstore.

Advanced, Integrated RPG Advanced, Integrated RPG
See how to take advantage of the latest technologies from within existing RPG applications.
List Price $79.95

Now On Sale

Extract, Transform, and Load with SQL Server Integration Services Extract, Transform, and Load with SQL Server Integration Services
Learn how to implement Microsoft’s SQL Server Integration Services for business applications.
List Price $79.95

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 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. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • 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 company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY 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. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) 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:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. 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:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot 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:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • LANSA Business 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.

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

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • Profound Logic 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.

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? 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: