Ilmar Kerm

Oracle, databases, Linux and maybe more

There are a few Oracle database replication solutions on the market:

  • Oracle Streams (powerful, included with RDBMS license (Oracle SE has trigger-based capture, EE mines redo logs and log buffer), but deprecated – no longer developed, complex to manage)
  • Oracle GoldenGate (powerful, but very expensive)
  • Tungsten (heterogeneous, but from Oracle side requires deprecated CDC and complex to set up – one interesting feature, you can write data modification plugins before data is applied on target)
  • DBVisit (pretty inexpensive compared to GoldenGate, but powerful)

In this blog post I’ll give a short overview of DBVisit Replicate, that can be used to replicate data real time between two Oracle databases or from Oracle to MySQL/MSSQL. I am not connected to DBVisit company in any way and I was testing their replication solution for a client of mine.

A few interesting key concepts behind DBVisit Replicate:

  • It uses optimistic apply on the target side, meaning that data changes are replicated and applied (but not committed) to the target even before transaction is committed on the source. In case of rollback, the target database needs to roll back all the changes too. Positive side is that committed transactions get replicated to the target faster, even if the transaction is large.
  • DBVisit uses its own change capture process to mine online redo logs, so it does not depend on triggers to log the changes and does not impact the end user session. The potential downside – Oracle can change the internal structure of redo logs any time, so before upgrading the database check the DBVisit compatibility first.
  • DBVisit can run its CPU intensive processing on a different server, so it does not waste expensive CPU cycles on the Oracle DB server. This is called 3-tier architecture in DBVisit. In this architecture source database only needs to run small FETCHER process, that sends redo log changes over a network to a dedicated MINE process/server that actually does to log processing. MINE filters out the required database changes and sends this processed information over network to APPLY process. APPLY then connects to the target database over OCI (so it does not need to be running on the target database server) and executes the DML statements. (Note: fetcher process is optional, so by default dbvisit runs mine process on the source database server).

DBVisit is very easy to install and it supports RAC and ASM. My setup is done on 11.2.0.3 3-node RAC+ASM running on Oracle Linux 5.8. For Grid Infrastructure (ASM) role separation is in use (GI runs under different OS account than RDBMS). I’m using DBVisit Replicate 2.4.21 (unreleased currently, but it contains a many bug fixes needed for my environment).

In my following easy test setup:

  • I’m using the default 2-tier architecture, so no fetcher process. Apply also runs in the same host as the target database.
  • I’m using TAR version of the dbvisit software (not RPM), so I could have a single shared copy of the software for all servers in the configuration. If you use RPM, then the same RPM package needs to be installed on all servers (and you need root privileges). In my case I’m using OCFS2 filesystem and dbvisit software is extracted to /u02/app/oracle/dbvisit.
  • For processing area for each dbvisit process I’m using /u03/dbvisit/pte in this example. In my current case it is also on an OCFS2 filesystem and shared between all servers, but it does not have to be and when I move this setup to production, I’ll also use 3-tier architecture and local disks.
  • Grid Infrastructure and ASM run under OS account grid.
  • I’m using IP 10.0.0.1 as the server address where MINE is running.
  • I’m using IP 10.0.0.2 as the server address where APPLY is running.

First execute the only executable file in dbvisit replicate installation package dbvrep and execute and complete the initialization wizard.

[oracle@jfadboc1n02.jfa.unibet.com pte]$ /u02/app/oracle/dbvisit/replicate/dbvrep
Initializing......done
Dbvisit Replicate version 2.4.21.2746
Copyright (C) Dbvisit Software Limited.  All rights reserved.
No DDC file loaded.
Run "setup wizard" to start the configuration wizard or try "help" to see all commands available.

dbvrep> setup wizard
This wizard configures Dbvisit Replicate to start a replication process.

The setup wizard creates configuration scripts, which need to be run after the wizard ends. No changes to the databases are made before that.

