SQL UDF
Purpose
As user-defined function written using regular SQL expressions, SQL UDF is used like a standard SQL function.
Syntax
where:
Syntax element … |
Specifies … |
udf_name |
the name of the SQL UDF. |
argument |
a valid SQL expression. See Usage Notes for rules that apply to SQL UDF arguments. |
ANSI Compliance
SQL UDFs are partially ANSI SQL:2011 compliant.
The requirement that parentheses appear when the argument list is empty is a Teradata extension to preserve compatibility with existing applications.
Restrictions
Self-referencing, forward-referencing, and circular-referencing SQL UDFs are not allowed.
Authorization
You must have EXECUTE FUNCTION privilege on the function or on the database containing the function.
You can specify an SQL SECURITY clause with the DEFINER option in the CREATE/REPLACE FUNCTION statement. This option is the default for an SQL UDF. SQL SECURITY DEFINER means that when an SQL UDF is invoked, Teradata Database verifies that the immediate owner and the creator of the UDF have the appropriate privileges on the underlying database objects referenced in the UDF. If the creator does not exist when the privileges are checked, an error is returned.
To invoke a UDF that takes a UDT argument or returns a UDT, you must have the UDTUSAGE privilege on the SYSUDTLIB database or on the specified UDT.
Usage Notes
An SQL UDF is a function that is defined by a user and is written using SQL expressions. When Teradata Database evaluates an SQL UDF expression, it invokes the function with the arguments passed to it. The following rules apply to the arguments in the function call:
To pass an argument that is not compatible with the corresponding parameter type, use CAST to explicitly convert the argument to the proper type. For information, see “CAST in Explicit Data Type Conversions” on page 590.
When an SQL UDF is invoked, Teradata Database searches for the UDF in the following locations:
For details regarding UDF search resolution, see SQL Data Definition Language.
The result type of an SQL UDF is based on the return type specified in the RETURNS clause of the CREATE FUNCTION statement.
The default title of an SQL UDF appears as:
UDF_name(argument_list)
Example
Consider the following function definition and query:
CREATE FUNCTION Test.MyUDF (a INT, b INT, c INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
SQL SECURITY DEFINER
COLLATION INVOKER
INLINE TYPE 1
RETURN a + b - c;
SELECT Test.MyUDF(t1.a1, t2.a2, t3.a3) FROM t1, t2, t3;
The user executing the SELECT statement must have the following privileges:
The privileges of the creator or owner are not checked since the UDF does not reference any database objects in its definition.
Example
In this example, the SQL UDF named MySQLUDF references an external UDF named MyExtUDF in the RETURN statement.
Consider the following function definition and query:
CREATE FUNCTION Test.MySQLUDF (a INT, b INT, c INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
SQL SECURITY DEFINER
COLLATION INVOKER
INLINE TYPE 1
RETURN a + b * MyExtUDF(a, b) - c;
SELECT Test.MySQLUDF(t1.a1, t2.a2, t3.a3) FROM t1, t2, t3;
The user executing the SELECT statement must have the following privileges:
Because the SQL UDF references MyExtUDF, the following privileges are also checked:
Example
In this example, invocations of the SQL UDF named MyUDF2 are passed as arguments to the SQL UDF named MyUDF1.
CREATE FUNCTION test.MyUDF1 (a INT, b INT, c INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
COLLATION INVOKER
INLINE TYPE 1
RETURN a * b * c;
CREATE FUNCTION test.MyUDF2 (d INT, e INT, f INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
COLLATION INVOKER
INLINE TYPE 1
RETURN d + e + f;
SELECT test.MyUDF1(test.MyUDF2(t1.a1, 1, 2),
test.MyUDF2(t1.b1, 2, 3), 5) FROM t1;
Example
In this example, the UDF invocation argument data type (BYTEINT) is not the same as that of the corresponding UDF parameter data type (INTEGER) since the size of the argument data type is less than the UDF parameter data type. However, because the two data types are compatible and a BYTEINT argument can fit inside an INTEGER parameter, this is allowed.
CREATE FUNCTION test.MyUDF (a INT, b INT, c INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
COLLATION INVOKER
INLINE TYPE 1
RETURN a * b * c;
CREATE TABLE t1 (a1 BYTEINT, b1 INT);
SELECT test.MyUDF(t1.a1, t1.b1, 2) FROM t1;
Example
In this example, the UDF invocation argument data type (INTEGER) is not the same as that of the corresponding UDF parameter data type (BYTEINT) since the size of the argument data type is greater than the UDF parameter data type. Although the two data types are compatible, an INTEGER argument cannot fit inside a BYTEINT parameter, so an error is returned.
CREATE FUNCTION test.MyUDF (a BYTEINT, b INT, c INT)
RETURNS INT
LANGUAGE SQL
CONTAINS SQL
DETERMINISTIC
COLLATION INVOKER
INLINE TYPE 1
RETURN a * b * c;
CREATE TABLE t1 (a1 INT, b1 INT);
SELECT test.MyUDF(t1.a1, t1.b1, 2) FROM t1;
The following error is returned:
Failure 5589: Function "test.MyUDF" does not exist.
To avoid the error, the caller must explicitly cast the value of t1.a1 to BYTEINT as follows:
SELECT test.MyUDF(CAST(t1.a1 AS BYTEINT), t1.b1, 2) FROM t1;
Related Topics
FOR more information on … |
SEE … |
|
|
EXECUTE FUNCTION and UDTUSAGE privileges |
SQL Data Control Language. |