This CREATE FUNCTION (External Table) statement creates an external table function at the current server. The function returns a result table.
A table function may be used in the FROM clause of a SELECT, and returns a table to the SELECT by returning one row at a time.
You can embed this statement in an application program, or you can issue this statement interactively. It is an executable statement that can be dynamically prepared.
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.
>>-CREATE FUNCTION--function-name-------------------------------> >--(--+---------------------------+--)--------------------------> | .-,---------------------. | | V | | '---parameter-declaration-+-' .-,---------------------------------------. V | >--RETURNS TABLE--(----column-name--data-type2--+------------+-+--)--> '-AS LOCATOR-' >--option-list-------------------------------------------------><
parameter-declaration: |--+----------------+--data-type1--+------------+---------------| '-parameter-name-' '-AS LOCATOR-' data-type1, data-type2: |--+-built-in-type------+---------------------------------------| '-distinct-type-name-'
built-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-----'
option-list: (1) |--+-----------------------+------------------------------------> '-LANGUAGE--+-C-------+-' +-C++-----+ +-CL------+ +-COBOL---+ +-COBOLLE-+ +-FORTRAN-+ +-JAVA----+ +-PLI-----+ +-RPG-----+ '-RPGLE---' >--+-PARAMETER STYLE DB2SQL-----+-------------------------------> '-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-. >--+------------+--+---------------+----DISALLOW PARALLEL-------> '-NOT FENCED-' '-FINAL CALL----' .-NO SCRATCHPAD-----------. >--+-------------------------+----------------------------------> | .-100-----. | '-SCRATCHPAD--+---------+-' '-integer-' .-EXTERNAL-----------------------------. >--+--------------------------------------+---------------------> '-EXTERNAL NAME--external-program-name-' >--+---------------------+--------------------------------------| '-CARDINALITY--bigint-'
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.
The maximum number of parameters allowed in CREATE FUNCTION (External Table) is 90. The maximum number of parameters may be additionally limited by the maximum number of parameters allowed by the licensed program that is used to compile the external program.
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.
Assume the number of parameters is N. For PARAMETER STYLE DB2GENERAL, there must be no more than (255-(N*2))/2 columns. For PARAMETER STYLE DB2SQL, there must be no more than (247-(N*2))/2 columns.
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 a CCSID is not specified,
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:
DB2GENERAL is only allowed when the LANGUAGE is JAVA.
The user may set the SQLSTATE to any valid value in the external program to return an error or warning from the function.
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.
If specific name is not specified, it is set to the function name. If a function or procedure with that specific name already exists, a unique name is generated similar to the rules used to generate unique table names.
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:
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:
|
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. |
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 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.
The types of calls are:
A final call occurs at these times:
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.
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.
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
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.
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.
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:
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. In addition, the DISALLOW PARALLEL keyword is added as table functions cannot operate in parallel. 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 DB2SQL NO SQL DETERMINISTIC NO EXTERNAL ACTION NOT FENCED SCRATCHPAD FINAL CALL DISALLOW PARALLEL CARDINALITY 20