The progress is saved every time a list of databases, replications, etc. is shown. It will be re-read if wizard is restarted and the same DDC name and script path is
selected.

           Run the wizard now? [yes] yes

           Accept end-user license agreement? (view/yes/no) [view] yes

Before starting the actual configuration, some basic information is needed. The DDC name and script path determines where all files created by the wizard go (and where
to reread them if wizard is rerun) and the license key determines which options are available for this configuration.

           (DDC_NAME) - Please enter a name for this replication (suggestion: use the name of the source database): [] pte

           (LICENSE_KEY) - Please enter your license key (or just enter "(trial)"): [(trial)] trial

           (SETUP_SCRIPT_PATH) - Please enter a directory for location of configuration scripts on this machine: [/home/oracle/pte] /u03/dbvisit/pte

… and so on. In the end the wizard will execute a script on both source and target databases that will create a DBVREP schemas and give it all necessary privileges. If you enabled DDL replication, then it will also enable database wide supplemental logging on the source database side (so check DBA_2PC_PENDING view before doing it, that you don’t have any pending 2PC transactions open, otherwise adding supplemental logging will hang until the 2PC transactions are resolved).

MINE (or FETCH in case of 3-tier architecture) process needs to run directly on the source database server (in case of RAC pick any one of the database nodes) and under the same OS account as ASM, so in my case grid. Setup wizard creates a script *-run-10.0.0.1.sh to start MINE.

[grid@xxxxxx pte]$ ./pte-run-10.0.0.1.sh
Initializing......done
DDC loaded from database (234 variables).
Dbvisit Replicate version 2.4.21.2746
Copyright (C) Dbvisit Software Limited.  All rights reserved.
DDC file /u03/dbvisit/pte/pte-MINE.ddc loaded.
Starting process MINE...started

Apply process shouldn’t need an installed Oracle client software, because DBvisit Replicate comes with an embedded Oracle Instantclient. In the version I’m currently using this did not work for me, so I needed to add the following line to *-APPLY.ddc file to set the correct ORACLE_HOME. But this bug should be fixed in the next released version.

memory_set ORACLE_HOME /u01/app/oracle/product/11.2.0.3/db

Also open *-run-10.0.0.2.sh (the script that executes APPLY process) and set NLS_LANG on the first line. NLS_LANG needs to be AMERICAN_AMERICA.SOURCE_DB_CHARSET:

export NLS_LANG=AMERICAN_AMERICA.AL32UTF8

Now start apply process:

[oracle@xxxxxxxxxx pte]$ ./pte-run-10.0.0.2.sh
Initializing......done
DDC loaded from database (234 variables).
Dbvisit Replicate version 2.4.21.2746
Copyright (C) Dbvisit Software Limited.  All rights reserved.
DDC file /u03/dbvisit/pte/pte-APPLY.ddc loaded.
Starting process APPLY...started

Monitoring and configuring the replication process is done through the replication console, which can be executed using the start-console.sh script. This will display the status of all dbvisit processes and limited list of tables that have had some changes replicated recently. From this command line you can control the replication process

/MINE IS running. Currently at plog 13 (redo sequence 1201 [1] 1395 [3] 1086 [2]) and SCN 96447934933 (04/04/2013 16:49:25).
APPLY IS running. Currently at plog 13 and SCN 96447934644 (04/04/2013 16:49:25).
Progress of replication pte:MINE->APPLY: total/this execution
--------------------------------------------------------------------------------------------------------------------------------------------
DBAUSER.DBVISIT_PING:         100%  Mine:21/21           Unrecov:0/0         Applied:21/21       Conflicts:0/0       Last:04/04/2013 18:24:36/OK
--------------------------------------------------------------------------------------------------------------------------------------------
1 tables listed.

dbvrep>

