INF: Creating a Linked Server to DB2 using Microsoft OLE DB Provider for DB2

ID: Q222937


The information in this article applies to:


SUMMARY

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 Distirbuted Query Processing (DQP) using DB2OLEDB, the Microsoft OLE DB provider for DB2. Please refer to the following article in the Microsoft Knowledge Base for information on the keywords used in the DB2OLEDB initstring.

Q218590 INF: Configuring Data Sources for the Microsoft OLE DB Provider for DB2

Creating Linked Server


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' 
Please note that:

Sample Distributed Queries

Example of SELECT using 4-part name: LinkedServer.Catalog.Schema.Table
SELECT * FROM WNW3XX.OLYMPIA.WNW3XX.DEPARTMENT

Example of Pass Through SELECT using OPENQUERY with 3-part name:
SELECT * FROM OPENQUERY(WNW3XX,"SELECT * FROM OLYMPIA.WNW3XX.EMP_ACT")

Example of Pass Through SELECT using OPENROWSET with 2-part name:
SELECT * 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:
INSERT INTO WNW3XX.OLYMPIA.WNW3XX.DEPARTMENT VALUES
('E21','DUMMY',NULL,'E01')

Please note that UPDATE and DELETE using DQP are not possible because DB2OLEDB does not support bookmarks.

Example of JOIN between a SQLServer and DB2 table:
SELECT 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 query words: AS/400 MVS OS/390 Mainframe


Keywords          : 
Version           : WINDOWS:4.0 SP2; winnt:7.0
Platform          : WINDOWS winnt 
Issue type        : kbinfo 

Last Reviewed: March 31, 1999