Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Ryan.

Asked: June 18, 2024 - 4:56 pm UTC

Last updated: June 19, 2024 - 6:30 am UTC

Version: 21c

Viewed 1000+ times

You Asked

I've installed Microsoft's ODBC driver and configured various files in an attempt to create an ODBC connection from my Oracle database to SQL server, but I'm having trouble connecting from SQL Developer.

Using the terminal, I can connect to the SQL Server successfully with:

isql -v MSSQL 'username' 'password'


But I get an error (detailed later) when I attempt to create a connection and run a query in SQL Developer.

Here's the various config I have:

UnixODBC

unixODBC 2.3.7
DRIVERS............: /etc/odbcinst.ini
SYSTEM DATA SOURCES: /etc/odbc.ini
FILE DATA SOURCES..: /etc/ODBCDataSources
USER DATA SOURCES..: /home/uat/.odbc.ini
SQLULEN Size.......: 8
SQLLEN Size........: 8
SQLSETPOSIROW Size.: 8



Microsoft ODBC Driver Path

/opt/microsoft/msodbcsql17/lib64/libmsodbcsql-17.9.so.1.1


/etc/odbc.ini

[MSSQL]
Driver = MSSQL
Server = xx.x.x.x
Port = 1433
Database = xxx-xxx


/etc/odbcinst.ini

[MSSQL]
Description=Microsoft ODBC Driver 17 for SQL Server
Driver=/opt/microsoft/msodbcsql17/lib64/libmsodbcsql-17.9.so.1.1
UsageCount=1


/opt/oracle/homes/OraDB21Home1/hs/admin/initMSSQL.ora

HS_FDS_CONNECT_INFO = MSSQL
HS_FDS_TRACE_LEVEL = DEBUG
HS_FDS_TRACE_FILE_NAME = /tmp/dg4odbc_debug1.trc
HS_FDS_SHAREABLE_NAME = /opt/microsoft/msodbcsql17/lib64/libmsodbcsql-17.9.so.1.1


/opt/oracle/homes/OraDB21Home1/network/admin/tnsnames.ora

ORCL =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = xxxx)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORCL)
    )
  )

ORCLPDB1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = xxxx)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORCLPDB1)
    )
  )

MSSQL =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = xxxx)(PORT = 1521))
    (CONNECT_DATA =
      (SID = MSSQL)
      (HS=OK)
    )
  )

LISTENER_ORCL =
  (ADDRESS = (PROTOCOL = TCP)(HOST = xxxx)(PORT = 1521))



/opt/oracle/homes/OraDB21Home1/network/admin/listener.ora

DEFAULT_SERVICE_LISTENER = ORCL

LISTENER =
  (DESCRIPTION_LIST =
    (DESCRIPTION =
      (ADDRESS = (PROTOCOL = TCP)(HOST = xxxx)(PORT = 1521))
      (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521))
    )
  )

SID_LIST_LISTENER =
  (SID_LIST =
    (SID_DESC =
      (SID_NAME = ORCL)
      (ORACLE_HOME = /opt/oracle/product/21.0.0/dbhome_1)
      (GLOBAL_DBNAME = ORCL)
    )
    (SID_DESC =
      (SID_NAME = ORCLPDB1)
      (ORACLE_HOME = /opt/oracle/product/21.0.0/dbhome_1)
      (GLOBAL_DBNAME = ORCLPDB1)
    )
    (SID_DESC =
      (SID_NAME = MSSQL)
      (ORACLE_HOME = /opt/oracle/product/21.0.0/dbhome_1)
      (PROGRAM = dg4odbc)
      (ENVS=LD_LIBRARY_PATH=/opt/microsoft/msodbcsql17/lib64)
    )
  )


