CREATE FUNCTION (External Scalar)

This CREATE FUNCTION (External Scalar) statement creates an external scalar function at the current server. A user-defined external scalar function returns a single value each time it is invoked.

Invocation

This statement can be embedded in an application program, or issued interactively. It is an executable statement that can be dynamically prepared.

Authorization

The privileges held by the authorization id of the statement must include at least one of the following:

If the external program or service program exists, the privileges held by the authorization ID of the statement must include at least one of the following:

If SQL names are specified and a user profile exists that has the same name as the library into which the function is created, and that name is different from the authorization ID of the statement, then the privileges held by the authorization ID of the statement must include at least one of the following:

If a distinct type is referenced, the privileges held by the authorization ID of the statement must include at least one of the following:

For information on the system authorities corresponding to SQL privileges, see Corresponding System Authorities When Checking Privileges to a Table or View and Corresponding System Authorities When Checking Privileges to a Distinct Type.

Syntax

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-CREATE FUNCTION--function-name------------------------------->
 
>--(--+---------------------------+--)-------------------------->
      | .-,---------------------. |
      | V                       | |
      '---parameter-declaration-+-'
 
>--RETURNS--+-data-type2--+------------+------------------------+-->
            |             '-AS LOCATOR-'                        |
            '-data-type3--CAST FROM--data-type4--+------------+-'
                                                 '-AS LOCATOR-'
 
>--option-list-------------------------------------------------><
 
Read syntax diagramSkip visual syntax diagramparameter-declaration:
 
|--+----------------+--data-type1--+------------+---------------|
   '-parameter-name-'              '-AS LOCATOR-'
 
data-type1, data-type2, data-type3, data-type4:
 
|--+-built-in-type------+---------------------------------------|
   '-distinct-type-name-'
 
Read syntax diagramSkip visual syntax diagrambuilt-in-type:
 
|--+-+---SMALLINT---+--------------------------------------------------------------------------+--|
   | +-+-INTEGER-+--+                                                                          |
   | | '-INT-----'  |                                                                          |
   | '---BIGINT-----'                                                                          |
   |                  .-(5,0)------------------------.                                         |
   +-+-+-DECIMAL-+-+--+------------------------------+-----------------------------------------+
   | | '-DEC-----' |  |             .-,0--------.    |                                         |
   | '-NUMERIC-----'  '-(--integer--+-----------+--)-'                                         |
   |                                '-, integer-'                                              |
   |          .-(--53--)------.                                                                |
   +-+-FLOAT--+---------------+-+--------------------------------------------------------------+
   | |        '-(--integer--)-' |                                                              |
   | +-REAL---------------------+                                                              |
   | |         .-PRECISION-.    |                                                              |
   | '-DOUBLE--+-----------+----'                                                              |
   |                    .-(--1--)-------.                                                      |
   +-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+---------------------+-+
   | | | '-CHAR------'  '-(--integer--)-'          |  +-FOR BIT DATA---+                     | |
   | | '-+-+-CHARACTER-+--VARYING-+--(--integer--)-'  +-FOR SBCS DATA--+                     | |
   | |   | '-CHAR------'          |                   +-FOR MIXED DATA-+                     | |
   | |   '-VARCHAR----------------'                   '-ccsid-clause---'                     | |
   | |                                          .-(--1M--)-------------.                     | |
   | '-----+-+-CHARACTER-+--LARGE OBJECT-+------+----------------------+--+----------------+-' |
   |       | '-CHAR------'               |      '-(--integer--+---+--)-'  +-FOR SBCS DATA--+   |
   |       '-CLOB------------------------'                    +-K-+       +-FOR MIXED DATA-+   |
   |                                                          +-M-+       '-ccsid-clause---'   |
   |                                                          '-G-'                            |
   |                .-(--1--)-------.                                                          |
   +-+---GRAPHIC----+---------------+-------+--+--------------+--------------------------------+
   | |              '-(--integer--)-'       |  '-ccsid-clause-'                                |
   | +-+-GRAPHIC VARYING-+--(--integer--)---+                                                  |
   | | '-VARGRAPHIC------'                  |                                                  |
   | |             .-(--1M--)-------------. |                                                  |
   | '---DBCLOB----+----------------------+-'                                                  |
   |               '-(--integer--+---+--)-'                                                    |
   |                             +-K-+                                                         |
   |                             +-M-+                                                         |
   |                             '-G-'                                                         |
   |             .-(--1--)-------.                                                             |
   +-+-+-BINARY--+---------------+---------+-----------------+---------------------------------+
   | | |         '-(--integer--)-'         |                 |                                 |
   | | '-+-BINARY VARYING-+--(--integer--)-'                 |                                 |
   | |   '-VARBINARY------'                                  |                                 |
   | |                              .-(--1M--)-------------. |                                 |
   | '---+-BLOB----------------+----+----------------------+-'                                 |
   |     '-BINARY LARGE OBJECT-'    '-(--integer--+---+--)-'                                   |
   |                                              +-K-+                                        |
   |                                              +-M-+                                        |
   |                                              '-G-'                                        |
   +-+-DATE-------------------+----------------------------------------------------------------+
   | |       .-(--0--)-.      |                                                                |
   | +-TIME--+---------+------+                                                                |
   | |            .-(--6--)-. |                                                                |
   | '-TIMESTAMP--+---------+-'                                                                |
   '---ROWID-----------------------------------------------------------------------------------'
 
