× 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.



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.

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.