So shortly about my plan to do
I have an Oracle XE 11gR2 instlled on Windows 2008 instance, from where i would like to connect to MSSQL server via dblink.
Steps what i have to do:
- Create and setup ODBC
- Edit listener.ora & tnsnames.ora
- Edit initMSSQL.ora & restart listener
- Tnsping to verify
- Create dblink
- Test
1. Create and setup ODBC
Go to Start -> Administrative Tools -> Data Sources (ODBC)
Under Use DSN click on Add button -> in new window choose SQL Server -> hit Finish
Next fill the necessary information as:
Go Next >
Next >
Next >
Finish. -> Test Data Source.
More details you can find at http://www.ehow.com/how ....connection.html
2. Edit listener.ora & tnsnames.ora
My new listener.ora file looks like this:
(C:\oraclexe\app\oracle\product\11.2.0\server\network\ADMIN\listener.ora)
SID_LIST_LISTENER =
(SID_LIST =
(SID_DESC =
(SID_NAME = PLSExtProc)
(ORACLE_HOME = C:\oraclexe\app\oracle\product\11.2.0\server)
(PROGRAM = extproc)
)
(SID_DESC =
(SID_NAME = CLRExtProc)
(ORACLE_HOME = C:\oraclexe\app\oracle\product\11.2.0\server)
(PROGRAM = extproc)
)
(SID_DESC =
(SID_NAME = MSSQL)
(ORACLE_HOME = C:\oraclexe\app\oracle\product\11.2.0\server)
(PROGRAM = dg4odbc)
)
(SID_DESC =
(SID_NAME = XE)
(ORACLE_HOME = C:\oraclexe\app\oracle\product\11.2.0\server)
)
)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1))
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.1)(PORT = 1521))
)
)
DEFAULT_SERVICE_LISTENER = (XE)
Please note (PROGRAM = dg4odbc ) from Oracle 11g it's no more (PROGRAM = hsodbc)
New tnsnames.ora file looks like this
New tnsnames.ora file looks like this
XE =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.1)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = XE)
)
)
EXTPROC_CONNECTION_DATA =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1))
)
(CONNECT_DATA =
(SID = PLSExtProc)
(PRESENTATION = RO)
)
)
ORACLR_CONNECTION_DATA =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1))
)
(CONNECT_DATA =
(SID = CLRExtProc)
(PRESENTATION = RO)
)
)
MSSQL =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.1)(PORT=1521))
)
(CONNECT_DATA =
(SID = MSSQL)
)
(HS = OK)
)
3. Edit initMSSQL.ora & restart listener
Copy
C:\oraclexe\app\oracle\product\11.2.0\server\hs\admin\initdg4odbc.ora
To
c:\oraclexe\app\oracle\product\11.2.0\server\hs\admin\initMSSQL.oraplease pay attention that you should rename file like init<DESCRIPTOR NAME>.ora!
The new edited initMSSQL.ora look like this:
# HS init parameters
#
HS_FDS_CONNECT_INFO = MSSQL
HS_FDS_TRACE_LEVEL = off
Restart (reload) the listener
LSNRCTL> reload
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=EXTPROC1)))
The command completed successfully
4. Tnsping to verify
C:\oraclexe\app\oracle\product\11.2.0\server\bin>tnsping.exe MSSQL
TNS Ping Utility for 32-bit Windows: Version 11.2.0.2.0 - Production on 12-Feb-2013 21:48:36
Copyright (c) 1997, 2010, Oracle. All rights reserved.
Used parameter files:
C:\oraclexe\app\oracle\product\11.2.0\server\network\admin\sqlnet.ora
Used TNSNAMES adapter to resolve the alias
Attempting to contact (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)
(HOST = 192.168.1.1)(PORT=1521))) (CONNECT_DATA = (SID = MSSQL)) (HS
= OK))
OK (0 msec)
5. Create dblink
Conncet to Oracle database and create dblink
C:\oraclexe\app\oracle\product\11.2.0\server\bin>sqlplus ora_user/ora_pwd@192.168.1.1:1521/xe
SQL*Plus: Release 11.2.0.2.0 Production on Mar. Feb. 12 21:58:31 2013
Copyright (c) 1982, 2010, Oracle. All rights reserved.
Connected to:
Oracle Database 11g Express Edition Release 11.2.0.2.0 - Production
SQL> CREATE DATABASE LINK MSSQL
2 CONNECT TO ms_user IDENTIFIED BY ms_pwd
3 USING 'MSSQL';
Database link created.
6. Test
SQL> select * from testTable @ MSSQL;
id val
------------------ --------------------
1 some val 1
2 some val 2