CREATE FUNCTION (External Table)

This CREATE FUNCTION (External Table) statement defines an external table function at the current server. The function returns a result table.

An external user-defined table function may be used in the FROM clause of a subselect, and returns a table to the subselect by returning one row 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:

  • For the SYSFUNCS catalog view and SYSPARMS catalog table:
    • The INSERT privilege on the table, and
    • The system authority *EXECUTE on library QSYS2
  • Administrative Authority

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:

  • For the external program or service program that is referenced in the SQL statement:
    • The system authority *EXECUTE on the library that contains the external program or service program.
    • The system authority *EXECUTE on the external program or service program, and
    • The system authority *CHANGE on the program or service program. The system needs this authority to update the program object to contain the information necessary to save/restore the function to another system. If user does not have this authority, the function is still created, but the program object is not updated.
  • Administrative Authority

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:

  • The system authority *ADD to the user profile with that name
  • Administrative authority

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 each distinct type identified in the statement:
    • The USAGE privilege on the distinct type, and
    • The system authority *EXECUTE on the library containing the distinct type
  • Administrative authority

Start of changeTo replace an existing function, the privileges held by the authorization ID of the statement must include at least one of the following:End of change

Start of change
  • The following system authorities:
    • The system authority of *OBJMGT on the service program object associated with the function
    • All authorities needed to DROP the function
    • Start of changeThe system authority *READ to the SYSFUNCS catalog view and SYSPARMS catalog tableEnd of change
  • Administrative authority
End of change

For information about 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

Read syntax diagramSkip visual syntax diagram
>>-CREATE--+------------+--FUNCTION--function-name-------------->
           '-OR REPLACE-'                            

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

                     .-,---------------------------------------.      
                     V                                         |      
>--RETURNS TABLE--(----column-name--data-type2--+------------+-+--)-->
                                                '-AS LOCATOR-'        

>--option-list-------------------------------------------------><

Read syntax diagramSkip visual syntax diagram
parameter-declaration

|--+----------------+--data-type1--+-----------------------+----|
   '-parameter-name-'              '-AS -+-LOCATOR-------+-'   
                                         '-XML-cast-type-'     

data-type1, data-type2

|--+-built-in-type------+---------------------------------------|
   '-distinct-type-name-'   

XML-cast-type

                      .-(--1--)-------.                                                                       
|--+-+-+-CHARACTER-+--+---------------+--+--------------+-----------------------------------------------+-+--|
   | | '-CHAR------'  '-(--integer--)-'  '-ccsid-clause-'                                               | |   
   | +-+-+-CHARACTER-+--VARYING-+--(--integer--)--+--------------+--------------------------------------+ |   
   | | | '-CHAR------'          |                 '-ccsid-clause-'                                      | |   
   | | '-VARCHAR----------------'                                                                       | |   
   | |                                          .-(--1M--)-------------.                                | |   
   | '-----+-+-CHARACTER-+--LARGE OBJECT-+------+----------------------+--+--------------+--+---------+-' |   
   |       | '-CHAR------'               |      '-(--integer--+---+--)-'  '-ccsid-clause-'  '-LOCATOR-'   |   
   |       '-CLOB------------------------'                    +-K-+                                       |   
   |                                                          +-M-+                                       |   
   |                                                          '-G-'                                       |   
   |                .-(--1--)-------.                                                                     |   
   +-+---GRAPHIC----+---------------+--+--------------+--------------------+------------------------------+   
   | |              '-(--integer--)-'  '-ccsid-clause-'                    |                              |   
   | +-+-GRAPHIC VARYING-+--(--integer--)--+--------------+----------------+                              |   
   | | '-VARGRAPHIC------'                 '-ccsid-clause-'                |                              |   
   | |             .-(--1M--)-------------.                                |                              |   
   | '---DBCLOB----+----------------------+--+--------------+--+---------+-'                              |   
   |               '-(--integer--+---+--)-'  '-ccsid-clause-'  '-LOCATOR-'                                |   
   |                             +-K-+                                                                    |   
   |                             +-M-+                                                                    |   
   |                             '-G-'                                                                    |   
   |             .-(--1--)-------.                                                                        |   
   '-+-+-BINARY--+---------------+---------+------------------------------+-------------------------------'   
     | |         '-(--integer--)-'         |                              |                                   
     | '-+-BINARY VARYING-+--(--integer--)-'                              |                                   
     |   '-VARBINARY------'                                               |                                   
     |                              .-(--1M--)-------------.              |                                   
     '---+-BLOB----------------+----+----------------------+--+---------+-'                                   
         '-BINARY LARGE OBJECT-'    '-(--integer--+---+--)-'  '-LOCATOR-'                                     
                                                  +-K-+                                                       
                                                  +-M-+                                                       
                                                  '-G-'                                                       

