Creating a function v14

The CREATE FUNCTION command defines and names a standalone function to store in the database.

If a schema name is included, then the function is created in the specified schema. Otherwise it's created in the current schema. The name of the new function must not match any existing function with the same input argument types in the same schema. However, functions of different input argument types can share a name. Sharing a name is called overloading.

Note

Overloading functions is an EDB Postgres Advanced Server feature. Overloading stored, standalone functions isn't compatible with Oracle databases.

To update the definition of an existing function, use CREATE OR REPLACE FUNCTION. You can't change the name or argument types of a function this way. If you try to, you instead create a new, distinct function. Also, CREATE OR REPLACE FUNCTION doesn't let you change the return type of an existing function. To do that, you must drop and recreate the function. When using OUT parameters, you can't change the types of any OUT parameters except by dropping the function.

CREATE [ OR REPLACE ] FUNCTION <name> [ (<parameters>) ]
  RETURN <data_type>
   [
           IMMUTABLE
        | STABLE
        | VOLATILE
        | DETERMINISTIC
        | [ NOT ] LEAKPROOF
        | CALLED ON NULL INPUT
        | RETURNS NULL ON NULL INPUT
        | STRICT
        | [ EXTERNAL ] SECURITY INVOKER
        | [ EXTERNAL ] SECURITY DEFINER
        | AUTHID DEFINER
        | AUTHID CURRENT_USER
        | PARALLEL { UNSAFE | RESTRICTED | SAFE }
        | COST <execution_cost>
        | ROWS <result_rows>
        | SET <configuration_parameter>
          { TO <value> | = <value> | FROM CURRENT }
   ...]
{ IS | AS }
    [ PRAGMA AUTONOMOUS_TRANSACTION; ]
    [ <declarations> ]
  BEGIN
    <statements>
  END [ <name> ];

Where:

name is the identifier of the function.

parameters is a list of formal parameters.

data_type is the data type of the value returned by the function’s RETURN statement.

declarations are variable, cursor, type, or subprogram declarations. If you include subprogram declarations, you must declare them after all other variable, cursor, and type declarations.

statements are SPL program statements. The BEGIN - END block can contain an EXCEPTION section.

IMMUTABLE

STABLE

VOLATILE

These attributes inform the query optimizer about the behavior of the function. You can specify only one. VOLATILE is the default behavior.

  • IMMUTABLE indicates that the function can't modify the database and always reaches the same result when given the same argument values. It doesn't do database lookups or otherwise use information not directly present in its argument list. If you include this clause, any call of the function with all-constant arguments can be immediately replaced with the function value.

  • STABLE indicates that the function can't modify the database. It also indicates that, in a single table scan, it consistently returns the same result for the same argument values but that its result might change across SQL statements. Select this attribute for functions that depend on database lookups, parameter variables (such as the current time zone), and so on.

  • VOLATILE indicates that the function value can change even in a single table scan, so no optimizations can be made. Classify any function that has side effects as volatile, even if its result is predictable, to prevent calls from being optimized away.

DETERMINISTIC

DETERMINISTIC is a synonym for IMMUTABLE. A DETERMINISTIC function can't modify the database and always reaches the same result when given the same argument values. It doesn't do database lookups or otherwise use information not directly present in its argument list. If you include this clause, you can replace any call of the function with all-constant arguments with the function value.

[ NOT ] LEAKPROOF

A LEAKPROOF function has no side effects and reveals no information about the values used to call the function.

CALLED ON NULL INPUT

RETURNS NULL ON NULL INPUT

STRICT

  • CALLED ON NULL INPUT (the default) indicates for the procedure to be called normally when some of its arguments are NULL. It is the author's responsibility to check for NULL values if necessary and respond appropriately.

  • RETURNS NULL ON NULL INPUT or STRICT indicates that the procedure always returns NULL when any of its arguments are NULL. If you specify these clauses, the procedure isn't executed when there are NULL arguments. Instead, a NULL result is assumed automatically.

[ EXTERNAL ] SECURITY DEFINER

SECURITY DEFINER (the default) specifies for the function to execute with the privileges of the user that created it. The key word EXTERNAL is allowed for SQL conformance but is optional.

