REVOKE
Description
Revokes permissions from one or more roles.
Precautions
If a non-owner user of an object attempts to REVOKE permission on the object, the statement is executed based on the following rules:
- If the user has no permissions whatsoever on the object, the statement will fail outright.
- If an authorized user has some permissions, only the permissions with authorization options are revoked.
- If the authorized user does not have the authorization option, the REVOKE ALL PRIVILEGES form will issue an error message. For other forms of statements, if the permission specified in the statement does not have the corresponding authorization option, the statement will issue a warning.
Syntax
- Revoke the permission on a specified table or view.
REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | ALTER | DROP | COMMENT | INDEX | VACUUM }[, ...] | ALL [ PRIVILEGES ] } ON { [ TABLE ] table_name [, ...] | ALL TABLES IN SCHEMA schema_name [, ...] } FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ]; - Revoke the permission on a specified column in a table.
REVOKE [ GRANT OPTION FOR ] { {{ SELECT | INSERT | UPDATE | REFERENCES | COMMENT } ( column_name [, ...] )}[, ...] | ALL [ PRIVILEGES ] ( column_name [, ...] ) } ON [ TABLE ] table_name [, ...] FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ]; - Revoke the permission on a specified sequence. The LARGE column is optional. The recycling statement does not distinguish whether the sequence is LARGE.
1 2 3 4 5 6
REVOKE [ GRANT OPTION FOR ] { { SELECT | UPDATE | ALTER | DROP | COMMENT }[, ...] | ALL [ PRIVILEGES ] } ON { [ [ LARGE ] SEQUENCE ] sequence_name [, ...] } FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ];
- Revoke the permission on a specified database.
REVOKE [ GRANT OPTION FOR ] { { CREATE | CONNECT | TEMPORARY | TEMP | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] } ON DATABASE database_name [, ...] FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ];
This syntax takes effect when the GUC parameter m_format_behavior_compat_options is set to grant_database_nomapping. It revokes the access permission of a specified user or role on database-level objects. If the grant_database_nomapping option is not set, REVOKE ON DATABASE is mapped to REVOKE ON SCHEMA, revoking the access permission of a specified user or role on schema-level objects. REVOKE ON DATABASE supports only the syntax options supported by REVOKE ON SCHEMA.
- Revoke the permission on a specified schema.
REVOKE [ GRANT OPTION FOR ] { { CREATE | USAPRIVILEGEGE | ALTER | DROP | COMMENT } [, ...] | ALL [ PRIVILEGES ] } ON SCHEMA schema_name [, ...] FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ]; - Revoke permissions from a role.
REVOKE [ ADMIN OPTION FOR ] role_name [, ...] FROM role_name [, ...] [ CASCADE | RESTRICT ]; - Revoke the SYSADMIN permission from a role.
REVOKE ALL PRIVILEGES FROM role_name;
- Revoke the ANY permissions.
1 2 3 4 5 6 7
REVOKE [ ADMIN OPTION FOR ] { CREATE ANY TABLE | ALTER ANY TABLE | DROP ANY TABLE | SELECT ANY TABLE | INSERT ANY TABLE | UPDATE ANY TABLE | DELETE ANY TABLE | CREATE ANY SEQUENCE | CREATE ANY INDEX | ALTER ANY SEQUENCE | DROP ANY SEQUENCE | SELECT ANY SEQUENCE | ALTER ANY INDEX | DROP ANY INDEX } [, ...] FROM [ GROUP ] role_name [, ...];
Parameters
The keyword PUBLIC indicates an implicitly defined group that has all roles.
For details about permission types and parameters, see Parameters in section "GRANT."
Permissions of a role include the permissions directly granted to the role, permissions inherited from the parent role, and permissions granted to PUBLIC. Therefore, revoking the SELECT permission on an object from PUBLIC users does not necessarily mean that the SELECT permission on the object has been revoked from all roles, because the SELECT permission directly granted to roles and inherited from parent roles remains. Similarly, if the SELECT permission is revoked from a user but is not revoked from PUBLIC users, the user can still run the SELECT statement.
If GRANT OPTION FOR is specified, the permission cannot be granted to others, but permission itself is not revoked.
If user A holds the UPDATE permission on a table and the WITH GRANT OPTION option and has granted them to user B, the permission that user B holds is called dependent permission. When user A's permission or grant option is revoked, CASCADE must be declared to revoke all dependent permissions.
A user can only revoke permissions that were granted directly by that user. For example, if user A has granted permission with grant option (WITH ADMIN OPTION) to user B, and user B has in turn granted it to user C, then user A cannot revoke the permission directly from C. However, user A can revoke the grant option held by user B and use CASCADE. In this way, the permission of user C is automatically revoked. For another example, if both user A and user B have granted the same permission to C, A can revoke A's own grant but not B's grant, so C will still effectively have the permission.
If the role executing REVOKE holds permissions indirectly by using more than one role membership path, it is unspecified which containing role will be used to execute the statement. In such cases, you are advised to use SET ROLE to become the specific role, and then execute REVOKE. Failure to do so may lead to deleting permissions not intended to delete, or not deleting any permissions at all.
Examples
See Examples in section "GRANT."
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