PNBR#64700: Monitoring werkplekbezetting in Facilitor
svn path=/Customer/trunk/; revision=51652
This commit is contained in:
126
PNBR/pnbr.sql
126
PNBR/pnbr.sql
@@ -2,24 +2,31 @@
|
||||
-- $Id$
|
||||
--
|
||||
-- Script containing customer specific sql statements for the FACILITOR database
|
||||
-- Voor dbuser invullen: - indien script voor 1 klant is: 'AADS' (de klantcode, zoals vermeld in fac_version_cust)
|
||||
-- - script is voor meerdere klanten: 'AAXX' (de groepcode, zoals vermeld in fac_version_group)
|
||||
-- - script is voor meerdere klanten met naam volgens een bepaald patroon: '^AA|^ASMS|^GULU|^NMMS|^RABO|^ZKHM'
|
||||
-- Ook als het script gedraaid wordt voor de verkeerde cust wordt er een logfile gemaakt.
|
||||
-- (dit in tegenstelling tot sample_xxxx.sql)
|
||||
|
||||
DEFINE thisfile = 'PNBR.SQL'
|
||||
DEFINE dbuser = '^PNBR'
|
||||
DEFINE custid = 'PNBR'
|
||||
DEFINE dbuser = 'PNBR'
|
||||
|
||||
SET ECHO ON
|
||||
SET DEFINE ON
|
||||
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
||||
WHENEVER SQLERROR EXIT;
|
||||
|
||||
SELECT adm.scriptspoolfile ('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
|
||||
|
||||
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 ------
|
||||
1
|
||||
|
||||
CREATE OR REPLACE PROCEDURE pnbr_imp_writelog (p_import_key IN NUMBER,
|
||||
p_severity IN VARCHAR2,
|
||||
@@ -154,6 +161,8 @@ AS
|
||||
p_link_key IN NUMBER,
|
||||
p_kenmerk_waarde IN VARCHAR2,
|
||||
p_history IN NUMBER);
|
||||
|
||||
|
||||
END;
|
||||
/
|
||||
|
||||
@@ -977,6 +986,9 @@ PROCEDURE set_kenmerk(p_module IN VARCHAR2,
|
||||
|
||||
RETURN v_result;
|
||||
END;
|
||||
|
||||
|
||||
|
||||
END;
|
||||
/
|
||||
|
||||
@@ -8033,7 +8045,7 @@ AS
|
||||
AND m.prs_perslid_key = pr.prs_perslid_key
|
||||
AND syncdate.mld_melding_key(+) = m.mld_melding_key
|
||||
AND km.mld_stdmelding_key = sm.mld_ins_discipline_key --- let op: kenmerk zit gekoppeld op discipline niveau
|
||||
AND m.mld_melding_status NOT IN (1, 2, 6, 7, 9)
|
||||
--- AND m.mld_melding_status NOT IN (1, 2, 6, 7, 9) na overleg met Menno: status doet er niet toe
|
||||
AND km.mld_srtkenmerk_key = 9083
|
||||
AND ( fac.safe_to_number (
|
||||
TO_CHAR (mld_melding_note_aanmaak,
|
||||
@@ -8817,40 +8829,56 @@ END;
|
||||
/
|
||||
|
||||
CREATE OR REPLACE VIEW PNBR_V_STATUSVERLOOP_WPBEZ
|
||||
(
|
||||
INS_DEEL_OMSCHRIJVING,
|
||||
INS_DEEL_KEY,
|
||||
ALG_RUIMTE_KEY,
|
||||
ALG_RUIMTE_NR,
|
||||
INS_DEEL_STATE_HISTORY_KEY,
|
||||
RANKING,
|
||||
INS_DEEL_STATE,
|
||||
STATUS,
|
||||
INS_DEEL_STATEDATE,
|
||||
DUUR_STATUS
|
||||
)
|
||||
AS
|
||||
SELECT d.ins_deel_omschrijving,
|
||||
d.ins_deel_key,
|
||||
r.alg_ruimte_key,
|
||||
r.alg_ruimte_nr,
|
||||
stat_his.ranking,
|
||||
stat_his.ins_deel_state,
|
||||
DECODE (stat_his.ins_deel_state,
|
||||
0, 'vrij',
|
||||
1, 'bezet',
|
||||
99, 'storing') status,
|
||||
stat_his.ins_deel_statedate,
|
||||
COALESCE (stat_his.duur_status,
|
||||
ROUND ((SYSDATE - stat_his.ins_deel_statedate) * 1440)) duur_status
|
||||
FROM ins_deel d,
|
||||
alg_ruimte r,
|
||||
(SELECT ranking,
|
||||
ins_deel_key,
|
||||
ins_deel_state,
|
||||
ins_deel_statedate,
|
||||
( ins_deel_statedate
|
||||
- LAG (ins_deel_statedate)
|
||||
OVER (PARTITION BY ins_deel_key ORDER BY ranking))
|
||||
* -1440 AS duur_status --- duur van de status in minuten
|
||||
FROM (SELECT ins_deel_key,
|
||||
ins_deel_state,
|
||||
ins_deel_statedate,
|
||||
RANK ()
|
||||
OVER (
|
||||
PARTITION BY ins_deel_key
|
||||
ORDER BY ins_deel_key, ins_deel_statedate DESC) AS ranking
|
||||
FROM ins_deel_state_history) rank_state) stat_his
|
||||
WHERE d.ins_deel_key = stat_his.ins_deel_key
|
||||
AND d.ins_alg_ruimte_key = r.alg_ruimte_key;
|
||||
SELECT d.ins_deel_omschrijving,
|
||||
d.ins_deel_key,
|
||||
r.alg_ruimte_key,
|
||||
r.alg_ruimte_nr,
|
||||
stat_his.ins_deel_state_history_key,
|
||||
stat_his.ranking,
|
||||
stat_his.ins_deel_state,
|
||||
DECODE (stat_his.ins_deel_state,
|
||||
0, 'vrij',
|
||||
1, 'bezet',
|
||||
99, 'storing') status,
|
||||
stat_his.ins_deel_statedate,
|
||||
COALESCE (stat_his.duur_status,
|
||||
ROUND ((SYSDATE - stat_his.ins_deel_statedate) * 1440)) duur_status
|
||||
FROM ins_deel d,
|
||||
alg_ruimte r,
|
||||
(SELECT ranking,
|
||||
ins_deel_key,
|
||||
ins_deel_state_history_key,
|
||||
ins_deel_state,
|
||||
ins_deel_statedate,
|
||||
( ins_deel_statedate
|
||||
- LAG (ins_deel_statedate)
|
||||
OVER (PARTITION BY ins_deel_key ORDER BY ranking))
|
||||
* -1440 AS duur_status --- duur van de status in minuten
|
||||
FROM (SELECT ins_deel_key,
|
||||
ins_deel_state_history_key,
|
||||
ins_deel_state,
|
||||
ins_deel_statedate,
|
||||
RANK ()
|
||||
OVER (
|
||||
PARTITION BY ins_deel_key
|
||||
ORDER BY
|
||||
ins_deel_key, ins_deel_statedate DESC) AS ranking
|
||||
FROM ins_deel_state_history) rank_state) stat_his
|
||||
WHERE d.ins_deel_key = stat_his.ins_deel_key
|
||||
AND d.ins_alg_ruimte_key = r.alg_ruimte_key;
|
||||
|
||||
--- bezet wordt direct bezet
|
||||
--- tussen 15 en 60 minuten vrij zien we als medewerker afwezig
|
||||
@@ -8896,19 +8924,21 @@ AS
|
||||
WHERE ranking = 1) current_state
|
||||
WHERE d.ins_deel_key = current_state.ins_deel_key;
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW PNBR_V_CAD_LABEL_SENSOREN
|
||||
AS
|
||||
SELECT ins_deel_key, ins_deel_opmerking waarde
|
||||
FROM ins_deel d
|
||||
WHERE d.ins_srtdeel_key = 3521;
|
||||
|
||||
------ payload end ------
|
||||
|
||||
SET DEFINE OFF
|
||||
|
||||
BEGIN
|
||||
adm.systrackscriptId (
|
||||
'$Id$',
|
||||
0);
|
||||
END;
|
||||
BEGIN adm.systrackscriptId ('$Id$', 0); END;
|
||||
/
|
||||
|
||||
COMMIT;
|
||||
SET ECHO OFF
|
||||
SPOOL OFF
|
||||
SET DEFINE ON
|
||||
PROMPT Logfile of this upgrade is: &fcltlogfile
|
||||
PROMPT Logfile of this upgrade is: &fcltlogfile
|
||||
|
||||
Reference in New Issue
Block a user