Monday, May 15, 2017

ORACLE 12C PARTITIONING NEW FEATURES

Online Move Partition

In Oracle 12c we can now move as well as compress partitions online while DML transactions on the partitioned table are in progress.
In earlier versions we would get an error like the one shown below if we attempted to move a partition while a DML statement on the partitioned table was in progress.
ORA-00054: resource busy and acquire with NOWAIT specified or timeout expired
This is tied in to the 12c new feature related to Information Lifecycle Management where tables (and partitions) can be moved to low cost storage and/or compressed as part of an ILM policy. So we would not like to impact any DML statements which are in progress when the partitions are being moved or compressed – hence the online feature.
Another feature in 12c is that this online partition movement will not make the associated partitioned indexes left in an unusable state. The UPDATE INDEXES ONLINE clause will maintain the global and local indexes on the table.
SQL> ALTER TABLE sales MOVE PARTITION sales_q2_1998 TABLESPACE users
2  UPDATE INDEXES ONLINE;
Table altered.

Interval Reference Partitioning

In Oracle 11g Interval as well as Reference partitioning methods were introduced. In 12c we take this one step further and combine both those partitioning methods into one. So we can now have a child table to be referenced partitioned based on a parent table which has interval partitioning defined for it.
So two things to keep in mind.
Whenever an interval partition is created in the parent table a partition is also created in the referenced child table and the  partition name inherited from the parent table.
Partitions in the child table corresponding to partitions in the parent table are created when rows are inserted into the child table.
Let us look an example using the classic ORDERS and ORDER_ITEMS table which have a parent-child relationship and the parent ORDERS table has been interval partitioned.
CREATE TABLE "OE"."ORDERS_PART"
 (    
"ORDER_ID" NUMBER(12,0) NOT NULL,
"ORDER_DATE" TIMESTAMP (6)  CONSTRAINT "ORDER_PART_DATE_NN" NOT NULL ENABLE,
"ORDER_MODE" VARCHAR2(8),
"CUSTOMER_ID" NUMBER(6,0) ,
"ORDER_STATUS" NUMBER(2,0),
"ORDER_TOTAL" NUMBER(8,2),
"SALES_REP_ID" NUMBER(6,0),
"PROMOTION_ID" NUMBER(6,0),
CONSTRAINT ORDERS_PART_pk PRIMARY KEY (ORDER_ID)
)
PARTITION BY RANGE (ORDER_DATE)
INTERVAL (NUMTOYMINTERVAL(1,'YEAR'))
(PARTITION P_2006 VALUES LESS THAN (TIMESTAMP'2007-01-01 00:00:00 +00:00'),
PARTITION P_2007 VALUES LESS THAN (TIMESTAMP'2008-01-01 00:00:00 +00:00'),
PARTITION P_2008 VALUES LESS THAN (TIMESTAMP'2009-01-01 00:00:00 +00:00')
)
;

CREATE TABLE "OE"."ORDER_ITEMS_PART"
(    
"ORDER_ID" NUMBER(12,0) NOT NULL,
"LINE_ITEM_ID" NUMBER(3,0) NOT NULL ENABLE,
"PRODUCT_ID" NUMBER(6,0) NOT NULL ENABLE,
"UNIT_PRICE" NUMBER(8,2),
"QUANTITY" NUMBER(8,0),
CONSTRAINT "ORDER_ITEMS_PART_FK" FOREIGN KEY ("ORDER_ID")
REFERENCES "OE"."ORDERS_PART" ("ORDER_ID") ON DELETE CASCADE )
PARTITION BY REFERENCE (ORDER_ITEMS_PART_FK)
;

Note the partitions in the parent table
SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDERS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008

We can see that the child table has inherited the same partitions from the parent table
SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDER_ITEMS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
We now insert a new row into the table which leads to the creation of a new partition automatically
SQL> INSERT INTO ORDERS_PART
  2   VALUES
  3   (9999,'17-MAR-15 01.00.00.000000 PM', 'DIRECT',147,5,1000,163,NULL);

1 row created.

SQL> COMMIT;

Commit complete.

SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDERS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
SYS_P301

Note at this point the child table still has only 3 partitions and a new partition corresponding to the parent table will only be created when rows are inserted into the child table.
We now insert some rows into the child table – note that the row insertions leads to a new partition being created in the child table corresponding to the parent table.
SQL> INSERT INTO ORDER_ITEMS_PART
  2  VALUES
  3  (9999,1,2289,10,100);

1 row created.

SQL> INSERT INTO ORDER_ITEMS_PART
  2   VALUES
  3  (9999,2,2268,500,1);

1 row created.

SQL> COMMIT;

Commit complete.

SQL> SELECT PARTITION_NAME FROM USER_TAB_PARTITIONS WHERE TABLE_NAME='ORDER_ITEMS_PART';

PARTITION_NAME
--------------------------------------------------------------------------------------------------------------------------------
P_2006
P_2007
P_2008
SYS_P301

TRUNCATE CASCADE

In Oracle 12c we can add the CASCADE option to the TRUNCATE TABLE or ALTER TABLE TRUNCATE PARTITION commands.
The CASCADE option will truncate all child tables which reference the parent table and also where the referential constraint has been created with the ON DELETE CASCADE option.
The TRUNCATE CASCADE when used at the partition level in a reference partition model will also cascade to the partitions in the child table as shown in the example below.
SQL> alter table orders_part truncate partition SYS_P301 cascade;

Table truncated.


SQL> select count(*) from orders_part partition (SYS_P301);

  COUNT(*)
----------
         0

SQL>  select count(*) from order_items_part partition (SYS_P301);

  COUNT(*)
----------
         0

Multi-Partition Maintenance Operations
In Oracle 12c we can add, truncate or drop multiple partitions as part of a single operation.
In versions prior to 12c, the SPLIT and MERGE PARTITION operations could only be carried out on two partitions at a time. If we had a table with 10 partitions which say we needed to merge, we had to issue 9 separate DDL statements
Now with a single command we can roll out data into smaller partitions or roll up data into a larger partition.
CREATE TABLE sales
( prod_id       NUMBER(6)
, cust_id       NUMBER
, time_id       DATE
, channel_id    CHAR(1)
, promo_id      NUMBER(6)
, quantity_sold NUMBER(3)
, amount_sold   NUMBER(10,2)
)
PARTITION BY RANGE (time_id)
( PARTITION sales_q1_2014 VALUES LESS THAN (TO_DATE('01-APR-2014','dd-MON-yyyy'))
, PARTITION sales_q2_2014 VALUES LESS THAN (TO_DATE('01-JUL-2014','dd-MON-yyyy'))
, PARTITION sales_q3_2014 VALUES LESS THAN (TO_DATE('01-OCT-2014','dd-MON-yyyy'))
, PARTITION sales_q4_2014 VALUES LESS THAN (TO_DATE('01-JAN-2015','dd-MON-yyyy'))
);


ALTER TABLE sales ADD
PARTITION sales_q1_2015 VALUES LESS THAN (TO_DATE('01-APR-2015','dd-MON-yyyy')),
PARTITION sales_q2_2015 VALUES LESS THAN (TO_DATE('01-JUL-2015','dd-MON-yyyy')),
PARTITION sales_q3_2015 VALUES LESS THAN (TO_DATE('01-OCT-2015','dd-MON-yyyy')),
PARTITION sales_q4_2015 VALUES LESS THAN (TO_DATE('01-JAN-2016','dd-MON-yyyy'));


SQL>  ALTER TABLE sales MERGE PARTITIONS sales_q1_2015,sales_q2_2015,sales_q3_2015,sales_q4_2015  INTO PARTITION sales_2015;

Table altered.

SQL>  ALTER TABLE sales SPLIT PARTITION sales_2015 INTO
  2  (PARTITION sales_q1_2015 VALUES LESS THAN (TO_DATE('01-APR-2015','dd-MON-yyyy')),
  3  PARTITION sales_q2_2015 VALUES LESS THAN (TO_DATE('01-JUL-2015','dd-MON-yyyy')),
  4  PARTITION sales_q3_2015 VALUES LESS THAN (TO_DATE('01-OCT-2015','dd-MON-yyyy')),
  5  PARTITION sales_q4_2015);

Table altered.

Partial Indexing

In Oracle 12c we can now have a case where only certain partitions of the table are indexed while the other partitions do not have any indexes. For example we may want the recent partitions which are subject to lots of OLTP type operations to not have any indexes in order to speed up insert activity while the older partitions of the table are subject to DSS type queries and would benefit from indexing.
We can turn indexing on or off at the table level and then enable or disable it selectively at the partition level.
Have a look at the example below.
CREATE TABLE "SH"."SALES_12C"
(
"PROD_ID" NUMBER NOT NULL ENABLE,
"CUST_ID" NUMBER NOT NULL ENABLE,
"TIME_ID" DATE NOT NULL ENABLE,
"CHANNEL_ID" NUMBER NOT NULL ENABLE,
"PROMO_ID" NUMBER NOT NULL ENABLE,
"QUANTITY_SOLD" NUMBER(10,2) NOT NULL ENABLE,
"AMOUNT_SOLD" NUMBER(10,2) NOT NULL ENABLE
) 
TABLESPACE "EXAMPLE"
INDEXING OFF
PARTITION BY RANGE ("TIME_ID")
(PARTITION "SALES_1995"  VALUES LESS THAN (TO_DATE(' 1996-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1996"  VALUES LESS THAN (TO_DATE(' 1997-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1997"  VALUES LESS THAN (TO_DATE(' 1998-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1998"  VALUES LESS THAN (TO_DATE(' 1999-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_1999"  VALUES LESS THAN (TO_DATE(' 2000-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) ,
PARTITION "SALES_2000"  VALUES LESS THAN (TO_DATE(' 2001-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON,
PARTITION "SALES_2001"  VALUES LESS THAN (TO_DATE(' 2002-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON,
PARTITION "SALES_2002"  VALUES LESS THAN (TO_DATE(' 2003-01-01 00:00:00', 'SYYYY-MM-DD HH24:MI:SS')) INDEXING ON
 )
;

Create a local partitioned index on the table and note the size of the local index.
SQL> CREATE INDEX SALES_12C_IND ON SALES_12C (TIME_ID) LOCAL;

Index created.


SQL> SELECT SUM(BYTES)/1048576 FROM USER_SEGMENTS WHERE SEGMENT_NAME='SALES_12C_IND';

SUM(BYTES)/1048576
------------------
                32

We drop the index and create the same index, but this time as a partial index. Since the index has only been created on a few partitions of the table and not the entire table, it is half the size of the original index.
SQL> CREATE INDEX SALES_12C_IND ON SALES_12C (TIME_ID) LOCAL INDEXING PARTIAL;

Index created.

SQL> SELECT SUM(BYTES)/1048576 FROM USER_SEGMENTS WHERE SEGMENT_NAME='SALES_12C_IND';

SUM(BYTES)/1048576
------------------
                16

We can see that for the partitions where indexing is not enabled, the index has been created as UNUSABLE.
SQL> SELECT PARTITION_NAME,STATUS FROM USER_IND_PARTITIONS WHERE INDEX_NAME='SALES_12C_IND';

PARTITION_NAME                 STATUS
------------------------------ --------
SALES_2002                     USABLE
SALES_2001                     USABLE
SALES_2000                     USABLE
SALES_1999                     UNUSABLE
SALES_1998                     UNUSABLE
SALES_1997                     UNUSABLE
SALES_1996                     UNUSABLE
SALES_1995                     UNUSABLE

Note the difference in the EXPLAIN PLAN between two queries – which access different partitions of the same table and in one case use the local partial index and in the other case performs a full table scan.
SQL>  EXPLAIN PLAN FOR
  2  SELECT SUM(QUantity_sold) from sales_12c
  3  where time_id <'01-JAN-97'; Explained. SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2557626605

-------------------------------------------------------------------------------------------------------
| Id  | Operation                 | Name      | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT          |           |     1 |    11 |  1925   (1)| 00:00:01 |       |       |
|   1 |  SORT AGGREGATE           |           |     1 |    11 |            |          |       |       |
|   2 |   PARTITION RANGE ITERATOR|           |   472 |  5192 |  1925   (1)| 00:00:01 |     1 |   KEY |
|*  3 |    TABLE ACCESS FULL      | SALES_12C |   472 |  5192 |  1925   (1)| 00:00:01 |     1 |   KEY |





SQL>  EXPLAIN PLAN FOR
  2   SELECT SUM(QUantity_sold) from sales_12c
  3  where time_id='01-JAN-97';

Explained.

SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------
Plan hash value: 2794067059

--------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                      | Name          | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                               |               |     1 |    22 |     2   (0)| 00:00:01 |       |       |
|   1 |  SORT AGGREGATE                                |               |     1 |    22 |            |          |       |       |
|   2 |   VIEW                                         | VW_TE_2       |     2 |    26 |     2   (0)| 00:00:01 |       |       |
|   3 |    UNION-ALL                                   |               |       |       |            |          |       |       |
|*  4 |     FILTER                                     |               |       |       |            |          |       |       |
|   5 |      PARTITION RANGE SINGLE                    |               |     1 |    22 |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|   6 |       TABLE ACCESS BY LOCAL INDEX ROWID BATCHED| SALES_12C     |     1 |    22 |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|*  7 |        INDEX RANGE SCAN                        | SALES_12C_IND |     1 |       |     1   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|*  8 |     FILTER                                     |               |       |       |            |          |       |       |
|   9 |      PARTITION RANGE SINGLE                    |               |     1 |    22 |     2   (0)| 00:00:01 |KEY(AP)|KEY(AP)|
|* 10 |       TABLE ACCESS FULL                        | SALES_12C     |     1 |    22 |     2   (0)| 00:00:01 |KEY(AP)|KEY(AP)|


--------------------------------------------------------------------------------------------------------------------------------

Note the new columns INDEXING and DEF_INDEXING in the data dictionary views
SQL> select def_indexing from user_part_tables where table_name='SALES_12C';

DEF
---
OFF


SQL> select indexing from user_indexes where index_name='SALES_12C_IND';

INDEXIN
-------
PARTIAL

Asynchronous Global Index Maintenance
In earlier versions operations like TRUNCATE or DROP PARTITION on even a single partition would render the global indexes unusable and would require the indexes to be rebuilt before the application could use the indexes.
Now when we issue the same DROP or TRUNCATE partition commands we can use the UPDATE INDEXES clause and this maintains the global indexes leaving them in a USABLE state.
The global index maintenance is now deferred and is performed by a DBMS_SCHEDULER job called SYS.PMO_DEFERRED_GIDX_MAINT_JOB which is scheduled to run at 2.00 AM on a daily basis.
We can also use the DBMS_PART package which has the CLEANUP_GIDX procedure which cleans up the global indexes.
A new column ORPHANED_ENTRIES in the DBA|USER|ALL_INDEXES view keeps a track of the global index and specifies if the global index partition contains any stale entries caused by the DROP/TRUNCATE PARTITION operation.
Let us look at an example of the same. Note the important point that the global index is left in a USABLE state even after we perform a TRUNCATE operation on the partitioned table.
SQL>  alter table sales_12c truncate partition SALES_2000 UPDATE INDEXES;

Table truncated.

SQL> select distinct status from user_ind_partitions;

STATUS
--------
USABLE


SQL> select partition_name, ORPHANED_ENTRIES from user_ind_partitions
  2  where index_name='SALES_GIDX';

PARTITION_NAME                 ORP
------------------------------ ---
SYS_P348                       YES
SYS_P347                       YES
SYS_P346                       YES
SYS_P345                       YES
SYS_P344                       YES
SYS_P343                       YES
SYS_P342                       YES
SYS_P341                       YES



SQL> exec dbms_part.cleanup_gidx('SH','SALES_12C');

PL/SQL procedure successfully completed.

SQL> select partition_name, ORPHANED_ENTRIES from user_ind_partitions
  2  where index_name='SALES_GIDX';

PARTITION_NAME                 ORP
------------------------------ ---
SYS_P341                       NO
SYS_P342                       NO
SYS_P343                       NO
SYS_P344                       NO
SYS_P345                       NO
SYS_P346                       NO
SYS_P347                       NO
SYS_P348                       NO

ORACLE 12C PLUGGABLE DATABASE UPGRADE

Until very recently I had really believed the marketing hype and sales pitch about how in 12c database upgrades are so much faster and easier than earlier releases – just unplug the PDB from one container and plug it in to another container and bingo you have an upgraded database!
Partly true …. maybe about 20%!
As Mike Dietrich from Oracle Corp. has rightly pointed out on his great blog (http://blogs.oracle.com/upgrade),it is not as straight forward as pointed out in slides seen I am sure by many of us at various Oracle conferences showcasing Oracle database 12c.
I tested out the upgrade of a PDB from version 12.1.0.1 to the latest 12c version 12.1.0.2 and here are the steps taken.
Note: If we are upgrading the entire CDB and all the PDB’s the steps would be different.
In this case we are upgrading just of the pluggable databases to a higher database software version.
 

Run the preupgrd.sql script and pre-upgrade fixup script


Connect to the 12.1.0.1 target database and run the preupgrd.sql script.
The source container database is cdb3 and the PDB which we are upgrading is pdb_gavin.
[oracle@edmbr52p5 ~]$ . oraenv
ORACLE_SID = [cdb1] ? cdb3

The Oracle base for ORACLE_HOME=/u01/app/oracle/product/12.1.0.1/dbhome_1 is /u01/app/oracle
[oracle@edmbr52p5 ~]$ sqlplus sys as sysdba

SQL*Plus: Release 12.1.0.1.0 Production on Fri Aug 21 10:49:21 2015

Copyright (c) 1982, 2013, Oracle.  All rights reserved.

Enter password:

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

SQL> alter session set container=pdb_gavin;

Session altered.

SQL> @?/rdbms/admin/preupgrd.sql
Loading Pre-Upgrade Package...
Executing Pre-Upgrade Checks...
Pre-Upgrade Checks Complete.
      ************************************************************

Results of the checks are located at:
 /u01/app/oracle/cfgtoollogs/cdb3/preupgrade/preupgrade.log

Pre-Upgrade Fixup Script (run in source database environment):
 /u01/app/oracle/cfgtoollogs/cdb3/preupgrade/preupgrade_fixups.sql

Post-Upgrade Fixup Script (run shortly after upgrade):
 /u01/app/oracle/cfgtoollogs/cdb3/preupgrade/postupgrade_fixups.sql

      ************************************************************

         Fixup scripts must be reviewed prior to being executed.

      ************************************************************

      ************************************************************
                   ====>> USER ACTION REQUIRED  <<====
      ************************************************************

 The following are *** ERROR LEVEL CONDITIONS *** that must be addressed
                    prior to attempting your upgrade.
            Failure to do so will result in a failed upgrade.


 1) Check Tag:    OLS_SYS_MOVE
    Check Summary: Check if SYSTEM.AUD$ needs to move to SYS.AUD$ before upgrade
    Fixup Summary:
     "Execute olspreupgrade.sql script prior to upgrade."
    +++ Source Database Manual Action Required +++

            You MUST resolve the above error prior to upgrade

      ************************************************************

The execution of the preupgrd.sql script will generate 3 separate files.
1)preupgrade.log
2)preupgrade_fixups.sql
3)postupgrade_fixups.sql
Let us examine the contents of the preupgrade.log file.
Oracle Database Pre-Upgrade Information Tool 08-21-2015 10:50:04
Script Version: 12.1.0.1.0 Build: 006
**********************************************************************
   Database Name:  CDB3
         Version:  12.1.0.1.0
      Compatible:  12.1.0.0.0
       Blocksize:  8192
        Platform:  Linux x86 64-bit
   Timezone file:  V18
**********************************************************************
                          [Renamed Parameters]
                     [No Renamed Parameters in use]
**********************************************************************
**********************************************************************
                    [Obsolete/Deprecated Parameters]
             [No Obsolete or Desupported Parameters in use]
**********************************************************************
                            [Component List]
**********************************************************************
--> Oracle Catalog Views                   [upgrade]  VALID
--> Oracle Packages and Types              [upgrade]  VALID
--> JServer JAVA Virtual Machine           [upgrade]  VALID
--> Oracle XDK for Java                    [upgrade]  VALID
--> Real Application Clusters              [upgrade]  OPTION OFF
--> Oracle Workspace Manager               [upgrade]  VALID
--> OLAP Analytic Workspace                [upgrade]  VALID
--> Oracle Label Security                  [upgrade]  VALID
--> Oracle Database Vault                  [upgrade]  VALID
--> Oracle Text                            [upgrade]  VALID
--> Oracle XML Database                    [upgrade]  VALID
--> Oracle Java Packages                   [upgrade]  VALID
--> Oracle Multimedia                      [upgrade]  VALID
--> Oracle Spatial                         [upgrade]  VALID
--> Oracle Application Express             [upgrade]  VALID
--> Oracle OLAP API                        [upgrade]  VALID
**********************************************************************
           [ Unsupported Upgrade: Tablespace Data Supressed ]
**********************************************************************
**********************************************************************
                          [Pre-Upgrade Checks]
**********************************************************************
ERROR: --> SYSTEM.AUD$ (audit records) Move

    An error occured retrieving a count from SYSTEM.AUD$
    This can happen when the table has already been cleaned up.
    The olspreupgrade.sql script should be re-executed.



WARNING: --> Existing DBMS_LDAP dependent objects

     Database contains schemas with objects dependent on DBMS_LDAP package.
     Refer to the Upgrade Guide for instructions to configure Network ACLs.
     USER APEX_040200 has dependent objects.


**********************************************************************
                      [Pre-Upgrade Recommendations]
**********************************************************************

                        *****************************************
                        ********* Dictionary Statistics *********
                        *****************************************

Please gather dictionary statistics 24 hours prior to
upgrading the database.
To gather dictionary statistics execute the following command
while connected as SYSDBA:
    EXECUTE dbms_stats.gather_dictionary_stats;

^^^ MANUAL ACTION SUGGESTED ^^^

**********************************************************************
                     [Post-Upgrade Recommendations]
**********************************************************************

                        *****************************************
                        ******** Fixed Object Statistics ********
                        *****************************************

Please create stats on fixed objects two weeks
after the upgrade using the command:
   EXECUTE DBMS_STATS.GATHER_FIXED_OBJECTS_STATS;

^^^ MANUAL ACTION SUGGESTED ^^^

**********************************************************************
                   ************  Summary  ************

 1 ERROR exist that must be addressed prior to performing your upgrade.
 2 WARNINGS that Oracle suggests are addressed to improve database performance.
 0 INFORMATIONAL messages messages have been reported.

 After your database is upgraded and open in normal mode you must run
 rdbms/admin/catuppst.sql which executes several required tasks and completes
 the upgrade process.

 You should follow that with the execution of rdbms/admin/utlrp.sql, and a
 comparison of invalid objects before and after the upgrade using
 rdbms/admin/utluiobj.sql

 If needed you may want to upgrade your timezone data using the process
 described in My Oracle Support note 977512.1
                   ***********************************

So as part of the pre-upgrade preparation we execute :
SQL> @?/rdbms/admin/olspreupgrade.sql

and 

SQL>  EXECUTE dbms_stats.gather_dictionary_stats;

Unplug the PDB from the 12.1.0.1 Container Database

SQL>  alter session set container=CDB$ROOT;

Session altered.

SQL> alter pluggable database  pdb_gavin unplug into '/home/oracle/pdb_gavin.xml';

Pluggable database altered

Create the PDB in the 12.1.0.2 Container Database

[oracle@edmbr52p5 ~]$ . oraenv
ORACLE_SID = [cdb2] ? cdb1
The Oracle base for ORACLE_HOME=/u01/app/oracle/product/12.1.0/dbhome_1 is /u01/app/oracle

[oracle@edmb]$ sqlplus sys as sysdba

SQL*Plus: Release 12.1.0.2.0 Production on Fri Aug 21 12:04:10 2015

Copyright (c) 1982, 2014, Oracle.  All rights reserved.

Enter password:

Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production
With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options


SQL> show con_name

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


SQL> create pluggable database pdb_gavin
  2   using '/home/oracle/pdb_gavin.xml'
  3  nocopy
  4  tempfile reuse;

Pluggable database created..

Upgrade the PDB to 12.1.0.2

After the pluggable database has been created in the 12.1.0.2 container, we will open it with the UPGRADE option in order to run the catupgrd.sql database upgrade script.
We can see that we receive some errors which we can ignore safely as we are in the middle of an upgrade to the PDB.
SQL> alter pluggable database pdb_gavin open upgrade;

Warning: PDB altered with errors.


SQL> select message, status from pdb_plug_in_violations where type like '%ERR%';

MESSAGE
--------------------------------------------------------------------------------
STATUS
---------
Character set mismatch: PDB character set US7ASCII. CDB character set AL32UTF8.
RESOLVED

PDB's version does not match CDB's version: PDB's version 12.1.0.1.0. CDB's vers
ion 12.1.0.2.0.
PENDING

We now run the catctl.pl perl script and we specify the PDB name (if we were upgrading multiple PDBs hee we would separate each PDB name with a comma) – not that we are also running the upgrade in parallel.
[oracle@edm ~]$ cd $ORACLE_HOME/rdbms/admin
[oracle@edm admin]$ $ORACLE_HOME/perl/bin/perl catctl.pl -c "PDB_GAVIN" -n 4 -l /tmp catupgrd.sql

Argument list for [catctl.pl]
SQL Process Count     n = 4
SQL PDB Process Count N = 0
Input Directory       d = 0
Phase Logging Table   t = 0
Log Dir               l = /tmp
Script                s = 0
Serial Run            S = 0
Upgrade Mode active   M = 0
Start Phase           p = 0
End Phase             P = 0
Log Id                i = 0
Run in                c = PDB_GAVIN
Do not run in         C = 0
Echo OFF              e = 1
No Post Upgrade       x = 0
Reverse Order         r = 0
Open Mode Normal      o = 0
Debug catcon.pm       z = 0
Debug catctl.pl       Z = 0
Display Phases        y = 0
Child Process         I = 0

catctl.pl version: 12.1.0.2.0
Oracle Base           = /u01/app/oracle

Analyzing file catupgrd.sql
Log files in /tmp
catcon: ALL catcon-related output will be written to /tmp/catupgrd_catcon_19456.lst
catcon: See /tmp/catupgrd*.log files for output generated by scripts
catcon: See /tmp/catupgrd_*.lst files for spool files, if any
Number of Cpus        = 8
Parallel PDB Upgrades = 2
SQL PDB Process Count = 2
SQL Process Count     = 4

[CONTAINER NAMES]

CDB$ROOT
PDB$SEED
PDB1_1
PDB_GAVIN
PDB Inclusion:[PDB_GAVIN] Exclusion:[]

Starting
[/u01/app/oracle/product/12.1.0/dbhome_1/perl/bin/perl catctl.pl -c 'PDB_GAVIN' -n 2 -l /tmp -I -i pdb_gavin catupgrd.sql]

Argument list for [catctl.pl]
SQL Process Count     n = 2
SQL PDB Process Count N = 0
Input Directory       d = 0
Phase Logging Table   t = 0
Log Dir               l = /tmp
Script                s = 0
Serial Run            S = 0
Upgrade Mode active   M = 0
Start Phase           p = 0
End Phase             P = 0
Log Id                i = pdb_gavin
Run in                c = PDB_GAVIN
Do not run in         C = 0
Echo OFF              e = 1
No Post Upgrade       x = 0
Reverse Order         r = 0
Open Mode Normal      o = 0
Debug catcon.pm       z = 0
Debug catctl.pl       Z = 0
Display Phases        y = 0
Child Process         I = 1

catctl.pl version: 12.1.0.2.0
Oracle Base           = /u01/app/oracle

Analyzing file catupgrd.sql
Log files in /tmp
catcon: ALL catcon-related output will be written to /tmp/catupgrdpdb_gavin_catcon_19562.lst
catcon: See /tmp/catupgrdpdb_gavin*.log files for output generated by scripts
catcon: See /tmp/catupgrdpdb_gavin_*.lst files for spool files, if any
Number of Cpus        = 8
SQL PDB Process Count = 2
SQL Process Count     = 2

[CONTAINER NAMES]

CDB$ROOT
PDB$SEED
PDB1_1
PDB_GAVIN
PDB Inclusion:[PDB_GAVIN] Exclusion:[]

------------------------------------------------------
Phases [0-73]
Container Lists Inclusion:[PDB_GAVIN] Exclusion:[]
Serial   Phase #: 0 Files: 1     Time: 15s   PDB_GAVIN
Serial   Phase #: 1 Files: 5     Time: 107s  PDB_GAVIN
Restart  Phase #: 2 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #: 3 Files: 18    Time: 40s   PDB_GAVIN
Restart  Phase #: 4 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #: 5 Files: 5     Time: 43s   PDB_GAVIN
Serial   Phase #: 6 Files: 1     Time: 18s   PDB_GAVIN
Serial   Phase #: 7 Files: 4     Time: 11s   PDB_GAVIN
Restart  Phase #: 8 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #: 9 Files: 62    Time: 110s  PDB_GAVIN
Restart  Phase #:10 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:11 Files: 1     Time: 28s   PDB_GAVIN
Restart  Phase #:12 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:13 Files: 91    Time: 8s    PDB_GAVIN
Restart  Phase #:14 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:15 Files: 111   Time: 15s   PDB_GAVIN
Restart  Phase #:16 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:17 Files: 3     Time: 2s    PDB_GAVIN
Restart  Phase #:18 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:19 Files: 32    Time: 43s   PDB_GAVIN
Restart  Phase #:20 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:21 Files: 3     Time: 11s   PDB_GAVIN
Restart  Phase #:22 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:23 Files: 23    Time: 75s   PDB_GAVIN
Restart  Phase #:24 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:25 Files: 11    Time: 25s   PDB_GAVIN
Restart  Phase #:26 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:27 Files: 1     Time: 1s    PDB_GAVIN
Restart  Phase #:28 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:30 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:31 Files: 257   Time: 29s   PDB_GAVIN
Serial   Phase #:32 Files: 1     Time: 0s    PDB_GAVIN
Restart  Phase #:33 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:34 Files: 1     Time: 3s    PDB_GAVIN
Restart  Phase #:35 Files: 1     Time: 0s    PDB_GAVIN
Restart  Phase #:36 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:37 Files: 4     Time: 62s   PDB_GAVIN
Restart  Phase #:38 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:39 Files: 13    Time: 33s   PDB_GAVIN
Restart  Phase #:40 Files: 1     Time: 0s    PDB_GAVIN
Parallel Phase #:41 Files: 10    Time: 5s    PDB_GAVIN
Restart  Phase #:42 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:43 Files: 1     Time: 7s    PDB_GAVIN
Restart  Phase #:44 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:45 Files: 1     Time: 1s    PDB_GAVIN
Serial   Phase #:46 Files: 1     Time: 0s    PDB_GAVIN
Restart  Phase #:47 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:48 Files: 1     Time: 71s   PDB_GAVIN
Restart  Phase #:49 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:50 Files: 1     Time: 9s    PDB_GAVIN
Restart  Phase #:51 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:52 Files: 1     Time: 41s   PDB_GAVIN
Restart  Phase #:53 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:54 Files: 1     Time: 51s   PDB_GAVIN
Restart  Phase #:55 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:56 Files: 1     Time: 36s   PDB_GAVIN
Restart  Phase #:57 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:58 Files: 1     Time: 37s   PDB_GAVIN
Restart  Phase #:59 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:60 Files: 1     Time: 48s   PDB_GAVIN
Restart  Phase #:61 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:62 Files: 1     Time: 112s  PDB_GAVIN
Restart  Phase #:63 Files: 1     Time: 0s    PDB_GAVIN
Serial   Phase #:64 Files: 1     Time: 1s    PDB_GAVIN
Serial   Phase #:65 Files: 1 Calling sqlpatch with LD_LIBRARY_PATH=/u01/app/oracle/product/12.1.0/dbhome_1/lib; export LD_LIBRARY_PATH;/u01/app/oracle/product/12.1.0/dbhome_1/perl/bin/perl -I /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin -I /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin/../../sqlpatch /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin/../../sqlpatch/sqlpatch.pl -verbose -upgrade_mode_only -pdbs PDB_GAVIN > /tmp/catupgrdpdb_gavin_datapatch_upgrade.log 2> /tmp/catupgrdpdb_gavin_datapatch_upgrade.err
returned from sqlpatch
    Time: 3s    PDB_GAVIN
Serial   Phase #:66 Files: 1     Time: 1s    PDB_GAVIN
Serial   Phase #:68 Files: 1     Time: 12s   PDB_GAVIN
Serial   Phase #:69 Files: 1 Calling sqlpatch with LD_LIBRARY_PATH=/u01/app/oracle/product/12.1.0/dbhome_1/lib; export LD_LIBRARY_PATH;/u01/app/oracle/product/12.1.0/dbhome_1/perl/bin/perl -I /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin -I /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin/../../sqlpatch /u01/app/oracle/product/12.1.0/dbhome_1/rdbms/admin/../../sqlpatch/sqlpatch.pl -verbose -pdbs PDB_GAVIN > /tmp/catupgrdpdb_gavin_datapatch_normal.log 2> /tmp/catupgrdpdb_gavin_datapatch_normal.err
returned from sqlpatch
    Time: 3s    PDB_GAVIN
Serial   Phase #:70 Files: 1     Time: 30s   PDB_GAVIN
Serial   Phase #:71 Files: 1     Time: 4s    PDB_GAVIN
Serial   Phase #:72 Files: 1     Time: 3s    PDB_GAVIN
Serial   Phase #:73 Files: 1     Time: 0s    PDB_GAVIN

Grand Total Time: 1155s PDB_GAVIN

LOG FILES: (catupgrdpdb_gavin*.log)

Upgrade Summary Report Located in:
/u01/app/oracle/product/12.1.0/dbhome_1/cfgtoollogs/cdb1/upgrade/upg_summary.log

Total Upgrade Time:          [0d:0h:19m:15s]

     Time: 1156s For PDB(s)

Grand Total Time: 1156s

LOG FILES: (catupgrd*.log)

Grand Total Upgrade Time:    [0d:0h:19m:16s]
[oracle@edmbr52p5 admin]$


Run the post upgrade steps

We then start the PDB and run the post-upgrade steps which includes recompiling all the invalid objects and also gathering fresh statistics on the fixed dictionary objects.
That completes the PDB upgrade – not quite a simple plug and unplug!!
SQL> startup;
Pluggable Database opened.


SQL> @?/rdbms/admin/utlrp.sql

TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_BGN  2015-08-21 12:35:42

DOC>   The following PL/SQL block invokes UTL_RECOMP to recompile invalid
DOC>   objects in the database. Recompilation time is proportional to the
DOC>   number of invalid objects in the database, so this command may take
DOC>   a long time to execute on a database with a large number of invalid
DOC>   objects.
DOC>
DOC>   Use the following queries to track recompilation progress:
DOC>
DOC>   1. Query returning the number of invalid objects remaining. This
DOC>      number should decrease with time.
DOC>         SELECT COUNT(*) FROM obj$ WHERE status IN (4, 5, 6);
DOC>
DOC>   2. Query returning the number of objects compiled so far. This number
DOC>      should increase with time.
DOC>         SELECT COUNT(*) FROM UTL_RECOMP_COMPILED;
DOC>
DOC>   This script automatically chooses serial or parallel recompilation
DOC>   based on the number of CPUs available (parameter cpu_count) multiplied
DOC>   by the number of threads per CPU (parameter parallel_threads_per_cpu).
DOC>   On RAC, this number is added across all RAC nodes.
DOC>
DOC>   UTL_RECOMP uses DBMS_SCHEDULER to create jobs for parallel
DOC>   recompilation. Jobs are created without instance affinity so that they
DOC>   can migrate across RAC nodes. Use the following queries to verify
DOC>   whether UTL_RECOMP jobs are being created and run correctly:
DOC>
DOC>   1. Query showing jobs created by UTL_RECOMP
DOC>         SELECT job_name FROM dba_scheduler_jobs
DOC>            WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>
DOC>   2. Query showing UTL_RECOMP jobs that are running
DOC>         SELECT job_name FROM dba_scheduler_running_jobs
DOC>            WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>#

PL/SQL procedure successfully completed.


TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_END  2015-08-21 12:36:02

DOC> The following query reports the number of objects that have compiled
DOC> with errors.
DOC>
DOC> If the number is higher than expected, please examine the error
DOC> messages reported with each object (using SHOW ERRORS) to see if they
DOC> point to system misconfiguration or resource constraints that must be
DOC> fixed before attempting to recompile these objects.
DOC>#

OBJECTS WITH ERRORS
-------------------
                  0

DOC> The following query reports the number of errors caught during
DOC> recompilation. If this number is non-zero, please query the error
DOC> messages in the table UTL_RECOMP_ERRORS to see if any of these errors
DOC> are due to misconfiguration or resource constraints that must be
DOC> fixed before objects can compile successfully.
DOC>#

ERRORS DURING RECOMPILATION
---------------------------
                          0


Function created.


PL/SQL procedure successfully completed.


Function dropped.

...Database user "SYS", database schema "APEX_040200", user# "98" 12:36:13
...Compiled 0 out of 3014 objects considered, 0 failed compilation 12:36:13
...271 packages
...263 package bodies
...452 tables
...11 functions
...16 procedures
...3 sequences
...457 triggers
...1320 indexes
...211 views
...0 libraries
...6 types
...0 type bodies
...0 operators
...0 index types
...Begin key object existence check 12:36:13
...Completed key object existence check 12:36:13
...Setting DBMS Registry 12:36:13
...Setting DBMS Registry Complete 12:36:13
...Exiting validate 12:36:13

PL/SQL procedure successfully completed.

SQL>

SQL> EXECUTE DBMS_STATS.GATHER_FIXED_OBJECTS_STATS;

PL/SQL procedure successfully completed.



SQL> SELECT NAME,OPEN_MODE FROM V$PDBS;

NAME                           OPEN_MODE
------------------------------ ----------
PDB$SEED                       READ ONLY
PDB_GAVIN                      READ WRITE

ORACLE 12C RMAN DUPLICATE DATABASE

In earlier versions the RMAN DUPLICATE database command was a push-based method. One of the new features in Oracle 12c is that it has been changed to a pull-based method which has many advantages. Let us note the difference between the two methods.
In the earlier push-based method, the source database transfers the required database files to the auxiliary database as image copies. Now let us say we had a tablespace which had a 10GB data file, but the tablespace only contained say about 1 GB of data. Regardless, since it is an image copy, the entire 10 GB data file had to be copied over the network.
Now in Oracle 12c RMAN performs active database duplication using backup sets and not image copies. Taking the earlier example of a tablespace having a 10GB data file but say having only 1 GB of occupied data, only the 1 GB is now copied over the network as a backup set and not the entire 10 GB data file.
With backupsets there are a number of advantages.
So now in Oracle 12c this is what is new in the DUPLICATE …. FROM ACTIVE DATABASE command. And these new features certainly are providing advantages over the earlier pre-12c method.
  • RMAN can employ unused block compression while creating backups, thus reducing the size of backups that are transported over the network (USING BACKUPSET, USING COMPRESSED BACKUPS clause).
  • Using multi-section backups, backup sets can be created in parallel on the source database (SECTION SIZE clause).
  • In addition we can also encrypt backup sets created on the source database via the SET ENCRYPTION command.
Let us look at an example using the pull-based method to create a duplicate database using RMAN backupsets from an active database.
Let us assume source database name is BSPRD and we are creating a clone of this database.
So what all preparation work we have to do for this RMAN Duplicate to work? – same as 11g – this part has not changed.
First and most important thing to do is to do the network part of the work.
Add a static entry in the listener.ora on the target and in the tnsnames.ora file on both database source and target servers add a TNS alias.
Then copy the password file from source to target and rename the file on the target if the ORACLE_SID on target is different to the source.
Create any required directories on the destination host as required if the directory path on the source and target are going to be different – for example we may need to create a directory for audit_dump_dest on the target.
If the ASM disk group names are different then we may have to connect via asmcmd on the target and create any directories we require.
Also don’t forget the DB_FILE_NAME_CONVERT and LOG_FILE_NAME_CONVERT parameters in the target database parameter file if the directory structure is different on the target as compared to the source.
When using the SECTION SIZE parameter take into account the sizes of the data files and the parallelism we are going to use.
In the example I have shown the RMAN parallelism has been set to 4 and two of the bigger data files are 2.2 GB and 1.5 GB – so I have used a section size of 500 MB.
Note – also now when you create the duplicate database via RMAN, we cannot just issue the “TARGET /” command in RMAN.
We have to explicitly provide the user, password as well as the TNS alias for both the target database as well as the auxiliary database.
Like for example:
rman target sys/sys_passwd@bsprd auxiliary sys/sys_passwd@bsprd_dup
Note the RMAN DUPLICATE DATABASE command – it includes the USING BACKUPSET and SECTION SIZE clauses.
Recovery Manager: Release 12.1.0.2.0 - Production on Thu Aug 27 05:27:22 2015
Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved.

connected to target database: BSPRD (DBID=3581332368)
connected to auxiliary database: BSPRD (not mounted)

RMAN> duplicate target database to bsprd from active database
2> using backupset
3> section size 500m;
Note the 4 auxiliary channels being created because we have configured RMAN with a parallelism of 4.
Starting Duplicate Db at 27-AUG-15
using target database control file instead of recovery catalog
allocated channel: ORA_AUX_DISK_1
channel ORA_AUX_DISK_1: SID=19714 device type=DISK
allocated channel: ORA_AUX_DISK_2
channel ORA_AUX_DISK_2: SID=19713 device type=DISK
allocated channel: ORA_AUX_DISK_3
channel ORA_AUX_DISK_3: SID=6 device type=DISK
allocated channel: ORA_AUX_DISK_4
channel ORA_AUX_DISK_4: SID=2820 device type=DISK
current log archived

The SYSTEM tablespace data file was about 2.2 GB in my case. So we can see that RMAN has split this 2.2 GB based on the section size we allocated which was 500 MB. We have 4 auxiliary channels working on ‘sections’ of the single data file in parallel.
channel ORA_AUX_DISK_1: starting datafile backup set restore
channel ORA_AUX_DISK_1: using network backup set from service bsprd
channel ORA_AUX_DISK_1: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_1: restoring datafile 00001 to +OEM_DATA/BSPRD/DATAFILE/system.302.888816535
channel ORA_AUX_DISK_1: restoring section 1 of 5

channel ORA_AUX_DISK_3: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_3: restoring datafile 00001 to +OEM_DATA/BSPRD/DATAFILE/system.302.888816535
channel ORA_AUX_DISK_3: restoring section 2 of 5
channel ORA_AUX_DISK_4: restore complete, elapsed time: 00:00:04


....

....

channel ORA_AUX_DISK_4: using network backup set from service bsprd
channel ORA_AUX_DISK_4: specifying datafile(s) to restore from backup set
channel ORA_AUX_DISK_4: restoring datafile 00001 to +OEM_DATA/BSPRD/DATAFILE/system.302.888816535
channel ORA_AUX_DISK_4: restoring section 5 of 5
channel ORA_AUX_DISK_1: restore complete, elapsed time: 00:00:10

ORACLE 12C RESOURCE MANAGER – CDB AND PDB RESOURCE PLANS


Part One: Creating an Oracle 12c Container Database (CDB) Resource Plan


In a CDB since we have multiple pluggable databases sharing a set of common resources, we can prevent multiple workloads to compete with each other for both system as well as CDB resources by using Resource Manager.

Let us look at an example of managing resources for Pluggable Databases (between PDB’s) at the multitenant Container database level.

The same can be achieved using 12c Cloud Control, but displayed here are the steps to be performed at the command line using the DBMS_RESOURCE_MANAGER package.

With Resource Manager at the Pluggable Database level, we can limit CPU usage of a particular PDB as well as the number of parallel execution servers which a particular PDB can use.

To allocate resources among PDB’s we use a concept of shares where we assign shares to particular PDB’s and a higher share to a PDB results in higher allocation of guaranteed resources to that PDB.

At a high level the steps involved include:

·         Create a Pending Area

·         Create a CDB resource plan

·         Create directives for the PDB’s

·         Optionally update the default directives which will specify resources which any newly created PDB’s will be allocated or which will be used when no directives have been explicitly defined for a particular PDB

·         Optionally update the directives which apply by default to the Automatic Maintenance Tasks which are configured to run in the out of the box maintenance windows

·         Validate the Pending Area

·         Submit the Pending Area

·         Enable the plan at the CDB level by setting the RESOURCE_MANAGER_PLAN parameter

Let us look at an example.

We have 5 Pluggable databases contained in the Container database and we wish to enable resource management at the PDB level.

We wish to guarantee CPU allocation in the ratio 4:3:1:1:1 so that the CPU is distributed among the PDB’s in this manner:

PDBPROD1 : 40%
PDBPROD2:  30%
PDBPROD3:  10%
PDBPROD4 :  10%
PDBPROD5:   10%

Further for PDB’s PDBPROD3, PDBPROD4 and PDBPROD5 we wish to ensure that CPU utilization for these 3 PDB’s never crosses the 70% limit.

Also for these 3 PDB’s we would like to limit the maximum number of parallel execution servers available to the PDB.

The value of 70% means that if the PARALLEL_SERVERS_TARGET initialization parameter is 200, then the PDB cannot use more than a maximum of 140 parallel execution servers. For PDBPROD1 and PDBPROD2 there is no limit, so they can use all 200 parallel execution servers if available.


We also want to limit the resources used by the Automatic Maintenance Tasks jobs when they do execute in a particular job window and also want to specify a default resource allocation limit for newly created PDB’s or those PDB’s where a resource limit directive has not been explicitly defined.



Create the Pending Area


SQL SYS@PRODCDB> exec DBMS_RESOURCE_MANAGER.CREATE_PENDING_AREA();

PL/SQL procedure successfully completed.


Create the CDB resource plan

SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN(
    plan    => 'PRODCDB_PLAN',
    comment => 'CDB resource plan for PRODCDB');
END;
/  2    3    4    5    6

PL/SQL procedure successfully completed.


Create directives which will specify how resources are allocated to each particular PDB


SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD1',
    shares                => 4,
    utilization_limit     => 100,
    parallel_server_limit => 100);
END;
/  2    3    4    5    6    7    8    9

PL/SQL procedure successfully completed.

SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD2',
    shares                => 3,
    utilization_limit     => 100,
    parallel_server_limit => 100);
END;
/  2    3    4    5    6    7    8    9

PL/SQL procedure successfully completed.



SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD3',
    shares                => 2,
    utilization_limit     => 70,
    parallel_server_limit => 70);
END;
/  2    3    4    5    6    7    8    9

PL/SQL procedure successfully completed.

SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
  2    3      plan                  => 'PRODCDB_PLAN',
  4      pluggable_database    => 'PDBPROD4',
  5      shares                => 1,
  6      utilization_limit     => 70,
  7      parallel_server_limit => 70);
  8  END;
  9  /