ccsid-clause:
 
                   .-NOT NORMALIZED-.
|--CCSID--integer--+----------------+---------------------------|
                   '-NORMALIZED-----'
 
Read syntax diagramSkip visual syntax diagramoption-list:
 
                             (1)
|--+-----------------------+------------------------------------>
   '-LANGUAGE--+-C-------+-'
               +-C++-----+
               +-CL------+
               +-COBOL---+
               +-COBOLLE-+
               +-FORTRAN-+
               +-JAVA----+
               +-PLI-----+
               +-RPG-----+
               '-RPGLE---'
 
   .-PARAMETER STYLE SQL--------------------.
>--+----------------------------------------+------------------->
   '-+-PARAMETER STYLE DB2SQL-------------+-'
     +-PARAMETER STYLE JAVA---------------+
     +-PARAMETER STYLE GENERAL------------+
     +-PARAMETER STYLE GENERAL WITH NULLS-+
     '-PARAMETER STYLE DB2GENERAL---------'
 
                                .-NOT DETERMINISTIC-.
>--+-------------------------+--+-------------------+----------->
   '-SPECIFIC--specific-name-'  '-DETERMINISTIC-----'
 
   .-READS SQL DATA----.  .-CALLED ON NULL INPUT-------.
>--+-------------------+--+----------------------------+-------->
   +-NO SQL------------+  '-RETURNS NULL ON NULL INPUT-'
   +-CONTAINS SQL------+
   '-MODIFIES SQL DATA-'
 
   .-STATIC DISPATCH-.  .-NO DBINFO-.  .-EXTERNAL ACTION----.
>--+-----------------+--+-----------+--+--------------------+--->
                        '-DBINFO----'  '-NO EXTERNAL ACTION-'
 
   .-FENCED-----.  .-NO FINAL CALL-.
>--+------------+--+---------------+--+-------------------+----->
   '-NOT FENCED-'  '-FINAL CALL----'  +-ALLOW PARALLEL----+
                                      '-DISALLOW PARALLEL-'
 
   .-NO SCRATCHPAD-----------.
>--+-------------------------+---------------------------------->
   |             .-100-----. |
   '-SCRATCHPAD--+---------+-'
                 '-integer-'
 
   .-EXTERNAL-----------------------------.
>--+--------------------------------------+---------------------|
   '-EXTERNAL NAME--external-program-name-'
 
