Tuesday, December 29, 2015

Oracle 12c Privilege Analysis

Introduction

In this post I'd like to demonstrate another new Oracle 12c security feature - Privilege Analysis. Using this feature, the DBA can easily understand which privileges are actually being used by users. Once the analysis has been completed, the DBA can revoke all of the unnecessary privileges/roles. This feature is only available for Enterprise Edition with Oracle Database Vault (extra cost option).

How does it work?

Oracle introduced a new package, DBMS_PRIVILEGE_CAPTURE which allows you to create a new privilege analysis policy, enable/disable it, generate the results of the analysis and drop the policy once the analysis is over and the policy is not needed anymore. In order to use the DBMS_PRIVILEGE_CAPTURE package you need to be grnted the CAPTURE_ADMIN role.

Demonstration

In order to create a new privilege analysis policy, use the following syntax:
DBMS_PRIVILEGE_CAPTURE.CREATE_CAPTURE(
   name              VARCHAR2, 
   description       VARCHAR2 DEFAULT NULL, 
   type              NUMBER DEFAULT DBMS_PRIVILEGE_CAPTURE.G_DATABASE, 
   roles             ROLE_NAME_LIST DEFAULT ROLE_NAME_LIST(), 
   condition         VARCHAR2 DEFAULT NULL);
Let's start by creating a user named "pini" and grant him the DBA role. Afterwards, we'll create and enable a simple policy named "capture_pini_privs" that simply captures all the privileges used by user pini:
SQL> create user pini identified by pini default tablespace users;
User created.

SQL> grant dba to pini;
Grant succeeded.

SQL> BEGIN
  2    DBMS_PRIVILEGE_CAPTURE.create_capture(
  3      name        => 'capture_pini_privs',
  4      type        => DBMS_PRIVILEGE_CAPTURE.g_context,
  5      condition   => 'SYS_CONTEXT(''USERENV'', ''SESSION_USER'') = ''PINI'''
  6    );
  7  END;
  8  /
PL/SQL procedure successfully completed.

SQL> EXECUTE DBMS_PRIVILEGE_CAPTURE.enable_capture('capture_pini_privs');
PL/SQL procedure successfully completed.
Explanation of the above code:

- In line 3 I set the name of the policy to be "capture_pini_privs"
- In line 4 I set the type to be DBMS_PRIVILEGE_CAPTURE.g_context to captrue privileges of the sessions defined in line 5
- In line 5 I used SYS_CONTEXT to specify capture privileges for user "PINI" only

After we have created the new policy we can verify it via DBA_PRIV_CAPTURES dictionary view that lists all the policies as follows:
SQL> SELECT TYPE, enabled, context FROM DBA_PRIV_CAPTURES;

TYPE             ENABLED    CONTEXT
---------------- ---------- --------------------------------------------------
CONTEXT          Y          SYS_CONTEXT('USERENV', 'SESSION_USER') = 'PINI'

Note that there are several other types that you can use (in line 4) like capturing privileges of the entire database users except of use SYS (using DBMS_PRIVILEGE_CAPTURE.G_DATABASE), or capturing the privileges of specific sessions with specific roles (DBMS_PRIVILEGE_CAPTURE.G_ROLE_AND_CONTEXT) which requires also to specify the "roles" parameter. You can read more about these options in the official documentation for the DBMS_PRIVILEGE_CAPTURE package.

Now, after we have created and enabled to policy, the analysis period has been started.
Next, let's connect with user pini and execute a few commands to test this feature:
SQL> connect pini/pini
Connected.

SQL> create table EMP (id number, name varchar2(20), constraint id_pk PRIMARY KEY (id));
Table created.

SQL> insert into EMP values (1, 'DAVID');
1 row created.

SQL> commit;
Commit complete.

SQL> CREATE OR REPLACE FUNCTION return_num_of_emps
  2     RETURN NUMBER IS
  3     num_of_emps NUMBER;
  4     BEGIN
  5        select count(*)
  6        into num_of_emps
  7        from EMP;
  8        RETURN(num_of_emps);
  9      END;
 10  /
Function created.

SQL> select return_num_of_emps from dual;
RETURN_NUM_OF_EMPS
------------------
                 1
SQL> select instance_name from v$instance;
INSTANCE_NAME
----------------
o1264np

SQL> select log_mode from v$database;
LOG_MODE
------------
NOARCHIVELOG
Now, I will disable the capture policy and generate the report as follows:
SQL> execute DBMS_PRIVILEGE_CAPTURE.DISABLE_CAPTURE('capture_pini_privs');
PL/SQL procedure successfully completed.

SQL> execute DBMS_PRIVILEGE_CAPTURE.generate_result('capture_pini_privs');
PL/SQL procedure successfully completed.
The output of the report will be printed to various dictionary views like DBA_USED_SYSPRIVS and DBA_USED_OBJPRIVS as you can see in the following demonstration:
SQL> SELECT SYS_PRIV
  2    FROM DBA_USED_SYSPRIVS
  3   WHERE username = 'PINI';

SYS_PRIV
---------------------------------------
CREATE SESSION
CREATE TABLE
CREATE ANY INDEX
CREATE PROCEDURE
UNLIMITED TABLESPACE

SQL> SELECT obj_priv, object_owner, object_name
  2    FROM DBA_USED_OBJPRIVS
  3   WHERE username = 'PINI';

OBJ_PRIV                                 OBJECT_OWNER         OBJECT_NAME
---------------------------------------- -------------------- ----------------------------------------
SELECT                                   SYS                  V_$INSTANCE
SELECT                                   SYS                  V_$DATABASE

Once the analysis has been completed, you can drop the policy. This step is optional and it's goal is to clean to policy-related information from the data-dictionary views. In order to do that use the following syntax:
SQL> execute DBMS_PRIVILEGE_CAPTURE.DROP_CAPTURE ('capture_pini_privs');
PL/SQL procedure successfully completed.


Summary

Granting minimum privileges for users is a security best practice, however, many DBAs are struggling with identifying which exact privileges are actually needed and which privileges are unnecessary - and therefore, should be revoked. This feature comes to solve this challenge. I would expect this useful security feature to be available for all Oracle Editions but unfortunately, it's only available for Enterprise Edition with Oracle Database Vault (extra cost option). 

Monday, December 14, 2015

Oracle Multiprocess and Multithreaded Architecture

Introduction

The Oracle process architecture of Windows operating system is a different process architecture comparing to Linux/Unix operating systems. On Windows, each Oracle instance has one single process that is multithreded, i.e. each background process is a thread within the single "father" process, therefore the "processes" tab in the the task manager will display only one "oracle.exe" process per each instance, as you can see in the following screenshot (taken from one of our Oracle environments):




























On Linux/Unix on the other hand, each background process is a different OS process so by looking for all the processes you should expect to get a long list of Oracle processes, as you can see the following screenshot (taken from one of our Oracle on Linux environments):






















































Oracle 12c Multiprocess and Multithreaded Architecture

By default, the pre-12c Oracle process architecture remains the same in Oracle 12c. However, in Oracle 12c you can enable the multithreaded architecture on Unix/Linux that will cause Oracle processes on Linux/Unix to run as threads - similar to the process architecture on Windows. In order to do so, simply set the THREADED_EXECUTION initialization parameter to TRUE (default value is FALSE). This is a static parameter (SCOPE=SPFILE), therefore requires restarting the instance in order for the changes to take effect.