SQL SYS@PRODCDB> SQL SYS@PRODCDB> SQL SYS@PRODCDB>   2    3      plan                  => 'PRODCDB_PLAN',
  4      pluggable_database    => 'PDBPROD5',
  5      shares                => 1,
  6      utilization_limit     => 70,
  7      parallel_server_limit => 70);
  8  END;
  9  /

PL/SQL procedure successfully completed.



Update (if required) default directive applies to PDBs for which specific directives have not been defined

SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.UPDATE_CDB_DEFAULT_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    new_shares                => 1,
    new_utilization_limit     => 50,
    new_parallel_server_limit => 50);
END;
/  2    3    4    5    6    7    8

PL/SQL procedure successfully completed.



Update the directive (if required) which will limit the resources available to run the Automatic Maintenance Tasks



SQL SYS@PRODCDB> BEGIN
  2    DBMS_RESOURCE_MANAGER.UPDATE_CDB_AUTOTASK_DIRECTIVE(
  3      plan                  => 'PRODCDB_PLAN',
  4      new_shares                => 1,
  5      new_utilization_limit     => 75,
  6      new_parallel_server_limit => 75);
  7  END;
  8  /

PL/SQL procedure successfully completed.


Validate the Pending Area

SQL exec DBMS_RESOURCE_MANAGER.VALIDATE_PENDING_AREA();

