On 20 Mar 2013 11:30, Steve Richter wrote:
in RPG record I/O I lock a control record, increment a control
number, then update the control record. Which reliably gives me
a unique value.
C** GET NEXT SID NUMBER FROM WCMAST
C inwacd CHAIN WCREC
C EVAL WCNSID += 1
C UPDATE WCREC
/free
outSid = wcnsid ;
/end-free
Can I use SQL to do the same thing?
If I understand correctly, I might do the following to replace that code:
/free
exec sql call wcnstdIncr(inwacd, outSid) ;
if sqlcode <> 0 ; // bad thing
exec sql rollback ;
// inform of failure as appropriate and exit
else ;
exec sql commit ;
endif ;
// if errors did not prevent our getting here
// then OutSid is the NEXT SID NUMBER FROM WCMAST
/end-free
The procedure would be defined something like the following [with
some added error-handling possibly, perhaps for resolving an overflow,
but things like a locked row, file not found, or row not found, file not
journaled, etc. could be deferred to caller to deal with, based upon the
SQL error, because there is less ability for the procedure to resolve
those]:
create procedure wcnstdIncr
( inKey in type-dcl /* such as VARCHAR(10) */
, outSid out type-dcl /* such as INTEGER */
) language sql /* other clauses of importance */
set option dbgview=*SOURCE, commit=UR
begin
declare IncrWcnstd cursor for
select wcnstd+1
from WCMAST
where WCMAST_key=inKey
for update of wcnstd ;
open IncrWcnstd ;
fetch IncrWcnstd into outSid ;
update WCMAST set wcnstd = wcnstd + 1 where current of IncrWcnstd ;
close IncrWcnstd ;
end
This could be done WITH NC isolation instead [of the UR shown], and
the row lock will be dropped upon CLOSE of the cursor instead of the
COMMIT in the invoking program.
As an Amazon Associate we earn from qualifying purchases.