Demonstration

First, I will connect to one of our 12c Oracle Linux environments and set the THREADED_EXECUTION to be TRUE:
SQL> alter system set THREADED_EXECUTION=true scope=spfile;
System altered.

SQL> shu immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.

SQL> startup
Total System Global Area 1073741824 bytes
Fixed Size                  2932632 bytes
Variable Size             692060264 bytes
Database Buffers          373293056 bytes
Redo Buffers                5455872 bytes
Database mounted.
Database opened.

Now I will check how many Oracle processes I have on the Linux environment:













As you can see, now there are much less processes than before. Most of the background processes now run as threads instead of processes but some of them might still run as operating system processes (like the PMON and the DB Writer processes).

Important things to keep in mind

  • OS authentication is not allowed with the multithreaded architecture. If you will try to connect via an OS authentication (for example, by connecting with "/ AS SYSDBA") you will encounter "ORA-01017: invalid username/password; logon denied", therefore you must use a password file for connecting with a SYSDBA/SYSOPER user.
  • When the THREADED_EXECUTION parameter is set to TRUE, you must set the DEDICATED_THROUGH_BROKER_LISTENER parameter to ON in your listener.​ora file. When that parameter is set, the listener knows that it should not spawn an OS process when a connect request is received, instead it passes the request to the database so that a database thread is spawned and answers the connection.​ 
  • In RAC environments all nodes must have the same value for the THREADED_EXECUTION parameter.

Summary

In this post I've reviewed the process architecture in Linux/Unix vs. Windows and demonstrated the new 12c Multithreaded option. This feature can be useful in order to reduce the number of OS processes in scenarios where you have many Oracle instances on the same machine which may cause a higher overhead as a result of a very high number of OS processes.

Useful Links


Wednesday, December 9, 2015

Oracle 12c ADR enhancements

Introduction

Oracle 11g introduced new locations for storing the diagnostics-related logs (e.g. alert log, background trace files, foreground trace files, core dumps, etc.). This feature named ADR (Automatic Diagnostic Repository). The base directory for the ADR is defined by the DIAGNOSTIC_DEST parameter. You can also obtain the specific location of each ADR file type via V$DIAG_INFO as follows:
SQL> show parameter diagnostic
NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
diagnostic_dest                      string      C:\APP\ORACLE

SQL> select name,value from v$diag_info;
NAME                           VALUE
------------------------------ ------------------------------------------------------------
Diag Enabled                   TRUE
ADR Base                       C:\APP\ORACLE
ADR Home                       C:\APP\ORACLE\diag\rdbms\orcl11\orcl11
Diag Trace                     C:\APP\ORACLE\diag\rdbms\orcl11\orcl11\trace
Diag Alert                     C:\APP\ORACLE\diag\rdbms\orcl11\orcl11\alert
Diag Incident                  C:\APP\ORACLE\diag\rdbms\orcl11\orcl11\incident
Diag Cdump                     C:\app\oracle\diag\rdbms\orcl11\orcl11\cdump
Health Monitor                 C:\APP\ORACLE\diag\rdbms\orcl11\orcl11\hm
Default Trace File             C:\APP\ORACLE\diag\rdbms\orcl11\orcl11\trace\orcl11_ora_1010
The ADRCI (ADR Command Interpreter) that was introduced in Oracle 11gR1 is a command line tool that is being installed as part of the Oracle software installation (similar to SQL*PLUS) and its purpose is to view and manage ADR diagnostic data needed for troubleshooting issues. More informatin about the ADRCI is available here.


DDL Logging

In Oracle 12c you can enable DDL logging which will audit all the DDL statements. Oracle Database 12c turns DDL logging off by default. The parameter ENABLE_DDL_LOGGING must be set to TRUE to activate DDL logging.​ DDL logs are stored in separate files and directories. DDL logs can be found in the $ADR_HOME/log/ddl. Let's see a quick demonstration of this feature:
SQL> show parameter enable_ddl_logging
NAME                                 TYPE        VALUE
------------------------------------ ----------- -------
enable_ddl_logging                   boolean     FALSE

SQL> alter system set enable_ddl_logging=true;
System altered.

SQL> create table test_ddl_logging (id number);
Table created.

SQL> drop table test_ddl_logging;
Table dropped.

SQL> alter system set enable_ddl_logging=false;
System altered.
Now I will connect to the machine via putty in order to view the DDL log file:





As you can see the log file prints the CREATE TABLE and DROP TABLE commands.
It's also possible to view the contents of the DDL log file via the ADRCI "SHOW LOG" command which will show you the actual statements and the execution date for each statements that was executed.

DEBUG Logging

Some low-severity issues that don't require immediate action can trigger a warning which will be recorded in a debug log file (instead of the alert log). These messages might be needed to diagnose a future problem and the debug information is included as part of the incident Packaging Service (IPS) which can be shipped to the Oracle support when needed.
The location of the debug log file is $ADR_BASE/diag/rdbms/{DB-name}/{SID}/log/debug

Useful Links

Tuesday, December 8, 2015

Demonstration of Oracle 12c Data Redaction

Introduction

In this post I'd like to demonstrate the new Oracle 12c security feature - Data Redaction. 
Although it was introduced in Oracle 12c, a similar feature named "column masking" has been introduced back in 2003 with Oracle version 10g. Data Redaction allows you to protect confidential data by masking the sensitive information from unauthorized users. The way for Oracle to know if the user is authorized to see the real data is by using the EXEMPT REDACTION POLICY system privilege. If the user doesn't have the EXEMPT REDACTION POLICY system privilege it means that he is unauthorized and therefore if a redaction policy is defined for the data the the user attempts to query, the output will be redacted rather than the real data.

Data Redaction Policies

Data Redaction policy for a table or view defines which column/s will be redacted and in which manner. 
The management of redaction policies is done via the DBMS_REDACT package. 
For example, you can create a new policy DBMS_REDACT.ADD_POLICY procedure, modify an existing policy using the DBMS_REDACT.ALTER_POLICY, disable a policy using DBMS_REDACT.DISABLE_POLICY and drop a policy using DBMS_REDACT.DROP_POLICY.

Demonstration

First, let's create a table and insert a 2 records to the table.
SQL> create table EMPLOYEE (id number, name varchar2(20), join_date timestamp);
Table created.

SQL> insert into EMPLOYEE values (1, 'PINI',sysdate);
1 row created.

SQL> insert into EMPLOYEE values (2, 'DAVID',sysdate);
1 row created.
SQL> commit;
Commit complete.

SQL> select * from EMPLOYREE;

        ID NAME                 JOIN_DATE
---------- -------------------- ------------------------------
         1 PINI                 08-DEC-15 03.33.27.000000 PM
         2 DAVID                08-DEC-15 03.33.28.000000 PM

Let's start by creating a new redaction policy named "REDACT_EMPLOYEE" for the "Name" column
SQL> BEGIN
  2     DBMS_REDACT.add_policy (object_name     => 'EMPLOYEE',
  3                             column_name     => 'ID',
  4                             policy_name     => 'REDACT_EMPLOYEE',
  5                             function_type   =>  DBMS_REDACT.full,
  6                             expression      => '1=1');
  7  END;
  8  /
PL/SQL procedure successfully completed.

SQL> select * from EMPLOYEE;

        ID NAME                 JOIN_DATE
