467 - Contracten overhangen

svn path=/Customer/trunk/; revision=12740
This commit is contained in:
Richard Derks
2005-05-26 10:22:44 +00:00
parent 331aaf7c02
commit 6f7b5581db

279
CONN/Once/conn#467.sql Normal file
View File

@@ -0,0 +1,279 @@
set lines 2000;
/*
Contracten met cnt_contract_key = 1 moeten cnt_contract_key 2 krijgen.
*/
create or replace view contract1 as
select *
from cnt_contract
where cnt_srtcontract_key = 1;
/
-- Wijzig trigger tijdelijk ...
CREATE OR REPLACE TRIGGER cnt_t_cnt_contract_plaats_B_IU
BEFORE INSERT OR UPDATE ON cnt_contract_plaats
FOR EACH ROW
BEGIN
IF :new.cnt_contract_plaats_key IS NULL THEN SELECT cnt_s_cnt_contract_plaats_key.nextval INTO :new.cnt_contract_plaats_key FROM DUAL; END IF;
IF ((:old.cnt_alg_plaats_key <> :new.cnt_alg_plaats_key)
OR (:old.cnt_alg_plaats_key IS NULL))
THEN
IF :new.cnt_alg_plaats_code = 'R'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_ruimte_key INTO dummy FROM alg_v_aanwezigruimte WHERE alg_ruimte_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m007'); END;
ELSIF :new.cnt_alg_plaats_code = 'V'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_verdieping_key INTO dummy FROM alg_v_aanwezigverdieping WHERE alg_verdieping_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m006'); END;
ELSIF :new.cnt_alg_plaats_code = 'G'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_gebouw_key INTO dummy FROM alg_v_aanweziggebouw WHERE alg_gebouw_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m005'); END;
ELSIF :new.cnt_alg_plaats_code = 'T'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_terreinsector_key INTO dummy FROM alg_v_aanwezigterreinsector WHERE alg_terreinsector_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m004'); END;
ELSIF :new.cnt_alg_plaats_code = 'L'
THEN
DECLARE dummy NUMBER(10);
BEGIN
-- Deze optie doet even niet mee ten tijde van de conversie ...
NULL;
END;
ELSE
raise_application_error(-20000, 'cnt_m008');
END IF;
END IF;
END;
/
--INSERT INTO CNT_CONTRACT_PLAATS
create or replace view contract_plaats_add as
select distinct co.cnt_contract_key, insd.ins_alg_locatie_key cnt_alg_plaats_key, 'L' cnt_alg_plaats_code
from cnt_contract c, cnt_contract_object co, ins_deel insd
where c.cnt_srtcontract_key = 1
and c.cnt_contract_key = co.cnt_contract_key
and co.cnt_ins_deel_key = insd.ins_deel_key(+);
/
-- 827 rows created
insert into cnt_contract_plaats (cnt_contract_key,cnt_alg_plaats_key,cnt_alg_plaats_code)
(select cnt_contract_key,cnt_alg_plaats_key,cnt_alg_plaats_code from contract_plaats_add);
drop view contract_plaats_add;
commit;
-- INSERT INTO CNT_CONTRACT_OBJECT
create or replace view contract_objecttype_add as
select co.cnt_contract_key, insd.ins_srtdeel_key cnt_ins_srtdeel_key
from cnt_contract c, cnt_contract_object co, ins_deel insd
where c.cnt_srtcontract_key = 1
and c.cnt_contract_key = co.cnt_contract_key
and co.cnt_ins_deel_key = insd.ins_deel_key(+)
group by co.cnt_contract_key, insd.ins_srtdeel_key;
/
-- 907 rows created
insert into cnt_contract_object (cnt_contract_key,cnt_ins_srtdeel_key)
(select cnt_contract_key,cnt_ins_srtdeel_key from contract_objecttype_add);
drop view contract_objecttype_add;
commit;
-- delete from cnt_contract_object
create or replace view contract_object_del as
select co.cnt_contract_object_key, co.cnt_contract_object_aanmaak
from cnt_contract c, cnt_contract_object co, ins_deel insd
where c.cnt_srtcontract_key = 1
and c.cnt_contract_key = co.cnt_contract_key
and co.cnt_ins_deel_key = insd.ins_deel_key(+)
and co.cnt_ins_deel_key is not null;
/
-- 2923 rows deleted
delete from cnt_contract_object
where cnt_contract_object_key in (select od.cnt_contract_object_key from contract_object_del od);
drop view contract_object_del;
commit;
-- update cnt datums
-- 2260 rows updated.
update cnt_contract
set CNT_CONTRACT_LOOPTIJD_TOT = CNT_CONTRACT_LOOPTIJD_TOT + (to_date('01-01-2001', 'dd-mm-yyyy') - to_date('02-01-2000', 'dd-mm-yyyy'))
where CNT_CONTRACT_LOOPTIJD_TOT is not null;
-- 2260 rows updated.
update cnt_contract
set CNT_CONTRACT_OPZEGDATUM = CNT_CONTRACT_OPZEGDATUM + (to_date('01-01-2001', 'dd-mm-yyyy') - to_date('02-01-2000', 'dd-mm-yyyy'))
where CNT_CONTRACT_OPZEGDATUM is not null;
-- 2260 rows updated.
update cnt_contract
set CNT_CONTRACT_RAPPELDATUM = CNT_CONTRACT_RAPPELDATUM + (to_date('01-01-2001', 'dd-mm-yyyy') - to_date('02-01-2000', 'dd-mm-yyyy'))
where CNT_CONTRACT_RAPPELDATUM is not null;
commit;
--
update cnt_contract
set CNT_SRTCONTRACT_KEY = 11
where CNT_SRTCONTRACT_KEY = 1;
commit;
/* Test van dit script op CONN_448@DIT06 van 26 mei 2005, notatie [voor/na]
-- CNT_CONTRACT
-- [1535/0]
select count(*)
from cnt_contract
where CNT_SRTCONTRACT_KEY = 1;
-- [131/1666(verschil=1535)]
select count(*)
from cnt_contract
where CNT_SRTCONTRACT_KEY = 11;
-- CNT_CONTRACT_OBJECT
-- [2923/0]
select count(*)
from cnt_contract_object co, cnt_contract cc
where co.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 1;
-- [111/1018(verschil=907)]
select count(*)
from cnt_contract_object co, cnt_contract cc
where co.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 11;
-- [111/1018(verschil=907: maw 1 srt_deel per contract)]
select count(*)
from
(select 'x'
from cnt_contract_object co, cnt_contract cc
where co.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 11
group by co.cnt_contract_key, co.cnt_ins_srtdeel_key);
-- [111?/1793(verschil=1682)]
select count(*)
from
(select 'x'
from cnt_contract_plaats cp, cnt_contract cc
where cp.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 11
group by cp.cnt_alg_plaats_key, cp.cnt_contract_key);
Bovenstaande waarnemning 111? klopt niet ('26-05-2005' is de testdag):
[nvt/827(dit aantal klopt, zie hieronder ....]
select count(*)
from cnt_contract_plaats
where to_char(cnt_contract_plaats_aanmaak, 'dd-mm-yyyy') = '26-05-2005';
-- CNT_CONTRACT_PLAATS
-- [855/0]
select count(*)
from cnt_contract_plaats cp, cnt_contract cc
where cp.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 1;
-- [111?/1793]
select count(*)
from cnt_contract_plaats cp, cnt_contract cc
where cp.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 11;
Bovenstaande waarnemning 111? klopt niet, zie ook hierboven
-- [827/0]
select count(*)
from
(select 'x'
from cnt_contract_object co, cnt_contract cc, ins_deel de
where co.cnt_contract_key = cc.cnt_contract_key
and cc.CNT_SRTCONTRACT_KEY = 1
and co.cnt_ins_deel_key = de.ins_deel_key
group by co.cnt_contract_key, de.ins_alg_locatie_key);
-- Ophogen datum met 1 jaar (opm: de actuele gegevens mbt de datums na uitvoeren script wijken 1 dag af)
-- [19 maart 1982/19-MAR-83]
select min(CNT_CONTRACT_LOOPTIJD_TOT)
from cnt_contract
where CNT_CONTRACT_LOOPTIJD_TOT is not null;
-- [1 januari 2005/01-JAN-06]
select max(CNT_CONTRACT_LOOPTIJD_TOT)
from cnt_contract
where CNT_CONTRACT_LOOPTIJD_TOT is not null;
-- [19-MAR-82/19-MAR-83]
select min(CNT_CONTRACT_OPZEGDATUM)
from cnt_contract
where CNT_CONTRACT_OPZEGDATUM is not null;
-- [01-JAN-14/01-JAN-15]
select max(CNT_CONTRACT_OPZEGDATUM)
from cnt_contract
where CNT_CONTRACT_OPZEGDATUM is not null;
-- [19-MAR-82/19-MAR-83]
select min(CNT_CONTRACT_RAPPELDATUM)
from cnt_contract
where CNT_CONTRACT_RAPPELDATUM is not null;
-- [01-JAN-14/01-JAN-15]
select max(CNT_CONTRACT_RAPPELDATUM)
from cnt_contract
where CNT_CONTRACT_RAPPELDATUM is not null;
*/
CREATE OR REPLACE TRIGGER cnt_t_cnt_contract_plaats_B_IU
BEFORE INSERT OR UPDATE ON cnt_contract_plaats
FOR EACH ROW
BEGIN
IF :new.cnt_contract_plaats_key IS NULL THEN SELECT cnt_s_cnt_contract_plaats_key.nextval INTO :new.cnt_contract_plaats_key FROM DUAL; END IF;
IF ((:old.cnt_alg_plaats_key <> :new.cnt_alg_plaats_key)
OR (:old.cnt_alg_plaats_key IS NULL))
THEN
IF :new.cnt_alg_plaats_code = 'R'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_ruimte_key INTO dummy FROM alg_v_aanwezigruimte WHERE alg_ruimte_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m007'); END;
ELSIF :new.cnt_alg_plaats_code = 'V'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_verdieping_key INTO dummy FROM alg_v_aanwezigverdieping WHERE alg_verdieping_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m006'); END;
ELSIF :new.cnt_alg_plaats_code = 'G'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_gebouw_key INTO dummy FROM alg_v_aanweziggebouw WHERE alg_gebouw_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m005'); END;
ELSIF :new.cnt_alg_plaats_code = 'T'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_terreinsector_key INTO dummy FROM alg_v_aanwezigterreinsector WHERE alg_terreinsector_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m004'); END;
ELSIF :new.cnt_alg_plaats_code = 'L'
THEN
DECLARE dummy NUMBER(10); BEGIN SELECT alg_locatie_key INTO dummy FROM alg_v_aanweziglocatie WHERE alg_locatie_key = :new.cnt_alg_plaats_key; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(-20000, 'cnt_m003'); END;
ELSE
raise_application_error(-20000, 'cnt_m008');
END IF;
END IF;
END;
/
commit;