Notes:
  1. The optional clauses can be specified in a different order.

Description

function-name
Names the user-defined function. The combination of name, schema name, the number of parameters, and the data type of each parameter (without regard for any length, precision, scale, or CCSID attributes of the data type) must not identify a user-defined function that exists at the current server.

For SQL naming, the function will be created in the schema specified by the implicit or explicit qualifier.

For system naming, the function will be created in the schema that is specified by the qualifier. If no qualifier is specified:

In general, more than one function can have the same name if the function signature of each function is unique.

Certain function names are reserved for system use. For more information see Choosing the Schema and Function Name.

(parameter-declaration,...)
Specifies the number of input parameters of the function and the data type of each parameter. Although not required, you can give each parameter a name.

The maximum number of parameters allowed in CREATE FUNCTION is 90. For external functions created with PARAMETER STYLE SQL, the input and result parameters specified and the implicit parameters for indicators, SQLSTATE, function name, specific name, and message text, as well as any optional parameters are included. The maximum number of parameters is also limited by the maximum number of parameters allowed by the licensed program that is used to compile the external program.

parameter-name
Names the parameter. Although not required, a parameter name can be specified for each parameter. The name cannot be the same as any other parameter-name in the parameter list.
data-type1
Specifies the data type of the input parameter. The data type can be a built-in data type or a distinct type.
built-in-type
Specifies a built-in data type. For a more complete description of each built-in data type, see CREATE TABLE. Some data types are not supported in all languages. For details on the mapping between the SQL data types and host language data types, see Embedded SQL Programming book. Built-in data type specifications can be specified if they correspond to the language that is used to write the user-defined function.
distinct-type-name
Specifies a user-defined distinct type. The length, precision, or scale attributes for the parameter are those of the source type of the distinct type (those specified on CREATE DISTINCT TYPE). For more information on creating a distinct type, see CREATE DISTINCT TYPE.

If the name of the distinct type is unqualified, the database manager resolves the schema name by searching the schemas in the SQL path.

If a CCSID is specified, the parameter will be converted to that CCSID prior to passing it to the function. If a CCSID is not specified, the CCSID is determined by the default CCSID at the current server at the time the function is invoked.

AS LOCATOR
Specifies that a locator to the value of the parameter is passed to the function 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. If AS LOCATOR is specified, FOR SBCS DATA or FOR MIXED DATA must not be specified. See "Specifying AS LOCATOR for a parameter" in CREATE FUNCTION for more information.
RETURNS
Specifies the output of the function.
data-type2
Specifies the data type and attributes of the output.

You can specify any built-in data type (except LONG VARCHAR, LONG VARGRAPHIC, or DataLink) or a distinct type (that is not based on a DataLink).

If a CCSID is specified,

  • If AS LOCATOR is not specified, the result returned is assumed to be encoded in that CCSID.
  • If AS LOCATOR is specified and the CCSID of the data the locator points to is encoded in a different CCSID, the data is converted to the specified CCSID.

If a CCSID is not specified,

  • If AS LOCATOR is not specified, the result returned is assumed to be encoded in the CCSID of the job (or associated graphic CCSID of the job for graphic string return values).
  • If AS LOCATOR is specified, the data the locator points to is converted to the CCSID of the job, if the CCSID of the data the locator points to is encoded in a different CCSID. To avoid any potential loss of characters during the conversion, consider explicitly specifying a CCSID that can represent any characters that will be returned from the function. This is especially important if the data type is graphic string data. In this case, consider using CCSID 1200 or 13488 (UTF-16 or UCS-2 graphic string data).
