Sunday, June 30, 2013

Oracle 12c New Features - Container and Pluggable Databases

Oracle 12c introduces "Multitenant Architecture" which allows consolidation of databases via Container Databases (CDB) and Pluggable Databases (PDB)

The CDB database owns the SGA and running processes, and the PDB databases are serviced by those resources.  This new architecture will be a big change for DBAs experienced in managing earlier versions of the Oracle database, so it is worth taking the time to read the documentation and testing extensively before using these new features.  The theory is that many databases sharing one SGA and set of processes should be more efficient that multiple individually managed memory segments, so this feature is specifically aimed at clouds and large companies.


I used the DBCA utility to create a CDB called T12, which also created a small PDB$SEED database.  DBCA is easy to run, and similar to previous versions, so I won't show screen shots here.  It is also possible to create a CDB database using the CREATE DATABASE statement along with the new ENABLE PLUGGABLE DATABASE clause.  


When managing CDBs and PDBs it is important to ensure you know what container you are currently working on.  By default when you login you will end up in CDB$ROOT.  


[oracle@rac1 admin]$ ps -ef | grep pmon
oracle    7830     1  0 09:08 ?        00:00:00 ora_pmon_T12

[oracle@rac1 admin]$ echo $ORACLE_SID

T12

[oracle@rac1 admin]$ sqlplus / as sysdba

SQL*Plus: Release 12.1.0.1.0 Production on Mon Jul 1 09:11:11 2013
Copyright (c) 1982, 2013, Oracle.  All rights reserved.

Connected to:

Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics, Real Application Testing
and Unified Auditing options

SQL> show con_name

CON_NAME
------------------------------
CDB$ROOT

SQL> show con_id

CON_ID
------------------------------
1

By selecting from v$database we can see that we are currently in a CDB.

SQL> select DBID, name, CDB, CON_ID, CON_DBID from v$database;

      DBID NAME      CDB     CON_ID   CON_DBID
---------- --------- --- ---------- ----------
1216820329 T12       YES          0 1216820329

We can select PDB from dba_services to check what PDBs exist.  In this case we have not created any PDBs, so only the CDB T12 is listed against CDB$ROOT.

SQL> select name, pdb from dba_services;

NAME                PDB
----------------------------------------------------------------
SYS$BACKGROUND      CDB$ROOT
SYS$USERS           CDB$ROOT
T12XDB              CDB$ROOT
T12                 CDB$ROOT

SQL> select name, con_id from v$active_services;

NAME                                                  CON_ID
---------------------------------------------------------------- 
T12XDB                                                1
T12                                                   1
SYS$BACKGROUND                                        1
SYS$USERS                                             1

Create a tnsnames.ora entry for connecting to CDB service T12.

T12 =
 (DESCRIPTION =
 (ADDRESS_LIST =
 (ADDRESS = (PROTOCOL = TCP)(HOST = rac1.test.com)(PORT = 1521)))
 (CONNECT_DATA =
 (SERVICE_NAME = T12)
 )
  )

When we try to create a user we find that in a CDB we are are not allowed to create "local" users, but can only create "common" users with usernames starting with "C##"

SQL> create user test identified by test;
create user test identified by test
            *
ERROR at line 1:
ORA-65096: invalid common user or role name

SQL> !oerr ora 65096
65096, 00000, "invalid common user or role name"
// *Cause:  An attempt was made to create a common user or role with a name
//          that wass not valid for common users or roles.  In addition to
//          the usual rules for user and role names, common user and role
//          names must start with C## or c## and consist only of ASCII
//          characters.
// *Action: Specify a valid common user or role name.
//

SQL> create user test identified by test container=current;
create user test identified by test container=current
                               *
ERROR at line 1:
ORA-65049: creation of local user or role is not allowed in CDB$ROOT

SQL> create user c##test identified by test;

User created.

There are now additional data dictionary views to help manage the PDB and CDB databases (names include PDB, CDB).  You will also notice that many data dictionary views now contain a column CON_ID which allows DBAs to check details for a specific CDB or PDB.  

If we select from v$datafile in the new container database we can see that in addition to the datafiles for the CDB T12, there are datafiles listed for database "pdbseed".  The PDB$SEED database is created at the same time as the CDB and can be used as a source to create PDB databases.


SQL> select name, con_id, plugged_in from v$datafile order by 2;

NAME                                           CON_ID PLUGGED_IN
-------------------------------------------------- ---------- ---
/u01/app/oracle/oradata/T12/system01.dbf            1          0
/u01/app/oracle/oradata/T12/sysaux01.dbf            1          0
/u01/app/oracle/oradata/T12/undotbs01.dbf           1          0
/u01/app/oracle/oradata/T12/users01.dbf             1          0
/u01/app/oracle/oradata/T12/pdbseed/system01.dbf    2          0
/u01/app/oracle/oradata/T12/pdbseed/sysaux01.dbf    2          0

6 rows selected.

The PDB$SEED database is mounted read only, so it is possible to explore it, but there are limits to what you can do with this DB.

SQL> select con_id, name, open_mode from v$pdbs;

    CON_ID NAME                                        OPEN_MODE

---------- ------------------------------------------- ---------
         2 PDB$SEED                                    READ ONLY

SQL> alter session set container=PDB$SEED;

Session altered.

SQL> select name from v$database;

NAME
---------
T12

SQL> show con_name

CON_NAME
------------------------------
PDB$SEED

SQL> show con_id

CON_ID
------------------------------
2

SQL> select open_mode from v$database;

OPEN_MODE
--------------------
READ ONLY

SQL> shutdown;
ORA-65017: seed pluggable database may not be dropped or altered

