Updated on 2024-05-07 GMT+08:00

ALTER FUNCTION

Function

ALTER FUNCTION modifies the attributes of a user-defined function or recompiles a function.

Precautions

  • Only the function owner or a user granted with the ALTER permission can run the ALTER FUNCTION command. The system administrator has this permission by default. The following are permission constraints depending on the attributes to be modified:
    • If a function involves operations on temporary tables, ALTER FUNCTION cannot be used.
    • To modify the owner or schema of a function, you must be a function owner or system administrator and a member of the new owner role.
    • Only the system administrator and initial user can change the schema of a function to public.
  • The plpgsql_dependency parameter must be set for function recompilation.
  • Only the initial user or the user who creates the stored procedure can modify the stored procedure to a stored procedure that has the definer permission.
  • When separation-of-duties is enabled, to modify the owner of a function, users must have the user group permission, even a system administrator.
  • Only the initial user can change the owner of a function to the initial user.

Syntax

  • Modify the additional parameters of the customized function.
    ALTER FUNCTION function_name ( [ { [ argname ] [ argmode ] argtype} [, ...] ] )
        action [ ... ] [ RESTRICT ];

    The syntax of the action clause is as follows:

    {CALLED ON NULL INPUT | RETURNS NULL ON NULL INPUT | STRICT}
     | {IMMUTABLE | STABLE | VOLATILE}
     | {SHIPPABLE | NOT SHIPPABLE}
     | {NOT FENCED | FENCED}
     | [ NOT ] LEAKPROOF
     | { [ EXTERNAL ] SECURITY INVOKER | [ EXTERNAL ] SECURITY DEFINER }
     | AUTHID { DEFINER | CURRENT_USER }
     | COST execution_cost
     | ROWS result_rows
     | SET configuration_parameter { { TO | = } { value | DEFAULT }| FROM CURRENT}
     | RESET {configuration_parameter | ALL}
  • Rename the customized function.
    ALTER FUNCTION funname ( [ { [ argname ] [ argmode ] argtype} [, ...] ] )
        RENAME TO new_name;
  • Change the owner of the customized function.
    ALTER FUNCTION funname ( [ { [ argname ] [ argmode ] argtype} [, ...] ] )
        OWNER TO new_owner;
  • Modify the schema of the customized function.
    ALTER FUNCTION funname ( [ { [ argname ] [ argmode ] argtype} [, ...] ] )
        SET SCHEMA new_schema;
  • Recompile the function.
    ALTER FUNCTION function_name COMPILE;

Parameter Description

  • function_name

    Specifies the name of the function to be modified.

    Value range: an existing function name

  • argmode

    Specifies whether a parameter is an input or output parameter.

    Value range: IN, OUT, INOUT, and VARIADIC

  • argname

    Parameter name.

    Value range: a string. It must comply with the naming convention.

  • argtype

    Specifies the data type of a function parameter.

  • CALLED ON NULL INPUT

    Declares that some parameters of the function can be called in normal mode if the parameter values are null. Omitting this parameter is the same as specifying it.

  • RETURNS NULL ON NULL INPUT

    STRICT

    Specifies that the function always returns NULL whenever any of its parameters is NULL. If STRICT is specified, the function will not be executed when there are null parameters; instead a null result is assumed automatically.

    RETURNS NULL ON NULL INPUT and STRICT have the same functions.

  • IMMUTABLE

    Specifies that the function always returns the same result if the parameter values are the same.

  • STABLE

    Specifies that the function cannot modify the database, and that within a single table scan it will consistently return the same result for the same parameter value, but its result varies by SQL statements.

  • VOLATILE

    Specifies that the function value can change in a single table scan and no optimization is performed.

  • LEAKPROOF

    Specifies that the function has no side effect and the parameter contains only the return value. LEAKPROOF can be set only by the system administrator.

  • EXTERNAL

    (Optional) The purpose is to be compatible with SQL. This feature applies to all functions, not only external functions.

  • SECURITY INVOKER

    AUTHID CURRENT_USER

    Specifies that the function will be executed with the permissions of the user who calls it. Omitting this parameter is the same as specifying it.

    SECURITY INVOKER and AUTHID CURRENT_USER have the same functions.

  • SECURITY DEFINER

    AUTHID DEFINER

    Specifies that the function will be executed with the permissions of the user who created it.

    AUTHID DEFINER and SECURITY DEFINER have the same functions.

  • COST execution_cost

    Estimates the execution cost of a function.

    The unit of execution_cost is cpu_operator_cost.

    Value range: a positive integer

  • ROWS result_rows

    Estimates the number of rows returned by the function. This is only allowed when the function is declared to return a set.

    Value range: a positive number. The default value is 1000.

  • configuration_parameter
    • value

      Sets a specified database session parameter to a specified value. If the value is DEFAULT or RESET, the default setting is used in the new session. OFF closes the setting.

      Value range: a string

      • DEFAULT
      • OFF
      • RESET

      Specifies the default value.

    • from current

      Uses the value of configuration_parameter of the current session.

  • new_name

    Specifies the new name of a function. To change the schema of a function, you must have the CREATE permission on the new schema.

    Value range: a string. It must comply with the naming convention.

  • new_owner

    Specifies the new owner of a function. To change the owner of a function, the new owner must have the CREATE permission on the schema to which the function belongs. Note that only the initial user can set the function owner to another initial user.

    Value range: an existing user role

  • new_schema

    Specifies the new schema of a function.

    Value range: an existing schema

Examples

See Examples in section "CREATE FUNCTION."

Recompilation examples:
-- Enable the dependency function.
gaussdb=# set behavior_compat_options ='plpgsql_dependency';

-- Create a function.
gaussdb=# create or replace function test_func(a int) return int
is
    proc_var int;
gaussdb=# begin
    proc_var := a;
    return 1;
end;
/

-- Recompile the function with a function name.
gaussdb=# alter procedure test_func compile;

-- Recompile the stored procedure with a signed int type function.
gaussdb=# alter procedure test_func(int) compile;

Helpful Links

CREATE FUNCTION and DROP FUNCTION