AS LOCATOR
Specifies that the function returns a locator to the value rather than the actual value. Specify AS LOCATOR only if the result of the function has a LOB data type or a distinct type based on a LOB data type. If AS LOCATOR is specified, FOR SBCS DATA or FOR MIXED DATA must not be specified. See "Specifying AS LOCATOR for a parameter" in CREATE FUNCTION for more information.
data-type3 CAST FROM data-type4
Specifies the data type and attributes of the output (data-type4) and the data type in which that output is returned to the invoking statement (data-type3). The two data types can be different. For example, for the following definition, the function returns a CHAR(10) value, which the database manager converts to a DATE value and then passes to the statement that invoked the function:
CREATE FUNCTION GET_HIRE_DATE (CHAR6)
  RETURNS DATE CAST FROM CHAR(10)
The value of data-type4 must not be a distinct type and must be castable to data-type3. The value for data-type3 can be any built-in data type or distinct type. (For information on casting data types, see Casting between data types).

For CCSID information, see the description of data-type2 above.

AS LOCATOR
Specifies that the function returns a locator to the value rather than the actual value. Specify AS LOCATOR only if the result of the function has a LOB data type or a distinct type based on a LOB data type. If AS LOCATOR is specified, FOR SBCS DATA or FOR MIXED DATA must not be specified. See "Specifying AS LOCATOR for a parameter" in CREATE FUNCTION for more information.
LANGUAGE
Specifies the language interface convention to which the function body is written. All programs must be designed to run in the server's environment.

If LANGUAGE is not specified, the LANGUAGE is determined from the program attribute information associated with the external program at the time the function is created. The language of the program is assumed to be C if:

C   
The external program is written in C.
C++
The external program is written in C++.
CL   
The external program is written in CL or ILE CL.
COBOL
The external program is written in COBOL.
COBOLLE
The external program is written in ILE COBOL.
FORTRAN
The external program is written in FORTRAN.
JAVA
The external program is written in JAVA. The database manager will call the user-defined function, which must be a public static method of the specified Java™ class
PLI
The external program is written in PL/I.
RPG
The external program is written in RPG.
RPGLE
The external program is written in ILE RPG.
PARAMETER STYLE
Specifies the conventions used for passing parameters to and returning the values from functions:
SQL
All applicable parameters are passed. The parameters are defined to be in the following order:
  • The first N parameters are the input parameters that are specified on the CREATE FUNCTION statement.
  • A parameter for the result of the function.
  • N parameters for indicator variables for the input parameters.
  • A parameter for the indicator variable for the result.
  • A CHAR(5) output parameter for SQLSTATE. The SQLSTATE returned indicates the success or failure of the function. The SQLSTATE returned either be:
    • the SQLSTATE from the last SQL statement executed in the external program,
    • an SQLSTATE that is assigned by the external program.

      The user may set the SQLSTATE to any valid value in the external program to return an error or warning from the function.

  • A VARCHAR(517) input parameter for the fully qualified function name.
  • A VARCHAR(128) input parameter for the specific name.
  • A VARCHAR(70) output parameter for the message text.

    When control is returned to the invoking program, the message text can be found in the 6th token of the SQLERRMC field of the SQLCA. Only a portion of the message text is available. For information on the layout of the message data in the SQLERRMC, see the replacement data descriptions for message SQL0443 in message file QSQLMSG. The complete message text can be retreived using the GET DIAGNOSTICS statement. For more information, see GET DIAGNOSTICS.

  • Zero to three optional parameters:
    • A structure (consisting of an INTEGER followed by a CHAR(n)) input and output parameter for the scratchpad, if SCRATCHPAD was specified on the CREATE FUNCTION statement.
    • An INTEGER input parameter for the call type, if FINAL CALL was specified on the CREATE FUNCTION statement.
    • A structure for the dbinfo structure, if DBINFO was specified on the CREATE FUNCTION statement.
For more information about the parameters passed, see the include sqludf in the appropriate source file in library QSYSINC. For example, for C, sqludf can be found in QSYSINC/H.
DB2GENERAL
This parameter style is used to specify the conventions for passing parameters to and returning the value from external functions that are defined as a method in a Java class. All applicable parameters are passed. The parameters are defined to be in the following order:
  • The first N parameters are the input parameters that are specified on the CREATE FUNCTION statement.
  • A parameter for the result of the function.