PL/SQL procedure successfully completed.

Submit the Pending Area

SQL exec DBMS_RESOURCE_MANAGER.SUBMIT_PENDING_AREA();

PL/SQL procedure successfully completed.


Enable the CDB resource plan

SQL ALTER SYSTEM SET RESOURCE_MANAGER_PLAN = 'PRODCDB_PLAN';

System altered.


If we launch Database Express (or OEM for that matter) we can now see the resource allocation to each of the PDB’s as well as the resource utilization limit which has been imposed on some of the PDB’s.



We can also query the DBA_CDB_RSRC_PLAN_DIRECTIVES view to obtain the same information in some more detail


SQL SYS@PRODCDB> SQL SYS@PRODCDB> SQL SYS@PRODCDB> SQL SYS@PRODCDB> SELECT PLAN,
  2         PLUGGABLE_DATABASE,
  3         SHARES,
  4         UTILIZATION_LIMIT,
  5         PARALLEL_SERVER_LIMIT
  6    FROM DBA_CDB_RSRC_PLAN_DIRECTIVES
  7    ORDER BY PLAN;

                                                                        Parallel
                           Pluggable                        Utilization   Server
Plan                       Database                  Shares       Limit    Limit
-------------------------- ------------------------- ------ ----------- --------
DEFAULT_CDB_PLAN           ORA$AUTOTASK                              90      100
DEFAULT_CDB_PLAN           ORA$DEFAULT_PDB_DIRECTIVE      1         100      100
DEFAULT_MAINTENANCE_PLAN   ORA$AUTOTASK                              90      100
DEFAULT_MAINTENANCE_PLAN   ORA$DEFAULT_PDB_DIRECTIVE      1         100      100

                                                                        Parallel
                           Pluggable                        Utilization   Server
