FSN#33170 KPI module versie 1

svn path=/Database/trunk/; revision=26370
This commit is contained in:
Peter Feij
2015-09-17 10:04:15 +00:00
parent 2061b414bf
commit 299ae90f6c
4 changed files with 767 additions and 25 deletions

View File

@@ -3,9 +3,227 @@
/* $Revision$
* $Id$
*/
/* TODO lcl */
_FAC_MODULE('KPI','Key Performance Indicators')
----- Grafieken -----
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Totaal ', 'kpi_v_graph_tot_tot', 2, 0, 70, 90, 100, null, fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Trend ', 'kpi_v_graph_tot_trend', 4, null, null, null, null, 'FCLT_SORT', fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Totaal ', 'kpi_v_graph_proc_tot', 2, 0, 70, 90, 100, null, fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Onderdelen ', 'kpi_v_graph_proc_ond', 1, null, null, null, null, 'FCLT_SORT', fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Trend ', 'kpi_v_graph_proc_trend', 4, null, null, null, null, 'FCLT_SORT', fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Totaal ', 'kpi_v_graph_ond_tot', 2, 0, 70, 90, 100, null, fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Onderdelen ', 'kpi_v_graph_ond_proc', 1, null, null, null, null, 'FCLT_SORT', fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
INSERT INTO fac_usrgraph
( fac_usrgraph_omschrijving, fac_usrgraph_view_name, fac_usrgraph_type, fac_usrgraph_limiet0, fac_usrgraph_limiet1, fac_usrgraph_limiet2, fac_usrgraph_limiet3, fac_usrgraph_orderby, fac_functie_key)
SELECT 'Trend ', 'kpi_v_graph_ond_trend', 4, null, null, null, null, 'FCLT_SORT', fac_functie_key FROM fac_functie WHERE fac_functie_code='WEB_PRSSYS';
SET SQLBLANKLINES ON
UPDATE fac_usrgraph SET fac_usrgraph_options = '{ title: "",
seriesDefaults: {
rendererOptions: {
background: "white",
ringColor: "#444",
needleThickness: 7,
hubRadius: 7,
intervalInnerRadius: 25,
intervalOuterRadius: 50,
shadowDepth: 0,
intervalColors: [ "#CC0000", "#EE9900", "#77BB00" ]
}
}
}'
WHERE fac_usrgraph_omschrijving = 'Totaal '; /* TODO lcl */
-- onderdeel
UPDATE fac_usrgraph SET fac_usrgraph_options = '{ title: "",
animate: true,
stackSeries: false,
seriesDefaults:{
pointLabels: {
show: true,
edgeTolerance: -100,
ypadding: 0
}
},
series: [ {
renderer: $.jqplot.BarRenderer,
rendererOptions: {
barWidth: 50,
varyBarColor: true,
shadow: false
}
} ],
axes: {
yaxis: {
min: 0,
max: 100,
ticks: [0, 20, 40, 60, 80, 100],
tickOptions: {
enableFontSupport: true,
fontFamily: "Tahoma",
fontSize: "9pt"
},
rendererOptions: {drawBaseline: false}
},
xaxis: {
tickOptions: {
enableFontSupport: true,
fontFamily: "Tahoma",
fontSize: "10pt",
showGridline: false
}
}
},
canvasOverlay: {
show: true,
objects: [ {
horizontalLine: {
name: "n070",
y: 70,
lineWidth: 1,
lineCap: "square",
color: "rgba(220, 160, 0, 0.5)",
shadow: false
}
},
{
horizontalLine: {
name: "n090",
y: 90,
lineWidth: 1,
lineCap: "square",
color: "rgba(85, 238, 0, 0.5)",
shadow: false
}
} ]
},
axesStyles: {
borderWidth: 0,
ticks: {
fontSize: "20pt",
fontFamily: "Tahoma",
textColor: "black"
},
label: {
fontFamily: "Tahoma",
textColor: "black"
}
},
grid: {
backgroundColor: "white",
borderWidth: 0,
gridLineColor: "#eee",
gridLineWidth: 1,
borderColor: "white",
shadow: false
}
}'
WHERE fac_usrgraph_omschrijving = 'Onderdelen '; /* TODO lcl */
-- trend
UPDATE fac_usrgraph SET fac_usrgraph_options = '{ title: "",
animate: true,
seriesDefaults: {
showMarker: false,
pointLabels: {
show: true
}
},
series: [ {
color: "#55acda",
shadow: true
} ],
axes: {
yaxis: {
tickOptions: {
enableFontSupport: true,
fontFamily: "Tahoma",
fontSize: "9pt"
},
rendererOptions: { drawBaseline: false }
},
xaxis: {
tickOptions: {
enableFontSupport: true,
fontFamily: "Tahoma",
fontSize: "10pt",
showGridline: false
}
}
},
axesStyles: {
borderWidth: 0,
ticks: {
fontSize: "20pt",
fontFamily: "Tahoma",
textColor: "black"
},
label: {
fontFamily: "Tahoma",
textColor: "black"
}
},
grid: {
backgroundColor: "white",
borderWidth: 0,
gridLineColor: "#eee",
gridLineWidth: 1,
borderColor: "white",
shadow: false
},
canvasOverlay: {
show: true,
objects: [ {
horizontalLine: {
name: "n070",
y: 70,
lineWidth: 2,
lineCap: "square",
color: "rgba(220, 160, 0, 0.5)",
shadow: false
}
},
{
horizontalLine: {
name: "n090",
y: 90,
lineWidth: 2,
lineCap: "square",
color: "rgba(85, 238, 0, 0.5)",
shadow: false
}
} ]
}
}'
WHERE fac_usrgraph_omschrijving = 'Trend '; /* TODO lcl */
SET SQLBLANKLINES OFF
REGISTERONCE('$Id$')
#endif // KPI

