CREATE PROCEDURE (SQL - native)

The CREATE PROCEDURE statement defines an SQL procedure at the current server and specifies the source statements for the procedure.

You can define multiple versions of the procedure. CREATE PROCEDURE is used to define the initial version, and ALTER PROCEDURE is used to define subsequent versions.

For information about the SQL control statements that are supported in native SQL procedures, refer to SQL control statements for SQL routines.

Invocation

This statement can only be dynamically prepared, and the DYNAMICRULES run behavior must be specified implicitly or explicitly.

Authorization

The privilege set that is defined below must include at least one of the following:

  • The CREATEIN privilege on the schema and the required authorization to add a new package or a new version of an existing package depending on the value of the BIND NEW PACKAGE field on installation panel DSNTIPP
  • SYSADM authority
  • SYSCTRL authority
  • Start of changeSystem DBADMEnd of change

The authorization ID that matches the schema name implicitly has the CREATEIN privilege on the schema.

Start of changeIf a distinct type is referenced (as the data type of a parameter or SQL variable), the privilege set must also include at least one of the following privileges or authorities:End of change

  • Ownership of the distinct type
  • The USAGE privilege on the distinct type
  • SYSADM authority
Start of changeIf the procedure uses a table as a parameter, the privilege set must also include at least one of the following privileges or authorities:
  • Ownership of the table
  • The SELECT privilege on the table
  • SYSADM authority
End of change

Additional authorization may be required on the SYSDUMMYx tables depending on the content of the procedure definition. See SYSDUMMYx tables.

Start of changeIf the authorization ID that is used to create the procedure has installation SYSADM authority, the procedure is identified as system-defined procedure.End of change

Privilege set: The privilege set is the privileges that are held by the SQL authorization ID of the process unless the process is within a trusted context and the ROLE AS OBJECT OWNER clause is specified. In that case, the privileges set is the privileges that are held by the role that is associated with the primary authorization ID of the process and the owner is that role.

If the statement is not running in a trusted context for which the ROLE AS OBJECT OWNER clause is specified, the privilege set is the set of privileges that are held by the SQL authorization ID of the process. If the schema name is not the same as the SQL authorization ID of the process, one of the following conditions must be met:

  • The privilege set includes SYSADM or SYSCTRL authority.
  • The SQL authorization ID of the process has the CREATEIN privilege on the schema.

The privilege set must also include the privileges required to execute the statements in SQL-routine-body.

If you specify the WLM ENVIRONMENT FOR DEBUG MODE clause, RACF® or an external security product is invoked to check the required authority for defining programs in the WLM environment. If the WLM environment access is protected in RACF, the privilege set must include the required authority.

The owner of the procedure is the SQL authorization ID in the CURRENT SQLID special register unless the process is running within a trusted context and the ROLE AS OBJECT OWNER clause is specified. In that case, the owner of the procedure is the role that is associated with the primary authorization ID of the process.

The owner is implicitly given the EXECUTE privilege with the GRANT option for the procedure.

Syntax

Read syntax diagram
>>-CREATE PROCEDURE--procedure-name----------------------------->

>--+-----------------------------------------+------------------>
   '-(--+-------------------------------+--)-'   
        | .-,-------------------------. |        
        | V                           | |        
        '---| parameter-declaration |-+-'        

   .-VERSION V1-------------------.                        
>--+------------------------------+--+-----------------+-------->
   '-VERSION-- routine-version-id-'  '-| option-list |-'   

>--SQL-routine-body--------------------------------------------><

parameter-declaration:

Read syntax diagram
   .-IN----.                                       
>>-+-------+--parameter-name--| parameter-type |---------------><
   +-OUT---+                                       
   '-INOUT-'                                       

parameter-type:

Read syntax diagram
>>-+-| data-type |--------------------------+------------------><
   '-TABLE LIKE--+-table-name-+--AS LOCATOR-'   
                 '-view-name--'                 

Start of change

data-type:

End of change
>>-+-| built-in-type |--+--------------------------------------><
   '-distinct-type-name-'   

built-in-type:

>>-+-+-SMALLINT----+-------------------------------------------------------------------------------------------------+-><
   | +-+-INTEGER-+-+                                                                                                 |   
   | | '-INT-----' |                                                                                                 |   
   | '-BIGINT------'                                                                                                 |   
   |              .-(5,0)--------------------.                                                                       |   
   +-+-DECIMAL-+--+--------------------------+-----------------------------------------------------------------------+   
   | +-DEC-----+  '-(integer-+-----------+-)-'                                                                       |   
   | '-NUMERIC-'             '-, integer-'                                                                           |   
   |          .-(53)------.                                                                                          |   
   +-+-FLOAT--+-----------+--+---------------------------------------------------------------------------------------+   
   | |        '-(integer)-'  |                                                                                       |   
   | +-REAL------------------+                                                                                       |   
   | |         .-PRECISION-. |                                                                                       |   
   | '-DOUBLE--+-----------+-'                                                                                       |   
   |           .-(34)-.                                                                                              |   
   +-DECFLOAT--+------+----------------------------------------------------------------------------------------------+   
   |           '-(16)-'                                                                                              |   
   |                    .-(1)-------.                                                                                |   
   +-+-+-+-CHARACTER-+--+-----------+----------+----+--------------------+--+----------------------+---------------+-+   
   | | | '-CHAR------'  '-(integer)-'          |    '-CCSID--+-ASCII---+-'  '-FOR--+-SBCS--+--DATA-'               | |   
   | | '-+-+-CHARACTER-+--VARYING-+--(integer)-'             +-EBCDIC--+           +-MIXED-+                       | |   
   | |   | '-CHAR------'          |                          '-UNICODE-'           '-BIT---'                       | |   
   | |   '-VARCHAR----------------'                                                                                | |   
   | |                                  .-(1M)-------------.                                                       | |   
   | '-+-+-CHARACTER-+--LARGE OBJECT-+--+------------------+----+--------------------+--+----------------------+---' |   
   |   | '-CHAR------'               |  '-(integer-+---+-)-'    '-CCSID--+-ASCII---+-'  '-FOR--+-SBCS--+--DATA-'     |   
   |   '-CLOB------------------------'             +-K-+                 +-EBCDIC--+           '-MIXED-'             |   
   |                                               +-M-+                 '-UNICODE-'                                 |   
   |                                               '-G-'                                                             |   
   |            .-(1)-------.                                                                                        |   
   +-+-GRAPHIC--+-----------+-------+--+--------------------+--------------------------------------------------------+   
   | |          '-(integer)-'       |  '-CCSID--+-ASCII---+-'                                                        |   
   | +-VARGRAPHIC--(--integer--)----+           +-EBCDIC--+                                                          |   
   | |         .-(1M)-------------. |           '-UNICODE-'                                                          |   
   | '-DBCLOB--+------------------+-'                                                                                |   
   |           '-(integer-+---+-)-'                                                                                  |   
   |                      +-K-+                                                                                      |   
   |                      +-M-+                                                                                      |   
   |                      '-G-'                                                                                      |   
   |           .-(1)-------.                                                                                         |   
   +-+-BINARY--+-----------+-------------------------+---------------------------------------------------------------+   
   | |         '-(integer)-'                         |                                                               |   
   | +-+-BINARY VARYING-+-(integer)------------------+                                                               |   
   | | '-VARBINARY------'                            |                                                               |   
   | |                          .-(1M)-------------. |                                                               |   
   | '-+-BINARY LARGE OBJECT-+--+------------------+-'                                                               |   
   |   '-BLOB----------------'  '-(integer-+---+-)-'                                                                 |   
   |                                       +-K-+                                                                     |   
   |                                       +-M-+                                                                     |   
   |                                       '-G-'                                                                     |   
   +-+-DATE------------------------------------------------+---------------------------------------------------------+   
   | +-TIME------------------------------------------------+                                                         |   
   | |            .-(--6--)-------.  .-WITHOUT TIME ZONE-. |                                                         |   
   | '-TIMESTAMP--+---------------+--+-------------------+-'                                                         |   
   |              '-(--integer--)-'  '-WITH TIME ZONE----'                                                           |   
   '-XML-------------------------------------------------------------------------------------------------------------'   

