PNBR#64700 Monitoring werkplekbezetting in Facilitor
svn path=/Customer/trunk/; revision=53600
This commit is contained in:
276
PNBR/pnbr.sql
276
PNBR/pnbr.sql
@@ -9957,7 +9957,281 @@ AS
|
||||
aant_verd.aant_sensoren,
|
||||
aant_verd.max_bez_minuten_dagdeel
|
||||
ORDER BY bezetting.datum, bezetting.alg_verdieping_volgnr;
|
||||
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_wp_bezetting_dag_verd
|
||||
AS
|
||||
SELECT
|
||||
to_char (wp.ins_deel_state_date , 'IW') weeknr,
|
||||
TO_CHAR (wp.ins_deel_state_date, 'DAY')
|
||||
dag,
|
||||
CASE
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'MAANDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'MONDAY' THEN 1
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'DINSDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'TUESDAY' THEN 2
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'WOENSDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'WEDNESDAY' THEN 3
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'DONDERDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'THURSDAY' THEN 4
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'VRIJDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'FRIDAY' THEN 5
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'ZATERDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'SATURDAY' THEN 6
|
||||
WHEN UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'ZONDAG' OR UPPER (TRIM (TO_CHAR (wp.ins_deel_state_date, 'DAY'))) = 'SUNDAY' THEN 7
|
||||
ELSE 0
|
||||
END
|
||||
sortering,
|
||||
aantal_sensoren_verdieping.alg_gebouw_naam,
|
||||
aantal_sensoren_verdieping.alg_verdieping_volgnr,
|
||||
aantal_sensoren_verdieping.alg_verdieping_omschrijving,
|
||||
aantal_sensoren_verdieping.aantal_sensoren,
|
||||
aantal_sensoren_verdieping.aantal_sensoren * 8 * 60
|
||||
max_bezetting,
|
||||
SUM (DECODE (wp.status, 'BEZET', wp.duur_status, 0))
|
||||
bezet,
|
||||
ROUND (
|
||||
(SUM (DECODE (wp.status, 'BEZET', wp.duur_status, 0)))
|
||||
/ (aantal_sensoren_verdieping.aantal_sensoren * 8 * 60)
|
||||
* 100,
|
||||
2)
|
||||
perc_bezet,
|
||||
SUM (DECODE (wp.status, 'STORING', wp.duur_status, 0))
|
||||
storing,
|
||||
ROUND (
|
||||
(SUM (DECODE (wp.status, 'STORING', wp.duur_status, 0)))
|
||||
/ (aantal_sensoren_verdieping.aantal_sensoren * 8 * 60)
|
||||
* 100,
|
||||
2)
|
||||
perc_storing
|
||||
FROM pnbr_werkplekbezetting wp,
|
||||
(SELECT --First day of previous month
|
||||
TRUNC (TRUNC (SYSDATE, 'Month') - 1, 'Month') van,
|
||||
--Last day of previous month
|
||||
LAST_DAY (TRUNC (TRUNC (SYSDATE, 'Month') - 1, 'Month')) tot
|
||||
FROM DUAL) datum,
|
||||
( SELECT v.alg_verdieping_key,
|
||||
r.alg_ruimte_nr,
|
||||
r.alg_ruimte_key,
|
||||
COUNT (d.ins_deel_key) aantal_sensoren
|
||||
FROM ins_deel d, alg_ruimte r, alg_verdieping v
|
||||
WHERE d.ins_srtdeel_key = 3521
|
||||
AND d.ins_deel_verwijder IS NULL
|
||||
AND d.ins_deel_actief = 1
|
||||
AND d.ins_alg_ruimte_type = 'R'
|
||||
AND d.ins_alg_ruimte_key = r.alg_ruimte_key
|
||||
AND r.alg_verdieping_key = v.alg_verdieping_key
|
||||
GROUP BY v.alg_verdieping_key, r.alg_ruimte_nr, r.alg_ruimte_key)
|
||||
aantal_sensoren_ruimte,
|
||||
( SELECT g.alg_gebouw_naam,
|
||||
v.alg_verdieping_volgnr,
|
||||
v.alg_verdieping_omschrijving,
|
||||
v.alg_verdieping_key,
|
||||
COUNT (d.ins_deel_key) aantal_sensoren
|
||||
FROM ins_deel d,
|
||||
alg_ruimte r,
|
||||
alg_verdieping v,
|
||||
alg_gebouw g
|
||||
WHERE d.ins_srtdeel_key = 3521
|
||||
AND d.ins_deel_verwijder IS NULL
|
||||
AND d.ins_deel_actief = 1
|
||||
AND d.ins_alg_ruimte_type = 'R'
|
||||
AND d.ins_alg_ruimte_key = r.alg_ruimte_key
|
||||
AND r.alg_verdieping_key = v.alg_verdieping_key
|
||||
AND v.alg_gebouw_key = g.alg_gebouw_key
|
||||
GROUP BY g.alg_gebouw_naam,
|
||||
v.alg_verdieping_volgnr,
|
||||
v.alg_verdieping_omschrijving,
|
||||
v.alg_verdieping_key
|
||||
ORDER BY g.alg_gebouw_naam, v.alg_verdieping_volgnr)
|
||||
aantal_sensoren_verdieping
|
||||
WHERE wp.alg_ruimte_key = aantal_sensoren_ruimte.alg_ruimte_key
|
||||
AND aantal_sensoren_ruimte.alg_verdieping_key =
|
||||
aantal_sensoren_verdieping.alg_verdieping_key
|
||||
AND ins_deel_state_date >= van
|
||||
AND ins_deel_state_date <= tot
|
||||
GROUP BY aantal_sensoren_verdieping.alg_gebouw_naam,
|
||||
aantal_sensoren_verdieping.alg_verdieping_volgnr,
|
||||
aantal_sensoren_verdieping.alg_verdieping_omschrijving,
|
||||
aantal_sensoren_verdieping.aantal_sensoren,
|
||||
wp.ins_deel_state_date
|
||||
ORDER BY wp.ins_deel_state_date,
|
||||
aantal_sensoren_verdieping.alg_verdieping_volgnr;
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_wp_gem_bezetting_dag_verd
|
||||
(
|
||||
dag,
|
||||
gebouw,
|
||||
verdieping,
|
||||
max_bezetting,
|
||||
bezetting,
|
||||
perc_bezetting
|
||||
)
|
||||
AS
|
||||
SELECT sortering || '-' || dag as dag,
|
||||
alg_gebouw_naam,
|
||||
alg_verdieping_volgnr,
|
||||
SUM (max_bezetting),
|
||||
SUM (bezet),
|
||||
ROUND ((SUM (bezet) / SUM (max_bezetting)) * 100) perc
|
||||
FROM pnbr_wp_bezetting_dag_verd
|
||||
GROUP BY sortering || '-' || dag, alg_gebouw_naam, alg_verdieping_volgnr
|
||||
ORDER BY dag;
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_wp_gem_bez_weeknr_dag_verd
|
||||
(
|
||||
weeknr_dag,
|
||||
gebouw,
|
||||
verdieping,
|
||||
perc_bez
|
||||
)
|
||||
AS
|
||||
SELECT TO_CHAR (ins_deel_state_date, 'IW')
|
||||
|| ' '
|
||||
|| sortering
|
||||
|| '-'
|
||||
|| dag,
|
||||
alg_gebouw_naam,
|
||||
alg_verdieping_volgnr,
|
||||
perc_bezet
|
||||
FROM pnbr_wp_bezetting_dag_verd
|
||||
ORDER BY TO_CHAR (ins_deel_state_date, 'IW')
|
||||
|| ' '
|
||||
|| sortering
|
||||
|| '-'
|
||||
|| dag;
|
||||
|
||||
CREATE OR REPLACE VIEW PNBR_WP_BEZETTING_DAGDEEL
|
||||
(
|
||||
DATUM,
|
||||
DAG,
|
||||
DAGDEEL,
|
||||
PERC_BEZ
|
||||
)
|
||||
BEQUEATH DEFINER
|
||||
AS
|
||||
SELECT bez.datum,
|
||||
TO_CHAR (bez.datum, 'DAY') dag,
|
||||
bez.dagdeel,
|
||||
ROUND (
|
||||
( SUM (bez.bez_minuten)
|
||||
/ ( (SELECT COUNT (d.ins_deel_key) aantal_sensoren
|
||||
FROM ins_deel d
|
||||
WHERE d.ins_srtdeel_key = 3521
|
||||
AND d.ins_deel_verwijder IS NULL
|
||||
AND d.ins_deel_actief = 1
|
||||
AND d.ins_alg_ruimte_type = 'R')
|
||||
* 4
|
||||
* 60))
|
||||
* 100) perc_bez
|
||||
FROM pnbr_v_bez_sensor_dagdeel bez,
|
||||
(SELECT --First day of previous month
|
||||
TRUNC (TRUNC (SYSDATE, 'Month') - 1, 'Month') van,
|
||||
--Last day of previous month
|
||||
LAST_DAY (TRUNC (TRUNC (SYSDATE, 'Month') - 1, 'Month')) tot
|
||||
FROM DUAL) tijdlijn
|
||||
WHERE bez.datum >= van AND bez.datum <= tot
|
||||
GROUP BY bez.datum, bez.dagdeel
|
||||
ORDER BY bez.datum, bez.dagdeel DESC;
|
||||
|
||||
CREATE OR REPLACE VIEW pnbr_wp_bezetting_dagdeel_perc
|
||||
AS
|
||||
SELECT CASE
|
||||
WHEN UPPER (TRIM (dag)) = 'MAANDAG'
|
||||
OR UPPER (TRIM (dag)) = 'MONDAY'
|
||||
THEN
|
||||
1
|
||||
WHEN UPPER (TRIM (dag)) = 'DINSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'TUESDAY'
|
||||
THEN
|
||||
2
|
||||
WHEN UPPER (TRIM (dag)) = 'WOENSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'WEDNESDAY'
|
||||
THEN
|
||||
3
|
||||
WHEN UPPER (TRIM (dag)) = 'DONDERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'THURSDAY'
|
||||
THEN
|
||||
4
|
||||
WHEN UPPER (TRIM (dag)) = 'VRIJDAG'
|
||||
OR UPPER (TRIM (dag)) = 'FRIDAY'
|
||||
THEN
|
||||
5
|
||||
WHEN UPPER (TRIM (dag)) = 'ZATERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SATURDAY'
|
||||
THEN
|
||||
6
|
||||
WHEN UPPER (TRIM (dag)) = 'ZONDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SUNDAY'
|
||||
THEN
|
||||
7
|
||||
ELSE
|
||||
0
|
||||
END
|
||||
|| '-'
|
||||
|| dag AS weekdag,
|
||||
dagdeel,
|
||||
SUM (perc_bez) as perc_bez
|
||||
FROM pnbr_wp_bezetting_dagdeel
|
||||
GROUP BY CASE
|
||||
WHEN UPPER (TRIM (dag)) = 'MAANDAG'
|
||||
OR UPPER (TRIM (dag)) = 'MONDAY'
|
||||
THEN
|
||||
1
|
||||
WHEN UPPER (TRIM (dag)) = 'DINSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'TUESDAY'
|
||||
THEN
|
||||
2
|
||||
WHEN UPPER (TRIM (dag)) = 'WOENSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'WEDNESDAY'
|
||||
THEN
|
||||
3
|
||||
WHEN UPPER (TRIM (dag)) = 'DONDERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'THURSDAY'
|
||||
THEN
|
||||
4
|
||||
WHEN UPPER (TRIM (dag)) = 'VRIJDAG'
|
||||
OR UPPER (TRIM (dag)) = 'FRIDAY'
|
||||
THEN
|
||||
5
|
||||
WHEN UPPER (TRIM (dag)) = 'ZATERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SATURDAY'
|
||||
THEN
|
||||
6
|
||||
WHEN UPPER (TRIM (dag)) = 'ZONDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SUNDAY'
|
||||
THEN
|
||||
7
|
||||
ELSE
|
||||
0
|
||||
END,
|
||||
dag,
|
||||
dagdeel
|
||||
ORDER BY CASE
|
||||
WHEN UPPER (TRIM (dag)) = 'MAANDAG'
|
||||
OR UPPER (TRIM (dag)) = 'MONDAY'
|
||||
THEN
|
||||
1
|
||||
WHEN UPPER (TRIM (dag)) = 'DINSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'TUESDAY'
|
||||
THEN
|
||||
2
|
||||
WHEN UPPER (TRIM (dag)) = 'WOENSDAG'
|
||||
OR UPPER (TRIM (dag)) = 'WEDNESDAY'
|
||||
THEN
|
||||
3
|
||||
WHEN UPPER (TRIM (dag)) = 'DONDERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'THURSDAY'
|
||||
THEN
|
||||
4
|
||||
WHEN UPPER (TRIM (dag)) = 'VRIJDAG'
|
||||
OR UPPER (TRIM (dag)) = 'FRIDAY'
|
||||
THEN
|
||||
5
|
||||
WHEN UPPER (TRIM (dag)) = 'ZATERDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SATURDAY'
|
||||
THEN
|
||||
6
|
||||
WHEN UPPER (TRIM (dag)) = 'ZONDAG'
|
||||
OR UPPER (TRIM (dag)) = 'SUNDAY'
|
||||
THEN
|
||||
7
|
||||
ELSE
|
||||
0
|
||||
END;
|
||||
------ payload end ------
|
||||
|
||||
SET DEFINE OFF
|
||||
|
||||
Reference in New Issue
Block a user