Plan                       Database                  Shares       Limit    Limit
-------------------------- ------------------------- ------ ----------- --------
ORA$INTERNAL_CDB_PLAN      ORA$DEFAULT_PDB_DIRECTIVE
ORA$INTERNAL_CDB_PLAN      ORA$AUTOTASK
ORA$QOS_CDB_PLAN           ORA$AUTOTASK                              90      100
ORA$QOS_CDB_PLAN           ORA$DEFAULT_PDB_DIRECTIVE      1         100      100
PRODCDB_PLAN               PDBPROD3                       2          70       70
PRODCDB_PLAN               PDBPROD5                       1          70       70
PRODCDB_PLAN               PDBPROD2                       3         100      100
PRODCDB_PLAN               PDBPROD1                       4         100      100
PRODCDB_PLAN               PDBPROD4                       1          70       70

                                                                        Parallel
                           Pluggable                        Utilization   Server
Plan                       Database                  Shares       Limit    Limit
-------------------------- ------------------------- ------ ----------- --------
PRODCDB_PLAN               ORA$AUTOTASK                   1          75       75
PRODCDB_PLAN               ORA$DEFAULT_PDB_DIRECTIVE      1          50       50

20 rows selected.







exec DBMS_RESOURCE_MANAGER.CREATE_PENDING_AREA();


BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN(
    plan    => 'PRODCDB_PLAN',
    comment => 'CDB resource plan for PRODCDB');
END;
/


BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD1',
    shares                => 4,
    utilization_limit     => 100,
    parallel_server_limit => 100);
END;
/

BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD2',
    shares                => 3,
    utilization_limit     => 100,
    parallel_server_limit => 100);
END;
/


BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD3',
    shares                => 1,
    utilization_limit     => 70,
    parallel_server_limit => 70);
END;
/


BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD4',
    shares                => 1,
    utilization_limit     => 70,
    parallel_server_limit => 70);
END;
/


BEGIN
  DBMS_RESOURCE_MANAGER.CREATE_CDB_PLAN_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    pluggable_database    => 'PDBPROD5',
    shares                => 1,
    utilization_limit     => 70,
    parallel_server_limit => 70);
END;
/


BEGIN
  DBMS_RESOURCE_MANAGER.UPDATE_CDB_DEFAULT_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    new_shares                => 1,
    new_utilization_limit     => 50,
    new_parallel_server_limit => 50);
END;
/

BEGIN
  DBMS_RESOURCE_MANAGER.UPDATE_CDB_AUTOTASK_DIRECTIVE(
    plan                  => 'PRODCDB_PLAN',
    new_shares                => 1,
    new_utilization_limit     => 75,
    new_parallel_server_limit => 75);