[ EXTERNAL ] SECURITY INVOKER

The SECURITY INVOKER clause indicates for the function to execute with the privileges of the user that calls it. The key word EXTERNAL is allowed for SQL conformance but is optional.

AUTHID DEFINER

AUTHID CURRENT_USER

  • The AUTHID DEFINER clause is a synonym for [EXTERNAL] SECURITY DEFINER. If the AUTHID clause is omitted or if AUTHID DEFINER is specified, the rights of the function owner determine access privileges to database objects.

  • The AUTHID CURRENT_USER clause is a synonym for [EXTERNAL] SECURITY INVOKER. If AUTHID CURRENT_USER is specified, the rights of the current user executing the function determine access privileges.

PARALLEL { UNSAFE | RESTRICTED | SAFE }

The PARALLEL clause enables the use of parallel sequential scans, that is, parallel mode. A parallel sequential scan uses multiple workers to scan a relation in parallel during a query in contrast to a serial sequential scan.

  • When this value is set to UNSAFE, you can't execute the function in parallel mode. The presence of such a function in a SQL statement forces a serial execution plan. This is the default setting.

  • When this value is set to RESTRICTED, you can execute the function in parallel mode, but the execution is restricted to the parallel group leader. If the qualification for any particular relation has anything that's parallel restricted, that relation isn't chosen for parallelism.

  • When this value is set to SAFE, you can execute the function in parallel mode with no restriction.

COST execution_cost

execution_cost is a positive number giving the estimated execution cost for the function, in units of cpu_operator_cost. If the function returns a set, this is the cost per returned row. Larger values cause the planner to try to avoid evaluating the function more often than necessary.

ROWS result_rows

result_rows is a positive number giving the estimated number of rows for the planner to expect the function to return. This is allowed only when the function is declared to return a set. The default assumption is 1000 rows.

SET configuration_parameter { TO value | = value | FROM CURRENT }

The SET clause causes the specified configuration parameter to be set to the specified value when the function is entered and then restored to its prior value when the function exits. SET FROM CURRENT saves the session's current value of the parameter as the value to apply when the function is entered.

If a SET clause is attached to a function, then the effects of a SET LOCAL command executed inside the function for the same variable are restricted to the function. The configuration parameter's prior value is restored at function exit. A SET command without LOCAL overrides the SET clause, much as it does for a previous SET LOCAL command. The effects of such a command persist after procedure exit, unless the current transaction is rolled back.

PRAGMA AUTONOMOUS_TRANSACTION

PRAGMA AUTONOMOUS_TRANSACTION is the directive that sets the function as an autonomous transaction.

Note

The STRICT, LEAKPROOF, PARALLEL, COST, ROWS and SET keywords provide extended functionality for EDB Postgres Advanced Server and aren't supported by Oracle.

Examples

This example shows a simple function that takes no parameters:

CREATE OR REPLACE FUNCTION simple_function
    RETURN VARCHAR2
IS
BEGIN
    RETURN 'That''s All Folks!';
END simple_function;

This function takes two input parameters:

CREATE OR REPLACE FUNCTION emp_comp (
    p_sal           NUMBER,
    p_comm          NUMBER
) RETURN NUMBER
IS
BEGIN
    RETURN (p_sal + NVL(p_comm, 0)) * 24;
END emp_comp;

This example uses the AUTHID CURRENT_USER clause and STRICT keyword in a function declaration:

CREATE OR REPLACE FUNCTION dept_salaries(dept_id int) RETURN NUMBER
  STRICT
  AUTHID CURRENT_USER
BEGIN
  RETURN QUERY (SELECT sum(salary) FROM emp WHERE deptno = id);
END;

Include the STRICT keyword to instruct the server to return NULL if any input parameter passed is NULL. If a NULL value is passed, the function doesn't execute.

The dept_salaries function executes with the privileges of the role that's calling the function. If the current user doesn't have the privileges to perform the SELECT statement querying the emp table (to display employee salaries), the function reports an error. To instruct the server to use the privileges associated with the role that defined the function, replace the AUTHID CURRENT_USER clause with the AUTHID DEFINER clause.