Read syntax diagramSkip visual syntax diagram
built-in-type

|--+-+---SMALLINT---+-------------------------------------------------------------------------------------+--|
   | +-+-INTEGER-+--+                                                                                     |   
   | | '-INT-----'  |                                                                                     |   
   | '---BIGINT-----'                                                                                     |   
   |                  .-(5,0)------------------------.                                                    |   
   +-+-+-DECIMAL-+-+--+------------------------------+----------------------------------------------------+   
   | | '-DEC-----' |  |             .-,0--------.    |                                                    |   
   | '-+-NUMERIC-+-'  '-(--integer--+-----------+--)-'                                                    |   
   |   '-NUM-----'                  '-, integer-'                                                         |   
   |          .-(--53--)------.                                                                           |   
   +-+-FLOAT--+---------------+-+-------------------------------------------------------------------------+   
   | |        '-(--integer--)-' |                                                                         |   
   | +-REAL---------------------+                                                                         |   
   | |         .-PRECISION-.    |                                                                         |   
   | '-DOUBLE--+-----------+----'                                                                         |   
   |             .-(--34--)-.                                                                             |   
   +---DECFLOAT--+----------+-----------------------------------------------------------------------------+   
   |             '-(--16--)-'                                                                             |   
   |                    .-(--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--)-------.                                                        |   
   +-+-+-+-NATIONAL CHARACTER-+--+---------------+----------+---------------------+--+------------------+-+   
   | | | +-NATIONAL CHAR------+  '-(--integer--)-'          |                     |  '-normalize-clause-' |   
   | | | '-NCHAR--------------'                             |                     |                       |   
   | | '-+-+-NATIONAL CHARACTER-+--VARYING-+--(--integer--)-'                     |                       |   
   | |   | +-NATIONAL CHAR------+          |                                      |                       |   
   | |   | '-NCHAR--------------'          |                                      |                       |   
   | |   '-NVARCHAR------------------------'                                      |                       |   
   | |                                                   .-(--1M--)-------------. |                       |   
   | '-----+-+-NATIONAL CHARACTER-+--LARGE OBJECT-+------+----------------------+-'                       |   
   |       | '-NCHAR--------------'               |      '-(--integer--+---+--)-'                         |   
   |       '-NCLOB--------------------------------'                    +-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----------------------------------------------------------------------------------------------+   
   '---XML--+------------------+--------------------------------------------------------------------------'   
            |              (1) |                                                                              
            '-ccsid-clause-----'                                                                              

ccsid-clause

|--CCSID--integer--+------------------+-------------------------|
                   '-normalize-clause-'   

normalize-clause

   .-NOT NORMALIZED-.   
|--+-NORMALIZED-----+-------------------------------------------|

Notes:
  1. The ccsid-clause for XML is only allowed for data-type2
Read syntax diagramSkip visual syntax diagram
option-list

                             (1)   
|--+-----------------------+------------------------------------>
   '-LANGUAGE--+-C-------+-'       
               +-C++-----+         
               +-CL------+         
               +-COBOL---+         
               +-COBOLLE-+         
               +-JAVA----+         
               +-PLI-----+         
               +-RPG-----+         
               '-RPGLE---'         

   .-PARAMETER STYLE SQL--------.   
>--+----------------------------+------------------------------->
   '-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-'                                   

   .-INHERIT SPECIAL REGISTERS-.  .-STATIC DISPATCH-.   
>--+---------------------------+--+-----------------+----------->

   .-NO DBINFO .  .-EXTERNAL ACTION----.  .-FENCED-----.   
>--+-----------+--+--------------------+--+------------+-------->
   '-DBINFO----'  '-NO EXTERNAL ACTION-'  '-NOT FENCED-'   

                          .-NO FINAL CALL-.   
>--+-------------------+--+---------------+--------------------->
   +-PROGRAM TYPE MAIN-+  '-FINAL CALL----'   
   '-PROGRAM TYPE SUB--'                      

                          .-NO SCRATCHPAD-----------.   
