Oracle12c : Truncate Table Cascade

Prior to Oracle 12c truncating tables with dependent children was a  pain. We had to disable the constraint before truncating the parent table followed  by enabling the constraint.  The performance gain achieved using TRUNCATE instead of DELETE  almost disappeared if the constraints were enabled with VALIDATE option.  If enabling the constraint with NOVALIDATE option was not acceptable, then DELETE seemed  to be the only way to go.

Starting with Oracle 12c , Oracle supports truncating tables with CASCADE option similar to other RDBMS like MySQL & PostgreSQL. Well  It took some time for Oracle to introduce this option but glad we finally have this option.

Similar to DELETE , the constraints have to be defined with ON DELETE CASCADE. Otherwise just like  DELETE , TRUNCATE also will fail. Also the cascading effect will impact all children , grand children and so on.

Let us look at an example. See scripts to create the table towards end of this blog.

In t his example we have 3 tables DEPT (PARENT) , EMP(CHILD) & EMPPROJ (GRANDCHILD) . The child/grandchild tables are created without the “ON DELETE CASCADE” , So obviously the TRUNCATE command with CASCADE option will fail. Please do note the difference in the error message for with and without CASCADE option.

SQL> truncate table emp;

truncate table emp
*
ERROR at line 1:
ORA-02266: unique/primary keys in table referenced by enabled foreign keys
SQL> truncate table emp cascade ;
truncate table emp cascade
*
ERROR at line 1:
ORA-14705: unique or primary keys referenced by enabled foreign keys in table
“SHAN”.”EMPPROJ”

 

Now lets go ahead modify the table to add the ON DELETE CASCADE option; To do this, we have to drop existing constraint and add the constraint with ON DELETE CASCADE option.

 

ALTER TABLE EMP DROP CONSTRAINT fk_deptno_dept ;

ALTER TABLE EMPPROJ DROP CONSTRAINT fk_empno_emp ;

ALTER TABLE EMP ADD CONSTRAINT fk_deptno_dept FOREIGN KEY (DEPTNO) REFERENCES dept(deptno) ON DELETE CASCADE;

ALTER TABLE EMPPROJ ADD CONSTRAINT fk_empno_emp foreign key (empno) REFERENCES emp(empno) ON DELETE CASCADE;

Before we truncate the table, lets take the count of emp & empproj table.

SQL>

SQL> select count(*) from emp;

COUNT(*)
———-
5

SQL> select count(*) from empproj;

COUNT(*)
———-
5

 

Now let us truncate the table with and without t he CASACADE option and then take a count of emp and empproj tables. The key thing to remember is that the CASCADE option will truncate all  data from empproj when emp table is truncated because of child & grandchild option.

SQL> truncate table emp;

truncate table emp
*
ERROR at line 1:
ORA-02266: unique/primary keys in table referenced by enabled foreign keys
SQL> truncate table emp cascade;

Table truncated.

SQL> select count(*) from emp;

COUNT(*)
———-
0

SQL> select count(*) from empproj;

COUNT(*)
———-
0

 

x==x==x==x==x==x==x==x==x==x==x=x=x==x==x==x==x==x==x==x==x==x==x==x=x=x==x

 

Scripts to create the tables 
create table dept
(
deptno number(4) constraint pk_dept primary key,
dname varchar2(20) not null,
loc varchar2(30)
);

 

create table emp
(
empno number(4) constraint pk_emp primary key,
ename varchar2(20) not null,
salary number(10,2) ,
deptno number(4) constraint fk_deptno_dept references dept(deptno)
);

 

create table empproj
(
empno number(4) ,
proj varchar2(20) not null,
hours number(4) ,
constraint pk_empproj primary key (empno, proj),
constraint fk_empno_emp foreign key (empno) references emp(empno)
);

INSERT INTO DEPT VALUES (10,’FINANCE’,’RESTON’);
INSERT INTO DEPT VALUES (20,’ACCOUNTING’,’CHICAGO’);
INSERT INTO DEPT VALUES (30,’RESEARCH’,’DALLAS’);

