The Syntax for GET DIAGNOSTICS is incomplete:
Declare Continue Handler for SQLException
Begin
Declare LocErrorMsg VarChar(256) not NULL Default '';
Get Diagnostics Condition 1 LocErrorMsg = MESSAGE_TEXT;
-- Now you can use the error message
INSERT INTO qtemp/WRKASP
Values(v_LPSEQUENCE, v_LPServer, 999999999, 'SQLerror',
-9999.99, LocErrMsg);
End;
Mit freundlichen Grüßen / Best regards
Birgitta Hauser
Modernization ? Education ? Consulting on IBM i
Database and Software Architect
IBM Champion since 2020
"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
"Train people well enough so they can leave, treat them well enough so they
don't want to. " (Richard Branson)
"Learning is experience ? everything else is only information!" (Albert
Einstein)
-----Original Message-----
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of Dan
Bale
Sent: Thursday, 16 May 2024 06:58
To: Midrange Systems Technical Discussion <midrange-l@xxxxxxxxxxxxxxxxxx>
Subject: How to insert a "special" row when SQLEXCEPTION happens?
A follow up to my earlier thread "SQL0206: Column or global variable
V_LPSERVER not found":
I've got this working now. As a former colleague liked to say, "it's
perfect except ..." ;-) In my testing, I found two scenarios when the
insert statement fails. 1) "User is not authorized to (remote) relational
database" and 2) the server is not defined in the RDB directory. When the
insert statement fails for whatever reason, I would still like to insert a
record into WRKASP using values from the LPARS table, LPSERVER and
LPSEQUENCE. In addition, the inserted record should have the error message
associated with the failure. (I've added a new ErrorMsg column to WRKASP.)
I discovered "DECLARE CONTINUE HANDLER FOR SQLEXCEPTION" in the SQL
Reference and you can see in the commented code below that I had an idea of
doing a special insert that utilized the LPARS columns but not
qsys2.asp_info columns, and included the error message. Unfortunately, the
live code (that is, the 6 lines under "GET DIAGNOSTICS CONDITION 1" were
uncommented) caused the CREATE PROCEDURE to fail with "SQL0199: Keyword
IMMEDIATE not expected. Valid tokens: =." I also tried wrapping those 6
lines around a Begin / End, but that just failed with "SQL0199: Keyword
EXECUTE not expected. Valid tokens: =." Any ideas?
CREATE or REPLACE PROCEDURE dbale/READ_LPARS_LOOP() modifies SQL data not
deterministic language SQL specific AC_WRKASP set option dbgview = *SOURCE
BEGIN
DECLARE v_LPSERVER VARCHAR(18);
DECLARE v_LPSEQUENCE INT;
DECLARE done INT DEFAULT 0;
DECLARE SQLstatement VARCHAR(1024);
DECLARE v_errormsg VARCHAR(70);
-- Declare a cursor to fetch rows from the LPARS table
DECLARE c_LPARS CURSOR FOR
SELECT LPSERVER, LPSEQUENCE
FROM LPARS
order by LPSEQUENCE;
-- Declare a CONTINUE HANDLER for NOT FOUND condition
DECLARE CONTINUE HANDLER FOR NOT FOUND
SET done = 1;
-- Declare a CONTINUE HANDLER for SQLEXCEPTION condition
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
GET DIAGNOSTICS CONDITION 1
-- EXECUTE IMMEDIATE
-- 'INSERT INTO qtemp/WRKASP (SELECT ' ||
-- v_LPSEQUENCE || ' AS Seq, ''' ||
-- v_LPSERVER || ''' AS Server, 999999999 as ASP_NUMBER,
''SQLerror'' as DEVD_NAME, ' ||
-- '-9999.99 AS Pct_Used, ''' || Message_Text || ''' as
ErrorMsg ' ||
-- 'FROM qsys2.asp_info ORDER BY Asp_Number)';
-- Open the cursor
OPEN c_LPARS;
-- Loop through the LPARS rows
read_loop: LOOP
FETCH c_LPARS INTO v_LPSERVER, v_LPSEQUENCE;
IF done = 1 THEN
LEAVE read_loop;
END IF;
set v_errormsg = '';
-- Execute the query for each LPARS row
EXECUTE IMMEDIATE
'INSERT INTO qtemp/WRKASP (SELECT ' ||
v_LPSEQUENCE || ' AS Seq, ''' ||
v_LPSERVER || ''' AS Server, ASP_NUMBER, DEVD_NAME, ' ||
'100 - ( ROUND( DEC(DEC(TOTAL_CAPACITY_AVAILABLE, 21, 3) /
DEC(TOTAL_CAPACITY, 21, 3) * 100, 21, 3), 2) ) AS Pct_Used, ' ||
' '''' as ErrorMsg ' ||
'FROM ' || trim(v_LPSERVER) || '.qsys2.asp_info ORDER BY
Asp_Number)';
END LOOP;
-- Close the cursor
CLOSE c_LPARS;
END;
*** CONFIDENTIALITY NOTICE: The information contained in this communication
may be confidential, and is intended only for the use of the recipients
named above. If the reader of this message is not the intended recipient,
you are hereby notified that any dissemination, distribution, or copying of
this communication, or any of its contents, is strictly prohibited. If you
have received this communication in error, please return it to the sender
immediately and delete the original message and any copy of it from your
computer system. If you have any questions concerning this message, please
contact the sender. ***
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxxxxxxxx To subscribe,
unsubscribe, or change list options,
visit:
https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/midrange-l.
Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.
As an Amazon Associate we earn from qualifying purchases.