View File

@@ -3,6 +3,123 @@
* $Id$
*/
-- Hulpfuncties voor berekenen normscores en bijbehorende kleuren in de grafiek
CREATE OR REPLACE PACKAGE kpi
AS
-- Gegeven berekende score en normdrempels, bereken normscore
FUNCTION getNormScore(pScore IN NUMBER,
p000 IN NUMBER,
p070 IN NUMBER,
p090 IN NUMBER,
p100 IN NUMBER)
RETURN NUMBER;
-- Gegeven berekende score en normdrempels, bepaal kleur van grafiek (rood, oranje, groen)
FUNCTION getKleur(pScore IN NUMBER,
p000 IN NUMBER,
p070 IN NUMBER,
p090 IN NUMBER,
p100 IN NUMBER)
RETURN VARCHAR2;
-- Gegeven normscore, bepaal kleur van grafiek (rood, oranje, groen)
FUNCTION getKleurNorm(pNormScore IN NUMBER)
RETURN VARCHAR2;
END kpi;
/
CREATE OR REPLACE PACKAGE BODY kpi
AS
FUNCTION getNormScore(pScore IN NUMBER,
p000 IN NUMBER,
p070 IN NUMBER,
p090 IN NUMBER,
p100 IN NUMBER)
RETURN NUMBER
IS
v_normScore NUMBER;
BEGIN
IF (p100 < p090)
THEN
v_normScore := CASE
WHEN pScore < p100
THEN 100
WHEN pScore < p090
THEN 90 + (100-90) * (p090 - pScore) / (p090-p100)
WHEN pScore < p070
THEN 70 + ( 90-70) * (p070 - pScore) / (p070-p090)
WHEN pScore < p000
THEN ( 70- 0) * (p000 - pScore) / (p000-p070)
ELSE
0
END;
ELSE
v_normScore := CASE
WHEN pScore > p100
THEN 100
WHEN pScore > p090
THEN 90 + (100-90) * (pScore - p090) / (p100-p090)
WHEN pScore > p070
THEN 70 + ( 90-70) * (pScore - p070) / (p090-p070)
WHEN pScore > p000
THEN ( 70- 0) * (pScore - p000) / (p070-p000)
ELSE
0
END;
END IF;
RETURN v_normScore;
END getNormScore;
-- Gegeven berekende score en normdrempels, bepaal kleur van grafiek (rood, oranje, groen)
FUNCTION getKleur(pScore IN NUMBER,
p000 IN NUMBER,
p070 IN NUMBER,
p090 IN NUMBER,
p100 IN NUMBER)
RETURN VARCHAR2
IS
v_kleur VARCHAR2(7);
BEGIN
v_kleur := CASE
WHEN pScore < p100
THEN '#55EE00'
WHEN pScore < p090
THEN '#77BB00'
WHEN pScore < p070
THEN '#EE9900'
WHEN pScore < p000
THEN '#CC0000'
ELSE
'#000000'
END;
RETURN v_kleur;
END getKleur;
-- Gegeven normscore, bepaal kleur van grafiek (rood, oranje, groen)
FUNCTION getKleurNorm(pNormScore IN NUMBER)
RETURN VARCHAR2
IS
v_kleur VARCHAR2(7);
BEGIN
v_kleur := CASE
WHEN pNormScore > 100
THEN '#55EE00'
WHEN pNormScore > 90
THEN '#77BB00'
WHEN pNormScore > 70
THEN '#EE9900'
WHEN pNormScore > 0
THEN '#CC0000'
ELSE
'#000000'
END;
RETURN v_kleur;
END getKleurNorm;
END kpi;
/
REGISTERRUN('$Id$')
#endif // KPI

