#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_VIEW(kpi_v_graph_tot_tot, 0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_graph_tot_trend, 0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_graph_proc_tot, 0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_graph_proc_ond,0) 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, lcl.l('lcl_all') 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, 'appl/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_VIEW(kpi_v_graph_proc_trend,0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_graph_ond_tot, 0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_graph_ond_proc,0) 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, lcl.l('lcl_all') fclt_text0, 'appl/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, 'appl/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_VIEW(kpi_v_graph_ond_trend,0) 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, lcl.l('lcl_all') 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_VIEW(kpi_v_cat1_cat2_detail,0) ( fclt_key, locatie, alg_locatie_key, kpi_score_datum, kpi_definitie_categorie1, kpi_definitie_categorie2, kpi_code, kpi_omschrijving, kpi_uitleg, score, kleur, totaalscore, totaalkleur ) AS SELECT -1 fclt_key, lcl.l ('lcl_all') locatie, -1 alg_locatie_key, 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.alg_locatie_key, 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$') #endif // KPI