2909 lines
109 KiB
SQL
2909 lines
109 KiB
SQL
--
|
||
-- $Id$
|
||
--
|
||
-- Script containing customer specific configuration sql statements for Asito Leisure
|
||
|
||
DEFINE thisfile = 'ASLE.SQL'
|
||
DEFINE dbuser = '^ASLE'
|
||
|
||
SET ECHO ON
|
||
SET DEFINE ON
|
||
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
||
COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT;
|
||
WHENEVER SQLERROR CONTINUE;
|
||
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
|
||
SPOOL &fcltlogfile
|
||
WHENEVER SQLERROR EXIT;
|
||
SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL;
|
||
WHENEVER SQLERROR CONTINUE;
|
||
---------------------------------------
|
||
PROMPT &fcltcusttxt
|
||
---------------------------------------
|
||
SET DEFINE OFF
|
||
|
||
------ payload begin ------
|
||
|
||
CREATE OR REPLACE VIEW asle_v_ruimte_gegevens
|
||
( alg_locatie_key,
|
||
alg_locatie_code,
|
||
alg_locatie_omschrijving,
|
||
alg_ruimte_key,
|
||
alg_ruimte_nr,
|
||
schoonmaaktijd_co,
|
||
schoonmaaktijd_so,
|
||
zone,
|
||
compartiment,
|
||
opmerking_sup
|
||
)
|
||
AS
|
||
SELECT r.alg_locatie_key,
|
||
r.alg_locatie_code,
|
||
r.alg_locatie_omschrijving,
|
||
r.alg_ruimte_key,
|
||
r.alg_ruimte_nr,
|
||
fac.safe_to_number (aogksc.alg_onrgoedkenmerk_waarde) co_schoonmaaktijd,
|
||
fac.safe_to_number (aogkss.alg_onrgoedkenmerk_waarde) so_schoonmaaktijd,
|
||
aogkz.alg_onrgoedkenmerk_waarde zone,
|
||
aogkc.alg_onrgoedkenmerk_waarde compartiment,
|
||
aogko.alg_onrgoedkenmerk_waarde opmerking_sup
|
||
FROM alg_v_ruimte_gegevens r,
|
||
(SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde FROM alg_onrgoedkenmerk WHERE alg_kenmerk_key = 1003) aogksc, -- CO schoonmaaktijd
|
||
(SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde FROM alg_onrgoedkenmerk WHERE alg_kenmerk_key = 1004) aogkss, -- SO schoonmaaktijd
|
||
(SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde FROM alg_onrgoedkenmerk WHERE alg_kenmerk_key = 1002) aogkz, -- Zone
|
||
(SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde FROM alg_onrgoedkenmerk WHERE alg_kenmerk_key = 1020) aogkc, -- Compartiment
|
||
(SELECT alg_onrgoed_key, alg_onrgoedkenmerk_waarde FROM alg_onrgoedkenmerk WHERE alg_kenmerk_key = 1040) aogko -- Opmerking supervisor
|
||
WHERE r.alg_ruimte_key = aogksc.alg_onrgoed_key(+)
|
||
AND r.alg_ruimte_key = aogkss.alg_onrgoed_key(+)
|
||
AND r.alg_ruimte_key = aogkz.alg_onrgoed_key(+)
|
||
AND r.alg_ruimte_key = aogkc.alg_onrgoed_key(+)
|
||
AND r.alg_ruimte_key = aogko.alg_onrgoed_key(+);
|
||
|
||
CREATE OR REPLACE VIEW asle_v_schoonmaak_bron
|
||
(
|
||
mld_melding_key,
|
||
mld_stdmelding_omschrijving,
|
||
mld_stdmelding_key,
|
||
mld_discipline_key,
|
||
mld_melding_einddatum,
|
||
mld_melding_afgerond,
|
||
mld_opdr_key,
|
||
mld_typeopdr_key,
|
||
mld_statusopdr_key,
|
||
alg_locatie_key,
|
||
alg_ruimte_key,
|
||
alg_ruimte_nr,
|
||
prs_perslid_naam,
|
||
prs_perslid_nr,
|
||
prs_perslid_key,
|
||
schoonmaaktijd_co,
|
||
schoonmaaktijd_so,
|
||
zone,
|
||
compartiment,
|
||
opmerking_sup,
|
||
plan_start,
|
||
plan_eind,
|
||
groep_naam
|
||
)
|
||
AS
|
||
SELECT m.mld_melding_key,
|
||
std.mld_stdmelding_omschrijving,
|
||
std.mld_stdmelding_key,
|
||
std.mld_ins_discipline_key,
|
||
m.mld_melding_einddatum,
|
||
m.mld_melding_afgerond,
|
||
o.mld_opdr_key,
|
||
o.mld_typeopdr_key,
|
||
mld_statusopdr_key,
|
||
r.alg_locatie_key,
|
||
r.alg_ruimte_key,
|
||
r.alg_ruimte_nr,
|
||
p.prs_perslid_naam,
|
||
p.prs_perslid_nr,
|
||
p.prs_perslid_key,
|
||
r.schoonmaaktijd_co,
|
||
r.schoonmaaktijd_so,
|
||
r.zone,
|
||
r.compartiment,
|
||
r.opmerking_sup,
|
||
(SELECT fac.safe_to_date (mld_kenmerkopdr_waarde,
|
||
'dd-mm-yyyy hh24:mi')
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE ko.mld_opdr_key = o.mld_opdr_key AND mld_kenmerk_key = 1)
|
||
starttijd,
|
||
(SELECT fac.safe_to_date (mld_kenmerkopdr_waarde,
|
||
'dd-mm-yyyy hh24:mi')
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE ko.mld_opdr_key = o.mld_opdr_key AND mld_kenmerk_key = 2)
|
||
eindtijd,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km
|
||
WHERE mld_kenmerkmelding_verwijder IS NULL
|
||
AND mld_kenmerk_key = 81 -- groep_naam
|
||
AND km.mld_melding_key = m.mld_melding_key) groep_naam
|
||
FROM mld_melding m,
|
||
mld_stdmelding std,
|
||
mld_opdr o,
|
||
prs_perslid p,
|
||
asle_v_ruimte_gegevens r
|
||
WHERE m.mld_stdmelding_key = std.mld_stdmelding_key
|
||
AND m.mld_melding_key = o.mld_melding_key(+)
|
||
AND o.mld_uitvoerende_keys = p.prs_perslid_key(+)
|
||
AND m.mld_alg_onroerendgoed_keys = r.alg_ruimte_key;
|
||
|
||
CREATE OR REPLACE VIEW asle_v_schoonmaak
|
||
(
|
||
mld_melding_key,
|
||
mld_stdmelding_omschrijving,
|
||
mld_stdmelding_key,
|
||
mld_melding_einddatum,
|
||
mld_opdr_key,
|
||
mld_statusopdr_key,
|
||
alg_locatie_key,
|
||
alg_ruimte_key,
|
||
alg_ruimte_nr,
|
||
prs_perslid_naam,
|
||
prs_perslid_nr,
|
||
prs_perslid_key,
|
||
schoonmaaktijd_co,
|
||
schoonmaaktijd_so,
|
||
zone,
|
||
plan_start,
|
||
plan_eind,
|
||
groep_naam
|
||
)
|
||
AS
|
||
SELECT mld_melding_key,
|
||
mld_stdmelding_omschrijving,
|
||
mld_stdmelding_key,
|
||
mld_melding_einddatum,
|
||
mld_opdr_key,
|
||
mld_statusopdr_key,
|
||
alg_locatie_key,
|
||
alg_ruimte_key,
|
||
alg_ruimte_nr,
|
||
prs_perslid_naam,
|
||
prs_perslid_nr,
|
||
prs_perslid_key,
|
||
schoonmaaktijd_co,
|
||
schoonmaaktijd_so,
|
||
zone,
|
||
plan_start,
|
||
plan_eind,
|
||
groep_naam
|
||
FROM asle_v_schoonmaak_bron
|
||
WHERE mld_stdmelding_omschrijving <> 'DND'
|
||
AND mld_stdmelding_omschrijving <> 'NoService'
|
||
AND mld_stdmelding_omschrijving <> 'Check'
|
||
AND mld_stdmelding_omschrijving <> 'Blocked' -- mld_discipline_key 21 = schoonmaak
|
||
AND mld_discipline_key = 21;
|
||
|
||
-- view voor gisteren, vandaag en morgen
|
||
CREATE OR REPLACE VIEW asle_v_arrival
|
||
(
|
||
vlucht,
|
||
tijdstip
|
||
)
|
||
AS
|
||
SELECT fac_usrdata_code,
|
||
TO_DATE (TO_CHAR (SYSDATE, 'yyyymmdd ') || fac_usrdata_omschr,
|
||
'yyyymmdd hh24:mi')
|
||
tijdstip
|
||
FROM fac_usrdata
|
||
WHERE fac_usrtab_key = 101
|
||
AND fac_usrdata_verwijder IS NULL
|
||
-- DECODE (TO_CHAR (SYSDATE, 'D'), 1, 121, 7, 121, 101) -- 121 weekend, 101 mdwdv
|
||
UNION ALL
|
||
SELECT fac_usrdata_code,
|
||
TO_DATE (TO_CHAR (SYSDATE - 1, 'yyyymmdd ') || fac_usrdata_omschr,
|
||
'yyyymmdd hh24:mi')
|
||
tijdstip
|
||
FROM fac_usrdata
|
||
WHERE fac_usrtab_key = 101
|
||
AND fac_usrdata_verwijder IS NULL
|
||
-- DECODE (TO_CHAR (SYSDATE - 1, 'D'), 1, 121, 7, 121, 101)
|
||
UNION ALL
|
||
SELECT fac_usrdata_code,
|
||
TO_DATE (TO_CHAR (SYSDATE + 1, 'yyyymmdd ') || fac_usrdata_omschr,
|
||
'yyyymmdd hh24:mi')
|
||
tijdstip
|
||
FROM fac_usrdata
|
||
WHERE fac_usrtab_key = 101
|
||
AND fac_usrdata_verwijder IS NULL;
|
||
-- DECODE (TO_CHAR (SYSDATE + 1, 'D'), 1, 121, 7, 121, 101);
|
||
|
||
CREATE OR REPLACE VIEW asle_v_work_list_cleaner
|
||
(
|
||
hide_f_timestamp,
|
||
mld_opdr_key,
|
||
fclt_3d_user_key,
|
||
mld_opdr_plandatum,
|
||
mld_opdr_einddatum,
|
||
kamernummer,
|
||
omschrijving
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (COALESCE (s.plan_start, s.mld_melding_einddatum),
|
||
'yyyymmddhh24mi'),
|
||
o.mld_opdr_key,
|
||
o.mld_uitvoerende_keys fclt_3d_user_key,
|
||
COALESCE (mld_opdr_plandatum, s.mld_melding_einddatum),
|
||
s.plan_start,
|
||
'K' || s.alg_ruimte_nr,
|
||
s.mld_stdmelding_omschrijving
|
||
|| DECODE (os.opm, NULL, NULL, ' ' || os.opm)
|
||
|| DECODE (o.mld_typeopdr_key, 101, ' (Herschoonmaak)', '')
|
||
|| DECODE (
|
||
o.mld_statusopdr_key,
|
||
8,
|
||
DECODE (mld_kenmerkopdr_waarde,
|
||
NULL, ' (gestart)',
|
||
' (gestopt)'),
|
||
'')
|
||
FROM mld_opdr o,
|
||
asle_v_schoonmaak_bron s,
|
||
(SELECT mld_opdr_key, mld_kenmerkopdr_waarde
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 61 AND mld_kenmerkopdr_verwijder IS NULL)
|
||
ks,
|
||
(SELECT alg_onrgoed_key alg_ruimte_key,
|
||
alg_onrgoedkenmerk_waarde opm
|
||
FROM alg_onrgoedkenmerk aogk
|
||
WHERE alg_onrgoedkenmerk_verwijder IS NULL
|
||
AND alg_kenmerk_key = 1080) os -- opmerking voor de schoonmaker
|
||
WHERE s.mld_statusopdr_key IN (3, 5, 8)
|
||
AND o.mld_opdr_key = s.mld_opdr_key
|
||
AND TRUNC (COALESCE (s.plan_start, o.mld_opdr_einddatum)) =
|
||
TRUNC (SYSDATE)
|
||
AND o.mld_opdr_key = ks.mld_opdr_key(+)
|
||
AND s.alg_ruimte_key = os.alg_ruimte_key(+);
|
||
|
||
CREATE OR REPLACE VIEW asle_v_work_list_supervisor
|
||
(
|
||
hide_f_timestamp,
|
||
naam,
|
||
ruimte,
|
||
type_schoonmaak,
|
||
opdr_status,
|
||
mld_opdr_key,
|
||
mld_melding_key,
|
||
track_key
|
||
)
|
||
AS
|
||
SELECT (volgorde
|
||
|| TO_CHAR (COALESCE (plan_eind, SYSDATE + 1), 'yyyymmddhh24mi'))
|
||
timestamp,
|
||
prs_perslid_naam,
|
||
alg_ruimte_nr,
|
||
type_schoonmaak,
|
||
status
|
||
|| ' - '
|
||
|| TO_CHAR (plan_eind, 'hh24:mi')
|
||
|| DECODE (opmerking_sup, NULL, NULL, ' (' || opmerking_sup || ')'),
|
||
mld_opdr_key,
|
||
mld_melding_key,
|
||
mld_melding_key || '-' || mld_opdr_key
|
||
FROM (SELECT TO_CHAR (mld_melding_einddatum, 'dd-mm-yyyy') datum,
|
||
(SELECT prs_perslid_voornaam
|
||
FROM prs_perslid p
|
||
WHERE p.prs_perslid_key = s.prs_perslid_key)
|
||
prs_perslid_naam,
|
||
'K' || rg.alg_ruimte_nr alg_ruimte_nr,
|
||
DECODE (mld_typeopdr_key,
|
||
101, 'Herschoonmaak',
|
||
mld_stdmelding_omschrijving)
|
||
type_schoonmaak,
|
||
rg.opmerking_sup,
|
||
rg.alg_locatie_omschrijving,
|
||
DECODE (
|
||
mld_statusopdr_omschrijving,
|
||
'Geaccepteerd',
|
||
DECODE (mld_kenmerkopdr_waarde, NULL, 'Gestart', 'Gestopt'),
|
||
'Toegekend',
|
||
'Gepland',
|
||
'Afgemeld',
|
||
'Klaar',
|
||
DECODE (mld_stdmelding_omschrijving,
|
||
'Check', 'Klaar',
|
||
''))
|
||
status,
|
||
DECODE (
|
||
mld_statusopdr_omschrijving,
|
||
'Geaccepteerd',
|
||
'2',
|
||
'Toegekend',
|
||
'3',
|
||
'Afgemeld',
|
||
'1',
|
||
DECODE (mld_stdmelding_omschrijving, 'Check', '0', '9'))
|
||
volgorde,
|
||
DECODE (
|
||
mld_statusopdr_omschrijving,
|
||
'Geaccepteerd',
|
||
mld.getopdrachtstatusdate (mld_opdr_key, 8) + (1 / 72), -- 20 min
|
||
'Afgemeld',
|
||
mld.getopdrachtstatusdate (mld_opdr_key,
|
||
mld_statusopdr_key),
|
||
COALESCE (plan_eind, SYSDATE))
|
||
plan_eind,
|
||
mld_opdr_key,
|
||
mld_melding_key
|
||
FROM (SELECT prs_perslid_naam,
|
||
COALESCE(plan_start, b.mld_melding_einddatum),
|
||
b.mld_melding_einddatum,
|
||
mld_stdmelding_omschrijving,
|
||
b.prs_perslid_key,
|
||
alg_ruimte_key,
|
||
b.mld_statusopdr_key,
|
||
mld_statusopdr_omschrijving,
|
||
plan_eind,
|
||
b.mld_opdr_key,
|
||
b.mld_melding_key,
|
||
b.mld_typeopdr_key,
|
||
ks.mld_kenmerkopdr_waarde
|
||
FROM asle_v_schoonmaak_bron b,
|
||
mld_statusopdr so,
|
||
mld_melding m,
|
||
(SELECT mld_opdr_key, mld_kenmerkopdr_waarde
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 61 AND mld_kenmerkopdr_verwijder IS NULL)
|
||
ks
|
||
WHERE b.mld_statusopdr_key = so.mld_statusopdr_key(+)
|
||
AND b.mld_melding_key = m.mld_melding_key
|
||
AND b.mld_opdr_key IS NOT NULL
|
||
AND mld_melding_status IN (2, 3, 4, 7)
|
||
AND b.mld_opdr_key = ks.mld_opdr_key(+)
|
||
AND TRUNC (b.mld_melding_einddatum) = TRUNC (SYSDATE))
|
||
s,
|
||
asle_v_ruimte_gegevens rg
|
||
WHERE rg.alg_ruimte_key = s.alg_ruimte_key);
|
||
|
||
-- Lijst met kamers die alleen maar gecontroleerd moeten worden.
|
||
CREATE OR REPLACE VIEW asle_v_work_list_chk_superv
|
||
(
|
||
ruimte,
|
||
type_schoonmaak,
|
||
mld_melding_key
|
||
)
|
||
AS
|
||
SELECT 'K' || alg_ruimte_nr, mld_stdmelding_omschrijving, m.mld_melding_key
|
||
FROM asle_v_schoonmaak_bron b, mld_melding m
|
||
WHERE m.mld_stdmelding_key = 62 -- Check
|
||
AND b.mld_melding_key = m.mld_melding_key
|
||
AND mld_melding_status in (2,4) -- nieuw, geaccepteerd
|
||
AND TRUNC (b.mld_melding_einddatum) = TRUNC (SYSDATE)
|
||
UNION ALL
|
||
SELECT 'K' || alg_ruimte_nr, mld_stdmelding_omschrijving, m.mld_melding_key
|
||
FROM asle_v_schoonmaak_bron b, mld_melding m
|
||
WHERE m.mld_stdmelding_key = 41 -- DND
|
||
AND b.mld_melding_key = m.mld_melding_key
|
||
AND mld_melding_status in (2,4) -- nieuw, geaccepteerd
|
||
AND TRUNC (b.mld_melding_einddatum) = TRUNC (SYSDATE);
|
||
|
||
CREATE OR REPLACE VIEW asle_v_work_list_coordinator
|
||
(
|
||
hide_f_timestamp,
|
||
mld_melding_key,
|
||
kamernr,
|
||
naam,
|
||
prs_perslid_key,
|
||
type_schoonmaak,
|
||
mld_melding_einddatum,
|
||
opdrachten,
|
||
opmerkingen,
|
||
opdrstatus
|
||
)
|
||
AS
|
||
SELECT MIN (opdr_status)
|
||
|| TO_CHAR (mld_melding_einddatum, 'yyyymmddhh24miss')
|
||
timestamp,
|
||
mld_melding_key,
|
||
alg_ruimte_nr,
|
||
(SELECT prs_perslid_voornaam
|
||
FROM prs_perslid p
|
||
WHERE p.prs_perslid_key = s.prs_perslid_key) naam,
|
||
s.prs_perslid_key,
|
||
mld_stdmelding_omschrijving,
|
||
mld_melding_einddatum,
|
||
listagg (mld_typeopdr_omschrijving, CHR (10))
|
||
WITHIN GROUP (ORDER BY mld_opdr_bedrijfopdr_volgnr)
|
||
AS opdracht,
|
||
listagg (found_clean || opm_herschoonmaak || DECODE(mld_opdr_opmerking, NULL, '' , ' (' || mld_opdr_opmerking || ')'),
|
||
CHR (10))
|
||
WITHIN GROUP (ORDER BY mld_opdr_bedrijfopdr_volgnr)
|
||
AS opmerking,
|
||
-- MIN (opdr_status),
|
||
DECODE (MAX (opdr_status),
|
||
1, 'Gecontroleerd',
|
||
2, 'Afgemeld',
|
||
3, 'Gestart',
|
||
4, 'Gepland',
|
||
'Onbekend')
|
||
FROM (SELECT s.*,
|
||
ot.mld_typeopdr_omschrijving,
|
||
mld_opdr_bedrijfopdr_volgnr,
|
||
mld_opdr_opmerking,
|
||
DECODE (o.mld_statusopdr_key, 9, 1, 6, 2, 8, 3, 5, 4, 0)
|
||
opdr_status,
|
||
DECODE ((SELECT mld_kenmerkopdr_waarde
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE ko.mld_opdr_key = o.mld_opdr_key
|
||
AND ko.mld_kenmerk_key = 21), 1, 'Found clean') found_clean,
|
||
COALESCE (
|
||
( SELECT LISTAGG (fac_usrdata_omschr, CHR (10))
|
||
WITHIN GROUP (ORDER BY mld_opdr_key)
|
||
FROM mld_kenmerkopdr ko, fac_usrdata ud
|
||
WHERE ko.mld_opdr_key = o.mld_opdr_key
|
||
AND fac.safe_to_number (mld_kenmerkopdr_waarde) =
|
||
ud.fac_usrdata_key
|
||
AND ud.fac_usrdata_verwijder IS NULL
|
||
AND ko.mld_kenmerk_key IN (101, 181)
|
||
GROUP BY mld_opdr_key),
|
||
'')
|
||
opm_herschoonmaak
|
||
FROM asle_v_schoonmaak_bron s, mld_opdr o, mld_typeopdr ot
|
||
WHERE TRUNC (mld_melding_einddatum) = TRUNC (SYSDATE)
|
||
AND o.mld_typeopdr_key = ot.mld_typeopdr_key
|
||
AND s.mld_opdr_key = o.mld_opdr_key(+)
|
||
AND s.mld_melding_afgerond <> 1) s
|
||
GROUP BY mld_melding_key,
|
||
prs_perslid_key,
|
||
mld_stdmelding_omschrijving,
|
||
mld_melding_einddatum,
|
||
alg_ruimte_nr;
|
||
|
||
CREATE OR REPLACE VIEW asle_v_rap_schoonmaak_sched
|
||
(
|
||
fclt_f_datum,
|
||
fclt_f_naam,
|
||
plan_start,
|
||
beschikbaar,
|
||
zone,
|
||
ruimte,
|
||
type_schoonmaak,
|
||
start_inzet,
|
||
locatie,
|
||
groep_naam,
|
||
alg_ruimte_key
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (mld_melding_einddatum, 'dd-mm-yyyy') datum,
|
||
prs_perslid_voornaam,
|
||
TO_CHAR (plan_start, 'hh24:mi'),
|
||
TO_CHAR (mld_melding_einddatum, 'hh24:mi'),
|
||
zone,
|
||
alg_ruimte_nr,
|
||
mld_stdmelding_omschrijving,
|
||
TO_CHAR (start_inzet, 'hh24:mi'),
|
||
(SELECT alg_locatie_omschrijving
|
||
FROM alg_locatie l
|
||
WHERE l.alg_locatie_key = w.alg_locatie_key),
|
||
groep_naam,
|
||
s.alg_ruimte_key
|
||
FROM asle_v_schoonmaak s, asle_imp_werkschema w, prs_perslid p
|
||
WHERE TRUNC (mld_melding_einddatum) > TRUNC (SYSDATE - 7)
|
||
AND TRUNC (mld_melding_einddatum) = TRUNC (start_inzet)
|
||
AND s.prs_perslid_key = w.prs_perslid_key
|
||
AND s.prs_perslid_key = p.prs_perslid_key
|
||
ORDER BY prs_perslid_voornaam, plan_start, zone;
|
||
|
||
CREATE OR REPLACE VIEW asle_v_rap_supervisor_sched
|
||
(
|
||
fclt_f_datum,
|
||
naam,
|
||
plan_start,
|
||
beschikbaar,
|
||
zone,
|
||
page,
|
||
compartiment,
|
||
ruimte,
|
||
type_schoonmaak,
|
||
start_inzet,
|
||
opmerking_sup,
|
||
locatie,
|
||
opdr_status,
|
||
groep_naam,
|
||
alg_ruimte_key
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (einddatum, 'dd-mm-yyyy') datum,
|
||
(SELECT prs_perslid_voornaam
|
||
FROM prs_perslid p
|
||
WHERE p.prs_perslid_key = s.prs_perslid_key)
|
||
prs_perslid_naam,
|
||
TO_CHAR (plan_start, 'hh24:mi') plan_start,
|
||
TO_CHAR (mld_melding_einddatum, 'hh24:mi') beschikbaar,
|
||
zone,
|
||
SUBSTR (compartiment, 1, 1),
|
||
compartiment,
|
||
alg_ruimte_nr,
|
||
mld_stdmelding_omschrijving type_schoonmaak,
|
||
(SELECT TO_CHAR (start_inzet, 'hh24:mi')
|
||
FROM asle_imp_werkschema w
|
||
WHERE TRUNC (s.mld_melding_einddatum) = TRUNC (w.start_inzet)
|
||
AND w.prs_perslid_key = s.prs_perslid_key)
|
||
start_inzet,
|
||
opmerking_sup,
|
||
alg_locatie_omschrijving,
|
||
mld_statusopdr_omschrijving status,
|
||
groep_naam,
|
||
alg_ruimte_key
|
||
FROM (SELECT *
|
||
FROM (SELECT prs_perslid_naam,
|
||
plan_start,
|
||
mld_melding_einddatum,
|
||
mld_stdmelding_omschrijving,
|
||
prs_perslid_key,
|
||
alg_ruimte_key alg_ruimte_keys,
|
||
b.mld_statusopdr_key,
|
||
mld_statusopdr_omschrijving,
|
||
groep_naam
|
||
FROM asle_v_schoonmaak_bron b, mld_statusopdr so
|
||
WHERE b.mld_statusopdr_key = so.mld_statusopdr_key(+)
|
||
AND TRUNC (mld_melding_einddatum) >
|
||
TRUNC (SYSDATE - 7)) s
|
||
RIGHT OUTER JOIN
|
||
(SELECT *
|
||
FROM asle_v_ruimte_gegevens rg,
|
||
(SELECT DISTINCT
|
||
TRUNC (mld_melding_einddatum) einddatum
|
||
FROM asle_v_schoonmaak_bron
|
||
WHERE TRUNC (mld_melding_einddatum) >
|
||
TRUNC (SYSDATE - 7))) rg
|
||
ON rg.alg_ruimte_key = s.alg_ruimte_keys
|
||
AND TRUNC (mld_melding_einddatum) = rg.einddatum) s;
|
||
|
||
-- View wordt gebruikt in rapport voor supervisor om op de iPad de status van de kamers voor vandaag op te vragen.
|
||
-- Door op de ruimte te klikken kan de supervisor vervolgens een nieuwe melding 'Check' op de kamer aanmaken.
|
||
CREATE OR REPLACE VIEW asle_v_rap_superv_sched_today (
|
||
naam,
|
||
plan_start,
|
||
beschikbaar,
|
||
zone,
|
||
page,
|
||
compartiment,
|
||
ruimte,
|
||
type_schoonmaak,
|
||
start_inzet,
|
||
opmerking_sup,
|
||
locatie,
|
||
opdr_status,
|
||
groep_naam,
|
||
alg_ruimte_key)
|
||
AS
|
||
SELECT naam,
|
||
plan_start,
|
||
beschikbaar,
|
||
zone,
|
||
page,
|
||
compartiment,
|
||
ruimte,
|
||
type_schoonmaak,
|
||
start_inzet,
|
||
opmerking_sup,
|
||
locatie,
|
||
opdr_status,
|
||
groep_naam,
|
||
alg_ruimte_key
|
||
FROM asle_v_rap_supervisor_sched
|
||
WHERE TO_DATE (fclt_f_datum, 'dd-mm-yyyy') = TRUNC(SYSDATE);
|
||
|
||
|
||
|
||
CREATE OR REPLACE VIEW asle_v_rap_leegloop
|
||
(
|
||
fclt_f_datum,
|
||
tijdstip,
|
||
beschikbaar,
|
||
schoonmaak_gestart
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (plan_start, 'dd-mm-yyyy') datum,
|
||
TO_CHAR (plan_start, 'hh24:mi') tijdstip,
|
||
(SELECT COUNT ( * )
|
||
FROM asle_v_schoonmaak e2
|
||
WHERE mld_melding_einddatum <= e1.plan_start
|
||
AND e2.alg_locatie_key = e1.alg_locatie_key
|
||
AND TRUNC (e1.plan_start) = TRUNC (e2.mld_melding_einddatum)
|
||
AND (mld_stdmelding_omschrijving = 'Checkout' or mld_stdmelding_omschrijving LIKE 'Stay%'))
|
||
aantal_kamers2,
|
||
(SELECT COUNT ( * )
|
||
FROM asle_v_schoonmaak e2
|
||
WHERE e2.plan_start <= e1.plan_start
|
||
AND e2.alg_locatie_key = e1.alg_locatie_key
|
||
AND TRUNC (e1.plan_start) = TRUNC (e2.plan_start))
|
||
aantal
|
||
FROM ( SELECT plan_start, alg_locatie_key
|
||
FROM asle_v_schoonmaak
|
||
WHERE TRUNC (plan_start) > TRUNC(SYSDATE-7)
|
||
GROUP BY plan_start, alg_locatie_key) e1;
|
||
|
||
CREATE OR REPLACE VIEW asle_v_rap_kamer_beschikbaar
|
||
(
|
||
fclt_f_datum,
|
||
tijdstip,
|
||
beschikbaar,
|
||
schoongemaakt
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (verw_start_schoonmaak, 'dd-mm-yyyy') datum,
|
||
TO_CHAR (verw_start_schoonmaak, 'hh24:mi') tijdstip,
|
||
(SELECT COUNT ( * )
|
||
FROM asle_imp_kamerschema s2
|
||
WHERE s2.alg_locatie_key = s.alg_locatie_key
|
||
AND s2.timestamp = s.timestamp
|
||
AND s2.verw_start_schoonmaak <= s.verw_start_schoonmaak)
|
||
kamers_beschikbaar,
|
||
(SELECT COUNT ( * )
|
||
FROM asle_v_schoonmaak e2
|
||
WHERE e2.plan_eind <= s.verw_start_schoonmaak
|
||
AND s.timestamp = TRUNC (e2.plan_eind))
|
||
checkouts_schoongemaakt
|
||
FROM ( SELECT verw_start_schoonmaak, timestamp, alg_locatie_key
|
||
FROM asle_imp_kamerschema s
|
||
WHERE verw_start_schoonmaak IS NOT NULL
|
||
GROUP BY verw_start_schoonmaak, timestamp, alg_locatie_key) s
|
||
ORDER BY verw_start_schoonmaak;
|
||
|
||
-- rapportage om het aantal zonewisselingen inzichtelijk te krijgen.
|
||
CREATE OR REPLACE VIEW asle_v_rap_zonewissel
|
||
(
|
||
fclt_f_datum,
|
||
naam,
|
||
tijd,
|
||
aantal
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (datum, 'dd-mm-yyyy') datum,
|
||
prs_perslid_naam_friendly,
|
||
tijd,
|
||
COUNT (tijd)
|
||
FROM (SELECT prs_perslid_naam_friendly, '0' tijd, TRUNC (tijdstip) datum
|
||
FROM asle_tmp_zone_wis w, prs_v_perslid_fullnames pf
|
||
WHERE w.prs_perslid_key = pf.prs_perslid_key
|
||
UNION ALL
|
||
SELECT ' Totaal',
|
||
TO_CHAR (tijdstip, 'hh24') tijd,
|
||
TRUNC (tijdstip) datum
|
||
FROM asle_tmp_zone_wis)
|
||
WHERE datum > SYSDATE - 7
|
||
GROUP BY prs_perslid_naam_friendly, tijd, TO_CHAR (datum, 'dd-mm-yyyy')
|
||
ORDER BY datum DESC, prs_perslid_naam_friendly, tijd
|
||
|
||
-- Rapport om het aantal aankomende gasten af te zetten tegen de schoongemaakte kamers
|
||
CREATE OR REPLACE VIEW asle_v_rap_arrival
|
||
(
|
||
fclt_f_datum,
|
||
tijdstip,
|
||
gasten,
|
||
kamer_beschikbaar
|
||
)
|
||
AS
|
||
SELECT TO_CHAR (tijdstip, 'dd-mm-yyyy') datum,
|
||
TO_CHAR (tijdstip, 'hh24:mi') tijdstip,
|
||
(SELECT (COUNT ( * ) * 14)
|
||
FROM asle_v_arrival a2
|
||
WHERE tijdstip <= a.tijdstip
|
||
AND TRUNC (a.tijdstip) = TRUNC (a2.tijdstip))
|
||
aantal_gasten,
|
||
(SELECT COUNT ( * ) + 32
|
||
FROM asle_v_schoonmaak s
|
||
WHERE greatest(s.plan_eind, (mld_melding_einddatum + 1 / (24 * 3) )) <= a.tijdstip
|
||
AND TRUNC (a.tijdstip) = TRUNC (s.plan_eind)
|
||
AND mld_stdmelding_omschrijving = 'Checkout')
|
||
aantal
|
||
FROM ( SELECT tijdstip
|
||
FROM asle_v_arrival
|
||
GROUP BY tijdstip) a;
|
||
|
||
-- Rapport om aantal binnenkomende gasten af te zetten tegen het aantal theoretisch
|
||
-- schoongemaakte kamers (= vertrek + 20 min)
|
||
CREATE OR REPLACE VIEW asle_v_rap_arrival2
|
||
(
|
||
fclt_f_datum,
|
||
tijdstip,
|
||
gasten,
|
||
kamer_beschikbaar,
|
||
verschil
|
||
)
|
||
AS
|
||
SELECT datum,
|
||
tijdstip,
|
||
aantal_gasten,
|
||
aantal,
|
||
aantal - aantal_gasten verschil
|
||
FROM (SELECT TO_CHAR (tijdstip, 'dd-mm-yyyy') datum,
|
||
TO_CHAR (tijdstip, 'hh24:mi') tijdstip,
|
||
(SELECT (COUNT ( * ) * 14)
|
||
FROM asle_v_arrival a2
|
||
WHERE tijdstip <= a.tijdstip
|
||
AND TRUNC (a.tijdstip) = TRUNC (a2.tijdstip))
|
||
aantal_gasten,
|
||
(SELECT COUNT ( * ) + 32
|
||
FROM asle_v_schoonmaak s
|
||
WHERE (s.mld_melding_einddatum + 1 / (24 * 3)) <=
|
||
a.tijdstip
|
||
AND TRUNC (a.tijdstip) = TRUNC (s.plan_eind))
|
||
aantal
|
||
FROM ( SELECT tijdstip
|
||
FROM asle_v_arrival
|
||
GROUP BY tijdstip) a);
|
||
|
||
-- rapport om schoonmakers te traceren. Een sterretje geeft aan dat de kamer al verlaten is.
|
||
CREATE OR REPLACE VIEW asle_v_rap_wie_zit_waar
|
||
(
|
||
naam,
|
||
kamer
|
||
)
|
||
AS
|
||
SELECT p.prs_perslid_voornaam,
|
||
alg_ruimte_nr
|
||
|| DECODE (
|
||
fac_srtnotificatie_key,
|
||
58, -- afgemeld
|
||
(SELECT ' --> ' || MAX (alg_ruimte_nr)
|
||
FROM asle_v_schoonmaak s
|
||
WHERE s.prs_perslid_key = p.prs_perslid_key
|
||
AND s.mld_statusopdr_key = 5 -- uitgegeven
|
||
AND NOT EXISTS
|
||
(SELECT mld_opdr_key
|
||
FROM asle_v_schoonmaak s2
|
||
WHERE s2.prs_perslid_key = p.prs_perslid_key
|
||
AND mld_statusopdr_key = 5 -- uitgegeven
|
||
AND COALESCE (s.plan_start, TRUNC (SYSDATE)) >
|
||
COALESCE (s2.plan_start,
|
||
TRUNC (SYSDATE))
|
||
AND s.mld_opdr_key <> s2.mld_opdr_key)))
|
||
|| ' ('
|
||
|| (SELECT COUNT ( * )
|
||
FROM asle_v_schoonmaak s, mld_opdr o2
|
||
WHERE TRUNC (mld_melding_einddatum) = TRUNC (SYSDATE)
|
||
AND s.prs_perslid_key = p.prs_perslid_key
|
||
AND o2.mld_opdr_key = s.mld_opdr_key
|
||
AND o.mld_typeopdr_key = 5 -- standaard
|
||
AND s.mld_statusopdr_key = 5)
|
||
|| '/'
|
||
|| (SELECT COUNT ( * )
|
||
FROM asle_v_schoonmaak s, mld_opdr o2
|
||
WHERE TRUNC (mld_melding_einddatum) = TRUNC (SYSDATE)
|
||
AND s.prs_perslid_key = p.prs_perslid_key
|
||
AND o2.mld_opdr_key = s.mld_opdr_key
|
||
AND o.mld_typeopdr_key = 5)
|
||
|| ')'
|
||
plaats
|
||
FROM ( SELECT lo.mld_uitvoerende_keys,
|
||
MAX (fac_tracking_key) fac_tracking_key
|
||
FROM fac_tracking t, mld_opdr lo -- laatste getrackte opdracht
|
||
WHERE t.fac_tracking_refkey = lo.mld_opdr_key
|
||
AND fac_srtnotificatie_key IN (65, 58) -- geaccepteerd, afgemeld
|
||
AND TRUNC (fac_tracking_datum) = TRUNC (SYSDATE)
|
||
GROUP BY lo.mld_uitvoerende_keys) tp,
|
||
prs_perslid p,
|
||
mld_opdr o,
|
||
fac_tracking t,
|
||
mld_melding m,
|
||
alg_ruimte r
|
||
WHERE tp.fac_tracking_key = t.fac_tracking_key
|
||
AND tp.mld_uitvoerende_keys = p.prs_perslid_key
|
||
AND t.fac_tracking_refkey = o.mld_opdr_key
|
||
AND o.mld_melding_key = m.mld_melding_key
|
||
AND m.mld_alg_onroerendgoed_keys = r.alg_ruimte_key
|
||
AND p.prs_perslid_key <> 4;
|
||
|
||
-- basisrapport voor schoonmaakresultaten incl schoonmaaktijd.
|
||
-- bevat de meldingen met opdrachten waar aan gewerkt is en
|
||
-- meldingen van DND waarvan door de gast is aangegeven dat ze niet schoongemaakt moeten worden.
|
||
CREATE OR REPLACE VIEW asle_v_rap_schoonmaak_result
|
||
(
|
||
naam,
|
||
datum,
|
||
typeschoonmaak,
|
||
srtruimte,
|
||
opdracht,
|
||
tijd,
|
||
volwassenen,
|
||
kinderen,
|
||
stop,
|
||
foundclean,
|
||
noservice,
|
||
herschoonmaak,
|
||
kamernr,
|
||
supervisor
|
||
)
|
||
AS
|
||
SELECT (SELECT prs_perslid_naam_friendly
|
||
FROM prs_v_perslid_fullnames_all pf
|
||
WHERE pf.prs_perslid_key = s.prs_perslid_key)
|
||
naam,
|
||
s.mld_melding_einddatum,
|
||
s.mld_stdmelding_omschrijving,
|
||
r.alg_srtruimte_omschrijving,
|
||
s.mld_melding_key || '/' || mld_opdr_bedrijfopdr_volgnr,
|
||
TRUNC( ( (SELECT MAX(fac_tracking_datum)
|
||
FROM fac_tracking
|
||
WHERE fac_tracking_refkey = o.mld_opdr_key
|
||
AND fac_srtnotificatie_key = 58) -- afgemeld
|
||
- (SELECT MAX(fac_tracking_datum)
|
||
FROM fac_tracking
|
||
WHERE fac_tracking_refkey = o.mld_opdr_key
|
||
AND fac_srtnotificatie_key = 65)) -- geaccepteerd
|
||
* 24
|
||
* 60)
|
||
tijd,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km WHERE mld_kenmerk_key = 161
|
||
AND mld_kenmerkmelding_verwijder IS NULL
|
||
AND km.mld_melding_key = o.mld_melding_key) volwassenen,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km WHERE mld_kenmerk_key = 162
|
||
AND mld_kenmerkmelding_verwijder IS NULL
|
||
AND km.mld_melding_key = o.mld_melding_key) kinderen,
|
||
(SELECT COUNT ( * )
|
||
FROM fac_tracking t
|
||
WHERE fac_tracking_oms LIKE '%Stopgezet%'
|
||
AND t.fac_tracking_refkey = o.mld_opdr_key)
|
||
stop,
|
||
COALESCE (
|
||
(SELECT SUM (mld_kenmerkopdr_waarde)
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 21
|
||
AND ko.mld_kenmerkopdr_verwijder IS NULL
|
||
AND ko.mld_opdr_key = s.mld_opdr_key),
|
||
0)
|
||
foundclean,
|
||
COALESCE (
|
||
(SELECT SUM (mld_kenmerkopdr_waarde)
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 141
|
||
AND ko.mld_kenmerkopdr_verwijder IS NULL
|
||
AND ko.mld_opdr_key = s.mld_opdr_key),
|
||
0)
|
||
noservice,
|
||
DECODE(o.mld_typeopdr_key, 101, 1, 0) herschoonmaak,
|
||
r.alg_ruimte_nr,
|
||
(SELECT prs_perslid_naam_friendly
|
||
FROM prs_v_perslid_fullnames_all pf
|
||
WHERE pf.prs_perslid_key = FAC.gettrackinguserkey ('ORDAFR', s.mld_opdr_key)) supervisor
|
||
FROM mld_opdr o, asle_v_schoonmaak s, alg_v_ruimte_gegevens r
|
||
WHERE o.mld_opdr_key = s.mld_opdr_key
|
||
AND s.alg_ruimte_key = r.alg_ruimte_key
|
||
UNION ALL
|
||
SELECT NULL naam,
|
||
mld_melding_einddatum datum,
|
||
'DND' typeschoonmaak,
|
||
r.alg_srtruimte_omschrijving srtruimte,
|
||
NULL opdracht,
|
||
NULL tijd,
|
||
NULL volwassenen,
|
||
NULL kinderen,
|
||
0 stop,
|
||
0 foundclean,
|
||
1 noservice,
|
||
0 herschoonmaak,
|
||
r.alg_ruimte_nr,
|
||
(SELECT prs_perslid_naam_friendly
|
||
FROM prs_v_perslid_fullnames_all pf
|
||
WHERE pf.prs_perslid_key = FAC.gettrackinguserkey ('ORDAFR', s.mld_opdr_key)) supervisor
|
||
FROM asle_v_schoonmaak_bron s, alg_v_ruimte_gegevens r
|
||
WHERE s.alg_ruimte_key = r.alg_ruimte_key
|
||
AND s.mld_stdmelding_omschrijving = 'DND'
|
||
AND s.mld_opdr_key IS NOT NULL;
|
||
|
||
|
||
-- View voor John om data uit FACILITOR te analyseren.
|
||
CREATE OR REPLACE VIEW asle_v_rap_schoonm_result_det
|
||
(
|
||
naam,
|
||
nummer,
|
||
typeschoonmaak,
|
||
kamernr,
|
||
zone,
|
||
srtruimte,
|
||
typebed,
|
||
roken,
|
||
groepnaam,
|
||
beschikbaar_jaar,
|
||
beschikbaar_maand,
|
||
beschikbaar_dag,
|
||
beschikbaar_uur,
|
||
beschikbaar_min,
|
||
beschikbaar_sec,
|
||
volwassenen,
|
||
kinderen,
|
||
opdracht,
|
||
plan_start_jaar,
|
||
plan_start_maand,
|
||
plan_start_dag,
|
||
plan_start_uur,
|
||
plan_start_min,
|
||
plan_start_sec,
|
||
plan_eind_jaar,
|
||
plan_eind_maand,
|
||
plan_eind_dag,
|
||
plan_eind_uur,
|
||
plan_eind_min,
|
||
plan_eind_sec,
|
||
gestart_jaar,
|
||
gestart_maand,
|
||
gestart_dag,
|
||
gestart_uur,
|
||
gestart_min,
|
||
gestart_sec,
|
||
gereed_jaar,
|
||
gereed_maand,
|
||
gereed_dag,
|
||
gereed_uur,
|
||
gereed_min,
|
||
gereed_sec,
|
||
checked_jaar,
|
||
checked_maand,
|
||
checked_dag,
|
||
checked_uur,
|
||
checked_min,
|
||
checked_sec,
|
||
stop,
|
||
foundclean,
|
||
noservice
|
||
)
|
||
AS
|
||
SELECT (SELECT prs_perslid_naam_friendly
|
||
FROM prs_v_perslid_fullnames_all pf
|
||
WHERE pf.prs_perslid_key = s.prs_perslid_key)
|
||
naam,
|
||
s.prs_perslid_nr,
|
||
s.mld_stdmelding_omschrijving,
|
||
r.alg_ruimte_nr,
|
||
s.zone,
|
||
r.alg_srtruimte_omschrijving,
|
||
(SELECT fac_usrdata_omschr
|
||
FROM fac_usrdata ud, alg_onrgoedkenmerk aogk
|
||
WHERE aogk.alg_onrgoed_key = r.alg_ruimte_key
|
||
AND aogk.alg_kenmerk_key = 1000
|
||
AND fac.safe_to_number (alg_onrgoedkenmerk_waarde) =
|
||
fac_usrdata_key)
|
||
type_bed,
|
||
(SELECT alg_onrgoedkenmerk_waarde
|
||
FROM alg_onrgoedkenmerk aogk
|
||
WHERE aogk.alg_onrgoed_key = r.alg_ruimte_key
|
||
AND aogk.alg_kenmerk_key = 1001
|
||
AND alg_onrgoedkenmerk_verwijder IS NULL)
|
||
roken,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km
|
||
WHERE mld_kenmerk_key = 81
|
||
AND mld_kenmerkmelding_verwijder IS NULL
|
||
AND km.mld_melding_key = o.mld_melding_key)
|
||
groepnaam,
|
||
TO_CHAR (s.mld_melding_einddatum, 'yyyy') beschikbaar_jaar,
|
||
TO_CHAR (s.mld_melding_einddatum, 'mm') beschikbaar_maand,
|
||
TO_CHAR (s.mld_melding_einddatum, 'dd') beschikbaar_dag,
|
||
TO_CHAR (s.mld_melding_einddatum, 'hh24') beschikbaar_uur,
|
||
TO_CHAR (s.mld_melding_einddatum, 'mi') beschikbaar_minuut,
|
||
TO_CHAR (s.mld_melding_einddatum, 'ss') beschikbaar_seconde,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km
|
||
WHERE mld_kenmerk_key = 161
|
||
AND mld_kenmerkmelding_verwijder IS NULL
|
||
AND km.mld_melding_key = o.mld_melding_key)
|
||
volwassenen,
|
||
(SELECT mld_kenmerkmelding_waarde
|
||
FROM mld_kenmerkmelding km
|
||
WHERE mld_kenmerk_key = 162
|
||
AND mld_kenmerkmelding_verwijder IS NULL
|
||
AND km.mld_melding_key = o.mld_melding_key)
|
||
kinderen,
|
||
s.mld_melding_key || '/' || mld_opdr_bedrijfopdr_volgnr,
|
||
TO_CHAR (s.plan_start, 'yyyy') plan_start_jaar,
|
||
TO_CHAR (s.plan_start, 'mm') plan_start_maand,
|
||
TO_CHAR (s.plan_start, 'dd') plan_start_dag,
|
||
TO_CHAR (s.plan_start, 'hh24') plan_start_uur,
|
||
TO_CHAR (s.plan_start, 'mi') plan_start_minuut,
|
||
TO_CHAR (s.plan_start, 'ss') plan_start_seconde,
|
||
TO_CHAR (s.plan_eind, 'yyyy') plan_eind_jaar,
|
||
TO_CHAR (s.plan_eind, 'mm') plan_eind_maand,
|
||
TO_CHAR (s.plan_eind, 'dd') plan_eind_dag,
|
||
TO_CHAR (s.plan_eind, 'hh24') plan_eind_uur,
|
||
TO_CHAR (s.plan_eind, 'mi') plan_eind_minuut,
|
||
TO_CHAR (s.plan_eind, 'ss') plan_eind_seconde,
|
||
TO_CHAR (st.fac_tracking_datum, 'yyyy') gestart_jaar,
|
||
TO_CHAR (st.fac_tracking_datum, 'mm') gestart_maand,
|
||
TO_CHAR (st.fac_tracking_datum, 'dd') gestart_dag,
|
||
TO_CHAR (st.fac_tracking_datum, 'hh24') gestart_uur,
|
||
TO_CHAR (st.fac_tracking_datum, 'mi') gestart_minuut,
|
||
TO_CHAR (st.fac_tracking_datum, 'ss') gestart_seconde,
|
||
TO_CHAR (afg.fac_tracking_datum, 'yyyy') afgemeld_jaar,
|
||
TO_CHAR (afg.fac_tracking_datum, 'mm') afgemeld_maand,
|
||
TO_CHAR (afg.fac_tracking_datum, 'dd') afgemeld_dag,
|
||
TO_CHAR (afg.fac_tracking_datum, 'hh24') afgemeld_uur,
|
||
TO_CHAR (afg.fac_tracking_datum, 'mi') afgemeld_minuut,
|
||
TO_CHAR (afg.fac_tracking_datum, 'ss') afgemeld_seconde,
|
||
TO_CHAR (chk.fac_tracking_datum, 'yyyy') check_jaar,
|
||
TO_CHAR (chk.fac_tracking_datum, 'mm') check_maand,
|
||
TO_CHAR (chk.fac_tracking_datum, 'dd') check_dag,
|
||
TO_CHAR (chk.fac_tracking_datum, 'hh24') check_uur,
|
||
TO_CHAR (chk.fac_tracking_datum, 'mi') check_minuut,
|
||
TO_CHAR (chk.fac_tracking_datum, 'ss') check_seconde,
|
||
(SELECT COUNT ( * )
|
||
FROM fac_tracking t
|
||
WHERE fac_tracking_oms LIKE '%Stopgezet%'
|
||
AND t.fac_tracking_refkey = o.mld_opdr_key)
|
||
stop,
|
||
COALESCE (
|
||
(SELECT SUM (mld_kenmerkopdr_waarde)
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 21
|
||
AND ko.mld_opdr_key = s.mld_opdr_key),
|
||
0)
|
||
foundclean,
|
||
COALESCE (
|
||
(SELECT SUM (mld_kenmerkopdr_waarde)
|
||
FROM mld_kenmerkopdr ko
|
||
WHERE mld_kenmerk_key = 141
|
||
AND ko.mld_opdr_key = s.mld_opdr_key),
|
||
0)
|
||
noservice
|
||
FROM mld_opdr o,
|
||
asle_v_schoonmaak s,
|
||
alg_v_ruimte_gegevens r,
|
||
(SELECT fac_tracking_refkey mld_opdr_key, fac_tracking_datum
|
||
FROM fac_tracking
|
||
WHERE fac_srtnotificatie_key = 58) afg,
|
||
(SELECT fac_tracking_refkey mld_opdr_key, fac_tracking_datum
|
||
FROM fac_tracking
|
||
WHERE fac_srtnotificatie_key = 65) st,
|
||
(SELECT fac_tracking_refkey mld_opdr_key, fac_tracking_datum
|
||
FROM fac_tracking
|
||
WHERE fac_srtnotificatie_key = 70) chk
|
||
WHERE o.mld_opdr_key = s.mld_opdr_key
|
||
AND s.alg_ruimte_key = r.alg_ruimte_key
|
||
AND o.mld_opdr_key = st.mld_opdr_key(+)
|
||
AND o.mld_opdr_key = afg.mld_opdr_key(+)
|
||
AND o.mld_opdr_key = chk.mld_opdr_key(+)
|
||
AND s.mld_melding_einddatum > TRUNC(add_months(SYSDATE, -6));
|
||
|
||
CREATE OR REPLACE PACKAGE ASLE
|
||
AS
|
||
PROCEDURE init_cleaning (p_locatie_key IN NUMBER, p_date IN DATE);
|
||
|
||
FUNCTION number_seq_rooms (p_zone IN VARCHAR2,
|
||
p_last_clean IN DATE,
|
||
p_locatie_key IN NUMBER,
|
||
p_efficiency IN NUMBER,
|
||
p_tolerantie IN NUMBER)
|
||
RETURN NUMBER;
|
||
|
||
FUNCTION calc_zone_costs (p_alg_locatie_key NUMBER,
|
||
p_van VARCHAR2,
|
||
p_naar VARCHAR2)
|
||
RETURN NUMBER;
|
||
|
||
FUNCTION find_next_room (p_import_key IN NUMBER,
|
||
p_locatie_key IN NUMBER,
|
||
p_date IN DATE,
|
||
p_perslid_key IN NUMBER,
|
||
p_tolerantie IN NUMBER)
|
||
RETURN NUMBER;
|
||
|
||
PROCEDURE schedule_stats (p_import_key IN NUMBER,
|
||
p_locatie_key IN NUMBER,
|
||
p_date IN DATE);
|
||
|
||
PROCEDURE estimate_workload (p_locatie_key IN NUMBER, p_date IN DATE);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PACKAGE BODY ASLE
|
||
AS
|
||
PROCEDURE init_cleaning (p_locatie_key IN NUMBER, p_date IN DATE)
|
||
AS
|
||
CURSOR c
|
||
IS SELECT prs_perslid_key, start_inzet
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND min_uren IS NULL
|
||
AND TRUNC (start_inzet) = p_date
|
||
ORDER BY efficiency, start_inzet;
|
||
|
||
CURSOR c_opdr_prs
|
||
IS SELECT prs_perslid_key, count(mld_opdr_key) aantal
|
||
FROM asle_v_schoonmaak
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (mld_melding_einddatum) = p_date
|
||
AND mld_opdr_key IS NOT NULL
|
||
GROUP BY prs_perslid_key;
|
||
|
||
CURSOR c_opdr(c_perslid_key NUMBER)
|
||
IS SELECT *
|
||
FROM asle_v_schoonmaak
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (mld_melding_einddatum) = p_date
|
||
AND mld_opdr_key IS NOT NULL
|
||
AND prs_perslid_key = c_perslid_key
|
||
ORDER BY plan_eind DESC;
|
||
|
||
v_rooms_tb_cleaned NUMBER;
|
||
v_rooms_remaining NUMBER;
|
||
v_rooms_fix_cnt NUMBER; -- vaste afspraken met medewerkers
|
||
v_empl_wo_cnt NUMBER; -- medewerkers zonder vast contract
|
||
v_count NUMBER;
|
||
BEGIN
|
||
UPDATE asle_imp_werkschema
|
||
SET min_num_clean = NULL,
|
||
last_clean = start_inzet,
|
||
num_clean = NULL,
|
||
last_zone = NULL,
|
||
efficiency = 1 / COALESCE (
|
||
(SELECT fac.safe_to_number (prs_kenmerklink_waarde)
|
||
FROM prs_kenmerklink
|
||
WHERE prs_link_key = prs_perslid_key
|
||
AND prs_kenmerk_key = 1020),
|
||
1)
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date;
|
||
|
||
SELECT COUNT ( * )
|
||
INTO v_rooms_tb_cleaned
|
||
FROM asle_imp_kamerschema
|
||
WHERE type_schoonmaak = 'Checkout' OR type_schoonmaak LIKE 'Stay%'
|
||
AND alg_locatie_key = p_locatie_key
|
||
AND clean_date = p_date;
|
||
|
||
DBMS_OUTPUT.put_line ('v_rooms_tb_cleaned:' || v_rooms_tb_cleaned);
|
||
|
||
UPDATE asle_imp_werkschema
|
||
SET min_num_clean = TRUNC (min_uren * 3 * efficiency)
|
||
WHERE alg_locatie_key = p_locatie_key AND TRUNC (start_inzet) = p_date;
|
||
|
||
SELECT SUM (COALESCE(min_num_clean, 0))
|
||
INTO v_rooms_fix_cnt
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key AND TRUNC (start_inzet) = p_date;
|
||
|
||
DBMS_OUTPUT.put_line ('v_rooms_fix_cnt:' || v_rooms_fix_cnt);
|
||
|
||
SELECT SUM(efficiency)
|
||
INTO v_empl_wo_cnt
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND min_num_clean IS NULL
|
||
AND TRUNC (start_inzet) = p_date;
|
||
|
||
DBMS_OUTPUT.put_line ('v_empl_wo_cnt:' || v_empl_wo_cnt);
|
||
DBMS_OUTPUT.put_line('TRUNC( (v_rooms_tb_cleaned - v_rooms_fix_cnt) / v_empl_wo_cnt):'
|
||
|| TRUNC( (v_rooms_tb_cleaned - v_rooms_fix_cnt)
|
||
/ v_empl_wo_cnt));
|
||
|
||
UPDATE asle_imp_werkschema
|
||
SET min_num_clean =
|
||
TRUNC ( (
|
||
(v_rooms_tb_cleaned - v_rooms_fix_cnt) / v_empl_wo_cnt) * efficiency)
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND min_num_clean IS NULL
|
||
AND TRUNC (start_inzet) = p_date;
|
||
|
||
SELECT v_rooms_tb_cleaned - SUM(COALESCE(min_num_clean,0))
|
||
INTO v_rooms_remaining
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date;
|
||
|
||
DBMS_OUTPUT.put_line ('v_rooms_remaining:' || v_rooms_remaining);
|
||
|
||
v_count := 0;
|
||
FOR rec IN c
|
||
LOOP
|
||
IF v_count >= v_rooms_remaining
|
||
THEN
|
||
EXIT;
|
||
END IF;
|
||
|
||
UPDATE asle_imp_werkschema
|
||
SET num_clean = 1
|
||
WHERE prs_perslid_key = rec.prs_perslid_key
|
||
AND TRUNC(start_inzet) = p_date;
|
||
|
||
DBMS_OUTPUT.put_line ('Kamer toegevoegd aan :' || rec.prs_perslid_key);
|
||
|
||
v_count := v_count + 1;
|
||
END LOOP;
|
||
|
||
UPDATE asle_imp_werkschema
|
||
SET min_num_clean = min_num_clean + num_clean,
|
||
num_clean = NULL
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND num_clean = 1
|
||
AND TRUNC (start_inzet) = p_date;
|
||
|
||
|
||
-- markeer de laatste zone, schoonmaaktijd en aantal gepoetste kamers in schoonmaaktabel.
|
||
FOR rec IN c_opdr_prs
|
||
LOOP
|
||
FOR rec1 IN c_opdr(rec.prs_perslid_key)
|
||
LOOP
|
||
UPDATE asle_imp_werkschema
|
||
SET num_clean = rec.aantal,
|
||
last_clean = rec1.plan_eind,
|
||
last_zone = rec1.zone
|
||
WHERE prs_perslid_key = rec.prs_perslid_key
|
||
AND TRUNC(start_inzet) = p_date;
|
||
EXIT;
|
||
END LOOP;
|
||
END LOOP;
|
||
|
||
-- bepaal het aantal schoongemaakte kamers in de tijd gezien.
|
||
ASLE.estimate_workload (p_locatie_key, p_date);
|
||
END;
|
||
|
||
FUNCTION number_seq_rooms (p_zone IN VARCHAR2,
|
||
p_last_clean IN DATE,
|
||
p_locatie_key IN NUMBER,
|
||
p_efficiency IN NUMBER,
|
||
p_tolerantie IN NUMBER)
|
||
RETURN NUMBER
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT *
|
||
FROM asle_t_schoonmaak s
|
||
WHERE s.alg_locatie_key = p_locatie_key
|
||
AND s.zone = p_zone
|
||
AND s.mld_opdr_key IS NULL
|
||
ORDER BY mld_melding_einddatum;
|
||
|
||
v_count NUMBER;
|
||
v_last_clean DATE;
|
||
v_start_clean DATE;
|
||
v_schoonmaaktijd NUMBER;
|
||
BEGIN
|
||
v_last_clean := p_last_clean;
|
||
v_count := 0;
|
||
|
||
FOR rec IN c
|
||
LOOP
|
||
BEGIN
|
||
IF rec.mld_melding_einddatum <= (v_last_clean + (p_tolerantie / (24*60)))
|
||
THEN
|
||
IF UPPER(rec.mld_stdmelding_omschrijving) = 'CHECKOUT'
|
||
THEN
|
||
v_schoonmaaktijd := rec.schoonmaaktijd_co;
|
||
ELSE
|
||
v_schoonmaaktijd := rec.schoonmaaktijd_so;
|
||
END IF;
|
||
v_start_clean := v_last_clean;
|
||
v_last_clean := v_last_clean + (v_schoonmaaktijd * p_efficiency) / (24 * 60);
|
||
|
||
IF TO_NUMBER (TO_CHAR (v_start_clean, 'hh24')) < 12 -- start voor 12 uur
|
||
AND TO_NUMBER (TO_CHAR (v_last_clean, 'hh24')) >= 12 -- einde na 12 uur
|
||
THEN
|
||
v_last_clean := v_last_clean + 0.5 / (24); -- lunchpauze toevoegen.
|
||
END IF;
|
||
|
||
v_count := v_count + 1;
|
||
ELSE
|
||
EXIT;
|
||
END IF;
|
||
END;
|
||
END LOOP;
|
||
|
||
RETURN v_count;
|
||
END;
|
||
|
||
FUNCTION calc_zone_costs (p_alg_locatie_key NUMBER,
|
||
p_van VARCHAR2,
|
||
p_naar VARCHAR2)
|
||
RETURN NUMBER
|
||
AS
|
||
v_costs NUMBER (2);
|
||
BEGIN
|
||
IF p_van = '-1' OR p_van = p_naar
|
||
THEN
|
||
RETURN (0);
|
||
END IF;
|
||
|
||
SELECT MAX (u.fac_usrdata_prijs)
|
||
INTO v_costs
|
||
FROM fac_usrdata u, alg_locatie l, fac_usrdata ul
|
||
WHERE l.alg_locatie_key = p_alg_locatie_key
|
||
AND l.alg_locatie_code = ul.fac_usrdata_code
|
||
AND u.fac_usrdata_parentkey = ul.fac_usrdata_key
|
||
AND u.fac_usrtab_key = 21
|
||
AND u.fac_usrdata_verwijder IS NULL
|
||
AND ul.fac_usrtab_key = 41
|
||
AND ul.fac_usrdata_verwijder IS NULL
|
||
AND (u.fac_usrdata_code = p_van || '-' || p_naar
|
||
OR u.fac_usrdata_code = p_naar || '-' || p_van);
|
||
|
||
RETURN v_costs;
|
||
END;
|
||
|
||
|
||
|
||
FUNCTION find_next_room (p_import_key IN NUMBER,
|
||
p_locatie_key IN NUMBER,
|
||
p_date IN DATE,
|
||
p_perslid_key IN NUMBER,
|
||
p_tolerantie IN NUMBER)
|
||
RETURN NUMBER
|
||
AS
|
||
CURSOR c_find_room (
|
||
c_last_clean DATE,
|
||
c_zone VARCHAR2,
|
||
c_mode VARCHAR2, -- Match, DontCare
|
||
c_tolerantie_plus NUMBER) -- Extra tolerantie als ik van verdieping moet wisselen.
|
||
IS
|
||
SELECT *
|
||
FROM (SELECT s.*,
|
||
DECODE (c_zone, s.zone, 0, 1) costs, -- 0: ik was al aan het werk in deze zone
|
||
(SELECT COUNT ( * )
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date
|
||
AND COALESCE (num_clean, 0) <= min_num_clean
|
||
AND COALESCE (last_zone, '-1') = s.zone)
|
||
aantal -- aantal personen die al werkzaam zijn op deze verdieping
|
||
FROM asle_t_schoonmaak s
|
||
WHERE s.alg_locatie_key = p_locatie_key
|
||
AND ( (s.zone = c_zone AND s.mld_melding_einddatum <= (c_last_clean + ((p_tolerantie + c_tolerantie_plus)/ (24*60))))
|
||
OR c_mode = 'DontCare') -- als er geen aansluitende kamer gevonden kan worden is een zoneovergang ook niet meer belangrijk.
|
||
AND s.mld_opdr_key IS NULL)
|
||
ORDER BY mld_melding_einddatum, costs, aantal;
|
||
|
||
CURSOR c_find_zone (c_last_clean DATE,
|
||
c_efficiency NUMBER,
|
||
c_last_zone VARCHAR2,
|
||
c_mode NUMBER)
|
||
IS
|
||
SELECT zone,
|
||
ASLE.number_seq_rooms (zone,
|
||
c_last_clean,
|
||
p_locatie_key,
|
||
c_efficiency,
|
||
p_tolerantie)
|
||
number_rooms,
|
||
ASLE.calc_zone_costs (p_locatie_key,
|
||
c_last_zone,
|
||
zone)
|
||
costs,
|
||
(SELECT count(*)
|
||
FROM asle_imp_werkschema w
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date
|
||
AND COALESCE (num_clean, 0) < min_num_clean
|
||
AND w.last_zone = zone) aantal_mdw
|
||
FROM ( SELECT zone
|
||
FROM asle_t_schoonmaak s
|
||
WHERE s.alg_locatie_key = p_locatie_key
|
||
AND ( (c_mode = 0 -- zonder dat er iemand in die zone werkt
|
||
AND s.zone NOT IN
|
||
(SELECT COALESCE (last_zone, '-1')
|
||
FROM asle_imp_werkschema
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date
|
||
AND COALESCE (num_clean, 0) <
|
||
min_num_clean) -- nog niet klaar met werken
|
||
)
|
||
OR c_mode = 1) -- ook als er al iemand werkt.
|
||
GROUP BY s.zone)
|
||
ORDER BY number_rooms / (1+aantal_mdw) DESC, costs;
|
||
|
||
|
||
v_efficiency NUMBER; -- efficientie van de medewekers. Kenmerk bij persoon???????
|
||
v_zone asle_imp_werkschema.last_zone%TYPE;
|
||
v_found_mld mld_melding.mld_melding_key%TYPE; -- melding key van gevonden ruimte
|
||
v_voorkeurzone asle_imp_werkschema.voorkeurzone%TYPE;
|
||
v_last_zone asle_imp_werkschema.last_zone%TYPE;
|
||
v_last_clean asle_imp_werkschema.last_clean%TYPE;
|
||
v_opdr_key mld_opdr.mld_opdr_key%TYPE;
|
||
v_stdmelding_omschrijving mld_stdmelding.mld_stdmelding_omschrijving%TYPE;
|
||
v_melding_einddatum mld_melding.mld_melding_einddatum%TYPE;
|
||
v_schoonmaaktijd NUMBER;
|
||
v_start_clean DATE;
|
||
v_rooms_tb_cleaned NUMBER; -- aantal ruimten dat door deze medewerker nog schoongemaakt moet worden.
|
||
v_rooms_that_can_be_cleaned NUMBER; -- aantal ruimten dat in die zone schoongemaakt kan worden
|
||
v_count NUMBER;
|
||
v_start_inzet DATE;
|
||
v_voornaam prs_perslid.prs_perslid_voornaam%TYPE;
|
||
v_aantal_schoonmakers NUMBER;
|
||
v_pauze NUMBER;
|
||
BEGIN
|
||
v_found_mld := NULL;
|
||
|
||
BEGIN
|
||
SELECT FAC.safe_to_number(prs_kenmerklink_waarde)
|
||
INTO v_efficiency
|
||
FROM prs_kenmerklink
|
||
WHERE prs_kenmerklink_verwijder IS NULL
|
||
AND prs_kenmerk_key = 1020 -- efficiency
|
||
AND prs_link_key = p_perslid_key;
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_efficiency := 1;
|
||
END;
|
||
|
||
BEGIN
|
||
SELECT voorkeurzone, last_zone, last_clean, min_num_clean - num_clean, start_inzet, prs_perslid_voornaam
|
||
INTO v_voorkeurzone, v_last_zone, v_last_clean, v_rooms_tb_cleaned, v_start_inzet, v_voornaam
|
||
FROM asle_imp_werkschema w, prs_perslid p
|
||
WHERE p.prs_perslid_key = p_perslid_key
|
||
AND w.prs_perslid_key = p_perslid_key
|
||
AND w.alg_locatie_key = p_locatie_key
|
||
AND TRUNC (w.start_inzet) = p_date;
|
||
|
||
DBMS_OUTPUT.put_line( '(' || p_perslid_key || ' ' || v_voornaam || ')'
|
||
|| ' v_voorkeurzone, v_last_zone, last_clean:'
|
||
|| v_voorkeurzone
|
||
|| ','
|
||
|| v_last_zone
|
||
|| ','
|
||
|| TO_CHAR (v_last_clean, 'yyyy-mm-dd hh24:mi'));
|
||
EXCEPTION
|
||
WHEN NO_DATA_FOUND
|
||
THEN
|
||
DBMS_OUTPUT.put_line (
|
||
'Geen gegevens gevonden perslid_key: ' || p_perslid_key);
|
||
RETURN -1;
|
||
END;
|
||
|
||
v_pauze := 0;
|
||
-- Om 12 uur is er lunchpauze, voor de mensen die voor xxx uur beginnen ???
|
||
IF TO_NUMBER (TO_CHAR (v_last_clean, 'hh24')) < 12 -- start voor 12 uur
|
||
AND TO_NUMBER (TO_CHAR (v_last_clean + 1/48, 'hh24')) >= 12 -- einde na 12 uur
|
||
THEN
|
||
v_pauze := 30;
|
||
END IF;
|
||
|
||
-- *** Als mensen eerder dan 6 uur beginnen krijgen ze verplicht een pauze van een kwartier
|
||
-- om 10 uur.
|
||
IF v_start_inzet <= p_date + 0.25 -- 6 uur
|
||
AND v_last_clean < p_date + 10/24 -- lastclean < 10 uur
|
||
AND v_last_clean + (1/96) > p_date + 10/24 -- lastclean + 15 minuten groter dan 10 uur
|
||
THEN
|
||
v_pauze := 15;
|
||
END IF;
|
||
|
||
IF v_pauze > 0
|
||
THEN
|
||
UPDATE asle_imp_werkschema
|
||
SET last_clean = last_clean + v_pauze/(24*60)
|
||
WHERE prs_perslid_key = p_perslid_key
|
||
AND alg_locatie_key = p_locatie_key
|
||
AND TRUNC (start_inzet) = p_date;
|
||
DBMS_OUTPUT.put_line ( '(' || p_perslid_key || ' ' || v_voornaam || ') '
|
||
|| v_pauze || ' minuten pauze toegevoegd voor: ' || p_perslid_key);
|
||
RETURN NULL;
|
||
END IF;
|
||
|
||
FOR rec IN c_find_room (v_last_clean, v_voorkeurzone, 'Match', 0)
|
||
LOOP
|
||
BEGIN
|
||
v_found_mld := rec.mld_melding_key;
|
||
v_zone := v_voorkeurzone;
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') melding in voorkeurzone:' || v_found_mld);
|
||
|
||
IF v_found_mld IS NULL
|
||
THEN
|
||
FOR rec IN c_find_room (v_last_clean, v_last_zone, 'Match', 0)
|
||
LOOP
|
||
BEGIN
|
||
v_found_mld := rec.mld_melding_key;
|
||
v_zone := v_last_zone;
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
END IF;
|
||
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') melding in last_zone:' || v_found_mld);
|
||
|
||
IF v_found_mld IS NULL
|
||
THEN
|
||
v_zone := NULL;
|
||
v_rooms_that_can_be_cleaned := 0;
|
||
v_aantal_schoonmakers := 0;
|
||
|
||
FOR rec IN c_find_zone (v_last_clean,
|
||
v_efficiency,
|
||
v_last_zone,
|
||
0) -- zonder dat er iemand in de zone werkt
|
||
LOOP
|
||
BEGIN
|
||
IF rec.number_rooms <> 0
|
||
THEN
|
||
v_zone := rec.zone;
|
||
v_rooms_that_can_be_cleaned := rec.number_rooms;
|
||
END IF;
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
|
||
|
||
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') zone zonder schoonmaker:' || v_zone || ' aantal kamers: ' || v_rooms_that_can_be_cleaned);
|
||
|
||
IF v_zone IS NULL
|
||
THEN
|
||
FOR rec IN c_find_zone (v_last_clean,
|
||
v_efficiency,
|
||
v_last_zone,
|
||
1) -- ook al werkt er iemand in die zone
|
||
LOOP
|
||
BEGIN
|
||
IF rec.number_rooms > 0
|
||
THEN
|
||
v_zone := rec.zone;
|
||
v_rooms_that_can_be_cleaned := rec.number_rooms;
|
||
v_aantal_schoonmakers := rec.aantal_mdw;
|
||
EXIT;
|
||
END IF;
|
||
END;
|
||
END LOOP;
|
||
|
||
IF v_zone IS NULL
|
||
THEN
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') *** geen schoonmaakactie gevonden');
|
||
-- log
|
||
END IF;
|
||
END IF;
|
||
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') zone met schoonmaker:' || v_zone || ' aantal kamers: ' || v_rooms_that_can_be_cleaned || ' Medew: ' || v_aantal_schoonmakers);
|
||
|
||
-- *** als nu blijkt dat we voor <20><>n kamer een zonewisseling over gaan, dan toch maar even proberen
|
||
-- of ik op mijn eigen zone met een langere (leegloop) tijd nog iets kan schoonmaken
|
||
-- dit wordt pas interessant na half tien
|
||
IF v_rooms_that_can_be_cleaned <2 AND to_number(to_char(v_last_clean, 'hh24mi')) > 930
|
||
THEN
|
||
FOR rec IN c_find_room (v_last_clean, v_last_zone, 'Match', 15)
|
||
LOOP
|
||
BEGIN
|
||
v_found_mld := rec.mld_melding_key;
|
||
v_zone := v_last_zone;
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') *** toch schoonmaakactie gevonden in zone: ' || v_zone);
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
END IF;
|
||
|
||
IF v_found_mld IS NULL
|
||
THEN -- *** check
|
||
|
||
-- geen zone gevonden waar gewerkt kan worden. Dit betekent dat we op zoek gaan naar de
|
||
-- eerst mogelijke melding waarbij we de leegloop moeten accepteren.
|
||
IF v_zone IS NULL
|
||
THEN
|
||
v_count := 0;
|
||
FOR rec IN c_find_room (v_last_clean, v_last_zone, 'DontCare', 0)
|
||
LOOP
|
||
BEGIN
|
||
v_found_mld := rec.mld_melding_key;
|
||
fac.imp_writelog (p_import_key,
|
||
'L',
|
||
'Leegloop geen schoonmaakactie gevonden',
|
||
'persoon:'
|
||
|| p_perslid_key
|
||
|| ' tijdstip:'
|
||
|| TO_CHAR (v_last_clean, 'dd-mm-yyyy hh24:mi')
|
||
|| ' zone:' || v_last_zone || ' -> ' || rec.zone
|
||
|| ' schoonmaaktijd:' || to_char(rec.mld_melding_einddatum, 'hh24:mi')
|
||
|| ' costs: ' || rec.costs
|
||
|| ' aantal: ' || rec.aantal);
|
||
v_zone := rec.zone;
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
ELSE
|
||
FOR rec IN c_find_room (v_last_clean, COALESCE(v_zone, v_last_zone), 'Match', 0)
|
||
LOOP
|
||
BEGIN
|
||
v_found_mld := rec.mld_melding_key;
|
||
EXIT;
|
||
END;
|
||
END LOOP;
|
||
END IF;
|
||
END IF; -- *** end loop
|
||
END IF;
|
||
|
||
|
||
|
||
|
||
DBMS_OUTPUT.put_line ('(' || p_perslid_key || ' ' || v_voornaam || ') volgende schoonmaakmelding:' || v_found_mld);
|
||
|
||
-- maak schoonmaakopdracht aan
|
||
IF v_found_mld IS NOT NULL
|
||
THEN
|
||
SELECT mld_stdmelding_omschrijving,
|
||
mld_melding_einddatum,
|
||
DECODE (UPPER (mld_stdmelding_omschrijving), 'CHECKOUT', schoonmaaktijd_co, schoonmaaktijd_so)
|
||
INTO v_stdmelding_omschrijving,
|
||
v_melding_einddatum,
|
||
v_schoonmaaktijd
|
||
FROM asle_t_schoonmaak s
|
||
WHERE s.mld_melding_key = v_found_mld;
|
||
ELSE
|
||
v_stdmelding_omschrijving := '';
|
||
v_melding_einddatum := NULL;
|
||
v_schoonmaaktijd := 5;
|
||
|
||
END IF;
|
||
|
||
-- *** v_start_clean op de begin van de beschikbaarheid zetten als ik zit te wachten.
|
||
/*IF v_melding_einddatum > v_start_clean
|
||
THEN
|
||
v_start_clean := v_melding_einddatum;
|
||
ELSE
|
||
v_start_clean := v_last_clean;
|
||
END IF; */ -- ***
|
||
v_start_clean := v_last_clean;
|
||
v_last_clean := v_last_clean + (v_schoonmaaktijd * v_efficiency) / (24 * 60);
|
||
|
||
UPDATE asle_imp_werkschema
|
||
SET last_clean = v_last_clean,
|
||
last_zone = v_zone,
|
||
num_clean = COALESCE (num_clean, 0) + 1
|
||
WHERE prs_perslid_key = p_perslid_key AND TRUNC (start_inzet) = p_date;
|
||
|
||
IF v_found_mld IS NULL
|
||
THEN
|
||
RETURN -1;
|
||
END IF;
|
||
|
||
mld.setmeldingstatus (v_found_mld, 4, 4);
|
||
|
||
INSERT INTO mld_opdr (mld_melding_key,
|
||
mld_opdr_module,
|
||
mld_uitvoerende_keys,
|
||
mld_typeopdr_key,
|
||
mld_statusopdr_key,
|
||
mld_opdr_omschrijving,
|
||
mld_opdr_datumbegin,
|
||
mld_opdr_einddatum,
|
||
mld_opdr_plandatum,
|
||
mld_opdr_bedrijfopdr_volgnr)
|
||
VALUES (v_found_mld,
|
||
'MLD',
|
||
p_perslid_key,
|
||
5,
|
||
5,
|
||
v_stdmelding_omschrijving,
|
||
TRUNC (SYSDATE),
|
||
TRUNC (SYSDATE + 1),
|
||
v_melding_einddatum,
|
||
1)
|
||
RETURNING mld_opdr_key
|
||
INTO v_opdr_key;
|
||
|
||
UPDATE asle_t_schoonmaak
|
||
SET mld_opdr_key = v_opdr_key
|
||
WHERE mld_melding_key = v_found_mld;
|
||
|
||
MLD.updatemeldingstatus (v_found_mld, 0, 4);
|
||
|
||
INSERT INTO mld_kenmerkopdr (mld_opdr_key,
|
||
mld_kenmerk_key,
|
||
mld_kenmerkopdr_waarde)
|
||
VALUES (v_opdr_key,
|
||
1,
|
||
TO_CHAR (v_start_clean, 'dd-mm-yyyy hh24:mi')); -- Schoonmaak starttijd
|
||
|
||
INSERT INTO mld_kenmerkopdr (mld_opdr_key,
|
||
mld_kenmerk_key,
|
||
mld_kenmerkopdr_waarde)
|
||
VALUES (v_opdr_key, 2, TO_CHAR (v_last_clean, 'dd-mm-yyyy hh24:mi')); -- Schoonmaak eindtijd
|
||
|
||
RETURN v_opdr_key;
|
||
END;
|
||
|
||
|
||
|
||
PROCEDURE schedule_stats (p_import_key IN NUMBER,
|
||
p_locatie_key IN NUMBER,
|
||
p_date IN DATE)
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT *
|
||
FROM asle_v_schoonmaak
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC(mld_melding_einddatum) = p_date
|
||
ORDER BY prs_perslid_naam, plan_start, zone;
|
||
|
||
v_zone_count NUMBER;
|
||
v_old_zone VARCHAR2 (10);
|
||
v_old_perslid_key NUMBER;
|
||
v_empty_count NUMBER;
|
||
v_empty_hours NUMBER;
|
||
BEGIN
|
||
v_zone_count := 0;
|
||
v_old_zone := NULL;
|
||
v_old_perslid_key := -1;
|
||
v_empty_count := 0;
|
||
|
||
DELETE asle_tmp_zone_wis
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC(tijdstip) = p_date;
|
||
|
||
FOR rec IN c
|
||
LOOP
|
||
IF rec.prs_perslid_key <> v_old_perslid_key
|
||
THEN
|
||
v_old_perslid_key := rec.prs_perslid_key;
|
||
v_old_zone := rec.zone;
|
||
ELSE
|
||
IF v_old_zone <> rec.zone
|
||
THEN
|
||
v_zone_count := v_zone_count + 1;
|
||
v_old_zone := rec.zone;
|
||
INSERT INTO asle_tmp_zone_wis (prs_perslid_key, tijdstip, alg_locatie_key)
|
||
VALUES (rec.prs_perslid_key, rec.plan_start, p_locatie_key);
|
||
END IF;
|
||
|
||
IF rec.plan_start < rec.mld_melding_einddatum
|
||
THEN
|
||
v_empty_count := v_empty_count + 1;
|
||
END IF;
|
||
END IF;
|
||
END LOOP;
|
||
|
||
SELECT ROUND (SUM (MAX (verschil)) * 24, 2)
|
||
INTO v_empty_hours
|
||
FROM (SELECT prs_perslid_key,
|
||
DECODE (SIGN (plan_start - mld_melding_einddatum),
|
||
-1, mld_melding_einddatum - plan_start,
|
||
0)
|
||
verschil,
|
||
mld_melding_einddatum,
|
||
plan_start
|
||
FROM asle_v_schoonmaak
|
||
WHERE TRUNC (mld_melding_einddatum) = p_date
|
||
AND alg_locatie_key = p_locatie_key)
|
||
GROUP BY prs_perslid_key;
|
||
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Leegloop:' || v_empty_count || 'keer, aantal uren:' || v_empty_hours,
|
||
'');
|
||
fac.imp_writelog (p_import_key,
|
||
'S',
|
||
'Zone wisselingen:' || v_zone_count,
|
||
'');
|
||
END;
|
||
|
||
PROCEDURE estimate_workload(p_locatie_key IN NUMBER, p_date IN DATE)
|
||
AS
|
||
v_count NUMBER;
|
||
v_time_start DATE;
|
||
v_time_eind DATE;
|
||
v_efficiency NUMBER;
|
||
BEGIN
|
||
DELETE asle_tmp_est_cleaning
|
||
WHERE alg_locatie_key = p_locatie_key
|
||
AND TRUNC(eindtijd) = p_date;
|
||
|
||
FOR rec IN (SELECT *
|
||
FROM asle_imp_werkschema
|
||
WHERE TRUNC (start_inzet) = p_date
|
||
AND alg_locatie_key = p_locatie_key)
|
||
LOOP
|
||
BEGIN
|
||
v_count := 0;
|
||
v_time_start := rec.start_inzet;
|
||
|
||
BEGIN
|
||
SELECT FAC.safe_to_number(prs_kenmerklink_waarde)
|
||
INTO v_efficiency
|
||
FROM prs_kenmerklink
|
||
WHERE prs_kenmerklink_verwijder IS NULL
|
||
AND prs_kenmerk_key = 1020 -- efficiency
|
||
AND prs_link_key = rec.prs_perslid_key;
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_efficiency := 1;
|
||
END;
|
||
|
||
WHILE v_count < rec.min_num_clean
|
||
LOOP
|
||
v_time_eind := v_time_start + v_efficiency / (24 * 3); -- 20 min
|
||
|
||
INSERT INTO asle_tmp_est_cleaning (starttijd, eindtijd, alg_locatie_key)
|
||
VALUES (v_time_start, v_time_eind, p_locatie_key);
|
||
|
||
v_time_start := v_time_eind;
|
||
v_count := v_count + 1;
|
||
END LOOP;
|
||
END;
|
||
END LOOP;
|
||
END;
|
||
END;
|
||
/
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_import_werkschema (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
CURSOR c_cursor
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_file
|
||
WHERE fac_import_key = p_import_key
|
||
ORDER BY fac_imp_file_index;
|
||
|
||
v_newline VARCHAR2 (1000); -- Import line
|
||
v_field VARCHAR2 (100); -- Import field
|
||
v_fielddelimitor VARCHAR2 (1); -- Field seperator
|
||
v_errormsg VARCHAR (200);
|
||
v_errorhint VARCHAR (200);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_skipfield VARCHAR2 (100);
|
||
-- De importvelden
|
||
v_locatie_code VARCHAR2(100);
|
||
v_datum_inzet VARCHAR2(100);
|
||
v_tijd_inzet VARCHAR2(100);
|
||
v_perslid_nr VARCHAR2(100);
|
||
v_perslid_naam VARCHAR2(100);
|
||
v_trolleynr VARCHAR2(100);
|
||
v_voorkeurzone VARCHAR2(100);
|
||
v_min_uren VARCHAR2(100);
|
||
v_max_uren VARCHAR2(100);
|
||
|
||
v_perslid_key PRS_PERSLID.PRS_PERSLID_KEY%TYPE;
|
||
v_locatie_key ALG_LOCATIE.ALG_LOCATIE_KEY%TYPE;
|
||
v_start_inzet DATE;
|
||
|
||
v_tabel_leeggemaakt BOOLEAN;
|
||
header_found BOOLEAN;
|
||
BEGIN
|
||
-- Init
|
||
header_found := FALSE;
|
||
v_tabel_leeggemaakt := FALSE;
|
||
v_fielddelimitor := ';';
|
||
|
||
FOR rec1 IN c_cursor
|
||
LOOP
|
||
BEGIN
|
||
v_newline := rec1.fac_imp_file_line;
|
||
|
||
IF SUBSTR (v_newline, 1, 3) = '?'
|
||
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;
|
||
|
||
v_errormsg := 'Inlezen velden';
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_locatie_code);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_datum_inzet);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_tijd_inzet);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_perslid_nr);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_perslid_naam);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_field);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_trolleynr);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_voorkeurzone);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_min_uren);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_max_uren);
|
||
|
||
v_errorhint := 'Medewerker: ' || v_perslid_naam;
|
||
-- Skip until a valid header is found
|
||
IF UPPER (v_locatie_code) = 'OBJECTNUMMER'
|
||
AND UPPER (v_datum_inzet) = 'DATUM'
|
||
AND UPPER (v_tijd_inzet) = 'BEGIN TIJDSTIP'
|
||
AND UPPER (v_perslid_nr) = 'PERSONEELSNUMMER'
|
||
AND UPPER (v_perslid_naam) = 'NAAM'
|
||
AND UPPER (v_trolleynr) = 'TROLLEYNR'
|
||
AND UPPER (v_voorkeurzone) = 'VOORKEURZONE'
|
||
AND UPPER (v_min_uren) = 'MIN. UREN'
|
||
AND UPPER (v_max_uren) = 'MAX. UREN'
|
||
THEN
|
||
-- Sla de kopregel over.
|
||
header_found := TRUE;
|
||
ELSIF (header_found)
|
||
THEN
|
||
v_errormsg := 'Bepalen locatie';
|
||
SELECT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM alg_locatie
|
||
WHERE alg_locatie_verwijder IS NULL
|
||
AND alg_locatie_code = v_locatie_code;
|
||
|
||
v_errormsg := 'Bepalen medewerker';
|
||
SELECT prs_perslid_key
|
||
INTO v_perslid_key
|
||
FROM prs_perslid
|
||
WHERE prs_perslid_verwijder IS NULL
|
||
AND prs_perslid_nr = v_perslid_nr;
|
||
|
||
v_errormsg := 'Bepalen inzet';
|
||
IF v_datum_inzet IS NULL OR v_tijd_inzet IS NULL
|
||
THEN
|
||
v_start_inzet := NULL;
|
||
ELSE
|
||
v_start_inzet := to_date(v_datum_inzet || ' ' || v_tijd_inzet, 'dd-mm-yyyy hh24:mi');
|
||
END IF;
|
||
|
||
IF NOT v_tabel_leeggemaakt AND v_start_inzet IS NOT NULL
|
||
THEN
|
||
DELETE asle_imp_werkschema
|
||
WHERE trunc(start_inzet) = trunc(v_start_inzet)
|
||
AND alg_locatie_key = v_locatie_key;
|
||
|
||
v_tabel_leeggemaakt := TRUE;
|
||
END IF;
|
||
|
||
IF v_start_inzet IS NOT NULL
|
||
THEN
|
||
INSERT INTO asle_imp_werkschema (prs_perslid_key,
|
||
alg_locatie_key,
|
||
start_inzet,
|
||
trolleynr,
|
||
voorkeurzone,
|
||
min_uren,
|
||
max_uren,
|
||
last_zone,
|
||
last_clean)
|
||
VALUES (v_perslid_key,
|
||
v_locatie_key,
|
||
v_start_inzet,
|
||
SUBSTR (v_trolleynr, 1, 10),
|
||
SUBSTR (v_voorkeurzone, 1, 10),
|
||
fac.safe_to_number(REPLACE(v_min_uren, ',', '.')),
|
||
fac.safe_to_number (REPLACE(v_max_uren, ',', '.')),
|
||
SUBSTR (COALESCE(v_voorkeurzone, '-1'), 1, 10),
|
||
v_start_inzet);
|
||
END IF;
|
||
ELSE
|
||
IF rec1.fac_imp_file_index = 1
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
SUBSTR (
|
||
v_locatie_code || ' als ' || 'OBJECTNUMMER' || ' - ' ||
|
||
v_datum_inzet || ' als ' || 'DATUM' || ' - ' ||
|
||
v_tijd_inzet || ' als ' || 'BEGIN TIJDSTIP' || ' - ' ||
|
||
v_perslid_nr || ' als ' || 'PERSONEELSNUMMER' || ' - ' ||
|
||
v_perslid_naam || ' als ' || 'NAAM' || ' - ' ||
|
||
v_trolleynr || ' als ' || 'TROLLEYNR' || ' - ' ||
|
||
v_voorkeurzone || ' als ' || 'VOORKEURZONE' || ' - ' ||
|
||
v_min_uren || ' als ' || 'MIN. UREN' || ' - ' ||
|
||
v_max_uren || ' als ' || 'MAX. UREN'
|
||
, 1, 1000),
|
||
'');
|
||
END IF;
|
||
END IF;
|
||
|
||
COMMIT;
|
||
END;
|
||
END LOOP;
|
||
|
||
IF NOT header_found
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'E',
|
||
'Geen geldige header aangetroffen',
|
||
'Bestand is geen geldig werkschema importbestand.');
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_errormsg || '-' || v_errorhint);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_update_werkschema (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
fac.imp_writelog (p_import_key, 'S', 'Inlezen werkschema voltooid', '');
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_import_kamerschema (
|
||
p_import_key IN NUMBER,
|
||
p_offset IN NUMBER)
|
||
AS
|
||
CURSOR c_cursor
|
||
IS
|
||
SELECT *
|
||
FROM fac_imp_file
|
||
WHERE fac_import_key = p_import_key
|
||
ORDER BY fac_imp_file_index;
|
||
|
||
v_newline VARCHAR2 (1000); -- Import line
|
||
v_field VARCHAR2 (100); -- Import field
|
||
v_fielddelimitor VARCHAR2 (1); -- Field seperator
|
||
v_errormsg VARCHAR (200);
|
||
v_errorhint VARCHAR (200);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_skipfield VARCHAR2 (100);
|
||
-- De importvelden
|
||
v_timestamp DATE;
|
||
v_timestamp_txt VARCHAR2(100);
|
||
v_locatie_code VARCHAR2(100);
|
||
v_locatie_key NUMBER(10);
|
||
v_kamer_nr VARCHAR2(100);
|
||
v_ruimte_key NUMBER(10);
|
||
v_klant_code VARCHAR2(100);
|
||
v_klant_naam VARCHAR2(100);
|
||
v_groep VARCHAR2(100);
|
||
v_groep_naam VARCHAR2(100);
|
||
v_aantal_personen_txt VARCHAR2(100);
|
||
v_aantal_personen NUMBER(2);
|
||
v_aantal_junior_txt VARCHAR2(100);
|
||
v_aantal_kinderen_txt VARCHAR2(100);
|
||
v_aantal_babies_txt VARCHAR2(100);
|
||
v_aantal_kinderen NUMBER(2);
|
||
v_ruimte_status VARCHAR(100); -- Vacant, Departure, Stay, Out of Order
|
||
v_checkout_status VARCHAR2(100); -- checked out
|
||
v_schoonmaak_status VARCHAR2(100); -- dirty, clean, pending to check
|
||
v_aankomst_datum_txt VARCHAR2(100);
|
||
v_aankomst_datum DATE;
|
||
v_vertrek_datum_txt VARCHAR2(100);
|
||
v_vertrek_datum DATE;
|
||
v_verw_checkin_txt VARCHAR2(100);
|
||
v_verw_checkin DATE;
|
||
v_verw_checkout_txt VARCHAR2(100);
|
||
v_verw_checkout DATE;
|
||
v_late_checkout_txt VARCHAR2(100);
|
||
v_late_checkout NUMBER(1);
|
||
v_type_gast VARCHAR2(10); -- CREW, IND
|
||
v_type_schoonmaak VARCHAR2(30); -- 1 - checkout, 2 - stayover LC, 3 - stayover NLC, ....
|
||
v_verw_start_schoonmaak DATE;
|
||
v_vervaldatum DATE;
|
||
v_usrtab_key NUMBER;
|
||
|
||
v_tabel_leeggemaakt BOOLEAN;
|
||
header_found BOOLEAN;
|
||
BEGIN
|
||
-- Init
|
||
header_found := FALSE;
|
||
v_tabel_leeggemaakt := FALSE;
|
||
v_fielddelimitor := ';';
|
||
|
||
FOR rec1 IN c_cursor
|
||
LOOP
|
||
BEGIN
|
||
v_errormsg := 'Inlezen velden';
|
||
v_newline := rec1.fac_imp_file_line;
|
||
|
||
IF SUBSTR (v_newline, 1, 3) = '?'
|
||
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;
|
||
|
||
--fac.imp_getfield (v_newline, v_fielddelimitor, v_timestamp_txt);
|
||
v_timestamp_txt := to_char(sysdate + p_offset, 'dd-mm-yyyy hh24:mi');
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_locatie_code);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_kamer_nr);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_skipfield); -- Room type
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_ruimte_status); -- Vacant, Departure, Stay
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_schoonmaak_status); -- dirty, clean, pending to check
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_aantal_personen_txt);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_aantal_junior_txt); -- JU(nior)
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_aantal_kinderen_txt); -- CH(ild)
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_aantal_babies_txt); -- B(a)B(y)
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_aankomst_datum_txt);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_vertrek_datum_txt);
|
||
fac.imp_getfield (v_newline, v_fielddelimitor, v_groep_naam);
|
||
|
||
v_late_checkout_txt := 'No';
|
||
v_verw_checkout_txt := NULL;
|
||
|
||
v_errorhint := 'Kamer: ' || v_kamer_nr;
|
||
-- Skip until a valid header is found
|
||
IF UPPER (v_locatie_code) = 'HOTEL'
|
||
AND UPPER (v_kamer_nr) = 'ROOM NUMBER'
|
||
AND UPPER (v_groep_naam) = 'GROUP NAME'
|
||
AND UPPER (v_ruimte_status) = 'OCCUPANCY'
|
||
AND UPPER (v_vertrek_datum_txt) = 'DEPARTURE DAY'
|
||
AND UPPER (v_aankomst_datum_txt) = 'ARRIVAL DAY'
|
||
THEN
|
||
-- Sla de kopregel over.
|
||
header_found := TRUE;
|
||
ELSIF (header_found) AND v_timestamp_txt IS NOT NULL -- vermijdt lege regels.
|
||
THEN
|
||
|
||
v_errormsg := 'Inlezen timestamp';
|
||
v_timestamp := TRUNC(SYSDATE) + p_offset;
|
||
|
||
v_errormsg := 'Inlezen locatie';
|
||
SELECT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM alg_v_aanweziglocatie
|
||
WHERE alg_locatie_code = v_locatie_code;
|
||
|
||
v_errormsg := 'Inlezen kamer';
|
||
IF LENGTH(v_kamer_nr) = 2
|
||
THEN
|
||
v_kamer_nr := '0' || v_kamer_nr;
|
||
END IF;
|
||
|
||
SELECT alg_ruimte_key
|
||
INTO v_ruimte_key
|
||
FROM alg_v_ruimte_gegevens
|
||
WHERE alg_locatie_key = v_locatie_key
|
||
AND alg_ruimte_nr = v_kamer_nr;
|
||
|
||
v_errormsg := 'Inlezen aantal_personen';
|
||
v_aantal_personen := to_number(v_aantal_personen_txt);
|
||
|
||
v_errormsg := 'Inlezen aantal_kinderen';
|
||
v_aantal_kinderen := COALESCE(FAC.safe_to_number(v_aantal_junior_txt),0)
|
||
+ COALESCE(FAC.safe_to_number(v_aantal_kinderen_txt),0)
|
||
+ COALESCE(FAC.safe_to_number(v_aantal_babies_txt),0);
|
||
|
||
v_errormsg := 'Inlezen aankomst datum';
|
||
v_aankomst_datum := to_date(v_aankomst_datum_txt, 'dd-mm-yyyy');
|
||
|
||
v_errormsg := 'Inlezen vertrek datum';
|
||
v_vertrek_datum := to_date(v_vertrek_datum_txt, 'dd-mm-yyyy');
|
||
|
||
-- Momenteel nog niet mogelijk, daarom wordt de verwachte checkout tijd gevuld met de
|
||
-- vluchtgegevens uit de eigen tabel. 61 tijden gedurende de week 62 tijden in het weekend
|
||
-- v_errormsg := 'Inlezen checkout tijd';
|
||
-- IF v_verw_checkout_txt IS NULL OR v_verw_checkout_txt = 'N'
|
||
-- THEN
|
||
-- v_verw_checkout := NULL;
|
||
-- ELSE
|
||
-- v_verw_checkout := to_date (v_vertrek_datum_txt || ' ' || SUBSTR(v_verw_checkout_txt,1,INSTR(v_verw_checkout_txt, ':', 1,2)-1), 'dd-mm-yyyy hh24:mi');
|
||
-- END IF;
|
||
|
||
IF v_groep_naam LIKE 'DELTA %'
|
||
THEN
|
||
IF v_ruimte_status = 'Departure'
|
||
THEN
|
||
IF INSTR(v_groep_naam, ' 0') > 0
|
||
THEN
|
||
v_groep_naam := REPLACE(v_groep_naam, 'DELTA 0', 'DL');
|
||
ELSE
|
||
v_groep_naam := REPLACE(v_groep_naam, 'DELTA ', 'DL');
|
||
END IF;
|
||
|
||
-- Kijk of het een werkdag is of het weekend
|
||
-- afhankelijk daarvan gebruiken we de weekend eigen tabel key 62 of de werkdagen eigen tabel key = 61
|
||
SELECT DECODE( to_char(v_timestamp, 'D'), 1,62,7,62,61)
|
||
INTO v_usrtab_key
|
||
FROM DUAL;
|
||
|
||
v_errormsg := 'Zoek de vluchtgegevens van vlucht: ' || v_groep_naam;
|
||
|
||
SELECT fac_usrdata_omschr, fac_usrdata_vervaldatum
|
||
INTO v_verw_checkout_txt, v_vervaldatum
|
||
FROM fac_usrdata
|
||
WHERE fac_usrtab_key = v_usrtab_key
|
||
AND fac_usrdata_verwijder IS NULL
|
||
AND UPPER(v_groep_naam) LIKE fac_usrdata_upper || '%';
|
||
|
||
IF v_vervaldatum < TRUNC(v_timestamp)
|
||
THEN
|
||
fac.imp_writelog (p_import_key, 'W', 'Vertrektijden zijn te oud. Vlucht: ' || v_groep_naam, '');
|
||
END IF;
|
||
|
||
v_verw_checkout := to_date (v_vertrek_datum_txt || ' ' || v_verw_checkout_txt, 'dd-mm-yyyy hh24:mi');
|
||
END IF;
|
||
v_type_gast := 'Crew';
|
||
ELSE
|
||
v_verw_checkout := NULL;
|
||
v_type_gast := 'Individual';
|
||
END IF;
|
||
|
||
v_errormsg := 'Inlezen late checkout';
|
||
IF UPPER(v_late_checkout_txt) = 'JA'
|
||
THEN
|
||
v_late_checkout := 1;
|
||
ELSE
|
||
v_late_checkout := 0;
|
||
END IF;
|
||
|
||
v_errormsg := 'Bepalen type schoonmaak';
|
||
CASE v_ruimte_status
|
||
WHEN 'Blocked' THEN v_type_schoonmaak := 'Blocked';
|
||
WHEN 'Departure' THEN v_type_schoonmaak := 'Checkout';
|
||
WHEN 'Free' THEN
|
||
IF v_schoonmaak_status = 'Dirty' AND p_offset = 0
|
||
THEN
|
||
v_type_schoonmaak := 'Checkout';
|
||
ELSE
|
||
v_type_schoonmaak := NULL;
|
||
END IF;
|
||
WHEN 'Stay' THEN
|
||
IF v_type_gast = 'Crew'
|
||
THEN
|
||
v_type_schoonmaak := 'DND';
|
||
ELSIF (TRUNC(SYSDATE + p_offset) - TRUNC(v_aankomst_datum)) MOD 2 = 0
|
||
THEN
|
||
v_type_schoonmaak := 'Stay LC';
|
||
ELSE
|
||
v_type_schoonmaak := 'Stay NLC';
|
||
END IF;
|
||
ELSE
|
||
v_type_schoonmaak := NULL;
|
||
END CASE;
|
||
|
||
|
||
v_errormsg := 'Bepalen verw start schoonmaak';
|
||
IF v_vertrek_datum_txt IS NULL THEN
|
||
v_vertrek_datum_txt := TO_CHAR(SYSDATE + p_offset, 'dd-mm-yyyy');
|
||
END IF;
|
||
|
||
IF v_schoonmaak_status = 'Clean' AND v_ruimte_status = 'Free'
|
||
THEN
|
||
v_verw_start_schoonmaak := TRUNC(SYSDATE + p_offset);
|
||
ELSIF v_checkout_status = 'checked out' -- nog niet in gebruik
|
||
THEN
|
||
v_verw_start_schoonmaak := SYSDATE;
|
||
ELSIF v_verw_checkout IS NOT NULL
|
||
THEN
|
||
v_verw_start_schoonmaak := v_verw_checkout;
|
||
ELSIF v_late_checkout = 1 AND v_type_schoonmaak = 'Checkout' -- nog niet in gebruik
|
||
THEN
|
||
v_verw_start_schoonmaak := to_date (v_vertrek_datum_txt || ' ' || '17:00', 'dd-mm-yyyy hh24:mi');
|
||
ELSE
|
||
v_verw_start_schoonmaak := TRUNC(SYSDATE + p_offset) + 0.5; -- 12:00 uur voor Stayover
|
||
END IF;
|
||
|
||
IF NOT v_tabel_leeggemaakt AND v_timestamp IS NOT NULL
|
||
THEN
|
||
DELETE asle_imp_kamerschema
|
||
WHERE 1=1 --trunc(timestamp) = trunc(v_timestamp)
|
||
AND alg_locatie_key = v_locatie_key;
|
||
|
||
v_tabel_leeggemaakt := TRUE;
|
||
END IF;
|
||
|
||
IF v_ruimte_status <> 'Arrival' -- aankomsten zijn niet interessant voor schoonmaak
|
||
THEN
|
||
INSERT INTO asle_imp_kamerschema (timestamp,
|
||
clean_date,
|
||
alg_locatie_key,
|
||
alg_ruimte_key,
|
||
klant_code,
|
||
klant_naam,
|
||
groep,
|
||
groep_naam,
|
||
aantal_personen,
|
||
aantal_kinderen,
|
||
ruimte_status,
|
||
checkout_status,
|
||
schoonmaak_status,
|
||
aankomst_datum,
|
||
vertrek_datum,
|
||
verw_checkin,
|
||
verw_checkout,
|
||
late_checkout,
|
||
type_gast,
|
||
type_schoonmaak,
|
||
verw_start_schoonmaak,
|
||
fac_import_key)
|
||
VALUES (v_timestamp,
|
||
TRUNC(SYSDATE) + p_offset,
|
||
v_locatie_key,
|
||
v_ruimte_key,
|
||
SUBSTR(v_klant_code,1,30),
|
||
SUBSTR(v_klant_naam,1,30),
|
||
SUBSTR(v_groep,1,30),
|
||
SUBSTR(v_groep_naam,1,30),
|
||
v_aantal_personen,
|
||
v_aantal_kinderen,
|
||
SUBSTR(v_ruimte_status,1,30),
|
||
SUBSTR(v_checkout_status,1,30),
|
||
SUBSTR(v_schoonmaak_status,1,30),
|
||
v_aankomst_datum,
|
||
v_vertrek_datum,
|
||
v_verw_checkin,
|
||
v_verw_checkout,
|
||
v_late_checkout,
|
||
v_type_gast,
|
||
v_type_schoonmaak,
|
||
v_verw_start_schoonmaak,
|
||
p_import_key);
|
||
END IF;
|
||
ELSE
|
||
IF rec1.fac_imp_file_index = 1
|
||
THEN
|
||
fac.imp_writelog (p_import_key,
|
||
'I',
|
||
SUBSTR(
|
||
v_locatie_code || ' als ' || 'HOTEL' || ' - ' ||
|
||
v_kamer_nr || ' als ' || 'ROOM NUMBER' || ' - ' ||
|
||
v_groep_naam || ' als ' || 'GROUP NAME' || ' - ' ||
|
||
v_ruimte_status || ' als ' || 'OCCUPANCY' || ' - ' ||
|
||
v_vertrek_datum_txt || ' als ' || 'DEPARTURE DAY' || ' - ' ||
|
||
v_aankomst_datum_txt || ' als ' || 'ARRIVAL DAY'
|
||
, 1, 1000),
|
||
'');
|
||
END IF;
|
||
END IF;
|
||
|
||
COMMIT;
|
||
END;
|
||
END LOOP;
|
||
|
||
IF NOT header_found
|
||
THEN
|
||
fac.imp_writelog (
|
||
p_import_key,
|
||
'E',
|
||
'Geen geldige header aangetroffen',
|
||
'Bestand is geen geldig kamerschema importbestand.');
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
v_errorhint := v_errormsg || '-' || v_errorhint;
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_errorhint);
|
||
END;
|
||
/
|
||
|
||
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_update_kamerschema (
|
||
p_import_key IN NUMBER,
|
||
p_offset IN NUMBER)
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT *
|
||
FROM asle_imp_kamerschema
|
||
WHERE fac_import_key = p_import_key AND type_schoonmaak IS NOT NULL;
|
||
|
||
CURSOR c_mld (
|
||
p_locatie_key NUMBER)
|
||
IS
|
||
SELECT m.mld_melding_key,
|
||
m.mld_stdmelding_key,
|
||
std.mld_stdmelding_omschrijving,
|
||
m.mld_melding_einddatum,
|
||
d.ins_discipline_omschrijving,
|
||
sd.ins_srtdiscipline_prefix
|
||
FROM mld_melding m,
|
||
mld_stdmelding std,
|
||
ins_tab_discipline d,
|
||
ins_srtdiscipline sd
|
||
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 TRUNC (mld_melding_einddatum) = TRUNC (SYSDATE + p_offset)
|
||
AND mld_alg_locatie_key = p_locatie_key
|
||
AND NOT EXISTS
|
||
(SELECT alg_ruimte_key
|
||
FROM asle_imp_kamerschema i
|
||
WHERE fac_import_key = p_import_key
|
||
AND type_schoonmaak IS NOT NULL
|
||
AND mld_alg_onroerendgoed_keys = i.alg_ruimte_key
|
||
AND TRUNC (mld_melding_einddatum) =
|
||
TRUNC (i.verw_start_schoonmaak));
|
||
|
||
CURSOR c_opdr (p_locatie_key NUMBER)
|
||
IS
|
||
SELECT *
|
||
FROM asle_imp_werkschema
|
||
WHERE TRUNC (start_inzet) = TRUNC (SYSDATE + p_offset)
|
||
AND alg_locatie_key = p_locatie_key
|
||
AND COALESCE (num_clean, 0) < min_num_clean
|
||
ORDER BY last_clean;
|
||
|
||
v_errormsg VARCHAR (200);
|
||
v_errorhint VARCHAR (200);
|
||
oracle_err_num NUMBER;
|
||
oracle_err_mes VARCHAR2 (200);
|
||
v_log VARCHAR2 (1000);
|
||
|
||
v_user_key prs_perslid.prs_perslid_key%TYPE;
|
||
v_stdmelding_key mld_stdmelding.mld_stdmelding_key%TYPE;
|
||
v_mld_stdmelding_key mld_stdmelding.mld_stdmelding_key%TYPE;
|
||
v_mld_stdmelding_omschrijving mld_stdmelding.mld_stdmelding_omschrijving%TYPE;
|
||
v_melding_eindtijd mld_melding.mld_melding_einddatum%TYPE;
|
||
v_discipline_omschrijving ins_tab_discipline.ins_discipline_omschrijving%TYPE;
|
||
v_srtdiscipline_prefix ins_srtdiscipline.ins_srtdiscipline_prefix%TYPE;
|
||
v_stdmelding_omschrijving mld_stdmelding.mld_stdmelding_omschrijving%TYPE;
|
||
v_melding_key mld_melding.mld_melding_key%TYPE;
|
||
v_locatie_key alg_locatie.alg_locatie_key%TYPE;
|
||
v_tolerantie NUMBER(3);
|
||
v_ruimte_aanduiding VARCHAR2(100);
|
||
c_mld_uitvoertijd mld_stdmelding.mld_stdmelding_t_uitvoertijd%TYPE
|
||
:= mld_t_uitvoertijd (1, 'D');
|
||
v_room_planned NUMBER (1);
|
||
v_loopcount NUMBER (10);
|
||
v_opdr_key mld_opdr.mld_opdr_key%TYPE;
|
||
v_opdr_count NUMBER (10);
|
||
BEGIN
|
||
-- Init
|
||
|
||
v_errormsg := 'Bepalen user';
|
||
|
||
SELECT prs_perslid_key
|
||
INTO v_user_key
|
||
FROM fac_import
|
||
WHERE fac_import_key = p_import_key;
|
||
|
||
v_errormsg := 'Bepalen locatie';
|
||
|
||
SELECT DISTINCT alg_locatie_key
|
||
INTO v_locatie_key
|
||
FROM asle_imp_kamerschema
|
||
WHERE fac_import_key = p_import_key;
|
||
|
||
v_errormsg := 'Bepalen schoonmaaktolerantie';
|
||
BEGIN
|
||
SELECT FAC.safe_to_number(alg_onrgoedkenmerk_waarde)
|
||
INTO v_tolerantie
|
||
FROM alg_onrgoedkenmerk aogk
|
||
WHERE alg_onrgoedkenmerk_verwijder IS NULL
|
||
AND alg_kenmerk_key = 1060
|
||
AND alg_onrgoed_key = v_locatie_key;
|
||
EXCEPTION WHEN NO_DATA_FOUND
|
||
THEN
|
||
v_tolerantie := 0;
|
||
END;
|
||
|
||
-- verwijder opdrachten waar nog niet mee gestart is
|
||
-- pas de tabel werkschema aan en vul last_zone en num_clean
|
||
-- met de actuele stand van zaken
|
||
DELETE mld_opdr WHERE mld_opdr_key IN
|
||
( SELECT mld_opdr_key
|
||
FROM asle_v_schoonmaak
|
||
WHERE alg_locatie_key = v_locatie_key
|
||
AND TRUNC(mld_melding_einddatum) = TRUNC (SYSDATE + p_offset)
|
||
AND mld_statusopdr_key NOT IN (
|
||
6, -- afgemeld
|
||
7, -- verwerkt
|
||
8, -- geaccepteerd
|
||
9 -- afgerond
|
||
)
|
||
);
|
||
|
||
-- Verwijder achtergebleven tracking
|
||
DELETE fac_tracking
|
||
WHERE fac_tracking_key IN (
|
||
SELECT fac_tracking_key
|
||
FROM fac_tracking ft, fac_srtnotificatie fs
|
||
WHERE ft.fac_srtnotificatie_key = fs.fac_srtnotificatie_key
|
||
AND fac_srtnotificatie_xmlnode = 'opdracht'
|
||
AND NOT EXISTS (SELECT 1
|
||
FROM mld_opdr
|
||
WHERE mld_opdr_key = fac_tracking_refkey
|
||
)
|
||
);
|
||
|
||
FOR rec IN c
|
||
LOOP
|
||
BEGIN
|
||
-- even het ruimtenummer bepalen voor de logging
|
||
v_errormsg := 'Bepalen ruimtenummer';
|
||
SELECT alg_ruimte_aanduiding
|
||
INTO v_ruimte_aanduiding
|
||
FROM alg_v_ruimte_gegevens
|
||
WHERE alg_ruimte_key = rec.alg_ruimte_key;
|
||
|
||
v_errorhint := 'Kamernummer (key): ' || v_ruimte_aanduiding;
|
||
|
||
v_errormsg := 'Bepalen standaardmelding';
|
||
|
||
SELECT mld_stdmelding_key, mld_stdmelding_omschrijving
|
||
INTO v_stdmelding_key, v_stdmelding_omschrijving
|
||
FROM mld_stdmelding
|
||
WHERE mld_stdmelding_verwijder IS NULL
|
||
AND UPPER (mld_stdmelding_omschrijving) =
|
||
UPPER (rec.type_schoonmaak);
|
||
|
||
v_errormsg := 'Controleer of melding al bestaat';
|
||
|
||
BEGIN
|
||
SELECT MIN(m.mld_melding_key)
|
||
INTO v_melding_key
|
||
FROM mld_melding m,
|
||
mld_stdmelding std
|
||
WHERE m.mld_stdmelding_key = std.mld_stdmelding_key
|
||
AND std.mld_ins_discipline_key = 21 -- schoonmaak
|
||
AND mld_alg_onroerendgoed_keys = rec.alg_ruimte_key
|
||
AND mld_meldbron_key = 6 -- System
|
||
AND TRUNC (mld_melding_einddatum) =
|
||
TRUNC (COALESCE(rec.verw_start_schoonmaak, SYSDATE+p_offset));
|
||
|
||
v_errormsg := 'Controleer of melding al bestaat2';
|
||
IF v_melding_key IS NOT NULL
|
||
THEN
|
||
SELECT m.mld_stdmelding_key,
|
||
std.mld_stdmelding_omschrijving,
|
||
m.mld_melding_einddatum,
|
||
d.ins_discipline_omschrijving,
|
||
sd.ins_srtdiscipline_prefix
|
||
INTO v_mld_stdmelding_key,
|
||
v_mld_stdmelding_omschrijving,
|
||
v_melding_eindtijd,
|
||
v_discipline_omschrijving,
|
||
v_srtdiscipline_prefix
|
||
FROM mld_melding m,
|
||
mld_stdmelding std,
|
||
ins_tab_discipline d,
|
||
ins_srtdiscipline sd
|
||
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 m.mld_melding_key = v_melding_key;
|
||
|
||
v_log := NULL;
|
||
|
||
IF v_mld_stdmelding_key <> v_stdmelding_key
|
||
THEN
|
||
v_log :=
|
||
'Melding: '
|
||
|| v_mld_stdmelding_omschrijving
|
||
|| ' --> '
|
||
|| v_stdmelding_omschrijving;
|
||
END IF;
|
||
|
||
IF rec.verw_start_schoonmaak <> v_melding_eindtijd
|
||
THEN
|
||
IF v_log IS NOT NULL
|
||
THEN
|
||
v_log := v_log || CHR (10);
|
||
END IF;
|
||
|
||
v_log :=
|
||
'Gereed: '
|
||
|| TO_CHAR (v_melding_eindtijd, 'dd-mm-yyyy hh24:mi')
|
||
|| ' --> '
|
||
|| TO_CHAR (rec.verw_start_schoonmaak,
|
||
'dd-mm-yyyy hh24:mi');
|
||
END IF;
|
||
|
||
IF v_log IS NOT NULL
|
||
THEN
|
||
UPDATE mld_melding
|
||
SET mld_stdmelding_key = v_stdmelding_key,
|
||
mld_melding_einddatum = rec.verw_start_schoonmaak
|
||
WHERE mld_melding_key = v_melding_key;
|
||
|
||
v_log :=
|
||
'*Melding '
|
||
|| v_srtdiscipline_prefix
|
||
|| v_melding_key
|
||
|| ' ('
|
||
|| v_discipline_omschrijving
|
||
|| '/'
|
||
|| v_stdmelding_omschrijving
|
||
|| ') is gewijzigd'
|
||
|| CHR (10)
|
||
|| v_log;
|
||
|
||
INSERT INTO fac_tracking (fac_srtnotificatie_key,
|
||
fac_tracking_refkey,
|
||
fac_tracking_oms,
|
||
prs_perslid_key)
|
||
SELECT fac_srtnotificatie_key,
|
||
v_melding_key,
|
||
v_log,
|
||
v_user_key
|
||
FROM fac_srtnotificatie
|
||
WHERE fac_srtnotificatie_code = 'MLDUPD';
|
||
END IF;
|
||
mld.upsertmeldingkenmerk (81, -- groepnaam
|
||
v_melding_key,
|
||
rec.groep_naam);
|
||
ELSE
|
||
v_errormsg := 'Aanmaken meldingen';
|
||
|
||
INSERT INTO mld_melding (mld_melding_omschrijving,
|
||
prs_perslid_key,
|
||
mld_stdmelding_key,
|
||
mld_alg_locatie_key,
|
||
mld_alg_onroerendgoed_keys,
|
||
mld_melding_einddatum,
|
||
mld_melding_datum,
|
||
mld_melding_t_uitvoertijd,
|
||
mld_meldbron_key,
|
||
mld_melding_module,
|
||
mld_melding_spoed)
|
||
VALUES ('Kamerschoonmaak uit TMS. Kamernummer: ' || v_ruimte_aanduiding,
|
||
v_user_key,
|
||
v_stdmelding_key,
|
||
rec.alg_locatie_key,
|
||
rec.alg_ruimte_key,
|
||
rec.verw_start_schoonmaak,
|
||
SYSDATE,
|
||
c_mld_uitvoertijd,
|
||
6, -- system
|
||
'MLD',
|
||
3)
|
||
RETURNING mld_melding_key
|
||
INTO v_melding_key;
|
||
|
||
END IF;
|
||
|
||
mld.upsertmeldingkenmerk (81, -- groepnaam
|
||
v_melding_key,
|
||
rec.groep_naam);
|
||
mld.upsertmeldingkenmerk (161, -- aantal volwassenen
|
||
v_melding_key,
|
||
rec.aantal_personen);
|
||
mld.upsertmeldingkenmerk (162, -- aantal kinderen
|
||
v_melding_key,
|
||
rec.aantal_kinderen);
|
||
|
||
SELECT count(*)
|
||
INTO v_opdr_count
|
||
FROM mld_opdr o
|
||
WHERE o.mld_melding_key = v_melding_key;
|
||
|
||
IF v_opdr_count = 0
|
||
THEN
|
||
mld.setmeldingstatus (v_melding_key, 2, v_user_key);
|
||
END IF;
|
||
END;
|
||
END;
|
||
END LOOP;
|
||
|
||
-- meldingen die niet meer in de import voorkomen
|
||
FOR rec IN c_mld (v_locatie_key)
|
||
LOOP
|
||
BEGIN
|
||
v_errormsg := 'Bepalen standaardmelding NoService';
|
||
|
||
SELECT mld_stdmelding_key, mld_stdmelding_omschrijving
|
||
INTO v_stdmelding_key, v_stdmelding_omschrijving
|
||
FROM mld_stdmelding
|
||
WHERE mld_stdmelding_verwijder IS NULL
|
||
AND UPPER (mld_stdmelding_omschrijving) = UPPER ('NOSERVICE');
|
||
|
||
v_log := NULL;
|
||
|
||
IF rec.mld_stdmelding_key <> v_stdmelding_key
|
||
THEN
|
||
v_log :=
|
||
'Melding: '
|
||
|| rec.mld_stdmelding_omschrijving
|
||
|| ' --> '
|
||
|| v_stdmelding_omschrijving;
|
||
END IF;
|
||
|
||
|
||
IF v_log IS NOT NULL
|
||
THEN
|
||
UPDATE mld_melding
|
||
SET mld_stdmelding_key = v_stdmelding_key
|
||
WHERE mld_melding_key = rec.mld_melding_key;
|
||
|
||
v_log :=
|
||
'*Melding '
|
||
|| v_srtdiscipline_prefix
|
||
|| rec.mld_melding_key
|
||
|| ' ('
|
||
|| v_discipline_omschrijving
|
||
|| '/'
|
||
|| v_stdmelding_omschrijving
|
||
|| ') is gewijzigd'
|
||
|| CHR (10)
|
||
|| v_log;
|
||
|
||
INSERT INTO fac_tracking (fac_srtnotificatie_key,
|
||
fac_tracking_refkey,
|
||
fac_tracking_oms,
|
||
prs_perslid_key)
|
||
SELECT fac_srtnotificatie_key,
|
||
rec.mld_melding_key,
|
||
v_log,
|
||
v_user_key
|
||
FROM fac_srtnotificatie
|
||
WHERE fac_srtnotificatie_code = 'MLDUPD';
|
||
END IF;
|
||
|
||
mld.upsertmeldingkenmerk (81, -- groepnaam
|
||
rec.mld_melding_key,
|
||
'');
|
||
mld.upsertmeldingkenmerk (161, -- aantal volwassenen
|
||
rec.mld_melding_key,
|
||
NULL);
|
||
mld.upsertmeldingkenmerk (162, -- aantal kinderen
|
||
rec.mld_melding_key,
|
||
NULL);
|
||
END;
|
||
END LOOP;
|
||
|
||
-- opdrachten inplannen
|
||
v_errormsg := 'Bepalen aantal opdrachten per persoon';
|
||
ASLE.init_cleaning (v_locatie_key, TRUNC (SYSDATE + p_offset));
|
||
|
||
v_loopcount := 0;
|
||
v_room_planned := 1;
|
||
|
||
-- Om performance redenen slaan we de view asle_v_schoonmaak even plat om de planning
|
||
-- te genereren. Tijd met view is ongeveer 2min35 en bij tabel ongeveer 20 seconden.
|
||
DELETE asle_t_schoonmaak;
|
||
|
||
INSERT INTO asle_t_schoonmaak
|
||
SELECT *
|
||
FROM asle_v_schoonmaak
|
||
WHERE TRUNC (mld_melding_einddatum) = TRUNC(SYSDATE+p_offset);
|
||
|
||
WHILE v_room_planned <> 0 AND v_loopcount < 1000
|
||
LOOP
|
||
v_room_planned := 0;
|
||
|
||
BEGIN
|
||
FOR rec IN c_opdr (v_locatie_key)
|
||
LOOP
|
||
v_opdr_key :=
|
||
ASLE.find_next_room (p_import_key,
|
||
rec.alg_locatie_key,
|
||
TRUNC (rec.last_clean),
|
||
rec.prs_perslid_key,
|
||
v_tolerantie);
|
||
|
||
IF v_opdr_key <> -1 OR v_opdr_key IS NULL
|
||
THEN
|
||
v_room_planned := 1;
|
||
END IF;
|
||
|
||
-- DBMS_OUTPUT.put_line (v_opdr_key);
|
||
EXIT;
|
||
END LOOP;
|
||
|
||
END;
|
||
|
||
v_loopcount := v_loopcount + 1;
|
||
END LOOP;
|
||
|
||
ASLE.schedule_stats (p_import_key, v_locatie_key, TRUNC(SYSDATE+p_offset));
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
v_errorhint := v_errormsg || '-' || v_errorhint;
|
||
oracle_err_num := SQLCODE;
|
||
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
||
v_errormsg :=
|
||
'OTHERS (error ' || oracle_err_num || '/' || oracle_err_mes || ')';
|
||
fac.imp_writelog (p_import_key,
|
||
'E',
|
||
SUBSTR (v_errormsg, 1, 1000),
|
||
v_errorhint);
|
||
END;
|
||
/
|
||
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_import_kamerschema_1 (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
asle_import_kamerschema(p_import_key,1);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_import_kamerschema_0 (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
asle_import_kamerschema(p_import_key,0);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_update_kamerschema_1 (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
asle_update_kamerschema(p_import_key,1);
|
||
END;
|
||
/
|
||
|
||
CREATE OR REPLACE PROCEDURE asle_update_kamerschema_0 (
|
||
p_import_key IN NUMBER)
|
||
AS
|
||
BEGIN
|
||
asle_update_kamerschema(p_import_key,0);
|
||
END;
|
||
/
|
||
|
||
-- tijdelijke procedure om opdrachten en meldingen automatisch af te melden.
|
||
CREATE OR REPLACE PROCEDURE asle_export_mld_opdr_close (
|
||
p_applname IN VARCHAR2,
|
||
p_applrun IN VARCHAR2,
|
||
p_filedir IN VARCHAR2,
|
||
p_filename IN VARCHAR2)
|
||
AS
|
||
CURSOR c
|
||
IS
|
||
SELECT o.mld_opdr_key, o.mld_statusopdr_key, m.mld_melding_key
|
||
FROM mld_opdr o, mld_melding m, mld_stdmelding std
|
||
WHERE o.mld_melding_key = m.mld_melding_key
|
||
AND mld_opdr_plandatum < TRUNC (SYSDATE)
|
||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||
AND mld_statusopdr_key IN (5, 8)
|
||
AND std.mld_ins_discipline_key = 21;
|
||
|
||
CURSOR c_m
|
||
IS
|
||
SELECT mld_melding_key, mld_melding_status
|
||
FROM mld_melding m, mld_stdmelding std
|
||
WHERE mld_melding_einddatum < TRUNC (SYSDATE)
|
||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||
AND mld_melding_status IN (2, 4, 5, 7)
|
||
AND std.mld_ins_discipline_key = 21;
|
||
BEGIN
|
||
FOR rec IN c
|
||
LOOP
|
||
BEGIN
|
||
IF (rec.mld_statusopdr_key = 5)
|
||
THEN
|
||
-- 5 toegekend -> 8 geaccepteerd
|
||
mld.setopdrachtstatus (rec.mld_opdr_key, 8, 4);
|
||
END IF;
|
||
|
||
IF (rec.mld_statusopdr_key = 8 OR rec.mld_statusopdr_key = 5)
|
||
THEN
|
||
-- 8 geaccepteerd -> 6 afgemeld
|
||
mld.setopdrachtstatus (rec.mld_opdr_key, 6, 4);
|
||
END IF;
|
||
|
||
mld.updatemeldingstatus (rec.mld_melding_key, 1, 4);
|
||
END;
|
||
END LOOP;
|
||
|
||
FOR rec IN c_m
|
||
LOOP
|
||
BEGIN
|
||
IF (rec.mld_melding_status = 2)
|
||
THEN
|
||
-- 2 nieuw -> 4 geaccepteerd
|
||
mld.setmeldingstatus (rec.mld_melding_key, 4, 4);
|
||
END IF;
|
||
|
||
mld.updatemeldingstatus (rec.mld_melding_key, 1, 4);
|
||
|
||
IF (rec.mld_melding_status = 4
|
||
OR rec.mld_melding_status = 2
|
||
OR rec.mld_melding_status = 7)
|
||
THEN
|
||
-- 4 geaccepteerd -> 5 afgemeld
|
||
mld.setopdrachtstatus (rec.mld_melding_key, 5, 4);
|
||
END IF;
|
||
EXCEPTION
|
||
WHEN OTHERS
|
||
THEN
|
||
-- dbms_output.put_line(to_char(rec.mld_melding_key));
|
||
NULL;
|
||
END;
|
||
END LOOP;
|
||
|
||
COMMIT;
|
||
END;
|
||
/
|
||
|
||
------ 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
|
||
|
||
|