Privileges for Common Users in Oracle 12c multitenant database architecture have unique constraints allowing for privileges at the CDB level and the PDB levels. Common users may or may not have privileges at all containers in the multitenant database or they may be restricted to only a few. Additionally, privileges maybe restricted to objects in individual containers. The following are general rules governing privileges of common users and we will examine each rule in the below procedures:
- A privilege granted commonly can be used in every container and future container.
- Only common users can grant common privileges.
- Granter of common privileges must connect to root and specify CONTAINER=ALL clause.
- Can include system and object privilege.
- Privileges should never be given to public.
- A privilege granted commonly can be used in every container and future container.
- Using the common user C##DBA we will create the user at the CDB level and grant DBA privileges with the CONTAINER clause equal to all.
SQL> show con_name
CON_NAME
——————————
CDB$ROOT
SQL> create user c##dba identified by password;
User created.
SQL> grant dba to c##dba container=all;
Grant succeeded.
SQL> connect c##dba/password@cdb1;
Connected.
SQL> create user c##user identified by password container=all;
User created.
SQL>
- Now alter the session to container PDB1 as the same user and create a user there. NOTE: Permissions are good both in CDB1 and PDB1 for Common users. This is true because container clause was set to ALL.
SQL> show user
USER is “C##DBA”
SQL> alter session set container=PDB1;
Session altered.
SQL> show user
USER is “C##DBA”
SQL> create user pdb1_user identified by password;
User created.
SQL>
- Only common users can grant common privileges.
- As the common user c##dba grant resource to common user c##user.
SQL> connect c##dba/password@cdb1;
Connected.
SQL> grant resource to c##user;
Grant succeeded.
SQL>
- Granter of common privileges must connect to root and specify CONTAINER=ALL clause for privileges to be granted in all containers.
- This one is a little tricky because it appears that you can do it, however the key is common privilege, you can have privileges in the CDB and a few PDB and it not be common. This procedure shows an example of this scenario.
- Connect to PDB1 as the common user c##dba and grant dba to the user c##user.
SQL> connect c##dba/password@pdb1
Connected.
SQL> grant dba to c##user;
Grant succeeded.
SQL>
- Now a user with common privilege of DBA should be able to connect to any PDB in the CDB, however when we try to connect to pdb2, it fails. Further more when we look at the view dba_role_privs, we note that user C##USER does have DBA role, but not commonly.
SQL> connect c##user/password@pdb2
ERROR:
ORA-01045: user C##USER lacks CREATE SESSION privilege; logon denied
Warning: You are no longer connected to ORACLE.
SQL> connect c##dba/password@pdb1
Connected.
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
GRANTEE COM
—————————— —
C##USER NO
SQL>
- Now logon to the root container as the C##DBA user and grant the DBA role to C##USER. Then view the dba_role_privs table and attempt to connect to PDB2.
SQL> connect c##dba/password@cdb1
Connected.
SQL> grant dba to c##user container=all;
Grant succeeded.
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
GRANTEE COM
—————————— —
C##USER NO
C##USER NO
C##USER YES
SQL> connect c##user/password@pdb2
Connected.
SQL>
- Can include system and object privilege.
- Revoke all rights from user C##USER. If you are following from the above example, the user C##USER has been granted the DBA role twice locally and once commonly. So revoke Common grant at ROOT container and local root grant. Then connect to PDB1 to remove local grant at PDB1.
SQL> connect c##dba/password@cdb1
Connected.
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
GRANTEE COM
—————————— —
C##USER NO
C##USER NO
C##USER YES
SQL> revoke dba from c##user container=ALL;
Revoke succeeded.
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
GRANTEE COM
—————————— —
C##USER NO
C##USER NO
SQL> revoke dba from c##user container=current;
Revoke succeeded.
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
GRANTEE COM
—————————— —
C##USER NO
SQL> connect c##dba/password@pdb1
Connected.
SQL> revoke dba from c##user;
Revoke succeeded.
SQL>
SQL> column grantee format a30
select grantee, common from dba_role_privs where grantee=’C##USER’;
SQL>
no rows selected
SQL>
- Now reconnect to C##DBA at the root level and grant connect and select on V$SESSIONS commonly the user C##USER. To test common privilege to objects.
SQL> connect c##dba/password@cdb1
Connected.
SQL> grant create session to c##user container=all;
Grant succeeded.
SQL> grant select on sys.v_$session to c##user container=all;
Grant succeeded.
SQL>
- Connect the C##USER and execute a select statement on v$session and v$sql objects to validate access from root container. NOTE: We are able to access object v$session but not v$sql.
SQL> connect c##user/password@cdb1
Connected.
SQL> select count(*) from v$session;
COUNT(*)
———-
37
SQL> select count(*) from v$sql;
select count(*) from v$sql
*
ERROR at line 1:
ORA-00942: table or view does not exist
SQL>
- Connect to PDB1 and repeat the above queries to validate common access privileges to objects.
SQL> connect c##user/password@pdb1
Connected.
SQL> select count(*) from v$session;
COUNT(*)
———-
35
SQL> select count(*) from v$sql;
select count(*) from v$sql
*
ERROR at line 1:
ORA-00942: table or view does not exist
SQL>
- Privileges should never be given to public from common account.
- Once a privilege is granted to public, all users have access to that privilege, which is a huge security risk. However, there is no restrictions built into Oracle to prevent this from occurring. We will demonstrate this by the creation of new user c##dba2, grant the new user no privileges, grant dba role to public, connect to both the CDB and PDB, and finally create a user. This is extremely dangerous, because granting privileges to public grants access to system and object privileges to every user. Finally we will revoke DBA role from public and note that the new user c##dba2 can no longer connect.
SQL> connect / as sysdba
Connected.
SQL> alter session set container=cdb$root;
Session altered.
SQL> create user c##dba2 identified by password;
User created.
SQL> grant dba to public container=all;
Grant succeeded.
SQL> connect c##dba2/password@cdb1
Connected.
SQL> connect c##dba2/password@pdb1
Connected.
SQL> create user testing identified by password;
User created.
SQL> connect / as sysdba
Connected.
SQL> revoke dba from public container=all;
Revoke succeeded.
SQL> connect c##dba2/password@cdb1
ERROR:
ORA-01045: user C##DBA2 lacks CREATE SESSION privilege; logon denied
Warning: You are no longer connected to ORACLE.
SQL>
This completes overview of Privileges for Common Users in Oracle Multitenant Databases.
Larry Catt
OCP