CREATE FUNCTION statement (external scalar function)
This CREATE FUNCTION statement registers a user-defined external scalar function with a database server. A scalar function returns a single value each time it is invoked.
Invocation for CREATE FUNCTION (external scalar)
This statement can be embedded in an application program or issued interactively. It is an executable statement that can be dynamically prepared only if DYNAMICRULES RUN behavior is in effect. For more information, see Authorization IDs and dynamic SQL.
Authorization for CREATE FUNCTION (external scalar)
The privilege set defined below must include at least one of the following:
- The CREATEIN privilege on the schema
- SYSADM or SYSCTRL authority
- System DBADM
Installation SYSOPR authority (when the current SQLID of the process is set to SYSINSTL)
The authorization ID that matches the schema name implicitly has the CREATEIN privilege on the schema.
If the authorization ID that is used to
create the function has the installation SYSADM authority or the
installation SYSOPR authority and if the current SQLID is set to SYSINSTL,
the function is identified as system-defined function.
Additional privileges are required if the function uses a table as a parameter, refers to a distinct type, or is to run in a WLM (workload manager) environment. These privileges are:
- The SELECT privilege on any table that is an input parameter to the function.
- The USAGE privilege on each distinct type that the function references.
- Authority to create programs in the specified WLM environment. This authorization is obtained from an external security product, such as RACF®. For more information, see Managing authorizations for creation of stored procedures in WLM environments.
At least one of the following additional privileges is required if the SECURED option is specified
- SECADM authority
- CREATE_SECURE_OBJECT privilege
When LANGUAGE is JAVA and a jar-name is specified in the EXTERNAL NAME clause, the privilege set must include USAGE on the JAR file.
Privilege set: If the statement is embedded in an application program, the privilege set is the privileges that are held by the owner of the plan or package. If the owner is a role, the implicit schema match does not apply and this role needs to include one of the previously listed conditions.
If the statement is dynamically prepared and is not running in a trusted context for which the ROLE AS OBJECT OWNER clause is specified, the privilege set is the set of privileges that are held by the SQL authorization ID of the process. If the schema name is not the same as the SQL authorization ID of the process, one of the following conditions must be met:
- The privilege set includes SYSADM or SYSCTRL authority.
- The SQL authorization ID of the process has the CREATEIN privilege on the schema.
Syntax for CREATE FUNCTION (external scalar)
- 1 This clause and the clauses that follow in the option-list can be specified in any order.
- 2 AS LOCATOR can be specified only for a LOB data type or a distinct type based on a LOB data type.
parameter-declaration:
- 1 AS LOCATOR can be specified only for a LOB data type or a distinct type based on a LOB data type.
data-type:
built-in-type:
option-list: (The clauses in the option list can be specified in any order)
- 1 The same clause must not be specified more than one time.
- 2 If NOT DETERMINISTIC, EXTERNAL ACTION, SCRATCHPAD, or FINAL CALL is specified, DISALLOW PARALLEL is the default.
Description for CREATE FUNCTION (external scalar)
- function-name
- Names the user-defined function. The name is implicitly or explicitly qualified by a schema name. For more information, see
Choosing the schema and function names
andDetermining the uniqueness of functions in a schema
in CREATE FUNCTION statement (overview). - (parameter-declaration,…)
- Identifies the number of input parameters of the function, and
specifies the data type of each parameter. All of the parameters for
a function are input parameters and are nullable. There must be one
entry in the list for each parameter that the function expects to
receive. Although not required, you can give each parameter a name.
A function can have no parameters. In this case, you must code an empty set of parentheses, for example:
CREATE FUNCTION WOOFER()
- parameter-name
- Specifies the name of the input parameter. The name is an SQL identifier, and each name in the parameter list must not be the same as any other name.
- data-type
- 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
- The data type of the input parameter is a built-in data type.
For information on the data types, see built-in-type.
For parameters with a character or graphic data type, the PARAMETER CCSID clause or CCSID clause indicates the encoding scheme of the parameter. If you do not specify either of these clauses, the encoding scheme is the value of field DEF ENCODING SCHEME on installation panel DSNTIPF.
- distinct-type-name
- The data type of the input parameter is a distinct type. Any length,
precision, scale, subtype, or encoding scheme attributes for the parameter
are those of the source type of the distinct type.
If you specify the name of the distinct type without a schema name, Db2 resolves the schema name by searching the schemas in the SQL path.
The implicitly or explicitly specified encoding scheme of all of the parameters with a character or graphic string data type must be the same—either all ASCII, all EBCDIC, or all UNICODE.
Although parameters with a character data type have an implicitly or explicitly specified subtype (BIT, SBCS, or MIXED), the function program can receive character data of any subtype. Therefore, conversion of the input data to the subtype of the parameter might occur when the function is invoked. An error occurs if mixed data that actually contains DBCS characters is used as the value for an input parameter that is declared with an SBCS subtype.
Parameters with a datetime data type or a distinct type are passed to the function as a different data type:
- A datetime type parameter is passed as a character data type,
and the data is passed in ISO format.
The encoding scheme for a datetime type parameter is the same as the implicitly or explicitly specified encoding scheme of any character or graphic string parameters. If no character or graphic string parameters are passed, the encoding scheme is the value of field DEF ENCODING SCHEME on installation panel DSNTIPF.
- A distinct type parameter is passed as the source type of the distinct type.
- 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.
Passing locators instead of values can result in fewer bytes being
passed to the function, especially when the value of the parameter
is very large.
The AS LOCATOR clause has no effect on determining whether data types can be promoted, nor does it affect the function signature, which is used in function resolution.
- TABLE LIKE table-name or view-name AS LOCATOR
- Specifies
that the parameter is a transition table. However, when the function
is invoked, the actual values in the transition table are not passed
to the function. A single value is passed instead. This single value
is a locator to the table, which the function uses to access the columns
of the transition table. A function with a table parameter can only
be invoked from the triggered action of a trigger.
The use of TABLE LIKE provides an implicit definition of the transition table. It specifies that the transition table has the same number of columns as the identified table or view. If a table is specified, the transition table includes columns that are defined as implicitly hidden in the table. The columns have the same data type, length, precision, scale, subtype, and encoding scheme as the identified table or view, as they are described in catalog tables SYSCOLUMNS and SYSTABLESPACE. The number of columns and the attributes of those columns are determined at the time the CREATE FUNCTION statement is processed. Any subsequent changes to the number of columns in the table or the attributes of those columns do not affect the parameters of the function.
table-name or view-name must identify a table or view that exists at the current server. A view cannot have columns of length 0. The name must not identify a declared temporary table. The table that is identified can contain XML columns; however, the function cannot reference those XML columns. The name does not have to be the same name as the table that is associated with the transition table for the trigger. An unqualified table or view name is implicitly qualified according to the following rules:
- If the CREATE FUNCTION statement is embedded in a program, the implicit qualifier is the authorization ID in the QUALIFIER bind option when the plan or package was created or last rebound. If QUALIFIER was not used, the implicit qualifier is the owner of the plan or package.
- If the CREATE FUNCTION statement is dynamically prepared, the implicit qualifier is the SQL authorization ID in the CURRENT SCHEMA special register.
When the function is invoked, the corresponding columns of the transition table identified by the table locator and the table or view identified in the TABLE LIKE clause must have the same definition. The data type, length, precision, scale, and encoding scheme of these columns must match exactly. The description of the table or view at the time the CREATE FUNCTION statement was executed is used.
Additionally, a character FOR BIT DATA column of the transition table cannot be passed as input for a table parameter for which the corresponding column of the table specified at the definition is not defined as character FOR BIT DATA. (The definition occurs with the CREATE FUNCTION statement.) Likewise, a character column of the transition table that is not FOR BIT DATA cannot be passed as input for a table parameter for which the corresponding column of the table specified at the definition is defined as character FOR BIT DATA.
For more information about using table locators, see Accessing transition tables in a user-defined function or stored procedure.
- RETURNS
- Specifies
the data type for the result of the function. Consider this clause
in conjunction with the optional CAST FROM clause.
- data-type2
- Specifies the data type of the output. The output
parameter is nullable.
The same considerations that apply to the data type and nullability of input parameter, as described under data-type, apply to the data type of the result of the function.
- AS LOCATOR
- Specifies that the function returns a locator to the value rather than the actual value. You can specify AS LOCATOR only if the output from the function has a LOB data type or a distinct type based on a LOB data type.
- data-type3 CAST FROM data-type4
- Specifies the data type of the output of the function (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 DOUBLE value, which Db2 converts
to a DECIMAL value and then passes to the statement that invoked the
function:
The value of data-type4 can be any built-in data type and must be castable to data-type3. The value for data-type3 can be any built-in data type. (For information on casting data types, see Casting between data types.) The encoding scheme of the parameters, if they are string data types, must be the same.CREATE FUNCTION SQRT(DECIMAL(15,0)) RETURNS DECIMAL(15,0) CAST FROM DOUBLE ...
If the PARAMETER VARCHAR clause is specified, data-type3 and data-type4 should be specified as VARCHAR.
- AS LOCATOR
- Specifies that the function returns a locator to the value rather than the value. You can specify AS LOCATOR only if data-type4 is a LOB data type or a distinct type based on a LOB data type.
- SPECIFIC specific-name
- Specifies
a unique name for the function. The name is implicitly or explicitly
qualified with a schema name. The name, including the schema name,
must not identify the specific name of another function that exists
at the current server.
The unqualified form of specific-name is an SQL identifier. The qualified form is an SQL identifier (the schema name) followed by a period and an SQL identifier.
If you do not specify a schema name, it is the same as the explicit or implicit schema name of the function name (function-name). If you specify a schema name, it must be the same as the explicit or implicit schema name of the function name.
If you do not specify the SPECIFIC clause, the default specific name is the name of the function. However, if the function name does not provide a unique specific name or if the function name is a single asterisk, Db2 generates a specific name in the form of:
whereSQLxxxxxxxxxxxx
'xxxxxxxxxxxx'
is a string of 12 characters that make the name unique.The specific name is stored in the SPECIFIC column of the SYSROUTINES catalog table. The specific name can be used to uniquely identify the function in several SQL statements (such as ALTER FUNCTION, COMMENT, DROP, GRANT, and REVOKE) and must be used in Db2 commands (START FUNCTION, STOP FUNCTION, and DISPLAY FUNCTION). However, the function cannot be invoked by its specific name.
- PARAMETER CCSID or VARCHAR
- Specifies
the encoding scheme for character and graphic string
parameters, and in the case of LANGUAGE C, specifies that representation
of variable length string parameters.
- CCSID
- Indicates whether the encoding scheme for character
and graphic string parameters is ASCII, EBCDIC, or UNICODE. The
default encoding scheme is the value specified in the CCSID clauses
of the parameter list or RETURNS clause, or in the field DEF ENCODING
SCHEME on installation panel DSNTIPF.
This clause provides a convenient way to specify the encoding scheme for all string parameters. If individual CCSID clauses are specified for individual parameters in addition to this PARAMETER CCSID clause, the value specified in all of the CCSID clauses must be the same value that is specified in this clause.
This clause also specifies the encoding scheme to be used for system-generated parameters of the routine such as message tokens and DBINFO.
- VARCHAR
- Specifies that the representation of the values of varying length
character string-parameters, including, if applicable, the output
of the function, for functions which specify LANGUAGE C.
This option can only be specified if LANGUAGE C is also specified.
- NULTERM
- Specifies that variable length character string parameters are represented in a NUL-terminated string form.
- STRUCTURE
- Specifies that variable length character string parameters are represented in a VARCHAR structure form.
Using the PARAMETER VARCHAR clause, there is no way to specify the VARCHAR form of an individual parameter as there is with the PARAMETER CCSID clause. The PARAMETER VARCHAR clause only applies to parameters in the parameter list of a function and in the RETURNS clause. It does not apply to system-generated parameters of the routine such as message tokens and DBINFO.
In a data sharing environment, you should not specify the PARAMETER VARCHAR clause until all members of the data sharing group support the clause. If some group members support this clause and others do not, and PARAMETER VARCHAR is specified in an external routine, the routine will encounter different parameter forms depending on which group member invokes the routine.
- 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.
Db2 loads the load module when the function is invoked. The load module is created when the program that contains the function body is compiled and link-edited. The load module does not need to exist when the CREATE FUNCTION statement is executed. However, it must exist and be accessible by the current server when the function is invoked.
You can specify the EXTERNAL clause in one of the following ways:EXTERNAL EXTERNAL NAME PKJVSP1 EXTERNAL NAME 'PKJVSP1'
If you specify an external program name, you must use the NAME keyword. For example, this syntax is not valid:EXTERNAL PKJVSP1
- NAME external-program-name or identifier
- Identifies
the user-written code that implements the user-defined function.
If LANGUAGE is JAVA, external-program-name must be specified and enclosed in single quotation marks, with no extraneous blanks within the single quotation marks. It must specify a valid external-java-routine-name. If multiple external-program-names are specified, the total length of all of them must not be greater than 1305 bytes and they must be separated by a space or a line break. Do not specify a JAR file for a JAVA function for which NO SQL is also specified.
An external-java-routine-name contains the following parts:- jar-name
- Identifies the name given to the JAR file when it was installed
in the database. The name contains jar-id,
which can optionally be qualified with a schema. Examples are "myJar"
and "mySchema.myJar." The unqualified jar-id is
implicitly qualified with a schema name according to the following
rules:
- If the statement is embedded in a program, the schema name is the authorization ID in the QUALIFIER bind option when the package or plan was created or last rebound. If the QUALIFIER was not specified, the schema name is the owner of the package or plan.
- If the statement is dynamically prepared, the schema name is the SQL authorization ID in the CURRENT SCHEMA special register.
If jar-name is specified, it must exist when the CREATE FUNCTION statement is processed.
If jar-name is not specified, the function is loaded from the class file directly instead of being loaded from a JAR file. Db2 searches the directories in the CLASSPATH associated with the WLM Environment. Environmental variables for Java™ routines are specified in a data set identified in a JAVAENV DD card on the JCL used to start the address space for a WLM-managed function.
- method-name
- Identifies the name of the method and must not be longer than
254 bytes. Its package, class, and method ID's are specific to Java and as such are not limited
to 18 bytes. In addition, the rules for what these can contain are
not necessarily the same as the rules for an SQL ordinary identifier.
- package-id
- Identifies a package. The concatenated list of package-ids identifies the package that the class identifier is part of. If the class is part of a package, the method name must include the complete package prefix, such as "myPacks.UserFuncs." The Java virtual machine looks in the directory "/myPacks/UserFuncs/" for the classes.
- class-id
- Identifies the class identifier of the Java object.
- method-id
- Identifies the method identifier with the Java class to be invoked.
- method-signature
- Identifies a list of zero or more Java data
types for the parameter list and must not be longer than 1024 bytes.
Specify the method-signature if the user-defined
function involves any input or output parameters that can be NULL.
When the function being created is called, Db2 searches for a Java method
with the exact method-signature. The number
of java-datatype elements specified indicates
how many parameters that the Java method
must have.
A Java procedure can have no parameters. In this case, you code an empty set of parentheses for method-signature. If a Java method-signature is not specified, Db2 searches for a Java method with a signature derived from the default JDBC types associated with the SQL types specified in the parameter list of the CREATE FUNCTION statement.
For other values of LANGUAGE, the name can be a string constant that is no longer than 8 characters. It must conform to the naming conventions for load modules. Alphabetical extenders for national languages can be used as the first character and as subsequent characters in the load module name.
If you do not specify the NAME clause, 'NAME function-name' is implicit. In this case, function-name must not be longer than 8 characters.
- LANGUAGE
- Specifies the language interface convention to which the body of the function is written. All programs must be designed to run in IBM®'s Language Environment® environment.
- ASSEMBLE
- The function is written in Assembler.
- C
- The function is written in C or C++.
- COBOL
- The function is written in COBOL, including the object-oriented language extensions.
- JAVA
- The user-defined function is written in Java and is executed in the Java Virtual Machine. When LANGUAGE JAVA is
specified, the EXTERNAL NAME clause must also be specified with a
valid external-java-routine-name and PARAMETER
STYLE must be specified with JAVA.
Do not specify LANGUAGE JAVA when SCRATCHPAD, FINAL CALL, DBINFO, PROGRAM TYPE MAIN, or RUN OPTIONS is in effect.
- PLI
- The function is written in PL/I.
- PARAMETER STYLE
- Specifies
the conventions for passing parameters to and returning a value from
the function.
- SQL
- Specifies the parameter passing convention that supports passing
null values both as input and for output. The parameters that are
passed between the invoking SQL statement and the function include:
- n parameters for the input parameters that are specified for the function
- A parameter for the result of the function
- n parameters for the indicator variables for the input parameters
- A parameter for the indicator variable for the result
- The SQLSTATE to be returned to Db2
- The qualified name of the function
- The specific name of the function
- The SQL diagnostic string to be returned to Db2
- The function can also pass from zero to three additional
parameters:
- The scratchpad, if SCRATCHPAD is specified
- The call type, if FINAL CALL is specified
- The DBINFO structure, if DBINFO is specified
- JAVA
- Indicates that the user-defined function uses a convention for passing parameters that conforms to the Java and SQLJ specifications. PARAMETER STYLE JAVA can be specified only if LANGUAGE is specified as JAVA. JAVA must be specified for PARAMETER STYLE when LANGUAGE JAVA is specified.
- NOT DETERMINISTIC or DETERMINISTIC
- Specifies whether the function
returns the same results each time that the function is invoked with
the same input arguments.
- NOT DETERMINISTIC
- 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. Db2 uses this information to disable the merging
of views and table expressions when processing SELECT or SQL
data change statements that refer to this function. An example
of a function that is not deterministic is one that generates random
numbers, or any function that contains SQL statements.
NOT DETERMINISTIC is the default.
Some functions that are not deterministic can receive incorrect results if the function is executed by parallel tasks. Specify the DISALLOW PARALLEL clause for these functions.
- DETERMINISTIC
- The function always returns the same result each time that the function is invoked with the same input arguments. An example of a deterministic function is a function that calculates the square root of the input. Db2 uses this information to enable the merging of views and table expressions for SELECT or SQL data change statements that refer to this function. DETERMINISTIC is not the default. If applicable, specify DETERMINISTIC to prevent non-optimal access paths from being chosen for SQL statements that refer to this function.
Db2 does not verify that the function program is consistent with the specification of DETERMINISTIC or NOT DETERMINISTIC.
- FENCED
- Specifies
that the external function runs in an external address space to prevent
the function from corrupting Db2 storage.
FENCED is the default.
- 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 NULL INPUT
- The function is not called if any of the input arguments is null. The result is the null value. RETURNS NULL ON INPUT is the default.
- CALLED ON NULL INPUT
- The function is called regardless of whether any of the input arguments are null, making the function responsible for testing for null argument values. The function can return a null or nonnull value.
- MODIFIES SQL DATA, READS SQL DATA, CONTAINS SQL, or NO SQL
- Specifies the classification of SQL statements and nested routines
that this routine can execute or invoke. The database manager verifies that the SQL statements
issued by the function, and all routines locally invoked by the routine, are consistent with this
specification; the verification is not performed when nested remote routines are invoked. For the
classification of each statement, see SQL statement data access classification for routines.
- MODIFIES SQL DATA
-
Specifies that the function can execute any SQL statement except the statements that are not supported in functions. Do not specify MODIFIES SQL DATA when ALLOW PARALLEL is in effect.
If a function that is defined with MODIFIES SQL DATA is invoked anywhere except the select-clause of the outermost SELECT statement, the results are unpredictable because the function can be invoked multiple times depending on the access plan that is used.
Recommendation:If a SELECT statement invokes a function that is defined with the
MODIFIES SQL DATA
option, ensure that statements nested inside the function do not modify objects that are referenced in any SQL statement at a higher level of nesting. Otherwise, unpredictable results are likely to occur. - READS SQL DATA
- Specifies that the function can execute statements with a data access indication of READS SQL DATA, CONTAINS SQL, or NO SQL. The function cannot execute SQL statements that modify data. The default is READS SQL DATA.
- CONTAINS SQL
- Specifies that the function can execute only SQL statements with an access indication of CONTAINS SQL or NO SQL. The function cannot execute statements that read or modify data.
- NO SQL
- Specifies that the function can execute only SQL statements with a data access classification of NO SQL. Do not specify NO SQL for a JAVA function that uses a JAR file.
- EXTERNAL ACTION or NO EXTERNAL ACTION
- Specifies
whether the function takes an action that changes the state of an
object that Db2 does not manage.
An example of an external action is sending a message or writing a
record to a file.
Because Db2 uses the RRS attachment for external functions, Db2 can participate in two-phase commit with any other resource manager that uses RRS. For resource managers that do not use RRS, there is no coordination of commit or rollback operations on non-Db2 resources.
- EXTERNAL ACTION
- Specifies that the function can take an action that changes the
state of an object that Db2 does
not manage.
Some SQL statements that invoke functions with external actions can result in incorrect results if parallel tasks execute the function. For example, if the function sends a note for each initial 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 do not work correctly with parallelism.
If you specify EXTERNAL ACTION, Db2:
- Materializes the views and table expressions in SELECT or data change statements statements that refer to the function. This materialization can adversely affect the access paths that are chosen for the SQL statements that refer to this function. Do not specify EXTERNAL ACTION if the function does not have an external action.
- Does not move the function from one task control block (TCB) to another between FETCH operations.
- Does not allow another function or stored procedure to use the TCB until the cursor is closed. This is also applicable for cursors declared WITH HOLD.
The only changes to resources made outside of Db2 that are under the control of commit and rollback operations are those changes made under RRS control.
EXTERNAL ACTION is the default.
- NO EXTERNAL ACTION
- Specifies that the function does not take any action that changes
the state of an object that Db2 does
not manage. Db2 uses this information
to enable the merging of views and table expressions
for SELECT and data change statements that refer to this function.
If applicable, specify NO EXTERNAL ACTION to prevent non-optimal access
paths from being chosen for SQL statements that refer to this function.
Although the scope of global variables are beyond the scope of the routine, global variables can be set in the routine body when NO EXTERNAL ACTION is specified.
Db2 does not verify that the function program is consistent with the specification of EXTERNAL ACTION or NO EXTERNAL ACTION.
- NO PACKAGE PATH or PACKAGE PATH package-path
- Specifies
the package path to use when the function is run. This is the list
of the possible package collections into which the DBRM this is associated
with the function is bound.
- NO PACKAGE PATH
- Specifies that the list of package collections for the function is the same as the list of package collection IDs for the program that invokes the function. If the program that invokes the function does not use a package, Db2 resolves the package by using the CURRENT PACKAGE PATH special register, the CURRENT PACKAGESET special register, or the PKLIST bind option (in this order). For information about how Db2 uses these three items, see Binding an application plan.
- PACKAGE PATH package-path
- Specifies a list of package collections, in the same format as
the SET CURRENT PACKAGE PATH special register.
If the COLLID clause is specified with PACKAGE PATH, the COLLID clause is ignored when the function is invoked.
The package-path value that is provided when the function is created is checked when the function is invoked. If package-path contains SESSION_USER (or USER), PATH, or PACKAGE PATH, an error is returned when the package-path value is checked.
- NO SCRATCHPAD or SCRATCHPAD
- Specifies
whether Db2 is to provide a
scratchpad for the function. It is strongly recommended that external
functions be reentrant, and a scratchpad provides an area for the
function to save information from one invocation to the next.
- NO SCRATCHPAD
- Specifies that a scratchpad is not allocated and passed to the function. NO SCRATCHPAD is the default.
- SCRATCHPAD length
- Specifies that when the function is invoked for the first time, Db2 allocates memory for a scratchpad.
A scratchpad has the following characteristics:
- length must be in the range 1–32767. The default value is 100 bytes.
- Db2 initializes the scratchpad to all binary zeros (X'00''s).
- 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.
- The scratchpad is persistent. Db2 preserves its content from one invocation of the function to the next. Any changes that the function makes to the scratchpad on one call are still there on the next call. Db2 initializes the scratchpads when it begins to execute an SQL statement. Db2 does not reset scratchpads when a correlated subquery begins to execute.
- The scratchpad can be a central point for the system resources that the function acquires. If the function acquires system resources, specify FINAL CALL to ensure that Db2 calls the function one more time so that the function can free those system resources.
Each time the function invoked, Db2 passes an additional argument to the function that contains the address of the scratchpad.
If you specify SCRATCHPAD, Db2:
- Does not move the function from one task control block (TCB) to another between FETCH operations.
- Does not allow another function or stored procedure to use the TCB until the cursor is closed. This is also applicable for cursors declared WITH HOLD.
Do not specify SCRATCHPAD when LANGUAGE JAVA is in effect.
- NO FINAL CALL or FINAL CALL
- Specifies
whether a final call is made to the 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 resource and anchors
them in the scratchpad.
- NO FINAL CALL
- Specifies that a final call is not made to the function. The function does not receive an additional argument that specifies the type of call. NO FINAL CALL is the default.
- 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. The types of calls are:
- First call
- Specifies that 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 that 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, Db2 attempts to make
the final call unless the function abended. 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.
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.
If a commit, rollback, or abort operation causes the final call, the function cannot issue any SQL statements when it is invoked.
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.
Do not specify FINAL CALL when LANGUAGE JAVA is in effect.
- ALLOW or DISALLOW PARALLEL
- For
a single reference to the function, specifies whether parallelism
can be used when the function is invoked. Although parallelism can
be used for most scalar functions, some functions such as those that
depend on a single copy of the scratchpad cannot be invoked with parallel
tasks.
Consider these characteristics when determining which clause to use:
- If all invocations of the function are completely independent from one another, specify ALLOW PARALLEL.
- If each invocation of the function updates the scratchpad, providing values that are of interest to the next invocation, such as incrementing a counter, specify DISALLOW PARALLEL.
- If the scratchpad is used only so that some expensive initialization processing is performed a minimal number of times, specify ALLOW PARALLEL.
- If the function performs some external action that should apply to only one partition, specify DISALLOW PARALLEL.
- If the function is defined with MODIFIES SQL DATA, specify DISALLOW PARALLEL, not ALLOW PARALLEL.
ALLOW PARALLEL is the default unless NOT DETERMINISTIC, EXTERNAL ACTION, SCRATCHPAD, or FINAL CALL is specified, in which case, DISALLOW PARALLEL is the default.
- ALLOW PARALLEL
- Specifies that Db2 can consider parallelism for the function. Parallelism is not forced on the SQL statement that invokes the function or on any SQL statement in the function. Existing restrictions on parallelism apply.
- DISALLOW PARALLEL
- Specifies that Db2 does not consider parallelism for the function.
- NO DBINFO or DBINFO
- Specifies whether
additional status information is passed to the function when it is
invoked.
- NO DBINFO
- No additional information is passed. NO DBINFO is the default.
- DBINFO
- An additional argument is passed when the function is invoked. The argument is a structure that contains information such as the application runtime authorization ID, the schema name, the name of a table or column that the function might be inserting into or updating, and identification of the database server that invoked the function. For details about the argument and its structure, see DBINFO structure.
Do not specify DBINFO when LANGUAGE JAVA is in effect.
- NO COLLID or COLLID collection-id
- Identifies
the package collection that is to be used when the function is executed.
This is the package collection into which the DBRM that is associated
with the function program is bound.
- NO COLLID
- The package collection for the function is the same as the package collection of the program that invokes the function. If a trigger invokes the function, the collection of the trigger package is used. If the invoking program does not use a package, Db2 resolves the package by using the CURRENT PACKAGE PATH special register, the CURRENT PACKAGESET special register, or the PKLIST bind option (in this order). For details about how Db2 uses these three items, see the information on package resolution in Overriding the values that Db2 uses to resolve package lists.
NO COLLID is the default.
- COLLID collection-id
- The name of the package collection that is to be used when the function is executed.
- WLM ENVIRONMENT
- Identifies the WLM (workload manager) application environment in which the function is to run. The name of the WLM environment is an SQL identifier.
If you do not specify WLM ENVIRONMENT, the function runs in the WLM-established stored procedure address space that is specified at installation time. When LANGUAGE is JAVA, you must specify WLM ENVIRONMENT, and the WLM environment in which the function is to run must be Java-enabled.
- name
- The WLM environment in which the function must run. If another user-defined function or a stored procedure calls the function and that calling routine is running in an address space that is not associated with the WLM environment, Db2 routes the function request to a different address space.
- (name,*)
- When an SQL application program directly invokes the function, the WLM environment in which the function runs.
If another user-defined function or a stored procedure calls the function, the function runs in same environment that the calling routine uses. In this case, authorization to run the function in the WLM environment is not checked because the authorization of the calling routine suffices.
Users must have the appropriate authorization to execute functions in the specified WLM environment.
- ASUTIME
- Specifies
the total amount of processor time, in CPU service units, that a single
invocation of the function can run. The value is unrelated to the
ASUTIME column of the resource limit specification table. This option
is ignored if LANGUAGE JAVA is specified.
When you are debugging a function, setting a limit can be helpful if the function gets caught in a loop. For information on service units, see z/OS MVS Initialization and Tuning Guide.
- NO LIMIT
- There is no limit on the service units. NO LIMIT is the default.
- LIMIT integer
- The limit on the number of CPU service units is a positive integer in the range 1–2147483647. If the procedure uses more service units than the specified value, Db2 cancels the procedure. The CPU cycles that are consumed by parallel tasks in a procedure do not contribute towards the specified ASUTIME LIMIT.
- STAY RESIDENT
- Specifies
whether the load module for the function is to remain resident in
memory when the function ends. This option is ignored if LANGUAGE
JAVA is specified.
- NO
- The load module is deleted from memory after the function ends. Use NO for non-reentrant functions. NO is the default.
- YES
- The load module remains resident in memory after the function ends. Use YES for reentrant functions.
- PROGRAM TYPE
- Specifies
whether the function program runs as a main routine or a subroutine.
- SUB
- The function runs as a subroutine. With LANGUAGE JAVA, PROGRAM TYPE SUB is the only valid option. SUB is the default.
- MAIN
- The function runs as a main routine.
- SECURITY
- Specifies
how the function interacts with an external security product, such
as RACF, to control access
to non-SQL resources.
- Db2
- The function does not require an external security environment.
If the function accesses resources that an external security product
protects, the access is performed using the authorization ID that
is associated with the WLM-established stored procedure address space.
Db2 is the default.
- USER
- An external security environment should be established for the function. If the function accesses resources that the external security product protects, the access is performed using the primary authorization ID of the process that invoked the function.
- DEFINER
- An external security environment should be established for the function. If the function accesses resources that the external security product protects, the access is performed using the authorization ID of the owner of the function.
- STOP AFTER SYSTEM DEFAULT FAILURES, STOP AFTER nn FAILURES, or CONTINUE AFTER FAILURE
- Specifies
whether the routine is to be put in a stopped state after some number
of failures.
- STOP AFTER SYSTEM DEFAULT FAILURES
- Specifies that this routine should be placed in a stopped state after the number of failures indicated by the value of field MAX ABEND COUNT on installation panel DSNTIPX. This is the default.
- STOP AFTER nn FAILURES
- Specifies that this routine should be placed in a stopped state after nn failures. The value nn can be an integer 1–32767.
- CONTINUE AFTER FAILURE
- Specifies that this routine should not be placed in a stopped state after any failure.
- RUN OPTIONS runtime-options
- Specifies
the Language Environment runtime
options to be used for the function. You must specify runtime-options as
a character string that is no longer than 254 bytes. If you do not
specify RUN OPTIONS or pass an empty string, Db2 does not pass any runtime options to Language Environment,
and Language Environment uses
its installation defaults. For a description of the Language Environment runtime
options, see Language Environment Programming Reference.
Do not specify RUN OPTIONS when LANGUAGE JAVA is in effect.
- INHERIT SPECIAL REGISTERS or DEFAULT SPECIAL REGISTERS
- Specifies how special registers are set on entry to the routine.
- INHERIT SPECIAL REGISTERS
- Specifies that the values of special registers are inherited according to the rules listed in the table for characteristics of special registers in a user-defined function in Special registers in a user-defined function or a stored procedure.
- DEFAULT SPECIAL REGISTERS
- Specifies that special registers are initialized to the default values, as indicated by the rules in the table for characteristics of special registers in a user-defined function in Special registers in a user-defined function or a stored procedure.
- STATIC DISPATCH
- At function resolution time, Db2 chooses a function based on the static (or declared) types of the function parameters. STATIC DISPATCH is the default.
- NOT SECURED or SECURED
- Specifies if the function is considered secure for row access
control and column access control.
- NOT SECURED
- Specifies that the function is not considered as secure for row
access control and column access control.
NOT SECURED is the default.
When the function is invoked, the arguments of the function must not reference a column for which a column mask is enabled when the table is using active column access control.
- SECURED
- Specifies that the function is considered secure for row access
control and column access control.
The function must be defined with SECURED when it is referenced in a row permission or a column mask.
Notes for CREATE FUNCTION (external scalar)
- Considerations for all types of user-defined functions:
- For considerations that apply to all types of user-defined functions, see CREATE FUNCTION statement (overview).
- Character string representation considerations:
- The PARAMETER VARCHAR clause is specific to LANGUAGE C functions because of the native use of NUL-terminated strings in C. VARCHAR structure representation is useful when character string data is known to contain embedded NUL-terminators. It is also useful when it cannot be guaranteed that character string data does not contain embedded NUL-terminators.
PARAMETER VARCHAR does not apply to fixed length character strings, VARCHAR FOR BIT DATA, CLOB, DBCLOB, or implicitly generated parameters. The clause does not apply to VARCHAR FOR BIT DATA because BIT DATA can contain X'00' characters, and its value representation starts with length information. It does not apply to LOB data because a LOB value representation starts with length information.
PARAMETER VARCHAR does not apply to optional parameters that are implicitly provided to an external function. For example, a CREATE FUNCTION statement for LANGUAGE C must also specify PARAMETER STYLE SQL, which returns an SQLSTATE NULL-terminated character string; that SQLSTATE will not be represented in VARCHAR structured form. Likewise, none of the parameters that represent the qualified name of the function, the specific name of the function, or the SQL diagnostic string that is returned to the database manager will be represented in VARCHAR structured form.
- Running external functions in WLM environments:
- You can use the WLM ENVIRONMENT clause to identify the address space in which a function or is to run. Using different WLM environments lets you isolate one group of programs from another. For example, you might choose to isolate programs based on security requirements and place all payroll applications in one WLM environment because those applications deal with data, such as employee salaries.
To prevent a user from defining functions in sensitive WLM environments, Db2 invokes the external security manager to determine whether the user has authorization to issue CREATE FUNCTION statements that refer to the specified WLM environment. The following example shows the RACF command that authorizes Db2 user DB2USER1 to register a function on Db2 subsystem DB2A that runs in the WLM environment named PAYROLL.
PERMIT DB2A.WLMENV.PAYROLL CLASS(DSNR) ID(DB2USER1) ACCESS(READ)
For more information, see Managing authorizations for creation of stored procedures in WLM environments.
- Considerations for accessing message tokens and DBINFO:
- Db2 returns system-generated parameters from a routine, such as message tokens and DBINFO. The message tokens and DBINFO are character string data. The CCSID for system-generated string parameters is determined from the CCSID that is in effect for string parameters that are defined for the routine. If the parameter list for the routine does not include any character or graphic string parameters, the CCSID for system-generated string parameters is determined from the PARAMETER CCSID option that is in effect for the routine. For example, with a Unicode database, you can specify PARAMETER CCSID EBCDIC to have the system-generated string parameters returned to the invoking application in EBCDIC.
- Alternative syntax and synonyms:
- To provide compatibility with previously releases of Db2 or other products in the Db2 family, Db2 supports the following alternative
syntax:
- VARIANT as a synonym for NOT DETERMINISTIC
- NOT VARIANT as a synonym for DETERMINISTIC
- NOT NULL CALL as a synonym for RETURNS NULL ON NULL INPUT
- NULL CALL as a synonym for CALLED ON NULL INPUT
- PARAMETER STYLE DB2SQL as a synonym for PARAMETER STYLE SQL
- TIMEZONE can be specified as an alternative to TIME ZONE.
Examples for CREATE FUNCTION (external scalar)
- Example 1
- Assume that you want to write an external function program in C that implements the following
logic:
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 or allow it to be the default. Write the statement needed to register the function, using the specific name MINENULL1.output = 2 * input - 4
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;
- Example 2
- Assume that user Smith wants to register an external function named CENTER in schema SMITH. The
function program will be written in C and will be reentrant. Write the statement that Smith needs to
register the function, letting Db2 generate
a specific name for the function.
CREATE FUNCTION CENTER (INTEGER, FLOAT) RETURNS FLOAT EXTERNAL NAME 'MIDDLE' LANGUAGE C DETERMINISTIC NO SQL FENCED PARAMETER STYLE SQL NO EXTERNAL ACTION STAY RESIDENT YES;
- Example 3
- Assume that user McBride (who has administrative authority) wants to register 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 FLOAT data type. Write the statement McBride
needs to register the function and ensure that when the function is invoked, it returns a value with
a data type of DECIMAL(8,4).
CREATE FUNCTION SMITH.CENTER (FLOAT, FLOAT, FLOAT) RETURNS DECIMAL(8,4) CAST FROM FLOAT 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 registers 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 (CLOB(100K)) RETURNS INTEGER FENCED LANGUAGE JAVA PARAMETER STYLE JAVA EXTERNAL NAME 'JAVAUDFS.FINDVWL' NO EXTERNAL ACTION CALLED ON NULL INPUT DETERMINISTIC NO SQL;