IBM Books

SQL Reference

CALL

Invokes a procedure stored at the location of a database. A stored procedure, for example, executes at the location of the database, and returns data to the client application.

Programs using the SQL CALL statement are designed to run in two parts, one on the client and the other on the server. The server procedure at the database runs within the same transaction as the client application. If the client application and stored procedure are on the same partition, the stored procedure is executed locally.

Invocation

This statement can only be embedded in an application program. It is an executable statement that cannot be dynamically prepared. However, the procedure name may be specified via a host variable and this, coupled with the use of the USING DESCRIPTOR clause, allows both the procedure name and the parameter list to be provided at run time; thus achieving the same effect as a dynamically prepared statement.

Authorization

The authorization rules vary according to the server at which the procedure is stored.

DB2 Universal Database:
The privileges held by the authorization ID of the CALL statement at run time statement must include at least one of the following:

DB2 Universal Database for OS/390:
The privileges held by the authorization ID of the CALL statement at bind time must include at least one of the following:

DB2 for AS/400:
The privileges held by the authorization ID of the CALL statement at bind time must include at least one of the following:

Syntax

>>-CALL----+-procedure-name-+----------------------------------->
           '-host-variable--'
 
>-----+---------------------------------------+----------------><
      +-(--+---------------------------+---)--+
      |    |  .-,--------------------. |      |
      |    |  V               (1)    | |      |
      |    '----host-variable--------+-'      |
      '-USING--DESCRIPTOR--descriptor-name----'
 

Notes:

  1. Stored procedures located at DB2 Universal Database for OS/390 and DB2 Universal Database for AS/400 servers and invoked by DB2 Universal Database for OS/390 or DB2 Universal Database for AS/400 clients support additional sources for procedure arguments (for example constant values). However, if the stored procedure is located on a DB2 Universal Database or the procedure is invoked from a DB2 Universal Database client, all arguments must be provided via host variables.

Description

procedure-name  or  host-variable
Identifies the procedure to call. The procedure name may be specified either directly or within a host variable. The procedure identified must exist at the current server (SQLSTATE 42724).

If procedure-name is specified it must be an ordinary identifier not greater than 254 bytes. Since this can only be an ordinary identifier, it cannot contain blanks or special characters and the value is converted to upper case. Thus, if it is necessary to use lower case names, blanks or special characters, the name must be specified via a host-variable.

If host-variable is specified, it must be a character-string variable with a length attribute that is not greater than 254 bytes, and it must not include an indicator variable. Note that the value is not converted to upper case. procedure-name must be left-justified.

The procedure name can take one of several forms. The forms supported vary according to the server at which the procedure is stored.

DB2 Universal Database:

procedure-name
The name (with no extension) of the procedure to execute. The procedure invoked is determined as follows.

  1. The procedure-name is used both as the name of the stored procedure library and the function name within that library. For example, if procedure-name is proclib, the DB2 server will load the stored procedure library named proclib and execute the function routine proclib() within that library.

    In UNIX-based systems, the DB2 server finds the stored procedure library in the default directory sqllib/function. Unfenced stored procedures are in the sqllib/function/unfenced directory.

    In OS/2, the location of the stored procedures is specified by the LIBPATH variable in the CONFIG.SYS file. Unfenced stored procedures are in the sqllib\dll\unfenced directory.

  2. If the library or function could not be found, the procedure-name is used to search the defined procedures (in SYSCAT.PROCEDURES) for a matching procedure. A matching procedure is determined using the steps that follow.

    1. Find the procedures from the catalog (SYSCAT.PROCEDURES) where the PROCNAME matches the procedure-name specified and the PROCSCHEMA is a schema name in the SQL path (CURRENT PATH special register). If the schema name is explicitly specified, the SQL path is ignored and only procedures with the specified schema name are considered.

    2. Next, eliminate any of these procedures that do not have the same number of parameters as the number of arguments specified in the CALL statement.

    3. Chose the remaining procedure that is earliest in the SQL path.

    4. If there are no remaining procedures after step 2, an error is returned (SQLSTATE 42884).

    Once the procedure is selected, DB2 will invoke the procedure defined by the external name.

procedure-library!function-name
The exclamation character (!) , acts as a delimiter between the library name and the function name of the stored procedure. For example, if proclib!func was specified, then proclib would be loaded into memory and the function func from that library would be executed. This allows multiple functions to be placed in the same stored procedure library.

The stored procedure library is located in the directories or specified in the LIBPATH variable, as described in procedure-name.

