With a little creativity, SQL allows you to add a form of overloading to RPG that can really extend your toolkit.
In the previous article in this series in this series, I created a simple user-defined function (UDF) that acted as an SQL interface to an RPG service program procedure. It was simple and easy to do, but the emphasis was on simple. The UDF simply passed parameters from the SQL environment straight through to the RPG procedure and returned the result. This is enough in many cases, but at other times, you might want a little more flexibility.
For example, you might want some of the parameters to be optional or you might want to hardcode one or more of the parameters. And while this sounds like it might be a job for the *NOPASS parameter on your RPG procedure, as it turns out, that doesn't work in the world of service programs and subprocedures. Instead, you need to take advantage of SQL function signatures, and this article explains how they work.
Recapping and Moving Forward
Let me do a quick recap. In the previous article, I showed you a simple file and then added a record to it. The order number is binary, and the customer is packed (you can look at the other article to get the rest of the file layout). I added a record with order = 314478, customer = 70021, ship-to = 3, and address = 1234 MAIN ST. When I performed a DSPPFM on the file, I saw this:
*...+....1....+....2....+...
ö> ø 1234 MAIN ST
00C607010000FFFF4DCCD4EE4444
04CE002F00031234041950230000
If you try, you can make out the customer number in positions 5-8 because the data is packed, but the order number is binary, so the hex values have no discernable relationship to the decimal order number 314478. Because of this, it's really hard to work with alpha fields with embedded binary data. Luckily, we don't have to very often, but there are times when that sort of processing is necessary. In the previous article, I brought up a specific example: looking at journal entries to try to find specific records. I noted that in the OUTFILE of the DSPJRN command, the whole record is stored without any sort of field definitions in the JOESD field; you have to access the individual fields using the substring function (SUBSTR). If you want to parse that data using SQL, it's very hard to work with that embedded numeric data. You can sort of do it with positive packed numbers (using the HEX function and dropping the trailing "F"), but it's impossible to extract the decimal representation of a binary field using traditional SQL techniques. Instead, I wrote a simple routine called UDFHEX2NUM that would take the binary data and convert it back into a usable decimal value. Here's an example of the code:
select * from JRNOUT where JOENTT = 'PT'
and HEX2NUM(substr(JOESD,1,4),2) between 314000 and 315000
It worked quite well. However, one of the problems with writing utility functions is that sometimes in order to make the routine flexible, you need extra parameters and then you have to use those parameters even when they aren't exactly intuitive. If you've used some of the IBM i's APIs you know exactly what I mean; although they're very powerful, the error structures for the APIs aren't intuitive at all. This tradeoff between flexibility and ease of use is even true in the case of my little procedure. It treats the first parameter as either binary or packed data, depending on the value of the second parameter. The second parameter was either 1 or 2, depending on the data being converted, and that means every time you call it, you have to remember whether to use 1 or 2. It's easy to make a mistake, and APIs that encourage mistakes are not good programming. So how do we fix it?
There Are Two Paths You Can Go Down
Sorry, just a little pop culture reference; if you don't remember "Stairway to Heaven," then never mind. But there really are two basic ways to attack the problem. The quickest might be to simply add another service program procedure; have one procedure for converting binary data and another for converting packed data. That's a reasonable option, and relatively straightforward. But this article is centered on the other approach: we're going to create different SQL UDFs, but they will all call the same RPG service program procedure. Once we've created the first two UDFs, we'll see how this approach can allow for even more flexibility. But for now, let me just separate the binary conversion from the packed conversion. It's quite simple. Assume that we have the HEX2NUM UDF shown above and outlined in the other article. I then simply create two more UDFs.
First, I'll create the UDF that converts a packed value to a number. The first and only parameter is the hexadecimal data being passed in. All this function does is pass that value to the HEX2NUM UDF along with a literal 1 to indicate that this is packed data.
create function PKD2NUM (hexdata varchar(16))
returns decimal(31, 0)
language sql deterministic
begin
return (HEX2NUM(hexData, 1));
end;
Next, I create the UDF that converts a packed value to a number. Again, the only parameter is the hexadecimal data being passed in. This function works just like the BIN2NUM UDF, except it passes a literal 2 instead of 1, to indicate that the value being passed in is binary.
create function BIN2NUM (hexdata varchar(16))
returns decimal(31, 0)
language sql deterministic
begin
return (HEX2NUM(hexData, 2));
end;
So now the developer can either use PKD2NUM or BIN2NUM on the substring. This is easier to remember, simpler to code, less prone to error, and—more importantly—easier to read six months (or six years!) down the road when you're trying to figure out what some piece of code does. Now, younger programmers have probably noted that I still have some serious GORP (Grumpy Old RPG Programmer) tendencies: the names PKD2NUM and BIN2NUM both use three-character abbreviations that probably would be even more readable if they were spelled out, say PackedToNumeric and BinaryToNumeric). One of the really nice things about this technique is that you can use long mixed-cased names here to wrap around short 10-character uppercase-only RPG names. The SQL developers won't even know that those names exist.
A Closing Comment on Polymorphism in SQL
Hey! Where did the ten-cent words get into this? Well, one of the problems I identified in the previous article is that when you're extracting packed decimal numbers from alpha fields, you can't tell the number of decimals from the data. That's something that will have to be specified by the developer. We could add a new parameter to the RPG service program procedure to specify the number of decimals, but then you'd have to remember to specify the number of decimals even if you don't need it, which would be the case for numbers with zero decimal places and pretty much any binary number. Note: theoretically, you can specify binary fields with decimal positions, but I try to avoid that whenever possible. I only use binary data types for true integer data—counts, sequence numbers, order numbers, that sort of thing.
But with SQL you can take advantage of the concept of a signature and add a new version of the UDF that includes the number of decimals. The new UDF looks like this:
create function PKD2NUM (hexdata varchar(16), decimals int)
returns decimal(31, 15)
language sql deterministic
begin
declare myresult decimal(31,15);
return (HEX2NUM(hexData, 1) / (10 ** decimals));
end;
If I call PKD2NUM with one parameter, I get the version above, which just calls the service program procedure and returns the results. If I call it with two parameters, I invoke this function instead. The second parameter must be an integer specifying the number of decimals. I call the HEX2NUM procedure and then divide the result of the packed data extraction by 10 to the power of the number of decimals; this effectively moves the decimal point to the left by the number of positions specified in the decimals variable. I can now do this:
select PKD2NUM(substr(JOESD,5,4),2) from JRNOUT where JOENTT = 'PT'
The result:
PKD2NUM
700.210000000000036
I realize it doesn't make a lot of sense to do this for an order number, but if this were instead a total invoice amount, you can see how this would be helpful. Also, note that because of the size of the fields, I'm seeing some rounding artifacts. This is an ongoing issue with SQL; its default use of floating point numbers isn't always helpful in the world of fixed precision arithmetic. But then again, this wasn't meant to be a treatise on SQL and business logic; it was a way to show you some of the flexibility available when using SQL to invoke service program procedures. I hope this has given you some more insights into SQL; go forth and be functional!
LATEST COMMENTS
MC Press Online