DB2GENERAL is only allowed when the LANGUAGE is JAVA.

GENERAL
All applicable parameters are passed. The parameters are defined to be in the following order:
  • The first N parameters are the input parameters that are specified on the CREATE FUNCTION statement.
Note that the result is returned through as a value of a value returning function. For example:
return_val func(parameter-1, parameter-2, ...)

GENERAL is only allowed when EXTERNAL NAME identifies a service program.

GENERAL WITH NULLS
All applicable parameters are passed. The parameters are defined to be in the following order:
  • The first N parameters are the input parameters that are specified on the CREATE FUNCTION statement.
  • An additional argument is passed for an indicator variable array.
  • A parameter for the indicator variable for the result.
Note that the result is returned through as a value of a value returning function. For example:
return_val func(parameter-1, parameter-2, ...)

GENERAL WITH NULLS is only allowed when EXTERNAL NAME identifies a service program.

JAVA
Specifies that the procedure will use a parameter passing convention that conforms to the Java language and ISO/IEC FCD 9075-13:2003, Information technology - Database languages - SQL - Part 13: Java Routines and Types (SQL/JRT) specification. All applicable parameters are passed. The parameters are defined to be in the following order:
  • The first N parameters are the input parameters that are specified on the CREATE FUNCTION statement.
Note that the result is returned through as a value of a value returning function. For example:
return_val func(parameter-1, parameter-2, ...)

JAVA is only allowed when the LANGUAGE is JAVA.

Note that the language of the external function determines how the parameters are passed. For example, in C, any VARCHAR or CHAR parameters are passed as NUL-terminated strings. For more information, see the SQL Programming book. For Java routines, see the IBM® Developer Kit for Java.

SPECIFIC specific-name
Specifies a unique name for the function. See "Specifying a Specific Name for a Function" in CREATE FUNCTION.
DETERMINISTIC or NOT DETERMINISTIC
Specifies whether the function is deterministic.
NOT DETERMINISTIC
Specifies that the function will not always return the same result from successive function invocations with identical input arguments. NOT DETERMINISTIC should be specified if the function contains a reference to a special register, a non-deterministic function, or a sequence.
DETERMINISTIC
Specifies that the function will always return the same result from successive invocations with identical input arguments.
CONTAINS SQL, READS SQL DATA, MODIFIES SQL DATA, or NO SQL
Specifies whether the function can execute any SQL statements and, if so, what type. The database manager verifies that the SQL issued by the function is consistent with this specification. See Appendix B. Characteristics of SQL statements for a detailed list of the SQL statements that can be executed under each data access indication.
CONTAINS SQL
The function does not execute SQL statements that read or modify data.
NO SQL
The function does not execute SQL statements.
READS SQL DATA
The function does not execute SQL statements that modify data.
MODIFIES SQL DATA
The function can execute any SQL statement except those statements that are not supported in any function.
RETURNS NULL ON NULL INPUT or CALLED ON NULL INPUT
Specifies whether the function is called if any of the input arguments is null at execution time.
RETURNS NULL ON INPUT
Specifies that the function is not invoked if any of the input arguments is null. The result is the null value.
CALLED ON NULL INPUT
Specifies that the function is to be invoked, if any, or all, argument values are null, making the function responsible for testing for null argument values. The function can return a null or nonnull value.
STATIC DISPATCH
Specifies that the function is dispatched statically. All functions are statically dispatched.
DBINFO
Specifies whether or not the function requires the database information be passed.
DBINFO
Specifies that the database manager should pass a structure containing status information to the function. Table 49 contains a description of the DBINFO structure. Detailed information about the DBINFO structure can be found in include sqludf in the appropriate source file in library QSYSINC. For example, for C, sqludf can be found in QSYSINC/H.