---------- -------------------- ------------------------------
         0 PINI                 08-DEC-15 03.33.27.000000 PM
         0 DAVID                08-DEC-15 03.33.28.000000 PM

As we can see, the value of the ID column has been changed to 0. You may ask yourself, why 0? How Oracle decides which values to use for the masking? We'll discuss about it in a minute. Now, let's redact the rest of the columns (Name and JOIN_DATE) using the ALTER_POLICY procedure. In order to do that, we'll set the value of "action" parameter to be the DBMS_REDACT.ADD_COLUMN constant, as follows:
SQL> BEGIN
  2     DBMS_REDACT.alter_policy (object_name     => 'EMPLOYEE',
  3                             column_name     => 'NAME',
  4                             policy_name     => 'REDACT_EMPLOYEE',
  5                             function_type   => DBMS_REDACT.full,
  6                             expression      => '1=1',
  7                             action          => DBMS_REDACT.ADD_COLUMN);
  8  END;
  9  /
PL/SQL procedure successfully completed.

SQL> BEGIN
  2     DBMS_REDACT.alter_policy (object_name     => 'EMPLOYEE',
  3                             column_name     => 'JOIN_DATE',
  4                             policy_name     => 'REDACT_EMPLOYEE',
  5                             function_type   => DBMS_REDACT.full,
  6                             expression      => '1=1',
  7                             action          => DBMS_REDACT.ADD_COLUMN);
  8  END;
  9  /
PL/SQL procedure successfully completed.

SQL> select * from EMPLOYEE;

        ID NAME                 JOIN_DATE
---------- -------------------- ------------------------------
         0                      01-JAN-01 01.00.00.000000 AM
         0                      01-JAN-01 01.00.00.000000 AM
As we can see, Oracle changed all values of the EMPLOYEE table with fixed values and that's because we set the function_type parameter to be DBMS_REDACT.FULL which is by the way, the default behaviour so if you will omit the function_type parameter, it will use a FULL redaction, i.e. it will use fixed values for the data redaction.
The default redaction values for the FULL redaction can be obtained via the REDACTION_VALUES_FOR_TYPE_FULL dictionary view.

As you can see, the default value for NUMBER is 0, for characther data types it's a single space and for date-time data types is the first day of January, 2001, which appears as 01-JAN-01.
In order to change the default masking valuess when using a FULL redaction, you can use the UPDATE_FULL_REDACTION_VALUES Procedure. In addition to the default FULL redaction type, you can also choose to work with other function types:
  • NONE - No redaction
  • PARTIAL - Partial redaction, redact a portion of the column data
  • RANDOM - Random redaction, each query results in a different random value
  • REGEXP - Regular expression based redaction

For example, you can change the function_type of all the columns to be RANDOM as follows:
SQL> BEGIN
  2     DBMS_REDACT.alter_policy (object_name     => 'EMPLOYEE',
  3                               column_name     => 'ID',
  4                               policy_name     => 'REDACT_EMPLOYEE',
  5                               function_type   => DBMS_REDACT.RANDOM,
  6                               action          => DBMS_REDACT.MODIFY_COLUMN);
  7  END;
  8  /
PL/SQL procedure successfully completed.

SQL> BEGIN
  2     DBMS_REDACT.alter_policy (object_name     => 'EMPLOYEE',
  3                               column_name     => 'NAME',
  4                               policy_name     => 'REDACT_EMPLOYEE',
  5                               function_type   => DBMS_REDACT.RANDOM,
  6                               action          => DBMS_REDACT.MODIFY_COLUMN);
  7  END;
  8  /
PL/SQL procedure successfully completed.

SQL> BEGIN
  2     DBMS_REDACT.alter_policy (object_name     => 'EMPLOYEE',
  3                               column_name     => 'JOIN_DATE',
  4                               policy_name     => 'REDACT_EMPLOYEE',
  5                               function_type   => DBMS_REDACT.RANDOM,
  6                               action          => DBMS_REDACT.MODIFY_COLUMN);
  7  END;
  8  /
PL/SQL procedure successfully completed.

SQL> select * from EMPLOYEE;

        ID NAME                 JOIN_DATE
