CREATE FUNCTION (inlined SQL scalar)

The CREATE FUNCTION (inlined SQL scalar) statement defines an SQL scalar function at the current server and specifies an SQL procedural language RETURN statement for the body of the function. The function returns a single value each time it is invoked.

Start of changeA package is not created for an inlined SQL scalar function. The function is not invoked as part of a query; instead, the expression in the RETURN statement of the function is copied (inlined) into the query itself. End of change

Invocation for CREATE FUNCTION (inlined SQL 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 (inlined SQL 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
  • Start of changeInstallation SYSOPR authority (when the current SQLID of the process is set to SYSINSTL)End of change

The authorization ID that matches the schema name implicitly has the CREATEIN privilege on the schema.

Start of changeIf 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.End of change

If a user-defined type is referenced (as the data type of a parameter), the privilege set must also include at least one of the following:

  • Ownership of the user-defined type
  • The USAGE privilege on the user-defined type
  • SYSADM authority
At least one of the following additional privileges is required if the SECURED option is specified:
  • SECADM authority
  • CREATE_SECURE_OBJECT privilege

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 (inlined SQL scalar)

Read syntax diagramSkip visual syntax diagram CREATE FUNCTION function-name ( ,parameter-declaration ) function-definitionWRAPPEDobfuscated-statement-text

parameter-declaration:

Read syntax diagramSkip visual syntax diagramparameter-name1 data-type
Notes:
  • 1 Note that the parameter-name is required for SQL functions.

data-type:

Read syntax diagramSkip visual syntax diagrambuilt-in-typedistinct-type-name

built-in-type:

Read syntax diagramSkip visual syntax diagramSMALLINTINTEGERINTBIGINTDECIMALDECNUMERIC(5,0)( integer, integer)FLOAT(53)( integer)REALDOUBLEPRECISIONDECFLOAT(34)(16)CHARACTERCHAR(1)( integer)CHARACTERCHARVARYINGVARCHAR( integer)CCSIDASCIIEBCDICUNICODEFORSBCSMIXEDBITDATACHARACTERCHARLARGE OBJECTCLOB(1M)( integerKMG)CCSIDASCIIEBCDICUNICODEFORSBCSMIXEDDATAGRAPHIC(1)( integer)VARGRAPHIC(integer)DBCLOB(1M)( integerKMG)CCSIDASCIIEBCDICUNICODEBINARY(1)( integer)BINARY VARYINGVARBINARY( integer)BINARY LARGE OBJECTBLOB(1M)( integerKMG)DATETIMETIMESTAMP(6)(integer)WITHOUT TIME ZONEWITH TIME ZONEROWIDXML

option-list:

Read syntax diagramSkip visual syntax diagramSPECIFICspecific-name1PARAMETER CCSIDASCIIEBCDICUNICODENOT DETERMINISTICDETERMINISTICEXTERNAL ACTIONNO EXTERNAL ACTIONREADS SQL DATACONTAINS SQLSTATIC DISPATCHCALLED ON NULL INPUTNOT SECUREDSECURED
Notes:
  • 1 This clause and the other clauses in the option-list can be specified in any order. However, the same clause cannot be specified more than one time.

function-defintion

Read syntax diagramSkip visual syntax diagram RETURNS data-type2 1 LANGUAGE SQL option-list SQL-routine-body
Notes:
  • 1 The RETURNS clause, the RETURN-statement, and the clauses in the option-list can be specified in any order. However, the same clause cannot be specified more than one time.

SQL-routine-body

Read syntax diagramSkip visual syntax diagramRETURN statement

Description for CREATE FUNCTION (inlined SQL 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 and Determining the uniqueness of functions in a schema in CREATE FUNCTION.
(parameter-declaration,…)

Specifies the number of input parameters of the function and the name and data type of each parameter. Each parameter-declaration specifies an input parameter for the function. A function can have zero or more input parameters. There must be one entry in the list for each parameter that the function expects to receive. All of the parameters for a function are input parameters and are nullable. If the function has more than 30 parameters, only the first 30 parameters are used to determine if the function is unique.

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 user-defined 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. The distinct type must not be based on a LOB data type.

If you specify the name of the distinct type without a schema name, Db2 resolves the distinct type 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.
RETURNS
Identifies the output of the function.
data-type2
Specifies the data type of the output. The output is nullable.

The same considerations that apply to the data type of input parameter, as described under "data-type" in data-type, apply to the data type of the output of the function.

LANGUAGE SQL
Specifies that the function is written exclusively in SQL.
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:
SQLxxxxxxxxxxxx
where '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
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 character and graphic 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.

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 and SQL data change statements that refer to this function. An example of a function that is not deterministic is one that generates random numbers.

NOT DETERMINISTIC must be specified explicitly or implicitly if the function program accesses a special register or invokes another function that is not deterministic. NOT DETERMINISTIC is the default.

DETERMINISTIC
The function always returns the same result function 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 and 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.

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.
EXTERNAL ACTION
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, then Db2:

  • Materializes the views and table expressions in SELECT and SQL data change 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 must be specified implicitly or explicitly specified if the SQL routine body invokes a function that is defined with EXTERNAL ACTION. EXTERNAL ACTION is the default.

NO EXTERNAL ACTION
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 SQL 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.

READS SQL DATA or CONTAINS 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.
READS SQL DATA
Specifies that the function can execute statements with a data access classification of READS SQL DATA, CONTAINS SQL, or NO SQL. The function cannot execute SQL statements that modify data.

READS SQL DATA is the default.

CONTAINS SQL
Specifies that the function can execute only SQL statements with a data access classification of CONTAINS SQL or NO SQL. The function cannot execute SQL statements that read or modify data.
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.
CALLED ON NULL INPUT
Specifies that the function is to be invoked if any, or if all, of the argument values are null. Specifying CALLED ON NULL INPUT means that the body of the function must be coded to test for null argument values.

CALLED ON NULL INPUT is the default.

NOT SECURED or SECURED
Specifies if the function is considered secure for row access control and column access control. The SECURED or NOT SECURED option applies to all future versions of the function.
NOT SECURED
Specifies that the function is not considered 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 secure when it is referenced in a row permission or a column mask.

SQL-routine-body
Start of changeSpecifies a single RETURN statement. For more information, see RETURN statement.

Start of changeIf the RETURN statement includes a scalar fullselect, Db2 attempts to define a compiled function. For more information, see CREATE FUNCTION (compiled SQL scalar). End of change

Start of change To determine what type of SQL scalar function is created, refer to the INLINE column of the SYSIBM.SYSROUTINES catalog table.End of change

End of change
Start of changeWRAPPED obfuscated-statement-textEnd of change
Start of changeSpecifies the encoded definition of the function. A CREATE FUNCTION statement can be encoded using the WRAP scalar function.

WRAPPED must not be specified on a static CREATE statement.

End of change

Notes for CREATE FUNCTION (inlined SQL scalar)

Considerations for all types of user-defined functions:
For considerations that apply to all types of user-defined functions, see CREATE FUNCTION.
Start of changeTypes of SQL scalar functions:End of change
Start of changeIf the syntax of the CREATE FUNCTION statement conforms to the syntax diagrams and descriptions for CREATE FUNCTION (inlined SQL scalar), Db2 defines an inlined function, and a package is not created. When an inlined SQL scalar function is invoked, the expression in the RETURN statement of the function is copied (inlined) into the query itself; the function is not invoked. The attributes of an inlined SQL scalar function are described in CREATE FUNCTION (inlined SQL scalar).

Otherwise, Db2 attempts to define a compiled function with an associated package. For example, if the RETURN statement contains a scalar fullselect, Db2 attempts to define a compiled function. The attributes of a compiled SQL scalar function are described in CREATE FUNCTION (compiled SQL scalar).

To determine what type of SQL scalar function is created, refer to the INLINE column of the SYSIBM.SYSROUTINES catalog table. In the INLINE column, a value of Y indicates that the function is an inlined function, and a value of N indicates that the function is a compiled function.

End of change
Start of changeConsiderations for functions defined with MODIFIES SQL DATA:End of change
Start of changeIf a function is specified in a subselect, and the function is defined as MODIFIES SQL DATA, the number of times the function is invoked is invoked will vary depending on the access plan used.End of change
Self-referencing function:
The body of an SQL function (that is, the expression or NULL in the RETURN statement in the body of the CREATE FUNCTION statement) cannot contain a recursive invocation of itself or to another function that invokes it, because such a function would not exist to be referenced.
Dependent objects:
An SQL routine is dependent on objects that are referenced in the routine body.
Start of changeObfuscated statements:End of change
Start of changeA CREATE FUNCTION statement can be executed in obfuscated form. In an obfuscated statement, only the function name, parameters, and the WRAPPED keyword are readable. The rest of the statement is encoded in such a way that it is not readable but can be decoded by a database server that supports obfuscated statements. The WRAP scalar function produces obfuscated statements. Any debug options that are specified when the function is created from an obfuscated statement are ignored.End of change
Resolution of object names:
Db2 resolves object names inside the body of the function according to the rules in Unqualified object name resolution and the type of the object. The name resolution occurs when the function is created.
Referencing date and time special registers:
If an SQL function contains multiple references to any of the date or time special registers, all references return the same value. In addition, this value is the same value that is returned by the retrieving value of the special register in the statement that invoked the function.
Self-referencing function:
The body of an SQL function (that is, the expression or NULL in the RETURN clause of the CREATE FUNCTION (inlined SQL scalar) statement) cannot contain a recursive invocation of itself or to another function that invokes it, because such a function would not exist to be referenced.
Dependent objects:
An SQL routine is dependent on objects that are referenced in the routine body.
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
  • NULL CALL as a synonym for CALLED ON NULL INPUT
  • TIMEZONE can be specified as an alternative to TIME ZONE.

For an inlined SQL scalar function, the RETURNS clause and the clauses in the option-list can be specified in any order.

Examples for CREATE FUNCTION (inlined SQL scalar)

Example 1: Define a scalar function that returns the tangent of a value using 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);