The CREATE FUNCTION statement defines a user-defined function at the current server. The following types of functions can be defined:
The function is written in a programming language such as C or Java™ and returns a scalar value. The external program is referenced by a function defined at the current server along with various attributes of the function. See CREATE FUNCTION (External Scalar).
The function is written in a programming language such as C or Java and returns a set of rows. The external program is referenced by a function defined at the current server along with various attributes of the function. See CREATE FUNCTION (External Table).
The function is implemented by invoking another function (built-in, external, sourced, or SQL) that already exists at the current server. A sourced function can return a scalar result, or the result of an aggregate function. See CREATE FUNCTION (Sourced). The function inherits attributes of the underlying source function.
The function is written exclusively in SQL and returns a scalar value. The function body is defined at the current server along with various attributes of the function. See CREATE FUNCTION (SQL Scalar).
The function is written exclusively in SQL and returns a set of rows. The function body is defined at the current server along with various attributes of the function. See CREATE FUNCTION (SQL Table).
Choosing the schema and function name: If a qualified function name is specified, the schema-name cannot be QSYS2, QSYS, QTEMP, or SYSIBM. If function-name is not qualified, it is implicitly qualified with the default schema name.
The unqualified function name must not be one of the following names reserved for system use even if they are specified as delimited identifiers:
= | < | > | >= |
<= | <> | ¬= | ¬< |
¬< | != | !< | !> |
ALL | DISTINCT | NODENAME | SOME |
AND | EXCEPT | NODENUMBER | STRIP |
ANY | EXISTS | NOT | SUBSTRING |
BETWEEN | EXTRACT | NULL | TABLE |
BOOLEAN | FALSE | ONLY | THEN |
CASE | FOR | OR | TRIM |
CAST | FROM | OVERLAPS | TRUE |
CHECK | HASHED_VALUE | PARTITION | TYPE |
DATAPARTITIONNAME | IN | POSITION | UNIQUE |
DATAPARTITIONNUM | IS | RRN | UNKNOWN |
DBPARTITIONNAME | LIKE | SELECT | WHEN |
DBPARTITIONNUM | MATCH | SIMILAR |
Defining the parameters: The input parameters for the function are specified as a list within parenthesis.
The maximum number of parameters allowed in CREATE FUNCTION is 90.
A function can have no input parameters. In this case, an empty set of parenthesis must be specified, for example:
CREATE FUNCTION WOOFER()
The data type of the result of the function is specified in the RETURNS clause for the function.
For portability of functions across platforms that are not DB2 UDB for iSeries, do not use the following data types, which might have different representations on different platforms:
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.
AS LOCATOR cannot be specified for SQL functions.
Determining the uniqueness of functions in a schema: The same name can be used for more than one function in a schema if the function signature of each function is unique. The function signature is the qualified function name combined with the number and data types of the input parameters. The combination of name, schema name, the number of parameters, and the data type each parameter (without regard for other attributes such as length, precision, scale, or CCSID) must not identify a user-defined function that exists at the current server. The return type has no impact on the determining uniqueness of a function. Two different schemas can each contain a function with the same name that have the same data types for all of their corresponding data types. However, a schema must not contain two functions with the same name that have the same data types for all of their corresponding data types.
When determining whether corresponding data types match, the database manager does not consider any length, precision, or scale attributes in the comparison. The database manager considers the synonyms of data types a match. For example, REAL and FLOAT, and DOUBLE and FLOAT are considered a match. Therefore, CHAR(8) and CHAR(35) are considered to be the same, as are DECIMAL(11,2), and DECIMAL(4,3). Furthermore, the character and graphic types are considered to be the same. For example, the following are considered to be the same type: CHAR and GRAPHIC, VARCHAR and VARGRAPHIC, and CLOB and DBCLOB. CHAR(13) and GRAPHIC(8) are considered to be the same type. An error is returned if the signature of the function being created is a duplicate of a signature for an existing user-defined function with the same name and schema.
Assume that the following statements are executed to create four functions in the same schema. The second and fourth statements fail because they create functions that are duplicates of the functions that the first and third statements created.
CREATE FUNCTION PART (INT, CHAR(15) ... CREATE FUNCTION PART (INTEGER, CHAR(40) ... CREATE FUNCTION ANGLE (DECIMAL(12,2)) ... CREATE FUNCTION ANGLE (DEC(10,7)) ...
Specifying a specific name for a function: When defining multiple functions with the same name and schema (with different parameter lists), it is recommended that a specific name also be specified. The specific name can be used to uniquely identify the function such as when sourcing on this function, dropping the function, or commenting on the function. However, the function cannot be invoked by its specific name.
The specific name is implicitly or explicitly qualified with a schema name. If a schema name is not specified on CREATE FUNCTION, it is the same as the explicit or implicit schema name of the function name (function-name). If a schema name is specified, it must be the same as the explicit or implicit schema name of the function name. The name, including the schema name must not identify the specific name of another function or procedure that exists at the current server.
If the SPECIFIC clause is not specified, a specific name is generated.
Extending or overriding a built-in function: Giving a user-defined function the same name as a built-in function is not a recommended practice unless the functionality of the built-in function needs to be extended or overridden.
Create the new user-defined function with the same name as the built-in function, and a unique function signature. For example, a user-defined function similar to the built-in function ROUND that accepts the distinct type MONEY as input rather than the built-in numeric types might be necessary. In this case, the signature for the new user-defined function named ROUND is different from all the function signatures supported by the built-in ROUND function.
Create the new user-defined function with the same name and signature as an existing built-in function. The new function has the same name and data type as the corresponding parameters of the built-in function but implements different logic. For example, a user-defined function similar to the built-in function ROUND that uses different rules for rounding than the built-in ROUND function might be necessary. In this case, the signature for the new user-defined function named ROUND will be the same as a signature that is supported by the built-in ROUND function.
Once a built-in function has been overridden, an application that uses the unqualified function name and was previously successful using the built-in function of that name might fail, or perhaps even worse, appear to run successfully but provide a different result if the user-defined function is chosen by the database manager rather than the built-in function.
Special registers in functions: The settings of the special registers of the invoker are inherited by the function on invocation and restored upon return to the invoker.