CREATE FUNCTION (SQL Scalar)

This CREATE FUNCTION (SQL Scalar) statement creates an SQL function at the current server. The function returns a single result.

Invocation

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.

Authorization

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

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

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

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

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

Syntax

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram>>-CREATE FUNCTION--function-name------------------------------->
 
>--(--+---------------------------+--)--RETURNS--data-type2----->
      | .-,---------------------. |
      | V                       | |
      '---parameter-declaration-+-'
 
>--LANGUAGE SQL--option-list--+----------------------+--SQL-routine-body-><
                              '-SET OPTION-statement-'
 
parameter-declaration:
 
|--parameter-name--data-type1-----------------------------------|
 
data-type:
 
|--+-built-in-type------+---------------------------------------|
   '-distinct-type-name-'
 
Read syntax diagramSkip visual syntax diagrambuilt-in-type:
 
|--+-+---SMALLINT---+--------------------------------------------------------------------------+--|
   | +-+-INTEGER-+--+                                                                          |
   | | '-INT-----'  |                                                                          |
   | '---BIGINT-----'                                                                          |
   |                  .-(5,0)------------------------.                                         |
   +-+-+-DECIMAL-+-+--+------------------------------+-----------------------------------------+
   | | '-DEC-----' |  |             .-,0--------.    |                                         |
   | '-NUMERIC-----'  '-(--integer--+-----------+--)-'                                         |
   |                                '-, integer-'                                              |
   |          .-(--53--)------.                                                                |
   +-+-FLOAT--+---------------+-+--------------------------------------------------------------+
   | |        '-(--integer--)-' |                                                              |
   | +-REAL---------------------+                                                              |
   | |         .-PRECISION-.    |                                                              |
   | '-DOUBLE--+-----------+----'                                                              |
   |                    .-(--1--)-------.                                                      |
   +-+-+-+-CHARACTER-+--+---------------+----------+--+----------------+---------------------+-+
   | | | '-CHAR------'  '-(--integer--)-'          |  +-FOR BIT DATA---+                     | |
   | | '-+-+-CHARACTER-+--VARYING-+--(--integer--)-'  +-FOR SBCS DATA--+                     | |
   | |   | '-CHAR------'          |                   +-FOR MIXED DATA-+                     | |
   | |   '-VARCHAR----------------'                   '-ccsid-clause---'                     | |
   | |                                          .-(--1M--)-------------.                     | |
   | '-----+-+-CHARACTER-+--LARGE OBJECT-+------+----------------------+--+----------------+-' |
   |       | '-CHAR------'               |      '-(--integer--+---+--)-'  +-FOR SBCS DATA--+   |
   |       '-CLOB------------------------'                    +-K-+       +-FOR MIXED DATA-+   |
   |                                                          +-M-+       '-ccsid-clause---'   |
   |                                                          '-G-'                            |
   |                .-(--1--)-------.                                                          |
   +-+---GRAPHIC----+---------------+-------+--+--------------+--------------------------------+
   | |              '-(--integer--)-'       |  '-ccsid-clause-'                                |
   | +-+-GRAPHIC VARYING-+--(--integer--)---+                                                  |
   | | '-VARGRAPHIC------'                  |                                                  |
   | |             .-(--1M--)-------------. |                                                  |
   | '---DBCLOB----+----------------------+-'                                                  |
   |               '-(--integer--+---+--)-'                                                    |
   |                             +-K-+                                                         |
   |                             +-M-+                                                         |
   |                             '-G-'                                                         |
   |             .-(--1--)-------.                                                             |
   +-+-+-BINARY--+---------------+---------+-----------------+---------------------------------+
   | | |         '-(--integer--)-'         |                 |                                 |
   | | '-+-BINARY VARYING-+--(--integer--)-'                 |                                 |
   | |   '-VARBINARY------'                                  |                                 |
   | |                              .-(--1M--)-------------. |                                 |
   | '---+-BLOB----------------+----+----------------------+-'                                 |
   |     '-BINARY LARGE OBJECT-'    '-(--integer--+---+--)-'                                   |
   |                                              +-K-+                                        |
   |                                              +-M-+                                        |
   |                                              '-G-'                                        |
   +-+-DATE-------------------+----------------------------------------------------------------+
   | |       .-(--0--)-.      |                                                                |
   | +-TIME--+---------+------+                                                                |
   | |            .-(--6--)-. |                                                                |
   | '-TIMESTAMP--+---------+-'                                                                |
   |             .-(--200--)-----.                                                             |
   +---DATALINK--+---------------+--+--------------+-------------------------------------------+
   |             '-(--integer--)-'  '-ccsid-clause-'                                           |
   '---ROWID-----------------------------------------------------------------------------------'
 