View File

@@ -3,31 +3,15 @@
* $Id$
*/
//CREATE TABLE akza_kpi_scores
//(
// periode DATE, -- periode (maand) waarover KPI gaat
// locatie VARCHAR2(50), -- omschrijving van alg_locatie
// alg_locatie_key NUMBER, --
//v proces VARCHAR2(50), -- proces (categorie) van KPI
//v onderdeel VARCHAR2(50), -- onderdeel (categorie) van KPI
//v kpi_code VARCHAR2(15), -- verkorte aanduiding KPI
//v kpi_omschrijving VARCHAR2(60), -- aanduiding KPI
//vv mld_melding_key NUMBER, -- melding waarin KPI-score is ingevuld
// score NUMBER(9,4), -- behaalde score voor KPI+periode+loc
// norm_drempels VARCHAR2(20), -- drempelwaardes voor KPI in periode
// norm_scores VARCHAR2(20) -- behaalde genormeerde score
//);
CREATE_TABLE(kpi_definitie, 0)
(
kpi_definitie_key NUMBER(10) PRIMARY KEY,
kpi_code VARCHAR2(15), -- verkorte aanduiding KPI
kpi_omschrijving VARCHAR2(60), -- aanduiding KPI
kpi_definitie_categorie1 VARCHAR2(50), -- proces (categorie) van KPI
kpi_definitie_categorie2 VARCHAR2(50), -- proces (categorie) van KPI
kpi_definitie_categorie3 VARCHAR2(50), -- proces (categorie) van KPI
kpi_definitie_code VARCHAR2(15), -- verkorte aanduiding KPI
kpi_definitie_omschrijving VARCHAR2(60), -- aanduiding KPI
kpi_definitie_info VARCHAR2(4000), -- uitleg
kpi_definitie_categorie1 VARCHAR2(50), -- proces van KPI
kpi_definitie_categorie2 VARCHAR2(50), -- onderdeel van KPI
kpi_definitie_categorie3 VARCHAR2(50), -- alternate groepering van KPI (future use)
kpi_definitie_drempels VARCHAR2(20), -- actuele drempelwaarde
fac_functie_key NUMBER(10) -- autorisatie
);
@@ -38,7 +22,6 @@ CREATE_TABLE(kpi_score, 0)
kpi_definitie_key NUMBER(10) CONSTRAINT kpi_r_kpi_definitie1 REFERENCES kpi_definitie(kpi_definitie_key),
kpi_score_datum DATE, -- peildatum waarover KPI gaat
alg_locatie_key NUMBER(10) CONSTRAINT kpi_r_alg_locatie1 REFERENCES alg_locatie(alg_locatie_key),
-- waarom ook niet gebouw of district?
kpi_score_xmlnode VARCHAR2(60), -- type van waarover deze KPI gaat
kpi_score_refkey NUMBER(10), -- key van de bijbehorende entiteit van type xmlnode
kpi_score_score NUMBER(9,4), -- behaalde score voor KPI+periode+loc
@@ -47,6 +30,5 @@ CREATE_TABLE(kpi_score, 0)
);
REGISTERONCE('$Id$')
#endif // KPI

View File

