function_name ::= name of the scalar UDF. UDF names must conform to the rules for identifiers and must be unique within the database.
parameter_name ::= a parameter in the scalar UDF. A maximum of 300 parameters is allowed. The value must be supplied when the function is invoked.
scalar_parameter_data_type ::= the data type for the specified parameter name.
scalar_return_data_type ::= the return value of a scalar UDF. Only scalar types are supported.
value ::= a value to assign to scalar_return_data_type, either with the DEFAULT keyword or with the equals sign.
body_of_function ::= the statements that compose the scalar function.
scalar_expression ::= specifies the scalar value that the scalar function returns.
Remarks
You must have the CREATE FUNCTION privilege when you create a function in a secured database.
Each fully qualified UDF name (database-name.function-name) must be unique within a database. The UDF name cannot be the same as any of the following in the same database:
•a built-in function name
•any other UDF name
•a stored procedure name
Restrictions
You cannot use the CREATE DATABASE or the DROP DATABASE statement in a user-defined function. The table actions CREATE, ALTER, UPDATE, DELETE, and INSERT are not permitted within a user-defined function.
Only scalar input parameters are supported. No OUTPUT and INOUT parameters are allowed. By default, all parameters are input. You need not specify the IN keyword.
Limits
Observe the following limitations when you create user-defined functions.
Supported Scalar Input Parameters and Returned Data Types
Zen supports the data types for input scalar parameters and returned values shown in the following table.
Table 20 Supported Input Parameters and Returned Data Types
AUTOTIMESTAMP
BIGDENTITY
BIGINT
BINARY
BIT
BLOB
CHAR
CHARACTER
CLOB
CURRENCY
DATE
DATETIME
DEC
DECIMAL
DOUBLE
FLOAT
IDENTITY
INT
INTEGER
LONG
LONGVARBINARY
LONGVARCHAR
NCHAR
NLONGVARCHAR
NUMERIC
NVARCHAR
REAL
SMALLIDENTITY
SMALLINT
TIME
TIMESTAMP
TIMESTAMP2
TINYINT
UBIGINT
UINT
UINTEGER
UNIQUEIDENTIFIER
USMALLINT
UTINYINT
VARBINARY
VARCHAR
Examples
This topic provides a number of examples of CREATE FUNCTION.
The following example creates a function that calculates the area of a rectangular box whose details are stored in the Box table:
CREATE FUNCTION CalculateBoxArea(:boxName char(20))
RETURNS REAL
AS
BEGIN
DECLARE :len REAL;
DECLARE :breadth REAL;
SELECT len, breadth INTO :len, :breadth FROM box WHERE name = :boxName;
RETURN(:len * :breadth);
END;
============
The following example creates a function that compares two integers and returns the smaller of the two:
CREATE FUNCTION GetSmallest(:A integer, :B Integer)
RETURNS Integer
AS
BEGIN
DECLARE :smallest INTEGER
IF (:A < :B ) THEN
SET :smallest = :A;
ELSE
SET :smallest = :B;
END IF;
RETURN :smallest;
END;
============
The following example creates a function that calculates simple interest using the formula SI = PTR/100, where P is the Principle, T is the period, and R is the rate of interest.
CREATE FUNCTION CalculateInterest(IN :principle float, IN :period real, IN :rate double)
RETURNS DOUBLE
AS
BEGIN
DECLARE :interest DOUBLE;
SET :interest = ((:principle * :period * :rate) / 100);
RETURN (:interest);
END;
Invoking a Scalar User-Defined Function
You can invoke a user-defined function wherever scalar expressions are supported, by specifying the function name followed by a comma-separated list of arguments. The list of arguments is enclosed in parentheses.
A UDF can be invoked with or without a database qualifier prefix. When a database qualifier is not prefixed, the UDF is executed from the current database context. If a database qualifier is prefixed, the UDF is executed in the context of the specified database. (In the examples below, some use a database qualifier prefix and some do not.)
Limits
Parameter names cannot be specified in the arguments, when invoking a function.
The argument values for all parameters (also known as actual parameters) must be in the same sequence in which the parameters are defined in the CREATE FUNCTION statement (also known as formal parameters).