1889 lines
73 KiB
SQL
1889 lines
73 KiB
SQL
-- Script containing customer specific configuration sql statements for CSUN: CSU National Accounts
|
|
-- (c) 2011 SG|facilitor
|
|
-- $Revision$
|
|
-- $Id$
|
|
--
|
|
-- Support: +31 53 4800710
|
|
SPOOL xCSUN.LST
|
|
SET ECHO ON
|
|
--------------
|
|
CREATE OR REPLACE PROCEDURE csun_imp_writelog (
|
|
p_import_key IN NUMBER,
|
|
p_severity IN VARCHAR2,
|
|
p_errormsg IN VARCHAR2,
|
|
p_errorhint IN VARCHAR2)
|
|
AS
|
|
PRAGMA AUTONOMOUS_TRANSACTION;
|
|
BEGIN
|
|
fac.imp_writelog (p_import_key,
|
|
p_severity,
|
|
p_errormsg,
|
|
p_errorhint);
|
|
COMMIT;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE CSUN_RAP
|
|
AS
|
|
-- PACKAGES voor de CSUN specifieke rapportages
|
|
TYPE t_cursor IS REF CURSOR;
|
|
|
|
PROCEDURE district_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2,
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor);
|
|
PROCEDURE regio_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2,
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor);
|
|
PROCEDURE client_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2,
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor);
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PACKAGE BODY CSUN_RAP
|
|
AS
|
|
--
|
|
--Rapportages
|
|
--
|
|
PROCEDURE district_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2, -- Let wel: formaat '13-05-2005'
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor)
|
|
AS
|
|
v_datum_van DATE;
|
|
v_datum_tot DATE;
|
|
v_alg_level_read NUMBER;
|
|
BEGIN
|
|
v_datum_van := fac.safe_to_date (p_datum_van, 'dd-mm-yyyy');
|
|
v_datum_tot := fac.safe_to_date (p_datum_tot, 'dd-mm-yyyy')+1;
|
|
|
|
OPEN p_cursor FOR
|
|
SELECT district,
|
|
COUNT (mld_key) aantal_meldingen,
|
|
SUM (acceptoptijd) acceptoptijd,
|
|
SUM (uitvoeringoptijd) uitvoeringoptijd
|
|
FROM (
|
|
SELECT DISTINCT
|
|
m.mld_melding_key mld_key,
|
|
di.alg_district_upper district,
|
|
l.alg_locatie_code locatie,
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
fac.gettrackingdate ('MLDNEW', m.mld_melding_key),
|
|
std.mld_stdmelding_urgentie,
|
|
'UREN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDACP', m.mld_melding_key), SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
acceptoptijd,
|
|
CASE
|
|
WHEN fac.gettrackingdate ('MLDREJ', m.mld_melding_key) IS NULL
|
|
THEN
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
m.mld_melding_datum,
|
|
m.mld_melding_uitvoertijd,
|
|
'DAGEN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDAFM', m.mld_melding_key), SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
ELSE 1
|
|
END
|
|
uitvoeringoptijd
|
|
FROM mld_melding m,
|
|
mld_discipline md,
|
|
alg_locatie l,
|
|
alg_district di,
|
|
prs_perslid p,
|
|
mld_stdmelding std
|
|
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
|
AND l.alg_district_key = di.alg_district_key
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
AND md.ins_discipline_key = std.mld_ins_discipline_key
|
|
AND std.mld_stdmelding_key = m.mld_stdmelding_key
|
|
AND m.mld_melding_datum BETWEEN v_datum_van AND v_datum_tot
|
|
)
|
|
GROUP BY district;
|
|
END;
|
|
|
|
PROCEDURE regio_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2, -- Let wel: formaat '13-05-2005'
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor)
|
|
AS
|
|
v_datum_van DATE;
|
|
v_datum_tot DATE;
|
|
v_alg_level_read NUMBER;
|
|
BEGIN
|
|
v_datum_van := fac.safe_to_date (p_datum_van, 'dd-mm-yyyy');
|
|
v_datum_tot := fac.safe_to_date (p_datum_tot, 'dd-mm-yyyy')+1;
|
|
|
|
OPEN p_cursor FOR
|
|
SELECT regio,
|
|
COUNT (mld_key) aantal_meldingen,
|
|
SUM (acceptoptijd) acceptoptijd,
|
|
SUM (uitvoeringoptijd) uitvoeringoptijd
|
|
FROM (
|
|
SELECT DISTINCT
|
|
m.mld_melding_key mld_key,
|
|
di.alg_district_upper district,
|
|
l.alg_locatie_code locatie,
|
|
r.alg_regio_omschrijving regio,
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
fac.gettrackingdate ('MLDNEW', m.mld_melding_key),
|
|
std.mld_stdmelding_urgentie,
|
|
'UREN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDACP', m.mld_melding_key), SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
acceptoptijd,
|
|
CASE
|
|
WHEN fac.gettrackingdate ('MLDREJ', m.mld_melding_key) IS NULL
|
|
THEN
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
m.mld_melding_datum,
|
|
m.mld_melding_uitvoertijd,
|
|
'DAGEN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDAFM', m.mld_melding_key), SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
ELSE 1
|
|
END
|
|
uitvoeringoptijd
|
|
FROM mld_melding m,
|
|
mld_discipline md,
|
|
alg_regio r,
|
|
alg_locatie l,
|
|
alg_district di,
|
|
prs_perslid p,
|
|
mld_stdmelding std
|
|
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
|
AND l.alg_district_key = di.alg_district_key
|
|
AND di.alg_regio_key = r.alg_regio_key
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
AND md.ins_discipline_key = std.mld_ins_discipline_key
|
|
AND std.mld_stdmelding_key = m.mld_stdmelding_key
|
|
AND m.mld_melding_datum BETWEEN v_datum_van AND v_datum_tot
|
|
)
|
|
GROUP BY regio;
|
|
END;
|
|
|
|
PROCEDURE client_periode (user_key IN NUMBER,
|
|
p_datum_van IN VARCHAR2, -- Let wel: formaat '13-05-2005'
|
|
p_datum_tot IN VARCHAR2,
|
|
p_cursor OUT t_cursor)
|
|
AS
|
|
v_datum_van DATE;
|
|
v_datum_tot DATE;
|
|
v_alg_level_read NUMBER;
|
|
BEGIN
|
|
v_datum_van := fac.safe_to_date (p_datum_van, 'dd-mm-yyyy');
|
|
v_datum_tot := fac.safe_to_date (p_datum_tot, 'dd-mm-yyyy')+1;
|
|
|
|
OPEN p_cursor FOR
|
|
SELECT fac_usrdata_omschr client,
|
|
COUNT (mld_key) aantal_meldingen,
|
|
SUM (acceptoptijd) acceptoptijd,
|
|
SUM (uitvoeringoptijd) uitvoeringoptijd
|
|
FROM (
|
|
SELECT DISTINCT
|
|
m.mld_melding_key mld_key,
|
|
fac_usrdata_omschr ,
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
fac.gettrackingdate ('MLDNEW', m.mld_melding_key),
|
|
std.mld_stdmelding_urgentie,
|
|
'UREN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDACP', m.mld_melding_key),
|
|
SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
acceptoptijd,
|
|
CASE
|
|
WHEN fac.gettrackingdate ('MLDREJ', m.mld_melding_key) IS NULL
|
|
THEN
|
|
CASE SIGN(fac.datumtijdplusuitvoertijd (
|
|
m.mld_melding_datum,
|
|
m.mld_melding_uitvoertijd,
|
|
'DAGEN')
|
|
- COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key),
|
|
COALESCE (fac.gettrackingdate ('MLDAFM', m.mld_melding_key),
|
|
SYSDATE)))
|
|
WHEN -1 THEN 0
|
|
ELSE 1
|
|
END
|
|
ELSE 1
|
|
END
|
|
uitvoeringoptijd
|
|
FROM mld_melding m,
|
|
alg_onrgoedkenmerk ogk,
|
|
mld_stdmelding std,
|
|
fac_usrdata ud
|
|
WHERE m.mld_alg_locatie_key = ogk.alg_onrgoed_key
|
|
AND ogk.alg_onrgoed_niveau = 'L'
|
|
AND ogk.alg_kenmerk_key = 1000
|
|
AND fac.safe_to_number(ogk.alg_onrgoedkenmerk_waarde) = fac_usrdata_key
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND m.mld_melding_datum BETWEEN v_datum_van AND v_datum_tot
|
|
)
|
|
GROUP BY fac_usrdata_omschr;
|
|
END;
|
|
END;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE csun_export_mailnoti (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
CURSOR c
|
|
IS
|
|
SELECT m.mld_melding_key, p.prs_perslid_email
|
|
FROM prs_perslid p,
|
|
mld_melding m,
|
|
alg_locatie l,
|
|
alg_locatie l2,
|
|
prs_v_perslidwerkplek_gegevens pwpg
|
|
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
|
AND pwpg.alg_locatie_key = l2.alg_locatie_key
|
|
AND l.alg_district_key = l2.alg_district_key
|
|
AND pwpg.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_srtperslid_key = 32 -- BBer
|
|
AND p.prs_perslid_email IS NOT NULL
|
|
AND NOT EXISTS
|
|
(SELECT fac_tracking_key
|
|
FROM fac_tracking t
|
|
WHERE fac_tracking_oms LIKE 'Gemaild naar BBer:%'
|
|
AND t.fac_tracking_refkey = mld_melding_key);
|
|
|
|
v_dummy VARCHAR2 (128);
|
|
BEGIN
|
|
-- stuur de notificatie ook naar het emailadres kenmerk.
|
|
INSERT INTO fac_notificatie (fac_srtnotificatie_key,
|
|
fac_notificatie_status,
|
|
fac_notificatie_receiver_email,
|
|
fac_notificatie_oms,
|
|
fac_notificatie_refkey,
|
|
fac_notificatie_prioriteit,
|
|
fac_notificatie_datum,
|
|
fac_notificatie_sender_email,
|
|
fac_notificatie_lang,
|
|
prs_perslid_key_sender)
|
|
SELECT n.fac_srtnotificatie_key,
|
|
fac_notificatie_status,
|
|
mld_kenmerkmelding_waarde,
|
|
fac_notificatie_oms,
|
|
fac_notificatie_refkey,
|
|
fac_notificatie_prioriteit,
|
|
fac_notificatie_datum,
|
|
fac_notificatie_sender_email,
|
|
fac_notificatie_lang,
|
|
prs_perslid_key_sender
|
|
FROM fac_notificatie n,
|
|
fac_srtnotificatie sn,
|
|
mld_kenmerkmelding km,
|
|
mld_kenmerk k
|
|
WHERE n.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND ( sn.fac_srtnotificatie_code = 'MLDAFM'
|
|
OR sn.fac_srtnotificatie_code = 'MLDUPD'
|
|
OR sn.fac_srtnotificatie_code = 'MLD_REJ')
|
|
AND n.fac_notificatie_refkey = km.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = 1; -- email notificatie
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
fac.putnotificationsrtprio(null, null, 'MLDMAI', rec.mld_melding_key, 'Melding ' || rec.mld_melding_key || ' is aan u in behandeling gegeven', 2, rec.prs_perslid_email, null, null, 2, null);
|
|
fac.trackaction('MLDMAI', rec.mld_melding_key, 4, NULL, 'Gemaild naar BBer: ' || rec.prs_perslid_email);
|
|
END;
|
|
END LOOP;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE CSUN_processemail (pfrom IN VARCHAR2,
|
|
pto IN VARCHAR2,
|
|
psubject IN VARCHAR2,
|
|
pbody IN VARCHAR2,
|
|
pextra IN VARCHAR2)
|
|
AS
|
|
sender prs_perslid.prs_perslid_key%TYPE;
|
|
kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
mldkey mld_melding.mld_melding_key%TYPE;
|
|
stdmelding mld_stdmelding.mld_stdmelding_key%TYPE;
|
|
subject_regexp fac_setting.fac_setting_default%TYPE;
|
|
kkey mld_kenmerk.mld_kenmerk_key%TYPE;
|
|
errormsg fac_result.fac_result_waarde%TYPE;
|
|
mldnum VARCHAR2(4000);
|
|
srtdisc VARCHAR2(4000);
|
|
cnt NUMBER(10);
|
|
|
|
BEGIN
|
|
errormsg := '(0x143)';
|
|
-- Valideer de sender in pfrom: kennen we deze?
|
|
SELECT MIN (prs_perslid_key), MIN (d.prs_kostenplaats_key)
|
|
INTO sender, kostenplaats
|
|
FROM prs_perslid p, prs_afdeling d
|
|
WHERE p.prs_afdeling_key = d.prs_afdeling_key
|
|
AND prs_perslid_verwijder IS NULL
|
|
AND (UPPER (prs_perslid_email) = UPPER (pfrom)
|
|
OR EXISTS
|
|
(SELECT *
|
|
FROM prs_kenmerklink kl
|
|
WHERE prs_kenmerk_key = 1020
|
|
AND prs_link_key = p.prs_perslid_key
|
|
AND UPPER (kl.prs_kenmerklink_waarde) =
|
|
UPPER (pfrom)));
|
|
|
|
CASE
|
|
WHEN UPPER (pto) LIKE 'SERVICEDESK@%'
|
|
THEN
|
|
errormsg := '(0x145)';
|
|
|
|
-- append (as a note?) to an existing melding if #key is found in the subject
|
|
-- Alternatief was: scannen van fac_srtnotificatie_oms maar dat voelt ook niet echt lekker
|
|
-- subject_regexp := fac.getsetting ('mld_reply_subject_regexp'); -- [[:alpha:]]*[[:digit:]]{3,}
|
|
subject_regexp := '[[:alpha:]]*[[:digit:]]{3,}';
|
|
mldnum := REGEXP_SUBSTR(psubject, subject_regexp, 1, 1, 'i'); -- MA12345
|
|
srtdisc := REGEXP_SUBSTR(mldnum, '[[:alpha:]]', 1, 1, 'i'); -- MA
|
|
mldkey := fac.safe_to_number(substr(mldnum, length(srtdisc) + 1));
|
|
DBMS_OUTPUT.PUT_LINE('mldnum: ' || mldnum);
|
|
DBMS_OUTPUT.PUT_LINE('srtdisc: ' || srtdisc);
|
|
DBMS_OUTPUT.PUT_LINE('mldkey: ' || mldkey);
|
|
-- We eisen
|
|
-- - Goed meldingnummer
|
|
-- - Goede srtdiscipline
|
|
-- - Afzender is degene voor wie de melding was
|
|
-- suggested extensions: ook collega's toestaan?
|
|
SELECT MIN(mm.mld_stdmelding_key)
|
|
INTO stdmelding
|
|
FROM mld_melding mm, mld_stdmelding msm, ins_tab_discipline insd, ins_srtdiscipline isd
|
|
WHERE mm.mld_melding_key = mldkey
|
|
AND mm.mld_stdmelding_key = msm.mld_stdmelding_key
|
|
AND msm.mld_ins_discipline_key = insd.ins_discipline_key
|
|
AND insd.ins_srtdiscipline_key = isd.ins_srtdiscipline_key
|
|
-- Controle op srtdisc werkt niet goed. Mails worden na binnenkomst namelijk doorgezet
|
|
-- naar de definitieve stdmelding(/discipline/srtdiscpline) en daarmee verandert de
|
|
-- prefix letter
|
|
--AND isd.ins_srtdiscipline_prefix = srtdisc
|
|
AND mm.prs_perslid_key_voor = sender;
|
|
DBMS_OUTPUT.PUT_LINE('mld_stdmelding_key: ' || TO_CHAR(stdmelding));
|
|
|
|
IF (stdmelding IS NOT NULL) THEN -- Bestaande melding
|
|
INSERT INTO mld_melding_note (mld_melding_key,
|
|
mld_melding_note_omschrijving,
|
|
prs_perslid_key,
|
|
mld_melding_note_flag)
|
|
VALUES(mldkey, pbody, sender, 1); -- 1 is zichtbaar FE want zelf ingevoerd.
|
|
-- Default tracking is even goed genoeg
|
|
fac.trackaction('MLDNOT', mldkey, sender, NULL, '#Notitie toegevoegd vanuit e-mail'); -- # voorkomt notificatie
|
|
-- suggested extensions:
|
|
-- Vlaggetjes zetten zoals mld_edit_note.asp dat doet?
|
|
DBMS_OUTPUT.PUT_LINE('Notitie toegevoegd.');
|
|
ELSE
|
|
-- suggested extensions:
|
|
-- check for MLDUSE-write autorisations
|
|
-- parse the subject to find an appropriate stdmelding, if uniquely possible
|
|
errormsg := '(0x148)';
|
|
BEGIN
|
|
stdmelding := fac.safe_to_number(fac.getsetting ('defaultstdmelding'));
|
|
INSERT INTO mld_melding (mld_melding_module,
|
|
mld_meldbron_key,
|
|
mld_melding_datum,
|
|
mld_melding_omschrijving,
|
|
mld_melding_status,
|
|
mld_melding_uitvoertijd,
|
|
mld_stdmelding_key,
|
|
prs_perslid_key,
|
|
prs_perslid_key_voor,
|
|
prs_kostenplaats_key,
|
|
mld_melding_spoed)
|
|
VALUES ('MLD',
|
|
4, -- email
|
|
SYSDATE,
|
|
SUBSTR (
|
|
psubject || CHR (13)
|
|
|| REPLACE (
|
|
SUBSTR(pbody, 1, 4000 - (LENGTH(psubject)+1)),
|
|
CHR (13) || CHR (10) || CHR (13) || CHR (10),
|
|
CHR (13) || CHR (10)),
|
|
1,
|
|
4000), -- verwijder onnodige witregels
|
|
NULL,
|
|
2,
|
|
stdmelding,
|
|
sender,
|
|
sender,
|
|
kostenplaats,
|
|
3)
|
|
RETURNING mld_melding_key
|
|
INTO mldkey;
|
|
DBMS_OUTPUT.PUT_LINE('Melding toegevoegd: ' || mldkey);
|
|
errormsg := '(0x165)';
|
|
mld.setmeldingstatus (mldkey, 2, sender);
|
|
END;
|
|
|
|
-- Zoek het laagste bijlagen kenmerk om de bijlagen onder te stoppen
|
|
errormsg := '(0x151)';
|
|
SELECT MIN (mld_kenmerk_key)
|
|
INTO kkey
|
|
FROM mld_kenmerk k,
|
|
mld_srtkenmerk sk,
|
|
mld_stdmelding std,
|
|
ins_tab_discipline d
|
|
WHERE mld_srtkenmerk_kenmerktype = 'M'
|
|
AND sk.mld_srtkenmerk_key = k.mld_srtkenmerk_key
|
|
AND std.mld_stdmelding_key = stdmelding
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND ( (k.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND k.mld_kenmerk_niveau = 'S')
|
|
OR (k.mld_stdmelding_key = d.ins_discipline_key
|
|
AND k.mld_kenmerk_niveau = 'D')
|
|
OR (k.mld_stdmelding_key = d.ins_srtdiscipline_key
|
|
AND k.mld_kenmerk_niveau = 'T'))
|
|
AND k.mld_kenmerk_verwijder IS NULL
|
|
AND NOT EXISTS
|
|
(SELECT mld_kenmerk_volgnummer
|
|
FROM mld_kenmerk k1,
|
|
mld_srtkenmerk sk1,
|
|
mld_stdmelding std1,
|
|
ins_tab_discipline d1
|
|
WHERE sk1.mld_srtkenmerk_kenmerktype = 'M'
|
|
AND sk1.mld_srtkenmerk_key =
|
|
k1.mld_srtkenmerk_key
|
|
AND std1.mld_stdmelding_key =
|
|
stdmelding
|
|
AND std1.mld_ins_discipline_key =
|
|
d1.ins_discipline_key
|
|
AND ( (k1.mld_stdmelding_key =
|
|
std1.mld_stdmelding_key
|
|
AND k1.mld_kenmerk_niveau = 'S')
|
|
OR (k1.mld_stdmelding_key =
|
|
d1.ins_discipline_key
|
|
AND k1.mld_kenmerk_niveau = 'D')
|
|
OR (k1.mld_stdmelding_key =
|
|
d1.ins_srtdiscipline_key
|
|
AND k1.mld_kenmerk_niveau = 'T'))
|
|
AND k1.mld_kenmerk_verwijder IS NULL
|
|
AND k1.mld_kenmerk_volgnummer >
|
|
k.mld_kenmerk_volgnummer);
|
|
|
|
errormsg := '(0x153)';
|
|
IF kkey IS NOT NULL
|
|
THEN
|
|
DBMS_OUTPUT.PUT_LINE('Bijlagen kenmerk: ' || kkey);
|
|
errormsg := '(0x157)';
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES ('hMailServer',
|
|
'kenmerkpath',
|
|
'MLD\M' || to_char(TRUNC(mldkey/1000), 'FM0000') || '___\M' || mldkey || '\' || kkey || '\');
|
|
END IF;
|
|
END IF;
|
|
ELSE
|
|
errormsg := '(0x187)';
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES ('hMailServer', 'errormsg', 'Database fout - Neem contact op met uw systeembeheerder ' || errormsg);
|
|
END CASE;
|
|
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
DBMS_OUTPUT.PUT_LINE('Mail niet geaccepteerd: ' || 'OTHERS (error ' || SQLCODE || '/' || SUBSTR (SQLERRM, 1, 100) || ')');
|
|
INSERT INTO fac_result (fac_result_sessionid,
|
|
fac_result_naam,
|
|
fac_result_waarde)
|
|
VALUES ('hMailServer',
|
|
'errormsg',
|
|
'Database fout - Neem contact op met uw systeembeheerder ' || errormsg);
|
|
|
|
fac.writelog ('PROCESSEMAIL',
|
|
'E',
|
|
'OTHERS (error ' || SQLCODE || '/' || SUBSTR (SQLERRM, 1, 100) || ')',
|
|
errormsg || ' afzender:' || pfrom);
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW CSUN_V_RAP_MAIL_ERROR
|
|
(
|
|
hide_f_offset,
|
|
datum,
|
|
hint,
|
|
error
|
|
)
|
|
AS
|
|
SELECT SYSDATE - imp_log_datum,
|
|
imp_log_datum,
|
|
imp_log_hint,
|
|
imp_log_omschrijving
|
|
FROM imp_log
|
|
WHERE imp_log_applicatie = 'PROCESSEMAIL'
|
|
AND imp_log_datum > SYSDATE - 30;
|
|
|
|
|
|
|
|
CREATE OR REPLACE VIEW csun_v_rap_melding
|
|
(
|
|
FCLT_F_CLIENT,
|
|
WERKBEDRIJF,
|
|
FCLT_D_DATUM,
|
|
WERKBON,
|
|
MELDING,
|
|
TYPE,
|
|
OMSCHRIJVING,
|
|
LOCATIE,
|
|
LOCATIE_ADRES,
|
|
LOCATIE_PLAATS,
|
|
OPLOSTIJD,
|
|
DATUM_REACTIE,
|
|
REACTIE_OPTIJD,
|
|
REACTIE,
|
|
UITVOERTIJD,
|
|
UITGEVOERD,
|
|
STATUS
|
|
)
|
|
AS
|
|
SELECT (SELECT fac_usrdata_omschr
|
|
FROM alg_onrgoedkenmerk, fac_usrdata ud
|
|
WHERE alg_kenmerk_key = 1000
|
|
AND alg_onrgoed_key = l.alg_locatie_key
|
|
AND fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
|
fac_usrdata_key)
|
|
client,
|
|
own.fac_usrdata_omschr werkbedrijf,
|
|
TO_CHAR (mld_melding_datum, 'dd-mm-yyyy'),
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = 2)
|
|
werkbon,
|
|
mld_melding_key,
|
|
sd.ins_srtdiscipline_omschrijving
|
|
|| ' - '
|
|
|| d.ins_discipline_omschrijving,
|
|
m.mld_melding_omschrijving,
|
|
l.alg_locatie_omschrijving,
|
|
l.alg_locatie_adres,
|
|
l.alg_locatie_plaats,
|
|
TO_CHAR (m.mld_melding_acceptdatum_std, 'dd-mm-yyyy hh24:mi'),
|
|
TO_CHAR (tr.fac_tracking_datum, 'dd-mm-yyyy hh24:mi')
|
|
datum_reactie,
|
|
DECODE (
|
|
SIGN (tr.fac_tracking_datum - m.mld_melding_acceptdatum_std),
|
|
-1,
|
|
'ja',
|
|
NULL
|
|
)
|
|
reactie_optijd,
|
|
mld_melding_opmerking,
|
|
TO_CHAR (m.mld_melding_einddatum_std, 'dd-mm-yyyy hh24:mi'),
|
|
(SELECT TO_CHAR (fac_tracking_datum, 'dd-mm-yyyy hh24:mi')
|
|
FROM fac_tracking
|
|
WHERE fac_tracking_refkey = mld_melding_key
|
|
AND fac_srtnotificatie_key = 35)
|
|
einddatum,
|
|
st.mld_statuses_omschrijving alg_locatie_omschrijving
|
|
FROM mld_melding m,
|
|
alg_locatie l,
|
|
mld_stdmelding std,
|
|
ins_tab_discipline d,
|
|
ins_srtdiscipline sd,
|
|
mld_statuses st,
|
|
(SELECT fac_usrdata_omschr, aok.alg_onrgoed_key
|
|
FROM alg_onrgoedkenmerk aok,
|
|
alg_kenmerk ak,
|
|
fac_kenmerkdomein fc,
|
|
fac_usrdata fu,
|
|
fac_usrtab ft
|
|
WHERE ak.alg_kenmerk_key = 1001
|
|
AND alg_onrgoedkenmerk_verwijder IS NULL
|
|
AND aok.alg_kenmerk_key = ak.alg_kenmerk_key
|
|
AND ak.fac_kenmerkdomein_key = fc.fac_kenmerkdomein_key
|
|
AND ft.fac_usrtab_key = fc.fac_usrtab_key
|
|
AND fu.fac_usrtab_key = ft.fac_usrtab_key
|
|
AND alg_onrgoedkenmerk_waarde = fac_usrdata_key) own,
|
|
(SELECT fac_tracking_datum, fac_tracking_refkey
|
|
FROM fac_tracking t
|
|
WHERE t.fac_tracking_oms LIKE '%Afhandeling: (leeg) -->%') tr
|
|
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key(+)
|
|
AND m.mld_melding_key = tr.fac_tracking_refkey(+)
|
|
AND m.mld_melding_status = st.mld_statuses_key
|
|
AND alg_locatie_key = own.alg_onrgoed_key(+);
|
|
|
|
CREATE OR REPLACE VIEW CSUN_V_RAP_MELDING_SANQ
|
|
(
|
|
MELDING,
|
|
RL,
|
|
DM,
|
|
LOCATIE,
|
|
RC,
|
|
RC_TELEFOON,
|
|
RC_MAIL,
|
|
FCLT_D_DATUM_MELDING,
|
|
TIJDSTIP_MELDING,
|
|
MAAND_MELDING,
|
|
MELDER,
|
|
AARD_MELDING,
|
|
OMSCHRIJVING,
|
|
RUIMTE_CATEGORIE,
|
|
RUIMTE_NUMMER,
|
|
URGENTIEKLASSE,
|
|
ONDERNOMEN_ACTIES,
|
|
RESULTAAT,
|
|
PREVENTIE,
|
|
STATUS,
|
|
DATUM_AFGEHANDELD,
|
|
TIJDSTIP_AFGEHANDELD,
|
|
AFHANDELTIJD_UREN,
|
|
AFHANDELTIJD_DAGEN,
|
|
BIJZONDERHEDEN
|
|
)
|
|
AS
|
|
SELECT mld_melding_key,
|
|
NULL rl,
|
|
NULL dm,
|
|
alg_locatie_omschrijving,
|
|
NULL rc_sanquin,
|
|
NULL telefoonnummer,
|
|
NULL mailadres,
|
|
TO_CHAR (mld_melding_datum, 'dd-mm-yyyy') datum,
|
|
TO_CHAR (mld_melding_datum, 'hh24:mi') tijdstip,
|
|
fac.safe_to_number (TO_CHAR (mld_melding_datum, 'mm')) maand,
|
|
pf.prs_perslid_naam_full melder,
|
|
std.mld_stdmelding_omschrijving aard,
|
|
mld_melding_omschrijving omschrijving,
|
|
NULL ruimte_categorie,
|
|
NULL ruimte_nummer,
|
|
mld_melding_spoed urgentieklasse,
|
|
-- decode (mld_melding_spoed, null vereistehersteltijd,
|
|
mld_melding_opmerking ondernomenacties,
|
|
NULL resultaat,
|
|
NULL preventie,
|
|
mld_statuses_omschrijving status,
|
|
TO_CHAR (einddatum.datum, 'dd-mm-yyyy') datumafgehandeld,
|
|
TO_CHAR (einddatum.datum, 'hh24:mi') tijdstipafgehandeld,
|
|
csu_count_WorkHours (mld_melding_datum, einddatum.datum)
|
|
afgehandelduren,
|
|
ROUND (
|
|
csu_count_WorkHours (mld_melding_datum, einddatum.datum) / 9,
|
|
2)
|
|
afgehandelddagen,
|
|
NULL bijzonderheden
|
|
FROM mld_melding m,
|
|
alg_locatie l,
|
|
prs_v_perslid_fullnames_all pf,
|
|
mld_stdmelding std,
|
|
mld_statuses st,
|
|
(SELECT fac_tracking_refkey, fac_tracking_datum datum
|
|
FROM fac_tracking
|
|
WHERE fac_srtnotificatie_key = 35) einddatum
|
|
WHERE m.mld_alg_locatie_key = l.alg_locatie_key
|
|
AND m.prs_perslid_key = pf.prs_perslid_key
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND m.mld_melding_key = einddatum.fac_tracking_refkey(+)
|
|
AND m.mld_melding_status = st.mld_statuses_key;
|
|
|
|
|
|
CREATE OR REPLACE FORCE VIEW CSUN_V_RAP_DISTRICTGEGEVENS
|
|
(
|
|
FCLT_F_BUSINESSUNIT,
|
|
DISTRICT,
|
|
BBER
|
|
)
|
|
AS
|
|
SELECT alg_regio_omschrijving,
|
|
alg_district_omschrijving,
|
|
(SELECT prs_perslid_naam_full
|
|
FROM prs_v_perslid_fullnames pf
|
|
WHERE pf.prs_perslid_key = p.prs_perslid_key)
|
|
BBer
|
|
FROM alg_district d,
|
|
alg_regio r,
|
|
prs_perslid p,
|
|
alg_locatie l2,
|
|
prs_v_perslidwerkplek_gegevens pwpg
|
|
WHERE d.alg_regio_key = r.alg_regio_key
|
|
AND pwpg.alg_locatie_key = l2.alg_locatie_key
|
|
AND d.alg_district_key = l2.alg_district_key
|
|
AND pwpg.prs_perslid_key = p.prs_perslid_key
|
|
AND p.prs_srtperslid_key = 32; -- BBer
|
|
|
|
CREATE OR REPLACE VIEW csun_v_rap_locatiegegevens
|
|
(
|
|
prjnr,
|
|
fclt_f_regioomschrijving,
|
|
fclt_f_districtomschrijving,
|
|
locatiecode,
|
|
locatieomschrijving,
|
|
bezoekadres,
|
|
postcode,
|
|
plaats,
|
|
fclt_f_client,
|
|
bud,
|
|
bb
|
|
)
|
|
AS
|
|
SELECT (SELECT alg_onrgoedkenmerk_waarde
|
|
FROM alg_onrgoedkenmerk ogk
|
|
WHERE alg_kenmerk_key = 1040
|
|
AND ogk.alg_onrgoed_key = l.alg_locatie_key)
|
|
prjnr,
|
|
alg_regio_omschrijving,
|
|
alg_district_omschrijving,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_omschrijving,
|
|
l.alg_locatie_adres,
|
|
l.alg_locatie_postcode,
|
|
l.alg_locatie_plaats,
|
|
(SELECT u.fac_usrdata_code
|
|
FROM fac_usrdata u, alg_onrgoedkenmerk ogk
|
|
WHERE alg_kenmerk_key = 1000
|
|
AND ogk.alg_onrgoed_key = l.alg_locatie_key
|
|
AND fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
|
u.fac_usrdata_key)
|
|
client,
|
|
(SELECT prs_perslid_naam_full
|
|
FROM prs_v_perslid_fullnames pf, alg_onrgoedkenmerk ogk
|
|
WHERE alg_kenmerk_key = 1006
|
|
AND ogk.alg_onrgoed_key = l.alg_locatie_key
|
|
AND fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
|
pf.prs_perslid_key)
|
|
bud,
|
|
(SELECT prs_perslid_naam_full
|
|
FROM prs_v_perslid_fullnames pf, alg_onrgoedkenmerk ogk
|
|
WHERE alg_kenmerk_key = 1007
|
|
AND ogk.alg_onrgoed_key = l.alg_locatie_key
|
|
AND fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
|
pf.prs_perslid_key)
|
|
bb
|
|
FROM alg_locatie l, alg_district d, alg_regio r
|
|
WHERE l.alg_district_key = d.alg_district_key
|
|
AND d.alg_regio_key = r.alg_regio_key
|
|
AND alg_locatie_verwijder IS NULL;
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE csun_set_kenmerk(p_module IN VARCHAR2,
|
|
p_kenmerk_key IN NUMBER,
|
|
p_link_key IN NUMBER,
|
|
p_kenmerk_waarde IN VARCHAR2,
|
|
p_history IN NUMBER)
|
|
AS
|
|
v_count NUMBER;
|
|
v_niveau VARCHAR2 (1);
|
|
BEGIN
|
|
CASE p_module
|
|
WHEN 'PRS'
|
|
THEN
|
|
-- niveau van prs_kenmerk ophalen, omdat deze ook in prs_kenmerklink wordt
|
|
-- opgeslagen (da's dus redundant..?)
|
|
SELECT prs_kenmerk_niveau
|
|
INTO v_niveau
|
|
FROM prs_kenmerk
|
|
WHERE prs_kenmerk_key = p_kenmerk_key;
|
|
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM prs_kenmerklink
|
|
WHERE prs_link_key = p_link_key
|
|
AND prs_kenmerk_key = p_kenmerk_key
|
|
AND prs_kenmerklink_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE prs_kenmerklink
|
|
WHERE prs_link_key = p_link_key
|
|
AND prs_kenmerk_key = p_kenmerk_key
|
|
AND prs_kenmerklink_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE prs_kenmerklink
|
|
SET prs_kenmerklink_waarde = p_kenmerk_waarde
|
|
WHERE prs_link_key = p_link_key
|
|
AND prs_kenmerk_key = p_kenmerk_key
|
|
AND prs_kenmerklink_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO prs_kenmerklink (prs_kenmerk_key,
|
|
prs_link_key,
|
|
prs_kenmerklink_niveau,
|
|
prs_kenmerklink_waarde)
|
|
VALUES (p_kenmerk_key,
|
|
p_link_key,
|
|
v_niveau,
|
|
p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
|
|
WHEN 'ALG'
|
|
THEN
|
|
-- niveau van prs_kenmerk ophalen, omdat deze ook in prs_kenmerklink wordt
|
|
-- opgeslagen (da's dus redundant..?)
|
|
SELECT alg_kenmerk_niveau
|
|
INTO v_niveau
|
|
FROM alg_kenmerk
|
|
WHERE alg_kenmerk_key = p_kenmerk_key;
|
|
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM alg_onrgoedkenmerk
|
|
WHERE alg_onrgoed_key = p_link_key
|
|
AND alg_kenmerk_key = p_kenmerk_key
|
|
AND alg_onrgoedkenmerk_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE alg_onrgoedkenmerk
|
|
WHERE alg_onrgoed_key = p_link_key
|
|
AND alg_kenmerk_key = p_kenmerk_key
|
|
AND alg_onrgoedkenmerk_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE alg_onrgoedkenmerk
|
|
SET alg_onrgoedkenmerk_waarde = p_kenmerk_waarde
|
|
WHERE alg_onrgoed_key = p_link_key
|
|
AND alg_kenmerk_key = p_kenmerk_key
|
|
AND alg_onrgoedkenmerk_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO alg_onrgoedkenmerk (alg_kenmerk_key,
|
|
alg_onrgoed_key,
|
|
alg_onrgoed_niveau,
|
|
alg_onrgoedkenmerk_waarde)
|
|
VALUES (p_kenmerk_key,
|
|
p_link_key,
|
|
v_niveau,
|
|
p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
|
|
WHEN 'MLD'
|
|
THEN
|
|
-- melding- of opdrachtkenmerk?
|
|
SELECT mld_kenmerk_niveau
|
|
INTO v_niveau
|
|
FROM mld_kenmerk
|
|
WHERE mld_kenmerk_key = p_kenmerk_key;
|
|
|
|
CASE v_niveau
|
|
WHEN 'O'
|
|
THEN
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM mld_kenmerkopdr
|
|
WHERE mld_opdr_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE mld_kenmerkopdr
|
|
WHERE mld_opdr_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE mld_kenmerkopdr
|
|
SET mld_kenmerkopdr_waarde = p_kenmerk_waarde
|
|
WHERE mld_opdr_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO mld_kenmerkopdr (mld_kenmerk_key,
|
|
mld_opdr_key,
|
|
mld_kenmerkopdr_waarde)
|
|
VALUES (p_kenmerk_key,
|
|
p_link_key,
|
|
p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
WHEN 'S'
|
|
THEN
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM mld_kenmerkmelding
|
|
WHERE mld_melding_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE mld_kenmerkmelding
|
|
WHERE mld_melding_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE mld_kenmerkmelding
|
|
SET mld_kenmerkmelding_waarde = p_kenmerk_waarde
|
|
WHERE mld_melding_key = p_link_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO mld_kenmerkmelding (mld_kenmerk_key,
|
|
mld_melding_key,
|
|
mld_kenmerkmelding_waarde)
|
|
VALUES (p_kenmerk_key,
|
|
p_link_key,
|
|
p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
END CASE;
|
|
END CASE;
|
|
END;
|
|
/
|
|
|
|
|
|
-- TODO: Projectnummer toevoegen aan import en imp tabel. !!!!!!!!!!!!!!!!!!!!!!!!!!
|
|
CREATE OR REPLACE PROCEDURE csun_import_onrgoed (p_import_key IN NUMBER)
|
|
AS
|
|
c_fielddelimitor VARCHAR2 (1) := ';';
|
|
v_newline VARCHAR2 (1000); -- Input line
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
header_is_valid NUMBER;
|
|
v_count NUMBER;
|
|
v_error NUMBER (1);
|
|
v_aanduiding VARCHAR2 (200);
|
|
-- De importvelden:
|
|
v_prjnr VARCHAR2 (10);
|
|
v_regio_omschrijving VARCHAR2 (255); -- 30
|
|
v_regio_key NUMBER (10);
|
|
v_district_omschrijving VARCHAR2 (255); -- 30
|
|
v_district_key NUMBER (10);
|
|
v_locatie_code VARCHAR2 (255); -- 10
|
|
v_locatie_omschrijving VARCHAR2 (255); -- 30
|
|
v_locatie_adres VARCHAR2 (255); -- 35
|
|
v_locatie_postcode VARCHAR2 (255); -- 12
|
|
v_locatie_plaats VARCHAR2 (255); -- 30
|
|
v_client VARCHAR2 (255); --40
|
|
v_client_key NUMBER (10);
|
|
v_bud VARCHAR2 (255); -- 100
|
|
v_bud_key NUMBER (10);
|
|
v_bb VARCHAR2 (255); -- 100
|
|
v_bb_key NUMBER (10);
|
|
v_kenmerk1 VARCHAR2 (255);
|
|
v_kenmerk2 VARCHAR2 (255);
|
|
v_kenmerk3 VARCHAR2 (255);
|
|
v_kenmerk4 VARCHAR2 (255);
|
|
v_kenmerk5 VARCHAR2 (255);
|
|
|
|
|
|
CURSOR c1
|
|
IS
|
|
SELECT *
|
|
FROM fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
ORDER BY fac_imp_file_index;
|
|
BEGIN
|
|
-- Eerst opruiming
|
|
DELETE FROM imp_log
|
|
WHERE fac_import_key = p_import_key;
|
|
|
|
DELETE FROM fac_imp_onrgoed1;
|
|
|
|
header_is_valid := 0;
|
|
v_count := 0;
|
|
COMMIT;
|
|
|
|
FOR rec1 IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_errormsg := 'Fout FETCH te importeren rij';
|
|
v_newline := rec1.fac_imp_file_line;
|
|
v_errormsg := 'Fout opvragen te importeren rij';
|
|
v_aanduiding := '';
|
|
v_error := 0;
|
|
-- Lees alle veldwaarden
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_prjnr);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_regio_omschrijving);
|
|
fac.imp_getfield (v_newline,
|
|
c_fielddelimitor,
|
|
v_district_omschrijving);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_locatie_code);
|
|
fac.imp_getfield (v_newline,
|
|
c_fielddelimitor,
|
|
v_locatie_omschrijving);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_locatie_adres);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_locatie_postcode);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_locatie_plaats);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_client);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_bud);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_bb);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_kenmerk1);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_kenmerk2);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_kenmerk3);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_kenmerk4);
|
|
fac.imp_getfield (v_newline, c_fielddelimitor, v_kenmerk5);
|
|
|
|
v_regio_key := '';
|
|
v_district_key := '';
|
|
v_client_key := '';
|
|
v_bud_key := '';
|
|
v_bb_key := '';
|
|
|
|
v_aanduiding :=
|
|
v_locatie_code || '|' || v_locatie_omschrijving || '| ';
|
|
|
|
IF (header_is_valid = 0)
|
|
THEN
|
|
IF UPPER (v_regio_omschrijving) = 'REGIOOMSCHRIJVING'
|
|
AND UPPER (v_locatie_postcode) = 'POSTCODE'
|
|
AND UPPER (v_bb) = 'BB'
|
|
THEN
|
|
header_is_valid := 1;
|
|
END IF;
|
|
ELSE
|
|
|
|
-- Controleer alle veldwaarden
|
|
IF LENGTH (v_regio_omschrijving) > 30
|
|
THEN
|
|
v_regio_omschrijving := SUBSTR (v_regio_omschrijving, 1, 30);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'District-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_regio_omschrijving
|
|
|| '>');
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT alg_regio_key
|
|
INTO v_regio_key
|
|
FROM alg_regio
|
|
WHERE alg_regio_verwijder IS NULL
|
|
AND UPPER (alg_regio_omschrijving) =
|
|
UPPER (v_regio_omschrijving);
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
v_aanduiding || 'Regio kan niet gevonden worden',
|
|
'Controleer regio notatie! <'
|
|
|| v_regio_omschrijving
|
|
|| '>');
|
|
v_error := 1;
|
|
END;
|
|
|
|
--
|
|
IF LENGTH (v_district_omschrijving) > 30
|
|
THEN
|
|
v_district_omschrijving :=
|
|
SUBSTR (v_district_omschrijving, 1, 30);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'District-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_district_omschrijving
|
|
|| '>');
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT alg_district_key
|
|
INTO v_district_key
|
|
FROM alg_district
|
|
WHERE alg_district_verwijder IS NULL
|
|
AND UPPER (alg_district_omschrijving) =
|
|
UPPER (v_district_omschrijving);
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
v_aanduiding || 'District kan niet gevonden worden',
|
|
'Controleer district notatie! <'
|
|
|| v_district_omschrijving
|
|
|| '>');
|
|
v_error := 1;
|
|
END;
|
|
|
|
--
|
|
IF LENGTH (v_locatie_code) > 10
|
|
THEN
|
|
v_locatie_code := SUBSTR (v_locatie_code, 1, 10);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'Locatiecode-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_locatie_code
|
|
|| '>');
|
|
END IF;
|
|
|
|
--
|
|
IF LENGTH (v_locatie_omschrijving) > 50
|
|
THEN
|
|
v_locatie_omschrijving :=
|
|
SUBSTR (v_locatie_omschrijving, 1, 50);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'Locatie-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_locatie_omschrijving
|
|
|| '>');
|
|
END IF;
|
|
|
|
--
|
|
IF LENGTH (v_locatie_adres) > 35
|
|
THEN
|
|
v_locatie_adres := SUBSTR (v_locatie_adres, 1, 35);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding
|
|
|| 'Locatie-aanduiding bezoek-adres is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_locatie_adres
|
|
|| '>');
|
|
END IF;
|
|
|
|
--
|
|
IF LENGTH (v_locatie_postcode) > 12
|
|
THEN
|
|
v_locatie_postcode := SUBSTR (v_locatie_postcode, 1, 12);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding
|
|
|| 'Postcode-aanduiding bezoek-adres is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_locatie_postcode
|
|
|| '>');
|
|
END IF;
|
|
|
|
--
|
|
IF LENGTH (v_locatie_plaats) > 30
|
|
THEN
|
|
v_locatie_plaats := SUBSTR (v_locatie_plaats, 1, 30);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'Plaats-aanduiding bezoek-adres is te lang',
|
|
'Aanduiding wordt afgebroken tot <'
|
|
|| v_locatie_plaats
|
|
|| '>');
|
|
END IF;
|
|
|
|
--
|
|
IF LENGTH (v_client) > 40
|
|
THEN
|
|
v_client := SUBSTR (v_client, 1, 40);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'client-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <' || v_client || '>');
|
|
END IF;
|
|
|
|
IF v_client IS NOT NULL
|
|
THEN
|
|
BEGIN
|
|
SELECT fac_usrdata_key
|
|
INTO v_client_key
|
|
FROM fac_usrdata
|
|
WHERE fac_usrdata_verwijder IS NULL
|
|
AND fac_usrtab_key = 1
|
|
AND UPPER (fac_usrdata_omschr) = UPPER (v_client);
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO fac_usrdata (fac_usrtab_key,
|
|
fac_usrdata_code,
|
|
fac_usrdata_omschr)
|
|
VALUES (1,
|
|
SUBSTR (v_client, 1, 40),
|
|
SUBSTR (v_client, 1, 60))
|
|
RETURNING fac_usrdata_key INTO v_client_key;
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'I',
|
|
v_aanduiding || 'Client wordt toegevoegd',
|
|
'<' || v_client || '>');
|
|
END;
|
|
END IF;
|
|
|
|
--
|
|
IF v_bud IS NOT NULL
|
|
THEN
|
|
IF LENGTH (v_bud) > 100
|
|
THEN
|
|
v_bud := SUBSTR (v_bud, 1, 100);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'BUD-aanduiding is te lang',
|
|
'Aanduiding wordt afgebroken tot <' || v_bud || '>');
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT prs_perslid_key
|
|
INTO v_bud_key
|
|
FROM prs_v_perslid_fullnames
|
|
WHERE prs_perslid_naam_full = v_bud;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
v_aanduiding || 'BUD kan niet gevonden worden',
|
|
'Controleer BUD notatie! <' || v_bud || '>');
|
|
v_error := 1;
|
|
END;
|
|
END IF;
|
|
|
|
--
|
|
IF v_bb IS NOT NULL
|
|
THEN
|
|
IF LENGTH (v_bb) > 100
|
|
THEN
|
|
v_bb := SUBSTR (v_bb, 1, 100);
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'W',
|
|
v_aanduiding || 'BB-aanduiding post-adres is te lang',
|
|
'Aanduiding wordt afgebroken tot <' || v_bb || '>');
|
|
END IF;
|
|
|
|
BEGIN
|
|
SELECT prs_perslid_key
|
|
INTO v_bb_key
|
|
FROM prs_v_perslid_fullnames
|
|
WHERE prs_perslid_naam_full = v_bb;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
v_aanduiding || 'BB kan niet gevonden worden',
|
|
'Controleer BB notatie! <' || v_bb || '>');
|
|
v_error := 1;
|
|
END;
|
|
END IF;
|
|
|
|
|
|
--
|
|
|
|
-- Insert geformatteerde import record
|
|
IF v_error = 0
|
|
THEN
|
|
|
|
v_errormsg :=
|
|
'Fout bij toevoegen te impoteren locatie ['
|
|
|| v_locatie_code
|
|
|| ']';
|
|
|
|
INSERT INTO csun_imp_onrgoed (alg_regio_omschrijving,
|
|
alg_regio_key,
|
|
alg_district_omschrijving,
|
|
alg_district_key,
|
|
alg_locatie_code,
|
|
alg_locatie_omschrijving,
|
|
alg_locatie_adres,
|
|
alg_locatie_postcode,
|
|
alg_locatie_plaats,
|
|
client,
|
|
client_key,
|
|
bud,
|
|
bud_key,
|
|
bb,
|
|
bb_key,
|
|
kenmerk1,
|
|
kenmerk2,
|
|
kenmerk3,
|
|
kenmerk4,
|
|
kenmerk5)
|
|
VALUES (v_regio_omschrijving,
|
|
v_regio_key,
|
|
v_district_omschrijving,
|
|
v_district_key,
|
|
v_locatie_code,
|
|
v_locatie_omschrijving,
|
|
v_locatie_adres,
|
|
v_locatie_postcode,
|
|
v_locatie_plaats,
|
|
v_client,
|
|
v_client_key,
|
|
v_bud,
|
|
v_bud_key,
|
|
v_bb,
|
|
v_bb_key,
|
|
v_kenmerk1,
|
|
v_kenmerk2,
|
|
v_kenmerk3,
|
|
v_kenmerk4,
|
|
v_kenmerk5);
|
|
v_count := v_count + 1;
|
|
END IF;
|
|
END IF;
|
|
END;
|
|
END LOOP;
|
|
|
|
IF (header_is_valid = 0)
|
|
THEN
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || 'Ongeldig importbestand',
|
|
'Geen geldige headerregel aanwezig');
|
|
ELSE
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'S',
|
|
'Locaties: aantal ingelezen regels: ' || TO_CHAR (v_count),
|
|
'');
|
|
END IF;
|
|
|
|
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,
|
|
'');
|
|
END csun_import_onrgoed;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE csun_update_onrgoed (p_import_key IN NUMBER)
|
|
IS
|
|
v_errormsg VARCHAR2 (1000);
|
|
v_errorhint VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (200);
|
|
v_locatie_key NUMBER (10);
|
|
|
|
CURSOR c_dist
|
|
IS
|
|
SELECT alg_regio_key,
|
|
alg_district_key,
|
|
alg_district_omschrijving,
|
|
alg_regio_omschrijving
|
|
FROM csun_imp_onrgoed i
|
|
WHERE NOT EXISTS
|
|
(SELECT alg_district_key
|
|
FROM alg_district d
|
|
WHERE d.alg_district_key = i.alg_district_key
|
|
AND d.alg_regio_key = i.alg_regio_key
|
|
AND d.alg_district_verwijder IS NULL)
|
|
GROUP BY alg_regio_key,
|
|
alg_district_key,
|
|
alg_district_omschrijving,
|
|
alg_regio_omschrijving;
|
|
|
|
|
|
CURSOR c
|
|
IS
|
|
SELECT * FROM csun_imp_onrgoed;
|
|
BEGIN
|
|
-- v_count_update := 0;
|
|
-- v_count_tot := 0;
|
|
|
|
FOR rec IN c_dist
|
|
LOOP
|
|
BEGIN
|
|
UPDATE alg_district
|
|
SET alg_regio_key = rec.alg_regio_key
|
|
WHERE alg_district_key = rec.alg_district_key;
|
|
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'I',
|
|
'District onder andere regio geplaatst['
|
|
|| rec.alg_district_omschrijving
|
|
|| '] naar regio: '
|
|
|| rec.alg_regio_omschrijving,
|
|
'');
|
|
END;
|
|
END LOOP;
|
|
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
BEGIN
|
|
v_aanduiding := 'rec.alg_locatie_code';
|
|
v_errorhint := 'check of locatie al bestaat';
|
|
|
|
-- check of locatie al bestaat
|
|
BEGIN
|
|
SELECT alg_locatie_key
|
|
INTO v_locatie_key
|
|
FROM alg_locatie
|
|
WHERE UPPER(alg_locatie_code) = UPPER (rec.alg_locatie_code)
|
|
AND alg_locatie_verwijder IS NULL;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
v_errorhint := 'voeg locatie toe';
|
|
INSERT INTO alg_locatie (alg_district_key,
|
|
alg_locatie_code,
|
|
alg_locatie_omschrijving)
|
|
VALUES (rec.alg_district_key,
|
|
rec.alg_locatie_code,
|
|
rec.alg_locatie_omschrijving)
|
|
RETURNING alg_locatie_key
|
|
INTO v_locatie_key;
|
|
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'I',
|
|
'Nieuwe locatie aangemaakt ['
|
|
|| rec.alg_locatie_code
|
|
|| ']: '
|
|
|| rec.alg_locatie_omschrijving,
|
|
'');
|
|
END;
|
|
v_errorhint := 'pas locatiegegevens aan';
|
|
UPDATE alg_locatie
|
|
SET alg_locatie_omschrijving = rec.alg_locatie_omschrijving,
|
|
alg_district_key = rec.alg_district_key,
|
|
alg_locatie_adres = rec.alg_locatie_adres,
|
|
alg_locatie_postcode = rec.alg_locatie_postcode,
|
|
alg_locatie_plaats = rec.alg_locatie_plaats
|
|
WHERE alg_locatie_key = v_locatie_key;
|
|
|
|
-- set kenmerken
|
|
v_errorhint := 'pas kenmerken aan';
|
|
csun_set_kenmerk ('ALG',
|
|
1000,
|
|
v_locatie_key,
|
|
rec.client_key,
|
|
0);
|
|
csun_set_kenmerk ('ALG',
|
|
1006,
|
|
v_locatie_key,
|
|
rec.bud_key,
|
|
0);
|
|
csun_set_kenmerk ('ALG',
|
|
1007,
|
|
v_locatie_key,
|
|
rec.bb_key,
|
|
0);
|
|
csun_export_set_werkplek ('ONRGOED',
|
|
TO_CHAR (SYSDATE, 'yyyymmdd hh24:mi:ss'),
|
|
'',
|
|
'');
|
|
END;
|
|
END LOOP;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 150);
|
|
v_errormsg := '(ORACLE error ' || oracle_err_mes || ')';
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
'Fout tijdens importeren van onroerend goed (locatie en gebouw) ',
|
|
v_errormsg);
|
|
END csun_update_onrgoed;
|
|
/
|
|
|
|
|
|
--
|
|
-- Procedures en functies om de doorlooptijd van meldingen te bepalen
|
|
--
|
|
CREATE OR REPLACE FUNCTION csu_find_next_workingday (pdate1 IN DATE)
|
|
RETURN DATE
|
|
IS
|
|
result DATE;
|
|
v_vrije_dagen NUMBER;
|
|
v_date DATE;
|
|
BEGIN
|
|
v_date := pdate1;
|
|
|
|
IF pdate1 < (TRUNC (v_date) + 8 / 24)
|
|
THEN
|
|
v_date := TRUNC (v_date) + 8 / 24;
|
|
END IF;
|
|
|
|
IF pdate1 > (TRUNC (v_date) + 17 / 24)
|
|
THEN
|
|
v_date := TRUNC (v_date) + 17 / 24;
|
|
END IF;
|
|
|
|
IF TO_CHAR (v_date, 'd') IN (1, 7)
|
|
THEN
|
|
result := csu_find_next_workingday (TRUNC (v_date) + 1 + 8 / 24);
|
|
ELSE
|
|
SELECT COUNT ( * )
|
|
INTO v_vrije_dagen
|
|
FROM mld_vrije_dagen
|
|
WHERE mld_vrije_dagen_datum = TRUNC (v_date);
|
|
|
|
IF v_vrije_dagen = 1
|
|
THEN
|
|
result := csu_find_next_workingday (TRUNC (v_date) + 1 + 8 / 24);
|
|
ELSE
|
|
result := v_date;
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN result;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE FUNCTION csu_find_prev_workingday (pdate1 IN DATE)
|
|
RETURN DATE
|
|
IS
|
|
result DATE;
|
|
v_vrije_dagen NUMBER;
|
|
v_date DATE;
|
|
BEGIN
|
|
v_date := pdate1;
|
|
|
|
IF pdate1 < (TRUNC (v_date) + 8 / 24)
|
|
THEN
|
|
v_date := TRUNC (v_date) + 8 / 24;
|
|
END IF;
|
|
|
|
IF pdate1 > (TRUNC (v_date) + 17 / 24)
|
|
THEN
|
|
v_date := TRUNC (v_date) + 17 / 24;
|
|
END IF;
|
|
|
|
IF TO_CHAR (v_date, 'd') IN (1, 7)
|
|
THEN
|
|
result := csu_find_prev_workingday (TRUNC (v_date) - 1 + 17 / 24);
|
|
ELSE
|
|
SELECT COUNT ( * )
|
|
INTO v_vrije_dagen
|
|
FROM mld_vrije_dagen
|
|
WHERE mld_vrije_dagen_datum = TRUNC (v_date);
|
|
|
|
IF v_vrije_dagen = 1
|
|
THEN
|
|
result := csu_find_prev_workingday (TRUNC (v_date) - 1 + 17 / 24);
|
|
ELSE
|
|
result := v_date;
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN result;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE FUNCTION csu_count_WorkHours (pdate_from IN DATE,
|
|
pdate_to IN DATE)
|
|
RETURN NUMBER
|
|
IS
|
|
eikdag NUMBER;
|
|
v_date_from DATE;
|
|
v_date_to DATE;
|
|
v_week NUMBER;
|
|
v_mod NUMBER;
|
|
v_holidays NUMBER;
|
|
v_beginuur NUMBER (5, 2);
|
|
v_einduur NUMBER (5, 2);
|
|
v_correction NUMBER;
|
|
BEGIN
|
|
-- Dit is een maandag, is dat volgens de huidige territory dag 2?
|
|
SELECT TO_NUMBER (TO_CHAR (TO_DATE ('01-01-2007', 'DD-MM-YYYY'), 'D'))
|
|
INTO eikdag
|
|
FROM DUAL;
|
|
|
|
IF eikdag <> 2
|
|
THEN
|
|
-- WE MOETEN met zondag=1 werken (geen nieuwe eis, wel duidelijker probleem)
|
|
raise_application_error (-20000, 'Facilitor: Invalid NLS_TERRITORY');
|
|
END IF;
|
|
|
|
v_date_from := csu_find_prev_workingday (pdate_from);
|
|
v_date_to := csu_find_next_workingday (pdate_to);
|
|
|
|
DBMS_OUTPUT.put_line (
|
|
'v_date_from:' || v_date_from || ' v_date_to:' || v_date_to);
|
|
|
|
-- Determine whole weeks (v_week) and remaining days (v_mod) between FROM and TO
|
|
v_week := TRUNC ( (TRUNC (v_date_to) - TRUNC (v_date_from)) / 7);
|
|
v_mod := MOD ( (TRUNC (v_date_to) - TRUNC (v_date_from)), 7);
|
|
|
|
-- Determine the registered holidays between FROM and TO
|
|
SELECT COUNT ( * )
|
|
INTO v_holidays
|
|
FROM MLD_VRIJE_DAGEN
|
|
WHERE MLD_VRIJE_DAGEN_DATUM BETWEEN v_date_from AND v_date_to;
|
|
|
|
v_beginuur := (TRUNC (v_date_from, 'MI') - TRUNC (v_date_from)) * 24;
|
|
v_einduur := (TRUNC (v_date_to, 'MI') - TRUNC (v_date_to)) * 24;
|
|
|
|
DBMS_OUTPUT.put_line (
|
|
'v_beginuur:' || v_beginuur || ' v_einduur:' || v_einduur);
|
|
|
|
IF v_einduur - v_beginuur > 0
|
|
THEN
|
|
v_correction := v_einduur - v_beginuur;
|
|
ELSE
|
|
v_correction := v_einduur - v_beginuur;
|
|
END IF;
|
|
|
|
DBMS_OUTPUT.put_line( 'v_week:'
|
|
|| v_week
|
|
|| ' v_mod:'
|
|
|| v_mod
|
|
|| ' v_holidays:'
|
|
|| v_holidays
|
|
|| ' v_correction: '
|
|
|| v_correction);
|
|
RETURN 9 * ( (5 * v_week) + v_mod - v_holidays) + v_correction;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
RETURN NULL;
|
|
END;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE csun_export_set_werkplek (
|
|
p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2
|
|
)
|
|
AS
|
|
BEGIN
|
|
-- toevoegen gebouwen
|
|
INSERT INTO alg_gebouw (alg_locatie_key,
|
|
alg_srtgebouw_key,
|
|
alg_gebouw_naam,
|
|
alg_gebouw_code)
|
|
SELECT alg_locatie_key,
|
|
40,
|
|
'Onbekend',
|
|
'O'
|
|
FROM alg_locatie l
|
|
WHERE NOT EXISTS (SELECT alg_locatie_key
|
|
FROM alg_gebouw g
|
|
WHERE g.alg_locatie_key = l.alg_locatie_key)
|
|
AND alg_locatie_omschrijving NOT LIKE 'CSU%';
|
|
|
|
-- toevoegen verdiepingen
|
|
INSERT INTO alg_verdieping (alg_gebouw_key,
|
|
alg_verdieping_omschrijving,
|
|
alg_verdieping_volgnr,
|
|
alg_verdieping_code)
|
|
SELECT alg_gebouw_key,
|
|
'Onbekend',
|
|
1,
|
|
'O'
|
|
FROM alg_gebouw g
|
|
WHERE NOT EXISTS (SELECT alg_gebouw_key
|
|
FROM alg_verdieping v
|
|
WHERE v.alg_gebouw_key = g.alg_gebouw_key);
|
|
|
|
-- toevoegen ruimten
|
|
INSERT INTO alg_ruimte (alg_verdieping_key,
|
|
alg_ruimte_nr,
|
|
alg_srtruimte_key,
|
|
alg_ruimte_omschrijving)
|
|
SELECT alg_verdieping_key,
|
|
'-',
|
|
1,
|
|
'Onbekend'
|
|
FROM alg_v_aanwezigverdieping v
|
|
WHERE NOT EXISTS (SELECT alg_verdieping_key
|
|
FROM alg_ruimte r
|
|
WHERE r.alg_verdieping_key = v.alg_verdieping_key);
|
|
|
|
-- toevoegen werkplekken
|
|
INSERT INTO prs_werkplek (prs_werkplek_volgnr, prs_werkplek_virtueel, prs_alg_ruimte_key)
|
|
SELECT 1, 0, alg_ruimte_key
|
|
FROM alg_v_aanwezigruimte r
|
|
WHERE NOT EXISTS
|
|
(SELECT wp.prs_alg_ruimte_key
|
|
FROM prs_v_aanwezigwerkplek wp
|
|
WHERE r.alg_ruimte_key = wp.prs_alg_ruimte_key
|
|
AND prs_werkplek_volgnr = 1);
|
|
|
|
-- toevoegen prs_perslidwerkplekken
|
|
INSERT INTO prs_perslidwerkplek (prs_perslid_key, prs_perslidwerkplek_bezetting, prs_werkplek_key)
|
|
SELECT prs_perslid_key, 100, prs_werkplek_key
|
|
FROM prs_v_aanwezigperslid p,
|
|
prs_afdeling a,
|
|
alg_onrgoedkenmerk aogk,
|
|
fac_usrdata ud,
|
|
prs_v_werkplek_gegevens wpg
|
|
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND a.prs_afdeling_verwijder IS NULL
|
|
AND a.prs_afdeling_naam IN
|
|
('Adecco',
|
|
'Manpower',
|
|
'Luba',
|
|
'Servex',
|
|
'USG PA',
|
|
'USG People')
|
|
AND fac.safe_to_number (aogk.alg_onrgoedkenmerk_waarde) =
|
|
fac_usrdata_key
|
|
AND aogk.alg_kenmerk_key = 1000
|
|
AND aogk.alg_onrgoed_key = wpg.alg_locatie_key
|
|
AND wpg.prs_werkplek_volgnr = 1
|
|
AND UPPER (prs_afdeling_naam) LIKE UPPER (fac_usrdata_code) || '%'
|
|
AND fac_usrtab_key = 1
|
|
AND EXISTS
|
|
(SELECT gg.prs_perslid_key
|
|
FROM fac_gebruikersgroep gg
|
|
WHERE fac_groep_key = 61
|
|
AND gg.prs_perslid_key = p.prs_perslid_key)
|
|
AND NOT EXISTS
|
|
(SELECT prs_perslidwerkplek_key
|
|
FROM prs_perslidwerkplek pwp
|
|
WHERE pwp.prs_perslid_key = p.prs_perslid_key
|
|
AND wpg.prs_werkplek_key = pwp.prs_werkplek_key);
|
|
END;
|
|
/
|
|
|
|
---- CSUN#25915: Portaal specials...
|
|
---- Drie Grafieken, scope op afdelingnivo1 (BU):
|
|
-- 1. openstaande meldingen per vakgroep.
|
|
-- 2. meldingen per maand.
|
|
-- 3. gemiddelde uitvoertijd per maand.
|
|
|
|
-- 1. openstaande meldingen per vakgroep.
|
|
CREATE OR REPLACE VIEW csun_v_graph_vakgroep_open
|
|
(
|
|
FCLT_XAS_,
|
|
FCLT_YAS_,
|
|
FCLT_URL,
|
|
FCLT_3D_AFDELING_KEY
|
|
)
|
|
AS
|
|
SELECT sd.ins_srtdiscipline_prefix || '-' || d.ins_discipline_omschrijving,
|
|
COUNT (d.ins_discipline_omschrijving),
|
|
'appl/mld/mld_search.asp?urole=fo' || '&' || 'autosearch=1' || '&' || 'disc_key_str=' || d.ins_discipline_key || '&' || 'dep_key=' || p.prs_afdeling_key,
|
|
p.prs_afdeling_key
|
|
FROM mld_melding m, mld_stdmelding std, ins_tab_discipline d, ins_srtdiscipline sd, prs_perslid p
|
|
WHERE m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
|
AND mld_melding_status IN (2, 3, 4, 7, 0) -- 2-ingevoerd, 3-ingezien, 4-geaccepteerd, 7-uitgegeven, 0-pending
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
GROUP BY d.ins_discipline_key, sd.ins_srtdiscipline_prefix || '-' || d.ins_discipline_omschrijving, p.prs_afdeling_key;
|
|
|
|
|
|
-- 2. meldingen per maand.
|
|
CREATE OR REPLACE VIEW csun_v_graph_meldingpm
|
|
(
|
|
FCLT_XAS_,
|
|
FCLT_YAS_,
|
|
VOLGORDE,
|
|
FCLT_3D_AFDELING_KEY
|
|
)
|
|
AS
|
|
SELECT DECODE (SUBSTR (TO_CHAR (mld_melding_datum, 'yyyymm'), 5),
|
|
'01', 'Januari',
|
|
'02', 'Februari',
|
|
'03', 'Maart',
|
|
'04', 'April',
|
|
'05', 'Mei',
|
|
'06', 'Juni',
|
|
'07', 'Juli',
|
|
'08', 'Augustus',
|
|
'09', 'September',
|
|
'10', 'Oktober',
|
|
'11', 'November',
|
|
'December'),
|
|
COUNT (d.ins_discipline_omschrijving),
|
|
TO_CHAR (mld_melding_datum, 'yyyymm'),
|
|
p.prs_afdeling_key
|
|
FROM mld_melding m, mld_stdmelding std, ins_tab_discipline d, prs_perslid p
|
|
WHERE mld_melding_datum BETWEEN ADD_MONTHS (
|
|
TO_DATE (
|
|
TO_CHAR (SYSDATE, 'yyyymm') || '01',
|
|
'yyyymmdd'),
|
|
-11)
|
|
AND SYSDATE
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
GROUP BY TO_CHAR (mld_melding_datum, 'yyyymm'),p.prs_afdeling_key;
|
|
|
|
-- 3. gemiddelde uitvoertijd per maand.
|
|
CREATE OR REPLACE VIEW csun_v_graph_uitvtijd_pm
|
|
(
|
|
FCLT_XAS_,
|
|
FCLT_YAS_,
|
|
VOLGORDE,
|
|
FCLT_3D_AFDELING_KEY
|
|
)
|
|
AS
|
|
SELECT DECODE (SUBSTR (TO_CHAR (mld_melding_datum, 'yyyymm'), 5),
|
|
'01', 'Januari',
|
|
'02', 'Februari',
|
|
'03', 'Maart',
|
|
'04', 'April',
|
|
'05', 'Mei',
|
|
'06', 'Juni',
|
|
'07', 'Juli',
|
|
'08', 'Augustus',
|
|
'09', 'September',
|
|
'10', 'Oktober',
|
|
'11', 'November',
|
|
'December'),
|
|
AVG(COALESCE (fac.gettrackingdate ('MLDREJ', m.mld_melding_key), COALESCE (fac.gettrackingdate ('MLDAFM', m.mld_melding_key), SYSDATE)) - m.mld_melding_datum),
|
|
TO_CHAR (mld_melding_datum, 'yyyymm'),
|
|
p.prs_afdeling_key
|
|
FROM mld_melding m, mld_stdmelding std, ins_tab_discipline d, prs_perslid p
|
|
WHERE mld_melding_datum BETWEEN ADD_MONTHS (
|
|
TO_DATE (
|
|
TO_CHAR (SYSDATE, 'yyyymm') || '01',
|
|
'yyyymmdd'),
|
|
-11)
|
|
AND SYSDATE
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
GROUP BY TO_CHAR (mld_melding_datum, 'yyyymm'),p.prs_afdeling_key;
|
|
|
|
|
|
|
|
BEGIN adm.systrackscript('$Workfile: csun.sql $', '$Revision$', 0); END;
|
|
/
|
|
BEGIN fac.registercustversion('CSUN', 7); END;
|
|
/
|
|
COMMIT;
|
|
spool off
|