Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Call DB2 stored procedure using Linked Server? Expand / Collapse
Author
Message
Posted Monday, October 12, 2009 7:45 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Friday, August 15, 2014 1:39 PM
Points: 26, Visits: 321
Hi Everyone,

Is it possible to call a DB2 stored procedure using a linked server? I've read a bunch of conflicting information out on the internet. Various posts have claimed it is not supported but then I came across a couple of posts which suggest it is possible. If it is possible..please provide me with a link to the information. Any help is appreciated!

Thanks
Post #801572
Posted Monday, October 12, 2009 8:05 PM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Thursday, June 5, 2014 10:54 AM
Points: 9,902, Visits: 9,480
Have you tried using the EXEC..AT feature?

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Post #801909
Posted Friday, November 2, 2012 3:12 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:03 AM
Points: 36,975, Visits: 31,492
I know it's an old post but the following should help a lot.
http://www.mcpressonline.com/index2.php?option=com_content&do_pdf=1&id=1541

The keys to the magic appear in the following...
--
-- Create Linked Server using ODBC DSN "AS400"
--
sp_addlinkedserver
@server=N'DB2400',
@srvproduct=N'DB2 UDB for iSeries',
@provider=N'MSDASQL',
@datasrc=N'AS400',
@provstr='CMT=0;SYSTEM=as400.mycompany.com',
@catalog='S104X824'
go
--
-- Define the credentials that will be used to
-- access objects hosted by the Linked Server
--
sp_addlinkedsrvlogin @rmtsrvname=N'DB2400',
@useself='false',
@rmtuser=N'MyUser',
@rmtpassword='MyPassword'
go
--
-- RPC option is required for doing EXEC AT
--
EXEC sp_serveroption 'DB2400', 'rpc out', true
go

The biggest key here is that you must use the MSDASQL driver and you must enable "rpc out".

The article at the link also gives an example call to return a result set as follows... Obviously, the temp table must already exist but that's also covered in the article.

--
-- A DB2 stored procedure can be executed
--
Set @OrderID = 10249
Insert Into #tmpOrderHdr
Exec ('Call DATALIB.GetOrders (?)', @OrderID) AT DB2400


To be clear, I've not tried any of this, yet. Our infrastructure team is in the process of installing the correct MSDASQL driver.


--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1380600
Posted Monday, November 5, 2012 11:53 AM


SSCrazy Eights

SSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy EightsSSCrazy Eights

Group: General Forum Members
Last Login: Thursday, June 5, 2014 10:54 AM
Points: 9,902, Visits: 9,480
Sweet. Really nice find, Jeff. This goes in my Favorites list...

-- RBarryYoung, (302)375-0451 blog: MovingSQL.com, Twitter: @RBarryYoung
Proactive Performance Solutions, Inc.
"Performance is our middle name."
Post #1381227
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse