In multi-application, mixed-platform environments, it's often necessary to have a job run on platform A to collect data for a job to be run on platform B. Since these diverse platforms often do not know how to "speak" to each other, one common solution has been to put the jobs on separate job schedulers, hope they run correctly, and merge the data later. However, for remote servers with SQL database engines, you can easily kick off a stored procedure (i.e., program) from the iSeries using Java.
As an example, we'll have the iSeries execute a simple stored procedure on an SQL Server machine and return the results to an RPG program. This method is so transparent that you won't be able to tell whether the stored procedures were executed on your local iSeries or on a database server on the other side of the world!
To use this technique, the iSeries requires a minimum of OS/400 V4R5, the Developer Kit for Java 5722-JV1, and Toolbox for Java 5722-JC1. To use the SQL Server demonstration, you'll need SQL Server 2000 (or the Microsoft Desktop Engine 2000) and the SQL Server 2000 JDBC driver (Service Pack 2). The sample RPG program uses embedded SQL and therefore requires the SQL Development Kit to be installed. Alternatively, if you're on at least a V5R2 system, the RPG program can be rewritten as a DB2 SQL stored procedure, thereby potentially eliminating the need for the SQL Development Kit.
The hypothetical example shown in Figure 1 consists of a financial app running on the iSeries that needs information from an SQL Server hosted order entry app before it can finish.
Figure 1: JDBC can bridge the communication gap between database servers. In this example, the iSeries executes and retrieves the results from a stored procedure running on a remote database server. (Click image to enlarge.)
A Quick Review
In "Query Remote Database Tables from the iSeries Using SQL and Java," I demonstrated how a user-defined table function (requires V5R2) can be written to allow the iSeries to execute a query on SQL Server (or any database that has a JDBC driver) and treat the result set as though it were a local table.
You may need to review the following topics covered in that article:
- How to install the SQL Server JDBC driver jar files so that DB2 SQL can use them
- Where to place Java classes so that DB2 SQL can use them
The SQL Server Stored Procedure
Figure 2 shows the spDailySales T-SQL stored procedure that I created in the "pubs" sample database that comes with SQL Server. (T-SQL is the name of SQL Server's SQL dialect.) The pubs database tracks orders from a chain of bookstores. This stored procedure returns information via output parameters about a given day's sales, including the top-selling book. The procedure has one input parameter and seven output parameters.
|
Figure 2: Stored procedure spDailySales summarizes order data for a given day.
The Java Link
To allow the iSeries to communicate with SQL Server, we'll use Java's database capabilities. DailySales.java is a standalone Java program that establishes a connection with SQL Server and executes the spDailySales stored procedure. The CallableStatement class from the java.sql package is used when running a stored procedure that returns parameters.
Once we have a Java program written, how will we run it? Options include using Qshell, the Java Native Interface (JNI), etc. But one of the easiest is to make the program executable as an external stored procedure. This method allows us to use SQL's CALL statement to run the Java code and allows non-Java programmers to easily call the remote procedure. We'll need to modify DailySales.java slightly to do this.
Creating an iSeries Stored Procedure Wrapper: Two Paths to Travel
There are two options for creating a stored procedure wrapper around a Java class. The first method is to extend a special IBM-supplied class called StoredProc. The second is to create a Java class according to the SQLJ standard specification. (SQLJ is a group of companies consisting of IBM, Oracle, and others that meet for the purpose of defining standards for how SQL interacts with Java.)
We'll create two stored procedures and two Java programs on the iSeries to demonstrate both options:
- Procedure spDailySalesDB2, which conforms to the DB2General parameter style and uses Java class DailySalesDB2.class to connect to SQL Server
- Procedure spDailySalesSQLJ, which conforms to the SQLJ standard and uses Java class DailySalesSQLJ.class to connect to SQL Server
Don't be intimidated by the two options; the external stored procedure definitions and Java programs are almost identical.
Option 1: DB2 Stored Procedure Wrapper
DailySalesDB2.java contains the revamped code designed to be called as a stored procedure from the iSeries.
Here is the statement required to register the class for use with SQL as an external stored procedure:
(SaleDate IN Date,
Qty OUT Integer,
No_Orders OUT Integer,
No_Books OUT Integer,
Sales OUT Dec(19,4),
TopID OUT VarChar(6),
TopTitle OUT VarChar(80),
TopSales OUT Dec(19,4))
Language Java
Parameter Style DB2General
External Name 'DailySalesDB2.dailySales'
Returns Null on Null Input
Not Deterministic
No SQL
Language Java specifies that the stored procedure is written in Java. The Parameter Style of DB2General indicates that the Java class being invoked will extend IBM's StoredProc class. The External Name keyword identifies method dailySales of class DailySalesDB2 as the method to run when DB2 runs the stored procedure.
Notice that the DB2 procedure signature (parameter list) is virtually identical to the signature in the SQL Server stored procedure. Since method dailySales will be run when the iSeries stored procedure is called, it must have a parameter list that is compatible with the stored procedure's signature. If you need help mapping data types between SQL and Java, see the section entitled "Parameter passing conventions for Java stored procedures and UDFs" in the IBM Developer Kit for Java.
Returning output parameters to DB2 is more than just populating parameter variables with values. StoredProc provides method set(), which must be called if parameter data is to be returned.
Passing NULLs with Primitive Types
Since Java's primitive types such as int and double cannot contain NULL values, the set method can be used as a mechanism for controlling whether the output parameters passed back to DB2 are NULL (similar to how a NULL indicator variable works in embedded SQL). In DailySalesDB2.java, the set method is conditionally invoked for "primitive" columns if the SQL Server stored procedure did not return a NULL.
if (!stmtDailySales.wasNull()) {
set(2, parmQty);
}
Set() takes two arguments: parameter number and value. The parameter number refers to the position of the parameter in the parameter list and is only useful for returning output parameters. If you do not call set for a given output parameter, the parameter will contain a NULL. You do not need to condition set when using non-primitives such as String variables, because they can contain NULLs. (Though not demonstrated, the companion isNull method inherited from StoredProc can be used to query if an input parameter for a primitive type is NULL.)
Once the parameters are set and the dailySales method is ended, control is returned to the database manager.
A Slight Detour: Dealing with String Parameter Data
One thing should be mentioned about passing string data between SQL and Java. CHAR and VARCHAR parameters are tagged with a default coded character set ID (CCSID) of 65535. This simply means that the string data is not necessarily associated with any particular character set. However, since Java stores its string data in Unicode, it needs to know what specific CCSID SQL is using so that the data can be translated correctly between an iSeries character set and Unicode. When the JNI encounters a parameter that has a CCSID of 65535, it will look to the job's CCSID to find out how the data should be translated to or from Unicode. If the string parameter's CCSID is 65535 and the job's CCSID is 65535, then the stored procedure call will fail because the string data cannot be translated. The lesson here is that if your jobs have a default CCSID of 65535, you'll have to override this setting to get Java and SQL to work together. You can easily do this with the Change Job command's CCSID parameter: CHGJOB CCSID(37).
As an alternative to changing the job's CCSID, the CCSID keyword may be specified on string data as follows:
TopTitle OUT VarChar(80) CCSID 37,
Specifying a CHAR or VARCHAR parameter with the optional CCSID parameter allows the correct translation between the iSeries character set and Unicode. However, while this technique worked with simple examples I tested with character parameters, I was not able to get it to work with the spDailySales stored procedures, probably because these procedures use the date data type. (The SQL date data type is problematic because, in my mind, it is a specialized character variable, but the CREATE PROCEDURE statement doesn't allow a CCSID to be specified on a date parameter.) I'm guessing that the job's CCSID is used to learn how to translate date data between Java and SQL.
For your troubleshooting pleasure, on a V5R3 system, I received message SQL4304 with a reason code 4 when my job's CCSID was set to 65535. This useless error mentioned nothing of the CCSID issue, and I only bring it up in case you encounter it.
Option 2: SQLJ Stored Procedure Wrapper
DailySalesSQLJ.java shows an alternative way to create a stored procedure wrapper for a Java program. In this example, there is no special class to be extended. Under the SQLJ specification, the method to be called must be a non-instance method (i.e., public void static). Additionally, the specification states that output parameters are to be defined as single element arrays. Finally, there is no mechanism for passing NULLs to primitive types such as int. If you need to test or return a NULL primitive parameter, then you have to implement an alternative solution, such as using extra parameters to serve as "null indicators."
Here is the CREATE PROCEDURE statement required to register the SQLJ-compatible Java program.
(SaleDate IN Date,
Qty OUT Integer,
No_Orders OUT Integer,
No_Books OUT Integer,
Sales OUT Dec(19,4),
TopID OUT VarChar(6),
TopTitle OUT VarChar(80),
TopSales OUT Dec(19,4))
Language Java
Parameter Style Java
External Name 'DailySalesSQLJ.dailySales'
Returns Null on Null Input
Not Deterministic
No SQL
The Parameter Style of Java is the only main difference from the prior CREATE PROCEDURE example. It indicates that the SQLJ standard was followed when writing the stored procedure code.
Note for V5R2 users: You may receive an SQL4304 error when running a Java stored procedure with the Java parameter style. This is apparently due to a setup bug in V5R2 and can be corrected with the following command:
NEWLNK('/qibm/userdata/Java400/ext/runtime.zip')
Which Option to Use When Creating a Java Stored Procedure?
Other than the NULL primitive issue and a few SQL-to-Java data mapping issues, there isn't much difference between the SQLJ and DB2 approaches to writing stored procedures using Java. The DB2 standard exists for things that are missing or inadequate in the SQLJ standard, such as allowing nullable parameters with primitive data types or user-defined table functions. However, for maximum portability to non-DB2 databases, the SQLJ standard should be used when writing SQL routines.
A Reminder on Creating Java Programs for Use with SQL
Don't forget to register the SQL Server JDBC driver's jar files (see "SQLJ procedures that manipulate JAR files" in the IBM Developer Kit for Java).
Don't forget that the .class files for all SQL routines (user-defined functions, user-defined table functions, and stored procedures) written in Java need to be placed in the special folder /qibm/userdata/os400/sqllib/function. See the program header for sample compilation instructions. During testing, once you re-compile the Java program, you may need to sign off and sign back on for the new program to take effect.
Once your code is working correctly, issue the CRTJVAPGM command to optimize the class file for running on the iSeries.
Running the SQL Server Stored Procedure from the iSeries
Now we have our Java program written to call the SQL Server stored procedure, and the iSeries stored procedure is defined to call the Java program, so the only step remaining is to call the stored procedure in a program. Because the stored procedure returns output parameters, we'll use embedded SQL to retrieve the results of the output parameters into host variables in an RPG program. (Of course, this can be done in any high-level language or even in SQL.)
Program DailySales.sqlrpgle.txt is used to execute the remote stored procedure. As shown here, a simple compiler directive allows you to choose which version of the stored procedure is called:
C/Exec SQL
C+
C+ -- Call DB2General Stored Procedure (DB2 Specific extends
C+ -- StoredProc class)
C+
C+ Call spDailySalesDB2 (:SaleDate,
C+ :Qty:NI,
C+ :No_Orders:NI,
C+ :No_Books:NI,
C+ :Sales:NI,
C+ :TopID:NI,
C+ :TopTitle:NI,
C+ :TopSales:NI)
C/End-Exec
/Else
C/Exec SQL
C+
C+ -- Call SQLJ Stored Procedure (Generic class
C+ -- conforms to SQLJ standard)
C+
C+ Call spDailySalesSQLJ (:SaleDate,
C+ :Qty:NI,
C+ :No_Orders:NI,
C+ :No_Books:NI,
C+ :Sales:NI,
C+ :TopID:NI,
C+ :TopTitle:NI,
C+ :TopSales:NI)
C/End-Exec
/EndIf
Of course, in the real world, you probably wouldn't use the same null indicator variable for more than one host variable as I've done!
When the RPG program runs the stored procedure, the following occurs:
- DB2 calls the Java program.
- The Java program establishes a connection with SQL Server.
- The Java program calls the SQL Server stored procedure and retrieves the output variables.
- The Java program passes the output variables back to DB2.
- DB2 passes the host variables back to the RPG program.
- The RPG program displays the results from SQL Server.
In this example, the iSeries stored procedure call is used to retrieve data from SQL Server during a nightly iSeries batch run. With this technique, only one system is required to control a batch process that can run on multiple platforms. Further, the job can act upon any error handling and take appropriate action. This eliminates the uncertainty of working with two separate jobs on different systems that need to share data.
Food for Further Thought
This example only demonstrates retrieving output parameters from a stored procedure. If your stored procedure returns result sets, you have the option of writing the data to a temporary table or combining the technique described here with the technique described in the table function article ("Query Remote Database Tables from the iSeries Using SQL and Java"). With the table function, the result set of a remote stored procedure can become the output for a table function.
Remote stored procedure execution using Java allows the iSeries to perform real-time execution of stored procedures on other platforms. Wrapping the Java program with a stored procedure reduces complex Java integration to a simple CALL statement. Putting multiple database servers under the control of a single iSeries job can streamline and simplify multi-platform data integration issues.
LATEST COMMENTS
MC Press Online