>--+-------------------+--+-------------------------+----------->
   +-ALLOW PARALLEL----+  |             .-100-----. |   
   '-DISALLOW PARALLEL-'  '-SCRATCHPAD--+---------+-'   
                                        '-integer-'     

   .-EXTERNAL-----------------------------.   
>--+--------------------------------------+--------------------->
   '-EXTERNAL NAME--external-program-name-'   

>--+---------------------+--------------------------------------|
   '-CARDINALITY--bigint-'   

Notes:
  1. This clause and the clauses that follow in the option-list can be specified in any order. Each clause can be specified at most once.

Description

Start of changeOR REPLACEEnd of change
Start of changeSpecifies to replace the definition for the function if one exists at the current server. The existing definition is effectively dropped before the new definition is replaced in the catalog with the exception that privileges that were granted on the function are not affected. This option is ignored if a definition for the function does not exist at the current server. To replace an existing function, the specific-name and function-name of the new definition must be the same as the specific-name and function-name of the old definition, or the signature of the new definition must match the signature of the old definition. Otherwise, a new function is created.End of change
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:

  • If the value of the CURRENT SCHEMA special register is *LIBL, the function will be created in the current library (*CURLIB).
  • Otherwise, the function will be created in the current schema.

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. Each parameter-declaration specifies an input parameter for the function. A maximum of 90 parameters can be specified. A function can have zero or more input parameters. There must be one entry in the list for each parameter that the function expects to receive. All the parameters for a function are input parameters and are nullable. In the case of JAVA, numeric parameters other than the DECIMAL and NUMERIC types are not nullable. A runtime error will occur if a null value is input to such a parameter for a CALLED ON NULL INPUT function. For more information, see Defining the parameters.
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 topic collection. 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 TYPE). For more information about creating a distinct type, see CREATE TYPE (Distinct)

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

Parameters with a large object (LOB) data type are not supported when PARAMETER STYLE JAVA is specified.

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.

Start of changeAny parameter that has an XML type must specify either the XML-cast-type clause or the AS LOCATOR clause.End of change

AS LOCATOR
Specifies that the input parameter is a locator to the value rather than the actual value. You can specify AS LOCATOR only if the input parameter has a Start of changeLOB or XML data type or a distinct type based on a LOB or XML data typeEnd of change. If AS LOCATOR is specified, FOR SBCS DATA or FOR MIXED DATA must not be specified.

For more information on the AS LOCATOR clause, see Specifying AS LOCATOR for a parameter.

Start of changeAS XML-cast-typeEnd of change
Start of changeSpecifies the data type passed to the function for a parameter that is XML type or a distinct type based on XML type. If LOCATOR is specified, the parameter is a locator to the value rather than the actual value.

Start of changeIf a CCSID value is specified, only Unicode CCSID values can be specified for graphic data types. If a CCSID value is not specified, the CCSID is established at the time the function is created according to the SQL_XML_DATA_CCSID QAQQINI option setting. The default CCSID is 1208. See XML Values for a description of this option.End of change

End of change
RETURNS TABLE
Specifies that the output of the function is a table. The parenthesis that follow this clause enclose a list of names and the data types of the columns of the result table.

Assume that the number of parameters is n. For PARAMETER STYLE DB2GENERAL, there must be no more than (255-(n*2))/2 columns. For PARAMETER STYLE SQL, there must be no more than (247-(n*2))/2 columns.

column-name
Specifies the name of a column of the output table. Do not specify the same name more than once.
data-type2
Specifies the data type of the column. The column is nullable.

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 DATE or TIME is specified, the table function must return the date or time in ISO format.

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.

Start of changeIf a CCSID is not specified and the function is not referenced in a view,End of change

  • 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 (Unicode graphic string data).

Start of changeIf a CCSID is not specified and the function is referenced in a view,End of change

Start of change
  • If AS LOCATOR is not specified, the result returned is assumed to be encoded in the CCSID of the associated view column.
  • If AS LOCATOR is specified, the data the locator points to is converted to the CCSID of the associated view column, 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 (Unicode graphic string data).
End of change
AS LOCATOR
Specifies that the function returns a locator to the value for the column rather than the actual value. You can specify AS LOCATOR only for a Start of changeLOB or XML data type or a distinct type based on a LOB or XML data typeEnd of change. If AS LOCATOR is specified, FOR SBCS DATA or FOR MIXED DATA must not be specified.