Some useful commands: LIST PREPARE, PREPARE SCHEMA, PREPARE TABLE, UNPREPARE SCHEMA, UNPREPARE TABLE, SHUTDOWN MINE, SHUTDOWN APPLY, SHUTDOWN ALL, LIST CONFLICT. Before you add (prepare) new tables/schemas with existing data to replication configuration, take a look at the users guide for a proper procedure. If you just execute PREPARE TABLE/SCHEMA and then export the existing data, you will get ORA-01466.

For my current project, it was very important to find a replication solution that could exclude some transactions from replication, for example when you need to purge data from source database but want to keep the same data on the target DB. It is possible with DBVisit Replicate:

  • Partition level DDL is not replicated by default, so on the source database you can just drop/truncate a partition and it will not be replicated by default to the target side.
  • If you need to exclude specific transactions from replication, then execute SET TRANSACTION NAME as a first command in that transaction.
    SET TRANSACTION NAME ‘DBREPL_DB_%s_XID_%s’
    The first %s: name of the target database (as configured in the setup wizard).
    The second %s: is not relevant.

    COMMIT; -- just to be sure that the next command is the first in that transaction
    SET TRANSACTION NAME 'DBREPL_DB_archpte_XID_XXXXX';
    DELETE FROM dbauser.dbvisit_ping;
    COMMIT;
    

I think this is enough for a first post. You can do a lot of complex configurations with DBVisit, it is a flexible product. Test your setup properly, there can be issues depending on your database setup, that DBVisit has not yet tested for. If you find an issue, report to DBVisit support (this can also be done if you have a trial license), DBVisit has an excellent and fast support team. So far I have created 7 tickets to DBVisit support and all of them have been resolved within hours or a day.

DBVisit also has some helpful videos in youtube.

One link that I have to send to developers quite frequently is how to use XMLTABLE in SQL queries to bind comma separated list of values instead of generating large IN list directly to the query (and this way avoid new sqlid/cursor/wasted memory for each different value combination provided). The link that I usually send is this, but in this post I’d like to expand it a little, so it would work even when the string contains special XML characters.

For numbers, the usage is simple:

> var num_list varchar2(100)
> exec :num_list := '2668,2669,2670'

PL/SQL procedure successfully completed.

> SELECT id FROM ath_case WHERE id IN (
 SELECT (column_value).getNumberVal() FROM xmltable(:num_list)
 );

        ID
----------
      2668
      2669
      2670

> exec :num_list := '2671,2672,2673,2674'

PL/SQL procedure successfully completed.

> SELECT id FROM ath_case WHERE id IN (
 SELECT (column_value).getNumberVal() FROM xmltable(:num_list)
 );

        ID
----------
      2671
      2672
      2673
      2674

