Configure a pluggable Oracle database

Datastream supports Oracle multi-tenant architecture, where a single container database (CDB) contains one or more pluggable databases (PDBs). Each pluggable database is a self-contained database with a unique ID and name, and can be managed independently.

To configure a self-hosted Oracle pluggable database so that you can use it with Datastream, perform the following steps:

  1. Verify that your database is running in ARCHIVELOG mode. To do so, run the following command from the CDB$ROOT container:

    SELECT LOG_MODE FROM V$DATABASE;

    1. If the result is ARCHIVELOG, then move on to step 2.
    2. If the result is NOARCHIVELOG, then you'll need to enable ARCHIVELOG mode for your database.
    3. Run the following commands when logged in as SYSDBA:

      SHUTDOWN IMMEDIATE;
      STARTUP MOUNT;
      ALTER DATABASE ARCHIVELOG;
      ALTER DATABASE OPEN;
      
    4. Archived log files consume disk space, so you'll want to configure the DB_RECOVERY_FILE_DEST_SIZE parameter for your database. Use this parameter to specify (in bytes) the hard limit on the total space to be used by target database recovery files. By setting this parameter, you can manage the tradeoff between protecting the database from running out of disk space and the stream failing because of log position loss.

  2. Define a data retention policy for your database by running the following Oracle Recovery Manager (RMAN) command from the CDB$ROOT container:

    CONFIGURE RETENTION POLICY TO RECOVERY WINDOW OF 4 DAYS;
    

    The command defines the data retention policy for all pluggable databases in your container database.

    We recommend that you retain backups and archive logs for a minimum of 4 days, and 7 days is recommended.

  3. Return to the SQL prompt of the database tool that you're using to configure the Oracle log file rotation policy. We recommend setting a maximum log file size of no more than 512MB.

  4. Enable supplemental log data. To do so, first enable supplemental logging on the database at the CDB$ROOT container level by running the following command:

    ALTER DATABASE ADD SUPPLEMENTAL LOG DATA;
    

    Next, choose whether to turn on logging for specific tables or the entire pluggable database.

    To log changes only for specific tables, connect to the pluggable database container and run the following command for each table that you want to replicate:

    ALTER TABLE SCHEMA.TABLE ADD SUPPLEMENTAL LOG DATA (ALL) COLUMNS
    

    Replace the following:

    • SCHEMA: the name of the schema that contains the table.
    • TABLE: the name of the table for which you want to log changes.

    To replicate multiple or all tables in your database, consider turning logging on for the entire database.

    Run the following command to enable supplemental log data for the entire database:

    ALTER DATABASE ADD SUPPLEMENTAL LOG DATA (ALL) COLUMNS;
    
  5. Create a common user. A common user has the same identity in the CDB$ROOT container and in the pluggable databases. A common user can connect to and perform operations within the CDB$ROOT container, and within any pluggable database in which it has privileges. The common username must start with C## or c##.

  6. Grant the appropriate privileges to the common user that will be used to connect to your database. Different permissions are required at the CDB$ROOT container and pluggable database levels.

    • Connect to the CDB$ROOT container and run the following commands:
    GRANT CREATE SESSION TO USER_NAME;
    GRANT SET CONTAINER TO USER_NAME;
    GRANT SELECT ON SYS.V_$DATABASE TO USER_NAME;
    GRANT SELECT ON SYS.V_$LOGMNR_CONTENTS TO USER_NAME;
    GRANT EXECUTE ON DBMS_LOGMNR TO USER_NAME;
    GRANT EXECUTE ON DBMS_LOGMNR_D TO USER_NAME;
    GRANT LOGMINING TO USER_NAME;
    GRANT EXECUTE_CATALOG_ROLE TO USER_NAME;
    
    • Connect to the pluggable database and run the following commands:
    GRANT CREATE SESSION TO USER_NAME;
    GRANT SET CONTAINER TO USER_NAME;
    GRANT SELECT ANY TABLE TO USER_NAME;
    GRANT SELECT ON SYS.V_$DATABASE TO USER_NAME;
    GRANT SELECT ON SYS.V_$ARCHIVED_LOG TO USER_NAME;
    GRANT SELECT ON DBA_SUPPLEMENTAL_LOGGING TO USER_NAME;