option-list: (The options can be specified in any order, but each one can only be specified one time.)

   .-LANGUAGE SQL-.  .-NOT DETERMINISTIC-.  .-MODIFIES SQL DATA-.  .-CALLED ON NULL INPUT-.   
>>-+--------------+--+-------------------+--+-------------------+--+----------------------+-->
                     '-DETERMINISTIC-----'  +-READS SQL DATA----+                             
                                            '-CONTAINS SQL------'                             

   .-DYNAMIC RESULT SETS 0--------.                                                                                     
>--+------------------------------+--+---------------------+--+-------------------------+--+------------------------+-->
   '-DYNAMIC RESULT SETS--integer-'  +-DISALLOW DEBUG MODE-+  +-PARAMETER CCSID ASCII---+  '-QUALIFIER--schema-name-'   
                                     +-ALLOW DEBUG MODE----+  +-PARAMETER CCSID EBCDIC--+                               
                                     '-DISABLE DEBUG MODE--'  '-PARAMETER CCSID UNICODE-'                               

                                          .-ASUTIME NO LIMIT-------.  .-COMMIT ON RETURN NO--.  .-INHERIT SPECIAL REGISTERS-.   
>--+-----------------------------------+--+------------------------+--+----------------------+--+---------------------------+-->
   '-PACKAGE OWNER--authorization-name-'  '-ASUTIME LIMIT--integer-'  '-COMMIT ON RETURN YES-'  '-DEFAULT SPECIAL REGISTERS-'   

                                                                  .-CURRENT DATA NO--.  .-DEGREE 1---.   
>--+--------------------------------------+--+-----------------+--+------------------+--+------------+-->
   '-WLM ENVIRONMENT FOR DEBUG MODE--name-'  +-DEFER PREPARE---+  '-CURRENT DATA YES-'  '-DEGREE ANY-'   
                                             '-NODEFER PREPARE-'                                         

>--+-------------------------------------------------------+---->
   +-CONCURRENT ACCESS RESOLUTION--USE CURRENTLY COMMITTED-+   
   '-CONCURRENT ACCESS RESOLUTION--WAIT FOR OUTCOME--------'   

   .-DYNAMICRULES RUN--------.                                           .-WITHOUT EXPLAIN-.  .-WITHOUT IMMEDIATE WRITE-.   
>--+-------------------------+--+-------------------------------------+--+-----------------+--+-------------------------+-->
   +-DYNAMICRULES BIND-------+  +-APPLICATION ENCODING SCHEME ASCII---+  '-WITH EXPLAIN----'  '-WITH IMMEDIATE WRITE----'   
   +-DYNAMICRULES DEFINEBIND-+  +-APPLICATION ENCODING SCHEME EBCDIC--+                                                     
   +-DYNAMICRULES DEFINERUN--+  '-APPLICATION ENCODING SCHEME UNICODE-'                                                     
   +-DYNAMICRULES INVOKEBIND-+                                                                                              
   '-DYNAMICRULES INVOKERUN--'                                                                                              

   .-ISOLATION LEVEL CS-.  .-WITHOUT KEEP DYNAMIC-.  .-OPTHINT--''--------------.                                               
>--+--------------------+--+----------------------+--+--------------------------+--+----------------------------------------+-->
   +-ISOLATION LEVEL RS-+  '-WITH KEEP DYNAMIC----'  '-OPTHINT--string-constant-'  |             .-,--------------------.   |   
   +-ISOLATION LEVEL RR-+                                                          |             V                      |   |   
   '-ISOLATION LEVEL UR-'                                                          '-SQL PATH------+-schema-name------+-+---'   
                                                                                                   +-SYSTEM PATH------+         
                                                                                                   '-+-SESSION USER-+-'         
                                                                                                     '-USER---------'           

>--+-----------------------------------------+------------------>
   +-QUERY ACCELERATION NONE-----------------+   
   +-QUERY ACCELERATION ENABLE---------------+   
   +-QUERY ACCELERATION ENABLE WITH FAILBACK-+   
   +-QUERY ACCELERATION ELIGIBLE-------------+   
   '-QUERY ACCELERATION ALL------------------'   

>--+-----------------------+------------------------------------>
   +-GET_ACCEL_ARCHIVE NO--+   
   '-GET_ACCEL_ARCHIVE YES-'   

   .-RELEASE AT COMMIT-----.  .-REOPT NONE---.  .-VALIDATE RUN--.                                     
>--+-----------------------+--+--------------+--+---------------+--+------------------------------+-->
   '-RELEASE AT DEALLOCATE-'  +-REOPT ALWAYS-+  '-VALIDATE BIND-'  +-ROUNDING DEC_ROUND_CEILING---+   
                              '-REOPT ONCE---'                     +-ROUNDING DEC_ROUND_DOWN------+   
                                                                   +-ROUNDING DEC_ROUND_FLOOR-----+   
                                                                   +-ROUNDING DEC_ROUND_HALF_DOWN-+   
                                                                   +-ROUNDING DEC_ROUND_HALF_EVEN-+   
                                                                   +-ROUNDING DEC_ROUND_HALF_UP---+   
                                                                   '-ROUNDING DEC_ROUND_UP--------'   

                                             .-FOR UPDATE CLAUSE REQUIRED-.                          
>--+-------------------+--+---------------+--+----------------------------+--+-------------------+-><
   +-DATE FORMAT ISO---+  +-DECIMAL(15)---+  '-FOR UPDATE CLAUSE OPTIONAL-'  +-TIME FORMAT ISO---+   
   +-DATE FORMAT EUR---+  +-DECIMAL(31)---+                                  +-TIME FORMAT EUR---+   
   +-DATE FORMAT USA---+  +-DECIMAL(15,s)-+                                  +-TIME FORMAT USA---+   
   +-DATE FORMAT JIS---+  '-DECIMAL(31,s)-'                                  +-TIME FORMAT JIS---+   
   '-DATE FORMAT LOCAL-'                                                     '-TIME FORMAT LOCAL-'   

SQL-routine-body:

Read syntax diagram
                                                                                                     (1)   