For more information on the AS LOCATOR clause, see Specifying AS LOCATOR for a parameter.

LANGUAGE
The language clause specifies the language of the external program.

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:

  • The program attribute information associated with the program does not identify a recognizable language
  • The program cannot be found
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.
JAVA
The external program is written in JAVA. The database manager will call the user-defined function as a method in a 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:
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.
  • The next M parameters are the result columns of the function that are specified on the RETURNS TABLE clause.

DB2GENERAL is only allowed when the LANGUAGE is JAVA.

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.
  • The next M parameters are the result columns of the function that are specified on the RETURNS TABLE clause.
  • N parameters for indicator variables for the input parameters.
  • M parameters for the indicator variables of the result columns of the function that are specified on the RETURNS TABLE clause
  • 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(1000) output parameter for the message text.
  • 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.
  • A structure for the dbinfo structure, if DBINFO was specified on the CREATE FUNCTION statement.
These parameters are passed according to the specified LANGUAGE. For example, if the language is C or C++, the VARCHAR parameters are passed as NUL-terminated strings. 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.

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 topic collection. For Java routines, see the IBM® Developer Kit for Java topic collection.

SPECIFIC specific-name
Specifies a unique name for the function. For more information on specific names, see Specifying a specific name for a function.
DETERMINISTIC or NOT DETERMINISTIC
Specifies whether the function returns the same results each time that the function is invoked with the same input arguments. The default is NOT DETERMINISTIC.
NOT DETERMINISTIC
Specifies that the function might not return the same result each time that the function is invoked with the same input arguments. The function depends on some state values that affect the results. The database manager uses this information during optimization of SQL statements. An example of a table function that is not deterministic is one that references special registers, non-deterministic functions, or a sequence in a way that affects the table function result table.
DETERMINISTIC
Start of changeSpecifies that the function always returns the same result table each time that the function is invoked with the same input arguments. The database manager uses this information during optimization of SQL statements.1End of change
CONTAINS SQL, READS SQL DATA, MODIFIES SQL DATA, or NO SQL
Specifies the classification of SQL statements that the function can execute. The database manager verifies that the SQL statements that the function issues are consistent with this specification. For the classification of each statement, see Characteristics of SQL statements. Start of changeThe default is READS SQL DATA.End of change
READS SQL DATA
Specifies that the function can execute statements with a data access classification of READS SQL DATA, CONTAINS SQL, or NO SQL. The function cannot execute SQL statements that modify data.
NO SQL
Specifies that the function can execute only SQL statements with a data access classification of NO SQL.
CONTAINS SQL
Specifies that the function can execute only SQL statements with a data access classification of CONTAINS SQL or NO SQL. The function cannot execute any SQL statements that read or 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. CALLED ON NULL INPUT is the default.
RETURNS NULL ON NULL INPUT
Specifies that the function is not called if any of the input arguments is null. The result is an empty table, which is a table with no rows.
CALLED ON NULL INPUT
Specifies that the function is to be invoked, if any argument values are null. This specification means that the function must be coded to test for null argument values. The function can return an empty table, depending on its logic.
INHERIT SPECIAL REGISTERS
Specifies that existing values of special registers are inherited upon entry to the function.
STATIC DISPATCH
Specifies that the function is dispatched statically. All functions are statically dispatched.
NO DBINFO or DBINFO
Specifies whether additional status information is passed when the function is invoked. The default is NO DBINFO.
NO DBINFO
Specifies that no additional information is passed.
DBINFO
Specifies that the database manager should pass a structure containing status information to the function. Table 1 contains a description of the DBINFO structure. Detailed information about the DBINFO structure can be found in sqludf in the appropriate source file in library QSYSINC. For example, for C, sqludf can be found in QSYSINC/H.
Table 1. 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.

Each set of CCSIDs is for a different encoding scheme (EBCDIC, ASCII, and Unicode).

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.
Number of table function column list entries SMALLINT The number of non-zero entries in the table function column list specified in the "Table function column list" field below.
Reserved CHAR(24) Reserved for future use.
Table function column list Pointer (16 Bytes) This field is a pointer to an array of short integers which is dynamically allocated by the database manager. Only the first n entries, where n is specified in the "Number of table function column list entries" field, are of interest, n may be equal to 0, and is less than or equal to the number of result columns defined for the function in the RETURNS TABLE clause. The values correspond to the ordinal numbers of the columns which this statement needs from the table function. A value of 1 means the first defined result column, 2 means the second defined result column, and so on. The values may be in any order. Note that n could be equal to zero for a statement that is similar to SELECT COUNT(*) FROM TABLE(TF(...)) AS QQ, where no actual column values are needed by the query.