INSERT INTO EMP VALUES ( 1001,’TIM’, 5800, 10);
INSERT INTO EMP VALUES ( 1002,’MIKE’, 5800, 30);
INSERT INTO EMP VALUES ( 1003,’SAM’, 5800, 30);
INSERT INTO EMP VALUES ( 1004,’JOE’, 5800, 20);
INSERT INTO EMP VALUES ( 1005,’SEAN’, 5800, 10);
INSERT INTO EMPPROJ VALUES (1001,’RED’,20);
INSERT INTO EMPPROJ VALUES (1001,’PINK’,30);
INSERT INTO EMPPROJ VALUES (1001,’BLUE’,10);
INSERT INTO EMPPROJ VALUES (1002,’PINK’,10);
INSERT INTO EMPPROJ VALUES (1002,’BLUE’,40);

 

 

 

Oracle 12c RMAN New Features

In Oracle 12c , there are lot of new great RMAN features  focused on reducing recovery time; Some of them to provide better DBA :) experience too .Let us  glance at some of them in this blog.

  1. Support for point in time recovery for tables  and partitions. I would rate this as one of best options of Oracle 12c.
  2. Option to duplicate database with NOOPEN option so that duplicated/cloned database remains in mount state. Prior to 12c, the cloned database is automatically opened in RESETLOGS mode. The NOOPEN option is very useful when you want to clone a database  as part of upgrade.
  3. In Oracle 12c , duplicate database supports pull based restore from backup sets; Prior to Oracle 12c , the support was only for push based restore from image copies.
  4. Support for recovering the database from snapshots taken using 3rd party vendors like EMC,Hitachi etc. The recover command now supports SNAPSHOT  TIME clause to implement this feature.
  5. Transporting database across platforms using backupsets. Prior to 12c, only image copies was supported.
  6. Transporting database across platforms using inconsistent backups i.e.. backups taken without putting the database in READONLY mode. New clause ALLOW INCONSISTENT is introduced to implement this.
  7. Support for execution of SQL commands from RMAN prompt without SQL prefix.
  8. Support for SQL*Plus command DESC  from RMAN prompt.

Oracle 12c : Partial Indexes

Let us assume you have a table with ten columns and four B*Tree indexes. If you analyze the space usage; chances are very high that size of all indexes together is nearly equal to more than the size of the table.  If you end up creating more indexes to support complex business requirements, the size of all indexes together could be 2-4 times(or more) the size of tables. So what is the big deal, space is cheap.  Really?  This is what you get to read but when your database is in 10s or 100s of terabytes, every byte matters. So how would you feel if you were told that there is an option in Oracle 12c that would let you create partial index on partitioned tables to save storage and improve on performance.

Let us explore more on this topic.

We know that the main purpose of index is to provide fast access to selective data and that the purpose of index is defeated when you retrieve large amounts of data(subjective to size of table).  Moreover for some applications, you need indexes only for the current or recent months whereas for some applications, index is not required for current or recent months. For reporting or data warehouse databases, full table scans in parallel are generally many times faster compared to sequential index range scans.  But when you create a global or local Index on partitioned table, index is created on all of the data or partitions. Prior to Oracle 12c , you could not create indexes on selective partitions; Indexes always meant on all of the data.  However with Oracle 12c, you can create partial indexes that  contains index data from selective partitions only.

 

So how would you implement partial indexes?

  1. Enable or disable the indexing property at table level or partition/subpartiton level using INDEXING clause.
  2. Create indexes as FULL or PARTIAL. When you specify PARTIAL, only partitions that have the indexing property turned on  will be part of index.

Example

In the below example, I am disabling the index property of the table and  enabling the indexing property at partition level. Now when I create partial indexes, only those partitions  with indexing property turned on are part of index.

