ALTER PROCEDURE

Modifies the properties for an existing stored procedure. If you need to make any changes not supported here, use DROP PROCEDURE instead and then recreate the stored procedure.

See also:

CREATE PROCEDURE , DROP PROCEDURE , SHOW PROCEDURES , DESCRIBE PROCEDURE

Syntax

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) RENAME TO <new_name>

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) SET LOG_LEVEL = '<log_level>'

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) SET TRACE_LEVEL = '<trace_level>'

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) SET COMMENT = '<string_literal>'

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) UNSET COMMENT

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) SET TAG <tag_name> = '<tag_value>' [ , <tag_name> = '<tag_value>' ... ]

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) UNSET TAG <tag_name> [ , <tag_name> ... ]

ALTER PROCEDURE [ IF EXISTS ] <name> ( [ <arg_data_type> , ... ] ) EXECUTE AS { CALLER | OWNER }
Copy

Parameters

name

Specifies the identifier for the stored procedure to alter. If the identifier contains spaces or special characters, the entire string must be enclosed in double quotes. Identifiers enclosed in double quotes are also case-sensitive.

arg_data_type [ , ... ]

Specifies the data type of the argument(s) for the stored procedure, if it has arguments. The argument types are required because stored procedures support name overloading (i.e. two stored procedures in the same schema can have the same name) and the argument types are used to identify the procedure you wish to alter.

RENAME TO new_name

Specifies the new identifier for the stored procedure; the combination of the identifier and existing argument data types must be unique for the schema.

For more details, see Identifier requirements.

You can move the object to a different database and/or schema while optionally renaming the object. To do so, specify a qualified new_name value that includes the new database and/or schema name in the form db_name.schema_name.object_name or schema_name.object_name, respectively.

Note

  • The destination database and/or schema must already exist. In addition, an object with the same name cannot already exist in the new location; otherwise, the statement returns an error.

  • Moving an object to a managed access schema is prohibited unless the object owner (i.e. the role that has the OWNERSHIP privilege on the object) also owns the target schema.

When an object is renamed, other objects that reference it must be updated with the new name.

SET ...

Specifies the properties to set for the stored procedure.

COMMENT = 'string_literal'

Adds a comment or overwrites the existing comment for the stored procedure. The value you specify is displayed in the DESCRIPTION column in the output for SHOW PROCEDURES.

LOG_LEVEL = 'log_level'

Specifies the severity level of messages that should be ingested and made available in the active event table. Messages at the specified level (and at more severe levels) are ingested.

For more information about levels, see LOG_LEVEL. For information about setting log level, see Setting log level.

TRACE_LEVEL = 'trace_level'

Controls how trace events are ingested into the event table.

For information about levels, see TRACE_LEVEL. For information about setting trace level, see Setting trace level.

TAG tag_name = 'tag_value' [ , tag_name = 'tag_value' , ... ]

Specifies the tag name and the tag string value.

The tag value is always a string, and the maximum number of characters for the tag value is 256.

For information about specifying tags in a statement, see Tag quotas for objects and columns.

UNSET ...

Specifies the properties to unset for the stored procedure, which resets them to the defaults.

Currently, the only properties you can unset are:

  • COMMENT, which removes the comment, if any, for the procedure.

  • TAG tag_name [ , tag_name ... ]

EXECUTE AS { CALLER | OWNER }

A stored procedure can execute with the privileges of the owner (an “owner’s rights” stored procedure) or with the privileges of the caller (a “caller’s rights” stored procedure). If you execute the statement ALTER PROCEDURE … EXECUTE AS CALLER, then when the procedure is called in the future, it will execute as a caller’s rights procedure. If you execute the statement ALTER PROCEDURE … EXECUTE AS OWNER, then in the future, the procedure will execute as an owner’s rights procedure.

Usage Notes

  • Regarding metadata:

    Attention

    Customers should ensure that no personal data (other than for a User object), sensitive data, export-controlled data, or other regulated data is entered as metadata when using the Snowflake service. For more information, see Metadata Fields in Snowflake.

Examples

Rename stored procedure procedure1 to procedure2:

ALTER PROCEDURE IF EXISTS procedure1(FLOAT) RENAME TO procedure2;
Copy