---------- -------------------- ------------------------------
         8 N(#i                 23-AUG-80 05.25.47.000000 AM
         5 SG*cK                11-DEC-90 04.19.26.000000 AM

As I've mentioned in the beginning of this post, once a user has the EXEMPT REDACTION POLICY system privilege it means that he is authotized to view the original data. Let's connect with user SYS and grant EXEMPT REDACTION POLICY to user "pini":
SQL> grant EXEMPT REDACTION POLICY to pini;
Grant succeeded.

SQL> connect pini/pini@//isrvmrh541:1521/pinidb
Connected.
SQL> select * from EMPLOYEE;

        ID NAME                 JOIN_DATE
---------- -------------------- ------------------------------
         1 PINI                 08-DEC-15 03.33.27.000000 PM
         2 DAVID                08-DEC-15 03.33.28.000000 PM
As you can see, now user "pini" is able to view the original "confidential" data because he has the EXEMPT REDACTION POLICY privilege.

    License

    The data redaction feature is available as part of the "Advanced Security" option. The "Advanced Security" option is an extra cost option to the Enterprise Edition.

    Useful Links

    Monday, November 23, 2015

    Review of Oracle 12c Unified Auditing

    Introduction

    Prior to Oracle 12c there were several tables in the Database that stored audit trails:
    1. SYS.AUD$ (also accessible through DBA_AUDIT_TRAIL view) which is the main database audit trail 
    2. SYS.FGA_LOG$ (also accessible through DBA_FGA_AUDIT_TRAIL view)  for the Fine-Grained auditing records
    3. DVSYS.AUDIT_TRAIL$ for the Label security and DB Vault
    In Oracle Database version 12c, Oracle introduced a new feature named "Unified Auditing" which basically consolidates all the audit trails into one single view - UNIFIED_AUDIT_TRAIL. There is no option to write audit records to the operating system.

    This feature is also introducing a new set of predefined audit policies and you can also create your own audit policies - they could be either simple or more complex depends on what you need. 
    For example, you can create audit policy that audits delete statements on specific tables (ORDERS and ORDER_LINE tables for example) by a specific user (user SALES for example) on a specific PDB (PDB named PROD for example).

    You can choose whether you want to have one policy that will contain all the audit settings for your database or several audit policies. Personally, I believe that having less policies and even one single policy enabled for your database is better because it has lower overhead on your Oracle instance.
    You can view all the audit policies that are configured in your database using AUDIT_UNIFIED_POLICIES dictionary view as you can see in the following example:
    SQL> select distinct policy_name
         from audit_unified_policies;
    
    POLICY_NAME
    -----------------------------------
    ORA_CIS_RECOMMENDATIONS
    ORA_LOGON_FAILURES
    ORA_RAS_POLICY_MGMT
    ORA_DATABASE_PARAMETER
    ORA_RAS_SESSION_MGMT
    ORA_ACCOUNT_MGMT
    ORA_DV_AUDPOL
    ORA_SECURECONFIG
    
    8 rows selected.
    

    Each policy contains one or more auditing options. Each auditing option has its type. Let's view all the auditing option types that the "ORA_SECURECONFIG" policy contains:
    SQL> select distinct audit_option_type
         from audit_unified_policies
         where policy_name ='ORA_SECURECONFIG';
    
    AUDIT_OPTION_TYPE
    ------------------
    SYSTEM PRIVILEGE
    STANDARD ACTION
    OBJECT ACTION
    
    

    Now, let's view all the audit options that defined in the "ORA_SECURECONFIG" policy and their type is "SYSTEM PRIVILEGE".
    SQL> select policy_name, audit_option
         from audit_unified_policies
         where policy_name = 'ORA_SECURECONFIG' AND audit_option_type = 'SYSTEM PRIVILEGE';
    
    POLICY_NAME          AUDIT_OPTION
    -------------------- ----------------------------------------
    ORA_SECURECONFIG     LOGMINING
    ORA_SECURECONFIG     TRANSLATE ANY SQL
    ORA_SECURECONFIG     EXEMPT REDACTION POLICY
    ORA_SECURECONFIG     PURGE DBA_RECYCLEBIN
    ORA_SECURECONFIG     ADMINISTER KEY MANAGEMENT
    ORA_SECURECONFIG     DROP ANY SQL TRANSLATION PROFILE
    ORA_SECURECONFIG     ALTER ANY SQL TRANSLATION PROFILE
    ORA_SECURECONFIG     CREATE ANY SQL TRANSLATION PROFILE
    ORA_SECURECONFIG     CREATE SQL TRANSLATION PROFILE
    ORA_SECURECONFIG     CREATE EXTERNAL JOB
    ORA_SECURECONFIG     CREATE ANY JOB
    
    POLICY_NAME          AUDIT_OPTION
    -------------------- ----------------------------------------
    ORA_SECURECONFIG     GRANT ANY OBJECT PRIVILEGE
    ORA_SECURECONFIG     EXEMPT ACCESS POLICY
    ORA_SECURECONFIG     CREATE ANY LIBRARY
    ORA_SECURECONFIG     GRANT ANY PRIVILEGE
    ORA_SECURECONFIG     DROP ANY PROCEDURE
    ORA_SECURECONFIG     ALTER ANY PROCEDURE
    ORA_SECURECONFIG     CREATE ANY PROCEDURE
    ORA_SECURECONFIG     ALTER DATABASE
    ORA_SECURECONFIG     GRANT ANY ROLE
    ORA_SECURECONFIG     DROP PUBLIC SYNONYM
    ORA_SECURECONFIG     CREATE PUBLIC SYNONYM
    
    POLICY_NAME          AUDIT_OPTION
    -------------------- ----------------------------------------
    ORA_SECURECONFIG     DROP ANY TABLE
    ORA_SECURECONFIG     ALTER ANY TABLE
    ORA_SECURECONFIG     CREATE ANY TABLE
    ORA_SECURECONFIG     DROP USER
    ORA_SECURECONFIG     CREATE USER
    ORA_SECURECONFIG     AUDIT SYSTEM
    ORA_SECURECONFIG     ALTER SYSTEM
    
    29 rows selected.
    
    


    Is this feature enabled by default?

    I have a new Oracle 12c instance so let's check if this feature is enabled using V$OPTION :
    SQL> select value
      2  from V$OPTION
      3  where parameter = 'Unified Auditing';
    
    VALUE
    -------------------------------------------
    FALSE
    

    Does this mean that the feature is disabled?
    Well, not Exactly. 

    When you install a new Oracle Database 12c or upgrade to Oracle Database 12c then by default it's configured to work in a "Mixed Mode". Mixed Mode allows you to run the traditional auditing (like you used prior to Oracle 12c) and also benefit the new 12c audit policies. It even has the ORA_SECURECONFIG and ORA_LOGON_FAILURES audit policies enabled by default (so don't be surprised that you see some records in the new UNIFIED_AUDIT_TRAIL view). You can verify which audit policies are enabled in your database using AUDIT_UNIFIED_ENABLED_POLICIES dictionary view. See the following screenshot as an example:
    SQL> select *
         FROM audit_unified_enabled_policies;
    
    USER_NAME            POLICY_NAME          ENABLED_ SUCCESS    FAILURE
    -------------------- -------------------- -------- ---------- ----------
    ALL USERS            ORA_SECURECONFIG     BY       YES        YES
    ALL USERS            ORA_LOGON_FAILURES   BY       NO         YES
    

    As I've mentioned, in this configuration Oracle will support both the traditional auditing and the new 12c audit policies so you may find new records written into the pre-12c audit trail - DBA_AUDIT_TRAIL dictionary view and also into the new UNIFIED_AUDIT_TRAIL dictionary view.
    Once you will decide that you want to enable the "Pure" unified auditing, Oracle will ignore the "old" AUDIT_TRAIL parameter and will also stop writing records to the old audit trails and will write trail records only to the new UNIFIED_AUDIT_TRAIL dictionary view.

    What other benefits the Unified Auditing feature provides?


    Performance

    Prior to Oracle 12c, if you configures auditing per execution (per "Action"), for example, let's say you configured auditing for every INSERT command by users SALES; in this case, every insert statement by user SALES will insert a row to the SYS.AUD$ table as an autonomous transaction which will obviously generate redo, undo, and perform a commit at the end of the transaction. Until this autonomous transaction is completed, the session will have to wait. In Oracle 12c Unified Auditing, the audit records will be written into an SGA queue and periodically, a dedicated background process will write the records to the AUDSYS schema in the SYSAUX tablespace in order to ensure that the data is persistent.

    Note:
    The SGA queue for the unified auditing default size is 1 MB, but can be adjusted to a value of [1,30] via the UNIFIED_AUDIT_SGA_QUEUE_SIZE initialization parameter.

    You may now ask yourself - does that mean that in a crash scenario soe audits records may be lost? The answer is yes; some audit records may be lost. There's always a trade-off between protection and performance. However, if you prefer to have 100% protection for the audit records in the cost of impacting your database performance you can change this default behavior and tell Oracle to write the audit trails records into the AUDSYS schema immediately (see the "Managing the Unified Audit Trail" section).

    Security

    Prior to Oracle 12c, if you chose to write the audit trail to the DB (audit_tail='db') then all the records will be written to SYS.AUD$ table, which means that the DBA can modify this table. In Oracle 12c Unified Auditing the DBA can't modify the audited information because the base X$ table behind the UNIFIED_AUDIT_TRAIL dictionary view is decrypted.

    How to enable the Pure Unified Auditing

    In order to enable to Pure Unified Auditing you will need to perform the following steps:
    1. Shutdown your Oracle Databases and listeners that are associated to the Oracle Home
    2. Relink the Oracle executable to support the Unified Auditing
    3. Start your Oracle instances and listener
    In order to relink the Oracle executable you will need to execute the "make" command from the $ORACLE_HOME/rdbms/lib directory:

    make -f ins_rdbms.mk uniaud_on ioracle

    Now, after the relink has been completed, let's query V$OPTION again to verify that the Unified Auditing feature is enabled:
    SQL> select value
         from V$OPTION
         where parameter = 'Unified Auditing';
    
    VALUE
    -------------------------------------------
    TRUE
    

    Changing the default audit trail write mode 

    As I've mentioned earlier in this article, this feature offers a great performance improvement by not writing the audit trails immediately, but rather writing into a dedicated SGA queue and periodically writing the audit trails persistenly.

    You can change the default write mode (Queued-write mode) to be Immediate-write mode using the DBMS_AUDIT_MGMT package, as follows:

    BEGIN
     DBMS_AUDIT_MGMT.SET_AUDIT_TRAIL_PROPERTY(
      DBMS_AUDIT_MGMT.AUDIT_TRAIL_UNIFIED,
      DBMS_AUDIT_MGMT.AUDIT_TRAIL_WRITE_MODE, 
      DBMS_AUDIT_MGMT.AUDIT_TRAIL_IMMEDIATE_WRITE);
    END;
    /

    Summary

    The Unified Auditing is a great security feature that was introduced in Oracle 12c. It offers a simple management for unified (consolidated) auditing that can be accessed via a single dictionary view - UNIFIED_AUDIT_TRAIL. It also provides major security and performance enhancements.

    Useful Links

    More information and details are available in the Oracle documentation:

    Tuesday, November 17, 2015

    How to enable extended data types in Oracle 12c?

    Introduction

    One of the coolest features that were introduced in Oracle 12c (in version 12.1.0.1) is the Extended Data Types which makes the maximum size limit of VARCHAR2, NVARCHAR2 and RAW data types to be 32767 bytes.
    In earlier releases (i.e. prior Oracle 12c) the maximum size limit for VARCHAR2, NVARCHAR2 data types was 4000 bytes and for RAW data types was 2000 bytes.

    How to enable extended data types in Oracle 12c?

    In order to enable support for extended data types, you will have to perform the following steps:
    1. SHUTDOWN IMMEDIATE;
    2. STARTUP UPGRADE;
    3. ALTER SYSTEM SET MAX_STRING_SIZE = EXTENDED; (instead of STANDARD)
    4. @$ORACLE_HOME/rdbms/admin/utl32k.​sql (execute it as SYSDBA)
    5. Restart the Oracle instance

    Conclusion

    Before Oracle 12c in order to support strings longer than 4000 bytes we mainly used LOB. If you decide to enable this feature you will need to take into account that internally Oracle is storing these extended types in out-of-line LOB segments but you can't manage these lob segments using DBMS_LOB as Oracle is managing them internally.
    From my point of view I think this feature can be useful although its biggest disadvantage is that it requires downtime to enable it which can be problematic for many Oracle customers.

    Another 12c new feature - Invisible Columns

    Introduction

    In my previous post I've demonstrated the In-Database archiving feature that was introduced in Oracle 12c (in version 12.1.0.1 to be more specific) and enables you to mark some rows as invisible to the application.
    In this post, I'd like to demonstrate the invisible columns feature which allows you to mark a specific column or set of columns as invisible. You can either mark the columns as invisible as part of the CREATE TABLE command, or as part of the ALTER TABLE command.

    If you will execute a SELECT * from the table, the invisible columns will not be displayed in the output of the select statement; however, if you will explicitly specify these columns as part of the SELECT statement they will be displayed in the output of the select statement.
    If you will execute an INSERT statement and you don't specify the columns, the INSERT will work; however, you can insert value to the invisible columns if you will explicitly specify the invisible columns as part of the INSERT statement.

    Demonstration

    Let's see a quick demonstration of this feature. In this demonstration I will perform the following steps:
    1. create a new table named "TEST" with 2 columns:
      • ID - VISIBLE (default)
      • NAME - INVISIBLE
    2. insert a row to the table without specifying the column - the insert statement will fail because it expects only 1 value for the ID column 
    3. insert a row to the tame - this time I explicitly specify the columns and and the insert statement works
    4. execute SELECT * from the table and see that only the ID column is displayed
    5. execute the select query again - but this time explicitly specify the columns - now both the ID and NAME columns are displayed
    6. execute the DESC command on the table - the NAME column is not being displayed as part of the DESC command output
    7. Changing the column to be visible using the ALTER TABLE command - this time the DESC command displays the NAME column





























    Invisible columns and constraints

    Oracle enforce integrity constraints for columns that are configured to be invisible like any other column. To demonstrate this, I will make the "NAME" column invisible again and then I will create the NOT NULL constraint and I will try to insert a value to the ID column only. This attempt will fail with ORA-01400 because it's impossible to insert a NULL value to the NAME column:












    Conclusions

    The Invisible columns is a very simple and straight-forward feature which can be useful if you would like to add a new column to a table but at the first stage you don't want that the application will be affected by the new column. SELECT * and INSERT statements will continue to function normal (unless an integrity constraint on the invisible column was violated), and in the moment that you decide that you want to make the column visible, you can manage to do so in a single command (ALTER TABLE table_name MODIFY column_name VISIBLE).

    Sunday, November 15, 2015

    12c New feature - Invisible Rows A.K.A In-Database Archiving

    Introduction

    In Oracle Database 12c (12.1.0.1 to be more specific) Oracle introduced a new feature named "In-Database Archiving" which allows to mark specific rows as invisible (archived) so they will not be visible. For example, if someone queries a table that is configured with this feature enabled then all the rows that are marked as archived will be invisible unless the session has enabled to see archived data. The rows that are archived can be compressed in order to reduce the storage of the database and also improve backup performance.

    So how does it work?

    In order to configure a table with the In-Database Archiving feature enable, you will need to use the ROW ARCHIVAL clause during the CREATE TABLE command, or if the table already exists then you can use the ROW ARCHIVAL clause using the ALTER TABLE command.
    Once you enable this feature, Oracle will create additional column named ORA_ARCHIVE_STATE. By default, this column contains the value '0' for each row which means that the row is visible. If you will change to value to be '1' then the row will be invisible. If you will disable this feature using the ALTER TABLE ... NO ARCHIVAL command then Oracle will automatically drop
    this column.

    Demonstration

    In this demonstration I will perform the following steps:
    1. Create a new table named "test" and enable the ROW Archival feature for this table
    2. Populate the table with 2 rows
    3. Query the table including the ORA_ARCHIVE_STATE column to see that that the additional column contains only the default '0' values:
    4. Mark "David" as invisible by changing the ORA_ARCHIVE_STATE  value to be '1'
    5. Query again the table to verify that "David" is actually invisible
    6. Allow the session to view the invisible data using the ALTER SESSION SET ROW ARCHIVAL VISIBILITY = ALL command
    7. Query again the table to verify that "David" is now visible
    8. Prohibit the session from viewing the invisible data using the ALTER SESSION SET ROW ARCHIVAL VISIBILITY = ACTIVE command
    9. Query again the table to verify that "David" is now invisible again
    10. Disable the In-Database Archiving feature for the table using the ALTER TABLE ... NO ARCHIVAL command
    11. Query the table to verify that the ORA_ARCHIVE_STATE column has been dropped













































    Useful Links:

    Wednesday, November 4, 2015

    Oracle Automatic Maintenance Tasks

    Introduction

    The Oracle automatic maintenance tasks were introduced in version 11g in order to automate tasks that Oracle DBAs used to do manually in the past (i.e. in earlier versions such as 9i, 10g).
    This includes the following predefined automated maintenance tasks:

    • Automatic Optimizer Statistics Collection - Collecting optimizer statistics for objects with stale or missing statistics
    • Automatics Segment Advisor - Collecting storage-related information for segments in order to provide Segment Recommendations on those segments
    • Automatic SQL Tuning Advisor - Collecting performance-related information for SQL Statements in order to provide SQL Tuning recommendations

    In Oracle 12c the following maintenance task has been added:
    • SQL Plan Management (SPM) Evolve Advisor - Collecting information about SQL execution plans in order to automatically evolve execution plans as part of the SQL Plan Management feature

    Demonstration

    You can query DBA_AUTOTASK_OERATION in order to see all the automatic maintenance tasks along with their status (whether it's enabled or disabled):





























    You may ask yourself when these jobs are actually running?
    The answer is during the Maintenance Windows 
    You can check the maintenance windows that are defined for each automatic task using DBA_AUTOTASK_WINDOW_CLIENTS
    Following is an example:


    The above are 7 predefined maintenance windows that are enabled by default when you install Oracle. If you'd like to see more information for each window you can query DBA_SCHEDULER_WINDOWS and it will display the exact time and duration for each window as well as the associated resource plan. You can modify the maintanence window settings using the SET_ATTRIBUTE procedure of the DBMS_SCHEDULER package. Read more here.

    Please note that during the time window Oracle will create a scheduler job for the automatic task and once the job is completed Oracle will drop it, so don't be surprised that you can find the jobs in DBA_SCHEDULER_JOBS. You can find historical automated tasks information using DBA_AUTOTASK_JOB_HISTORY below is an example:





























    You can manually disable (or enable) all the maintenance tasks using the DBMS_AUTO_TASK_ADMIN package, for example:
    EXECUTE DBMS_AUTO_TASK_ADMIN.DISABLE;

    You can also disable or enable a particular maintenance task. Following is an example of how to disable the sql tuning advisor maintenance task
    BEGIN
      dbms_auto_task_admin.disable(
        client_name => 'sql tuning advisor',
        operation   => NULL,
        window_name => NULL);
    END;
    /

    If you want to disable to enable a particular maintenance task only for a particular maintenance window, you can use the "window_name" parameter. Following is an example of how to disable the sql tuning advisor maintenance task only for the SATURDAY_WINDOW:
    BEGIN
      dbms_auto_task_admin.disable(
        client_name => 'sql tuning advisor',
        operation   => NULL,
        window_name => 'SATURDAY_WINDOW');
    END;
    /


    Summary

    The goal of this post was to shed light on the automatic maintenance tasks feature which is very useful but you need to aware of its behavior. In this post, I've covered the following items:
    • Pre-defined automatic maintenance tasks in 11g & 12c
    • Maintanence windows and how to determine their start time and duration
    • Viewing historical automated tasks information (time, status, etc.)
    • Disabling/enabling automated tasks

    Friday, October 30, 2015

    Oracle OpenWorld 2015 - Summary

    This year I attended the Oracle OpenWorld conference for the second time (my first time was last year), and it was amazing! Many customers came to visit Dell's booth to learn about our Oracle-related solutions for monitoring, replication, management, etc. The sessions were really good and Elton John gave a great show at the appreciation event.

    Below are some pictures of myself having fun and also explaining about the advantages of Foglight for Oracle to the conference attendees who came to visit Dell's booth:










    Wednesday, October 21, 2015

    Oracle OpenWorld 2015 is taking place next week!

    As you probably know, Oracle OpenWorld 2015 is taking place next week (October 25-29, 2015).
    I'd like to invite you all to visit Dell's booth #601 and learn how Dell can help you maximize your Oracle investment by improving database performance, administration, change management, and more.

    You can meet me at at Dell's booth and I'd be happy to show you how Oracle DBAs are winning performance challenges using Foglight for Oracle



    Monday, October 12, 2015

    12.1.0.2 New Feature - PDB State Management Across CDB Restart

    Introduction

    In this post I'd like to review a very useful feature that was introduced in version 12.1.0.2 - PDB State Management Across CDB Restart. In version 12.1.0.1, after instance restart you will notice that the Pluggable Databases (PDBs) are MOUNTED, i.e. they are not accesible to the users. It doesn't matter if before the restart the PDB was MOUNTED or OPEN, in any case after the restart it will be MOUNTED. let's see a demonstartion for that:

























    This means that after every restart of the instance DBA need to manually start the Pluggable Databases in order to make it accessible to the users.

    12.1.0.2 solution - "Save State" clause

    The solution for this behaviour was introduced with version 12.1.0.2 which provides an option to execute a command that will set the state of a PDB so in the next time that the instance will be started, the open mode of that PDB will be remains the same as it was when we executed the ALTER PLUGGABLE DATABASE ... SAVE STATE command. Let's see a demonstration

























    As you can see, after I exectued "ALTER PLUGGABLE DATABASE ... SAVE STATE" command, the PDB open mode remains the same (OPEN) after I restarted the instance.

    Few Notes:

    • You can query DBA_PDB_SAVED_STATES dictinoary view which shows information about the current saved PDB states in the CDB.
    • You can discard the state of a PDB in order to make the open mode mounted again in the next instance reboot. Below is a demonstartion of this:






































    Sunday, October 11, 2015

    How to resolve PRVF-0002: could not retrieve local node name

    Introduction

    In this short post I'd like to show you how to resolve error "PRVF-0002: could not retrieve local node name". When I started an Oracle 12.1.0.2 installation on Solaris x86-64 (Version [11.2] Description [SunOS 5.11]) I encountered the following error:





















    Solution

    First, verify that the "hostname" command returns the host name:

    isrvmsol07:ora[43] /oravl01/database> hostname
    isrvmsol07

    Afterwards check that /etc/hosts file, and if you find out that the hostname doesn't appear for the local IP address (127.0.0.1), add the following entry to the /etc/hosts file:

    127.0.0.1       isrvmsol07

    Re-execute the installation and then everything should work properly:







































    Conclusion

    At the start of the installation Oracle performs healthcheck test for forward and reverse resolution of the host name so you can fix it by setting properly the DNS or maunally set the host IP address and name in the /etc/hosts file.

    Wednesday, September 30, 2015

    UNDO_RETENTION behaviour in autoextend undo tabelspace vs. fixed-size undo tablespace

    Introduction

    In this post I'd like to clarify a common misconception regarding the UNDO_RETENTION initialization parameter but first, let's start with a short introduction.
    The Undo Tablespace is a key component in Oracle Databases. It consists of undo segments which hold the "before" images of the data that has been changed by users running transactions. The undo is essential for Rollback operations, Data Concurrency, Read Consistency and is being used by several flashback features (Flashback Query, Flashback Table, Flashback Version Query, Flashback Transaction Query).
    As you probably know, the UNDO_RETENTION initialization parameter specifies the low threshold (in seconds) for the undo retention period. Obviously, this parameter is important and you should bear in mind the different behaviour of this parameter in fixed-size undo tablespace and in autoextend undo tablespace.

    Undo Extent Types - Active/Expired/Unexpired

    Active undo extents are used by running transactions. These extents will never be overwritten as they are needed in order to perform ROLLBACK operations. 
    Expired Undo Extents hold committed information that is older than the UNDO_RETENTION period.
    Unexpired undo Extents hold committed information that its age is less than the UNDO_RETENTION period.

    You can use the following query in order to calculate the distribution of the different extent types:
    select status,
           ROUND (sum_bytes / (1024 * 1024), 0)  MB,
           ROUND ((sum_bytes / undo_size) * 100, 0)  "%"
      from (  select status, SUM (bytes) sum_bytes
                from dba_undo_extents
            group by status),
           (select SUM (a.bytes) undo_size
              from dba_tablespaces c
                   join v$tablespace b
                      on (b.name = c.tablespace_name)
                   join v$datafile a
                      using (ts#)
             where c.contents = 'UNDO')
    
    Sample Output:
    
    STATUS                                 MB        %
    ------------------------------    ----------  ----------
    ACTIVE                               1040         70
    EXPIRED                                27          3
    UNEXPIRED                             418         27
    
    If the ACTIVE percent is 100 it means that all the undo extents contain undo images of running transaction and needed for performing a ROLLBACK operation and none of them can be overwritten therefore you'll get "ORA-30036: unable to extend segment by string in undo tablespace" so you need to make sure that the ACTIVE percent is not close to 100.
    Also, if the UNEXPIRED pecent is close to 100 it means that almost all of the undo extents hold data of committed information that its age is less than the UNDO_RETENTION period so these undo extents may be overwritten and then the chances of encountering "ORA-01555: Snapshot Too Old" will increase. Other option is that you just set you UNDO_RETENTION to be too high and you can verify it by comparing the UNDO_RETENTION to the longest running query (MAXQUERYLEN column in V$UNDOSTAT).

    Fixed-Size Undo Tablespace

    For fixed-size undo tablespaces this parameter is being ignored (unless retention guarantee is enabled) and Oracle will automatically tune for the maximum possible undo retention period, based on the undo tablespace size and undo usage history.

    Autoextend Undo Tablespace

    For autoextend undo tablespace this parameter specifies the minimum retention period the Oracle will attempt to honor. When space in the undo tablespace becomes low (due to running transactions which generate undo records) Oracle will increase the tablespace size (up to the MAXSIZE limit) and once it will reach to the upper limit of the MAXSIZE it will begin to overwrite unexpired undo information therefore the retention period defined in the UNDO_RETENTION period is not guaranteed. This is why the actual period might be lower or even higher. The actual undo retention period can be obtained by querying the TUNED_UNDORETENTION column in V$UNDOSTAT dynamic performance view.
    Note: You can specify RETENTION GUARANTEE (in the CREATE UNDO TABLESPACE or ALTER TABLESPACE commands) and then Oracle never overwrites unexpired undo data even if it means that transactions fail due to lack of space in the undo tablespace.

    Below is an example of a database that I have configured with UNDO_RETENTION of 15 minutes (i.e. UNDO_RETENTION = 900) but because there are queries with higher elapsed time than 900 (in my case the longest query duration is ~23 minutes (=1358 seconds) and therefore V$UNDOSTAT will report on a TUNED_UNDORETENTION which is higher than 900 in many cases (558 to be more specific). Following is a screenshot of my example:


















    Useful Links:

    Wednesday, September 16, 2015

    Wondering why you can't view data with a COMMON USER in Oracle 12c? You probably didn't use the CONTAINER_DATA clause

    Introduction
    Let's say you've created a common user in your Oracle 12c instance and you granted the user permissions to connect and select some specific dynamic views (e.g. V$PDBS, V$CONTAINERS).
    Afterwards, you connect with that common user to the root container (CDB$ROOT), you query V$PDBS but no rows are returned.
    This issue was raised in the OTN forum by a user and my answer to that user was  very simple - use the CONTAINER_DATA clause (See: https://community.oracle.com/message/13301017#13301017).

    Basically, when a common user is connected to the ROOT and it executes a query on a container data object (As per Oracle Doc, container data objects include: V$, GV$, CDB_, and some Automatic Worklaod Repository DBA_HIST* view), then that query will only dispay data for the PDBs which are visible for that common user, and this is what you can set using the CONTAINER_DATA clause.

    Demonstration
    In the first step I'll create a common user, grant him permissions to connect and query V$PDBS and then I'll connect with that user and try to query V$PDBS.
    SQL> select name,open_mode from v$pdbs;
    NAME                           OPEN_MODE
    ------------------------------ ----------
    PDB$SEED                       READ ONLY
    PDBTEST                        MOUNTED
    PINIDB                         READ WRITE
    
    SQL> create user C##TEST identified by test;
    User created.
    
    SQL> grant connect to C##TEST;
    Grant succeeded.
    
    SQL> grant select on sys.v_$pdbs to C##TEST;
    Grant succeeded.
    
    SQL> connect C##TEST/test@isrvmrh541-cdb.world
    Connected.
    
    SQL> select * from v$pdbs;
    no rows selected
    
    As you can see, no rows are returned from the query.
    Let's connect again with SYS and verify which PDBs are visible for user C##TEST using the CDB_CONTAINER_DATA dictionary view which displays information about the user-level and object-level CONTAINER_DATA attributes specific in the CDB:
    SQL> connect sys@isrvmrh541-cdb.world as sysdba
    Enter password:
    Connected.
    
    SQL> SELECT username,
      2         owner,
      3         object_name,
      4         all_containers container_name
      5    FROM CDB_CONTAINER_DATA
      6   WHERE username = 'C##TEST';
    no rows selected
    
    As you can see, user C##TEST has no container data attributes.
    Let's specify that user C##TEST can see the data of V$PDBS from all the containers:
    SQL> alter user C##TEST set container_data=all for sys.v_$pdbs container = current;
    User altered.
    
    SQL> SELECT username,
      2         owner,
      3         object_name,
      4         all_containers,
      5         container_name
      6    FROM CDB_CONTAINER_DATA
      7   WHERE username = 'C##TEST'
      8   ;
    
    USERNAME           OWNER     OBJECT_NAME   ALL_CONTAINERS CONTAINER_NAME
    --------------- ---------- --------------- ------------- --------------------
    C##TEST            SYS      V_$PDBS           Y
    
    As you can see, the CONTAINER_NAME is NULL because I sepcific in the aler command that the container_data will be visible for all containers.
    If we would like to specify that the data of every container data object that the user has SELECT permissions to access, you can remove the "for" clause and execute the following command:
    SQL> alter user C##TEST set container_data=all container = current;
    User altered.
    
    SQL> SELECT username,
      2         owner,
      3         object_name,
      4         all_containers,
      5         container_name
      6    FROM CDB_CONTAINER_DATA
      7   WHERE username = 'C##TEST';
    
    USERNAME           OWNER    OBJECT_NAME    ALL_CONTAINERS CONTAINER_NAME
    --------------- ---------- --------------- ------------- --------------------
    C##TEST            SYS      V_$PDBS            Y
    C##TEST                                        Y
    
    As you can see, now user C##TEST has an access for all the objects which he will granted permissions to SELECT from. 

    Summary
    • Once you create a COMMON USER, you should also specify which PDBs data are visible to that common user for which objects using the CONTAINER_DATA clause
    • You can specify the object-level CONTAINER_DATA attributes for a user using the ALTER USER command
    • You can view the information about the user-level and object-level CONTAINER_DATA attributes via CDB_CONTAINER_DATA dictionary view

    Useful Links:

    Friday, September 11, 2015

    The new Oracle Edition - "Standard Edition 2" has been released!

    The new Oracle Edition, Standard Edition 2 has been released (on September 1st) and is available for download as version 12.1.0.2 at: http://www.oracle.com/technetwork/database/enterprise-edition/downloads/index.html

    So far 12.1.0.2 was available only for the Enterprise Edition so with this new edition, customers who are using 12.1.0.1 with the Standard Edition, can finally upgrade to 12.1.0.2

    This new edition will replace the Standard Edition and Standard Edition one, therefore 12.1.0.1 is the last version that offers the Standard Edition and Standard Edition One. Standard Edition 2 will cost exactly the same as Standard Edition (as per Oracle global price list, it costs 17,500$ per processor), therefore customers who are using Standard Edition One (as per Oracle global price list, it costs 5,800$ per processor) and would like to upgrade to Standard Edition 2, will need to pay an extra charge in order to benefit the advantages of Standard Edition 2 (such as using Real Application Clusters). For customers who are using 12.1.0.1 Standard Edition or Standard Edition One, the permier support is available until september 1st, 2016

    Notes:

    1. Standard Edition 2 is limited to 2 CPU sockets per system (Standard Edition was limited to 4)
    2. RAC with Standard Edition 2 is limited to 2 nodes (1 CPU socket per node)
    3. Standard Edition 2 is limited to 16 CPU threads per system (Standard Edition was unlimited)
    4. RAC with Standard Edition 2 is limited to 8 CPU threads per node


    Useful Links:

    Monday, September 7, 2015

    Table point in-time recovery using RMAN

    Introduction
    In this post I'd like to present a new 12c feature - RMAN table point in time recovery.
    This feature allows to perform a recovery for a specific table or table partition via RMAN, and it can be very useful in the following cases :
    • The table was truncated - so you can't use the 10g Flashback Table feature as the undo is not available
    • The table was dropped with the purge clause -so you can't use the 10g Flashback Drop feature
    • Table was logically corrupted and no undo is available - so you can't use the 10g Flashback Table feature
    • Table was logically corrupted and a DDL operation modified the structure of the table - so you can't use the 10g Flashback Table feature in order to flashback the table prior to the DDL
    In order to overcome this scenarios before Oracle 12c you could recover the entire database to a point in time recovery - however, you will also recover all the other objects to the same point in time which will result in a data loss.
    A better option would be to perform a tablespace point-in-time-recovery (only available for the Enterprise Edition) which means that you can recovery the entire tablespace of that table to an auxiliary instance and then manually export and import the table to the target database.
    The new feature in Oracle 12c performs all this automatically.

    Prerequisites
    In order to use this feaute you must have a backup of the tablespace/s for the selected table/tables because during the recover process Oracle will automatically perform point in time recovery using those tablespaces and then it will export the table/s from the auxiliary (temporary) instance and then it will import the data into the target (source) instance.

    Demonstration:
    In this demonstration I'm connected with user "pini", creating a table "emp" and inserts 1 row and then commit it:
    SQL> show user;
    USER is "PINI"
    SQL> create table emp (id number, name varchar2(20));
    Table created.
    SQL> insert into emp values (1, 'DAVID');
    1 row created.
    SQL> commit;
    Commit complete.
    
    Now, I check what's the current SCN so I can use it later in the RMAN RECOVER command (RMAN supports point-in-time-recovery until SCN or TIME or SEQUENCE)
    SQL> select current_scn from v$database;
    CURRENT_SCN
    -----------
       25427549
    
    Now I will drop it with the "purge" option (so the flashback drop feature is irrelevant):
    SQL> drop table emp purge;
    Table dropped.
    
    The next step would be to connect to RMAN and execute the RECOVER TABLE command.
    You should also specify the auxiliary destination which is the location of the auxiliary database files and also the Data Pump Export Dump File:
    RMAN> recover table pini.emp until scn 25427549 auxiliary destination '/oravl01/recover';
    
    Starting recover at 07-SEP-15
    using channel ORA_DISK_1
    RMAN-05026: WARNING: presuming following set of tablespaces applies to specified Point-in-Time
    
    List of tablespaces expected to have UNDO segments
    Tablespace SYSTEM
    Tablespace UNDOTBS1
    
    Creating automatic instance, with SID='Fkyk'
    
    initialization parameters used for automatic instance:
    db_name=O12102NP
    db_unique_name=Fkyk_pitr_O12102NP
    compatible=12.1.0.2.0
    db_block_size=8192
    db_files=200
    diagnostic_dest=/oravl01/oracle
    _system_trig_enabled=FALSE
    sga_target=1024M
    processes=200
    db_create_file_dest=/oravl01/recover
    log_archive_dest_1='location=/oravl01/recover'
    #No auxiliary parameter file used
    ...
    ...
    ...
    ...
    Performing import of tables...
       IMPDP> Master table "SYS"."TSPITR_IMP_Fkyk_kvas" successfully loaded/unloaded
       IMPDP> Starting "SYS"."TSPITR_IMP_Fkyk_kvas":
       IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE
       IMPDP> Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
       IMPDP> . . imported "PINI"."EMP"                                5.476 KB       1 rows
       IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/TABLE_STATISTICS
       IMPDP> Processing object type TABLE_EXPORT/TABLE/STATISTICS/MARKER
       IMPDP> Job "SYS"."TSPITR_IMP_Fkyk_kvas" successfully completed at Mon Sep 7 14:13:05 2015 elapsed 0 00:00:11
    Import completed
    
    
    Removing automatic instance
    Automatic instance removed
    auxiliary instance file /oravl01/recover/O12102NP/datafile/o1_mf_temp_bytw2co8_.tmp deleted
    auxiliary instance file /oravl01/recover/FKYK_PITR_O12102NP/onlinelog/o1_mf_3_bytw4md4_.log deleted
    auxiliary instance file /oravl01/recover/FKYK_PITR_O12102NP/onlinelog/o1_mf_2_bytw4m1t_.log deleted
    auxiliary instance file /oravl01/recover/FKYK_PITR_O12102NP/onlinelog/o1_mf_1_bytw4lhq_.log deleted
    auxiliary instance file /oravl01/recover/FKYK_PITR_O12102NP/datafile/o1_mf_users_bytw4gos_.dbf deleted
    auxiliary instance file /oravl01/recover/O12102NP/datafile/o1_mf_sysaux_bytvy598_.dbf deleted
    auxiliary instance file /oravl01/recover/O12102NP/datafile/o1_mf_undotbs1_bytvy590_.dbf deleted
    auxiliary instance file /oravl01/recover/O12102NP/datafile/o1_mf_system_bytvy59h_.dbf deleted
    auxiliary instance file /oravl01/recover/O12102NP/controlfile/o1_mf_bytvxw4w_.ctl deleted
    auxiliary instance file tspitr_Fkyk_10996.dmp deleted
    Finished recover at 07-SEP-15
    
    That's it!
    The EMP table is now available in the source instance with the data which is relevant to the selected time period (in my case to SCN 25427549):
    SQL> select * from emp;
            ID NAME
    ---------- --------------------
             1 DAVID
    

    Few Notes:
    • You can specify a different location for the dump file using the DATAPUMP DESTINATION clause
    • During the last step of this process, i.e. during the import step, you may choose to import the table to a new table name and not to its original name using the REMAP TABLE clause
    • During the last step of this process, i.e. during the import step, you may choose to import the table to a new tablespace and not to its original tablespace using the REMAP TABLESPACE clause
    • If you prefer to have a dump file point in time export backup without actually importing it backup to the target (source) database, use the NOTABLEIMPORT clause
    Conclusions
    • This feature requires minimum work and effort from the DBA
    • Due to the fact that as part of the recovery process RMAN needs to restore an auxiliary instance, and also export and import the relevant table/s, this whole process has an overhead (mainly in terms of I/O load), therefore If you can use other options for recovering the table (such as Flashback Table/Flashback Drop) you should use them and avoid using this feature. Also, table-recovery using this feature takes much longer than using the Flashback drop/Flashback table
    • When you can't use Flashback drop/Flashback table to recover the table, you may find this feature very useful.
    • This feature is available with the Enterprise Edition only