SQL>  CREATE TABLE TRANSACTION(
2    TRANSACTION_ID           NUMBER(12)    PRIMARY KEY,
3    OPERATION_ID             NUMBER(3)     NOT NULL,
4    TRANSCTION_AMT           NUMBER(9,2)   NOT NULL,
5    TRANSACTION_DATE         DATE,
6    TRANSACTION_TYPE         VARCHAR2(2))
INDEXING OFF
8  PARTITION BY RANGE (TRANSACTION_DATE)
9  (
10     PARTITION TRANSACTIONDATE_P1 VALUES LESS THAN (TO_DATE(’01-MAR-2014′,’DD-MON-YYYY’))      INDEXING OFF,
11     PARTITION TRANSACTIONDATE_P2 VALUES LESS THAN (TO_DATE(’01-APR-2014′,’DD-MON-YYYY’))      INDEXING OFF,
12     PARTITION TRANSACTIONDATE_P3 VALUES LESS THAN (TO_DATE(’01-MAY-2014′,’DD-MON-YYYY’))      INDEXING OFF,
13     PARTITION TRANSACTIONDATE_P4 VALUES LESS THAN (TO_DATE(’01-JUN-2014′,’DD-MON-YYYY’))         INDEXING ON,
14     PARTITION TRANSACTIONDATE_P5 VALUES LESS THAN (TO_DATE(’01-JUL-2014′,’DD-MON-YYYY’))         INDEXING ON
15 ) ;

Table created.

In the example below,Only data from partitions TRANSACTIONDATE_P4 and TRANSACTIONDATE_P5 are part of index.

SQL> CREATE INDEX   IDX_TRANS_OID  ON TRANSCTION(OPERATION_ID)
2  GLOBAL INDEXING PARTIAL;

Index created.

In this example, all partitions are part of index.

SQL> CREATE INDEX   IDX_TRANS_TYPE ON TRANSCTION(TRANSACTION_TYPE)
2  GLOBAL INDEXING FULL;

Index created.

In the example below,Only data from partitions TRANSACTIONDATE_P4 and TRANSACTIONDATE_P5 are part of index.

SQL> CREATE INDEX  IDX_TRANS_DATE ON TRANSACTION(TRANSACTION_DATE)
2  LOCAL INDEXING PARTIAL;

Index created.

 You can enable or disable the indexing property of the table or partition or subpartition using the ALTER TABLE command;  

SQL> alter table transaction modify partition TRANSACTIONDATE_P3 indexing on ;

Table altered.

 

 

Oracle 12c Extended Datatypes

Extended Datatypes

Prior to Oracle 12c, VARCHAR2/NVARCHAR2 datatypes  allowed storing variable length characters of up to 4000 bytes whereas RAW data type  allowed storing variable length binry data of up to  2000 bytes.  In Oracle 12c, the maximum size for data types VARCHAR2, NVARCHAR2  and RAW is increased to 32767 bytes.  These data types are now referred to as extended data types. Extended data types are implicitly implemented using concept of LOBs;  Just like LOB’s, any data stored in excess of  4000 bytes for VARCHAR2/NVARCHAR2/RAW is stored out-line. If the data stored is within pre-Oracle12c limits , then they are stored in-line.  So be aware about the restrictions of LOBs since all most all of the restrictions of lobs are applicable to  extended datatypes (at least for now).

The first thing that came to mind about extended data types is what purpose does it actually serve since it is implemented as LOB; Why would you introduce LOB restrictions to your columns by increasing the limits of VARCHAR2, NVARCHAR2  and RAW. As most of you are aware that all versions of databases including Oracle 12c do  not support changing VARCHAR2/NUMBER/RAW  to LOBs directly with ALTER ..MODIFY command. (Would result in ORA-22858: invalid alteration of datatype); I thought that  instead of  extended datatype ,Oracle could have removed the restriction to convert VARCHAR2/NUMBER/RAW  to LOBs directly and provided some restricted form of index support.

Being a new feature, I did not find much useful information about the feature and so decided why not be one of the earliest blogger to explore this topic.

So let us make sure that  the database is  enabled for extended datatypes.

