Use an SQL user-defined table function (UDTF) to access messages in a message file.
If you've ever needed to retrieve information from a message file, you're probably already aware of the Retrieve Message (QMHRTVM) API, which allows you to retrieve message descriptions for messages in a specified message file. But is that enough?
If your software is like most, you may need to store message IDs associated with a message for historical tracing or auditing purposes. The challenge comes when you want to generate reporting off of that data at a later time. There are several ways to approach this need. One might be to store the message description along with the message ID. While this approach will work, it does so at the cost of taking up disk space to store static information. Another option would be to write your reporting application to retrieve this information each time a record is read. While this approach will also work, it restricts you to using a program to generate reporting rather than being able to utilize SQL-based reporting and/or query tools. There is a better solution. Ideally, what you would like to be able to do is access the message descriptions in a message file in the same way that you access data in a physical file. Enter a UDTF.
What Is a UDTF?
User-defined table functions (UDTFs) are, as their name indicates, a means by which you can return data from a program or service program in much the same way that you can read records from a physical or logical file. Creating a UDTF requires a few steps:
1. Create your program or service program containing specific, required function parameters.
2. Compile your program (in the case of a service program, compile the module and create the service program).
3. Use the CREATE FUNCTION SQL statement to create the UDTF. The key here is including the RETURNS TABLE... clause.
There is an optional fourth step that I'll explain later.
The required function parameters mentioned in step 1 refer to a set of parameters that must be passed into and back from your program. These parameters follow the parameters used by your program (both input and output). First, you need to include a series of null indicator parameters, one for each input or output parameter used by your program. Each of these is defined as an integer (5i 0) field. After these parameters, you also need a series of SQL information parameters, which provide information to the SQL database engine about from your program. These include the following:
•· SQL State identifies the status of the most recent action. This parameter indicates when your program has sent its last record (i.e., end of file).
•· Function name is the fully qualified name of the UDTF calling the program.
•· Specific name is the name of the UDTF calling the program.
•· SQL Message provides message text along with the state.
•· Call type indicates how the function was called.
For now, the only one of these you're concerned with is the SQL State. While the others provide some useful information, the only one you need to use is the SQL State parameter. Each time a record is sent back from the program, this parameter is used to indicate that either the data was read OK or the file is at end of file.
Message File, Meet Message..."File"
To make accessing message file descriptions easier, you'll take an RPGLE service program and wrap a UDTF around that service program to allow you to read that data just like you would any other physical file. Click here to obtain the source for the RPGLE service program.
This program accepts two input parameters: the first identifies the library containing the message file; the second contains the message file name. The program returns the following four parameters as output (while input and output aren't really defined here, they come into play a little later):
•· MsgID--The message ID for the message
•· MsgSev--The severity (0-99) for the message
•· MsgDesc--The message description text
•· MsgHelp--The message help text
For each of these parameters, you have a null indicator (six total) defined. After that, you define the SQL information parameters. In addition to the entry parameters, you've also defined a RetrieveMsg prototype for the QMHRTVM API along with a data structure for the RTVM0300 structure returned by the API.
In addition to some other work variables, the program defined two static variables. These static variables keep their values between program calls until the *INLR is set on. You can determine the first call of the routine based on the CALLTYPE SQL Info parameter. The -1 value indicates the "open files" call. One of these static variables set in this routine is used to hold the retrieve option, used to identify which message to retrieve. You use that value to perform logic required to initialize static variables. On this "open call," this value is populated with '*FIRST', indicating that the first message description in the message file should be read. Every time after that, the field is populated with '*NEXT', indicating that the message following the message identified on the MSGID parameter should be read. The lastMsg variable stores the message ID that is passed to the API between program calls. Upon a successful read from the API, the relevant variables are passed back to the UDTF through the program parameters. When no more data is found, a value of SQL_EOF is passed to the UDTF to indicate that there is no more data.
To compile this service program, perform the following two steps:
CRTRPGMOD MODULE(mylib/LISTMSGF) SRCFILE(nylib/QRPGLESRC)
SRCMBR(LISTMSGF) REPLACE(*YES)
CRTSRVPGM SRVPGM(LISTMSGF) EXPORT(*ALL)
You now have a working service program to retrieve the message descriptions from the message file.
The next step is to take this service program, specifically the getMessages subprocedure, and create your UDTF. This is accomplished using SQL's CREATE FUNCTION statement:
CREATE FUNCTION MYLIB/GetMessages(Library VARCHAR (10),
MessageFile VARCHAR (10))
RETURNS TABLE ( MsgID CHAR (7 ),
MsgSev DECIMAL (2 , 0),
MsgDesc VARCHAR (500 ),
MsgHelp VARCHAR (500 ))
LANGUAGE RPGLE
EXTERNAL NAME 'MYLIB/LISTMSGF(GETMESSAGES)'
PARAMETER STYLE DB2SQL
DISALLOW PARALLEL
NO SQL
NO FINAL CALL
When executed, this statement builds a bridge between your getMessages subprocedure and the SQL table function by the same name. The two parameters identified in parentheses (Library and MessageFile) identify the UDTF's input parameters. The following RETURNS TABLE clause identifies the parameters returned by the function that will act as the fields in our resulting table--in this case, the message ID, message severity, message description, and message help text. The LANGUAGE RPGLE clause identifies that the called program is an RPGLE program. The EXTERNAL NAME clause identifies the service program and subprocedure to be called. The PARAMETER STYLE DB2SQL clause defines how parameters are passed to the subprocedure. This identifier triggers the passing of null indicators and SQL information to and from the subprocedure. The DISALLOW PARALLEL clause tells DB2 that the function must not be called in parallel. The NO SQL clause simply defines that the program being called doesn't contain any SQL statements. The NO FINAL CALL clause tells DB2 not to initiate a final call to the program once end of file has been reached. In the case of this application, this final call is not required; however, in some cases a final call may be necessary in order for your application to perform cleanup tasks.
It's a good idea to save the CREATE FUNCTION statement to a source file member and execute it using the Run SQL Statement (RUNSQLSTM) command shown here:
RUNSQLSTM SRCFILE(mylib/QSQLSRC)
SRCMBR(LISTMSGF)
This statement assumes that you've saved the CREATE FUNCTION statement to source physical file QSQLSRC under the member name LISTMSGF.
Now that you have your UDTF, you're ready to execute a call. You can do this using interactive SQL (STRSQL). The SELECT statement shown below utilizes the new UDTF:
SELECT *
FROM TABLE(mylib/getmessages('QSYS ','QCPFMSG ')) AS Messages
WHERE Upper(MsgDesc) like '%FILE%'
The key to this SQL SELECT statement is the TABLE function. This identifies that we want to retrieve records from an SQL UDTF. Note that the first parameter identifies the library containing your message file, while the second identifies your message file itself. The alias for our data is defined using the "AS Messages" qualifier. This example includes a WHERE clause to illustrate the fact that you can filter the results from your UDTF using standard SQL logic. Figure 1 shows what the results from this statement look like.
Figure 1: Here's your output from the getMessages UDTF. (Click image to enlarge.)
You'll notice that each message displayed contains the word "file" somewhere in the message description. You could just as easily retrieve a single message based on the MsgID value.
The Real Power of UDTFs
Perhaps the most powerful reasons to use UDTFs is the fact that a single UDTF can be accessed from any application or utility that has the capability of making SQL calls to the System i. This includes not only applications running on the System i, written in programming languages that include embedded SQL commands, but also applications running on other platforms using ADO, ODBC, or JDBC. In the case of the example here, that means that you can write Windows applications that have access to standard messages in a System i message file.
LATEST COMMENTS
MC Press Online