>>-+-SQL-control-statement-------------------------------------------------------------------------+-----><
   +-ALTER DATABASE statement----------------------------------------------------------------------+       
   +-ALTER FUNCTION statement (external scalar, external table, sourced, SQL scalar, or SQL table)-+       
   +-ALTER INDEX statement-------------------------------------------------------------------------+       
   +-ALTER PROCEDURE statement (external, SQL - external, or SQL - native)-------------------------+       
   +-ALTER SEQUENCE statement----------------------------------------------------------------------+       
   +-ALTER STOGROUP statement----------------------------------------------------------------------+       
   +-ALTER TABLE statement-------------------------------------------------------------------------+       
   +-ALTER TABLESPACE statement--------------------------------------------------------------------+       
   +-ALTER TRUSTED CONTEXT statement---------------------------------------------------------------+       
   +-ALTER VIEW statement--------------------------------------------------------------------------+       
   +-COMMENT statement-----------------------------------------------------------------------------+       
   +-COMMIT statement------------------------------------------------------------------------------+       
   +-CONNECT statement-----------------------------------------------------------------------------+       
   +-CREATE ALIAS statement------------------------------------------------------------------------+       
   +-CREATE DATABASE statement---------------------------------------------------------------------+       
   +-CREATE FUNCTION statement (external scalar, external table, or sourced)-----------------------+       
   +-CREATE GLOBAL TEMPORARY TABLE statement-------------------------------------------------------+       
   +-CREATE INDEX statement------------------------------------------------------------------------+       
   +-CREATE PROCEDURE statement (external) --------------------------------------------------------+       
   +-CREATE ROLE statement-------------------------------------------------------------------------+       
   +-CREATE SEQUENCE statement---------------------------------------------------------------------+       
   +-CREATE STOGROUP statement---------------------------------------------------------------------+       
   +-CREATE SYNONYM statement----------------------------------------------------------------------+       
   +-CREATE TABLE statement------------------------------------------------------------------------+       
   +-CREATE TABLESPACE statement-------------------------------------------------------------------+       
   +-CREATE TRUSTED CONTEXT statement--------------------------------------------------------------+       
   +-CREATE TYPE statement-------------------------------------------------------------------------+       
   +-CREATE VIEW statement-------------------------------------------------------------------------+       
   +-DECLARE CURSOR statement----------------------------------------------------------------------+       
   +-DECLARE GLOBAL TEMPORARY TABLE statement------------------------------------------------------+       
   +-DELETE statement------------------------------------------------------------------------------+       
   +-DROP statement--------------------------------------------------------------------------------+       
   +-EXCHANGE statement----------------------------------------------------------------------------+       
   +-EXECUTE IMMEDIATE statement-------------------------------------------------------------------+       
   +-GRANT statement-------------------------------------------------------------------------------+       
   +-INSERT statement------------------------------------------------------------------------------+       
   +-LABEL statement-------------------------------------------------------------------------------+       
   +-LOCK TABLE statement--------------------------------------------------------------------------+       
   +-MERGE statement-------------------------------------------------------------------------------+       
   +-REFRESH TABLE statement-----------------------------------------------------------------------+       
   +-RELEASE statement-----------------------------------------------------------------------------+       
   +-RELEASE SAVEPOINT  statement------------------------------------------------------------------+       
   +-RENAME statement------------------------------------------------------------------------------+       
   +-REVOKE statement------------------------------------------------------------------------------+       
   +-ROLLBACK statement----------------------------------------------------------------------------+       
   +-SAVEPOINT statement---------------------------------------------------------------------------+       
   +-SELECT INTO statement-------------------------------------------------------------------------+       
   +-SET CONNECTION statement----------------------------------------------------------------------+       
   +-SET special-register statement----------------------------------------------------------------+       
   +-TRUNCATE statement----------------------------------------------------------------------------+       
   +-UPDATE statement------------------------------------------------------------------------------+       
   '-VALUES INTO statement-------------------------------------------------------------------------'       

Notes:
  1. An ALTER FUNCTION statement (SQL scalar) or an ALTER PROCEDURE statement (SQL native) with an ADD VERSION or REPLACE clause are not allowed in an SQL-routine-body.

Description

procedure-name
Names the procedure. If procedure-name already exists, an error is returned even if VERSION is specified with a version-id that is different from any existing version identifier for the procedure that is specified in procedure-name.

The schema name can be 'SYSIBM' or 'SYSPROC'. It can also be 'SYSTOOLS' if the user who executes the CREATE statement has SYSADM or SYSCTRL privilege. Otherwise, the schema name must not begin with 'SYS' unless the schema name is 'SYSADM'.

(parameter-declaration,…)
Specifies the number of parameters of the procedure, the data type and usage of each parameter, and the name of each parameter for the version of the procedure that is being defined. The number of parameters and the specified data type and usage of each parameter must match the data types in the corresponding position of the parameter for all other versions of this procedure. Synonyms for data types are considered to be a match. Start of changeAll parameters are nullable.End of change

IN, OUT, and INOUT specify the usage of the parameter. The usage of the parameters must match the implicit or explicit usage of the parameters of other versions of the same procedure.

IN
Identifies the parameter as an input parameter to the procedure. The value of the parameter on entry to the procedure is the value that is returned to the calling SQL application, even if changes are made to the parameter within the procedure.

IN is the default.

OUT
Identifies the parameter as an output parameter that is returned by the procedure. If the parameter is not set within the procedure, the null value is returned.
INOUT
Identifies the parameter as both an input and output parameter for the procedure. If the parameter is not set within the procedure, its input value is returned.
parameter-name
Names the parameter for use as an SQL variable. A parameter name cannot be the same as the name of any other parameter for this version of the procedure. The name of the parameter in this version of the procedure can be different than the name of the corresponding parameter for other versions of this procedure.
built-in-type
The data type of the parameter is a built-in data type.

For more information on the data types, including the subtype of character data types (the FOR subtype DATA clause), see built-in-type. However, the varying length string data types have different maximum lengths than for the CREATE TABLE statement. The maximum lengths for parameters (and SQL variables) are as follows: 32704 for VARCHAR or VARBINARY, and 16352 for VARGRAPHIC.

For parameters with a character or graphic data type, the PARAMETER CCSID clause or CCSID clause indicates the encoding scheme of the parameter. If you do not specify either of these clauses, the encoding scheme is the value of field DEF ENCODING SCHEME on installation panel DSNTIPF.

Although an input parameter with a character data type has an implicitly or explicitly specified subtype (BIT, SBCS, or MIXED), the value that is actually passed in the input parameter can have any subtype. Therefore, conversion of the input data to the subtype of the parameter might occur when the procedure is called. With ASCII or EBCDIC, an error occurs if mixed data that actually contains DBCS characters is used as the value for an input parameter that is declared with an SBCS subtype.

Start of changeParameters with a datetime data type or a distinct type are passed to the function as a different data type:
  • A datetime type parameter is passed as a character data type, and the data is passed in ISO format. The encoding scheme for a datetime type parameter is the same as the implicitly or explicitly specified encoding scheme of any character or graphic string parameters. If no character or graphic string parameters are passed, the encoding scheme is the value of field DEF ENCODING SCHEME on installation panel DSNTIPF.
  • A distinct type parameter is passed as the source type of the distinct type.
