ALTER FUNCTION
Description
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. By default, system administrators have the permission. 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, no role is allowed to modify the owner of a function with the definer permission.
- When separation of duties is disabled, only the initial user and system administrator can change the owner of a function with the definer permission. However, the function owner cannot be changed to an O&M administrator.
- Only the initial user can change the owner of a function to the initial user.
Syntax
- Modify the additional parameters of the user-defined 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 user-defined function.
ALTER FUNCTION function_name ( [ { [ argname ] [ argmode ] argtype} [, ...] ] ) RENAME TO new_name;
- Change the owner of the user-defined function.
ALTER FUNCTION function_name ( [ { [ argname ] [ argmode ] argtype} [, ...] ] ) OWNER TO new_owner;
- Modify the schema of the user-defined function.
ALTER FUNCTION function_name ( [ { [ argname ] [ argmode ] argtype} [, ...] ] ) SET SCHEMA new_schema;
- Recompile the function.
ALTER FUNCTION function_name COMPILE;
Parameters
- 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: declares input parameters.
- OUT: declares output parameters.
- INOUT: declares input and output parameters.
- VARIADIC: declares parameters of the array type.
- argname
Parameter name.
Value range: a string. It must comply with the naming convention.
- argtype
Specifies the data type of a function parameter.
Value range: a valid type. For details, see Data Types.
- 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 this parameter is specified, the function is not executed when there is NULL parameter; 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 disables the setting.
Value range: a string
- DEFAULT
- OFF
- RESET
- User-specified value: The value must meet the restriction of the modified parameter.
- FROM CURRENT
Uses the value of configuration_parameter of the current session.
- value
- 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
- The following is an example of modifying a function:
-- 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; BEGIN proc_var := a; return 1; END; / -- Change the name of the function test_func(a int) to test_func_tk(a int). gaussdb=# ALTER FUNCTION test_func(a int) RENAME TO test_func_tk; -- Create a user jim. gaussdb=# CREATE USER jim PASSWORD '********'; -- Change the owner of the function to jim. gaussdb=# ALTER FUNCTION test_func_tk(a int) OWNER TO jim; -- Create a schema named test. gaussdb=# CREATE SCHEMA test; -- Change the function schema to test. gaussdb=# ALTER FUNCTION test_func_tk(a int) SET SCHEMA test;
- The following is an example of recompiling a function:
-- Recompile the function with a function name. gaussdb=# ALTER FUNCTION test.test_func_tk COMPILE; -- Recompile the stored procedure with a function of a signed type. gaussdb=# ALTER FUNCTION test.test_func_tk(a int) COMPILE; -- Delete the function. gaussdb=# DROP FUNCTION test.test_func_tk(a int); -- Delete user jim. gaussdb=# DROP USER jim; -- Delete a schema. gaussdb=# DROP SCHEMA test;
Helpful Links
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot