| Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-01 |
|
SQL Statements: DROP SEQUENCE to ROLLBACK, 18 of 19
Use the REVOKE statement to:
See Also:
|
To revoke a system privilege or role, you must have been granted the privilege with the ADMIN OPTION.
To revoke a role, you must have been granted the role with the ADMIN OPTION. You can revoke any role if you have the GRANT ANY ROLE system privilege.
To revoke an object privilege, you must previously have granted the object privilege to the user and role or you must have the GRANT ANY OBJECT PRIVILEGE system privilege. In the latter case, you can revoke any object privilege that was granted by the object owner or on behalf of the owner (that is, by a user with the GRANT ANY OBJECT PRIVILEGE). However, you cannot revoke an object privilege that was granted by way of a WITH GRANT OPTION grant.
The REVOKE statement can revoke only privileges and roles that were previously granted directly with a GRANT statement. You cannot use this statement to revoke:
revoke::=
(on_object_clause::=, grantee_clause::=)
Specify the system privilege to be revoked.
| See Also:
Table 17-1 for a list of the system privileges |
PUBLIC, then Oracle removes the privilege from the privilege domain of each user who has been granted the privilege through PUBLIC. Effective immediately, such users can no longer exercise the privilege. However, the privilege is not revoked from users who have been granted the privilege directly or through roles.Restriction on system privileges: A system privilege cannot appear more than once in the list of privileges to be revoked.
Oracle provides a shortcut for specifying all system privileges at once:
ALL PRIVILEGES: Specify ALL PRIVILEGES to revoke all the system privileges listed in Table 17-1.Specify the role to be revoked.
PUBLIC, then Oracle makes the role unavailable to all users who have been granted the role through PUBLIC. Any user who has enabled the role can continue to exercise the privileges in its privilege domain as long as it remains enabled. However, users cannot subsequently enable the role. The role is not revoked from users who have been granted the role directly or through other roles.Restriction on system roles: A system role cannot appear more than once in the list of roles to be revoked.
| See Also:
Table 17-2 for a list of the roles predefined by Oracle |
FROM grantee_clause identifies users or roles from which the system privilege, role, or object privilege is to be revoked.
Specify PUBLIC to revoke the privileges or roles from all users.
Specify the object privilege to be revoked. You can substitute any of the following values: ALTER, DELETE, EXECUTE, INDEX, INSERT, READ, REFERENCES, SELECT, UPDATE.
If you revoke a privilege from a user, then Oracle removes the privilege from the user's privilege domain. Effective immediately, the user cannot exercise the privilege.
REFERENCES privilege from a user who has exercised the privilege to define referential integrity constraints, then you must specify the CASCADE CONSTRAINTS clause.
If you revoke a privilege from a role, then Oracle removes the privilege from the role's privilege domain. Effective immediately, users with the role enabled cannot exercise the privilege. Other users who have been granted the role cannot exercise the privilege after enabling the role.
If you revoke a privilege from PUBLIC, then Oracle removes the privilege from the privilege domain of each user who has been granted the privilege through PUBLIC. Effective immediately, all such users are restricted from exercising the privilege. However, the privilege is not revoked from users who have been granted the privilege directly or through roles.
Restriction on object privileges: A privilege cannot appear more than once in the list of privileges to be revoked. A user, a role, or PUBLIC cannot appear more than once in the FROM clause.
Specify ALL to revoke all object privileges that you have granted to the revokee. (The keyword PRIVILEGES is provided for semantic clarity and is optional.)
|
Note: If no privileges have been granted on the object, then Oracle takes no action and does not return an error. |
This clause is relevant only if you revoke the REFERENCES privilege or ALL [PRIVILEGES]. It drops any referential integrity constraints that the revokee has defined using the REFERENCES privilege (which might have been granted either explicitly or implicitly through a grant of ALL [PRIVILEGES]).
Specify FORCE to revoke the EXECUTE object privilege on user-defined type objects with table or type dependencies. You must use FORCE to revoke the EXECUTE object privilege on user-defined type objects with table dependencies.
If you specify FORCE, then all privileges will be revoked, but all dependent objects are marked INVALID, data in dependent tables becomes inaccessible, and all dependent function-based indexes are marked UNUSABLE. (Regranting the necessary type privilege will revalidate the table.)
| See Also:
Oracle9i Database Concepts for detailed information about type dependencies and user-defined object privileges |
The on_object_clause identifies the objects on which privileges are to be revoked.
Specify the object on which the object privileges are to be revoked. This object can be:
If you do not qualify object with schema, then Oracle assumes the object is in your own schema.
If you revoke the SELECT object privilege (with or without the GRANT OPTION) on the containing table or materialized view of a materialized view, then Oracle invalidates the materialized view.
If you revoke the SELECT object privilege (with or without the GRANT OPTION) on any of the master tables of a materialized view, then Oracle invalidates both the materialized view and its containing table or materialized view.
Specify the directory object on which privileges are to be revoked. You cannot qualify directory_name with schema. The object must be a directory.
The JAVA clause lets you specify a Java source or resource schema object on which privileges are to be revoked.
The following statement revokes the DROP ANY TABLE system privilege from the users hr and oe:
REVOKE DROP ANY TABLE FROM hr, oe;
The users hr and oe can no longer drop tables in schemas other than their own.
The following statement revokes the role dw_manager from the user sh:
REVOKE dw_manager FROM sh;
sh can no longer enable the dw_manager role.
The following statement revokes the CREATE TABLESPACE system privilege from the dw_manager role:
REVOKE CREATE TABLESPACE FROM dw_manager;
Enabling the dw_manager role no longer allows users to create tablespaces.
To revoke the role dw_user from the role dw_manager, issue the following statement:
REVOKE dw_user FROM dw_manager;
dw_user privileges are no longer granted to dw_manager
You can grant DELETE, INSERT, SELECT, and UPDATE privileges on the table orders to the user hr with the following statement:
GRANT ALL ON orders TO hr;
To revoke the DELETE privilege on orders from hr, issue the following statement:
REVOKE DELETE ON orders FROM hr;
To revoke the remaining privileges on orders that you granted to hr, issue the following statement:
REVOKE ALL ON orders FROM hr;
You can grant SELECT and UPDATE privileges on the view emp_details_view to all users by granting the privileges to the role PUBLIC:
GRANT SELECT, UPDATE ON emp_details_view TO public;
The following statement revokes UPDATE privilege on emp_details_view from all users:
REVOKE UPDATE ON emp_details_view FROM public;
Users can no longer update the emp_details_view view, although users can still query it. However, if you have also granted the UPDATE privilege on emp_details_view to any users, either directly or through roles, then these users retain the privilege.
You can grant the user oe the SELECT privilege on the departments_seq sequence in the schema hr with the following statement:
GRANT SELECT ON hr.departments_seq TO oe;
To revoke the SELECT privilege on departments_seq from oe, issue the following statement:
REVOKE SELECT ON hr.departments_seq FROM oe;
However, if the user hr has also granted SELECT privilege on departments to sh, then sh can still use departments by virtue of hr's grant.
You can grant oe the privileges REFERENCES and UPDATE on the employees table in the schema hr with the following statement:
GRANT REFERENCES, UPDATE ON hr.employees TO oe;
oe can exercise the REFERENCES privilege to define a constraint in his own dependent table that refers to the employees table in the schema hr:
CREATE TABLE dependent (dependno NUMBER, dependname VARCHAR2(10), employee NUMBER CONSTRAINT in_emp REFERENCES hr.employees(employee_id) );
You can revoke the REFERENCES privilege on hr.employees from oe by issuing the following statement that contains the CASCADE CONSTRAINTS clause:
REVOKE REFERENCES ON hr.employees FROM oe CASCADE CONSTRAINTS;
Revoking oe's REFERENCES privilege on hr.employees causes Oracle to drop the in_emp constraint, because oe required the privilege to define the constraint.
However, if oe has also been granted the REFERENCES privilege on hr.employees by a user other than you, then Oracle does not drop the constraint. oe still has the privilege necessary for the constraint by virtue of the other user's grant.
You can revoke READ privilege on directory bfile_dir from hr, by issuing the following statement:
REVOKE READ ON DIRECTORY bfile_dir FROM hr;
Suppose that the database administrator has granted GRANT ANY OBJECT PRIVILEGE to user sh. Now suppose that user hr grants the update privilege on the employees table to oe:
CONNECT hr/hr GRANT UPDATE ON employees TO oe WITH GRANT OPTION;
This grant gives user oe the right to pass the object privilege along to another user:
CONNECT oe/oe GRANT UPDATE ON hr.employees TO pm;
User sh, who has the GRANT ANY OBJECT PRIVILEGE, can now act on behalf of user hr and revoke the update privilege from user oe, because oe was granted the privilege by hr:
CONNECT sh/sh REVOKE UPDATE ON hr.employees FROM oe;
User sh cannot revoke the update privilege from user pm explicitly, because pm received the grant neither from the object owner (hr), nor from sh, nor from another user with GRANT ANY OBJECT PRIVILEGE, but from user oe. However, the preceding statement cascades, removing all privileges that depend on the one revoked. Therefore the object privilege is implicitly revoked from pm as well.
|
![]() Copyright © 1996, 2002 Oracle Corporation. All Rights Reserved. |
|