DBINFO is only allowed with PARAMETER STYLE DB2SQL or PARAMETER STYLE DB2GENERAL.

Table 49. DBINFO fields
Field Data Type Description
Relational database VARCHAR(128) The name of the current server.
Authorization ID VARCHAR(128) The run-time authorization ID.
CCSID Information
INTEGER
INTEGER
INTEGER
 
INTEGER
INTEGER
INTEGER
 
INTEGER
INTEGER
INTEGER
 
INTEGER
 
CHAR(8)
The CCSID information of the job. Three sets of three CCSIDs are returned. The following information identifies the three CCSIDs in each set:
  • SBCS CCSID
  • DBCS CCSID
  • Mixed CCSID
Following the three sets of CCSIDs is an integer that indicates which set of three sets of CCSIDs is applicable and eight bytes of reserved space.

If a CCSID is not explicitly specified for a parameter on the CREATE FUNCTION statement, the input string is assumed to be encoded in the CCSID of the job at the time the function is executed. If the CCSID of the input string is not the same as the CCSID of the parameter, the input string passed to the external function will be converted before calling the external program.

Target column VARCHAR(128)
VARCHAR(128)
VARCHAR(128)
If a user-defined function is specified on the right-hand side of a SET clause in an UPDATE statement, the following information identifies the target column:
  • Schema name
  • Base table name
  • Column name
If the user-defined function is not on the right-hand side of a SET clause in an UPDATE statement, these fields are blank.
Version and release CHAR(8) The version, release, and modification level of the database manager.
Platform INTEGER The server's platform type.
NO DBINFO
Specifies that the function does not require the database information to be passed.
EXTERNAL ACTION or NO EXTERNAL ACTION
Specifies whether the function contains an external action.
EXTERNAL ACTION
The function performs some external action (outside the scope of the function program). Thus, the function must be invoked with each successive function invocation. EXTERNAL ACTION should be specified if the function contains a reference to another function that has an external action.
NO EXTERNAL ACTION
The function does not perform an external action. It need not be called with each successive function invocation.
This parameter implies that the function
FENCED or NOT FENCED
Specifies whether the external function runs in an environment that is isolated from the database manager environment.
FENCED
The function will run in a separate thread.

FENCED functions cannot keep SQL cursors open across individual calls to the function. However, the cursors in one thread are independent of the cursors in any other threads which reduces the possibility of cursor name conflicts.

NOT FENCED
The function may run in the same thread as the invoking SQL statement.

NOT FENCED functions can keep SQL cursors open across individual calls to the function. Since cursors can be kept open, the cursor position will also be preserved between calls to the function. However, cursor names may conflict since the UDF is now running in the same thread as the invoking SQL statement and other NOT FENCED UDFs.

NOT FENCED functions usually perform better than FENCED functions.

FINAL CALL
Specifies whether the function requires special call indication. If PARAMETER STYLE DB2SQL is specified and FINAL CALL is specified, an additional parameter is passed to the function indicating first call, normal call, or final call.
NO FINAL CALL
Specifies that a final call is not made to the function.
FINAL CALL
Specifies that a final call is made to the function. To differentiate between final calls and other calls, the function receives an additional argument that specifies the type of call.

FINAL CALL is only allowed with PARAMETER STYLE DB2SQL or PARAMETER STYLE DB2GENERAL.

The types of calls are:

First Call
Specifies the first call to the function for this reference to the function in this SQL statement. A first call is a normal call. SQL arguments are passed and the function is expected to return a result.
Normal Call
Specifies that SQL arguments are passed and the function is expected to return a result.
Final Call
Specifies the last call to the function to enable the function to free resources. A final call is not a normal call. If an error occurs, the database manager attempts to make the final call.

A final call occurs at these times:

  • End of statement: When the cursor is closed for cursor-oriented statements, or the execution of the statement has completed.
  • End of a parallel task: When the function is executed by parallel tasks.
  • End of transaction: When normal end of statement processing does not occur. For example, the logic of an application, for some reason, bypasses closing the cursor.