absolute-path!function-name
The absolute-path specifies the complete path to the stored procedure library.

In a UNIX-based system, for example, if /u/terry/proclib!func was specified, then the stored procedure library proclib would be obtained from the directory /u/terry and the function func from that library would be executed.

In OS/2, if d:\terry\proclib!func was specified, then it would cause the database manager to load the func.dll file from the d:\terry\proclib directory.

In all these cases, the total length of the procedure name including its implicit or explicit full path must not be longer than 254 bytes.

DB2 Universal Database for OS/390 (V4.1 or later) server:
An implicit or explicit three part name. The parts are as follows.

high order:
The location name of the server where the procedure is stored.

middle:
SYSPROC

middle:
Some value in the PROCEDURE column of the SYSIBM.SYSPROCEDURES catalog table.

DB2 for OS/400 (V3.1 or later) server:
The external program name is assumed to be the same as the procedure-name.

For portability, procedure-name should be specified as a single token no larger than 8 bytes.

(host-variable,...)
Each specification of host-variable is a parameter of the CALL. The nth parameter of the CALL corresponds to the nth parameter of the server's stored procedure.

Each host-variable is assumed to be used for exchanging data in both directions between client and server. In order to avoid sending unnecessary data between client and server, the client application should provide an indicator variable with each parameter and set the indicator to -1 if the parameter is not used to transmit data to the stored procedure. The stored procedure should set the indicator variable to -128 for any parameter that is not used to return data to the client application.

If the server is DB2 Universal Database the parameters must have matching data types in both the client and server program. 58

USING DESCRIPTOR descriptor-name
Identifies an SQLDA that must contain a valid description of host variables. The nth SQLVAR element corresponds to the nth parameter of the server's stored procedure.

Before the CALL statement is processed, the application must set the following fields in the SQLDA:

Each SQLDA is assumed to be used for exchanging data in both directions between client and server. In order to avoid sending unnecessary data between client and server, the client application should set the SQLIND field to -1 if the parameter is not used to transmit data to the stored procedure. The stored procedure should set the SQLIND field -128 for any parameter that is not used to return data to the client application.

Notes

Examples

Example 1: 

In C, invoke a procedure called TEAMWINS in the ACHIEVE library passing it a parameter stored in the host variable HV_ARGUMENT.

   strcpy(HV_PROCNAME, "ACHIEVE!TEAMWINS");
   CALL :HV_PROCNAME (:HV_ARGUMENT);

Example 2: 

In C, invoke a procedure called :SALARY_PROC using the SQLDA named INOUT_SQLDA.

   struct sqlda *INOUT_SQLDA;
 
  /* Setup code for SQLDA variables goes here */
 
   CALL :SALARY_PROC 
   USING DESCRIPTOR :*INOUT_SQLDA;

Example 3: 

A Java stored procedure is defined in the database using the following statement:

   CREATE PROCEDURE PARTS_ON_HAND (IN  PARTNUM  INTEGER, 
                                  OUT COST     DECIMAL(7,2), 
                                  OUT QUANTITY INTEGER)
                    EXTERNAL NAME 'parts!onhand' 
                    LANGUAGE JAVA PARAMETER STYLE DB2GENERAL;

A Java application calls this stored procedure using the following code fragment:

  ... 
  CallableStatement stpCall ;
 
  String sql = "CALL PARTS_ON_HAND ( ?,?,? )" ;
 
  stpCall = con.prepareCall( sql ) ; /* con is the connection */
 
  stpCall.setInt( 1, variable1 ) ;
  stpCall.setBigDecimal( 2, variable2 ) ;
  stpCall.setInt( 3, variable3 ) ;
 
  stpCall.registerOutParameter( 2, Types.DECIMAL, 2 ) ;
  stpCall.registerOutParameter( 3, Types.INTEGER ) ;
 
  stpCall.execute() ;
 
  variable2 = stpCall.getBigDecimal(2) ;
  variable3 = stpCall.getInt(3) ;
  ...  

This application code fragment will invoke the Java method onhand in class parts since the procedure-name specified on the CALL statement is found in the database and has the external name 'parts!onhand'.


Footnotes:

58
DB2 Universal Database for OS/390 and DB2 Universal Database for AS/400 servers support conversions between compatible data types when invoking their stored procedures. For example, if the client program uses the INTEGER data type and the stored procedure expects FLOAT, the server will convert the INTEGER value to FLOAT before invoking the procedure.


[ Top of Page | Previous Page | Next Page | Table of Contents | Index ]

[ DB2 List of Books | Search the DB2 Books ]