Removes access privileges.
REVOKE [GRANT OPTION FOR] { {SELECT | INSERT | UPDATE | DELETE
| REFERENCES | TRIGGER | TRUNCATE } [, ...] | ALL [PRIVILEGES] }
ON { [TABLE] <table_name> [, ...]
| ALL TABLES IN SCHEMA schema_name [, ...] }
FROM { [ GROUP ] <role_name> | PUBLIC} [, ...]
[CASCADE | RESTRICT]
REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE
| REFERENCES } ( <column_name> [, ...] )
[, ...] | ALL [ PRIVILEGES ] ( <column_name> [, ...] ) }
ON [ TABLE ] <table_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [GRANT OPTION FOR] { {USAGE | SELECT | UPDATE} [,...]
| ALL [PRIVILEGES] }
ON { SEQUENCE <sequence_name> [, ...]
| ALL SEQUENCES IN SCHEMA schema_name [, ...] }
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[CASCADE | RESTRICT]
REVOKE [GRANT OPTION FOR] { {CREATE | CONNECT
| TEMPORARY | TEMP} [, ...] | ALL [PRIVILEGES] }
ON DATABASE <database_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC} [, ...]
[CASCADE | RESTRICT]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | ALL [ PRIVILEGES ] }
ON DOMAIN <domain_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN DATA WRAPPER <fdw_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | ALL [ PRIVILEGES ] }
ON FOREIGN SERVER <server_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [GRANT OPTION FOR] {EXECUTE | ALL [PRIVILEGES]}
ON { FUNCTION <funcname> ( [[<argmode>] [<argname>] <argtype>
[, ...]] ) [, ...]
| ALL FUNCTIONS IN SCHEMA schema_name [, ...] }
FROM { [ GROUP ] <role_name> | PUBLIC} [, ...]
[CASCADE | RESTRICT]
REVOKE [GRANT OPTION FOR] {USAGE | ALL [PRIVILEGES]}
ON LANGUAGE <langname> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC} [, ...]
[ CASCADE | RESTRICT ]
REVOKE [GRANT OPTION FOR] { {CREATE | USAGE} [, ...]
| ALL [PRIVILEGES] }
ON SCHEMA <schema_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC} [, ...]
[CASCADE | RESTRICT]
REVOKE [GRANT OPTION FOR] { CREATE | ALL [PRIVILEGES] }
ON TABLESPACE <tablespacename> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[CASCADE | RESTRICT]
REVOKE [ GRANT OPTION FOR ]
{ USAGE | ALL [ PRIVILEGES ] }
ON TYPE <type_name> [, ...]
FROM { [ GROUP ] <role_name> | PUBLIC } [, ...]
[ CASCADE | RESTRICT ]
REVOKE [ADMIN OPTION FOR] <parent_role> [, ...]
FROM [ GROUP ] <member_role> [, ...]
[CASCADE | RESTRICT]
REVOKE
command revokes previously granted privileges from one or more roles. The key word PUBLIC
refers to the implicitly defined group of all roles.
See the description of the GRANT command for the meaning of the privilege types.
Note that any particular role will have the sum of privileges granted directly to it, privileges granted to any role it is presently a member of, and privileges granted to PUBLIC
. Thus, for example, revoking SELECT
privilege from PUBLIC
does not necessarily mean that all roles have lost SELECT
privilege on the object: those who have it granted directly or via another role will still have it. Similarly, revoking SELECT
from a user might not prevent that user from using SELECT
if PUBLIC
or another membership role still has SELECT
rights.
If GRANT OPTION FOR
is specified, only the grant option for the privilege is revoked, not the privilege itself. Otherwise, both the privilege and the grant option are revoked.
If a role holds a privilege with grant option and has granted it to other roles then the privileges held by those other roles are called dependent privileges. If the privilege or the grant option held by the first role is being revoked and dependent privileges exist, those dependent privileges are also revoked if CASCADE
is specified, else the revoke action will fail. This recursive revocation only affects privileges that were granted through a chain of roles that is traceable to the role that is the subject of this REVOKE
command. Thus, the affected roles may effectively keep the privilege if it was also granted through other roles.
When you revoke privileges on a table, Greenplum Database revokes the corresponding column privileges (if any) on each column of the table, as well. On the other hand, if a role has been granted privileges on a table, then revoking the same privileges from individual columns will have no effect.
When revoking membership in a role, GRANT OPTION
is instead called ADMIN OPTION
, but the behavior is similar.
See GRANT.
A user may revoke only those privileges directly granted by that user. If, for example, user A grants a privilege with grant option to user B, and user B has in turn granted it to user C, then user A cannot revoke the privilege directly from C. Instead, user A could revoke the grant option from user B and use the CASCADE
option so that the privilege is in turn revoked from user C. For another example, if both A and B grant the same privilege to C, A can revoke their own grant but not B's grant, so C effectively still has the privilege.
When a non-owner of an object attempts to REVOKE
privileges on the object, the command fails outright if the user has no privileges whatsoever on the object. As long as some privilege is available, the command proceeds, but it will revoke only those privileges for which the user has grant options. The REVOKE ALL PRIVILEGES
forms issue a warning message if no grant options are held, while the other forms issue a warning if grant options for any of the privileges specifically named in the command are not held. (In principle these statements apply to the object owner as well, but since Greenplum Database always treats the owner as holding all grant options, the cases can never occur.)
If a superuser chooses to issue a GRANT
or REVOKE
command, Greenplum Database performs the command as though it were issued by the owner of the affected object. Since all privileges ultimately come from the object owner (possibly indirectly via chains of grant options), it is possible for a superuser to revoke all privileges, but this might require use of CASCADE
as stated above.
REVOKE
may also be invoked by a role that is not the owner of the affected object, but is a member of the role that owns the object, or is a member of a role that holds privileges WITH GRANT OPTION
on the object. In this case, Greenplum Database performs the command as though it were issued by the containing role that actually owns the object or holds the privileges WITH GRANT OPTION
. For example, if table t1
is owned by role g1
, of which role u1
is a member, then u1
can revoke privileges on t1
that are recorded as being granted by g1
. This includes grants made by u1
as well as by other members of role g1
.
If the role that runs REVOKE
holds privileges indirectly via more than one role membership path, it is unspecified which containing role will be used to perform the command. In such cases it is best practice to use SET ROLE
to become the specific role as which you want to do the REVOKE
. Failure to do so may lead to revoking privileges other than the ones you intended, or not revoking any privileges at all.
Use psql
's \dp
meta-command to obtain information about existing privileges for tables and columns. There are other \d
meta-commands that you can use to display the privileges of non-table objects.
Revoke insert privilege for the public on table films
:
REVOKE INSERT ON films FROM PUBLIC;
Revoke all privileges from role sally
on view topten
. Note that this actually means revoke all privileges that the current role granted (if not a superuser).
REVOKE ALL PRIVILEGES ON topten FROM sally;
Revoke membership in role admins
from user joe
:
REVOKE admins FROM joe;
The compatibility notes of the GRANT command also apply to REVOKE
.
Either RESTRICT
or CASCADE
is required according to the standard, but Greenplum Database assumes RESTRICT
by default.
Parent topic: SQL Commands