Some functions that use a final call can receive incorrect results if parallel tasks execute the function. For example, if a function sends a note for each final call to it, one note is sent for each parallel task instead of once for the function. Specify the DISALLOW PARALLEL clause for functions that have inappropriate actions when executed in parallel.

If a commit operation occurs while a cursor defined as WITH HOLD is open, a final call is made when the cursor is closed or the application ends. If a commit occurs at the end of a parallel task, a final call is made regardless of whether a cursor defined as WITH HOLD is open.

Commitable operations should not be performed during a FINAL CALL, because the FINAL CALL may occur during a close invoked as part of a COMMIT operation.

PARALLEL
Specifies whether the function can be run in parallel.
ALLOW PARALLEL
Specifies that the function can be run in parallel.
DISALLOW PARALLEL
Specifies that the function cannot be run in parallel.
The default is DISALLOW PARALLEL, if you specify one or more of the following clauses: Otherwise, ALLOW PARALLEL is the default.
SCRATCHPAD
Specifies whether the function requires a static memory area.
SCRATCHPAD integer
Specifies that the function requires a persistent memory area of length integer. The integer can range from 1 to 16,000,000. If the memory area is not specified, the size of the area is 100 bytes. If parameter style DB2SQL is specified, a pointer is passed following the required parameters that points to a static storage area. If PARALLEL is specified, a memory area is allocated for each user-defined function reference in the statement. If DISALLOW PARALLEL is specified, only 1 memory area will be allocated for the function.

The scope of a scratchpad is the SQL statement. For each reference to the function in an SQL statement, there is one scratchpad. For example, assuming that function UDFX was defined with the SCRATCHPAD keyword, three scratchpads are allocated for the three references to UDFX in the following SQL statement:

SELECT A, UDFX(A) 
  FROM TABLEB
  WHERE UDFX(A) > 103 OR UDFX(A) < 19

If the function is run under parallel tasks, one scratchpad is allocated for each parallel task of each reference to the function in the SQL statement. This can lead to unpredictable results. For example, if a function uses the scratchpad to count the number of times that it is invoked, the count reflects the number of invocations done by the parallel task and not the SQL statement. Specify the DISALLOW PARALLEL clause for functions that will not work correctly with parallelism.

SCRATCHPAD is only allowed with PARAMETER STYLE DB2SQL or PARAMETER STYLE DB2GENERAL.

NO SCRATCHPAD
Specifies that the function does not require a persistent memory area.
EXTERNAL NAME external-program-name
Specifies the program, service program, or java class that will be executed when the function is invoked in an SQL statement. The name must identify a program, service program, or java class that exists at the application server at the time the function is invoked. If the naming option is *SYS and the name is not qualified:

The validity of the name is checked at the application server. If the format of the name is not correct, an error is returned.

If external-program-name is not specified, the external program name is assumed to be the same as the function name.

The program, service program, or java class need not exist at the time the function is created, but it must exist at the time the function is invoked.

A CONNECT, SET CONNECTION, RELEASE, DISCONNECT, COMMIT, ROLLBACK and SET TRANSACTION statement is not allowed in the external program of the function.

Notes

General considerations for defining user-defined functions: See CREATE FUNCTION for general information on defining user-defined functions.

Creating the function: When an external function associated with an ILE external program or service program is created, an attempt is made to save the function's attributes in the associated program or service program object. If the *PGM or *SRVPGM object is saved and then restored to this or another system, the catalogs are automatically updated with those attributes.

The attributes can be saved for external functions subject to the following restrictions:

If the object cannot be updated, the function will still be created.

During restore of the function:

Invoking the function: When an external function is invoked, it runs in whatever activation group was specified when the external program or service program was created. However, ACTGRP(*CALLER) should normally be used so that the function runs in the same activation group as the calling program. ACTGRP(*NEW) is not allowed.

