Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Call DB2 stored procedure using Linked Server?


Call DB2 stored procedure using Linked Server?

Author
Message
speja01
speja01
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 364
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
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9438 Visits: 9517
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."
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45127 Visits: 39923
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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
RBarryYoung
RBarryYoung
SSCrazy Eights
SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)SSCrazy Eights (9.4K reputation)

Group: General Forum Members
Points: 9438 Visits: 9517
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."
Newbie2LinkedServer
Newbie2LinkedServer
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 10
I am newbie to linked server concept, I am looking for help to resolve my issue. Please suggest.

My requirement:
In DB2 data base I have a stored procedure and from SQL 2008 R2 using Linked server I need to be able to execute stored procedure. I am getting the error while I am trying to execute.

Created SP as below with db2admin user:
CREATE OR REPLACE PROCEDURE SP_MyStoredProcedure
LANGUAGE SQL
SPECIFIC SP_MyStoredProcedure
-- EXTERNAL ACTION
BEGIN
.......
END


select * from [MyDb2LinkedServer].[db2DB].[db2admin].TLS_MyDb2Table and I get the results, which means my linked server DB2 connectivity is fine.

Then while executing as below SP got the error

exec [MyDb2LinkedServer].[db2DB].[db2admin].SP_MyStoredProcedure

Error:
OLE DB provider "DB2OLEDB" for linked server "MyDb2LinkedServer" returned message "Routine "*rocedure"?SQL150518145704050?...erver"."SP_MyStoredProcedure"?*?4" (specific name "") is implemented with code in library or path "", function "" which cannot be accessed. Reason code: "". SQLSTATE: 42724, SQLCODE: -444".
Msg 7212, Level 17, State 1, Line 1
Could not execute procedure 'SP_MyStoredProcedure' on remote server 'MyDb2LinkedServer'.


Here in the error
specific name ""
library or path ""
function ""
Reason code: ""

all are empty, no much information is available.

Need help on this and how this can be resolved? Any help is appreciated.

Note:
"rpc", "rpc out" both options are true.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search