Creates a user-defined function in the database. A function can be created for another user by specifying an owner name. Subject to permissions, a user-defined function can be used in exactly the same way as other non-aggregate functions.
CREATE [ OR REPLACE ] [ TEMPORARY ] FUNCTION [ owner.]function-name ( [ parameter, … ] ) [ SQL SECURITY { INVOKER | DEFINER } ] RETURNS data-type ON EXCEPTION RESUME | [ NOT ] DETERMINISTIC { compound-statement | AS tsql-compound-statement | EXTERNAL NAME library-call | EXTERNAL NAME java-call LANGUAGE JAVA }
CREATE FUNCTION [ owner.]function-name ( [ parameter, … ] ) RETURNS data-type URL url-string [ HEADER header-string ] [ SOAPHEADER soap-header-string ] [ TYPE { 'HTTP[:{ GET | POST } ] ' | 'SOAP[:{ RPC | DOC } ]' } ] [ NAMESPACE namespace-string ] [ CERTIFICATE certificate-string ] [ CLIENTPORT clientport-string ] [ PROXY proxy-string ] parameter - (back to Syntax 1) or (back to Syntax 2) IN parameter-name data-type [ DEFAULT expression ] tsql-compound-statement - (back to Syntax 1) sql-statement sql-statement … library-call - (back to Syntax 1) '[ operating-system:]function-name@library; …' operating-system - (back to library-call) UNIX java-call - (back to Syntax 1) '[ package-name.]class-name.method-name method-signature' method-signature - (back to java-call) ( [ field-descriptor, ….] ) return-descriptor field-descriptor and return-descriptor - (back to method-signature) Z | B | S | I | J | F | D | C | V | [ descriptor | L class-name; url-string - (back to Syntax 2) ' { HTTP | HTTPS | HTTPS_FIPS }://[user:password@]hostname[:port][/path] '
The CREATE clause creates a new function, while the OR REPLACE clause replaces an existing function with the same name. When a function is replaced, the definition of the function is changed but the existing permissions are preserved. You cannot use the OR REPLACE clause with temporary functions.
Temporary functions execute with the permissions of their creator (current user), and can only be owned by their creator. Therefore, do not specify owner when creating a temporary function. They can be created and dropped when connected to a read-only database.
When INVOKER is specified, more memory is used because annotation must be done for each user that calls the procedure. Also, name resolution is done as the invoker as well. Therefore, take care to qualify all object names (tables, procedures, and so on) with their appropriate owner.
The external-name clause is not supported for temporary functions.
Functions that have side effects, such as modifying the underlying data, should be declared as NOT DETERMINISTIC. For example, a function that generates primary key values and is used in an INSERT … SELECT statement should be declared NOT DETERMINISTIC:
CREATE FUNCTION keygen( increment INTEGER ) RETURNS INTEGER NOT DETERMINISTIC BEGIN DECLARE keyval INTEGER; UPDATE counter SET x = x + increment; SELECT counter.x INTO keyval FROM counter; RETURN keyval END INSERT INTO new_table SELECT keygen(1), ... FROM old_table
Functions may be declared as DETERMINISTIC if they always return the same value for given input parameters. All user-defined functions are treated as deterministic unless they are declared NOT DETERMINISTIC. Deterministic functions return a consistent result for the same parameters and are free of side effects. That is, the database server assumes that two successive calls to the same function with the same parameters will return the same result without unwanted side-effects on the semantics of the query.
For web service client functions, the return type of SOAP and HTTP functions must one of the character data types, such as VARCHAR. The value returned is the body of the HTTP response. No HTTP header information is included. If more information is required, such as status information, use a procedure instead of a function.
Parameter values are passed as part of the request. The syntax used depends on the type of request. For HTTP:GET, the parameters are passed as part of the URL; for HTTP:POST requests, the values are placed in the body of the request. Parameters to SOAP requests are always bundled in the request body.
Key | Abbreviation | Description |
---|---|---|
file | File name of certificate | |
certificate | cert | The certificate |
company | co | Company specified in the certificate |
unit | Company unit specified in the certificate | |
name | Common name specified in the certificate |
Certificates are required only for requests that are either directed to an HTTPS server or can be redirected from an insecure to a secure server.
CREATE FUNCTION fullname ( firstname CHAR(30), lastname CHAR(30) ) RETURNS CHAR(61) BEGIN DECLARE name CHAR(61); SET name = firstname || ' ' || lastname; RETURN (name); END
This example illustrates the use of the fullname function.
Return a full name from two supplied strings:
SELECT fullname ('joe','smith')
fullname('joe', 'smith') |
---|
joe smith |
List the names of all employees:
SELECT fullname (givenname, surname) FROM Employees
fullname (givenname, surname) |
---|
Fran Whitney |
Matthew Cobb |
Philip Chin |
Julie Jordan |
Robert Breault |
... |
CREATE FUNCTION DoubleIt ( @Input INT ) RETURNS INT AS DECLARE @Result INT SELECT @Result = @Input * 2 RETURN @Result
The statement SELECT DoubleIt( 5 ) returns a value of 10.
CREATE FUNCTION dba.encrypt( IN name char(254) ) RETURNS VARCHAR EXTERNAL NAME 'Scramble.encrypt (Ljava/lang/String;)Ljava/lang/String;' LANGUAGE JAVA
To modify a user-defined function, or to hide the contents of a function by scrambling its definition, use the ALTER FUNCTION statement.
When functions are executed, not all parameters need to be specified. If a default value is provided in the CREATE FUNCTION statement, missing parameters are assigned the default values. If an argument is not provided by the caller and no default is set, an error is given.
For function to be owned by self – Requires the CREATE PROCEDURE system privilege.