SQL> show parameter max_string_size

NAME                                 TYPE        VALUE

———————————— ———– ——————————

max_string_size                      string      EXTENDED

Please refer to following blog on instructions of how to set up your database for extended datatypes. http://twelvec.com/2014/02/08/oracle-12c-how-to-setup-your-database-to-support-extended-datatypes/

Now lets create a table with two columns , one with VARCHAR2 and other with LOB

SQL> CONN SHAN/SHAN

Connected.

SQL> CREATE TABLE EXT_DATATYPE (

2  EMPLOYEE_NO VARCHAR2(32767) ,

3  EMPLOYEE_COMMENTS  BLOB);

Table created.

 Ok now lets trying adding primary key to this table. Ooops , It failed because of the restrictions on  index lengths.

SQL> ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_NO);

ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_NO)

*

ERROR at line 1:

ORA-01450: maximum key length (6398) exceeded

Now lets modify the column size to 6398 bytes and add primary key to the table. The command still fails; So what is the secret column length that supports indexes? It is actually  6389 bytes.

SQL>  ALTER TABLE EXT_DATATYPE MODIFY  (EMPLOYEE_NO VARCHAR2(6398));

Table altered.

SQL>  ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_NO);

ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_NO)

ERROR at line 1:

ORA-01450: maximum key length (6398) exceeded

For VARCHAR2/NVARCHR2/RAW columns more that 6389 bytes , you can create indexes using function based indexes or virtual columns. With both approaches, you are shortening the length of column to create indexes using either SUBSTR or new STANDARD_HASH functions or something creative that you can come up with.

Let us revert  the column length to  time trusted 4000 bytes, add index and then try to increase the column length. You are going to get a different error but the underlying cause us same.

SQL>  ALTER TABLE EXT_DATATYPE MODIFY  (EMPLOYEE_NO VARCHAR2(4000));

Table altered.

SQL>  ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_NO);

Table altered.

SQL> ALTER TABLE EXT_DATATYPE MODIFY  (EMPLOYEE_NO VARCHAR2(6390));

ALTER TABLE EXT_DATATYPE MODIFY  (EMPLOYEE_NO VARCHAR2(6390))

*

ERROR at line 1:

ORA-01404: ALTER COLUMN will make an index too large

Now let us drop our primary key constraint and  try adding lob data type as primary key; It will fail as LOB columns cannot be primary key or unique key.

SQL> alter table EXT_DATATYPE drop primary key;

Table altered.

SQL> ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_COMMENTS));

ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_COMMENTS))

ERROR at line 1:

ORA-01735: invalid ALTER TABLE option

SQL> ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_COMMENTS);

ALTER TABLE EXT_DATATYPE  ADD PRIMARY KEY (EMPLOYEE_COMMENTS)

ERROR at line 1:

ORA-02329: column of datatype LOB cannot be unique or a primary key

Summary: In essence, It if would have been better if Oracle increased the datatypes sizes to 6000 bytes instead of 32K so that indexing , primary key constraints are all supported.  There is always a learning curve with new features;  it gets little more complicated with enhancements.  With 32K sizes ,Initially it is going to introduce new risks and create confusion if implemented without understanding the actual consequences even though there are some workarounds for creating indexes using  virtual columns or function based indexes.  I just picked one restriction of LOBs ; More testing to be done to verify the behavior of AFTER UPDATE DML trigger , INSERT AS SELECT and many more restrictions.

Oracle 12c: How to setup your database to support extended datatypes?

This blog discusses the setup required to support extended datatypes in Oracle12c; For more information about extended datatypes, please refer to http://twelvec.com/2014/02/08/oracle12c_extended_datatypes/

In  nutshell , the following steps are required to enable extended datatypes. Most of the  steps are familiar except for step 3 and 4. In step 3 , we are modifying initialization parameter MAX_STRING_SIZE from STANDARD to EXTENDED. Once changed , this is a irreversible action.  Step 4  increases the sizes of VARCHAR2, NVARCHAR2 & RAW in the required views.