@@ -1,8 +1,433 @@
#ifdef KPI
/* $Revision$
* $Id$
*/
-- categorie1 = proces
-- categorie2 = onderdeel
-- categorie3: future use
/*
TODO: lcl_all
*/
CREATE_VIEW(kpi_v_kpi_scores, 0)
(
kpi_score_datum,
locatie,
alg_locatie_key,
kpi_definitie_categorie1,
kpi_definitie_categorie2,
kpi_code,
kpi_omschrijving,
kpi_definitie_info,
mld_melding_key,
score,
norm_drempels,
norm_scores
)
AS
SELECT s.kpi_score_datum,
l.alg_locatie_code,
l.alg_locatie_key,
d.kpi_definitie_categorie1,
d.kpi_definitie_categorie2,
d.kpi_definitie_code,
d.kpi_definitie_omschrijving,
d.kpi_definitie_info,
s.kpi_score_refkey,
s.kpi_score_score,
s.kpi_score_drempels,
s.kpi_score_norm_score
FROM kpi_definitie d, kpi_score s, alg_locatie l
WHERE d.kpi_definitie_key = s.kpi_definitie_key
AND kpi_score_xmlnode = 'melding'
AND s.alg_locatie_key = l.alg_locatie_key;
----- Views voor grafieken -----------------------------------------------------
-- Totaalscore op een periode, over alle processen en onderdelen.
CREATE OR REPLACE VIEW kpi_v_graph_tot_tot
AS
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_score_datum
UNION ALL
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_score_datum,
ml.alg_locatie_key,
ks.locatie;
-- Trend van laatste 12 maanden over alle processen en onderdelen.
CREATE OR REPLACE VIEW kpi_v_graph_tot_trend
AS
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG(ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX(kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key
UNION ALL
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG(ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX(kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key,
ml.alg_locatie_key,
ks.locatie;
-- Totalen op een periode per proces.
CREATE OR REPLACE VIEW kpi_v_graph_proc_tot
AS
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie1 fclt_text2
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_definitie_categorie1,
ks.kpi_score_datum
UNION ALL
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
TO_CHAR (ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie1 fclt_text2
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_definitie_categorie1,
ks.kpi_score_datum,
ml.alg_locatie_key,
ks.locatie;
-- Score op een periode van Onderdelen, per proces.
CREATE OR REPLACE VIEW kpi_v_graph_proc_ond
AS
SELECT kpi_definitie_categorie2 fclt_xas_,
AVG(ks.score) fclt_yas_,
kpi.getKleurNorm(AVG(ks.score)) fclt_color,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
'appl/kpi/kpi_detail.asp?fclt_key=-1'
|| '&periode=' || TO_CHAR(ks.kpi_score_datum, 'yyyymm')
|| '&fclt_f_kpi_definitie_categorie1=' || ks.kpi_definitie_categorie1
fclt_url,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie1 fclt_text2,
ks.kpi_definitie_categorie2 fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_definitie_categorie1,
ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie2
UNION ALL
SELECT kpi_definitie_categorie2 fclt_xas_,
AVG(ks.score) fclt_yas_,
kpi.getKleurNorm(AVG(ks.score)) fclt_color,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
'kpi/kpi/kpi_detail.asp?fclt_key=' || ml.alg_locatie_key
|| '&periode=' || TO_CHAR(ks.kpi_score_datum, 'yyyymm')
|| '&fclt_f_kpi_definitie_categorie1=' || ks.kpi_definitie_categorie1
fclt_url,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie1 fclt_text2,
ks.kpi_definitie_categorie2 fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_definitie_categorie1,
ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie2,
ml.alg_locatie_key,
ks.locatie;
-- Trend, per proces.
CREATE OR REPLACE VIEW kpi_v_graph_proc_trend
AS
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG(ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
ks.kpi_definitie_categorie1 fclt_text2,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX(kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie1
UNION ALL
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG (ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
ks.kpi_definitie_categorie1 fclt_text2,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX (kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie1,
ml.alg_locatie_key,
ks.locatie;
-- Totalen op een periode, per onderdeel.
CREATE OR REPLACE VIEW kpi_v_graph_ond_tot
AS
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie2 fclt_text2
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_definitie_categorie2,
ks.kpi_score_datum
UNION ALL
SELECT TO_CHAR(ROUND(AVG(ks.score), 1)) fclt_xas_,
100 fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie2 fclt_text2
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ml.prs_perslid_key,
ks.kpi_definitie_categorie2,
ks.kpi_score_datum,
ml.alg_locatie_key,
ks.locatie;
-- Score op een periode van Onderdelen, per proces.
CREATE OR REPLACE VIEW kpi_v_graph_ond_proc
AS
SELECT ks.kpi_definitie_categorie1 fclt_xas_,
AVG(ks.score) fclt_yas_,
kpi.getKleurNorm(AVG(ks.score)) fclt_color,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
'kpi/kpi/kpi_detail.asp?fclt_key=-1'
|| '&periode=' || TO_CHAR(ks.kpi_score_datum, 'yyyymm')
|| '&fclt_f_kpi_definitie_categorie2=' || ks.kpi_definitie_categorie2
fclt_url,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie2 fclt_text2,
ks.kpi_definitie_categorie1 fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_definitie_categorie2,
ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie1
UNION ALL
SELECT ks.kpi_definitie_categorie1 fclt_xas_,
AVG(ks.score) fclt_yas_,
kpi.getKleurNorm(AVG(ks.score)) fclt_color,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
'kpi/kpi/kpi_detail.asp?fclt_key=' || ml.alg_locatie_key
|| '&periode=' || TO_CHAR(ks.kpi_score_datum, 'yyyymm')
|| '&fclt_f_kpi_definitie_categorie2=' || ks.kpi_definitie_categorie2
fclt_url,
TO_CHAR(ks.kpi_score_datum, 'yyyymm') fclt_text1,
ks.kpi_definitie_categorie2 fclt_text2,
kpi_definitie_categorie1 fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_definitie_categorie2,
ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie1,
ml.alg_locatie_key,
ks.locatie;
-- Trend, per kpi_definitie_categorie2.
CREATE OR REPLACE VIEW kpi_v_graph_ond_trend
AS
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG(ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
-1 fclt_key,
'Alle' fclt_text0,
ks.kpi_definitie_categorie2 fclt_text2,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX(kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie2
UNION ALL
SELECT TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_xas_,
ROUND(AVG(ks.score), 1) fclt_yas_,
ml.prs_perslid_key fclt_3d_user_key,
ml.alg_locatie_key fclt_key,
ks.locatie fclt_text0,
ks.kpi_definitie_categorie2 fclt_text2,
TO_CHAR(ks.kpi_score_datum, 'YYYY-MM') fclt_sort
FROM kpi_v_kpi_scores ks,
fac_v_my_locations ml
WHERE ks.kpi_score_datum > (SELECT ADD_MONTHS(MAX(kpi_score_datum), -12) FROM kpi_v_kpi_scores)
AND ml.alg_locatie_key = ks.alg_locatie_key
GROUP BY ks.kpi_score_datum,
ml.prs_perslid_key,
ks.kpi_definitie_categorie2,
ml.alg_locatie_key,
ks.locatie;
-- Details score.
CREATE OR REPLACE VIEW kpi_v_cat1_cat2_detail
AS
SELECT -1 fclt_key,
'Alle' locatie,
po.kpi_score_datum,
po.kpi_definitie_categorie1,
po.kpi_definitie_categorie2,
kpis.kpi_code,
kpis.kpi_omschrijving,
kpis.kpi_definitie_info kpi_uitleg,
kpis.score,
kpis.kleur,
po.score totaalscore,
po.kleur totaalkleur
FROM ( SELECT ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ROUND (AVG (ks.score), 1) score,
kpi.getkleurnorm (AVG (ks.score)) kleur
FROM kpi_v_kpi_scores ks
GROUP BY ks.kpi_score_datum, ks.kpi_definitie_categorie1, ks.kpi_definitie_categorie2) po
LEFT OUTER JOIN
( SELECT ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ROUND (AVG (ks.score), 1) score,
kpi.getkleurnorm (AVG (ks.score)) kleur,
ks.kpi_code,
ks.kpi_omschrijving,
ks.kpi_definitie_info
FROM kpi_v_kpi_scores ks
GROUP BY ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ks.kpi_code,
ks.kpi_omschrijving,
ks.kpi_definitie_info) kpis
ON kpis.kpi_definitie_categorie1 = po.kpi_definitie_categorie1
AND kpis.kpi_definitie_categorie2 = po.kpi_definitie_categorie2
AND kpis.kpi_score_datum = po.kpi_score_datum
UNION ALL
SELECT po.alg_locatie_key fclt_key,
po.locatie,
po.kpi_score_datum,
po.kpi_definitie_categorie1,
po.kpi_definitie_categorie2,
kpis.kpi_code,
kpis.kpi_omschrijving,
kpis.kpi_definitie_info kpi_uitleg,
kpis.score,
kpis.kleur,
po.score totaalscore,
po.kleur totaalkleur
FROM ( SELECT ks.alg_locatie_key,
ks.locatie,
ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ROUND (AVG (ks.score), 1) score,
kpi.getkleurnorm (AVG (ks.score)) kleur
FROM kpi_v_kpi_scores ks
GROUP BY ks.alg_locatie_key,
ks.locatie,
ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2) po
LEFT OUTER JOIN
( SELECT ks.alg_locatie_key,
ks.locatie,
ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ROUND (AVG (ks.score), 1) score,
kpi.getkleurnorm (AVG (ks.score)) kleur,
ks.kpi_code,
ks.kpi_omschrijving,
ks.kpi_definitie_info
FROM kpi_v_kpi_scores ks
GROUP BY ks.alg_locatie_key,
ks.locatie,
ks.kpi_score_datum,
ks.kpi_definitie_categorie1,
ks.kpi_definitie_categorie2,
ks.kpi_code,
ks.kpi_omschrijving,
ks.kpi_definitie_info) kpis
ON kpis.kpi_definitie_categorie1 = po.kpi_definitie_categorie1
AND kpis.kpi_definitie_categorie2 = po.kpi_definitie_categorie2
AND kpis.locatie = po.locatie
AND kpis.kpi_score_datum = po.kpi_score_datum;
REGISTERRUN('$Id$')