In a multitenant environment, a common user is a database user whose identity and password are known in the root and in every existing and future pluggable database (PDB). Common users can connect to the root and perform administrative tasks specific to the root or PDBs. There are two types of common users :
- All Oracle-supplied administrative user accounts, such as SYS and SYSTEM
- User created common users- Their names must start with C## or c##.
When a PDB having a user created common user is plugged into another CDB and the target CDB does not have a common user with the same name, the common user in a newly plugged in PDB becomes a locked account.
To access such common user’s objects, you can do one of the following:
- Leave the user account locked and use the objects of its schema.
- Create a common user with the same name as the locked account.
Let’s demonstrate …
Current scenario:
Source CDB : CDB1
– one PDB (PDB1)
– Two common users C##NXISTS and C##EXISTS
Destination CDB : CDB2
– No PDB
– One common user C##EXISTS
Overview:
– As user C##NXISTS, create and populate a table in PDB1@CDB1
– Unplug PDB1 from CDB1 and plug into CDB2 as PDB1_COPY
– Open PDB1_COPY and Verify that
- user C##NXISTS has not been created in root
- users C##NXISTS and C##EXISTS both have been created in PDB1_COPY. Account of C##EXISTS is open whereas account of C##NXISTS is closed.
– Unlock user C##NXISTS account in PDB1_COPY.
– Try to connect to pdb1_copy as C##NXISTS – fails with internal error.
– Create a local user LUSER in PDB1_COPY with privileges on C##NXISTS’ table and verify that LUSER can access C##NXISTS’ table.
– Create user C##NXISTS in root with PDB1_COPY closed. Account of
C##NXISTS is automatically opened on opening PDB1_COPY.
– Try to connect as C##NXISTS to pdb1_copy – succeeds
Implementation:
– Setup –
CDB1>sho con_name CON_NAME ------------------------------ CDB$ROOT CDB1>sho pdbs CON_ID CON_NAME OPEN MODE RESTRICTED ---------- ------------------------------ ---------- ---------- 2 PDB$SEED READ ONLY NO 3 PDB1 READ WRITE NO CDB1>select username, common from cdb_users where username like 'C##%'; no rows selected
- Create 2 common users in CDB1
– C##NXISTS
– C##EXISTS
CDB1>create user C##EXISTS identified by oracle container=all; create user C##NXISTS identified by oracle container=all; col username for a30 col common for a10 select username, common from cdb_users where username like 'C##%'; USERNAME COMMON ------------------------------ ---------- C##NXISTS YES C##EXISTS YES C##NXISTS YES C##EXISTS YES
- Create user C##EXISTS in CDB2
CDB2>sho parameter db_name NAME TYPE VALUE ------------------------------------ ----------- db_name string cdb2 CDB2>sho pdbs CON_ID CON_NAME OPEN MODE RESTRICTED ---------- ------------------------------ ---------- ---------- 2 PDB$SEED READ ONLY NO CDB2>create user C##EXISTS identified by oracle container=all; col username for a30 col common for a10 select username, common from cdb_users where username like 'C##%'; USERNAME COMMON ------------------------------ ---------- C##EXISTS YES
- As user C##NXISTS, create and populate a table in PDB1@CDB1
CDB1>alter session set container=pdb1; alter user C##NXISTS quota unlimited on users; create table C##NXISTS.test(x number); insert into C##NXISTS.test values (1); commit;
- Unplug PDB1 from CDB1
CDB1>alter session set container=cdb$root; alter pluggable database pdb1 close immediate; alter pluggable database pdb1 unplug into '/home/oracle/pdb1.xml'; CDB1>select name from v$datafile where con_id = 3; NAME ----------------------------------------------------------------------- /u01/app/oracle/oradata/cdb1/pdb1/system01.dbf /u01/app/oracle/oradata/cdb1/pdb1/sysaux01.dbf /u01/app/oracle/oradata/cdb1/pdb1/SAMPLE_SCHEMA_users01.dbf /u01/app/oracle/oradata/cdb1/pdb1/example01.dbf
- Plug in PDB1 into CDB2 as PDB1_COPY
CDB2>create pluggable database pdb1_copy using '/home/oracle/pdb1.xml' file_name_convert =
('/u01/app/oracle/oradata/cdb1/pdb1','/u01/app/oracle/oradata/cdb2/pdb1_copy');
sho pdbs
CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------------------------ ---------- ----------
2 PDB$SEED READ ONLY NO
3 PDB1_COPY MOUNTED
– Verify that C##NXISTS user is not visible as PDB1_COPY is closed
CDB2>col username for a30 col common for a10 select username, common from cdb_users where username like 'C##%'; USERNAME COMMON ------------------------------ ---------- C##EXISTS YES
- Open PDB1_COPY and Verify that
. users C##NXISTS and C##EXISTS both have been created in PDB.
. Account of C##EXISTS is open whereas account of C##NXISTS is locked.
CDB2>alter pluggable database pdb1_copy open; col account_status for a20 select con_id, username, common, account_status from cdb_users where username like 'C##%' order by con_id, username; CON_ID USERNAME COMMON ACCOUNT_STATUS ---------- ------------------------------ ---------- -------------------------- 1 C##EXISTS YES OPEN 3 C##EXISTS YES OPEN 3 C##NXISTS YES LOCKED
– Unlock user C##NXISTS account on PDB1_COPY
CDB2>alter session set container = pdb1_copy; alter user C##NXISTS account unlock; col account_status for a20 select con_id, username, common, account_status from cdb_users where username like 'C##%' order by con_id, username; CON_ID USERNAME COMMON ACCOUNT_STATUS ---------- ------------------------------ ------------- --------------------------- 3 C##EXISTS YES OPEN 3 C##NXISTS YES OPEN
– Try to connect as C##NXISTS to pdb1_copy – fails with internal error
CDB2>conn c##nxists/oracle@localhost:1522/pdb1_copy ERROR: ORA-00600: internal error code, arguments: [kziaVrfyAcctStatinRootCbk: !user], [C##NXISTS], [], [], [], [], [], [], [], [], [], []
- Since user C##NXISTS cannot connect pdb1_copy, we can lock the account again
CDB2>conn sys/oracle@localhost:1522/pdb1_copy as sysdba
alter user C##NXISTS account lock;
col account_status for a20
select username, common, account_status from dba_users where username like 'C##%' order by username;
USERNAME COMMON ACCOUNT_STATUS
------------------------------ ---------- --------------------
C##EXISTS YES OPEN
C##NXISTS YES LOCKED
– Now if C##NXISTS tries to log in to PDB1_COPY, ORA-28000 is returned instead of internal error
CDB2>conn c##nxists/oracle@localhost:1522/pdb1_copy
ERROR:
ORA-28000: the account is locked
How to access C##NXISTS objects?
SOLUTION – I
- Create a local user in PDB1_COPY with appropriate object privileges on C##NXISTS’ table
CDB2>conn sys/oracle@localhost:1522/pdb1_copy as sysdba create user luser identified by oracle; grant select on c##nxists.test to luser; grant create session to luser;
–Check that local user can access common user C##NXISTS tables
CDB2>conn luser/oracle@localhost:1522/pdb1_copy; select * from c##nxists.test; X ---------- 1
SOLUTION – II : Create the common user C##NXISTS in CDB2
- Check that C##NXISTS has not been created in CDB$root
CDB2>conn sys/oracle@cdb2 as sysdba col account_status for a20 select con_id, username, common, account_status from cdb_users where username like 'C##%' order by con_id, username; CON_ID USERNAME COMMON ACCOUNT_STATUS ---------- ------------------------------ ------------- ------------------------- 1 C##EXISTS YES OPEN 3 C##EXISTS YES OPEN 3 C##NXISTS YES LOCKED
- Try to create user C##NXISTS with PDB1_COPY open – fails
CDB2>create user c##NXISTS identified by oracle; create user c##NXISTS identified by oracle * ERROR at line 1: ORA-65048: error encountered when processing the current DDL statement in pluggable database PDB1_COPY ORA-01920: user name 'C##NXISTS' conflicts with another user or role name
- Close PDB1_COPY and Create user C##NXISTS in root and verify that his account is automatically unlocked on opening PDB1_COPY
CDB2>alter pluggable database pdb1_copy close; create user c##NXISTS identified by oracle; alter pluggable database pdb1_copy open; col account_status for a20 select con_id, username, common, account_status from cdb_users where username like 'C##%' order by con_id, username; CON_ID USERNAME COMMON ACCOUNT_STATUS ---------- ------------------------------ ---------- -------------------- 1 C##EXISTS YES OPEN 1 C##NXISTS YES OPEN 3 C##EXISTS YES OPEN 3 C##NXISTS YES OPEN
– Connect to PDB1_COPY as C##NXISTS after granting appropriate privilege – Succeeds
CDB2>conn c##nxists/oracle@localhost:1522/pdb1_copy ERROR: ORA-01045: user C##NXISTS lacks CREATE SESSION privilege; logon denied Warning: You are no longer connected to ORACLE. CDB2>conn sys/oracle@localhost:1522/pdb1_copy as sysdba grant create session to c##nxists; conn c##nxists/oracle@localhost:1522/pdb1_copy CDB2>sho con_name CON_NAME ------------------------------ PDB1_COPY CDB2>sho user USER is "C##NXISTS" CDB2>select * from test; X ---------- 1
References:
http://docs.oracle.com/database/121/DBSEG/users.htm#DBSEG573
———————————————————————————————
Related Links:
—————-