End of change
Start of changeAS LOCATOREnd of change
Start of changeSpecifies that a locator to the value of the parameter is passed to the procedure instead of the actual value. Specify AS LOCATOR only for parameters with a LOB data type or a distinct type based on a LOB data type. Passing locators instead of values can result in fewer bytes being passed to the procedure, especially when the value of the parameter is very large.

The AS LOCATOR clause has no effect on determining whether data types can be promoted.

End of change
Start of changedistinct-type-nameEnd of change
Start of changeThe data type of the input parameter is a distinct type. Any length, precision, scale, subtype, or encoding scheme attributes for the parameter are those of the source type of the distinct type. The distinct type must not be based on a LOB data type.End of change
TABLE LIKE table-name AS LOCATOR
Specifies that the parameter is a transition table. However, when the procedure is called, the actual values in the transition table are not passed to the procedure. A single value is passed instead. This single value is a locator to the table, which the procedure uses to access the columns of the transition table. The table that is identified can contain XML columns; however, the procedure cannot reference those XML columns. A procedure with a table parameter can only be invoked from the triggered action of a trigger.
VERSION routine-version-id
Specifies the version identifier for the first version of the procedure that is to be generated. See Naming conventions for information about specifying routine-version-id. You can use an ALTER PROCEDURE statement with the ADD VERSION clause or the BIND DEPLOY command to create additional versions of the procedure.

V1 is the default version identifier.

Important: Start of changeDo not create additional versions of procedures that are supplied with DB2 by specifying the VERSION keyword. Only versions that are supplied with DB2 are supported. Additional versions of such routines cause the installation and configuration of the supplied routines to fail.End of change

See Versions of a procedure for more information about the use of versions for procedures.

LANGUAGE SQL
Specifies that the procedure is written in the DB2 SQL procedural language.
DETERMINISTIC or NOT DETERMINISTIC
Specifies whether the procedure returns the same results each time it is called with the same IN and INOUT arguments.
DETERMINISTIC
The procedure always returns the same results each time it is called with the same IN and INOUT arguments if the data that is referenced in the database has not changed.
NOT DETERMINISTIC
The procedure might not return the same result each time it is called with the same IN and INOUT arguments, even when the data that is referenced in the database has not changed.

NOT DETERMINISTIC is the default.

DB2 does not verify that the procedure code is consistent with the specification of DETERMINISTIC or NOT DETERMINISTIC.

MODIFIES SQL DATA, READS SQL DATA, or CONTAINS SQL
Specifies the classification of SQL statements and nested routines that this routine can execute or invoke. The database manager verifies that the SQL statements issued by the procedure, and all routines locally invoked by the routine, are consistent with this specification; the verification is not performed when nested remote routines are invoked. For the classification of each statement, see SQL statement data access classification for routines.
MODIFIES SQL DATA
Specifies that the procedure can execute any SQL statement except statements that are not supported in procedures.

MODIFIES SQL DATA is the default.

READS SQL DATA
Specifies that the procedure can execute statements with a data access indication of READS SQL DATA or CONTAINS SQL. The procedure cannot execute SQL statements that modify data.
CONTAINS SQL
Specifies that the procedure can execute only SQL statements with a data access indication of CONTAINS SQL. The procedure cannot execute statements that read or modify data.
CALLED ON NULL INPUT
Specifies that the procedure will be called if any, or even if all parameter values are null.
DYNAMIC RESULT SETS integer
Specifies the maximum number of query result sets that the procedure can return. The default is DYNAMIC RESULT SETS 0, which indicates that there are no result sets. The value must be between 0 and 32767.
ALLOW DEBUG MODE, DISALLOW DEBUG MODE, or DISABLE DEBUG MODE
Specifies whether this version of the routine can be run in debugging mode. The default is determined using the value of the CURRENT DEBUG MODE special register.
ALLOW DEBUG MODE
Specifies that this version of the routine can be run in debugging mode. When this version of the routine is invoked and debugging is attempted, a WLM environment must be available.
DISALLOW DEBUG MODE
Specifies that this version of the routine cannot be run in debugging mode.

You can use an ALTER statement to change this option to ALLOW DEBUG MODE for this initial version of the routine.

DISABLE DEBUG MODE
Specifies that this version of the routine can never be run in debugging mode.

This version of the routine cannot be changed to specify ALLOW DEBUG MODE or DISALLOW DEBUG MODE after this version of the routine has been created or altered to use DISABLE DEBUG MODE. To change this option, drop the routine and create it again using the option that you want. An alternative to dropping and recreating the routine is to create a version of the routine that uses the option that you want and making that version the active version.

When DISABLE DEBUG MODE is in effect, the WLM ENVIRONMENT FOR DEBUG MODE is ignored.

PARAMETER CCSID
Indicates whether the encoding scheme for character or graphic string parameters is ASCII, EBCDIC, or UNICODE. The default encoding scheme is the value that is specified in the CCSID clauses of the parameter list, or in the field DEF ENCODING SCHEME on installation panel DSNTIPF.

This clause provides a convenient way to specify the encoding scheme for character or graphic string parameters. If individual CCSID clauses are specified for individual parameters in addition to this PARAMETER CCSID clause, the value that is specified in all of the CCSID clauses must be the same value that is specified in this clause.

If the data type for a parameter is a user-defined distinct type that is defined as a character or graphic type string, the CCSID of the distinct type must be the same as the value that is specified in this clause.

This clause also specifies the encoding scheme that will be used for system-generated parameters of the routine.

QUALIFIER schema-name
Specifies the implicit qualifier that is used for unqualified object names that are referenced in the procedure body. See Unqualified alias, index, JAR file, sequence, table, trigger, and view names for information about how the default for this option is determined.
PACKAGE OWNER authorization-name
Specifies the owner of the package that is associated with the version of the routine. The SQL authorization ID of the process is the default value.

The authorization ID must have the privileges that are required to execute the SQL statements that are contained in the routine body and must contain the necessary bind privileges. The value of PACKAGE OWNER is subject to translation when it is sent to a remote system.

If the privilege set lacks SYSADM or SYSCTRL authority, authorization-name must be the same as one of the authorization IDs of the process or the authorization ID of the process. If the privilege set includes SYSADM or SYSCTRL authority, authorization-name can be any authorization ID that contains the necessary bind privileges.

ASUTIME
Specifies the total amount of processor time, in CPU service units, that a single invocation of a routine can run. The value is unrelated to the ASUTIME column of the resource limit specification table.

When you are debugging a routine, setting a limit can be helpful in case the routine gets caught in a loop. For information on service units, see z/OS MVS Initialization and Tuning Guide.

NO LIMIT
Specifies that there is no limit on the service units.

NO LIMIT is the default.

LIMIT integer
Start of changeThe limit on the number of CPU service units is a positive integer in the range of 1 to 2 147 483 647. If the procedure uses more service units than the specified value, DB2 cancels the procedure. The CPU cycles that are consumed by parallel tasks in a procedure do not contribute towards the specified ASUTIME LIMIT.End of change
COMMIT ON RETURN NO or COMMIT ON RETURN YES
Indicates whether DB2 commits the transaction immediately on return from the procedure.
COMMIT ON RETURN NO
DB2 does not issue a commit when the procedure returns. NO is the default.
COMMIT ON RETURN YES,
DB2 issues a commit when the procedure returns if the following statements are true:
  • The SQLCODE that is returned by the CALL statement is not negative.
  • The procedure is not in a must-abort state.

