CREATE FUNCTION Statement

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.

Quick Links:

Go to Parameters

Go to Examples

Go to Usage

Go to Standards

Go to Permissions

Syntax

Syntax 1

CREATE [ OR REPLACE ] [ TEMPORARY ] FUNCTIONowner.]function-name  ( [ parameter, … ] )
   [ SQL SECURITYINVOKER | DEFINER } ]
   RETURNS data-type ON EXCEPTION RESUME 
   | [ NOT ] DETERMINISTICcompound-statementAS tsql-compound-statementEXTERNAL NAME library-callEXTERNAL NAME java-call LANGUAGE JAVA }

Syntax 2

CREATE FUNCTIONowner.]function-name ( [ parameter, … ] )
   RETURNS data-type
   URL url-stringHEADER 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-typeDEFAULT 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] '

Parameters

(back to top)

Examples

(back to top)

Usage

(back to top)

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.

Side Effects
  • Automatic commit

Standards

(back to top)

  • SQL—ISO/ANSI SQL compliant.
  • SAP Sybase Database product—Not supported by Adaptive Server.

Permissions

(back to top)

For function to be owned by self – Requires the CREATE PROCEDURE system privilege.

For function to be owned by any user – Requires one of:
  • CREATE ANY PROCEDURE system privilege.
  • CREATE ANY OBJECT system privilege.
To create a function containing an external reference, regardless of whether or not they are the owner of the function, also requires the CREATE EXTERNAL REFERENCE system privilege.
Related reference
ALTER FUNCTION Statement
BEGIN … END Statement
CREATE PROCEDURE Statement
DROP Statement
RETURN Statement