BVB1#79885 Automatisch nummeren van objecten inclusief scheidingsteken
svn path=/Database/trunk/; revision=61718
This commit is contained in:
@@ -10747,9 +10747,7 @@ AS
|
||||
-- "uitgeleend" aan dezelfde ruimte (ruimte kan >1 deuren hebben).
|
||||
v_errormsg := 'Fout bij bepalen default ID (cilinder)';
|
||||
|
||||
SELECT INS.GET_DESCRIPTION ('LPN_INS_DEEL',
|
||||
NULL,
|
||||
UPPER (rec.ins_srtdeel_code))
|
||||
SELECT INS.nextdescription (rec.ins_srtdeel_code, NULL)
|
||||
INTO v_deel_oms
|
||||
FROM ins_srtdeel
|
||||
WHERE ins_srtdeel_key = v_srtdeel_key;
|
||||
@@ -10953,10 +10951,7 @@ AS
|
||||
BEGIN
|
||||
v_errormsg := 'Fout bij bepalen default ID (sleutel)';
|
||||
|
||||
SELECT INS.GET_DESCRIPTION (
|
||||
'LPN_INS_DEEL',
|
||||
NULL,
|
||||
UPPER (rec.ins_srtdeel_code))
|
||||
SELECT INS.nextdescription (rec.ins_srtdeel_code, NULL)
|
||||
INTO v_deel_oms
|
||||
FROM ins_srtdeel
|
||||
WHERE ins_srtdeel_key = v_srtdeel_key;
|
||||
|
||||
192
INS/INS_PAC.SRC
192
INS/INS_PAC.SRC
@@ -6,7 +6,8 @@
|
||||
|
||||
CREATE OR REPLACE PACKAGE ins AS
|
||||
FUNCTION delete_deelkoppeling( DeelKey IN NUMBER ) RETURN BOOLEAN;
|
||||
FUNCTION get_description(LPNName IN VARCHAR2, CondKey IN NUMBER, Prefix IN VARCHAR2) RETURN VARCHAR2;
|
||||
FUNCTION get_description(pentityname IN VARCHAR2, pparentkey IN NUMBER, pprefix IN VARCHAR2) RETURN VARCHAR2;
|
||||
FUNCTION nextdescription(pprefix IN VARCHAR2, pparentkey IN NUMBER, pseparator IN VARCHAR2 DEFAULT '') RETURN VARCHAR2;
|
||||
FUNCTION sprintf (ps IN varchar2, pins_deel_key IN number) RETURN varchar2;
|
||||
FUNCTION contrsprintf (ps IN varchar2, pins_deelsrtcontr_key IN NUMBER) RETURN varchar2;
|
||||
FUNCTION nextcyclusdate (p_insdeel IN NUMBER, p_srtcontrole IN NUMBER, p_scenario IN NUMBER, p_steps IN NUMBER DEFAULT 0) RETURN DATE;
|
||||
@@ -33,140 +34,65 @@ CREATE OR REPLACE PACKAGE BODY ins AS
|
||||
WHEN OTHERS THEN RETURN FALSE;
|
||||
END;
|
||||
|
||||
-- Was: FAC_F_FAC_GET_DESCRIPTION
|
||||
FUNCTION get_description(LPNName IN VARCHAR2
|
||||
,CondKey IN NUMBER
|
||||
,Prefix IN VARCHAR2) RETURN VARCHAR2 IS
|
||||
NextVolgNr VARCHAR2(30);
|
||||
DeelUpper ins_deel.ins_deel_omschrijving%TYPE;
|
||||
ReturnString VARCHAR2(30);
|
||||
-- For backwards compatibility only (used in some CUST procedures) DEPRECATED!
|
||||
FUNCTION get_description( pentityname IN VARCHAR2
|
||||
, pparentkey IN NUMBER
|
||||
, pprefix IN VARCHAR2) RETURN VARCHAR2 IS
|
||||
BEGIN
|
||||
-- From 4.40 on, CondKey is dummy for ins_deel (object): uniqueness is assumed over the entire database
|
||||
-- From DB23 on, object uniqueness is forced by prefix only, last parameter PrefixKey was dropped
|
||||
IF LPNName = 'LPN_INS_DEEL'
|
||||
THEN
|
||||
SELECT NVL(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(Prefix)),'0'),'001')
|
||||
INTO NextVolgNr
|
||||
FROM ins_deel
|
||||
WHERE ins_deel_upper LIKE Prefix||'%'
|
||||
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))) IS NOT NULL
|
||||
AND LTRIM(SUBSTR (ins_deel_upper, LENGTH (Prefix) + 1), '0') = TO_CHAR(fac.safe_to_integer ((SUBSTR (ins_deel_upper, LENGTH (Prefix) + 1))))
|
||||
AND ins_deel_parent_key IS NULL
|
||||
AND ins_deel_verwijder IS NULL;
|
||||
ELSIF LPNName = 'LPN_INS_ONDERDEEL'
|
||||
THEN
|
||||
SELECT NVL(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(Prefix)),'0'),'001')
|
||||
INTO NextVolgNr
|
||||
FROM INS_DEEL
|
||||
WHERE ins_deel_upper LIKE Prefix||'%'
|
||||
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(Prefix)+1,LENGTH(ins_deel_upper)-LENGTH(Prefix))) IS NOT NULL
|
||||
AND ins_deel_parent_key = CondKey
|
||||
AND ins_deel_verwijder IS NULL;
|
||||
ELSIF LPNName = 'LPN_ALG_TERREINSECTOR'
|
||||
THEN
|
||||
FOR i IN 3..10
|
||||
LOOP
|
||||
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_terreinsector_code,LENGTH(alg_terreinsector_code)-(i-1),LENGTH(alg_terreinsector_code)))+1)), '***')
|
||||
INTO NextVolgNr
|
||||
FROM alg_v_aanwezigterreinsector
|
||||
WHERE LTRIM(SUBSTR(alg_terreinsector_code, LENGTH(alg_terreinsector_code)-(i-1), LENGTH(alg_terreinsector_code))) BETWEEN '0' AND LPAD('9',i,'9')
|
||||
AND alg_locatie_key = CondKey
|
||||
AND LENGTH(alg_terreinsector_code) <= i;
|
||||
IF NextVolgNr = '***'
|
||||
THEN
|
||||
IF i = 3
|
||||
THEN
|
||||
NextVolgNr := '001';
|
||||
ELSE
|
||||
NextVolgNr := POWER(10, (i-1));
|
||||
END IF;
|
||||
EXIT;
|
||||
ELSE
|
||||
IF LENGTH(NextVolgNr) <= i
|
||||
THEN
|
||||
NextVolgNr:= LPAD(NextVolgNr,i,'0');
|
||||
EXIT;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
ELSIF LPNName = 'LPN_ALG_GEBOUW'
|
||||
THEN
|
||||
FOR i IN 3..10
|
||||
LOOP
|
||||
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_gebouw_code, LENGTH(alg_gebouw_code)-(i-1), LENGTH(alg_gebouw_code)))+1)), '***')
|
||||
INTO NextVolgNr
|
||||
FROM alg_v_aanweziggebouw
|
||||
WHERE LTRIM(SUBSTR(alg_gebouw_code, LENGTH(alg_gebouw_code)-(i-1), LENGTH(alg_gebouw_code))) BETWEEN '0' AND LPAD('9',i,'9')
|
||||
AND alg_locatie_key = CondKey
|
||||
AND LENGTH(alg_gebouw_code) <= i;
|
||||
IF NextVolgNr = '***'
|
||||
THEN
|
||||
IF i = 3
|
||||
THEN
|
||||
NextVolgNr := '001';
|
||||
ELSE
|
||||
NextVolgNr := POWER(10, (i-1));
|
||||
END IF;
|
||||
EXIT;
|
||||
ELSE
|
||||
IF LENGTH(NextVolgNr) <= i
|
||||
THEN
|
||||
NextVolgNr:= LPAD(NextVolgNr,i,'0');
|
||||
EXIT;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
ELSIF LPNName = 'LPN_ALG_RUIMTE'
|
||||
THEN
|
||||
FOR i IN 3..10
|
||||
LOOP
|
||||
SELECT NVL(TO_CHAR(MAX(TO_NUMBER(SUBSTR(alg_ruimte_nr, LENGTH(alg_ruimte_nr)-(i-1), LENGTH(alg_ruimte_nr)))+1)), '***')
|
||||
INTO NextVolgNr
|
||||
FROM alg_v_aanwezigruimte
|
||||
WHERE LTRIM(SUBSTR(alg_ruimte_nr, LENGTH(alg_ruimte_nr)-(i-1), LENGTH(alg_ruimte_nr))) BETWEEN '0' AND LPAD('9',i,'9')
|
||||
AND alg_verdieping_key = CondKey
|
||||
AND LENGTH(alg_ruimte_nr) <= i;
|
||||
IF NextVolgNr = '***'
|
||||
THEN
|
||||
IF i = 3
|
||||
THEN
|
||||
NextVolgNr := '001';
|
||||
ELSE
|
||||
NextVolgNr := POWER(10, (i-1));
|
||||
END IF;
|
||||
EXIT;
|
||||
ELSE
|
||||
IF LENGTH(NextVolgNr) <= i
|
||||
THEN
|
||||
NextVolgNr:= LPAD(NextVolgNr,i,'0');
|
||||
EXIT;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
ELSIF LPNName = 'LPN_PRS_WERKPLEK'
|
||||
THEN
|
||||
BEGIN
|
||||
SELECT TO_CHAR(NVL(MAX(prs_werkplek_volgnr),0) +1)
|
||||
INTO NextVolgNr
|
||||
FROM prs_werkplek
|
||||
WHERE prs_alg_ruimte_key = CondKey;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN NextVolgNr := '1';
|
||||
END;
|
||||
/* Omschrijving */
|
||||
BEGIN
|
||||
SELECT alg_ruimte_nr ||' - '|| NextVolgNr
|
||||
INTO NextVolgNr
|
||||
FROM alg_ruimte
|
||||
WHERE alg_ruimte_key = CondKey;
|
||||
EXCEPTION
|
||||
WHEN OTHERS
|
||||
THEN NULL;
|
||||
END;
|
||||
IF pentityname = 'LPN_INS_DEEL'
|
||||
THEN
|
||||
RETURN ins.nextdescription(pprefix, NULL, '');
|
||||
END IF;
|
||||
ReturnString := Prefix||NextVolgNr;
|
||||
RETURN ReturnString;
|
||||
|
||||
IF pentityname = 'LPN_INS_ONDERDEEL'
|
||||
THEN
|
||||
RETURN ins.nextdescription(pprefix, pparentkey, '');
|
||||
END IF;
|
||||
RETURN 'unsupported use of ins.get_description';
|
||||
END;
|
||||
|
||||
-- Determine max+1 volgnr for an object (deel or onderdeel) op basis van het format prefix+volgnummer
|
||||
-- De laagste is 001 maar vervolgens wordt het gevonde aantal cijfers aangehouden, dus prefix0001+1 = prefix0002
|
||||
-- Zo nodig wordt er een cijfer bij gedaan. De prefix wordt case-insensitive beschouwd.
|
||||
-- Alleen actuele objecten worden beschouwd, dus dit is in zekere zin een beetje tijdsafhankelijk
|
||||
FUNCTION nextdescription( pprefix IN VARCHAR2
|
||||
, pparentkey IN NUMBER
|
||||
, pseparator IN VARCHAR2 DEFAULT '') RETURN VARCHAR2 IS
|
||||
nextvolgnr VARCHAR2(30);
|
||||
returnstring ins_deel.ins_deel_omschrijving%TYPE;
|
||||
lprefix VARCHAR2(60);
|
||||
BEGIN
|
||||
lprefix := pprefix||pseparator;
|
||||
-- uniqueness is assumed over the entire database
|
||||
IF pparentkey IS NULL
|
||||
THEN
|
||||
SELECT COALESCE(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(lprefix)+1,LENGTH(ins_deel_upper)-LENGTH(lprefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(lprefix)),'0'),'001')
|
||||
INTO nextvolgnr
|
||||
FROM ins_deel
|
||||
WHERE ins_deel_upper LIKE UPPER(lprefix)||'%'
|
||||
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(lprefix)+1,LENGTH(ins_deel_upper)-LENGTH(lprefix))) IS NOT NULL
|
||||
AND LTRIM(SUBSTR (ins_deel_upper, LENGTH (lprefix) + 1), '0') = TO_CHAR(fac.safe_to_integer ((SUBSTR (ins_deel_upper, LENGTH (lprefix) + 1))))
|
||||
AND ins_deel_parent_key IS NULL
|
||||
AND (ins_deel_vervaldatum IS NULL OR (ins_deel_vervaldatum is not null and ins_deel_vervaldatum > SYSDATE))
|
||||
AND ins_deel_verwijder IS NULL;
|
||||
ELSIF pparentkey IS NOT NULL
|
||||
THEN
|
||||
SELECT COALESCE(LPAD( TO_CHAR(MAX(TO_NUMBER(SUBSTR(ins_deel_upper, LENGTH(lprefix)+1,LENGTH(ins_deel_upper)-LENGTH(lprefix))))+1) , MAX(LENGTH(ins_deel_upper)-LENGTH(lprefix)),'0'),'001')
|
||||
INTO nextvolgnr
|
||||
FROM ins_deel
|
||||
WHERE ins_deel_upper LIKE UPPER(lprefix)||'%'
|
||||
AND fac.safe_to_integer(SUBSTR(ins_deel_upper, LENGTH(lprefix)+1,LENGTH(ins_deel_upper)-LENGTH(lprefix))) IS NOT NULL
|
||||
AND ins_deel_parent_key = pparentkey
|
||||
AND (ins_deel_vervaldatum IS NULL OR (ins_deel_vervaldatum is not null and ins_deel_vervaldatum > SYSDATE))
|
||||
AND ins_deel_verwijder IS NULL;
|
||||
END IF;
|
||||
-- bij overflow moet er een digit bij komen: 999+1=1000 en bovenstaande levert dan 100
|
||||
IF LOG (10, TO_NUMBER(nextvolgnr)) = ROUND (LOG (10, TO_NUMBER(nextvolgnr)), 0)
|
||||
THEN
|
||||
nextvolgnr := nextvolgnr||'0';
|
||||
END IF;
|
||||
returnstring := pprefix||pseparator||nextvolgnr;
|
||||
RETURN returnstring;
|
||||
END;
|
||||
|
||||
FUNCTION sprintf (ps IN varchar2, pins_deel_key IN number)
|
||||
|
||||
@@ -117,9 +117,10 @@ AS
|
||||
AND ins_srtdeel_key = srtdeelkey
|
||||
AND ins_deel_verwijder IS NULL;
|
||||
-- Gevonden, dus niet uniek. Probeer het met een sterretje ervoor, passen ze dat later maar zelf aan
|
||||
SELECT ins.get_description('LPN_INS_DEEL',parent_key , ins_srtdeel_code_upper)
|
||||
INTO omschrijving
|
||||
FROM ins_srtdeel WHERE ins_srtdeel_key=srtdeelkey;
|
||||
SELECT ins.nextdescription(ins_srtdeel_code, parent_key)
|
||||
INTO omschrijving
|
||||
FROM ins_srtdeel
|
||||
WHERE ins_srtdeel_key = srtdeelkey;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND
|
||||
THEN
|
||||
|
||||
Reference in New Issue
Block a user