The commit operation includes the work that is performed by the calling application process and by the procedure.

If the procedure returns result sets, the cursors that are associated with the result sets must have been defined as WITH HOLD to be usable after the commit.

INHERIT SPECIAL REGISTERS or DEFAULT SPECIAL REGISTERS
Specifies how special registers are set on entry to the routine.
INHERIT SPECIAL REGISTERS
Specifies that the values of special registers are inherited, according to the rules that are listed in the table for characteristics of special registers in a routine in Table 1.

INHERIT SPECIAL REGISTERS is the default.

DEFAULT SPECIAL REGISTERS
Specifies that special registers are initialized to the default values, as indicated by the rules in the table for characteristics of special registers in a routine in Table 1.
WLM ENVIRONMENT FOR DEBUG MODE name
Specifies the WLM (workload manager) application environment that is used by DB2 when debugging the routine. The name of the WLM environment is an SQL identifier.

If you do not specify WLM ENVIRONMENT FOR DEBUG MODE, DB2 uses the default WLM-established stored procedure address space specified at installation time.

To define a routine that is to run in a specified WLM application environment, you must have the appropriate authority for the WLM application environment. For an example of a RACF command that provides this authorization, see Running stored procedures.

The WLM ENVIRONMENT FOR DEBUG MODE value is ignored when DISABLE DEBUG MODE is in effect.

DEFER PREPARE or NODEFER PREPARE
Specifies whether to defer preparation of dynamic SQL statements that refer to remote objects, or to prepare them immediately.

The default depends on the value in effect for the REOPT option. If REOPT NONE is in effect, the default is inherited from the plan at run time. Otherwise, the default is DEFER PREPARE.

DEFER PREPARE
Specifies that the preparation of dynamic SQL statements that refer to remote objects will be deferred.

For considerations for distributed processing, see DEFER and NODEFER bind options.

NODEFER PREPARE
Specifies that the preparation of dynamic SQL statements that refer to remote objects will not be deferred.
CURRENT DATA YES or CURRENT DATA NO
Specifies whether to require data currency for read-only and ambiguous cursors when the isolation level of cursor stability is in effect. CURRENT DATA also determines whether block fetch can be used for distributed, ambiguous cursors.
CURRENT DATA YES
Specifies that data currency is required for read-only and ambiguous cursors. DB2 acquired page or row locks to ensure data currency. Block fetch is ignored for distributed, ambiguous cursors.
CURRENT DATA NO
Specifies that data currency is not required for read-only and ambiguous cursors. Block fetch is allowed for distributed, ambiguous cursors. Use of CURRENT DATA NO is not recommended if the routine attempts to dynamically prepare and execute a DELETE WHERE CURRENT OF statement against an ambiguous cursor after that cursor is opened. You receive a negative SQLCODE if your routine attempts to use a DELETE WHERE CURRENT OF statement for any of the following cursors:
  • A cursor that is using block fetch
  • A cursor that is using query parallelism
  • A cursor that is positioned on a row that is modified by this or another application process

CURRENT DATA NO is the default.

DEGREE
Specifies whether to attempt to run a query using parallel processing to maximize performance.
1
Specifies that parallel processing should not be used.

1 is the default.

ANY
Specifies that parallel processing can be used.
Start of changeCONCURRENT ACCESS RESOLUTIONEnd of change
Start of changeSpecifies the whether processing uses only committed data or whether it will wait for commit or rollback of data that is in the process of being updated.
WAIT FOR OUTCOME
Specifies that processing will wait for the commit or rollback of data that is in the process of being updated.
USE CURRENTLY COMMITTED
Specifies that processing use the currently committed version of the data when data that is in the process of being updated is encountered. USE CURRENTLY COMMITTED is applicable on scans that access tables that are defined in universal table spaces with row or page level lock size.

When there is lock contention between a read transaction and an insert transaction, USE CURRENTLY COMMITTED is applicable to scans with isolation level CS or RS. Applicable scans include intent read scans for read-only and ambiguous queries and for updatable cursors. USE CURRENTLY COMMITTED is also applicable to scans initiated from WHERE predicates of UPDATE or DELETE statements and the subselect of INSERT statements.

When there is lock contention is between a read transaction and a delete transaction, USE CURRENTLY COMMITTED is applicable to scans with isolation level CS and when CURRENT DATA NO is specified.

End of change
DYNAMICRULES
Specifies the values that apply, at run time, for the following dynamic SQL attributes:
  • The authorization ID that is used to check authorization
  • The qualifier that is used for unqualified objects
  • The source for application programming options that DB2 uses to parse and semantically verify dynamic SQL statements

DYNAMICRULES also specifies whether dynamic SQL statements can include GRANT, REVOKE, ALTER, CREATE, DROP, and RENAME statements.

In addition to the value of the DYNAMICRULES clause, the run time environment of a routine controls how dynamic SQL statements behave at run time. The combination of the DYNAMICRULES value and the run time environment determines the value for the dynamic SQL attributes. That set of attribute values is called the dynamic SQL statement behavior. The following values can be specified:
RUN
Specifies that dynamic SQL statements are to be processed using run behavior.

RUN is the default.

BIND
Specifies that dynamic SQL statements are to be processed using bind behavior.
DEFINEBIND
Specifies that dynamic SQL statements are to be processed using either define behavior or bind behavior.
DEFINERUN
Specifies that dynamic SQL statements are to be processed using either define behavior or run behavior.
INVOKEBIND
Specifies that dynamic SQL statements are to be processed using either invoke behavior or bind behavior.
INVOKERUN
Specifies that dynamic SQL statements are to be processed using either invoke behavior or run behavior.
See Authorization IDs and dynamic SQL for information on the effects of these options.
APPLICATION ENCODING SCHEME
Specifies the default encoding scheme for SQL variables in static SQL statements in the routine body. The value is used for defining an SQL variable in a compound statement if the CCSID clause is not specified as part of the data type, and the PARAMETER CCSID routine option is not specified.
ASCII
Specifies that the data is encoded using the ASCII CCSIDs of the server.
EBCDIC
Specifies that the data is encoded using the EBCDIC CCSIDs of the server.
UNICODE
Specifies that the data is encoded using the Unicode CCSIDs of the server.

See the ENCODING bind option in ENCODING bind option for information about how the default for this option is determined.

WITH EXPLAIN or WITHOUT EXPLAIN
Specifies whether information will be provided about how SQL statements in the routine will execute.
WITHOUT EXPLAIN
Specifies that information will not be provided about how SQL statements in the routine will execute.

You can get EXPLAIN output for a statement that is embedded in a routine that is specified using WITHOUT EXPLAIN by embedding the SQL statement EXPLAIN in the routine body. Otherwise, the value of the EXPLAIN option applies to all explainable SQL statements in the routine body, and to the fullselect portion of any DECLARE CURSOR statements.

WITHOUT EXPLAIN is the default.

