FSN#516 (to be approved)
svn path=/Database/trunk/; revision=8468
This commit is contained in:
@@ -131,6 +131,31 @@ CREATE_TABLE(alg_locatie,ALG_NORMAAL_PRIVILEGE)
|
||||
CONSTRAINT alg_u_alg_locatie_upper UNIQUE(alg_district_key, alg_locatie_upper, alg_locatie_verwijder)
|
||||
);
|
||||
|
||||
CREATE_TABLE(alg_srtterreinsector,ALG_BIBLIOTHEEK_PRIVILEGE)
|
||||
(
|
||||
alg_srtterreinsector_key
|
||||
NUMBER(10)
|
||||
CONSTRAINT alg_k_alg_srtterreinsector_key PRIMARY KEY,
|
||||
alg_srtterreinsec_omschrijving
|
||||
VARCHAR2(30)
|
||||
CONSTRAINT alg_c_alg_srtterreinsec_omschr CHECK(alg_srtterreinsec_omschrijving IS NOT NULL),
|
||||
alg_srtterreinsector_upper
|
||||
VARCHAR2(30)
|
||||
CONSTRAINT alg_c_alg_srtterreinsec_upper CHECK(alg_srtterreinsector_upper IS NOT NULL),
|
||||
alg_srtterreinsector_prijs
|
||||
NUMBER(8,2),
|
||||
alg_srtterreinsector_aanmaak
|
||||
DATE
|
||||
DEFAULT SYSDATE
|
||||
CONSTRAINT alg_c_alg_srtterrein_aanmaak NOT NULL,
|
||||
alg_srtterreinsector_verwijder
|
||||
DATE
|
||||
DEFAULT NULL,
|
||||
CONSTRAINT alg_u_alg_srtterreinsec_upper UNIQUE(alg_srtterreinsector_upper, alg_srtterreinsector_verwijder),
|
||||
prs_verhuurbaar NUMBER(1),
|
||||
alg_srtterreinsector_code VARCHAR2(10)
|
||||
);
|
||||
|
||||
CREATE_TABLE(alg_terreinsector,ALG_NORMAAL_PRIVILEGE)
|
||||
(
|
||||
alg_terreinsector_key
|
||||
@@ -158,6 +183,9 @@ CREATE_TABLE(alg_terreinsector,ALG_NORMAAL_PRIVILEGE)
|
||||
NOT_NULL(alg_terreinsector_upper, alg_c_alg_terreinsector_upper)
|
||||
#endif
|
||||
,
|
||||
alg_srtterreinsector_key NUMBER(10)
|
||||
CONSTRAINT alg_r_alg_srtterreinsector_key
|
||||
REFERENCES alg_srtterreinsector(alg_srtterreinsector_key),
|
||||
alg_terreinsector_oppervlak
|
||||
NUMBER(12,2)
|
||||
CONSTRAINT alg_c_alg_terreinsector_opp CHECK(alg_terreinsector_oppervlak >= 0),
|
||||
@@ -332,6 +360,8 @@ CREATE_TABLE(alg_srtruimte,ALG_BIBLIOTHEEK_PRIVILEGE)
|
||||
NOT_NULL(alg_srtruimte_upper, alg_c_alg_srtruimte_upper)
|
||||
#endif
|
||||
,
|
||||
alg_srtruimte_code
|
||||
VARCHAR2(10),
|
||||
alg_srtruimte_prijs
|
||||
NUMBER(8,2),
|
||||
alg_srtruimte_aanmaak
|
||||
|
||||
@@ -1,5 +1,6 @@
|
||||
/* Triggers voor ALG-module
|
||||
*
|
||||
* 10-11-2003 RL alg_t_alg_srtterreinsector_B_IU created for FSN 516.
|
||||
* 07-05-2003 RL alg_t_alg_onrgoedkenmerk_b_iu: INSTR -> INSTR2, select .nextval in #ifdef
|
||||
* 23-04-2003 BIV FSN#203 : Trigger alg_t_alg_kenmerk_b_iu aangepast.
|
||||
*/
|
||||
@@ -739,3 +740,17 @@ BEGIN
|
||||
END;
|
||||
/
|
||||
*/
|
||||
|
||||
|
||||
CREATE_TRIGGER(alg_t_alg_srtterreinsec_B_IU)
|
||||
BEFORE INSERT OR UPDATE ON alg_srtterreinsector
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE_PRIMARY_KEY(alg_srtterreinsector_key, alg_s_alg_srtruimte_key);
|
||||
UPDATE_UPPER(alg_srtterreinsec_omschrijving, alg_srtterreinsector_upper);
|
||||
UPDATE_AANMAAKDATUM(alg_srtterreinsector, alg_srtterreinsector_aanmaak);
|
||||
|
||||
CHECK_NOG_REFERENCES(alg_srtterreinsector, alg_srtterreinsector_verwijder,
|
||||
alg_v_aanwezigsrtterreinsector, alg_srtterreinsector_key, 'alg_m041');
|
||||
END;
|
||||
/
|
||||
|
||||
156
ALG/ALG_VIE.SRC
156
ALG/ALG_VIE.SRC
@@ -212,7 +212,7 @@ SELECT ALG_L.alg_locatie_key, ALG_L.alg_district_key,
|
||||
ALG_R.alg_ruimte_opp_gevelbekleding,
|
||||
ALG_L.alg_locatie_code ||' - '
|
||||
|| ALG_G.alg_gebouw_code ||' - '
|
||||
|| ALG_V.alg_verdieping_code ||' - '
|
||||
|| ALG_V.alg_verdieping_code ||' - '
|
||||
|| ALG_R.alg_ruimte_nr ALG_RUIMTE_AANDUIDING,
|
||||
ALG_R.alg_ruimte_omtrek,
|
||||
ALG_R.alg_ruimte_inhoud,
|
||||
@@ -421,7 +421,8 @@ CREATE_VIEW(alg_v_onroerendgoed_gegevens,ALG_NORMAAL_PRIVILEGE)
|
||||
alg_terreinsector_key,
|
||||
alg_terreinsector_code,
|
||||
alg_terreinsector_naam,
|
||||
alg_type) AS
|
||||
alg_type,
|
||||
alg_locatie_key ) AS
|
||||
SELECT ALG_R.alg_ruimte_key,
|
||||
ALG_R.alg_ruimte_nr,
|
||||
ALG_R.alg_ruimte_omschrijving,
|
||||
@@ -437,7 +438,8 @@ CREATE_VIEW(alg_v_onroerendgoed_gegevens,ALG_NORMAAL_PRIVILEGE)
|
||||
to_number(NULL),
|
||||
NULL,
|
||||
NULL,
|
||||
'R'
|
||||
'R',
|
||||
ALG_G.alg_locatie_key
|
||||
FROM alg_v_aanwezigruimte ALG_R, alg_verdieping ALG_V, alg_gebouw ALG_G
|
||||
WHERE ALG_R.alg_verdieping_key = ALG_V.alg_verdieping_key
|
||||
AND ALG_V.alg_gebouw_key = ALG_G.alg_gebouw_key
|
||||
@@ -457,7 +459,8 @@ CREATE_VIEW(alg_v_onroerendgoed_gegevens,ALG_NORMAAL_PRIVILEGE)
|
||||
to_number(NULL),
|
||||
NULL,
|
||||
NULL,
|
||||
'V'
|
||||
'V',
|
||||
ALG_G.alg_locatie_key
|
||||
FROM alg_v_aanwezigverdieping ALG_V, alg_gebouw ALG_G
|
||||
WHERE ALG_V.alg_gebouw_key = ALG_G.alg_gebouw_key
|
||||
UNION
|
||||
@@ -476,7 +479,8 @@ CREATE_VIEW(alg_v_onroerendgoed_gegevens,ALG_NORMAAL_PRIVILEGE)
|
||||
to_number(NULL),
|
||||
NULL,
|
||||
NULL,
|
||||
'G'
|
||||
'G',
|
||||
ALG_G.alg_locatie_key
|
||||
FROM alg_v_aanweziggebouw ALG_G
|
||||
UNION
|
||||
SELECT ALG_T.alg_terreinsector_key,
|
||||
@@ -494,7 +498,8 @@ CREATE_VIEW(alg_v_onroerendgoed_gegevens,ALG_NORMAAL_PRIVILEGE)
|
||||
ALG_T.alg_terreinsector_key,
|
||||
ALG_T.alg_terreinsector_code,
|
||||
ALG_T.alg_terreinsector_naam,
|
||||
'T'
|
||||
'T',
|
||||
ALG_T.alg_locatie_key
|
||||
FROM alg_v_aanwezigterreinsector ALG_T;
|
||||
|
||||
CREATE_VIEW(alg_v_alg_ruimte_verdieping,ALG_NORMAAL_PRIVILEGE)
|
||||
@@ -623,62 +628,62 @@ DEFINIEER_VIEW_AANWEZIG(alg_refkenmerk, alg_refkenmerk_verwijder,
|
||||
CREATE_VIEW(alg_v_my_room, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT alg_ruimte_key,
|
||||
alg_verdieping_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_ruimte, prs_perslid p
|
||||
WHERE alg_ruimte_key IN
|
||||
(SELECT prs_alg_ruimte_key
|
||||
FROM prs_v_aanwezigperslid pp, prs_v_aanwezigperslidwerkplek pl,
|
||||
prs_v_aanwezigwerkplek wp
|
||||
prs_v_aanwezigwerkplek wp
|
||||
WHERE pp.prs_perslid_key = pl.prs_perslid_key
|
||||
AND pl.prs_werkplek_key = wp.prs_werkplek_key
|
||||
AND pp.prs_perslid_key = p.prs_perslid_key);
|
||||
AND pl.prs_werkplek_key = wp.prs_werkplek_key
|
||||
AND pp.prs_perslid_key = p.prs_perslid_key);
|
||||
|
||||
CREATE_VIEW(alg_v_my_floor, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT v.alg_verdieping_key,
|
||||
alg_gebouw_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_v_my_room r, alg_verdieping v
|
||||
WHERE r.alg_verdieping_key = v.alg_verdieping_key;
|
||||
|
||||
CREATE_VIEW(alg_v_my_building, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT f.alg_gebouw_key,
|
||||
alg_locatie_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_v_my_floor f, alg_gebouw b
|
||||
WHERE f.alg_gebouw_key = b.alg_gebouw_key;
|
||||
|
||||
CREATE_VIEW(alg_v_my_location, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT b.alg_locatie_key,
|
||||
l.alg_district_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_v_my_building b, alg_locatie l
|
||||
WHERE b.alg_locatie_key = l.alg_locatie_key;
|
||||
|
||||
CREATE_VIEW(alg_v_my_district, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT l.alg_district_key,
|
||||
alg_regio_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_v_my_location l, alg_district d
|
||||
WHERE l.alg_district_key = d.alg_district_key;
|
||||
|
||||
CREATE_VIEW(alg_v_my_region, ALG_NORMAAL_PRIVILEGE) AS
|
||||
SELECT alg_regio_key,
|
||||
prs_perslid_key
|
||||
prs_perslid_key
|
||||
FROM alg_v_my_district;
|
||||
|
||||
|
||||
CREATE_VIEW(fac_v_my_regions, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_regio_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_regio_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_region
|
||||
UNION
|
||||
SELECT alg_regio_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
4
|
||||
FROM alg_v_my_region
|
||||
UNION
|
||||
SELECT alg_regio_key,
|
||||
@@ -692,28 +697,28 @@ UNION
|
||||
FROM alg_v_my_region
|
||||
UNION
|
||||
SELECT alg_regio_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_region
|
||||
UNION
|
||||
SELECT alg_regio_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_v_my_region;
|
||||
|
||||
|
||||
CREATE_VIEW(fac_v_my_districts, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_district_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_district_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_district
|
||||
UNION
|
||||
SELECT alg_district_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
4
|
||||
FROM alg_v_my_district
|
||||
UNION
|
||||
SELECT alg_district_key,
|
||||
@@ -727,29 +732,29 @@ UNION
|
||||
FROM alg_v_my_district
|
||||
UNION
|
||||
SELECT alg_district_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_district d
|
||||
UNION
|
||||
SELECT alg_district_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_district d, alg_v_my_region ro
|
||||
WHERE ro.alg_regio_key = d.alg_regio_key;
|
||||
|
||||
|
||||
CREATE_VIEW(fac_v_my_locations, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_locatie_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_locatie_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_location
|
||||
UNION
|
||||
SELECT alg_locatie_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
4
|
||||
FROM alg_v_my_location
|
||||
UNION
|
||||
SELECT alg_locatie_key,
|
||||
@@ -763,14 +768,14 @@ UNION
|
||||
FROM alg_v_my_location
|
||||
UNION
|
||||
SELECT l.alg_locatie_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_district d, alg_locatie l
|
||||
WHERE l.alg_district_key= d.alg_district_key
|
||||
UNION
|
||||
SELECT l.alg_locatie_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_locatie l, alg_district d, alg_v_my_region ro
|
||||
WHERE l.alg_district_key= d.alg_district_key
|
||||
AND ro.alg_regio_key = d.alg_regio_key;
|
||||
@@ -778,16 +783,16 @@ UNION
|
||||
|
||||
CREATE_VIEW(fac_v_my_buildings, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_gebouw_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_gebouw_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_building
|
||||
UNION
|
||||
SELECT alg_gebouw_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
4
|
||||
FROM alg_v_my_building
|
||||
UNION
|
||||
SELECT alg_gebouw_key,
|
||||
@@ -802,15 +807,15 @@ UNION
|
||||
WHERE g.alg_locatie_key = l.alg_locatie_key
|
||||
UNION
|
||||
SELECT g.alg_gebouw_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_district d, alg_locatie l, alg_gebouw g
|
||||
WHERE d.alg_district_key = l.alg_district_key
|
||||
AND g.alg_locatie_key = l.alg_locatie_key
|
||||
UNION
|
||||
SELECT g.alg_gebouw_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_v_my_region ro, alg_gebouw g, alg_locatie l, alg_district d
|
||||
WHERE ro.alg_regio_key = d.alg_regio_key
|
||||
AND l.alg_district_key= d.alg_district_key
|
||||
@@ -819,16 +824,16 @@ UNION
|
||||
|
||||
CREATE_VIEW(fac_v_my_floors, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_verdieping_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_verdieping_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_floor
|
||||
UNION
|
||||
SELECT alg_verdieping_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
4
|
||||
FROM alg_v_my_floor
|
||||
UNION
|
||||
SELECT v.alg_verdieping_key,
|
||||
@@ -845,16 +850,16 @@ UNION
|
||||
AND g.alg_gebouw_key = v.alg_gebouw_key
|
||||
UNION
|
||||
SELECT v.alg_verdieping_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_district d, alg_locatie l, alg_gebouw g, alg_verdieping v
|
||||
WHERE d.alg_district_key = l.alg_district_key
|
||||
AND l.alg_locatie_key = g.alg_locatie_key
|
||||
AND g.alg_gebouw_key = v.alg_gebouw_key
|
||||
UNION
|
||||
SELECT v.alg_verdieping_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_v_my_region ro, alg_district d, alg_locatie l, alg_gebouw g, alg_verdieping v
|
||||
WHERE ro.alg_regio_key = d.alg_regio_key
|
||||
AND d.alg_district_key= l.alg_district_key
|
||||
@@ -864,37 +869,37 @@ UNION
|
||||
|
||||
CREATE_VIEW(fac_v_my_rooms, ALG_NORMAAL_PRIVILEGE)
|
||||
(alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
prs_perslid_key,
|
||||
niveau) AS
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
5
|
||||
prs_perslid_key,
|
||||
5
|
||||
FROM alg_v_my_room
|
||||
UNION
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
4
|
||||
prs_perslid_key,
|
||||
4
|
||||
FROM alg_v_my_floor f, alg_ruimte r
|
||||
WHERE f.alg_verdieping_key = r.alg_verdieping_key
|
||||
UNION
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
3
|
||||
prs_perslid_key,
|
||||
3
|
||||
FROM alg_v_my_building b, alg_verdieping v, alg_ruimte r
|
||||
WHERE b.alg_gebouw_key = v.alg_gebouw_key
|
||||
AND v.alg_verdieping_key = r.alg_verdieping_key
|
||||
UNION
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
2
|
||||
prs_perslid_key,
|
||||
2
|
||||
FROM alg_v_my_location l, alg_gebouw b, alg_verdieping v, alg_ruimte r
|
||||
WHERE l.alg_locatie_key = b.alg_locatie_key
|
||||
AND b.alg_gebouw_key = v.alg_gebouw_key
|
||||
AND v.alg_verdieping_key = r.alg_verdieping_key
|
||||
UNION
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
1
|
||||
prs_perslid_key,
|
||||
1
|
||||
FROM alg_v_my_district d, alg_locatie l, alg_gebouw b, alg_verdieping v, alg_ruimte r
|
||||
WHERE d.alg_district_key = l.alg_district_key
|
||||
AND l.alg_locatie_key = b.alg_locatie_key
|
||||
@@ -902,8 +907,8 @@ UNION
|
||||
AND v.alg_verdieping_key = r.alg_verdieping_key
|
||||
UNION
|
||||
SELECT alg_ruimte_key,
|
||||
prs_perslid_key,
|
||||
0
|
||||
prs_perslid_key,
|
||||
0
|
||||
FROM alg_v_my_region ro, alg_district d, alg_locatie l, alg_gebouw b, alg_verdieping v, alg_ruimte r
|
||||
WHERE ro.alg_regio_key = d.alg_regio_key
|
||||
AND d.alg_district_key = l.alg_district_key
|
||||
@@ -911,3 +916,6 @@ UNION
|
||||
AND b.alg_gebouw_key = v.alg_gebouw_key
|
||||
AND v.alg_verdieping_key = r.alg_verdieping_key;
|
||||
|
||||
DEFINIEER_VIEW_AANWEZIG(alg_srtterreinsector, alg_srtterreinsector_verwijder,
|
||||
alg_v_aanwezigsrtterreinsector,ALG_BIBLIOTHEEK_PRIVILEGE);
|
||||
|
||||
|
||||
@@ -124,5 +124,12 @@ DEF_FAC_MESSAGE ('cnt_r_cnt_contract_stdmld' ,'De aangegeven dienst bestaat n
|
||||
DEF_FAC_MESSAGE ('cnt_r_cnt_contract_bedrijf' ,'Het aangegeven bedrijf bestaat niet.' ,'That company does not exist.');
|
||||
DEF_FAC_MESSAGE ('cnt_r_cnt_contractint' ,'De aangegeven interne contactpersoon bestaat niet.' ,'That internal contact person does not exist');
|
||||
|
||||
insert into cnt_mutatie_status values(1, 'Open');
|
||||
insert into cnt_mutatie_status values(2, 'Concept');
|
||||
insert into cnt_mutatie_status values(3, 'Ontvangen&Ok');
|
||||
insert into cnt_mutatie_status values(4, 'Ontvangen&NietOk');
|
||||
insert into cnt_mutatie_status values(5, 'Voltooid');
|
||||
|
||||
|
||||
#endif // CNT
|
||||
|
||||
|
||||
@@ -4,6 +4,7 @@
|
||||
**
|
||||
** Revisie:
|
||||
**
|
||||
** 11-10-03 RL - cnt_complete_mutatie add for FSN#516
|
||||
** 04-01-01 EGR Creation.
|
||||
*/
|
||||
|
||||
@@ -25,6 +26,7 @@ CREATE OR REPLACE PACKAGE Cnt AS
|
||||
PROCEDURE cnt_kenmerkcontract_update(p_kenmerkcontract_key IN NUMBER
|
||||
,p_waarde IN VARCHAR2
|
||||
,p_historymode IN VARCHAR2);
|
||||
PROCEDURE cnt_complete_mutatie(p_mutaite_key IN NUMBER);
|
||||
|
||||
PRAGMA RESTRICT_REFERENCES (cnt_contract_items, WNDS, WNPS);
|
||||
PRAGMA RESTRICT_REFERENCES (cnt_contract_status, WNDS, WNPS);
|
||||
@@ -321,6 +323,46 @@ END;
|
||||
END cnt_update_kenmerkcontract;
|
||||
|
||||
|
||||
PROCEDURE cnt_complete_mutatie(p_mutaite_key IN NUMBER) IS
|
||||
|
||||
-- The following actions should be executed when the state becomes 'Voltooid':
|
||||
-- Find the matching records in the CNT_CONTRACT_ONRGOED table where one row without a mutation_key
|
||||
-- filled in matches a row with a mutation_key filled in.
|
||||
-- The match will be successful if both rows have the same ALG_ONRGOED_KEY,
|
||||
-- the same ALG_ONRGOED_NIVEAU and the same CNT_CONTRACT_KEY.
|
||||
-- From these matching records the one without CNT_MUTATION_KEY should be deleted
|
||||
BEGIN
|
||||
DELETE
|
||||
cnt_contract_onrgoed
|
||||
WHERE cnt_contract_onrgoed_key IN (
|
||||
SELECT a.cnt_contract_onrgoed_key
|
||||
FROM cnt_contract_onrgoed b, cnt_contract_onrgoed a
|
||||
WHERE a.cnt_contract_key = b.cnt_contract_key
|
||||
AND a.alg_onrgoed_key = b.alg_onrgoed_key
|
||||
AND a.alg_onrgoed_niveau = b.alg_onrgoed_niveau
|
||||
AND b.cnt_mutatie_key = p_mutaite_key
|
||||
AND a.cnt_mutatie_key IS NULL);
|
||||
|
||||
-- Delete the entries in the CNT_CONTRACT_ONRGOED table with the mutation_key equal
|
||||
-- to the CNT_MUTATION that will be accepted and where the area size (CNT_CONTRACT_ONRGOED_OPP) = 0.
|
||||
|
||||
DELETE
|
||||
cnt_contract_onrgoed
|
||||
WHERE cnt_mutatie_key = p_mutaite_key
|
||||
AND CNT_CONTRACT_ONRGOED_OPP = 0;
|
||||
|
||||
-- Set the Mutation_key to NULL from the rows where the CNT_MUTATION_KEY will be equal to the CNT_MUTATION that was accepted.
|
||||
UPDATE
|
||||
cnt_contract_onrgoed
|
||||
SET cnt_mutatie_key = NULL
|
||||
WHERE cnt_mutatie_key = p_mutaite_key;
|
||||
--The state of the mutation should be set to 'Voltooid'
|
||||
UPDATE cnt_mutatie
|
||||
SET CNT_MUTATIE_DATUM_VOLTOOID = SYSDATE,
|
||||
CNT_MUTATIE_STATUS = 5
|
||||
WHERE cnt_mutatie_key = p_mutaite_key;
|
||||
END cnt_complete_mutatie;
|
||||
|
||||
END Cnt;
|
||||
/
|
||||
|
||||
|
||||
@@ -4,6 +4,7 @@
|
||||
**
|
||||
** Revisie:
|
||||
**
|
||||
** 10-11-03 RL cnt_s_cnt_onrgoed_key, cnt_s_cnt_mutatie_key added for FSN# 516
|
||||
** 04-01-01 EGR Creation.
|
||||
*/
|
||||
|
||||
@@ -18,4 +19,8 @@ CREATE SEQUENCE cnt_s_cnt_srtkenmerk_key MINVALUE 1;
|
||||
CREATE SEQUENCE cnt_s_cnt_kenmerk_key MINVALUE 1;
|
||||
CREATE SEQUENCE cnt_s_cnt_kenmerkcontract_key MINVALUE 1;
|
||||
|
||||
CREATE SEQUENCE cnt_s_cnt_onrgoed_key MINVALUE 1 CACHE 2;
|
||||
CREATE SEQUENCE cnt_s_cnt_mutatie_key MINVALUE 1 CACHE 2;
|
||||
|
||||
|
||||
#endif // CNT
|
||||
|
||||
@@ -86,6 +86,11 @@ CREATE_TABLE(cnt_contract,CNT_NORMAAL_PRIVILEGE)
|
||||
, prs_perslid_key_beh
|
||||
NUMBER(10)
|
||||
CONSTRAINT cnt_r_cnt_perslid_key_beh REFERENCES prs_perslid (prs_perslid_key)
|
||||
, cnt_contract_kostenplaats
|
||||
VARCHAR2(30)
|
||||
, prs_afdeling_key_eig
|
||||
NUMBER(10)
|
||||
CONSTRAINT cnt_r_prs_afdeling_key_eig REFERENCES prs_afdeling(prs_afdeling_key)
|
||||
, cnt_contract_status
|
||||
NUMBER(1)
|
||||
, CONSTRAINT cnt_c_cnt_contract_rappel
|
||||
@@ -325,4 +330,42 @@ CREATE_TABLE(cnt_kenmerkcontract, CNT_NORMAAL_PRIVILEGE)
|
||||
, CONSTRAINT cnt_u_cnt_kenmerkcontract UNIQUE(cnt_kenmerk_key, cnt_contract_key, cnt_kenmerkcontract_verwijder)
|
||||
);
|
||||
|
||||
|
||||
CREATE_TABLE(cnt_mutatie, CNT_BIBLIOTHEEK_PRIVILEGE)
|
||||
( cnt_mutatie_key NUMBER(10)
|
||||
CONSTRAINT cnt_k_cnt_mutatie_key PRIMARY KEY,
|
||||
cnt_mutatie_omschrijving VARCHAR2(50),
|
||||
cnt_mutatie_datum DATE,
|
||||
cnt_mutatie_datum_concept DATE,
|
||||
cnt_mutatie_datum_ontvangen DATE,
|
||||
cnt_mutatie_datum_voltooid DATE,
|
||||
cnt_mutatie_datum_ingang DATE,
|
||||
prs_perslid_key NUMBER(10)
|
||||
CONSTRAINT cnt_r_prs_perslid_key REFERENCES prs_perslid(prs_perslid_key),
|
||||
cnt_mutatie_status NUMBER(1) -- Open = 1 Concept = 2 OntvangenOK = 3 OntvangenNOK = 4 Voltooid = 5
|
||||
);
|
||||
|
||||
CREATE_TABLE(cnt_contract_onrgoed, CNT_BIBLIOTHEEK_PRIVILEGE)
|
||||
( cnt_contract_onrgoed_key NUMBER(10)
|
||||
CONSTRAINT cnt_k_cnt_contract_onrgoed_key PRIMARY KEY,
|
||||
cnt_contract_key NUMBER(10)
|
||||
CONSTRAINT cnt_r_cnt_contract_key REFERENCES cnt_contract(cnt_contract_key),
|
||||
alg_onrgoed_key NUMBER(10),
|
||||
alg_onrgoed_niveau VARCHAR2 1
|
||||
CONSTRAINT cnt_c_cnt_onrgoed_niveau CHECK(alg_onrgoed_niveau IN ('R', 'T')),
|
||||
cnt_mutatie_key NUMBER(10)
|
||||
CONSTRAINT cnt_r_cnt_mutatie_key REFERENCES cnt_mutatie(cnt_mutatie_key) on delete cascade,
|
||||
cnt_contract_onrgoed_opp NUMBER(8,2),
|
||||
alg_srtonrgoed_key NUMBER(10)
|
||||
);
|
||||
|
||||
CREATE_TABLE(cnt_mutatie_status,BES_BIBLIOTHEEK_PRIVILEGE)
|
||||
(
|
||||
cnt_mutatie_status
|
||||
NUMBER(1),
|
||||
cnt_mutatie_status_omschrijv
|
||||
VARCHAR2(30)
|
||||
);
|
||||
|
||||
|
||||
#endif // CNT
|
||||
|
||||
@@ -4,6 +4,7 @@
|
||||
**
|
||||
** Revisie:
|
||||
**
|
||||
** 11-10-03 RL cnt_t_cnt_contract_onrg_B_IU, cnt_t_cnt_mutatie_B_IU created for FSN#516
|
||||
** 07-05-03 RL cnt_t_cnt_contract_B_IU modified for SQL Server
|
||||
** 22-04-03 RL "declare dummy ... if ... select into dummy ..." modified
|
||||
**
|
||||
@@ -107,15 +108,16 @@ BEGIN
|
||||
#endif
|
||||
IF :new.PRS_BEDRIJF_KEY IS NULL THEN
|
||||
#ifndef MS_SQL
|
||||
SELECT cnt_prs_bedrijf_key, cnt_contract_contact_persoon
|
||||
SELECT C.cnt_prs_bedrijf_key, P.prs_perslid_naam_full
|
||||
INTO :new.prs_bedrijf_key, :new.CNT_CONTRACT_DIENST_CONTACTEXT
|
||||
#else
|
||||
update cnt_contract_dienst
|
||||
set prs_bedrijf_key=C.cnt_prs_bedrijf_key,
|
||||
CNT_CONTRACT_DIENST_CONTACTEXT=C.cnt_contract_contact_persoon
|
||||
CNT_CONTRACT_DIENST_CONTACTEXT=P.prs_perslid_naam_full
|
||||
#endif
|
||||
FROM cnt_contract C
|
||||
FROM cnt_contract C, PRS_V_PERSLID_FULLNAMES_ALL P
|
||||
WHERE C.cnt_contract_key=:new.cnt_contract_key
|
||||
AND P.prs_perslid_key = C.prs_contactpersoon_key
|
||||
#ifdef MS_SQL
|
||||
and cnt_contract_dienst_key=:new.cnt_contract_dienst_key
|
||||
#endif
|
||||
@@ -123,10 +125,11 @@ BEGIN
|
||||
--:new.CNT_CONTRACT_DIENST_CONTACTEXT := NULL;
|
||||
END IF;
|
||||
IF :new.CNT_CONTRACT_DIENST_CONTACTINT IS NULL THEN
|
||||
SELECT PRS_PERSLID_KEY_EIG
|
||||
SELECT P.prs_perslid_naam_full
|
||||
INTO :new.CNT_CONTRACT_DIENST_CONTACTINT
|
||||
FROM cnt_contract C
|
||||
WHERE C.cnt_contract_key=:new.cnt_contract_key;
|
||||
FROM cnt_contract C, PRS_V_PERSLID_FULLNAMES_ALL P
|
||||
WHERE C.cnt_contract_key=:new.cnt_contract_key
|
||||
AND P.prs_perslid_key = C.prs_contactpersoon_key;
|
||||
END IF;
|
||||
DECLARE
|
||||
dummy VARCHAR2(1);
|
||||
@@ -471,5 +474,26 @@ lcontinue:
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE_TRIGGER(cnt_t_cnt_contract_onrg_B_IU)
|
||||
BEFORE INSERT OR UPDATE ON cnt_contract_onrgoed
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE_PRIMARY_KEY(cnt_contract_onrgoed_key,cnt_s_cnt_onrgoed_key);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE_TRIGGER(cnt_t_cnt_mutatie_B_IU)
|
||||
BEFORE INSERT OR UPDATE ON cnt_mutatie
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
:new.cnt_mutatie_datum := SYSDATE;
|
||||
UPDATE_PRIMARY_KEY(cnt_mutatie_key,cnt_s_cnt_mutatie_key);
|
||||
IF :new.cnt_mutatie_key IS NOT NULL AND :old.cnt_mutatie_key IS NULL THEN
|
||||
:new.cnt_mutatie_datum_ingang := SYSDATE;
|
||||
END IF;
|
||||
END;
|
||||
/
|
||||
|
||||
|
||||
|
||||
#endif // CNT
|
||||
|
||||
111
CNT/CNT_VIE.SRC
111
CNT/CNT_VIE.SRC
@@ -132,4 +132,115 @@ SELECT MLD_O.*
|
||||
mld_s.mld_statusopdr_upper = 'MLD_AFGEMELD');
|
||||
/
|
||||
|
||||
|
||||
CREATE_VIEW (cnt_v_cnt_mutatie_header, CNT_NORMAAL_PRIVILEGE) AS
|
||||
SELECT m.cnt_mutatie_key cnt_mutatie_key,
|
||||
'<Mutation>'||Chr(10)||Chr(9)||'<MutationNumber>'||to_char(m.cnt_mutatie_key)||
|
||||
'</MutationNumber>'||Chr(10)||Chr(9)||'<MutationDescription>'||m.cnt_mutatie_omschrijving||
|
||||
'</MutationDescription>'||Chr(10)||Chr(9)||'<MutationLastChangeDate>'||DATE_TO_CHAR(m.cnt_mutatie_datum,'DD-MM-YYYY')||
|
||||
'</MutationLastChangeDate>'||Chr(10)||Chr(9)||'<MutationLastChangeBy>'||p.prs_perslid_naam_full||
|
||||
'</MutationLastChangeBy>'||Chr(10)||Chr(9)||'<MutationStartDate>'||DATE_TO_CHAR(m.cnt_mutatie_datum_ingang,'DD-MM-YYYY')||
|
||||
'</MutationStartDate>'||Chr(10)||Chr(9)||'<Contract>'||Chr(10)||Chr(9)||Chr(9)||'<ContractNumber>'||c.cnt_contract_nummer||
|
||||
'</ContractNumber>'||Chr(10)||Chr(9)||Chr(9)||'<ContractId>'||to_char(c.cnt_contract_key)||
|
||||
'</ContractId>'||Chr(10)||Chr(9)||Chr(9)||'<ContractOwner>'||a.prs_afdeling_naam||
|
||||
'</ContractOwner>'||Chr(10)||Chr(9)||Chr(9)||'<ContractingParty>'||
|
||||
decode(c.cnt_prs_afdeling_key, NULL, b.prs_bedrijf_naam, a1.prs_afdeling_naam)||'</ContractingParty>'
|
||||
mutatie
|
||||
FROM cnt_mutatie m, prs_v_perslid_fullnames_all p, cnt_contract c, prs_afdeling a,
|
||||
(SELECT DISTINCT cnt_mutatie_key, cnt_contract_key FROM cnt_contract_onrgoed) o, prs_bedrijf b, prs_afdeling a1
|
||||
WHERE m.prs_perslid_key = p.prs_perslid_key
|
||||
AND m.cnt_mutatie_key = o.cnt_mutatie_key
|
||||
AND o.cnt_contract_key = c.cnt_contract_key
|
||||
AND c.prs_afdeling_key_eig = a.prs_afdeling_key
|
||||
AND c.cnt_prs_afdeling_key = a1.prs_afdeling_key(+)
|
||||
AND c.cnt_prs_bedrijf_key = b.prs_bedrijf_key(+);
|
||||
/
|
||||
|
||||
CREATE_VIEW (cnt_v_cnt_mutatie_cnt_item, CNT_NORMAAL_PRIVILEGE) AS
|
||||
SELECT o.cnt_mutatie_key cnt_mutatie_key,
|
||||
Chr(10)||Chr(9)||Chr(9)||'<ContractItem>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Location>'||l.alg_locatie_code||
|
||||
'</Location>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Building>'||g.alg_gebouw_code||
|
||||
'</Building>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Floor>'||v.alg_verdieping_code||
|
||||
'</Floor>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Room>'||r.alg_ruimte_nr||
|
||||
'</Room>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Terrain></Terrain>'||
|
||||
Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<SizeOld>'||x.cnt_contract_onrgoed_opp||
|
||||
'</SizeOld>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<SizeNew>'||o.cnt_contract_onrgoed_opp||
|
||||
'</SizeNew>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<TypeOld>'||x.alg_srtruimte_code||
|
||||
'</TypeOld>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<TypeNew>'||rs.alg_srtruimte_code||
|
||||
'</TypeNew>'||Chr(10)||Chr(9)||Chr(9)||'</ContractItem>' contract_item
|
||||
FROM cnt_contract_onrgoed o, alg_v_aanwezigruimte r, alg_verdieping v, alg_gebouw g, alg_locatie l,
|
||||
alg_srtruimte rs,
|
||||
(SELECT o1.alg_onrgoed_key alg_onrgoed_key, o1.cnt_contract_key cnt_contract_key,
|
||||
o1.cnt_contract_onrgoed_opp cnt_contract_onrgoed_opp, rs1.alg_srtruimte_code alg_srtruimte_code
|
||||
FROM cnt_contract_onrgoed o1, alg_srtruimte rs1
|
||||
WHERE o1.alg_onrgoed_niveau = 'R'
|
||||
AND o1.alg_srtonrgoed_key = rs1.alg_srtruimte_key(+)
|
||||
AND o1.cnt_mutatie_key IS NULL) x
|
||||
WHERE o.alg_onrgoed_key = r.alg_ruimte_key
|
||||
AND r.alg_verdieping_key = v.alg_verdieping_key
|
||||
AND v.alg_gebouw_key = g.alg_gebouw_key
|
||||
AND g.alg_locatie_key = l.alg_locatie_key
|
||||
AND o.alg_srtonrgoed_key = rs.alg_srtruimte_key(+)
|
||||
AND o.alg_onrgoed_key = x.alg_onrgoed_key(+)
|
||||
AND o.cnt_contract_key = x.cnt_contract_key(+)
|
||||
AND o.alg_onrgoed_niveau = 'R'
|
||||
AND o.cnt_mutatie_key IS NOT NULL
|
||||
UNION
|
||||
SELECT o.cnt_mutatie_key cnt_mutatie_key,
|
||||
Chr(10)||Chr(9)||Chr(9)||'<ContractItem>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Location>'||l.alg_locatie_code||
|
||||
'</Location>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Building>'||
|
||||
'</Building>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Floor>'||
|
||||
'</Floor>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Room>'||
|
||||
'</Room>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<Terrain>'||t.alg_terreinsector_code||'</Terrain>'||
|
||||
Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<SizeOld>'||x.cnt_contract_onrgoed_opp||
|
||||
'</SizeOld>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<SizeNew>'||o.cnt_contract_onrgoed_opp||
|
||||
'</SizeNew>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<TypeOld>'||x.alg_srtterreinsector_code ||
|
||||
'</TypeOld>'||Chr(10)||Chr(9)||Chr(9)||Chr(9)||'<TypeNew>'||ts.alg_srtterreinsector_code ||
|
||||
'</TypeNew>'||Chr(10)||Chr(9)||Chr(9)||'</ContractItem>' contract_item
|
||||
FROM cnt_contract_onrgoed o, alg_v_aanwezigterreinsector t, alg_locatie l,
|
||||
alg_srtterreinsector ts,
|
||||
(SELECT o1.alg_onrgoed_key alg_onrgoed_key, o1.cnt_contract_key cnt_contract_key,
|
||||
o1.cnt_contract_onrgoed_opp cnt_contract_onrgoed_opp, ts1.alg_srtterreinsector_code alg_srtterreinsector_code
|
||||
FROM cnt_contract_onrgoed o1, alg_srtterreinsector ts1
|
||||
WHERE o1.alg_onrgoed_niveau = 'T'
|
||||
AND o1.alg_srtonrgoed_key = ts1.alg_srtterreinsector_key (+)
|
||||
AND o1.cnt_mutatie_key IS NULL ) x
|
||||
WHERE o.alg_onrgoed_key = t.alg_terreinsector_key
|
||||
AND t.alg_locatie_key = l.alg_locatie_key
|
||||
AND o.alg_srtonrgoed_key = ts.alg_srtterreinsector_key(+)
|
||||
AND o.alg_onrgoed_key = x.alg_onrgoed_key(+)
|
||||
AND o.cnt_contract_key = x.cnt_contract_key(+)
|
||||
AND o.alg_onrgoed_niveau = 'T'
|
||||
AND o.cnt_mutatie_key IS NOT NULL
|
||||
/
|
||||
|
||||
|
||||
CREATE_VIEW (cnt_v_cnt_contract_item, CNT_NORMAAL_PRIVILEGE) AS
|
||||
SELECT o.cnt_contract_key cnt_contract_key, o.cnt_mutatie_key cnt_mutatie_key,
|
||||
l.alg_locatie_code || ' - ' || g.alg_gebouw_code || ' - ' || v.alg_verdieping_code || ' - ' || r.alg_ruimte_nr onrgoed,
|
||||
r.alg_ruimte_bruto_vloeropp total_opp, o.cnt_contract_onrgoed_opp contr_opp,
|
||||
r.alg_ruimte_bruto_vloeropp - o.cnt_contract_onrgoed_opp diff,
|
||||
rs.alg_srtruimte_code code, r.alg_ruimte_key onrgoed_key, o.alg_onrgoed_niveau
|
||||
FROM cnt_contract_onrgoed o, alg_v_aanwezigruimte r, alg_verdieping v, alg_gebouw g, alg_locatie l,
|
||||
alg_srtruimte rs
|
||||
WHERE o.alg_onrgoed_key = r.alg_ruimte_key
|
||||
AND r.alg_verdieping_key = v.alg_verdieping_key
|
||||
AND v.alg_gebouw_key = g.alg_gebouw_key
|
||||
AND g.alg_locatie_key = l.alg_locatie_key
|
||||
AND o.alg_srtonrgoed_key = rs.alg_srtruimte_key(+)
|
||||
AND o.alg_onrgoed_niveau = 'R'
|
||||
UNION
|
||||
SELECT o.cnt_contract_key cnt_contract_key, o.cnt_mutatie_key cnt_mutatie_key,
|
||||
l.alg_locatie_code || ' - ' || t.alg_terreinsector_code onrgoed,
|
||||
t.alg_terreinsector_oppervlak total_opp, o.cnt_contract_onrgoed_opp contr_opp,
|
||||
t.alg_terreinsector_oppervlak - o.cnt_contract_onrgoed_opp diff,
|
||||
ts.alg_srtterreinsector_code code, alg_terreinsector_key onrgoed_key, o.alg_onrgoed_niveau
|
||||
FROM cnt_contract_onrgoed o, alg_v_aanwezigterreinsector t, alg_locatie l,
|
||||
alg_srtterreinsector ts
|
||||
WHERE o.alg_onrgoed_key = t.alg_terreinsector_key
|
||||
AND t.alg_locatie_key = l.alg_locatie_key
|
||||
AND o.alg_srtonrgoed_key = ts.alg_srtterreinsector_key(+)
|
||||
AND o.alg_onrgoed_niveau = 'T'
|
||||
/
|
||||
|
||||
#endif // CNT
|
||||
|
||||
Reference in New Issue
Block a user