If the binded list consists of strings, then some extra steps are needed – the comma-separated has to be enclosed with double-quotes and the values have to be XML-encoded (XML special characters, like " replaced with codes).

> var str_list varchar2(100)
> exec :str_list := '"GI1","BI1"'

PL/SQL procedure successfully completed.

> SELECT u.first_name FROM ath_user u 
 JOIN ath_team t ON u.id = t.manager_id 
 WHERE t.name IN (
 SELECT DBMS_XMLGEN.CONVERT((column_value).getStringVal(), 1) FROM xmltable(:str_list)
 );

FIRST_NAME
-----------
Riho
Kaur

> exec :str_list := '"OS1","OS2"'

PL/SQL procedure successfully completed.

> SELECT u.first_name FROM ath_user u 
 JOIN ath_team t ON u.id = t.manager_id 
 WHERE t.name IN (
 SELECT DBMS_XMLGEN.CONVERT((column_value).getStringVal(), 1) FROM xmltable(:str_list)
 );

FIRST_NAME
-----------
Markko
Aive

> set define off
> exec :str_list := '"value1","value2","value " with quot","value & with amp"';

PL/SQL procedure successfully completed.

> SELECT DBMS_XMLGEN.CONVERT((column_value).getStringVal(), 1) FROM xmltable(:str_list);

DBMS_XMLGEN.CONVERT((COLUMN_VALUE).GETSTRINGVAL(),1)
-------------------------------------------------------------------------
value1
value2
value " with quot
value & with amp

Starting from 11.2 its possible to use SSL client certificates to authenticate yourself to a remote web service using SSL client certificates. I did not find much information on it using Google or documentation, that is why I’m writing this post.

Please refer to this post by Tim Hall to get started on connecting to HTTPS service using UTL_HTTP, all of this is needed before continuing with SSL client certificate authentication.

The first thing you need is to generate user certificate request inside Oracle Wallet, sign it by CA and load the returned certificate back to Wallet. I’m not going to very detailed steps here, but basically (using Oracle Wallet Manager OWM):

  1. Open the wallet you created using Tim Hall’s post mentioned previously.
  2. Go to Operations > Add Certificate Request
  3. Fill in all the needed fields
  4. After certificate request has been created, go to Operations > Export Certificate Request
  5. Send the request to a Certification Authority (that the remote service trusts) for signing and wait for a reply (in a form of signed certificate)
  6. Import the signed certificate to wallet – go to Operations > Import User Certificate

If you are using 11g OWM/ORAPKI and when importing the user certificate to wallet OWM displays an error or ORAPKI corrupts your wallet, you can just use OWM/ORAPKI programs from 10gR2 database client. This is due to bug Bug 9395937: UNABLE TO IMPORT USER CERTIFICATE IN OWM 11.1, WORKS IN 10.2.

Next thing is to add ACL privileges inside the database. UTL_HTTP documentation requires the use of use-client-certificates ACL privilege. How to do that I’ll refer to Tim Hall’s post again Fine-Grained Access to Network Services in Oracle Database 11g Release 1. In the example below I already have ACL all_access.xml and I’m granting connect and use-client-certificates privileges to CLTEST schema.

SQL> exec DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE('all_access.xml','CLTEST', true, 'connect');

PL/SQL procedure successfully completed.

SQL> exec DBMS_NETWORK_ACL_ADMIN.ADD_PRIVILEGE('all_access.xml','CLTEST', true, 'use-client-certificates');

PL/SQL procedure successfully completed.

Now the step that is not mentioned in UTL_HTTP documentation and got me stuck for weeks until I opened SR to Oracle Support. The network ACL needs also privileges on the Wallet file using DBMS_NETWORK_ACL_ADMIN.ASSIGN_WALLET_ACL.

SQL> exec DBMS_NETWORK_ACL_ADMIN.ASSIGN_WALLET_ACL('all_access.xml','file:/path/to/oracle/wallet');

PL/SQL procedure successfully completed.

After the privileges have been assigned, you can use UTL_HTTP to query remote web service like you do with normal HTTPS connection. If the remote web service requests client to be authenticated using certificates, UTL_HTTP automatically handles it in the background and uses the user certificate located in the wallet. For example:

SQL> SELECT utl_http.request('https://secure.service.com/status', '', 'file://path/to/oracle/wallet', 'WalletPassword') FROM dual;

Back-story: A developer came to me and wanted explanation for a weird behavior in MySQL. They inserted a record (to InnoDB table), committed, and after receiving a message (on another application) tried to read that inserted record immediately, but the newly inserted record was not found. Problem only happened in production, but not always (quite frequently).

After comparing the MySQL parameter files between production and development environments I discovered that in production autocommit was disabled to make MySQL behave more like Oracle. This setting was removed from development after we rebuilt the environment (to use multiple MySQL instances with Oracle Clusterware, instead of one large MySQL instance), but the rebuild was not yet done in production.

The default transaction level for MySQL InnoDB is REPEATABLE READ (unlike Oracle, that has READ COMMITTED as default), that means that the SELECT query always returns the data at the time point when the transaction was started. If autocommit is off, then the first issued select statement will open the transaction and any subsequent select statement will return the data at the time point when the first select was issued, until transaction is ended with COMMIT/ROLLBACK. If autocommit is enabled, SELECT statement is run in a self-contained transaction, ending with COMMIT, so the end result is like READ COMMITTED isolation level in Oracle.

Here is an example what you’d expect to see as a result:

mysql session 1$ create table test (id integer unsigned primary key) engine=innodb;
Query OK, 0 rows affected (0.01 sec)

mysql session 1$ set autocommit=1;
Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
Empty set (0.01 sec)

  mysql session 2$ begin;
  Query OK, 0 rows affected (0.00 sec)

  mysql session 2$ insert into test values (1);
  Query OK, 1 row affected (0.05 sec)

  mysql session 2$ commit;
  Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
+----+
1 row in set (0.00 sec)

The same example of having autocommit off and transaction isolation level set as default:

mysql session 1$ set autocommit=0;
Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
+----+
1 row in set (0.00 sec)

  mysql session 2$ begin;
  Query OK, 0 rows affected (0.00 sec)

  mysql session 2$ insert into test values (2);
  Query OK, 1 row affected (0.05 sec)

  mysql session 2$ commit;
  Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
+----+
1 row in set (0.00 sec)

mysql session 1$ commit;
Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
|  2 |
+----+
2 rows in set (0.00 sec)

Now, autocommit off and transaction isolation level set to READ COMMITTED:

mysql session 1$ set autocommit=0;
Query OK, 0 rows affected (0.00 sec)

mysql session 1$ set session transaction isolation level read committed;
Query OK, 0 rows affected (0.03 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
|  2 |
+----+
2 rows in set (0.01 sec)

  mysql session 2$ begin;
  Query OK, 0 rows affected (0.00 sec)

  mysql session 2$ insert into test values (3);
  Query OK, 1 row affected (0.05 sec)

  mysql session 2$ commit;
  Query OK, 0 rows affected (0.00 sec)

mysql session 1$ select * from test;
+----+
| id |
+----+
|  1 |
|  2 |
|  3 |
+----+
3 rows in set (0.00 sec)

You can read more about how autocommit is handled by InnoDB in documentation.

Another key component in our puzzle – application server used connection pools for managing MySQL connections, so after Java session requested a connection from pool, it was only a matter of chance whether the connection already had a transaction left open by the previous user of that connection, did the previous user commit, or was it a brand new connection.

Oracle Database has had the possibility to run Java code inside the database for a long time. It’s a very rare occasion when you need to use it but still. Here is one example I used to download content from HTTPS website that required user certificates for authentication. Please take the code below more as an example how to put simple Java code inside the database, not as a solution for user certificates authentication, because UTL_HTTP can do the same thing (although I wasn’t successful in implementing it under 11.2.0.2).

First, load the Java source into database. The code below shows:

  • How to return simple datatype (int) from Java function – makeConnection
  • How to return Oracle CLOB datatype from Java – makeConnectionClob
  • How to execute SQL from Java, in the same calling session

Note that method main is just added for testing from command line.

Then you need to create a wrapper package in database. This declares the PL/SQL wrapper function names and input/output parameters.

Download the source: java_source.java and PL/SQL wrapper.sql.

When you first execute the code, you will most likely get some privilege errors, but the error message will tell you how to grant the needed privileges. For example, for this code the following grants were needed:

exec dbms_java.grant_permission( 'OWNER', 'SYS:java.util.PropertyPermission', 'javax.net.ssl.keyStore', 'write' );
exec dbms_java.grant_permission( 'OWNER', 'SYS:java.util.PropertyPermission', 'javax.net.ssl.trustStore', 'write' );
exec dbms_java.grant_permission( 'OWNER', 'SYS:java.util.PropertyPermission', 'javax.net.ssl.keyStorePassword', 'write' );
exec dbms_java.grant_permission( 'OWNER', 'SYS:java.net.SocketPermission', 'site.that.requires.user.cert', 'resolve' );
exec dbms_java.grant_permission( 'OWNER', 'SYS:java.net.SocketPermission', '1.2.3.4:443', 'connect,resolve' );