WITH EXPLAIN
Specifies that information will be provided about how SQL statements in the routine will execute. Information is inserted into the table owner.PLAN_TABLE. owner is the authorization ID of the owner of the routine. Alternatively, the authorization ID of the owner of the routine can have an alias as owner.PLAN_TABLE that points to the base table, PLAN_TABLE. owner must also have the appropriate SELECT and INSERT privileges on that table. WITH EXPLAIN does not obtain information for statements that access remote objects. PLAN_TABLE must have a base table and can have multiple aliases with the same table name, PLAN_TABLE, but have different schema qualifiers. It cannot be a view or a synonym and should exist before the version is added or replaced. In all inserts to owner.PLAN_TABLE, the value of QUERYNO is the statement number that is assigned by DB2.

The WITH EXPLAIN option also populates two optional tables if they exist: DSN_STATEMNT_TABLE and DSN_FUNCTION_TABLE. DSN_STATEMNT_TABLE contains an estimate of the processing cost for an SQL statement. See DB2 Application Programming and SQL Guide for more information. DSN_FUNCTION_TABLE contains information about function resolution. See DB2 Application Programming and SQL Guide for more information.

For a description of the tables that are populated by the WITH EXPLAIN option, see EXPLAIN.

WITH IMMEDIATE WRITE or WITHOUT IMMEDIATE WRITE
Specifies whether immediate writes are to be done for updates that are made to group buffer pool dependent page sets or partitions. This option is only applicable for data sharing environments. The IMMEDWRITE subsystem parameter has no affect of this option. IMMEDWRITE bind option shows the implied hierarchy of the IMMEDWRITE bind option (which is similar to this routine option) as it affects run time.
WITHOUT IMMEDIATE WRITE
Specifies that normal write activity is performed. Updated pages that are group buffer pool dependent are written at or before phase one of commit or at the end of abort for transactions that have been rolled back.

WITHOUT IMMEDIATE WRITE is the default.

WITH IMMEDIATE WRITE
Specifies that updated pages that are group buffer pool dependent are immediately written as soon as the buffer update completes. Updated pages are written immediately even if the buffer is updated during forward progress or during the rollback of a transaction. WITH IMMEDIATE WRITE might impact performance.
ISOLATION LEVEL RR, RS, CS, or UR
Specifies how far to isolate the routine from the effects of other running applications. For information about isolation levels, see Managing DB2 Performance.
RR
Specifies repeatable read.
RS
Specifies read stability.
CS
Specifies cursor stability. CS is the default.
UR
Specifies uncommitted read.
WITH KEEP DYNAMIC or WITHOUT KEEP DYNAMIC
Specifies whether DB2 keeps dynamic SQL statements after commit points.
WITHOUT KEEP DYNAMIC
Specifies that DB2 does not keep dynamic SQL statements after commit points.

WITHOUT KEEP DYNAMIC is the default.

WITH KEEP DYNAMIC
Specifies that DB2 keeps dynamic SQL statements after commit points. If you specify WITH KEEP DYNAMIC, the application does not need to prepare an SQL statement after every commit point. DB2 keeps the dynamic SQL statement until one of the following occurs:
  • The application process ends
  • A rollback operations occurs
  • The application executes an explicit PREPARE statement with the same statement identifier as the dynamic SQL statement

If you specify WITH KEEP DYNAMIC, and the prepared statement cache is active, the DB2 subsystem keeps a copy of the prepared statement in the cache. If the prepared statement cache is not active, the subsystem keeps only the SQL statement string past a commit point. If the application executes an OPEN, EXECUTE, or DESCRIBE operation for that statement, the statement is implicitly prepared.

If you specify WITH KEEP DYNAMIC, DDF server threads that are used to execute procedures or packages that have this option in effect will remain active. Active DDF server threads are subject to idle thread timeouts, as described in DB2 Installation Guide for installation panel DSNTIPR.

If you specify WITH KEEP DYNAMIC, you must not specify REOPT ALWAYS. WITH KEEP DYNAMIC and REOPT ALWAYS are mutually exclusive. However, you can specify WITH KEEP DYNAMIC and REOPT ONCE.

Use WITH KEEP DYNAMIC to improve performance if your DRDA client application uses a cursor that is defined as WITH HOLD. The DB2 subsystem automatically closes a held cursor when there are no more rows to retrieve, which eliminates an extra network message.

OPTHINT string-constant
Specifies whether query optimization hints are used for static SQL statements that are contained within the body of the routine.

string-constant is a character string of up to 128 bytes in length, which is used by the DB2 subsystem when searching the PLAN_TABLE for rows to use as input. The default value is an empty string, which indicates that the DB2 subsystem does not use optimization hints for static SQL statements.

Optimization hints are only used if optimization hints are enabled for your system. See DB2 Installation Guide for information about enabling optimization hints.

SQL PATH
Specifies the SQL path that DB2 uses to resolve unqualified user-defined type, function, and procedure names in the procedure body. The default value is "SYSIBM", "SYSFUN", "SYSPROC", and the value of the QUALIFIER option, which is the qualifier for the procedure that is the target of the statement.

Schemas "SYSIBM", "SYSFUN", "SYSPROC" do not need to be explicitly specified. If any of these schemas is not explicitly specified, it is implicitly assumed at the beginning the SQL path.

DB2 calculates the length by taking each schema-name specified and removing any trailing blanks from it, adding two delimiters around it, and adding one comma after each schema name except for the last one. The length of the resulting string cannot exceed the length of the CURRENT SCHEMA special register. If you do not specify the "SYSIBM", "SYSFUN", "SYSPROC", schemas, they are not included in the length of the SQL path. If the total length of the SQL path exceeds the length of the CURRENT PATH special register, DB2 returns an error for the CREATE statement.

Related information:
schema-name
Specifies a schema. DB2 does not validate that the specified schema actually exists when the CREATE statement is processed.
schema-name-list
Specifies a comma separated list of schema names. The same schema name should not appear more than one time in the list of schema names. The number of schema names that you can specify is limited by the maximum length of the resulting SQL path.
Start of changeSYSTEM PATHEnd of change
Start of changeSpecifies the schema names "SYSIBM", "SYSFUN", "SYSPROC".End of change
SESSION_USER or USER
Specifies the value of the SESSION_USER or USER special register, which represents a maximum 8 byte (in EBCDIC) schema-name. At the time the CREATE statement is processed, this length is included in the total length of the list of schema names that is specified for the PATH bind option.
RELEASE AT
Specifies when to release resources that the procedure uses: either at each commit point or when the procedure terminates.
COMMIT
Specifies that resources will be released at each commit point.

COMMIT is the default.

DEALLOCATE
Start of changeSpecifies that resources will be released only when the thread terminates. DEALLOCATE has no effect on dynamic SQL statements, which always use RELEASE AT COMMIT, with this exception: When you use the RELEASE AT DEALLOCATE clause and the WITH KEEP DYNAMIC clause, and the subsystem is installed with a value of YES for the field CACHE DYNAMIC SQL on installation panel DSNTIP8, the RELEASE AT DEALLOCATE option is honored for dynamic SELECT and data change statements.

Locks that are acquired for dynamic statements are held unit one of the following events occurs:

  • The application process ends.
  • The application process issues a PREPARE statement with the same statement identifier. (Locks are released at the next commit point).
  • The statement is removed from the prepared statement cache because the statement has not been used. (Locks are released at the next commit point).
  • An object that the statement is dependent on is dropped or altered, or a privilege that the statement needs is revoked. (Locks are released at the next commit point).

