Create a linked server to an Oracle database (and not lock up the instance)

I’ve created numerous linked servers to Oracle from SQL Server and what should be a straightforward process using SSMS has caused me some headaches.  For whatever reason, when using the GUI, I’ve actually locked up the entire SQL Server instance and had to restart the service when trying to create a linked server to Oracle.  This is not good when working in production. The following will outline the do’s and don’ts for this process.

To begin: download, install and configure the Oracle client to communicate with your Oracle database.  This link can assist you with that process.

Once the Oracle client is installed, here’s the steps that can cause potential problems (skip to code section for the correct solution):

Using SQL Server 2005 Management Studio, I expanded ‘Server Objects‘, right clicked ‘Linked Servers‘ and chose ‘New Linked Server‘.  I entered a name in the ‘Linked Server‘ text box then went to ‘Provider‘ (after choosing the ‘Other Data Source‘ radio button).  The drop down showed me a list of the drivers installed; to connect to Oracle we have two choices: the Microsoft driver, called ‘Microsoft OLE DB Provider for Oracle‘ and the Oracle driver, ‘Oracle Provider for OLE DB‘.  Here’s where I ran into problems: if I chose the Oracle driver, about half the time the drop down would freeze and eventually the instance would become unresponsive.  I’d have to restart the SQL Server service.

Here’s the code section, showing how to create a linked server using T-SQL:

-- Create the linked server
EXEC master.dbo.sp_addlinkedserver
@server = N'LinkToOracle', -- name of the Linked Server
@srvproduct=N'Oracle',
@provider=N'MSDAORA', -- Microsoft driver
@datasrc=N'myOracleDatabase' -- TNS name of the Oracle database
go
 
-- Add the user to connect to the Oracle database
EXEC master.dbo.sp_addlinkedsrvlogin
@rmtsrvname=N'LinkToOracle', -- name of the Linked Server
@useself=N'False',
@locallogin=NULL,
@rmtuser=N'myOracleUser', -- Oracle database user
@rmtpassword='########' -- Enter the correct password here
go

The above code will create a linked server called ‘LinkToOracle’ using the Microsoft OLE DB driver, then using an Oracle database user to authenticate.  To use the Oracle OLE DB driver, replace the ‘@provider’ line in the top call to the sp_addlinkedserver stored procedure with:

@provider=N'OraOLEDB.Oracle'

To test connectivity, open a query window and do a select from a table that the Oracle user has access to.  The following assumes an ‘Employee’ table in the ‘HumanResources’ schema exists in the Oracle database:

SELECT count(*) FROM LinkToOracle..HumanResources.Employee

Notice the double dots between ‘LinkToOracle‘ and ‘HumanResources‘.  This denotes use of the default catalog of the linked server.

To send the query to the Oracle database for processing, which would allow you to write PL/SQL, use the OPENQUERY command:

SELECT * 
FROM OPENQUERY(LinkToOracle, 'select count(*) from HumanResources.Employees')
Tagged , , , , , , . Bookmark the permalink.

6 Responses to Create a linked server to an Oracle database (and not lock up the instance)

  1. Dean Peterson says:

    This article was pretty much a lifesaver for me. I just want to say thanks.

  2. SUKSAN says:

    good job

  3. Marshall says:

    We ran into the same hanging issue, however, with less frequency (SQL Server 2008 on a Windows 2003 32 bit system). Thanks for posting

  4. Ger says:

    Don’t normally post comments but this really saved my sanity.
    For the record using Windows 2008 R2 & SQLExpress 2014 & Oracle Client 11.2 x64.

    Well done that man.

Leave a Reply to Dean Peterson Cancel reply

Your email address will not be published. Required fields are marked *