Was this helpful?
Restrict versus Cascade
The RESTRICT and CASCADE options specify how the DBMS Server handles dependent privileges. The CASCADE option directs the DBMS Server to revoke the specified privileges plus all privileges and objects that depend on the privileges being revoked. The RESTRICT option directs the DBMS Server not to revoke the specified privilege if there are any dependent privileges or objects.
The owner of an object can grant privileges on that object to any user, group, or role. Privileges granted by users who do not own the object are dependent on the privileges granted WITH GRANT OPTION by the owner.
For example, if user jerry owns the employees table, he can grant tom the ability to select data from the table and to enable other users to select data from the table:
GRANT SELECT ON employees TO tom WITH GRANT OPTION;
User tom can now enable another user to select data from the employees table:
GRANT SELECT ON employees TO sylvester WITH GRANT OPTION;
The grant tom conferred on sylvester is dependent on the grant the table's owner jerry conferred on tom. In addition, sylvester can enable other users to select data from the employees table.
If sylvester creates a view on the employees table, that view depends on the SELECT privilege that tom granted to sylvester. For example:
CREATE VIEW njemps AS SELECT * FROM employees WHERE state='New Jersey'
To remove his grant to tom, all grants tom can have issued, and any dependent objects, jerry must specify REVOKE...CASCADE:
REVOKE SELECT ON employees FROM tom CASCADE;
As a result of this statement, the SELECT privilege granted by tom to sylvester is revoked, as are any SELECT grants issued by sylvester to other users conferring SELECT privilege for the employees table. The njemps view is destroyed.
To prevent dependent privileges from being revoked, jerry must specify REVOKE...RESTRICT:
REVOKE SELECT ON employees FROM tom RESTRICT;
Because there are dependent privileges (tom has granted SELECT privilege on the employees table to sylvester), this REVOKE statement fails, and no privileges are revoked. The njemps view is not destroyed.
Note:  If privileges are revoked from specific authorization IDs (users, groups, and roles) that were also granted to PUBLIC, privileges and objects that depend on the grants persist (until the privileges are revoked from PUBLIC).
The RESTRICT and CASCADE parameters have the same effect whether revoking a specific privilege or the GRANT OPTION for a specific privilege. In either case, RESTRICT prevents the operation from occurring if there are dependent privileges, and CASCADE causes dependent privileges to be deleted. When revoking a GRANT OPTION with CASCADE, all dependent privileges are revoked, not only the GRANT OPTION portion of the dependent privileges.
RESTRICT or CASCADE must be specified when revoking privileges on tables, database procedures, or database events. When revoking database privileges, CASCADE, RESTRICT or GRANT OPTION cannot be specified (because database privileges cannot be granted with GRANT OPTION).
Last modified date: 08/28/2024