1. SHUTDOWN IMMEDIATE
2. STARTUP UPGRADE;
3. ALTER SYSTEM SET max_string_size=extended scope=spfile;
4. @?/rdbms/admin/utl32k.sql
5. SHUTDOWN IMMEDIATE;
6. STARTUP;

Example:

SQL> select name from v$database;

NAME

———

ORCL12C

SQL> shutdown immediate

Database closed.

Database dismounted.

ORACLE instance shut down.

SQL>

SQL>

SQL>

SQL> startup upgrade

ORACLE instance started.

Total System Global Area 2505338880 bytes

Fixed Size                  2291472 bytes

Variable Size             671090928 bytes

Database Buffers         1811939328 bytes

Redo Buffers               20017152 bytes

Database mounted.

Database opened.

SQL>

SQL>

SQL> ALTER SYSTEM SET max_string_size=extended;

System altered.

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

Session altered.

DOC>#######################################################################

DOC>#######################################################################

DOC>   The following statement will cause an “ORA-01722: invalid number”

DOC>   error if the database has not been opened for UPGRADE.

DOC>

DOC>   Perform a “SHUTDOWN ABORT”  and

DOC>   restart using UPGRADE.

DOC>#######################################################################

DOC>#######################################################################

DOC>#

no rows selected

DOC>#######################################################################

DOC>#######################################################################

DOC>   The following statement will cause an “ORA-01722: invalid number”

DOC>   error if the database does not have compatible >= 12.0.0

DOC>

DOC>   Set compatible >= 12.0.0 and retry.

DOC>#######################################################################

DOC>#######################################################################

DOC>#

PL/SQL procedure successfully completed.

Session altered.

0 rows updated.

Commit complete.

System altered.

PL/SQL procedure successfully completed.

Commit complete.

System altered.

Session altered.

PL/SQL procedure successfully completed.

No errors.

Session altered.

PL/SQL procedure successfully completed.

Commit complete.

Package altered.

TIMESTAMP

——————————————————————————–

COMP_TIMESTAMP UTLRP_BGN  2014-01-28 14:51:31

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  2014-01-28 14:51:33

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″ 14:51:48

…Compiled 0 out of 2998 objects considered, 0 failed compilation 14:51:48

…263 packages

…255 package bodies

…453 tables

…11 functions

…16 procedures

…3 sequences

…458 triggers

…1322 indexes

…207 views

…0 libraries

…6 types

…0 type bodies

…0 operators

…0 index types

…Begin key object existence check 14:51:48

…Completed key object existence check 14:51:48

…Setting DBMS Registry 14:51:48

…Setting DBMS Registry Complete 14:51:48

…Exiting validate 14:51:48

PL/SQL procedure successfully completed.

SQL> SHUTDOWN IMMEDIATE

Database closed.

Database dismounted.

ORACLE instance shut down.

SQL>

SQL>

SQL>

SQL> startup

ORACLE instance started.

Total System Global Area 2505338880 bytes

Fixed Size                  2291472 bytes

Variable Size             671090928 bytes

Database Buffers         1811939328 bytes

Redo Buffers               20017152 bytes

Database mounted.

Database opened.

SQL> show parameter max_string_size

NAME                                 TYPE        VALUE

———————————— ———– ——————————

max_string_size                      string      EXTENDED

PURGE DBA_RECYCLEBIN System Privilege in Oracle 12c

PURGE DBA_RECYCLEBIN  command empties the recyclebin at  database level i.e. purges the recyclebin for all users in the database.  Until 11g , you need to have powerful  SYSDBA system privilege to execute this command.  To some extent it made sense as this option was mainly used for upgrades or migration or to apply DST patch. One of focus areas of Oracle12c is separation of duties resulting in  new roles like SYSKM for wallet management, SYSBACKUP for backups and restore, SYSDG  for administration of Data Guard.

