Training
Creating a linked server to DB2 using Microsoft OLE DB provider for DB2
This article describes a sample SQL script for creating a linked server to DB2 using sp_addlinkedserver
, and issues a few queries to illustrate the Distributed Query Processing (DQP).
Original product version: Host Integration Server
Original KB number: 222937
This article provides a sample SQL script for creating a linked server to DB2 using sp_addlinkedserver
, and issues a few queries to illustrate the DQP using DB2OLEDB
, the OLE DB provider for DB2.
INF: Configuring Data Sources for the Microsoft OLE DB Provider for DB2
EXEC sp_addlinkedserver
@server = 'WNW3XX',
@srvproduct = 'Microsoft OLE DB Provider for DB2',
@catalog = 'OLYMPIA',
@provider = 'DB2OLEDB',
@provstr='NetLib=SNA;NetAddr=;NetPort=;RemoteLU=OLYMPIA;LocalLU=LOCAL;ModeName=QPCSUPP;User ID=WNW3XX;Password=WNW3XX;InitCat=OLYMPIA;Default Schema=WNW3XX;PkgCol=WNW3XX;TPName=;Commit=YES;IsoLvl=NC;AccMode=;CCSID=37;PCCodePage=1252;BinAsChar=NO;Data Source=Olympia_WNW3XX'
EXEC sp_addlinkedsrvlogin 'WNW3XX', false, NULL, 'WNW3XX', 'WNW3XX'
Note
DB2OLEDB
provider needs to run in-proc. To enable this setting:Start the SQL Server Enterprise Manager.
In the Console tree, find the Linked Servers node (under the Security folder). Right-click on the linked server created above, and in the Properties dialog box, click the General tab, then click on Options, and click to enable the Allow InProcess setting. This is the only way to enable this setting, and after it has been enabled for a given provider, the setting is used for every subsequent linked server created using that provider, including the ones created with T-SQL script.
The total length of the linked server initstring must be no more than 278 characters, so it is advantageous to use the
DB2OLEDB
short connection string arguments as documented above.Linked Servers using
DB2OLEDB
can also be configured to connect over TCP/IP, though the above script illustrates this using an SNA APPC connection.
Example of
SELECT
using 4-part name:LinkedServer.Catalog.Schema.Table
SQLSELECT * FROM WNW3XX.OLYMPIA.WNW3XX.DEPARTMENT
Example of Pass Through
SELECT
usingOPENQUERY
with 3-part name:SQLSELECT * FROM OPENQUERY(WNW3XX,"SELECT * FROM OLYMPIA.WNW3XX.EMP_ACT")
Example of Pass Through
SELECT
usingOPENROWSET
with 2-part name:SQLSELECT * FROM OPENROWSET ('DB2OLEDB',Netlib=SNA;NetAddr=;NetPort=;RemoteLU=OLYMPIA;LocalLU=LOCAL;ModeName=QPCSUPP;User ID=WNW3XX;Password=WNW3XX;InitCat=OLYMPIA;Default Schema=WNW3XX;PkgCol=WNW3XX;TPName=;Commit=YES;IsoLvl=NC;AccMode=;CCSID=37;PCCodePage=1252;BinAsChar=NO;Data Source=Sample', 'SELECT * FROM WNW3XX.EMPLOYEE')
Example of an
INSERT
using 4-part name:SQLINSERT INTO WNW3XX.OLYMPIA.WNW3XX.DEPARTMENT VALUES ('E21','DUMMY',NULL,'E01')
Note
UPDATE
andDELETE
using DQP are not possible with theDB2OLEDB
provider that shipped with SNA version 4.0 Service Pack 2 and Service Pack 3 due to lack of bookmark support, but these do work with the SNA 4.0 Service Pack 4 provider and the provider that shipped with Host Integration Server.Example of JOIN between a SQLServer and DB2 table:
SQLSELECT A.EMPLOYEE_NUMBER,B.ACTNO FROM CORPDATA..EMPLOYEE_ACCOUNT A, WNW3XX.OLYMPIA.WNW3XX.EMP_ACT B WHERE A.EMPLOYEE_NUMBER = B.EMPNO ORDER BY A.EMPLOYEE_NUMBER
Additional resources
Documentation
-
Storing DB2 connection strings - Host Integration Server
This article explains how to save DB2 connection strings in Enterprise Single Sign-On, using KB 2499828 for Microsoft Host Integration Server 2010, or Cumulative Update 1.
-
Configure data sources - Host Integration Server
This article describes how to configure data sources for the Microsoft OLE DB Provider for DB2.
-
Data Links (DB2) - Host Integration Server
Learn more about: Data Links (DB2)