RELEASE AT DEALLOCATE can increase the package or plan size because additional items become resident in the package or plan.

Related information:
End of change
REOPT
Specifies if DB2 will determine the access path at run time by using the values of SQL variables or SQL parameters, parameter markers, and special registers.
NONE
Specifies that DB2 does not determine the access path at run time by using the values of SQL variables or SQL parameters, parameter markers, and special registers.

NONE is the default.

ALWAYS
Specifies that DB2 always determines the access path at run time each time an SQL statement is run. Do not specify REOPT ALWAYS with the WITH KEEP DYNAMIC or NODEFER PREPARE clauses.
ONCE
Specifies that DB2 determine the access path for any dynamic SQL statements only once, at the first time the statement is opened. This access path is used until the prepared statement is invalidated or removed from the dynamic statement cache and need to be prepared again.
Start of changeQUERY ACCELERATIONEnd of change
Start of changeSpecifies whether a static SQL query is bound for acceleration, and if so, with what behavior.
NONE
Specifies that no static SQL query in the application is bound for acceleration or will be accelerated when the application is run.
ENABLE
Specifies that a static SQL query is bound for acceleration if it satisfies the acceleration criteria, including the cost and heuristics criteria. The query is routed to an accelerator when the application runs. Otherwise, if the static query does not satisfy the acceleration criteria, the query is bound for execution in DB2.

If an error condition, such as one of the following examples, occurs while executing the accelerated static query when the application is run, DB2 fails the static query and returns a negative SQL code to the application:

  • A failure occurs while running the static query on the accelerator.
  • The accelerator returns an error for the query.
  • The accelerator is not started and DB2 cannot route the static query to the accelerator for execution.
ENABLE WITH FAILBACK
Results in the same behavior as ENABLE, except if one of the error conditions occurs on the first OPEN of the accelerated static query when the application is run. In this case, instead of failing the static query and returning a negative SQL code to the application, DB2 performs a temporary statement-level incremental bind of the query and runs the query in DB2. The application does not see the acceleration failure. Failback to DB2 is not possible after the application does a successful OPEN for the query on the accelerator.
ELIGIBLE
Specifies that a static SQL query is bound for acceleration if the query meets the basic acceleration criteria, regardless of the cost or heuristics criteria. The query is routed to the accelerator when the application runs.

Like the behavior for ENABLE, if an error condition occurs while executing the accelerated static query when the application is run, DB2 fails the static query and returns a negative SQL code to the application.

ALL
Specifies that all of the static SQL queries in the application are to be bound for acceleration and routed to the accelerator when the application runs. If DB2 determines that a static query cannot be bound to run on the accelerator and the query references a user base table or view, the BIND or REBIND PACKAGE operation fails with an error message for that query. (A failure exception is made for declared global temporary tables (DGTTs) and created global temporary tables and (CGTTs) because these tables cannot be accelerated.)

Like the behavior for ENABLE, if an error condition occurs while executing the accelerated static query when the application is run, DB2 fails the static query and returns a negative SQL code to the application.

This bind option does not apply to a fullselect or WITH common-table-expression that is specified in a RETURN statement for the routine, or in a SET host-variable-assignment that is used in the routine. The queries that are specified in these cases cannot be accelerated.

End of change
Start of changeGET_ACCEL_ARCHIVEEnd of change
Start of changeSpecifies whether a static SQL query that is bound for acceleration retrieves archived data on the accelerator, instead of active data.
NO
Specifies that no static SQL query is bound to retrieve archived data from the accelerator. If the static query also is not bound for acceleration, the query is bound to run in DB2.

If the static query is bound for acceleration because the QUERYACCELERATION bind option was specified, the query is routed to the accelerator when the application runs; however, the query does not retrieve any archived data.

YES
Specifies that if all of the following criteria are met, the query is bound for acceleration and retrieves the archived data on the accelerator when the application runs:
  • The QUERYACCELERATION bind option is also specified.
  • The static SQL query references an accelerated table that has partitioned data archived on an accelerator.
  • The static query satisfies the acceleration criteria that is specified by the QUERYACCELERATION bind option.

If the static query does not satisfy the acceleration criteria that is specified by the QUERYACCELERATION bind option, the BIND or REBIND PACKAGE operation fails with an error message for that query.

This bind option does not apply to a fullselect or WITH common-table-expression that is specified in a RETURN statement for the routine, or in a SET host-variable-assignment that is used in the routine. The queries that are specified in these cases cannot be accelerated.

End of change
VALIDATE RUN or VALIDATE BIND
Specifies whether to recheck, at run time, errors of the type "OBJECT NOT FOUND" and "NOT AUTHORIZED" that are found during bind or rebind. The option has no effect if all objects and needed privileges exist.
VALIDATE RUN
Specifies that if needed objects or privileges do not exist when the CREATE statement is processed, warning messages are returned, but the CREATE statement succeeds. The DB2 subsystem rechecks for the objects and privileges at run time for those SQL statements that failed the checks during processing of the CREATE statement. The authorization checks the use of the authorization ID of the owner of the routine.

VALIDATE RUN is the default.

VALIDATE BIND
Specifies that if needed objects or privileges do not exist at the time the CREATE statement is processed, an error is issued and the CREATE statement fails.
ROUNDING
Specifies the rounding mode for manipulation of DECFLOAT data. The default value is taken from the DEFAULT DECIMAL FLOATING POINT ROUNDING MODE in DECP.
DEC_ROUND_CEILING
Specifies numbers are rounded towards positive infinity.
DEC_ROUND_DOWN
Specifies numbers are rounded towards 0 (truncation).
DEC_ROUND_FLOOR
Specifies numbers are rounded towards negative infinity.
DEC_ROUND_HALF_DOWN
Specifies numbers are rounded to nearest; if equidistant, round down.
DEC_ROUND_HALF_EVEN
Specifies numbers are rounded to nearest; if equidistant, round so that the final digit is even.
DEC_ROUND_HALF_UP
Specifies numbers are rounded to nearest; if equidistant, round up.
DEC_ROUND_UP
Specifies numbers are rounded away from 0.
DATE FORMAT ISO, EUR, USA, JIS, or LOCAL
Specifies the date format for result values that are string representations of date or time values. See String representations of datetime values for more information.

The default format is specified in the DATE FORMAT field of installation panel DSNTIP4 of the system where the routine is defined. You cannot use the LOCAL option unless you have a date exit routine.

DECIMAL(15), DECIMAL(31), DECIMAL(15,s), or DECIMAL(31,s)
Specifies the maximum precision that is to be used for decimal arithmetic operations. See Arithmetic with two decimal operands for more information. The default format is specified in the DECIMAL ARITHMETIC field of installation panel DSNTIPF of the system where the routine is defined. If the form pp.s is specified, s must be a number between 1 and 9. s represents the minimum scale that is to be used for division.
FOR UPDATE CLAUSE OPTIONAL or FOR UPDATE CLAUSE REQUIRED
Specifies whether the FOR UPDATE clause is required for a DECLARE CURSOR statement if the cursor is to be used to perform positioned updates.
FOR UPDATE CLAUSE REQUIRED
Specifies that a FOR UPDATE clause must be specified as part of the cursor definition if the cursor will be used to make positioned updates.

