13.6. Statements for Revoking Privileges
A REVOKE statement is used for revoking privileges — including roles — from users and other database objects.
13.6.1. REVOKE
Used forRevoking privileges or role assignments
Available inDSQL, ESQL
Syntax (revoking privileges)
REVOKE [GRANT OPTION FOR] <privileges>
FROM <grantee_list>
[{GRANTED BY | AS} [USER] grantor]
<privileges> ::=
!! See GRANT syntax !!
Syntax (revoking roles)
REVOKE [ADMIN OPTION FOR] <role_granted_list>
FROM <role_grantee_list>
[{GRANTED BY | AS} [USER] grantor]
<role_granted_list> ::=
!! See
GRANT syntax !!
<role_grantee_list> ::=
!! See GRANT syntax !!
Syntax (revoking all)
REVOKE ALL ON ALL FROM <grantee_list>
<grantee_list> ::=
!! See GRANT syntax !!
REVOKE Statement Parameters| Parameter | Description |
|---|---|
grantor | The grantor user on whose behalf the privilege(s) are being revoked |
The REVOKE statement revokes privileges that were granted using the GRANT statement from users, roles, and other database objects.
See GRANT for detailed descriptions of the various types of privileges.
Only the user who granted the privilege can revoke it.
13.6.1.1. The DEFAULT Clause
When the DEFAULT clause is specified, the role itself is not revoked, only its DEFAULT property is removed without revoking the role itself.
13.6.1.2. The FROM Clause
The FROM clause specifies a list of users, roles and other database objects that will have the enumerated privileges revoked.
The optional USER keyword in the FROM clause allow you to specify exactly which type is to have the privilege revoked.
If a USER (or ROLE) keyword is not specified, the server first checks for a role with this name and, if there is no such role, the privileges are revoked from the user with that name without further checking.
Although the
USERkeyword is optional, it is advisable to use them in order to avoid ambiguity with roles.The
REVOKEstatement does not check for the existence of the user from which the privileges are being revoked.When revoking a privilege from a database object other than
USERorROLE, you must specify its object type
PUBLICPrivileges that were granted to the special user named PUBLIC must be revoked from the user PUBLIC.
User PUBLIC provides a way to grant privileges to all users at once, but it is not a group of users
.
13.6.1.3. Revoking the GRANT OPTION
The optional GRANT OPTION FOR clause revokes the user’s privilege to grant the specified privileges to other users, roles, or database objects (as previously granted with the WITH GRANT OPTION).
It does not revoke the specified privilege itself.
13.6.1.4. Removing the Privilege to One or More Roles
One usage of the REVOKE statement is to remove roles that were assigned to a user, or a group of users, by a GRANT statement.
In the case of multiple roles and/or multiple grantees, the REVOKE verb is followed by the list of roles that will be removed from the list of users specified after the FROM clause.
The optional ADMIN OPTION FOR clause provides the means to revoke the grantee’s administrator
privilege, the ability to assign the same role to other users, without revoking the grantee’s privilege to the role.
Multiple roles and grantees can be processed in a single statement.
13.6.1.5. Revoking Privileges That Were GRANTED BY
A privilege that has been granted using the GRANTED BY clause is internally attributed explicitly to the grantor designated by that original GRANT statement.
Only that user can revoke the granted privilege.
Using the GRANTED BY clause you can revoke privileges as if you are the specified user.
To revoke a privilege with GRANTED BY, the current user must be logged in either with full administrative privileges, or as the user designated as grantor by that GRANTED BY clause.
Not even the owner of a role can use GRANTED BY unless they have administrative privileges.
The non-standard AS clause is supported as a synonym of the GRANTED BY clause to simplify migration from other database systems.
13.6.1.6. Revoking ALL ON ALL
The REVOKE ALL ON ALL statement allows a user to revoke all privileges (including roles) on all object from one or more users, roles or other database objects.
It is a quick way to clear
privileges when access to the database must be blocked for a particular user or role.
When the current user is logged in with full administrator privileges in the database, the REVOKE ALL ON ALL will remove all privileges, no matter who granted them.
Otherwise, only the privileges granted by the current user are removed.
The GRANTED BY clause is not supported
13.6.1.7. Examples using REVOKE
Revoking the privileges for selecting and inserting into the table (or view)
SALESREVOKE SELECT, INSERT ON TABLE SALESFROM USER ALEX;Revoking the privilege for slecting from the
CUSTOMERtable from theMANAGERandENGINEERroles and from the userIVAN:REVOKE SELECT ON TABLE CUSTOMERFROM ROLE MANAGER, ROLE ENGINEER, USER IVAN;Revoking from the
ADMINISTRATORrole the privilege to grant any privileges on theCUSTOMERtable to other users or roles:REVOKE GRANT OPTION FOR ALL ON TABLE CUSTOMERFROM ROLE ADMINISTRATOR;Revoking the privilege for selecting from the
COUNTRYtable and the privilege to reference theNAMEcolumn of theCOUNTRYtable from any user, via the special userPUBLIC:REVOKE SELECT, REFERENCES (NAME) ON TABLE COUNTRYFROM PUBLIC;Revoking the privilege for selecting form the
EMPLOYEEtable from the userIVAN, that was granted by the userALEX:REVOKE SELECT ON TABLE EMPLOYEEFROM USER IVAN GRANTED BY ALEX;Revoking the privilege for updating the
FIRST_NAMEandLAST_NAMEcolumns of theEMPLOYEEtable from the userIVAN:REVOKE UPDATE (FIRST_NAME, LAST_NAME) ON TABLE EMPLOYEEFROM USER IVAN;Revoking the privilege for inserting records into the
EMPLOYEE_PROJECTtable from theADD_EMP_PROJprocedure:REVOKE INSERT ON EMPLOYEE_PROJECTFROM PROCEDURE ADD_EMP_PROJ;Revoking the privilege for executing the procedure
ADD_EMP_PROJfrom theMANAGERrole:REVOKE EXECUTE ON PROCEDURE ADD_EMP_PROJFROM ROLE MANAGER;Revoking the privilege to grant the
EXECUTEprivilege for the functionGET_BEGIN_DATEto other users from the roleMANAGER:REVOKE GRANT OPTION FOR EXECUTEON FUNCTION GET_BEGIN_DATEFROM ROLE MANAGER;Revoking the
EXECUTEprivilege on the packageDATE_UTILSfrom userALEX:REVOKE EXECUTE ON PACKAGE DATE_UTILSFROM USER ALEX;Revoking the
USAGEprivilege on the sequenceGEN_AGEfrom the roleMANAGER:REVOKE USAGE ON SEQUENCE GEN_AGEFROM ROLE MANAGER;Revoking the
USAGEprivilege on the sequenceGEN_AGEfrom the triggerTR_AGE_BI:REVOKE USAGE ON SEQUENCE GEN_AGEFROM TRIGGER TR_AGE_BI;Revoking the
USAGEprivilege on the exceptionE_ACCESS_DENIEDfrom the packagePKG_BILL:REVOKE USAGE ON EXCEPTION E_ACCESS_DENIEDFROM PACKAGE PKG_BILL;Revoking the privilege to create tables from user
JOE:REVOKE CREATE TABLEFROM USER Joe;Revoking the privilege to alter any procedure from user
JOE:REVOKE ALTER ANY PROCEDUREFROM USER Joe;Revoking the privilege to create databases from user
SUPERUSER:REVOKE CREATE DATABASEFROM USER Superuser;Revoking the
DIRECTORandMANAGERroles from the userIVAN:REVOKE DIRECTOR, MANAGER FROM USER IVAN;Revoke from the user
ALEXthe privilege to grant theMANAGERrole to other users:REVOKE ADMIN OPTION FOR MANAGER FROM USER ALEX;Revoking all privileges (including roles) on all objects from the user
IVAN:REVOKE ALL ON ALLFROM USER IVAN;After this statement is executed by an administrator, the user
IVANwill have no privileges whatsoever, except those granted throughPUBLIC.Revoking the
DEFAULTproperty of theDIRECTORrole from userALEX, while the role itself remains granted:REVOKE DEFAULT DIRECTORFROM USER ALEX;
See alsoGRANT