668 lines
23 KiB
SQL
668 lines
23 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the Vesteda database
|
|
|
|
DEFINE thisfile = 'VEST.SQL'
|
|
DEFINE dbuser = '^VEST'
|
|
DEFINE custid = 'VEST'
|
|
|
|
SET ECHO ON
|
|
SET DEFINE ON
|
|
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
|
WHENEVER SQLERROR EXIT;
|
|
SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
SPOOL &fcltlogfile
|
|
SET DEFINE OFF
|
|
|
|
------ payload begin ------
|
|
|
|
--
|
|
-- Personen import
|
|
--
|
|
|
|
CREATE OR REPLACE PROCEDURE vest_import_perslid (p_import_key IN NUMBER)
|
|
AS
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_errormsg VARCHAR2 (400);
|
|
v_errorhint VARCHAR2 (400);
|
|
v_newline FAC_IMP_FILE.FAC_IMP_FILE_LINE%TYPE;
|
|
BEGIN
|
|
|
|
BEGIN
|
|
SELECT fac_imp_file_line
|
|
INTO v_newline
|
|
FROM fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
AND fac_imp_file_index = 1;
|
|
|
|
IF v_newline LIKE
|
|
CHR (TO_NUMBER ('EF', 'xx'))
|
|
|| CHR (TO_NUMBER ('BB', 'xx'))
|
|
|| CHR (TO_NUMBER ('BF', 'xx'))
|
|
|| '%'
|
|
THEN
|
|
-- EF BB BF aangetroffen
|
|
fac.imp_writelog (p_import_key,
|
|
'W',
|
|
'Byte Order Mark aangetroffen',
|
|
'Bestand heeft onbehandeld UTF-8 formaat.'
|
|
);
|
|
v_newline := SUBSTR (v_newline, 4);
|
|
END IF;
|
|
|
|
-- Verwijder de dubbele quotes
|
|
v_newline := REPLACE (v_newline, '"');
|
|
|
|
UPDATE fac_imp_file
|
|
SET fac_imp_file_line = v_newline
|
|
WHERE fac_import_key = p_import_key
|
|
AND fac_imp_file_index = 1;
|
|
|
|
|
|
EXCEPTION WHEN OTHERS
|
|
THEN
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
'Fout bij controle op Byte Order Mark',
|
|
''
|
|
);
|
|
END;
|
|
|
|
|
|
v_errorhint := 'Generieke update';
|
|
-- de sequence array staat beschreven in PRS_PAC.SRC bij de prs.import_perslid proc
|
|
prs.import_perslid (p_import_key,
|
|
'13;14;15;16;0;0;6;1;3;2;' ||
|
|
'0;0;0;0;9;10;11;5;0;12;' ||
|
|
'7;4;0;8;0;0;0;0;0;0;'||
|
|
'0;0;0;0;0;0;0;0;0;0;'||
|
|
'0;0;0;0;0;0',
|
|
'Achternaam;Voornaam;Tussenvoegsel;SamAccountName;Email;Afdeling;Functie;Titel/Aanhef;Geslacht;Telefoonnummer;Mobiel nummer;Personeelsnummer;Locatie;Gebouw;Verdieping;Ruimte%'
|
|
);
|
|
|
|
UPDATE fac_imp_perslid
|
|
SET alg_locatie_code = (
|
|
SELECT a.alg_locatie_code
|
|
FROM alg_locatie a
|
|
WHERE fac_imp_perslid.alg_locatie_code = a.alg_locatie_omschrijving);
|
|
|
|
UPDATE fac_imp_perslid
|
|
SET alg_gebouw_code = '001'
|
|
WHERE fac_imp_perslid.alg_locatie_code LIKE '%AMS%';
|
|
|
|
UPDATE fac_imp_perslid
|
|
SET alg_verdieping_volgnr = '0'
|
|
WHERE fac_imp_perslid.alg_locatie_code LIKE '%AMS%';
|
|
|
|
UPDATE fac_imp_perslid
|
|
SET alg_ruimte_nr = '001'
|
|
WHERE fac_imp_perslid.alg_locatie_code LIKE '%AMS%';
|
|
|
|
|
|
UPDATE fac_imp_perslid
|
|
SET prs_afdeling_naam =
|
|
(
|
|
SELECT DISTINCT p.prs_afdeling_naam
|
|
FROM prs_afdeling p
|
|
WHERE fac_imp_perslid.prs_afdeling_naam = substr (p.prs_afdeling_omschrijving, 1, 15)
|
|
AND p.prs_afdeling_verwijder IS NULL
|
|
)
|
|
WHERE fac_imp_perslid.prs_afdeling_naam NOT IN (SELECT p.prs_afdeling_naam FROM prs_afdeling p);
|
|
|
|
DELETE FROM fac_imp_perslid
|
|
WHERE alg_locatie_code NOT IN (SELECT alg_locatie_code FROM alg_locatie);
|
|
|
|
COMMIT;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg := 'Error ' || oracle_err_num || '/' || oracle_err_mes;
|
|
fac.imp_writelog (p_import_key, 'E', v_errormsg, v_errorhint);
|
|
END vest_import_perslid;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE vest_update_perslid (
|
|
p_import_key IN NUMBER
|
|
) IS
|
|
-- Alle personen verwijderen die niet meer in import bestand voorkomen.
|
|
CURSOR c_del
|
|
IS
|
|
SELECT p.prs_perslid_key, p.prs_perslid_oslogin, pf.prs_perslid_naam_full
|
|
FROM fac_imp_perslid i, prs_perslid p, prs_v_perslid_fullnames_all pf
|
|
WHERE UPPER (p.prs_perslid_oslogin) = UPPER (i.prs_perslid_oslogin(+))
|
|
AND pf.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_perslid_oslogin IS NOT NULL
|
|
AND i.prs_perslid_oslogin IS NULL
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND substr(p.prs_perslid_oslogin, 1, 1) != '_'
|
|
ORDER BY 2;
|
|
|
|
v_count NUMBER;
|
|
|
|
BEGIN
|
|
-- generic update
|
|
|
|
SELECT count(*)
|
|
INTO v_count
|
|
FROM fac_imp_perslid;
|
|
|
|
IF v_count < 150
|
|
THEN
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
'Het aantal te importeren personen is te klein ('
|
|
|| TO_CHAR (v_count) || ')',
|
|
'Zie Specificatie'
|
|
);
|
|
RETURN;
|
|
END IF;
|
|
|
|
-- 'LOGIN' betekent dat op basis van oslogin wordt gematched.
|
|
-- 'A' betekent altijd alle (andere/overige) werkplekken verwijderen
|
|
prs.update_perslid (p_import_key, 'LOGIN', NULL);
|
|
|
|
-- Verwijder personen die niet meer in de import voorkomen.
|
|
FOR rec IN c_del
|
|
LOOP
|
|
BEGIN
|
|
prs.delete_perslid (p_import_key, rec.prs_perslid_key);
|
|
END;
|
|
END LOOP;
|
|
|
|
END vest_update_perslid;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_RAP_CATERINGDAGLIJST
|
|
(
|
|
RESKEY,
|
|
FCLT_F_DATUM,
|
|
RESNR,
|
|
VAN,
|
|
TOT,
|
|
FCLT_F_RUIMTE,
|
|
FCLT_F_CATALOGUS,
|
|
LEVERING,
|
|
VOORZIENING,
|
|
AANTAL,
|
|
OPMERKING,
|
|
AANTAL_PERS,
|
|
FCLT_F_GASTHEER_VROUW
|
|
)
|
|
AS
|
|
SELECT rr.res_rsv_ruimte_key,
|
|
rr.res_rsv_ruimte_van,
|
|
rr.res_reservering_key || '/' || rr.res_rsv_ruimte_volgnr,
|
|
TO_CHAR (rr.res_rsv_ruimte_van, 'hh24:mi'),
|
|
TO_CHAR (rr.res_rsv_ruimte_tot, 'hh24:mi'),
|
|
r.alg_ruimte_nr || ' ' || r.alg_ruimte_omschrijving,
|
|
rd.ins_discipline_omschrijving,
|
|
TO_CHAR (rra.res_rsv_artikel_levering, 'hh24:mi'),
|
|
TRIM (ra.res_artikel_omschrijving),
|
|
rra.res_rsv_artikel_aantal,
|
|
rr.res_rsv_ruimte_opmerking,
|
|
rr.res_rsv_ruimte_bezoekers,
|
|
prs_perslid_naam_full
|
|
FROM res_rsv_ruimte rr,
|
|
alg_ruimte r,
|
|
res_artikel ra,
|
|
res_rsv_artikel rra,
|
|
prs_v_perslid_fullnames ppf,
|
|
res_reservering re,
|
|
res_discipline rd
|
|
WHERE rr.alg_ruimte_key = r.alg_ruimte_key
|
|
AND rra.res_rsv_ruimte_key = rr.res_rsv_ruimte_key
|
|
AND rra.res_artikel_key = ra.res_artikel_key
|
|
AND rr.res_rsv_ruimte_contact_key = ppf.prs_perslid_key
|
|
AND rr.res_rsv_ruimte_host_key = ppf.prs_perslid_key
|
|
AND ra.res_discipline_key = rd.ins_discipline_key
|
|
AND re.res_reservering_key = rr.res_reservering_key
|
|
AND re.res_reservering_verwijder IS NULL;
|
|
|
|
CREATE OR REPLACE VIEW vest_v_rap_mahler
|
|
(
|
|
mld_key,
|
|
maand,
|
|
datum,
|
|
stempelnummer,
|
|
uitgegeven_aan, -- Afhankelijk van wel/niet extern, anders prs_perslid
|
|
bezoeker_van,
|
|
inrijdtijd,
|
|
uitrijdtijd,
|
|
toelichting
|
|
)
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
TO_CHAR (m.mld_melding_datum, 'MM-YYYY') maand,
|
|
TRUNC (m.mld_melding_datum),
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 1)
|
|
stempelnummer,
|
|
COALESCE (
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 22),
|
|
(SELECT p.prs_perslid_naam_friendly
|
|
FROM PRS_V_PERSLID_FULLNAMES_ALL p
|
|
WHERE p.prs_perslid_key =
|
|
(SELECT fac.safe_to_number (
|
|
mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 204)))
|
|
uitgegeven_aan,
|
|
COALESCE (
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 23),
|
|
'Vesteda')
|
|
bezoeker_van,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 24)
|
|
inrijdtijd,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 25)
|
|
uitrijdtijd,
|
|
m.mld_melding_omschrijving toelichting
|
|
FROM mld_melding m
|
|
WHERE m.mld_stdmelding_key = 281;
|
|
|
|
CREATE OR REPLACE VIEW vest_v_rap_kluistoegang
|
|
(
|
|
datum,
|
|
bevoegd_persoon_1,
|
|
bevoegd_persoon_2,
|
|
datum_toegang,
|
|
reden_toegang,
|
|
maand
|
|
)
|
|
AS
|
|
SELECT m.mld_melding_datum,
|
|
(SELECT pf.prs_perslid_naam_friendly
|
|
FROM prs_v_perslid_fullnames pf
|
|
WHERE pf.prs_perslid_key =
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 41))
|
|
bp1,
|
|
(SELECT pf.prs_perslid_naam_friendly
|
|
FROM prs_v_perslid_fullnames pf
|
|
WHERE pf.prs_perslid_key =
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 42))
|
|
bp2,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 44)
|
|
datum_toegang,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND k.mld_srtkenmerk_key = 43)
|
|
reden_toegang,
|
|
TO_CHAR (m.mld_melding_datum, 'MM-YYYY') maand
|
|
FROM mld_melding m
|
|
WHERE m.mld_stdmelding_key = 101;
|
|
|
|
CREATE OR REPLACE VIEW vest_v_rap_wf_progress
|
|
(
|
|
wf,
|
|
melding_key,
|
|
melding_datum,
|
|
melding_onderwerp,
|
|
melding_status,
|
|
melding_behandelaar,
|
|
max_stap_melding_key,
|
|
max_stap_melding_datum,
|
|
max_stap_melding_onderwerp,
|
|
max_stap_melding_status,
|
|
max_stap_melding_behandelaar,
|
|
max_stap_stdmelding_key,
|
|
max_stap_stdmelding_oms,
|
|
melder,
|
|
melder_afdeling_code,
|
|
melder_afdeling_oms
|
|
)
|
|
AS
|
|
SELECT (SELECT mld_workflowstep_omschrijving FROM mld_workflowstep WHERE mld_workflowstep_key = x.mld_workflowstep_key)
|
|
wf,
|
|
x.mld_melding_key,
|
|
x.mld_melding_datum,
|
|
x.mld_melding_onderwerp,
|
|
x.mld_statuses_omschrijving melding_status,
|
|
(SELECT prs_perslid_naam_full FROM prs_v_perslid_fullnames_all WHERE prs_perslid_key = x.mld_melding_behandelaar_key)
|
|
melding_behandelaar,
|
|
stap.mld_melding_key max_stap_melding_key,
|
|
stap.mld_melding_datum max_stap_melding_datum,
|
|
stap.mld_melding_onderwerp max_stap_melding_onderwerp,
|
|
stap.mld_statuses_omschrijving max_stap_melding_status,
|
|
(SELECT prs_perslid_naam_full FROM prs_v_perslid_fullnames_all WHERE prs_perslid_key = stap.mld_melding_behandelaar_key)
|
|
max_stap_melding_behandelaar,
|
|
stap.mld_stdmelding_key max_stap_stdmelding_key,
|
|
stap.mld_stdmelding_omschrijving max_stap_stdmelding_oms,
|
|
(SELECT prs_perslid_naam_full FROM prs_v_perslid_fullnames_all WHERE prs_perslid_key = x.prs_perslid_key)
|
|
melder,
|
|
x.prs_afdeling_naam,
|
|
x.prs_afdeling_omschrijving
|
|
FROM (SELECT m.mld_melding_key,
|
|
m.mld_melding_datum,
|
|
m.mld_melding_onderwerp,
|
|
ms.mld_statuses_omschrijving,
|
|
m.mld_melding_behandelaar_key,
|
|
m.mld_workflowstep_key,
|
|
p.prs_perslid_key,
|
|
a.prs_afdeling_naam,
|
|
a.prs_afdeling_omschrijving
|
|
FROM mld_melding m, mld_statuses ms, prs_perslid p, prs_afdeling a
|
|
WHERE m.mld_melding_status = ms.mld_statuses_key
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key) x
|
|
LEFT JOIN
|
|
(SELECT m.mld_melding_start_key,
|
|
m.mld_melding_key,
|
|
m.mld_melding_datum,
|
|
m.mld_melding_onderwerp,
|
|
ms.mld_statuses_omschrijving,
|
|
m.mld_melding_behandelaar_key,
|
|
sm.mld_stdmelding_key,
|
|
sm.mld_stdmelding_omschrijving
|
|
FROM mld_melding m, mld_statuses ms, mld_stdmelding sm
|
|
WHERE m.mld_workflowstep_key IS NOT NULL -- Beschouw alleen WF-stappen
|
|
AND m.mld_melding_status = ms.mld_statuses_key
|
|
AND m.mld_stdmelding_key = sm.mld_stdmelding_key) stap
|
|
ON x.mld_melding_key = stap.mld_melding_start_key;
|
|
|
|
CREATE OR REPLACE VIEW vest_v_ins_qrc_mld
|
|
AS
|
|
SELECT i.ins_deel_omschrijving hide_f_sort,
|
|
l.alg_locatie_code||' '||l.alg_locatie_omschrijving fclt_f_locatie,
|
|
o.alg_gebouw_omschrijving fclt_f_gebouw,
|
|
o.alg_plaatsaanduiding fclt_f_plaats,
|
|
d.ins_discipline_omschrijving fclt_f_discipline,
|
|
g.ins_srtgroep_omschrijving fclt_f_objectgroep,
|
|
s.ins_srtdeel_omschrijving fclt_f_objectsoort,
|
|
i.ins_deel_omschrijving fclt_f_identificatie,
|
|
d.ins_discipline_omschrijving||' / '||sm.mld_stdmelding_omschrijving fclt_f_melding,
|
|
i.ins_deel_key,
|
|
s.ins_srtdeel_key,
|
|
o.alg_gebouw_code,
|
|
o.alg_verdieping_code,
|
|
i.ins_discipline_key fclt_3d_discipline_key,
|
|
l.alg_locatie_key fclt_3d_locatie_key,
|
|
i.ins_alg_ruimte_type,
|
|
i.ins_alg_ruimte_key,
|
|
b.fac_bookmark_id hide_f_bookmark_id
|
|
FROM ins_deel i,
|
|
ins_v_alg_overzicht o,
|
|
ins_srtdeel s,
|
|
ins_srtgroep g,
|
|
ins_discipline d,
|
|
alg_locatie l,
|
|
fac_bookmark b,
|
|
mld_stdmelding sm,
|
|
mld_stdmelding_srtinst si
|
|
WHERE b.fac_bookmark_naam = 'QRC_MELDING'
|
|
AND (b.fac_bookmark_expire IS NULL OR b.fac_bookmark_expire > SYSDATE)
|
|
AND ins_deel_verwijder IS NULL
|
|
AND i.ins_deel_module = 'INS'
|
|
AND i.ins_deel_parent_key IS NULL
|
|
AND s.ins_srtdeel_key = i.ins_srtdeel_key
|
|
AND g.ins_srtgroep_key = s.ins_srtgroep_key
|
|
AND d.ins_discipline_key = g.ins_discipline_key
|
|
AND o.alg_onroerendgoed_keys = i.ins_alg_ruimte_key
|
|
AND o.alg_onroerendgoed_type = i.ins_alg_ruimte_type
|
|
AND i.ins_alg_ruimte_type IN ('T', 'R', 'W')
|
|
AND o.alg_locatie_key = i.ins_alg_locatie_key
|
|
AND i.ins_alg_locatie_key = l.alg_locatie_key
|
|
AND sm.mld_stdmelding_key = si.mld_stdmelding_key
|
|
AND si.ins_srtinstallatie_key = DECODE(si.ins_srtinstallatie_niveau,
|
|
'S', i.ins_srtdeel_key,
|
|
'G', s.ins_srtgroep_key,
|
|
'D', g.ins_discipline_key);
|
|
|
|
CREATE OR REPLACE VIEW vest_v_rap_uitleen
|
|
(
|
|
HIDE_F_REFKEY,
|
|
HIDE_F_FAC_TRACKING_DATUM,
|
|
INS_DEEL_KEY,
|
|
OBJECTSOORT,
|
|
OBJECT,
|
|
UITGELEEND_AAN,
|
|
IN_UIT,
|
|
TRACKING_DATUM
|
|
)
|
|
AS
|
|
SELECT t.fac_tracking_refkey sort_refkey,
|
|
t.fac_tracking_datum sort_datum,
|
|
d.ins_deel_key,
|
|
i.ins_srtdeel_omschrijving,
|
|
d.ins_deel_omschrijving,
|
|
DECODE (
|
|
t.fac_srtnotificatie_key,
|
|
108,
|
|
SUBSTR (REPLACE (fac_tracking_oms, CHR (10), ''),
|
|
( (INSTR (fac_tracking_oms, 'is uitgegeven aan')) + 18)),
|
|
NULL)
|
|
uitgeleend_aan,
|
|
DECODE (fac_srtnotificatie_key,
|
|
108, 'Uitgifte datum: ',
|
|
'Inname datum: ')
|
|
In_uit,
|
|
fac_tracking_datum
|
|
FROM fac_tracking t, ins_deel d, ins_srtdeel i
|
|
WHERE fac_srtnotificatie_key IN (108, 110)
|
|
AND t.fac_tracking_refkey = d.ins_deel_key
|
|
AND d.ins_srtdeel_key = i.ins_srtdeel_key;
|
|
|
|
CREATE OR REPLACE VIEW vest_v_rap_parkeer
|
|
(
|
|
ins_deel_key,
|
|
locatie,
|
|
identificatie,
|
|
eigenaar,
|
|
kenteken,
|
|
van,
|
|
tot,
|
|
bedrag,
|
|
factuurdatum
|
|
)
|
|
AS
|
|
SELECT i.ins_deel_key,
|
|
al.alg_locatie_omschrijving,
|
|
i.ins_deel_omschrijving,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 42)
|
|
eigenaar,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 44)
|
|
kenteken,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 46)
|
|
van,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 45)
|
|
tot,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 41)
|
|
bedrag,
|
|
(SELECT d.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel d, ins_kenmerk k
|
|
WHERE i.ins_deel_key = d.ins_deel_key
|
|
AND k.ins_kenmerk_key = d.ins_kenmerk_key
|
|
AND k.ins_srtkenmerk_key = 43)
|
|
factuurdatum
|
|
FROM ins_deel i,
|
|
alg_ruimte ar,
|
|
alg_verdieping av,
|
|
alg_gebouw ag,
|
|
alg_locatie al
|
|
WHERE i.ins_srtdeel_key = 41
|
|
AND i.ins_deel_verwijder IS NULL
|
|
AND i.ins_alg_ruimte_key = ar.alg_ruimte_key
|
|
AND i.ins_alg_ruimte_type = 'R'
|
|
AND ar.alg_verdieping_key = av.alg_verdieping_key
|
|
AND av.alg_gebouw_key = ag.alg_gebouw_key
|
|
AND ag.alg_locatie_key = al.alg_locatie_key;
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_THEMA_VENDING
|
|
(
|
|
INS_DEEL_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT ins_deel_key,
|
|
ins_alg_ruimte_key,
|
|
DECODE (
|
|
(SELECT COUNT ( * )
|
|
FROM mld_melding m, mld_melding_object mo
|
|
WHERE m.mld_melding_key = mo.mld_melding_key
|
|
AND mo.ins_deel_key = d.ins_deel_key
|
|
AND mld_melding_status IN (0, 2, 3, 4, 7, 99)),
|
|
0,
|
|
'Normaal',
|
|
'Defect')
|
|
ins_status
|
|
FROM ins_deel d
|
|
WHERE ins_discipline_key = 183;
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_THEMA_GEBOUW
|
|
(
|
|
INS_DEEL_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT ins_deel_key,
|
|
ins_alg_ruimte_key,
|
|
DECODE (
|
|
(SELECT COUNT ( * )
|
|
FROM mld_melding m, mld_melding_object mo
|
|
WHERE m.mld_melding_key = mo.mld_melding_key
|
|
AND mo.ins_deel_key = d.ins_deel_key
|
|
AND mld_melding_status IN (0, 2, 3, 4, 7, 99)),
|
|
0,
|
|
'Normaal',
|
|
'Defect')
|
|
ins_status
|
|
FROM ins_deel d
|
|
WHERE ins_discipline_key = 184;
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_THEMA_ICT
|
|
(
|
|
INS_DEEL_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT ins_deel_key,
|
|
ins_alg_ruimte_key,
|
|
DECODE (
|
|
(SELECT COUNT ( * )
|
|
FROM mld_melding m, mld_melding_object mo
|
|
WHERE m.mld_melding_key = mo.mld_melding_key
|
|
AND mo.ins_deel_key = d.ins_deel_key
|
|
AND mld_melding_status IN (0, 2, 3, 4, 7, 99)),
|
|
0,
|
|
'Normaal',
|
|
'Defect')
|
|
ins_status
|
|
FROM ins_deel d
|
|
WHERE ins_discipline_key = 186;
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_THEMA_INVENTARIS
|
|
(
|
|
INS_DEEL_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT ins_deel_key,
|
|
ins_alg_ruimte_key,
|
|
DECODE (
|
|
(SELECT COUNT ( * )
|
|
FROM mld_melding m, mld_melding_object mo
|
|
WHERE m.mld_melding_key = mo.mld_melding_key
|
|
AND mo.ins_deel_key = d.ins_deel_key
|
|
AND mld_melding_status IN (0, 2, 3, 4, 7, 99)),
|
|
0,
|
|
'Normaal',
|
|
'Defect')
|
|
ins_status
|
|
FROM ins_deel d
|
|
WHERE ins_discipline_key = 182;
|
|
|
|
CREATE OR REPLACE VIEW VEST_V_THEMA_VEILIGHEID
|
|
(
|
|
INS_DEEL_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
WAARDE
|
|
)
|
|
AS
|
|
SELECT ins_deel_key,
|
|
ins_alg_ruimte_key,
|
|
DECODE (
|
|
(SELECT COUNT ( * )
|
|
FROM mld_melding m, mld_melding_object mo
|
|
WHERE m.mld_melding_key = mo.mld_melding_key
|
|
AND mo.ins_deel_key = d.ins_deel_key
|
|
AND mld_melding_status IN (0, 2, 3, 4, 7, 99)),
|
|
0,
|
|
'Normaal',
|
|
'Defect')
|
|
ins_status
|
|
FROM ins_deel d
|
|
WHERE ins_discipline_key = 181;
|
|
|
|
------ payload end ------
|
|
|
|
SET DEFINE OFF
|
|
BEGIN adm.systrackscriptId ('$Id$', 0); END;
|
|
/
|
|
|
|
COMMIT;
|
|
SET ECHO OFF
|
|
SPOOL OFF
|
|
SET DEFINE ON
|
|
PROMPT Logfile of this upgrade is: &fcltlogfile |