Notes for Java functions: To be able to run Java functions, you must have the IBM Developer Kit for Java (5722-JV1) installed on your system. Otherwise, an SQLCODE of -443 will be returned and a CPDB521 message will be placed in the job log.

If an error occurs while running a Java procedure, an SQLCODE of -443 will be returned. Depending on the error, other messages may exist in the job log of the job where the procedure was run.

Syntax alternatives: The following keywords are synonyms supported for compatibility to prior releases. These keywords are non-standard and should not be used:

Examples

Example 1: Assume an external function program in C is needed that implements the following logic:

    rslt   = 2 * input - 4

The function should return a null value if and only if one of the input arguments is null. The simplest way to avoid a function call and get a null result when an input value is null is to specify RETURNS NULL ON NULL INPUT on the CREATE FUNCTION statement. The following statement defines the function, using the specific name MINENULL1.

  CREATE FUNCTION NTEST1 (SMALLINT)
      RETURNS SMALLINT
      EXTERNAL NAME NTESTMOD
      SPECIFIC MINENULL1
      LANGUAGE C
      DETERMINISTIC
      NO SQL
      FENCED
      PARAMETER STYLE SQL
      RETURNS NULL ON NULL INPUT
      NO EXTERNAL ACTION

The program code:

  void nudft1
    (int *input,                 /* ptr to input argument         */
     int *output,                /* ptr to output argument        */
     short *input_ind,           /* ptr to input indicator        */
     short *output_ind,          /* ptr to output indicator       */
     char sqlstate[6],  /* sqlstate                      */
     char fname[140],   /* fully qualified function name */
     char finst[129],   /* function specific name        */
     char msgtext[71])  /* msg text buffer               */
  {
    if (*input_ind == -1)
      *output_ind = -1;
    else
  {
      *output = 2*(*input)-4;
      *output_ind = 0;
    }
    return;
 }                                

Example 2: Assume that a user wants to define an external function named CENTER. The function program will be written in C. The following statement defines the function, and lets the database manager generate a specific name for the function. The name of the program containing the function body is the same as the name of the function, so the EXTERNAL clause does not include 'NAME external-program-name'.

   CREATE FUNCTION CENTER (INTEGER, FLOAT)
      RETURNS FLOAT
      LANGUAGE C
      DETERMINISTIC
      NO SQL
      PARAMETER STYLE SQL
      NO EXTERNAL ACTION

Example 3: Assume that user McBride (who has administrative authority) wants to define an external function named CENTER in the SMITH schema. McBride plans to give the function specific name FOCUS98. The function program uses a scratchpad to perform some one-time only initialization and save the results. The function program returns a value with a DOUBLE data type. The following statement written by user McBride defines the function and ensures that when the function is invoked, it returns a value with a data type of DECIMAL(8,4).

   CREATE FUNCTION SMITH.CENTER (DOUBLE, DOUBLE, DOUBLE)
      RETURNS DECIMAL(8,4)
      CAST FROM DOUBLE
      EXTERNAL NAME CMOD
      SPECIFIC FOCUS98
      LANGUAGE C
      DETERMINISTIC
      NO SQL
      FENCED
      PARAMETER STYLE SQL
      NO EXTERNAL ACTION
      SCRATCHPAD
      NO FINAL CALL

Example 4: The following example defines a Java user-defined function that returns the position of the first vowel in a string. The user-defined function is written in Java, is to be run fenced, and is the FINDVWL method of class JAVAUDFS.

   CREATE FUNCTION FINDV (VARCHAR(32000))
      RETURNS INTEGER
      FENCED
      LANGUAGE JAVA
      PARAMETER STYLE JAVA
      EXTERNAL NAME 'JAVAUDFS.FINDVWL'
      NO EXTERNAL ACTION
      CALLED ON NULL INPUT
      DETERMINISTIC
      NO SQL

65.
The GRTOBJAUT CL command must be used to grant these privileges.



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