ccsid-clause:
 
                   .-NOT NORMALIZED-.
|--CCSID--integer--+----------------+---------------------------|
                   '-NORMALIZED-----'
 
Read syntax diagramSkip visual syntax diagramoption-list:
 
                               (1)   .-NOT DETERMINISTIC-.
|--+-------------------------+-------+-------------------+------>
   '-SPECIFIC--specific-name-'       '-DETERMINISTIC-----'
 
   .-EXTERNAL ACTION----.  .-READS SQL DATA----.
>--+--------------------+--+-------------------+---------------->
   '-NO EXTERNAL ACTION-'  +-CONTAINS SQL------+
                           '-MODIFIES SQL DATA-'
 
   .-STATIC DISPATCH-.  .-CALLED ON NULL INPUT-------.
>--+-----------------+--+----------------------------+---------->
                        '-RETURNS NULL ON NULL INPUT-'
 
   .-FENCED-----.
>--+------------+--+-------------------+------------------------|
   '-NOT FENCED-'  +-ALLOW PARALLEL----+
                   '-DISALLOW PARALLEL-'
 
Notes:
  1. The optional clauses can be specified in a different order.
Read syntax diagramSkip visual syntax diagramSQL-routine-body:
 
|----SQL-control-statement--------------------------------------|
 

Description

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

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

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

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

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

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

The maximum number of parameters allowed is 90.

parameter-name
Names the parameter. The name is used to refer to the parameter within the body of the function. 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 data type.
built-in-type
Specifies a built-in data type. For a more complete description of each built-in data type, see CREATE TABLE.
distinct-type-name
Specifies a distinct type. The length, precision, or scale attributes for the parameter are those of the source type of the distinct type (those specified on CREATE DISTINCT TYPE). For more information on creating a distinct type, see CREATE DISTINCT TYPE.

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

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

RETURNS
Specifies the output of the function.
data-type2
Specifies the data type and attributes of the output.

You can specify any built-in data type (except LONG VARCHAR, or LONG VARGRAPHIC) or a distinct type.

If a CCSID is specified and the CCSID of the return data is encoded in a different CCSID, the data is converted to the specified CCSID.

If a CCSID is not specified the return data is converted to the CCSID of the job (or associated graphic CCSID of the job for graphic string return values), if the CCSID of the return data is encoded in a different CCSID. To avoid any potential loss of characters during the conversion, consider explicitly specifying a CCSID that can represent any characters that will be returned from the function. This is especially important if the data type is graphic string data. In this case, consider using CCSID 1200 or 13488 (UTF-16 or UCS-2 graphic string data).

LANGUAGE SQL
Specifies that this is an SQL function.
SPECIFIC specific-name
Provides 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 or procedure that exists at the current server. If unqualified, the implicit qualifier is the same as the qualifier of the function name. If qualified, the qualifier must be the same as the qualifier of the function name.

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.

DETERMINISTIC or NOT DETERMINISTIC
Specifies whether the function is deterministic.
NOT DETERMINISTIC
Specifies that the function will not always return the same result from successive function invocations with identical input arguments. NOT DETERMINISTIC should be specified if the function contains a reference to a special register, a non-deterministic function, or a sequence.
DETERMINISTIC
Specifies that the function will always return the same result from successive invocations with identical input arguments.
EXTERNAL ACTION or NO EXTERNAL ACTION
Specifies whether the function contains an external action.
EXTERNAL ACTION
The function performs some external action (outside the scope of the function program). Thus, the function must be invoked with each successive function invocation. EXTERNAL ACTION should be specified if the function contains a reference to another function that has an external action.
NO EXTERNAL ACTION
The function does not perform an external action. It need not be called with each successive function invocation.
CONTAINS SQL, READS SQL DATA, or MODIFIES SQL DATA
Specifies whether the function can execute any SQL statements and, if so, what type. The database manager verifies that the SQL issued by the function is consistent with this specification. See Appendix B. Characteristics of SQL statements for a detailed list of the SQL statements that can be executed under each data access indication.
CONTAINS SQL
The function does not execute SQL statements that read or modify data.
READS SQL DATA
The function does not execute SQL statements that modify data.
MODIFIES SQL DATA
The function can execute any SQL statement except those statements that are not supported in any function.
STATIC DISPATCH
Specifies that the function is dispatched statically. All functions are statically dispatched.
RETURNS NULL ON NULL INPUT or CALLED ON NULL INPUT
Specifies whether the function is called if any of the input arguments is null at execution time.
RETURNS NULL ON INPUT
Specifies that the function is not invoked if any of the input arguments is null. The result is the null value.
CALLED ON NULL INPUT
Specifies that the function is to be invoked, if any, or all, argument values are null, making the function responsible for testing for null argument values. The function can return a null or nonnull value.
FENCED or NOT FENCED
Specifies whether the SQL function runs in an environment that is isolated from the database manager environment.
FENCED
The function will run in a separate thread.

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

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

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