To create our own read-write PDB as a copy of the PDB$SEED database we just need to execute the "create pluggable database" command.

SQL> create pluggable database PDB1 admin user pdb1_admin identified by password roles = (DBA) FILE_NAME_CONVERT=('/u01/app/oracle/oradata/T12/pdbseed','/u01/app/oracle/oradata/T12/pdb1');

Pluggable database created.


SQL> select pdb_name, status from cdb_pdbs;

PDB_NAME      STATUS
----------------------------------------------------------------
PDB$SEED      NORMAL
PDB1          NEW

SQL> select name, con_id from v$active_services order by 1;

NAME                                           CON_ID
---------------------------------------------------------------- 
SYS$BACKGROUND                                 1
SYS$USERS                                      1
T12                                            1
T12XDB                                         1
pdb1                                           3

SQL> select name from v$datafile where con_id=3;

NAME
-----------------------------------------------------------------
/u01/app/oracle/oradata/T12/pdb1/system01.dbf
/u01/app/oracle/oradata/T12/pdb1/sysaux01.dbf

SQL> select name, open_mode from v$pdbs;

NAME                           OPEN_MODE
------------------------------ ----------
PDB$SEED                       READ ONLY
PDB1                           MOUNTED

We can see from the above that the new PDB was created in MOUNTED state.  We will need to open it if we want to use it.  When we look in the CDB alert log we can see the following :-

Mon Jul 01 10:02:30 2013
create pluggable database PDB1 admin user pdb1_admin identified by * roles = (DBA) FILE_NAME_CONVERT=('/u01/app/oracle/oradata/T12/pdbseed','/u01/app/oracle/oradata/T12/pdb1')
Mon Jul 01 10:02:53 2013
****************************************************************
Pluggable Database PDB1 with pdb id - 3 is created as UNUSABLE.
If any errors are encountered before the pdb is marked as NEW,
then the pdb must be dropped
****************************************************************
Deleting old file#5 from file$
Deleting old file#7 from file$
Adding new file#10 to file$(old file#5)
Adding new file#11 to file$(old file#7)
Successfully created internal service pdb1 at open
ALTER SYSTEM: Flushing buffer cache inst=0 container=3 local
****************************************************************
Post plug operations are now complete.
Pluggable database PDB1 with pdb id - 3 is now marked as NEW.
****************************************************************

Completed: create pluggable database PDB1 admin user pdb1_admin identified by * roles = (DBA) FILE_NAME_CONVERT=('/u01/app/oracle/oradata/T12/pdbseed','/u01/app/oracle/oradata/T12/pdb1')

We can open databases individually as follows, or open all PDBs using "alter pluggable database all open;"

SQL> alter session set container=PDB1;

Session altered.

SQL> show con_name

CON_NAME
------------------------------
PDB1

SQL> alter database open;

Database altered.

SQL> select name, open_mode from v$pdbs;

NAME                           OPEN_MODE
------------------------------ ----------
PDB1                           READ WRITE

We can see the following in the CDB alert log.

alter database open
Mon Jul 01 10:12:50 2013
Pluggable database PDB1 dictionary check beginning
Pluggable Database PDB1 Dictionary check complete
Opening pdb PDB1 (3) with no Resource Manager plan active

XDB installed.


XDB initialized.

Pluggable database PDB1 opened read write

Completed: alter database open

Create a tnsnames.ora entry for the new PDB using the default service PDB1.

PDB1 =
 (DESCRIPTION =
 (ADDRESS_LIST =
 (ADDRESS = (PROTOCOL = TCP)(HOST = rac1.test.com)(PORT = 1521)))
 (CONNECT_DATA =
 (SERVICE_NAME = PDB1)
 )
  )

Now that we have created a PDB we can create "local" users.

SQL> show con_name

CON_NAME
------------------------------
PDB1

SQL> create user test identified by test;

User created.

SQL> grant create session to test;

Grant succeeded.

It is also possible to grant privileges in the PDB for the "common" users that exist in the CDB.

SQL> grant create session to C##TEST container=ALL;


Grant succeeded.

We can now connect directly to the PDB1 pluggable database using both the "local" and "common" users.

SQL> connect test/test@PDB1
Connected.
SQL> show con_name

CON_NAME

------------------------------
PDB1

SQL> connect C##TEST/test@PDB1
Connected.

SQL> show con_name

CON_NAME
------------------------------
PDB1

When logged into PDBs many data dictionary views will restrict our view of the world via CON_ID so that we can't see records relating to other PDBs.  We can see from the following selects that PDB1 uses the UNDO and REDO files from the container database, but has its own SYSTEM, SYSAUX, TEMP files.

SQL> select name from v$datafile;

NAME
-----------------------------------------------------------------
/u01/app/oracle/oradata/T12/undotbs01.dbf
/u01/app/oracle/oradata/T12/pdb1/system01.dbf
/u01/app/oracle/oradata/T12/pdb1/sysaux01.dbf

SQL> select name from v$tempfile;

NAME
-----------------------------------------------------------------
/u01/app/oracle/oradata/T12/pdb1/pdbseed_temp01.dbf

SQL> select member from v$logfile;

MEMBER
-----------------------------------------------------------------
/u01/app/oracle/oradata/T12/redo03.log
/u01/app/oracle/oradata/T12/redo02.log
/u01/app/oracle/oradata/T12/redo01.log

PDB databases can be created from a seed database as demonstrated above, cloned from other PDB databases, or plugged in from previously unplugged PDBs or converted non-CDB databases.  In addition to creating new PDB databases we can also drop, rename, clone, unplug, plug backup, restore, and duplicate.  Check the Oracle documentation for details.

More details here :- Introduction to the Multitenant Architecture