SQL is a great tool when used properly, and this article gives you a simple, practical example to get you started.
Welcome to the wonderful world of practical SQL for RPG programmers. Over the coming months, I hope to bring you a whole host of practical techniques that you can use to become more productive using SQL in your daily programming efforts. I know it may seem odd to some to hear me giving advice on SQL, since over the years I've been very steadfast in my opinion that SQL should not replace native I/O for business logic. But really, there is no conflict here; I have always believed in the best tool for the job, and there are times when SQL is definitely the best tool.
One of my favorite uses of SQL is in reporting. Because I can create a single joined query over multiple files, I can take advantage of a standard skeleton to write many of my reports. In today's example, I'm going to show you a simple, basic report that takes advantage of SQL's flexibility and its integration with RPG, particularly with free-format RPG IV.
So What Are We Going to Do?
In simplest terms, we're going to create a query over a few files and then output that data to a report. I went back and forth a little bit over how I was going to accomplish this. In the end, I decided to use an internally described print file. I know that using an internally described printer puts this article a bit behind the technology curve. (Although, to be honest, I'm not sure just how many people have gotten rid of all their O-specs; I'd be interested to hear how many of you use internally described vs. externally described printer files.) An externally described printer file would make some of this work easier, but I think an internally described printer file will keep the example simpler and a little more cohesive.
And in the end, it doesn't matter: internal or external--the basic concepts are still the same. The single most important piece of this particular discussion is going to be how to build the data structure, which will then be used as the target of the FETCH operation. That's how we communicate between the SQL engine and the RPG code. If you know me, you know I'm all about messages and inter-tier communications, and my focus is no different when working with embedded SQL.
How Does Embedded SQL Work?
Let me take just a moment to explain the basics. Traditional modern (I hope that's not too much of an oxymoron) RPG programs use File specifications (F-specs) to identify externally described database files. Those specifications in turn automatically define all the fields in the file and make them globally available to the program. You'll hear arguments rising to the level of political rhetoric or religious fervor when it comes to the pros and cons of this concept, but nobody disputes the actual mechanics: you don't have to manually define the individual fields, and reading a record from a file brings all those fields in automatically. The biggest minus (besides the architectural issue of global fields) is that adding a field to a file requires a recompile; forget that and you have to deal with the dreaded CPF4131 level-check message.
With SQL, it's a little different. There are no F-specs and thus no automatic fields defined or read magically. You have to explicitly identify each field that you want to read from the file, and although defining fields is second nature to most SQL developers, it can mean quite a bit of typing. Not only that, but for embedded SQL programs, you then have to explicitly tell the SQL precompiler where in your program you want those retrieved fields to go. And since you don't have the externally described file in your program, that means you have to define those work fields as well.
But let's walk through it. I'm going to create a simple program that will print the results of a nice little SELECT statement. Let's just execute the basics in this example. First, we need an SQL statement. Whenever I'm creating a report, I start out by testing my SQL in STRSQL. In this case, I ended up with the following:
select CMCUST, CMNAME, ADCITY, ADSTATE
from CUSMAS join ADRMAS on (CMCUST,CMSAID) = (ADCUST,ADID)
I have two files: the customer master and the address master. The customer master has a couple of fields in it: the ship-to address ID and the bill-to address ID. The combination of the customer number and one of those IDs is the key used to get to the address master. By the way, you may notice that on the join I don't have to compare each field individually; I can compare them all at one time using what is known as a "row expression." This is a truly handy technique. Anyway, now that I have the basic SELECT working, it's time to deck it out a little.
A Little Formatting Goes a Long Way
I want to have a nicely formatted city and state, and also I need to add some order to the equation. Here's a more complete version:
select CMCUST, CMNAME,
TRIM(ADCITY) CONCAT ', ' CONCAT ADSTATE
from CUSMAS join ADRMAS on (CMCUST,CMSAID) = (ADCUST,ADID)
order by ADSTATE, ADCITY, CMCUST
So I trim the city and then add the state with a comma in between. Note, by the way, that I am using a simple JOIN rather than an OUTER JOIN. Because of that, I don't have to worry about NULL values, but I will lose any customer records that don't have matches. Such is the tradeoff between INNER and OUTER JOINs, and that's a subject we can cover in detail another day. I also added an ORDER BY clause that will order my selections by state and then city within state. My SQL statement returns this:
CMCUST CMNAME String Expression
510,002 Mazda North American Operations Irvine, CA
100,250 Costco - Bloomingdale Bloomingdale, IL
100,150 Costco - Glenview Glenview, IL
302,001 Kraft Foods Glenview, IL
100,100 Costco - Lake Zurich Lake Zurich, IL
So, as you can see, I've created a nice little query. The trick is to then take that query and turn it into a report. Let me show you how it's done!
From Interactive to Embedded in 12 Easy Steps
I couldn't decide whether to give you the whole listing at the end of the article and then refer to it step by step in the text, or to intersperse the explanation each step of the way. I'm going to try the latter and see how it works. I've got 12 portions of the program, and I'll explain each one as I go along (alphabetically from "A" to "L").
A H DEBUG OPTION(*SRCSTMT:*NODEBUGIO)
A H DFTACTGRP(*NO) ACTGRP(*NEW)
First, a few compiler settings. Back in the old days, these would be specified on the compile command. I really like that nowadays you can put these settings in the header, because reusing them becomes very convenient: just copy a line or two from another program rather than try to remember the setting when you compile the program. The easier it is to add these settings, the better life is. For example, *SRCSTMT makes post-mortem debugging a lot easier because any error messages will indicate the actual source line where the error occurred, as opposed to a compiler-generated internal statement number that only appears on the compile listing.
B FQSYSPRT O F 132 PRINTER OFLIND(OverFlow)
B d Overflow s n
This is a standard printer file. Remember, I'm going with an internally described file here, so I just specify the width and an overflow indicator. A little trick here: I always put my printer file at the end of my F-specs so that I can immediately specify a D-spec that defines the overflow indicator. Yeah, it's a little cheesy, but it works out just fine most of the time.
*
* These externally defined data structures are only used
* to get field definitions into the program.
*
C d CUSMAS e ds
C d ADRMAS e ds
Here you see the first piece of code needed to support embedded SQL as opposed to native file I/O. Because we don't have any F-specs for database files, we need to define the fields somehow. I'll do that in the next section using the LIKE keyword, but I still need to bring in the external definitions so that I can use LIKE. That's where externally described data structures come into play. In this case, I define one externally described data structure for each file. This, by the way, is one of the reasons that I prefer to have unique field names in my database. If I had the same field name in two files and I tried to define both in data structures, I would get a compiler error. I would have to qualify the field in the LIKE keyword (more on that in a moment). One additional point about these data structures: they take up space. Since I don't really use them for storage, I could have made them based data structures by specifying basing pointers, but that's a little beyond the scope of today's article.
*
* This is the data structure used in the SQL fetch.
* The field definitions here must match exactly the
* fields in the SELECT clause of the cursor.
*
D d dsCursor ds
D d p_CMCUST like(CMCUST)
D d p_CMNAME like(CMNAME)
D d pw_ADCITY +4 like(ADCITY)
Next I define the actual cursor--or more specifically, the data structure that contains the fields that will be fetched by the cursor. The fields in this data structure must match the fields in the SELECT statement. In order to do that, I define them LIKE the corresponding fields in the externally defined data structures. My SQL statement (coming up in section H) selects CMCUST, CMNAME, and then a formatted city. I use a simple naming convention: the name of the work field is the name of the database field with the prefix "p_". You may notice that I did a little extra magic with the city field. I named it pw_ADCITY; take note of the extra "w." That stands for "work" and indicates that, for whatever reason, it's not an exact replica of the database field. In this case, I want to append the state onto the city, so I need as many as four extra characters (comma, space, and two letters for the state code). That being the case, you'll notice the "+4" in the definition; this makes the field pw_ADCITY like the ADCITY field, except that it's four characters longer.
E d Done s n inz(*off)
E d Count s 5u 0 inz(0)
E d Now s
LATEST COMMENTS
MC Press Online