END;
/

exec DBMS_RESOURCE_MANAGER.VALIDATE_PENDING_AREA();


exec DBMS_RESOURCE_MANAGER.SUBMIT_PENDING_AREA();

ALTER SYSTEM SET RESOURCE_MANAGER_PLAN = 'PRODCDB_PLAN';





Part Two: Creating an Oracle 12c Pluggable Database (PDB) Resource Plan


We have seen how a CDB resource plan allocates resources among the various PDB’s in the container database.

The PDB resource plan will now allocate resources within the database based on Consumer Groups – the method is in fact the same as what we used for Non-CDB’s in earlier versions of the Oracle database.

Our requirement is to ensure certain Batch users do not hog the system resources when batch jobs execute and we would like to enable a PDB resource plan which will impose limits on the amount of Undo the statement can use as well as the amount of time the statement is allowed to run and also the amount of physical I/O resources it can use.

At a high level the steps involved are:

·         Connect to the appropriate PDB where we need to create the PDB Resource Plan

·         Create the Pending Area

·         Create the Consumer Groups

·         Map sessions to the Consumer Groups

·         Create the PDB Resource Plan

·         Create PDB resource plan directives

·         Validate the Pending Area

·         Submit the Pending Area

·         Enable the PDB Resource Plan



Connect to the appropriate PDB