This array represents an opportunity for optimization. The function need not return all values for all the result columns of the table function. Only a subset of the values may be needed in a particular context, and these are the columns identified (by number) in the array. Since this optimization may complicate the function logic, the function can choose to return every defined column.

EXTERNAL ACTION or NO EXTERNAL ACTION
Specifies whether the function takes an action that changes the state of an object that the database manager does not manage. An example of an external action is sending a message or writing a record to a stream file. The default is EXTERNAL ACTION.
EXTERNAL ACTION
Specifies that the function can take an action that changes the state of an object that the database manager does not manage. 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.

NO EXTERNAL ACTION functions might perform better than EXTERNAL ACTION functions because they might not be invoked for each successive function invocation.

FENCED or NOT FENCED
Specifies whether the external function runs in an environment that is isolated from the database manager environment. FENCED is the default.
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.

PROGRAM TYPE MAIN or PROGRAM TYPE SUB
This parameter is allowed for compatibility with other products. It indicates whether the routine's external program is a program (*PGM) or a procedure in a service program (*SRVPGM).
PROGRAM TYPE MAIN
Specifies that the routine executes as the main entry point in a program. The external program must be a *PGM object.
PROGRAM TYPE SUB
Specifies that the routine executes as a procedure in a service program. The external program must be a *SRVPGM object.
NO FINAL CALL or FINAL CALL
Specifies whether a separate first call and final call are made to the function. To differentiate between types of calls, the function receives an additional argument that specifies the type of call. For table functions, the call-type argument is always present (regardless of whether FINAL CALL or NO FINAL CALL is in effect), and it indicates first call, open call, fetch call, close call, or final call.

With NO FINAL CALL, the database manager will only make three types of calls to the table function: open, fetch and close. However, if FINAL CALL is specified, then in addition to open, fetch and close, a first call and a final call can be made to the table function.

A final call enables the function to free any system resources that it has acquired. A final call is useful when the function has been defined with the SCRATCHPAD keyword and the function acquires system resources and stores them in the scratchpad. The default is NO FINAL CALL.

NO FINAL CALL
Specifies that separate first and final calls are not made to the function. However, the open, fetch, and close calls are still made to the function, and the table function always receives an additional argument that specifies the type of call.
FINAL CALL
Specifies that separate first and final calls are made to the function. It also controls when the scratchpad is re-initialized.

The types of calls are:

First Call
Specifies the first call to the function for this reference to the function in this SQL statement.
Open Call
Specifies a call to open the table function result in this SQL statement.
Fetch Call
Specifies a call to fetch a row from the table function in this SQL statement.
Close Call
Specifies a call to close the table function result in this SQL statement.
Final Call
Specifies the last call to the function to enable the function to free resources. 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 transaction: When normal end of statement processing does not occur. For example, the logic of an application, for some reason, bypasses closing the cursor.

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.

Committable 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.

ALLOW PARALLEL or DISALLOW PARALLEL
Specifies whether the function can be run in parallel.

The default is DISALLOW PARALLEL if one or more of the following clauses are specified: NOT DETERMINISTIC, EXTERNAL ACTION, FINAL CALL, MODIFIES SQL DATA, or SCRATCHPAD. Otherwise, ALLOW PARALLEL is the default.

ALLOW PARALLEL
Specifies that the database manager can consider parallelism for the function. The database manager is not required to use parallelism on the SQL statement that invokes the function or on any SQL statement issued from within the function.

See the descriptions of NOT DETERMINISTIC, EXTERNAL ACTION, MODIFIES SQL DATA, SCRATCHPAD, and FINAL CALL for considerations that apply to specification of ALLOW PARALLEL.

DISALLOW PARALLEL
Specifies that the database manager must not use parallelism for the function.
NO SCRATCHPAD or SCRATCHPAD
Specifies whether the function requires a static memory area.
NO SCRATCHPAD
Specifies that the function does not require a persistent 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 SQL is specified, a pointer is passed following the required parameters that points to a static storage area. 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, two scratchpads are allocated for the two references to UDFX in the following SQL statement:
SELECT A.C1, B.C1 
  FROM TABLE(UDFX(:hv1)) AS A, TABLE(UDFX(:hv1)) AS B  