FOR UPDATE CLAUSE REQUIRED is the default.

FOR UPDATE CLAUSE OPTIONAL
Specifies that the FOR UPDATE clause does not need to be specified in order for a cursor to be used for positioned updates. The routine body can include positioned UPDATE statements that update columns that the user is authorized to update.
aThe FOR UPDATE clause with no column list applies to static or dynamic SQL statements. Even if you do not use this clause, you can specify FOR UPDATE OF with a column list to restrict updates to only the columns that are identified in the FOR UPDATE clause and to specify the acquisition of update locks.
TIME FORMAT ISO, EUR, USA, JIS, or LOCAL
Specifies the time format for result values that are string representations of date or time values. See String representations of datetime values for more information.

The default format is specified in the TIME FORMAT field of installation panel DSNTIP4 of the system where the routine is defined. You cannot use the LOCAL option unless you have a date exit routine.

SQL-routine-body
Specifies the statements that define the body of the SQL procedure. For information on the SQL control statements that are supported in native SQL procedures, see SQL control statements for SQL routines. If an SQL-procedure-statement is the only statement in the procedure body, the statement must not end with a semicolon.

Notes

Additional Notes:
See Notes for information about:
  • Owner privileges
  • Choosing data types for parameters
  • Specifying the encoding scheme for parameters
  • Environments for running stored procedures
  • Accessing result sets from nested stored procedures
Versions of a procedure:
The CREATE PROCEDURE statement for an SQL procedure defines the initial version of the procedure. You can define additional versions using the ADD VERSION clause of the ALTER PROCEDURE statement. All versions of a procedure share the same procedure signature and the same specific name. However, the parameters names can differ between versions of a procedure. Only one version of the procedure can be considered to be the active version of the procedure.
Important: Start of changeDo not create additional versions of procedures that are supplied with DB2 by specifying the VERSION keyword. Only versions that are supplied with DB2 are supported. Additional versions of such routines cause the installation and configuration of the supplied routines to fail.End of change
Characteristics of the package that is generated for a procedure:
The package that is associated with the first version of a procedure is named as follows:
  • location is set to the value of the CURRENT SERVER special register
  • collection-id (schema) for the package is the same as the schema qualifier of the procedure.
  • package-id is the same as the specific name of the procedure
  • version-id is the same as the version identifier for the initial version of the procedure.

If you want to change the collection-id for the name of the package, you need to make a copy of the package.

The package is generated using the bind options that correspond to the implicitly or explicitly specified procedure options. See "Implicit rebinding and regeneration that occurs because of an ALTER PROCEDURE statement" in SQL control statements for SQL routines for more information. In addition to the corresponding bind options, the package is generated using the following bind options:

  • DBPROTOCOL(DRDA)
  • FLAG(1)
  • SQLERROR(NOPACKAGE)
  • ENABLE(*)

See Table 1 for additional information about the correspondence of procedure options to bind options.

Start of changeConsiderations for SQL processor programs:End of change
Start of changeSQL processor programs, such as SPUFI, the command line processor, and DSNTEP2, might not correctly parse SQL statements in the routine body that end with semicolons. These processor programs accept multiple SQL statements as input, with each statement separated with a terminator character. Processor programs that use a semicolon as the SQL statement terminator can truncate a CREATE FUNCTION statement with embedded semicolons and pass only a portion of it to DB2. Therefore, you might need to change the SQL terminator character for these processor programs. For information on changing the terminator character for SPUFI and DSNTEP2, see DB2 Application Programming and SQL Guide.End of change
Identifier resolution:
Start of changeSee SQL control statements for SQL routines for information on how names are resolved to columns, SQL variables, or SQL parameters within an SQL routine.

If duplicate names are used for columns and SQL variables and parameters, qualify the duplicate names by using the table designator for columns, the routine name for parameters, and the label name for SQL variables.

End of change
Lines within the SQL procedure definition:
When a procedure is created, information is retained on lines in the CREATE statement. Lines are determined by the presence of the new line control character.
Start of changeIn an SQL procedure, a new line control character is a special character that is used for a new line. The new line control characters for an SQL procedure include:
  • Line feed
  • New line
  • Carriage return
  • Carriage return, followed by a line feed
  • Carriage return, followed by a new line
For more information about control characters, see Tokens.End of change
Error handling in SQL procedures:
You should consider the possible exceptions that can occur for each SQL statement in the body of a procedure. Any exception SQLSTATE that is not handled within the procedure using a handler within a compound statement or a compound statement that is nested within that compound statement results in the exception SQLSTATE being returned to the caller of the procedure.
Compatibilities:
For compatibility with previous versions of DB2, the following clauses can be specified, but they will be ignored and a warning will be issued:
  • STAY RESIDENT
  • PROGRAM TYPE
  • RUN OPTIONS
  • NO DBINFO
  • COLLID or NOCOLLID
  • SECURITY
  • PARAMETER STYLE GENERAL WITH NULLS
  • STOP AFTER SYSTEM DEFAULT FAILURES
  • STOP AFTER nn FAILURES
  • CONTINUE AFTER FAILURES
  • PARAMETER VARCHAR

If the FENCED or EXTERNAL clause is specified, an external SQL procedure will be generated. See CREATE PROCEDURE (SQL - external) for more information.

If WLM ENVIRONMENT is specified without the FOR DEBUG MODE keywords, and error is returned. If WLM ENVIRONMENT is specified for a native SQL procedure, WLM ENVIRONMENT FOR DEBUG MODE must be specified.

Alternative syntax and synonyms:
To provide compatibility with previous releases of DB2 or other products in the DB2 family, DB2 supports the following keywords:
  • RESULT SET and RESULT SETS as synonyms for DYNAMIC RESULT SETS
  • VARIANT as a synonym for NOT DETERMINISTIC
  • NOT VARIANT as a synonym for DETERMINISTIC
  • NULL CALL as a synonym for CALLED ON NULL

Examples

Example 1: Create the definition for an SQL procedure. The procedure accepts an employee number and a multiplier for a pay raise as input. The following tasks are performed in the procedure body:

  • Calculate the employee's new salary.
  • Update the employee table with the new salary value.
CREATE PROCEDURE UPDATE_SALARY_1
 (IN EMPLOYEE_NUMBER CHAR(10),
 IN RATE DECIMAL(6,2))
 LANGUAGE SQL
 MODIFIES SQL DATA
  UPDATE EMP
  SET SALARY = SALARY * RATE
  WHERE EMPNO = EMPLOYEE_NUMBER

Example 2: Create the definition for the SQL procedure described in example 1, but specify that the procedure has these characteristics:

  • The same input always produces the same output.
  • SQL work is committed on return to the caller.
CREATE PROCEDURE UPDATE_SALARY_1
 (IN EMPLOYEE_NUMBER CHAR(10),
 IN RATE DECIMAL(6,2))
 LANGUAGE SQL
 MODIFIES SQL DATA
 DETERMINISTIC
 COMMIT ON RETURN YES
   UPDATE EMP
   SET SALARY = SALARY * RATE
   WHERE EMPNO = EMPLOYEE_NUMBER

For more examples of SQL procedures, see SQL control statements for SQL routines.