NOT FENCED functions usually perform better than FENCED functions.

PARALLEL
Specifies whether the function can be run in parallel.
ALLOW PARALLEL
Specifies that the function can be run in parallel.
DISALLOW PARALLEL
Specifies that the function cannot be run in parallel.
The default is DISALLOW PARALLEL, if you specify one or more of the following clauses: Otherwise, ALLOW PARALLEL is the default.
SET OPTION-statement
Specifies the options that will be used to create the function. For example, to create a debuggable function, the following statement could be included:
SET OPTION DBGVIEW = *SOURCE 
For more information, see SET OPTION.

The options CLOSQLCSR, CNULRQD, COMPILEOPT, NAMING, and SQLCA are not allowed in the CREATE FUNCTION statement.

SQL-routine-body
Specifies a single SQL statement, including a compound statement. See SQL control statements for more information about defining SQL functions.

A call to a procedure that issues a CONNECT, SET CONNECTION, RELEASE, DISCONNECT, COMMIT, ROLLBACK and SET TRANSACTION statement is not allowed in a function.

If the SQL-routine-body is a compound statement, it must contain at least one RETURN statement and a RETURN statement must be executed when the function is called.

Notes

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

Function ownership: If SQL names were specified:

If system names were specified, the owner of the function is the user profile or group user profile of the job executing the statement.

Function authority: If SQL names are used, functions are created with the system authority of *EXCLUDE on *PUBLIC. If system names are used, functions are created with the authority to *PUBLIC as determined by the create authority (CRTAUT) parameter of the schema.

If the owner of the function is a member of a group profile (GRPPRF keyword) and group authority is specified (GRPAUT keyword), that group profile will also have authority to the function.

Creating the function: When an SQL function is created, the database manager creates a temporary source file that will contain C source code with embedded SQL statements. A *SRVPGM object is then created using the CRTSRVPGM command. The SQL options used to create the service program are the options that are in effect at the time the CREATE FUNCTION statement is executed. The service program is created with ACTGRP(*CALLER).

The specific name is used to determine the name of the source file member and *SRVPGM object. If the specific name is a valid system name, it will used as the name of member and program. If the member already exists, it will be overlaid. If a program already exists in the specified library, a unique name is generated using the rules for generating system table names. If the specific name is not a valid system name, a unique name is generated using the rules for generating system table names.

The function's attributes are saved in the associated service program object. If the *SRVPGM object is saved and then restored to this or another system, the catalogs are automatically updated with those attributes.

During restore of the function:

Identifier resolution: If the tables specified in a routine body exist, all references in the routine body of an SQL routine are resolved to identify a particular column, SQL parameter, or SQL variable at the time the SQL routine is created. If the tables do not exist, all names that exist as SQL variables or parameters are resolved to identify the variable or parameter when the function is created. The remaining names are assumed to be columns bound to the tables when the function is invoked.

If duplicate names are used for columns and SQL variables and parameters, qualify the duplicate names by using the table designator for columns, the function name for parameters, and the label name for SQL variables.

Invoking the function: When an SQL function is invoked, it runs in the activation group of the calling program.

If a function is specified in the select-list of a select-statement and if the function specifies EXTERNAL ACTION or MODIFIES SQL DATA, the function will only be invoked for each row returned. Otherwise, the UDF may be invoked for rows that are not selected.

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

Example

Define a scalar function that returns the tangent of a value using the existing SIN and COS built-in functions.

         CREATE FUNCTION TAN
              (X DOUBLE)
           RETURNS DOUBLE
           LANGUAGE SQL
           CONTAINS SQL
           NO EXTERNAL ACTION
           DETERMINISTIC
           RETURN SIN(X)/COS(X)

Notice that a parameter name (X) is specified for the input parameter to function TAN. The parameter name is used within the body of the function to refer to the input parameter. The invocations of the SIN and COS functions, within the body of the TAN user-defined function, pass the parameter X as input.



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