ORA-01031
ORA-01031: Insufficient Privileges means that the current user did not use the right privilege to process the SQL statement.
Since this error can be seen almost in every kind of SQL statement, sometimes you would never know what privilege you lack. So I do my best to collect cases for you.
There're several error patterns of ORA-01031 in this post. You may click whichever situation you encountered.
- Select (Query)
- Create Table
- Create Index
- Create View
- Alter Table (Add Constraint)
- Alter User
- Password Change
- Insert, Update and Delete
- EXECUTE IMMEDIATE
- DGMGRL
- Alter Pluggable Database Close
- PDB Clone
Select (Query)
Tried to select other's table, we got ORA-01031: insufficient privileges.
SQL> show user
USER is "HR"
SQL> select distinct gender from oe.customers;
select distinct gender from oe.customers
*
ERROR at line 1:
ORA-01031: insufficient privileges
Theoretically, if we can't see other's table, we got ORA-00942: table or view does not exist. But the error message indicates us that we don't use the right privilege to do it. Why? We'd better do some tests.
The first test is that, can we describe the table's definition?
SQL> desc oe.customers;
Name Null? Type
----------------------------------------- -------- ----------------------------
...
GENDER VARCHAR2(1)
...
Yes, we can see its metadata, but not data.
So what object privileges we have now? Let's check them by a privileged user.
SQL> show user
USER is "SYSTEM"
SQL> select privilege from dba_tab_privs where owner = 'OE' and table_name = 'CUSTOMERS' and grantee = 'HR' order by 1;
PRIVILEGE
----------------------------------------
DELETE
INSERT
UPDATE
OK, we can INSERT, UPDATE and DELETE, but no SELECT privilege. This is really weird.
Solution to ORA-01031
To solve insufficient privilege in querying, we should grant SELECT privilege to the user.
SQL> grant select on oe.customers to hr;
Grant succeeded.
Then we query the table again.
SQL> select distinct gender from oe.customers;
G
-
M
F
OK, the problem is solved.
Create Table
ORA-01031 is very common when a new user wants to create a table. Let's see an example.
SQL> conn / as sysdba
Connected.
SQL> create user thomas identified by thomas;
User created.
SQL> grant create session to thomas;
Grant succeeded.
As you can see, a new user THOMAS is created, but we only grant CREATE SESSION to him, which allows him to connect to the database. Let's see what will happen if the new user wants to create a table.
C:\Users\edchen>sqlplus thomas/thomas@orcl
...
SQL> create table test1 (id number, e_id number);
create table test1 (id number, e_id number)
*
ERROR at line 1:
ORA-01031: insufficient privileges
Immediately, ORA-01031: insufficient privileges shows up, which tells THOMAS he doesn't have the right privilege to do that.
Solution to ORA-01031
The solution is simple, just grant CREATE TABLE to user, a schema-based privilege or CREATE ANY TABLE, a system-wide privilege.
SQL> conn / as sysdba
Connected.
SQL> grant create table to thomas;
Grant succeeded.
Then tell Thomas to try it again.
SQL> create table test1 (id number, e_id number);
Table created.
If you use EXECUTE IMMEDIATE to run CREATE TABLE in a stored procedure, you may check ORA-01031 in EXECUTE IMMEDIATE section in this post.
Create Index
In the above section, we have granted CREATE TABLE to THOMAS, which enables Thomas the ability to CREATE INDEX in his schema.
Please note that, CREATE INDEX is not a valid privilege, but CREATE ANY INDEX is.
Let's see an example and then we guess what privilege we need.
Suppose Thomas wants to create an index for SH.CUSTOMERS in Thomas's schema, so we grant SELECT on that table (object privilege) by instinct.
SQL> grant select on sh.customers to thomas;
Grant succeeded.
Then Thomas tries to create an index on that table.
SQL> create index customer_id_gen_idx on sh.customers (cust_id, cust_gender);
create index oe.customer_id_gen_idx on sh.customers (cust_id, cust_gender)
*
ERROR at line 1:
ORA-01031: insufficient privileges
Solution to ORA-01031
This is because SELECT on that table is not enough, you should additionally grant INDEX on that table to user, which is an object privilege.
SQL> grant index on sh.customers to thomas;
Grant succeeded.
Try again.
SQL> create index customer_id_gen_idx on sh.customers (cust_id, cust_gender);
Index created.
Even though the case is possible in reality, we seldom create index for other user's table in our schema.
Create View
If you have read the above section, then you have known that you have to grant CREATE VIEW to the user who complain ORA-01031.
SQL> grant create view to thomas;
Grant succeeded.
If the user still got ORA-01031 after granting CREATE VIEW to him, it must be a deeper problem. That's why this section is little longer.
Inherit Privilege from Role
Some privileges inherited from the role might not work in some situation, especially when accessing intermediate kinds of object, like views or store procedures.
Here is a case that can reproduce the error.
We grant role RESOURCE to THOMAS. Then we grant the system privilege SELECT ANY TABLE to the role RESOURCE.
SQL> grant resource to thomas;
Grant succeeded.
SQL> grant select any table to resource;
Grant succeeded.
So we can expect that the user THOMAS inherits the system privilege from RESOURCE. That is, THOMAS can select any other's table.
Let's do the first test. Use THOMAS to select other user's table SH.SALE.
SQL> select count(*) from sh.sales;
COUNT(*)
----------
918843
Good, it acts as we expect, although THOMAS has not any object privilege on SH.SALE.
Let's do the second test. Use THOMAS to create a view which is based on other user's table SH.SALE.
SQL> create view sh_sales_v as select * from sh.sales;
create view sh_sales_v as select * from sh.sales
*
ERROR at line 1:
ORA-01031: insufficient privileges
What happened? THOMAS has CREATE VIEW and inherit SELECT ANY TABLE from RESOURCE, it should have no problem.
The result implies that the role's privileges does not reach underlying objects through intermediate objects like views.
Solution to ORA-01031
The solution to this problem is to grant SELECT on the table to user directly.
First, grant the object privilege explicitly to resolve the problem.
SQL> grant select on sh.sales to thomas;
Grant succeeded.
Then tell Thomas to create view again.
SQL> create view sh_sales_v as select * from sh.sales;
View created.
Now, it's no problem.
Please notice that, if you create a synonym on SH.SALES, it will succeed whether the explicit object privilege is granted directly or not.
Alter Table (ADD CONSTRAINT)
In the above section, we have granted CREATE TABLE to THOMAS. Implicitly, he also has the right to ALTER TABLE on schema-level. So the cause of ORA-01031 in ALTER TABLE is not so obvious as we thought.
Please note that, ALTER TABLE is not a privilege, but ALTER ANY TABLE is. That's why there's no such GRANT ALTER TABLE TO statement.
Let's see an example. User Thomas wants to add a constraint so as to make a reference to another user's data, so we grant SELECT on that table to THOMAS by instinct.
SQL> grant select on hr.employees to thomas;
Then we make the reference.
SQL> alter table test1 add constraint fk_eid foreign key (e_id) references hr.employees (employee_id);
alter table test1 add constraint fk_eid foreign key (e_id) references hr.employees (employee_id)
*
ERROR at line 1:
ORA-01031: insufficient privileges
We got ORA-01031.
Solution to ORA-01031
The right privilege to reference other's data is not SELECT, it's REFERENCES.
We should grant REFERENCES on the table to user either by HR or privileged users.
SQL> grant references on hr.employees to thomas;
Grant succeeded.
Now Thomas can finish his job.
SQL> alter table test1 add constraint fk_eid foreign key (e_id) references hr.employees (employee_id);
Table altered.
Alter User
Tried to add some quota on tablespace to itself, but it lacks of some privileges.
SQL> show user
USER is "HR"
SQL> alter user hr quota unlimited on users;
alter user hr quota unlimited on users
*
ERROR at line 1:
ORA-01031: insufficient privileges
The right privilege in this case is ALTER USER.
SQL> show user
USER is "SYSTEM"
SQL> grant alter user to hr;
Grant succeeded.
Then we do it again.
SQL> show user
USER is "HR"
SQL> alter user hr quota unlimited on users;
User altered.
SQL> alter user oe account lock;
User altered.
As you can see, with ALTER USER privilege, the user not only can grant some quota to itself, but also can change other's status.
Password Change
Tried to change other's password by SQL*Plus command password, but the user has inadequate privileges.
SQL> show user
USER is "HR"
SQL> password oe
Changing password for oe
New password:
Retype new password:
ERROR:
ORA-01031: insufficient privileges
Password unchanged
Since password command is actually an ALTER USER statement, the correct privilege to change other's password is ALTER USER.
Insert, Update and Delete
You may have the right to select other's table.
SQL> conn sh/sh
Connected.
SQL> select * from hr.t1;
ID
----------
1
2
3
But you may not have the right to modify the table. For example, INSERT INTO some data like this:
SQL> insert into hr.t1 values (4);
insert into hr.t1 values (4)
*
ERROR at line 1:
ORA-01031: insufficient privileges
This is because you lack INSERT, UPDATE or DELETE privilege to modify on that table which is usually owned by others.
Solution to ORA-01031
Clearly, the right privilege is INSERT, UPDATE or DELETE at object-level. You may ask for DBA or the object owner to grant the privilege to you.
SQL> conn hr/hr
Connected.
SQL> grant insert,update,delete on hr.t1 to sh;
Grant succeeded.
As we can see, the grantor grants 3 object privileges INSERT, UPDATE and DELETE on the table to the grantee at a time.
In some cases, you may consider to grant all possible object privileges to user, for example:
SQL> grant all on hr.t1 to sh;
Grant succeeded.
In the statement, ALL is a keyword which means all possible privileges on specified object. For a table, it naturally includes not only SELECT, but also INSERT, UPDATE and DELETE.
As a result, we can insert some rows.
SQL> conn sh/sh
Connected.
SQL> insert into hr.t1 values (4);
1 row created.
SQL> commit;
Commit complete.
SQL> select * from hr.t1;
ID
----------
1
2
3
4
That is to say, not only SELECT, but also INSERT, UPDATE or DELETE privilege you should have to manipulate tables owned by other users.
EXECUTE IMMEDIATE
Let's see how I reproduce ORA-01031 for statements using EXECUTE IMMEDIATE by the following example.
Inherit Privilege from Role
In the above section, I have granted role RESOURCE to THOMAS. Now I grant CREATE ANY DIRECTORY and DROP ANY DIRECTORY to the role RESOURCE.
SQL> grant create any directory, drop any directory to resource;
Grant succeeded.
So we can expect that user THOMAS can also do such operations by inheriting all privileges from RESOURCE.
Things look fine when we use THOMAS to create or drop directories.
SQL> create directory tmp_path as '/u02/tmp';
Directory created.
SQL> drop directory tmp_path;
Directory dropped.
SQL> create directory tmp_path as '/u02/tmp';
Directory created
Now, Thomas would like to create directories in stored procedures which is also called named PL/SQL blocks or programming units.
First of all, DBA have to grant CREATE PROCEDURE to him before Thomas doing anything.
SQL> grant create procedure to thomas;
Grant succeeded.
Then Thomas create a procedure like this:
SQL> create or replace procedure drop_create_tmp_dir is
begin
execute immediate 'drop directory tmp_path';
execute immediate 'create or replace directory tmp_path as ''/u02/tmp''';
end drop_create_tmp_dir;
/
2 3 4 5 6
Procedure created.
It seems no problem. But when we execute the stored procedure (named PL/SQL), we got ORA-01031 at line 3.
SQL> exec drop_create_tmp_dir;
BEGIN drop_create_tmp_dir; END;
*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "THOMAS.DROP_CREATE_TMP_DIR", line 3
ORA-06512: at line 1
Rationale
This is because the system privileges inherited from role cannot be used in named stored procedures with definer's right.
Solutions to ORA-01031
Now we have several options, the first one is to grant all necessary privilege to the user directly, the second one is to use invoker's right, and the last one is to use anonymous PL/SQL blocks.
1. Directly Granting to User
THOMAS should directly get the system privilege from DBA, not inherit from role.
SQL> grant create any directory, drop any directory to thomas;
Grant succeeded.
Back to THOMAS, we can execute it again.
SQL> exec drop_create_tmp_dir;
PL/SQL procedure successfully completed.
The better thing is that we don't have to recompile the procedure.
2. Use Invoker's Right
Another way to solve ORA-01031 for statements in EXECUTE IMMEDIATE is to use invoker's right to define the procedure.
Let's revert the granting by SYS.
SQL> revoke create any directory, drop any directory from thomas;
Revoke succeeded.
Then we created the procedure with AUTHID CURRENT_USER clause.
SQL> create or replace procedure drop_create_tmp_dir authid current_user is
begin
execute immediate 'drop directory tmp_path';
execute immediate 'create or replace directory tmp_path as ''/u02/tmp''';
end drop_create_tmp_dir;
/
2 3 4 5 6
Procedure created.
Try to execute the procedure by THOMAS.
SQL> exec drop_create_tmp_dir;
PL/SQL procedure successfully completed.
By invoker's right, we can use role's privileges.
3. Anonymous PL/SQL Block
What we mean in the above is that role privileges cannot penetrate NAMED stored procedures. That is to say, you can use role privileges in anonymous PL/SQL blocks. For instance, we can rewrite the stored procedure to an anonymous PL/SQL as this:
begin
execute immediate 'drop directory tmp_path';
execute immediate 'create or replace directory tmp_path as ''/u02/tmp''';
end;
/
You can save and use it as a normal SQL script file.
For the same reason, CREATE TABLE in EXECUTE IMMEDIATE can also throw ORA-01031.
DGMGRL
DGMGRL allows user to query the status of all nodes involved through the local authentication without problem, but it might fail to switchover to a standby database or convert to a snapshot standby.
DGMGRL Switchover
Let's see a switchover in 11g, it will fail when you connect DGMGRL with local authentication.
[oracle@primary01 ~]$ dgmgrl /
...
DGMGRL> switchover to standb
Performing switchover NOW, please wait...
Operation requires shutdown of instance "primdb2" on database "primdb"
Shutting down instance "primdb2"...
ORA-01031: insufficient privileges
Warning: You are no longer connected to ORACLE.
Please complete the following steps and reissue the SWITCHOVER command:
shut down instance "primdb2" of database "primdb"
DGMGRL>
But if you connect DGMGRL with the database password, the switchover will succeed.
[oracle@primary01 ~]$ dgmgrl sys/password@primdb1
...
DGMGRL> switchover to standb
Performing switchover NOW, please wait...
Operation requires shutdown of instance "primdb2" on database "primdb"
Shutting down instance "primdb2"...
Database closed.
Database dismounted.
ORACLE instance shut down.
New primary database "standb" is opening...
Operation requires shutdown of instance "primdb1" on database "primdb"
Shutting down instance "primdb1"...
ORA-01109: database not open
Database dismounted.
ORACLE instance shut down.
Operation requires startup of instance "primdb1" on database "primdb"
Starting instance "primdb1"...
ORACLE instance started.
Database mounted.
Switchover succeeded, new primary is "standb"
DGMGRL>
DGMGRL Convert
Same error happened in a conversion.
[oracle@primary01 ~]$ dgmgrl /
...
DGMGRL> CONVERT DATABASE standb TO SNAPSHOT STANDBY;
Converting database "standb" to a Snapshot Standby database, please wait...
Operation requires shutdown of instance "standb2" on database "standb"
Shutting down instance "standb2"...
ORA-01031: insufficient privileges
Warning: You are no longer connected to ORACLE.
Please complete the following steps and reissue the CONVERT command:
shut down instance "standb2" of database "standb"
Solution to ORA-01031
You must use the database authentication to convert a standby database.
[oracle@primary01 ~]$ dgmgrl sys/password@primdb1
...
DGMGRL> CONVERT DATABASE standb TO SNAPSHOT STANDBY;
Converting database "standb" to a Snapshot Standby database, please wait...
Operation requires shutdown of instance "standb2" on database "standb"
Shutting down instance "standb2"...
ORA-01109: database not open
Database dismounted.
ORACLE instance shut down.
Continuing to convert database "standb" ...
Database "standb" converted successfully
...
For the same reason, the broker is unable to startup the new standby database during a switchover and throws ORA-01017 due to OS authentication.
Alter Pluggable Database Close
We saw an error when we tried to close a pluggable database (PDB) by a normal user.
SQL> conn hr/password@orclpdb
Connected.
SQL> show user
USER is "HR"
SQL> alter pluggable database close;
alter pluggable database close
*
ERROR at line 1:
ORA-01031: insufficient privileges
To solve ORA-01031, we take two steps to make the user be able to close a PDB.
1. Grant SYSDBA to the User
Please make sure that you login as SYS and are in the right container.
SQL> show user
USER is "SYS"
SQL> show con_namev
CON_NAME
------------------------------
ORCLPDB
Then we grant SYSDBA privilege to the user.
SQL> grant sysdba to hr;
Grant succeeded.
2. Connect as SYSDBA
The user should use SYSDBA privilege to connect to the PDB.
SQL> conn hr/password@orclpdb as sysdba
Connected.
SQL> alter pluggable database close;
Pluggable database altered.
Actually, the normal user has become a SYS which of course has the ability to maintain database.
PDB Clone
When you try to clone a remote PDB via a database link, you may see ORA-17628 and ORA-01031 at that moment. I have talk about it in that post.
Hola! Justamente estábamos tratando de implementar una autogestión para poder crear usuarios y la parte de la cláusula de autenticación nos vino perfecto. Infinitas gracias por compartir este conocimiento valioso