SQL SYS@PRODCDB> alter session set container=pdbprod4;

Session altered.

Create the Pending Area

SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.CREATE_PENDING_AREA();
END;
/  2    3    4

PL/SQL procedure successfully completed.


Create the PDB Resource Plan

SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.CREATE_PLAN(PLAN => 'pdbprod4_plan',
COMMENT => 'Resource plan at the PDB level');
END;
/  2    3    4    5

PL/SQL procedure successfully completed.



Create the Consumer Groups


SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.CREATE_CONSUMER_GROUP(CONSUMER_GROUP => 'batch_user_group',
COMMENT => 'Resource consumer group for batch users');
END;
/  2    3    4    5

PL/SQL procedure successfully completed.


Create the directives which will limit resources allocated to a particular Consumer Group

Note – 20 MB of UNDO usage  is a very small value – only used to illustrate the example!

SQL SYS@PRODCDB> BEGIN
  2  DBMS_RESOURCE_MANAGER.CREATE_PLAN_DIRECTIVE(PLAN => 'pdbprod4_plan',
  3  GROUP_OR_SUBPLAN => 'batch_user_group',
  4  COMMENT=>'Cancel SQL statement after exceeding either 20 MB of Undo, elapsed time of 3 minutes or limit i/o to 10 MB',
  5  UNDO_POOL => 20000,
  6  SWITCH_ELAPSED_TIME => 180,
  7  SWITCH_IO_MEGABYTES => 10,
  8  SWITCH_GROUP=>'CANCEL_SQL',
  9  SWITCH_FOR_CALL=> TRUE);
 10  END;
 11  /

PL/SQL procedure successfully completed.

Here are some of the other common directives we can set (taken from the official documentation)

·         MAX_IDLE_TIME – maxiumum session idle time in seconds
·         MAX_EST_EXEC_TIME - maximum execution time (in CPU seconds) allowed for a call as determined by the CBO
·         SWITCH_IO_REQS - number of physical I/O requests that a session can execute before an action is taken
·         PARALLEL_SERVER_LIMIT - maximum percentage of the parallel execution server pool that a particular consumer group can use
·         SWITCH_IO_LOGICAL - Number of logical I/O requests that will trigger the action specified by SWITCH_GROUP
·         ACTIVE_SESS_POOL_P1 - Specifies the maximum number of concurrently active sessions for a consumer group.
·         MGMT_P1 - For a plan with the MGMT_MTH parameter set to EMPHASIS, specifies the CPU percentage to allocate at the first level
·         MGMT_P2 - For a plan with the MGMT_MTH parameter set to EMPHASIS, specifies the CPU percentage to allocate at the second level


Create a directive for the mandatory Consumer Group OTHER_GROUPS. This will apply to all users not mapped to the Consumer Group BATCH_USER_GROUP

SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.CREATE_PLAN_DIRECTIVE(PLAN => 'pdbprod4_plan',
  2    3  GROUP_OR_SUBPLAN => 'OTHER_GROUPS',
  4  COMMENT => 'Mandatory Group covering all users not in batch group');
  5  END;
  6  /



Map the user SH to the Consumer Group BATCH_USER_GROUP and set the initial Consumer Group for the user SH


SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.SET_CONSUMER_GROUP_MAPPING(
ATTRIBUTE      => DBMS_RESOURCE_MANAGER.ORACLE_USER,
VALUE          => 'SH',
CONSUMER_GROUP => 'batch_user_group');
END;
/  2    3    4    5    6    7

PL/SQL procedure successfully completed.

SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER_PRIVS.GRANT_SWITCH_CONSUMER_GROUP ( 'SH','batch_user_group',FALSE);
END;
/  2    3    4

PL/SQL procedure successfully completed.

SQL SYS@PRODCDB> BEGIN
DBMS_RESOURCE_MANAGER.set_initial_consumer_group('SH', 'batch_user_group');
END;
/  2    3    4

PL/SQL procedure successfully completed.



Validate the Pending Area

SQL SYS@PRODCDB> BEGIN
  DBMS_RESOURCE_MANAGER.VALIDATE_PENDING_AREA();
END;
/

PL/SQL procedure successfully completed


Submit the Pending Area

BEGIN
  DBMS_RESOURCE_MANAGER.SUBMIT_PENDING_AREA();
END;
/

PL/SQL procedure successfully completed.



Enable the PDB Resource Plan

SQL SYS@PRODCDB> alter system set resource_manager_plan='pdbprod4_plan';

System altered.

SQL SYS@PRODCDB> show parameter resource_manager_plan

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
resource_manager_plan                string      pdbprod4_plan



Let us now test the PDB resource plan and see if the directive to limit the use of Undo to 20 MB is enforced.

Initially we can see that the user SH which belongs to the BATCH_USER_GROUP Consumer Group is not using any Undo.


SQL SYS@PRODCDB> alter system set resource_manager_plan='pdbprod4_plan';

System altered.

SQL SYS@PRODCDB> show parameter resource_manager_plan

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
resource_manager_plan                string      pdbprod4_plan




From another session let us connect as the user SH and execute an UPDATE statement which will cause the amount of Undo usage to exceed the 20 MB limit.


SQL SH@pdbprod4> update sh.sales set amount_sold=1;

Back to the original session we can now Undo usage is increasing – and then we see it has gone back to 0

This is because the session was cancelled as the resource limit of 20 MB Undo usage was exceeded


SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                  6342144                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 11872540                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 11872540                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 11872540                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                        0                    0
        74 OTHER_GROUPS                                            0                    0



SQL SH@pdbprod4> update sh.sales set amount_sold=1;
update sh.sales set amount_sold=1
          *
ERROR at line 1:
ORA-56720: I/O data limit exceeded - call aborted



If we limit the usage of Undo now by including a WHERE clause in the UPDATE statement, we can see that the Undo usage remains below the 20 MB imposed resource limit and the statement executes successfully this time.

SQL SH@pdbprod4> update sh.sales set amount_sold=1 where rownum < 50001;

50000 rows updated.


SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                  9565964                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 10830200                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 12400376                    0
        74 OTHER_GROUPS                                            0                    0

SQL SYS@PRODCDB> /

   SESS_ID CONSUMER_GROUP                   CURRENT_UNDO_CONSUMPTION MAX_UNDO_CONSUMPTION
---------- -------------------------------- ------------------------ --------------------
        43 BATCH_USER_GROUP                                 12400376                    0
        74 OTHER_GROUPS                                            0                    0