Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
Use the GRANT
statement to grant:
PUBLIC
. Table 17-3 summarizes the object privileges that you can grant on each type of object. Table 17-4 lists object privileges and the operations that they authorize.
See Also:
|
To grant a system privilege, you must either have been granted the system privilege with the ADMIN
OPTION
or have been granted the GRANT
ANY
PRIVILEGE
system privilege.
To grant a role, you must either have been granted the role with the ADMIN
OPTION
or have been granted the GRANT
ANY
ROLE
system privilege, or you must have created the role.
To grant an object privilege, you must own the object, or the owner of the object must have granted you the object privileges with the GRANT
OPTION
, or you must have been granted the GRANT
ANY
OBJECT
PRIVILEGE
system privilege.
grant::=
Specify the system privilege you want to grant. Table 17-1 lists the system privileges (organized by the database object operated upon).
PUBLIC
, then Oracle adds the privilege to the privilege domains of each user. All users can immediately perform operations authorized by the privilege.Oracle provides a shortcut for specifying all system privileges at once:
ALL
PRIVILEGES:
Specify ALL
PRIVILEGES
to grant all the system privileges listed in Table 17-1, " System Privileges", except the SELECT
ANY
DICTIONARY
privilege.Specify the role you want to grant. You can grant an Oracle predefined role or a user-defined role. Table 17-2 lists the predefined roles.
PUBLIC
, then Oracle makes the role available to all users. All users can immediately enable the role and exercise the privileges in the roles privilege domain.
See Also:
CREATE ROLE for information on creating a user-defined role |
Use the IDENTIFIED
BY
clause to specifically identify an existing user by password or to create a nonexistent user. This clause is not valid if the grantee is a role or PUBLIC
. If the user specified in the grantee_clause
does not exist, then Oracle creates the user with the password and with the privileges and roles specified in this clause.
See Also:
CREATE USER for restrictions on usernames and passwords |
Specify WITH
ADMIN
OPTION
to enable the grantee to:
GLOBAL
roleIf you grant a system privilege or role to a user without specifying WITH
ADMIN
OPTION
, and then subsequently grant the privilege or role to the user WITH
ADMIN
OPTION
, then the user has the ADMIN
OPTION
on the privilege or role.
To revoke the ADMIN
OPTION
on a system privilege or role from a user, you must revoke the privilege or role from the user altogether and then grant the privilege or role to the user without the ADMIN
OPTION
.
TO
grantee_clause
identifies users or roles to which the system privilege, role, or object privilege is granted.
A user, role, or PUBLIC
cannot appear more than once in TO
grantee_clause.
Specify PUBLIC
to grant the privileges to all users.
IDENTIFIED
GLOBALLY
to anything.IDENTIFIED
EXTERNALLY
to a global user or global role.banker
to the role teller
, then you cannot subsequently grant teller
to banker
.Specify the object privilege you want to grant. You can specify any of the values shown in Table 17-3. See also Table 17-4.
A privilege cannot appear more than once in the list of privileges to be granted.
Specify ALL
to grant all the privileges for the object that you have been granted with the GRANT
OPTION
. The user who owns the schema containing an object automatically has all privileges on the object with the GRANT
OPTION
. (The keyword PRIVILEGES
is provided for semantic clarity and is optional.)
Specify the table or view column on which privileges are to be granted. You can specify columns only when granting the INSERT
, REFERENCES
, or UPDATE
privilege. If you do not list columns, then the grantee has the specified privilege on all columns in the table or view.
For information on existing column object grants, query the USER_
,ALL_
, and DBA_COL_PRIVS
data dictionary view.
See Also:
Oracle9i Database Reference for information on the data dictionary views and "Granting Multiple Object Privileges on Individual Columns: Example" |
The on_object_clause
identifies the object on which the privileges are granted. Directory schema objects and Java source and resource schema objects are identified separately because they reside in separate namespaces.
If you can make this grant only because you have the GRANT
ANY
OBJECT
PRIVILEGE
system privilege--that is, you are not the owner of object
, nor do you have object_privilege
on object
WITH
GRANT
OPTION
--then the effect of this grant is that you are acting on behalf of the object owner. The *_TAB_PRIVS
data dictionary views will reflect that this grant was made by the owner of object
.
See Also:
|
Specify WITH
GRANT
OPTION
to enable the grantee to grant the object privileges to other users and roles.
You can specify WITH
GRANT
OPTION
only when granting to a user or to PUBLIC
, not when granting to a role.
Specify WITH
HIERARCHY
OPTION
to grant the specified object privilege on all subobjects of object
, including subobjects created subsequent to this statement (such as subviews created under a view).
Specify the schema object on which the privileges are to be granted. If you do not qualify object
with schema
, then Oracle assumes the object is in your own schema. The object can be one of the following types:
Specify a directory schema object on which privileges are to be granted. You cannot qualify directory_name
with a schema name.
The JAVA
clause lets you specify a Java source or resource schema object on which privileges are to be granted.
Predefined Role | Purpose |
---|---|
|
These roles are provided for compatibility with previous versions of Oracle. You can determine the privileges encompassed by these roles by querying the Note: Oracle Corporation recommends that you design your own roles for database security rather than relying on these roles. These roles may not be created automatically by future versions of Oracle. See Also: Oracle9i Database Reference for a description of this view |
|
These roles are provided for accessing data dictionary views and packages. See Also: Oracle9i Database Administrator's Guide for more information on these roles |
|
These roles are provided for convenience in using the Import and Export utilities. See Also: Oracle9i Database Utilities for more information on these roles |
|
You need these roles to use Oracle's Advanced Queuing functionality. See Also: Oracle9i Application Developer's Guide - Advanced Queuing for more information on these roles |
|
|
|
You need this role to create a user who owns a recovery catalog. See Also: Oracle9i User-Managed Backup and Recovery Guide for more information on recovery catalogs |
|
A DBA using Oracle's heterogeneous services feature needs this role to access appropriate tables in the data dictionary. See Also: Oracle9i Heterogeneous Connectivity Administrator's Guide and Oracle9i Supplied PL/SQL Packages and Types Reference for more information |
Object Privilege | Operations Authorized |
---|---|
The following table privileges authorize operations on a table. Any one of following object privileges allows the grantee to lock the table in any lock mode with the |
|
|
Change the table definition with the |
|
Remove rows from the table with the Note: You must grant the |
|
Access, through a debugger: |
|
Create an index on the table with the |
|
Add new rows to the table with the |
|
Create a constraint that refers to the table. You cannot grant this privilege to a role. |
|
Query the table with the |
|
Change data in the table with the Note: You must grant the |
The following view privileges authorize operations on a view. Any one of the following object privileges allows the grantee to lock the view in any lock mode with the To grant a privilege on a view, you must have that privilege with the |
|
|
Access, through a debugger: |
|
Remove rows from the view with the |
|
Add new rows to the view with the |
|
Define foreign key constraints on the view. |
|
Query the view with the |
|
Create a subview under this view. You can grant this object privilege only if you have the |
|
Change data in the view with the |
The following sequence privileges authorize operations on a sequence. |
|
|
Change the sequence definition with the |
|
Examine and increment values of the sequence with the |
The following procedure, function, and package privilege authorizes operations on procedures, functions, and packages. This privilege also applies to Java sources, classes, and resources, which Oracle treats as though they were procedures for purposes of granting object privileges. |
|
|
Access, through a debugger, all public and nonpublic variables, methods, and types defined on the procedure, function, or package. Place a breakpoint or stop at a line or instruction boundary within the procedure, function, or package. This privilege grants access to the declarations in the method or package specification and body. |
|
Compile the procedure or function or execute it directly, or access any program object declared in the specification of a package. Access, through a debugger, public variables, types, and methods defined on the procedure, function, or package. This privilege grants access to the declarations in the method or package specification only. Note: Users do not need this privilege to execute a procedure, function, or package indirectly. See Also: Oracle9i Database Concepts and Oracle9i Application Developer's Guide - Fundamentals |
The following materialized view privileges authorize operations on a materialized view. |
|
|
Create a refresh-on-commit materialized on the specified table. |
|
Create a materialized view for query rewrite using the specified table. |
|
Query the materialized view with the |
Synonym privileges are the same as the privileges for the base object. Granting a privilege on a synonym is equivalent to granting the privilege on the base object. Similarly, granting a privilege on a base object is equivalent to granting the privilege on all synonyms for the object. If you grant to a user a privilege on a synonym, then the user can use either the synonym name or the base object name in the SQL statement that exercises the privilege. |
|
The following directory privileges provide secured access to the files stored in the operating system directory to which the directory object serves as a pointer. The directory object contains the full path name of the operating system directory where the files reside. Because the files are actually stored outside the database, Oracle server processes also need to have appropriate file permissions on the file system server. Granting object privileges on the directory database object to individual database users, rather than on the operating system, allows Oracle to enforce security during file operations. |
|
|
Read files in the directory. |
|
Write files in the directory. This privilege is useful only in connection with external tables. It allows the grantee to determine whether the external table agent can write a log file, or a bad file to the directory. Restriction: This privilege does not allow the grantee to write to a |
The following library privileges authorize operations on a library |
|
|
Use and reference the specified object and to invoke its methods. |
The following object type privilege authorizes operations on a database object type |
|
|
Access, through a debugger, all public and nonpublic variables, methods, and types defined on the object type. Place a breakpoint or stop at a line or instruction boundary within the type body. |
|
Use and reference the specified object and to invoke its methods. Access, through a debugger, public variables, types, and methods defined on the object type. |
|
Create a subtype under this type. You can grant this object privilege only if you have the |
The following indextype privilege authorizes operations on indextypes. |
|
|
Reference an indextype. |
The following operator privilege authorizes operations on user-defined operators. |
|
|
Reference an operator. |
To grant the CREATE
SESSION
system privilege to the sample user hr
, allowing hr
to log on to Oracle, issue the following statement:
GRANT CREATE SESSION TO hr;
To grant appropriate system privileges to a data warehouse manager role (which was created in the "Creating a Role: Example") :
GRANT CREATE ANY MATERIALIZED VIEW , ALTER ANY MATERIALIZED VIEW , DROP ANY MATERIALIZED VIEW , QUERY REWRITE , GLOBAL QUERY REWRITE TO dw_manager WITH ADMIN OPTION;
dw_manager
's privilege domain now contains the system privileges related to materialized views.
To grant the dw_manager
role with the ADMIN
OPTION
to the sample user sh
, issue the following statement:
GRANT dw_manager TO sh WITH ADMIN OPTION;
User sh
can now perform the following operations with the dw_manager
role:
CREATE
MATERIALIZED
VIEW
system privilegeTo grant the SELECT
object privileges to a data warehouse user role (which was created in the "Creating a Role: Example") :
GRANT SELECT ON sh.sales TO warehouse_user;
The following statement grants the warehouse_user
role to the dw_manager
role (both roles were created in the "Creating a Role: Example"):
GRANT warehouse_user TO dw_manager;
The dw_manager
role now contains all of the privileges in the domain of the warehouse_user
role.
To grant READ
on directory bfile_dir
to user hr
, with the GRANT
OPTION
, issue the following statement:
GRANT READ ON DIRECTORY bfile_dir TO hr WITH GRANT OPTION;
To grant all privileges on the table oe.bonuses
(created in "Merging into a Table: Example") to the user hr
with the GRANT
OPTION
, issue the following statement:
GRANT ALL ON bonuses TO hr WITH GRANT OPTION;
hr
can subsequently perform the following operations:
bonuses
tablebonuses
table to another user or roleTo grant SELECT
and UPDATE
privileges on the view emp_view
(created in "Creating a View: Example") to all users, issue the following statement:
GRANT SELECT, UPDATE ON emp_view TO PUBLIC;
All users can subsequently query and update the view of employee details.
To grant SELECT
privilege on the customers_seq
sequence in the schema oe
to the user hr
, issue the following statement:
GRANT SELECT ON oe.customers_seq TO hr;
hr
can subsequently generate the next value of the sequence with the following statement:
SELECT oe.customers_seq.NEXTVAL FROM DUAL;
To grant to user oe
the REFERENCES
privilege on the employee_id
column and the UPDATE
privilege on the employee_id
, salary
, and commission_pct
columns of the employees
table in the schema hr
, issue the following statement:
GRANT REFERENCES (employee_id), UPDATE (employee_id, salary, commission_pct) ON hr.employees TO oe;
oe
can subsequently update values of the employee_id
, salary
, and commission_pct
columns. oe
can also define referential integrity constraints that refer to the employee_id
column. However, because the GRANT
statement lists only these columns, oe
cannot perform operations on any of the other columns of the employees
table.
For example, oe
can create a table with a constraint:
CREATE TABLE dependent (dependno NUMBER, dependname VARCHAR2(10), employee NUMBER CONSTRAINT in_emp REFERENCES hr.employees(employee_id) );
The constraint in_emp
ensures that all dependents in the dependent
table correspond to an employee in the employees
table in the schema hr
.