Along the same lines, We have new privilege  PURGE DBA_RECYCLEBIN that helps with implementing separation of duty. Users granted the PURGE DBA_RECYCLEBIN system privilege can purge the recyclebin for all users in the database using the PURGE DBA_RECYCLEBIN command.

Unified Auditing (Part-I)

Increased scrutiny of Organizations adherence to  regulatory guidance like SOX, Hippa & PCI DSS has made audit of   critical and privileged actions in the database more likely to be mandatory than optional. Therefore forcing database or software vendors to implement auditing with piecemeal approach. Oracle is no different with various  ways to audit  & various  locations  to store them in various formats.  For example some of the auditing options available with Oracle 11g are mandatory auditing, standard database auditing , Data Vault auditing & FGA and so on ….

Staying complaint is expensive , time consuming and complex. Some of the complexities involved with auditing has been simplified with unified auditing available with Oracle12c. In this blog , we will discuss about Unified auditing in 4 part series. Here is the 1st part.

So what is unified auditing ?
Unified Auditing is selective and effective auditing  of database actions to a single unified audit trail  inside of the database using policies and conditions.  Most of unified auditing features are implemented using DBMS_AUDIT_MGMT or Oracle Grid Control. DBMS_AUDIT_MGMT is not a new to some/most of us as it is available with Oracle11g. It is enhanced in Oracle12c to support unified auditing.  Unified auditing supports auditing of following components.

  1. FGA
  2. Real Application Security
  3. RMAN
  4. Database Vault
  5. Oracle Label Security
  6. Data Mining
  7. Data Pump
  8. SQL*Loader

My next question why do we need a unified auditing? What is wrong with existing auditing?  Why couldn’t we audit everything in the database and get done with it and make our auditors happy. What actually stopped us from auditing everything in the database? The main reasons were performance impact caused by auditing followed by security.  Now we have the burden on us to prove that all our audit is safe, correct and not tampered with. And finally where do I store all the audit data ; Getting additional storage for database itself is cumbersome…. Now you need space to store all of audit data.

Let us look at how unified auditing measures  itself against the 3 metrics: Performance, Security & Storage

Performance

As per Oracle, Unified auditing  results in  negligible overhead. Why ? Because it  is implemented in SGA using named Queues. Dequeing is continuous with each audit client (Example: RMAN, Oracle Label Security) having two separate queues so that the client can continue to write to the second queue while the first queue is being dequeued to database table by background process GEN0. if needed audit Data can also be manually flushed to the database using procedure FLUSH_UNIFIED_AUDIT_TRAIL.

Example: EXECUTE DBMS_AUDIT_MGMT.FLUSH_UNIFIED_AUDIT_TRAIL;

As usual we have the choice of synchronous and asynchronous dequeuing. In  unified audit terms, they are called as Immediate write mode and queued write mode.

Immediate-Write mode

Audit records are immediately written to the trail and there is a performance overhead associated with this approach

Example: EXECUTE DBMS_AUDIT_MGMT.SET_AUDIT_TRAIL_PROPERTY (DBM_MS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,DBMS_AUDIT_MGMT.AUDIT_TRAIL_WRITE_MODE,  DBMS_AUDIT_MGMT.AUDIT_TRAIL_IMMEDIATE_MODE);

Queued-Write mode(Default)

The named queue in the SGA is  dequeued periodically. In this mode , data could be lost after an instance crash and therefore its a trade-in  for data loss for performance. How cruel …. never can have everything

Example: EXECUTE DBMS_AUDIT_MGMT.SET_AUDIT_TRAIL_PROPERTY (DBM_MS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,DBMS_AUDIT_MGMT.AUDIT_TRAIL_WRITE_MODE, DBMS_AUDIT_MGMT.AUDIT_TRAIL_QUEUED_MODE);

Summary: Performance is better mainly because of  queued-write mode architecture; Using immediate-write mode will cause performance impact but not as significant pre12c auditing.

 

 

Let us look at other metrics in Part-II of this series. I will post the link once  I am ready.

Follow

Get every new post delivered to your Inbox.

Join 53 other followers