ASLE#32161 -- Ondersteuning analysefase MST
svn path=/Customer/trunk/; revision=27341
This commit is contained in:
154
ASME/asme.sql
154
ASME/asme.sql
@@ -8,6 +8,160 @@
|
||||
SPOOL xasme.lst
|
||||
SET ECHO ON
|
||||
|
||||
CREATE OR REPLACE PACKAGE ASME
|
||||
AS
|
||||
PROCEDURE mld_postsave (p_melding_key IN NUMBER);
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE PACKAGE BODY ASME
|
||||
AS
|
||||
PROCEDURE mld_postsave (p_melding_key IN NUMBER)
|
||||
AS
|
||||
BEGIN
|
||||
mld.upsertmeldingkenmerk (101, -- steekproef
|
||||
p_melding_key,
|
||||
1);
|
||||
END;
|
||||
END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE FORCE VIEW asme_v_work_list_cleaner
|
||||
(
|
||||
hide_f_timestamp,
|
||||
mld_opdr_key,
|
||||
fclt_3d_user_key,
|
||||
mld_opdr_startdatum,
|
||||
mld_opdr_einddatum,
|
||||
kamernummer,
|
||||
omschrijving
|
||||
)
|
||||
AS
|
||||
SELECT TO_CHAR (mld_opdr_einddatum, 'yyyymmddhh24mi'),
|
||||
o.mld_opdr_key,
|
||||
o.mld_uitvoerende_keys fclt_3d_user_key,
|
||||
mld_melding_datum + 1/(24*4), -- kwartier
|
||||
mld_opdr_einddatum,
|
||||
r.alg_ruimte_nr,
|
||||
mld_stdmelding_omschrijving
|
||||
|| ' ('
|
||||
|| DECODE (o.mld_statusopdr_key, 8, 'gestart', 'nieuw')
|
||||
|| ')'
|
||||
FROM mld_opdr o,
|
||||
mld_melding m,
|
||||
alg_v_ruimte_gegevens r,
|
||||
mld_stdmelding std
|
||||
WHERE o.mld_statusopdr_key IN (5, 8)
|
||||
AND o.mld_melding_key = m.mld_melding_key
|
||||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND m.mld_alg_onroerendgoed_keys = r.alg_ruimte_key;
|
||||
|
||||
--
|
||||
-- Rapportages
|
||||
--
|
||||
|
||||
CREATE OR REPLACE VIEW asme_v_rap_startwerkzaamheden
|
||||
(
|
||||
volgorde,
|
||||
mld_melding_key,
|
||||
starttijd,
|
||||
ruimtenr,
|
||||
melding,
|
||||
schoonmaker,
|
||||
marge
|
||||
)
|
||||
AS
|
||||
SELECT TO_CHAR (mld_melding_datum, 'yyyymmddhh24miss') volgorde,
|
||||
m.mld_melding_key,
|
||||
TO_CHAR (mld_melding_datum, 'dd-mm-yyyy hh24:mi') starttijd,
|
||||
alg_ruimte_nr ruimtenr,
|
||||
mld_stdmelding_omschrijving melding,
|
||||
pf.prs_perslid_naam_friendly,
|
||||
15 - ROUND ((SYSDATE - mld_melding_datum) * 24 * 60) marge
|
||||
FROM mld_opdr o,
|
||||
mld_melding m,
|
||||
mld_stdmelding std,
|
||||
alg_v_ruimte_gegevens rg,
|
||||
prs_v_perslid_fullnames pf
|
||||
WHERE o.mld_melding_key(+) = m.mld_melding_key
|
||||
AND o.mld_uitvoerende_keys = pf.prs_perslid_key(+)
|
||||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND m.mld_alg_onroerendgoed_keys = rg.alg_ruimte_key
|
||||
AND (o.mld_statusopdr_key IN (5) OR o.mld_statusopdr_key IS NULL)
|
||||
AND m.mld_melding_status NOT IN (1,5,6) -- afgewezen, gereed, verwerkt
|
||||
ORDER BY mld_melding_datum;
|
||||
|
||||
CREATE OR REPLACE VIEW asme_v_rap_eindwerkzaamheden
|
||||
(
|
||||
volgorde,
|
||||
mld_melding_key,
|
||||
eindtijd,
|
||||
ruimtenr,
|
||||
melding,
|
||||
schoonmaker,
|
||||
marge
|
||||
)
|
||||
AS
|
||||
SELECT TO_CHAR (mld_melding_datum, 'yyyymmddhh24miss') volgorde,
|
||||
m.mld_melding_key,
|
||||
TO_CHAR (mld_opdr_einddatum, 'dd-mm-yyyy hh24:mi') eindtijd,
|
||||
alg_ruimte_nr ruimtenr,
|
||||
mld_stdmelding_omschrijving melding,
|
||||
pf.prs_perslid_naam_friendly,
|
||||
ROUND ( (mld_opdr_einddatum - SYSDATE) * 24 * 60) marge
|
||||
FROM mld_opdr o,
|
||||
mld_melding m,
|
||||
mld_stdmelding std,
|
||||
alg_v_ruimte_gegevens rg,
|
||||
prs_v_perslid_fullnames pf
|
||||
WHERE o.mld_melding_key(+) = m.mld_melding_key
|
||||
AND o.mld_uitvoerende_keys = pf.prs_perslid_key(+)
|
||||
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
||||
AND m.mld_alg_onroerendgoed_keys = rg.alg_ruimte_key
|
||||
AND std.mld_ins_discipline_key NOT IN (42, 61) -- Techniek, Regie
|
||||
AND o.mld_statusopdr_key IN (8)
|
||||
AND m.mld_melding_status NOT IN (1, 5, 6) -- afgewezen, gereed, verwerkt
|
||||
ORDER BY mld_melding_datum;
|
||||
|
||||
-- rapport van het aantal checkouts die de schoonmaker op zijn naam heeft staan
|
||||
-- ten opzichte van het aantal checkouts dat hij per dag (kenmerk_key = 1000) moet halen.
|
||||
-- dit ook beschikbaar op weekniveau.
|
||||
CREATE OR REPLACE VIEW asme_v_rap_aantal_checkouts
|
||||
(
|
||||
naam,
|
||||
vandaag,
|
||||
todo_vandaag,
|
||||
week,
|
||||
todo_week
|
||||
)
|
||||
AS
|
||||
SELECT pf.prs_perslid_naam_friendly,
|
||||
(SELECT COUNT ( * )
|
||||
FROM mld_opdr o, mld_melding m
|
||||
WHERE o.mld_uitvoerende_keys = p.prs_perslid_key
|
||||
AND o.mld_melding_key = m.mld_melding_key
|
||||
AND TRUNC (m.mld_melding_datum) = TRUNC (SYSDATE))
|
||||
co_today,
|
||||
aantal_co,
|
||||
(SELECT COUNT ( * )
|
||||
FROM mld_opdr o, mld_melding m
|
||||
WHERE o.mld_uitvoerende_keys = p.prs_perslid_key
|
||||
AND o.mld_melding_key = m.mld_melding_key
|
||||
AND TO_CHAR (m.mld_melding_datum, 'YYYYIW') =
|
||||
TO_CHAR (SYSDATE, 'YYYYIW'))
|
||||
co_week,
|
||||
(TO_CHAR (SYSDATE, 'D') - 1) * aantal_co week_co
|
||||
FROM (SELECT fac.safe_to_number (prs_kenmerklink_waarde) aantal_co,
|
||||
prs_link_key prs_perslid_key
|
||||
FROM prs_kenmerklink
|
||||
WHERE prs_kenmerk_key = 1000
|
||||
AND prs_kenmerklink_verwijder IS NULL) co,
|
||||
prs_perslid p,
|
||||
prs_v_perslid_fullnames pf
|
||||
WHERE p.prs_perslid_key = pf.prs_perslid_key
|
||||
AND p.prs_perslid_key = co.prs_perslid_key;
|
||||
|
||||
|
||||
|
||||
|
||||
BEGIN adm.systrackscriptId('$Id$', 0); END;
|
||||
|
||||
Reference in New Issue
Block a user