EXTERNAL
Specifies that the CREATE FUNCTION statement is being used to define a new function that is based on code that is written in an external programming language.

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

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 current path will be used to search for the program at the time the function is invoked.
  • *LIBL will be used to search for the program or service program at the time Start of changeCOMMENT, GRANT, LABEL, or REVOKEEnd of change operations are performed on the function.

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

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.

CONNECT, SET CONNECTION, RELEASE, DISCONNECT, COMMIT, ROLLBACK, and SET TRANSACTION statements are not allowed in the external program of the function.

CARDINALITY bigint
Specifies an estimate of the expected number of rows to be returned by the function for the database manager to use during optimization. bigint must be in the range from 0 to 9 223 372 036 854 775 807 inclusive. The database manager assumes a finite value if CARDINALITY is not specified.

A table function that returns a row every time it is called and never returns the end-of-table condition has infinite cardinality. A query that invokes such a function and requires an eventual end-of-table condition before it can return any data will not return unless interrupted. Table functions that never return the end-of-table condition should not be used in queries involving DISTINCT, GROUP BY, or ORDER BY.

Notes

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

Start of change
REPLACE rules: When an external function is recreated by REPLACE:
  • Any existing comment or label is discarded.
  • If a different external program is specified:
    • Authorized users are not copied to the new program.
    • Journal auditing is not changed.
  • Otherwise:
    • Authorized users are maintained. The object owner will not change.
    • Current journal auditing is not changed.
End of change

Start of changeCreating 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 attributes are used to update the catalogs.End of change

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

  • The external program library must not be SYSIBM, QSYS, or QSYS2.
  • The external program must exist when the CREATE FUNCTION statement is issued.

    If system naming is specified and the external program name is not qualified, the external program must be found in the library list.

  • The external program must be an ILE *PGM or *SRVPGM object.
  • The external program must not already contain attributes for 32 routines.

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

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.

Start of changeLANGUAGE JAVA functions always run in the default activation group (*DFTACTGRP). Caution should be used when writing MODIFIES SQL DATA Java functions. Since changes performed by the Java function are performed in the default activation group, transaction problems may occur if the invoker runs in a new activation group (*NEW).End of change

Notes for Java functions: To be able to run Java functions, you must have the IBM Developer Kit for Java (5761-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 function, an SQLCODE of -443 will be returned. Depending on the error, other messages may exist in the job log of the job where the function 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:

  • The keywords VARIANT and NOT VARIANT can be used as synonyms for NOT DETERMINISTIC and DETERMINISTIC.
  • The keywords NULL CALL and NOT NULL CALL can be used as synonyms for CALLED ON NULL INPUT and RETURNS NULL ON NULL INPUT.
  • The value DB2GENRL may be used as a synonym for DB2GENERAL.
  • The keywords PARAMETER STYLE in the PARAMETER STYLE clause are optional.
  • The keywords IS DETERMINISTIC may be used as a synonym for DETERMINISTIC.
  • The keywords PARAMETER STYLE DB2SQL may be used as a synonym for PARAMETER STYLE SQL.

Example

The following creates a table function written to return a row consisting of a single document identifier column for each known document in a text management system. The first parameter matches a given subject area and the second parameter contains a given string.

Within the context of a single session, the UDF will always return the same table, and therefore it is defined as DETERMINISTIC. Note the RETURNS clause which defines the output from DOCMATCH. FINAL CALL must be specified for each table function. Although the size of the output for DOCMATCH is highly variable, CARDINALITY 20 is a representative value, and is specified to help the optimizer.

CREATE FUNCTION DOCMATCH (VARCHAR(30), VARCHAR(255))
  RETURNS TABLE (DOCID CHAR(16))
  EXTERNAL NAME 'MYLIB/RAJIV(UDFMATCH)'
  LANGUAGE C
  PARAMETER STYLE SQL
  NO SQL
  DETERMINISTIC
  NO EXTERNAL ACTION
  NOT FENCED
  SCRATCHPAD
  FINAL CALL
  DISALLOW PARALLEL
  CARDINALITY 20
1 The query optimizer may choose to cache deterministic table function results. The DETERMINISTIC_UDF_SCOPE QAQQINI option can be used to control the scope of the caching. For more information, see the Database Performance and Query Optimization topic collection.