Wednesday, April 16, 2008

Oracle Transparent Gateway for MS SQL Server - Part II

Following my last post about Oracle Transparent Gateways which was theoretical post, this post will be more practical.

In this post I'll show an example of configuring Oracle Transparent Gateway for MS SQL Server.
The goal is to make it possible to retrieve data from MS SQL server database by querying from Oracle database.

The steps are:

  1. install Oracle Transparent Gateway for MS SQL Server (not explained here)
  2. Configure the gateway initialization parameter file
  3. Configure the listener
  4. Configure the Oracle database tnsnames.ora
  5. Creating DB link from Oracle database to MS SQL Server

In my environment there are 3 servers involved:

  1. Oracle database server - name: orclsrv01, with Oracle database installed name: orcldb
  2. Microsoft SQL server - name: msqlsrv01, with MS SQL server installed name: msqldb
  3. Oracle Gateway server - name: oragwsrv01, with Oracle Transparent Gateway installed.


Configure the gateway initialization parameter file

After Oracle Transparent Gateway for MS SQL server installed on ORAGWSRV01 server, a new default initialization file is created at: $ORACLE_HOME\tg4msql\admin\inittg4msql.ora.

$ORACLE_HOME - is the directory where Transparent Gateway installed.
inittg4msql.ora - is the default initialization parameter file, as tg4msql represents the Gateway SID.
If you choose to not use the default SID (or when you have more than one MS Sql server to connect to), the initialization parameter file should be named as follow: init[GW_SID].ora

Edit the inittg4msql.ora file and specify the MS Sql Server connection details as follow:
HS_FDS_CONNECT_INFO=server_name.database_name

in our case:
HS_FDS_CONNECT_INFO=msqlsrv01.msqldb

Alternatively you can set it as follow:
HS_FDS_CONNECT_INFO="SERVER=msqlsrv01; DATABASE=msqldb"

Configure the listener

In order to make the listener work with the gateway we should configure it.
The listener have to be on the same server like the Gateway.
We should edit the listener.ora within the Oracle home on which the Gateway installed.

The listener.ora must have at least 2 entries:

  • The address to listen on
  • the Gateway to start

On ORAGWSRV01 server at $ORACLE_HOME\network\admin edit the listener.ora as follow:

LISTENER=
               (ADDRESS=
                   (PROTOCOL=TCP)
                   (HOST=host_name)
                   (PORT=port_number))

SID_LIST_LISTENER=
      (SID_LIST=
           (SID_DESC=
                 (SID_NAME=gateway_sid)
                 (ORACLE_HOME=oracle_home)
                 (PROGRAM=tg4msql)
           ) 
      )

Where:
host_name - is the server name on which the gateway is installed
port_number - is the listener port
gateway_sid - is the gateway SID (default is tg4msql)
oracle_home - is the Oracle directory on which the gateway is installed

In our case:

LISTENER=
              (ADDRESS= 
              (PROTOCOL=TCP)
              (HOST=oragwsrv01)
              (PORT=1521))

SID_LIST_LISTENER=
      (SID_LIST=
          (SID_DESC= 
               (SID_NAME=tg4msql)
               (ORACLE_HOME=C:\oracle\product\10.2.0)
               (PROGRAM=tg4msql)
          )
      )

After finishing the Gateway configuration, restart the listener (lsnrctl stop; lsnrctl start).

Configure the Oracle database tnsnames.ora

Now, when the Gateway configured, we need to configure the Oracle database server to communicate with the Gateway via Oracle Net services.
On ORCLSRV01 server at $TNS_ADMIN ($ORACLE_HOME/network/admin) edit the tnsnames.ora file and add the Gateway's connect descriptor as follow:

connect_descriptor=
   (DESCRIPTION=
      (ADDRESS=
         (PROTOCOL=TCP)
         (HOST=host_name)
         (PORT=port_number)
      )
      (CONNECT_DATA=
         (SID=gateway_sid))
      (HS=OK))

Where:

connect_descriptor - you can specify a name which will be used later when we create a db link
host_name - is the server on which the Gateway installed
port_number - is the port used by the listener that listening for the Gateway
gateway_sid - is the gateway SID (default tg4msql)
HS=OK - indicates this connect descriptor is using heterogeneous Services

In our case:

mytg4msql=
   (DESCRIPTION=
      (ADDRESS=
         (PROTOCOL=TCP)
         (HOST=oragwsrv01)
         (PORT=1521)
      )
      (CONNECT_DATA=
         (SID=tg4msql))
      (HS=OK))

Creating DB link from Oracle database to MS SQL Server

Now, when all configurations were done, we only need to create a Database Link from Oracle to the Gateway.
Connect to orcldb database and create a db link as follow:

create database link ORCLDB2MSQLDB
  connect to [MSQLUSER] identified by [MSQLPWD]
  using 'mytg4msql';

Where MSQLUSER & MSQLPWD are the user name and password to connect to the MS SQL server.

Test it...

At this stage we can get data from MS SQL Server via Oracle Database as if we query from Oracle database.

For example, if we have a RESERVATIONS table in MSQLDB, we can retrieve RESERVATIONS rows from ORCLDB by issuing the following SQL statement:

select *
from reservations@ORCLDB2MSQLDB;

For more information about Transparent Gateway for Microsoft SQL Server:
Oracle® Transparent Gateway for Microsoft SQL Server Administrator's Guide 10g Release 2 (10.2) for Microsoft Windows (32-bit)

For more information about other Transparent Gateways for other Database systems:
Oracle Database Documentation Library 10g release 2 (10.2) - Information Integration

You are welcome to leave a comment.

Aviad

Monday, April 14, 2008

Oracle Transparent Gateways - General Description - Part I

A lot of companies have several applications based on more than one database system (e.g DB2, SQL Server, Sybase, etc).
Each database system store its own data and naturally there's a need to share data among the various heterogeneous database systems.

Oracle, starting with Oracle Database 9i, offers the "Oracle Transparent Gateways" (Oracle Database Gateways) to allow integration of Oracle database with non-Oracle databases.
Unlike "Oracle Generic Connectivity" that provide a generic solution to connect any ODBC/OLEDB compliant non-Oracle system using ODBC and OLEDB standards, the "Oracle Transparent Gateways" are solutions specifically tailored for each target non-Oracle database system.
The "Oracle Transparent Gateways" communicates using the target database native interface, it's make it possible to access to non-Oracle systems as if they were Oracle databases.

The Transparent Gateway solution composed of two parts:

  • Heterogeneous Services (HS) - this is a general integrated component that make it possible to connect to non-Oracle systems from Oracle database
  • Oracle Database Gateways (agent) - these are specific tailored agents for non-Oracle systems that make it possible to interacts with the target non-Oracle system.

Heterogeneous Services (HS)

This is a generic component for connecting to non-Oracle systems.
It's an integrated component of the database that "extends the Oracle SQL engine to recognize the SQL and procedural capabilities of the remote non-Oracle system and the mappings required to obtain necessary data dictionary information" (Oracle Doc').

The following services are provided by the Heterogeneous Services (HS):

  • Transaction service
    Responsible for establishing authenticated connection when the non-Oracle system is accessed and close the connection when session end.
    Also responsible for global data integrity using two phase commit protocol, even for non-Oracle systems that do not support two phase commit natively.
  • SQL Service
    Provide the translation capabilities: SQL & data dictionary translations.
    The SQL services uses an information arrived from the Gateway to translate Oracle SQL to the appropriate SQL dialect of the non-Oracle system. Also, references to data dictionary tables in a query will be rewrite by the SQL Service and result with a result set as from Oracle database.
    ** Data type translation performed by the Gateway.
  • Procedural Service
    An interface for executing stored procedures on non-Oracle system.
  • Pass through SQL
    A mechanism for issuing a SQL statement against the non-Oracle system. It is useful when the statement/function/procedure are not supported by the Gateway.

Oracle Database Gateways (agents)

This component responsible for the interface to the remote non-Oracle system.
It's also responsible for SQL mappings and data type conversions.
The Gateway interacts with Heterogeneous Services to make it possible to transparently connect from an Oracle Database to a non-Oracle System.
In contrast to the HS (Heterogeneous Services) which is a generic component, the Gateways are tailored specifically for each target non-Oracle system.
There are Gateways for many systems such as: DB2, Sybase, Informix, SQL Server, IMS, VSAM, Adabas, Ingres, Teradata, to name a few.
The Gateway can be installed on the same server like the non-Oracle system or on the same server like the Oracle system or on a separate server.

Next post I'll show an example of connecting and retrieving data from a SQL Server database to an Oracle database using Oracle Transparent Gateway for Microsoft SQL Server including all configuration required for Transparent Gateway and the source Oracle System.

Related Documents for more information:

- Oracle® Transparent Gateway for Microsoft SQL Server Administrator's Guide 10g Release 2 (10.2) for Microsoft Windows (32-bit)

- Database Gateways Technical Whitepaper

You are more than welcome to leave a comment.

Aviad