× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



For the archives, this is what I ended up putting in:

DECLARE SQLERRM VARCHAR ( 4000 ) DEFAULT '' ;
Declare this_proc varchar(120)
Default 'CcdLib/procedureName';

DECLARE EXIT HANDLER FOR SQLEXCEPTION, SQLWARNING
BEGIN
GET DIAGNOSTICS EXCEPTION 1 SQLERRM = MESSAGE_TEXT ;
Set errorMessage = 'Exit Handler for sqlException: Message : '
|| SQLERRM;

SET rtnOutParm = -1;
INSERT INTO SPErrLogP
(StoredProc, ErrorMsg, Parm1, Parm2)
VALUES(this_Proc, errorMessage, inAlphaParm, char(inNumericParm))
WITH NC;
END ;

rtnOutParm is, as implied, an output parameter on the Stored Procedure. It's defined as an Integer.

I created SPErrLogP to house any errors encountered by our (pure) SQL Stored procedures. I gave the file 10 parameter fields, we haven't hit that many parms on a stored procedure yet.

-Kurt

-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Anderson, Kurt
Sent: Friday, March 22, 2013 9:28 AM
To: Midrange Systems Technical Discussion
Subject: RE: Error handling in SQL Stored Procedure

Thanks for the responses.

I may have overcomplicated this (or under-thought it).

I'm working on a stored procedure that is pure SQL. So it's not SQL embedded in RPG. I was using Run SQL Scripts from iNavigator to test my stored procedure and it returned a message about a duplicate record. It gave me the impression that the stored procedure had a hard stop on the failed statement. But if it's like how SQL runs in RPG, I suppose it wouldn't stop, and I can check the SQL State as I would have in RPG.

I just got done wrapping most SQL we send to SQL Server in a Try/Catch so I was looking for something to that extent.

I haven't had a chance to apply any ideas proposed yet. Will hopefully get back to that project this afternoon.

I found the error handling section in the redbook on Stored Procedures (etc), thanks Vern.

Thanks,
Kurt

-----Original Message-----
From: midrange-l-bounces@xxxxxxxxxxxx [mailto:midrange-l-bounces@xxxxxxxxxxxx] On Behalf Of Mark S Waterbury
Sent: Thursday, March 21, 2013 11:12 PM
To: Midrange Systems Technical Discussion
Subject: Re: Error handling in SQL Stored Procedure

Hi, Kurt:

Try this google search: "os/400 db2 error handling in embedded
sql" (without the quotes)

The first link:

http://www.mcpressonline.com/tips-techniques/sql/techtip-simple-error-handling-in-embedded-sql.html

appears to be a good intro.

See also the Redbook"Stored Procedures, Triggers and User-Defined Functions on DB2 UDB for iSeries"
:
http://www.redbooks.ibm.com/abstracts/sg246503.html

mentioned in a previous reply by Vern Hamburg.

HTH,

Mark S. Waterbury

On 3/21/2013 4:44 PM, Anderson, Kurt wrote:
I'm at IBM i 7.1 and I just created a stored procedure to insert a record into a file (and return the identity created). However, I'm not sure how to apply error handling (to monitor for such things as a duplicate record error). I ran a bunch of searches, but I must not be using the right words. I've looked for Exception, Error handling, try, catch, and monitor.
I'm using this document as my main source of info:
http://pic.dhe.ibm.com/infocenter/iseries/v7r1m0/topic/db2/rbafz.pdf

Can anyone show me the path toward error handling in SQL on the IBM i?

Thanks,
Kurt

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a moment to review the archives at http://archive.midrange.com/midrange-l.

--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list To post a message email: MIDRANGE-L@xxxxxxxxxxxx To subscribe, unsubscribe, or change list options,
visit: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx Before posting, please take a moment to review the archives at http://archive.midrange.com/midrange-l.


As an Amazon Associate we earn from qualifying purchases.

This thread ...


Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.