lsnrctl status

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=xxxx)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias                     LISTENER
Version                   TNSLSNR for Linux: Version 21.0.0.0.0 - Production
Start Date                06-JUN-2024 13:49:07
Uptime                    12 days 3 hr. 49 min. 10 sec
Trace Level               off
Security                  ON: Local OS Authentication
SNMP                      OFF
Default Service           ORCL
Listener Parameter File   /opt/oracle/homes/OraDB21Home1/network/admin/listener.ora
Listener Log File         /opt/oracle/diag/tnslsnr/uat/listener/alert/log.xml
Listening Endpoints Summary...
  (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=xxxx)(PORT=1521)))
  (DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Services Summary...
Service "14df5e8e854d3c6ae06305e875145f23" has 1 instance(s).
  Instance "orcl", status READY, has 1 handler(s) for this service...
Service "MSSQL" has 1 instance(s).
  Instance "MSSQL", status UNKNOWN, has 1 handler(s) for this service...
Service "ORCL" has 2 instance(s).
  Instance "ORCL", status UNKNOWN, has 1 handler(s) for this service...
  Instance "orcl", status READY, has 1 handler(s) for this service...
Service "ORCLPDB1" has 2 instance(s).
  Instance "ORCLPDB1", status UNKNOWN, has 1 handler(s) for this service...
  Instance "orcl", status READY, has 1 handler(s) for this service...
Service "c8209f27c6b16005e053362ee80ae60e" has 1 instance(s).
  Instance "orcl", status READY, has 1 handler(s) for this service...
Service "orclXDB" has 1 instance(s).
  Instance "orcl", status READY, has 1 handler(s) for this service...
The command completed successfully


Create DB link

CREATE DATABASE LINK mssql_link
CONNECT TO "username" IDENTIFIED BY "password"
USING 'MSSQL';


SQL Developer error when attempting query

SELECT * FROM xxxx@mssql_link;


ORA-28546: connection initialization failed, probable Net8 admin error
ORA-02063: preceding line from MSSQL_LINK
28546. 0000 -  "connection initialization failed, probable Net8 admin error"
*Cause:    A failure occurred during initialization of a network connection
           from the Oracle server to a second process:  The connection
           was completed but a disconnect occurred while trying to
           perform protocol-specific initialization, usually due to
           use of different network protocols by opposite sides
           of the connection.  This usually is caused by incorrect
           Net8 administrative setup for database links or external
           procedure calls.   The most frequent specific causes are:
           --  Database link setup for an Oracle-to-Oracle connection
           instead connects to a Heterogeneous Services agent
           or an external procedure agent.
           --  Database link setup for a Heterogeneous Services connection
           instead connects directly to an Oracle server.
           --  The extproc_connection_data definition in tnsnames.ora
           connects to an Oracle instance instead of an external
           procedure agent.
           --  Connect data for a Heterogeneous Services database link,
           usually defined in tnsnames.ora, does not specify (HS=).
           --  Connect data for an Oracle-to-Oracle database link,
           usually defined in tnsnames.ora, specifies (HS=).
*Action:   Check Net8 administration in the following ways
           --  When using TNSNAMES.ORA or an Oracle Names server, make sure
           that the connection from the ORACLE server uses the correct
           service name or SID.
           --  Check LISTENER.ORA on the connection end point's host machine
           to assure that this service name or SID connects to the
           correct program.
           --  Confirm in TNSNAMES.ORA or the equivalent service definition
           that service 'extproc_connection_data' does NOT contain
           (HS=), or that the service definition used by a
           Heterogeneous Services database link DOES contain (HS=).
Error at Line: 9 Column: 25


echo $LD_LIBRARY_PATH (as oracle user)

/opt/microsoft/msodbcsql17/lib64:/opt/oracle/product/21.0.0/dbhome_1/lib:/opt/oracle/product/21.0.0/dbhome_1/lib


Please help me to resolve the error so I can make successful ODBC connections to my SQL Server from my Oracle DB. I'm at my wit's end with this one!

Also worth noting, /tmp/dg4odbc_debug1.trc (configured in initMSSQL.ora) isn't being generated at all.

Any assistance I can get with this would be very much appreciated!

and Connor said...

Everything looks fine to me, but here's a couple of things to try (just comparing and contrasting your setup to a local machine I have here)

1) adding "set ODBCINI=/etc/odbc.ini" in initMSSQL.ora
2) in /etc/odbc.ini, nominate the driver explicitly rather than the indirect reference, ie

Driver=/opt/microsoft/msodbcsql17/lib64/libmsodbcsql-17.9.so.1.1

3) My ODBC driver installed directly into /usr/lib64, so maybe make sure your odbc libraries are on the system path or perhaps do:

ln -s /opt/microsoft/msodbcsql17/lib64/libmsodbcsql-17.9.so.1.1 /usr/lib64/libmsodbcsql-17.9.so.1.1

If that fails, its probably time to speak to Support.

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library