Commit 284a960f authored by Laurent Lécluse's avatar Laurent Lécluse
Browse files

Optimisation : on peut maintenant passer jusqu'à 5 critères pour actualiser un TBL

parent d95373b2
CHANGELOG
=========
4.2 (08/11/2021)
----------------
Optimisation : on peut maintenant passer jusqu'à 5 critères pour actualiser un TBL
4.1 (03/11/2020)
----------------
......
create or replace PACKAGE "UNICAEN_TBL" AS
TYPE t_params IS RECORD (
c1 VARCHAR2(30), v1 VARCHAR2(80),
c2 VARCHAR2(30), v2 VARCHAR2(80),
c3 VARCHAR2(30), v3 VARCHAR2(80),
c4 VARCHAR2(30), v4 VARCHAR2(80),
c5 VARCHAR2(30), v5 VARCHAR2(80),
sqlcond CLOB
);
CREATE OR REPLACE PACKAGE "UNICAEN_TBL" AS
ACTIV_TRIGGERS BOOLEAN DEFAULT TRUE;
ACTIV_CALCULS BOOLEAN DEFAULT TRUE;
CALCUL_PROC_PARAMS t_params;
FUNCTION MAKE_PARAMS(
c1 VARCHAR2 DEFAULT NULL, v1 VARCHAR2 DEFAULT NULL,
c2 VARCHAR2 DEFAULT NULL, v2 VARCHAR2 DEFAULT NULL,
c3 VARCHAR2 DEFAULT NULL, v3 VARCHAR2 DEFAULT NULL,
c4 VARCHAR2 DEFAULT NULL, v4 VARCHAR2 DEFAULT NULL,
c5 VARCHAR2 DEFAULT NULL, v5 VARCHAR2 DEFAULT NULL,
sqlcond CLOB DEFAULT NULL
) RETURN t_params;
TYPE t_params IS RECORD (
p1 VARCHAR2(30), v1 VARCHAR2(80),
p2 VARCHAR2(30), v2 VARCHAR2(80),
p3 VARCHAR2(30), v3 VARCHAR2(80),
p4 VARCHAR2(30), v4 VARCHAR2(80),
p5 VARCHAR2(30), v5 VARCHAR2(80)
);
FUNCTION PARAMS_FROM_DEMS( TBL_NAME VARCHAR2 ) RETURN t_params;
FUNCTION PARAMS_TO_CONDS ( PARAMS UNICAEN_TBL.T_PARAMS, alias VARCHAR2 DEFAULT NULL ) RETURN CLOB;
CALCUL_PROC_PARAMS t_params;
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2 );
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2, CONDS CLOB );
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2, PARAMS t_params );
FUNCTION QUERY_APPLY_PARAM( sqlQuery VARCHAR2, param VARCHAR2, value VARCHAR2) RETURN CLOB;
FUNCTION MAKE_WHERE(param VARCHAR2 DEFAULT NULL, value VARCHAR2 DEFAULT NULL, alias VARCHAR2 DEFAULT NULL) RETURN VARCHAR2;
PROCEDURE CALCULER( TBL_NAME VARCHAR2 );
PROCEDURE CALCULER( TBL_NAME VARCHAR2, CONDS CLOB );
PROCEDURE CALCULER( TBL_NAME VARCHAR2, PARAMS t_params );
PROCEDURE CALCULER( TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2 );
PROCEDURE CALCULER(TBL_NAME VARCHAR2, params t_params);
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2 );
PROCEDURE ANNULER_DEMANDES;
PROCEDURE ANNULER_DEMANDES( TBL_NAME VARCHAR2 );
......@@ -42,305 +30,296 @@ create or replace PACKAGE "UNICAEN_TBL" AS
-- END OF AUTOMATIC GENERATION --
END UNICAEN_TBL;
/
CREATE OR REPLACE PACKAGE BODY "UNICAEN_TBL" AS
TYPE t_dems_values IS TABLE OF BOOLEAN INDEX BY VARCHAR2(80);
TYPE t_dems_params IS TABLE OF t_dems_values INDEX BY VARCHAR2(30);
TYPE t_dems IS TABLE OF t_dems_params INDEX BY VARCHAR2(30);
create or replace PACKAGE BODY "UNICAEN_TBL" AS
dems t_dems;
FUNCTION MAKE_PARAMS(
c1 VARCHAR2 DEFAULT NULL, v1 VARCHAR2 DEFAULT NULL,
c2 VARCHAR2 DEFAULT NULL, v2 VARCHAR2 DEFAULT NULL,
c3 VARCHAR2 DEFAULT NULL, v3 VARCHAR2 DEFAULT NULL,
c4 VARCHAR2 DEFAULT NULL, v4 VARCHAR2 DEFAULT NULL,
c5 VARCHAR2 DEFAULT NULL, v5 VARCHAR2 DEFAULT NULL,
sqlcond CLOB DEFAULT NULL
) RETURN t_params IS
params t_params;
FUNCTION MAKE_WHERE(param VARCHAR2 DEFAULT NULL, value VARCHAR2 DEFAULT NULL,
alias VARCHAR2 DEFAULT NULL) RETURN VARCHAR2 IS
res VARCHAR2(120) DEFAULT '';
BEGIN
IF c1 IS NOT NULL THEN
params.c1 := c1;
params.v1 := v1;
END IF;
IF c2 IS NOT NULL THEN
params.c2 := c2;
params.v2 := v2;
IF param IS NULL THEN
RETURN '1=1';
END IF;
IF c3 IS NOT NULL THEN
params.c3 := c3;
params.v3 := v3;
IF alias IS NOT NULL THEN
res := alias || '.';
END IF;
IF c4 IS NOT NULL THEN
params.c4 := c4;
params.v4 := v4;
IF value IS NULL THEN
RETURN res || param || ' IS NULL';
END IF;
IF c5 IS NOT NULL THEN
params.c5 := c5;
params.v5 := v5;
END IF;
params.sqlcond := sqlcond;
RETURN params;
RETURN res || param || ' = q''[' || value || ']''';
END;
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2 ) IS
p t_params;
FUNCTION QUERY_APPLY_PARAM(sqlQuery VARCHAR2, param VARCHAR2, value VARCHAR2) RETURN CLOB IS
pos NUMERIC;
paramLen NUMERIC;
paramComm VARCHAR2(200);
debComm NUMERIC;
endComm NUMERIC;
debReal NUMERIC;
realParam VARCHAR2(80);
realValue VARCHAR2(120);
q CLOB;
BEGIN
DEMANDE_CALCUL( tbl_name, p );
END;
q := sqlQuery;
IF param IS NULL THEN
RETURN q;
END IF;
paramlen := length(param);
IF value IS NULL THEN
realValue := ' IS NULL';
ELSE
BEGIN
realValue := TO_NUMBER(value);
EXCEPTION
WHEN VALUE_ERROR THEN
realValue := 'q''[' || value || ']''';
END;
realValue := '=' || realValue;
END IF;
LOOP
pos := instr(q, '/*@' || param, 1, 1);
EXIT WHEN pos = 0;
debComm := pos - 1;
endComm := instr(q, '*/', pos, 1);
paramComm := substr(q, debComm, endComm - debComm);
debReal := instr(paramComm, '=', 1, 1);
realParam := trim(substr(paramComm, debReal + 1));
--realParam := 'AND ' || substr(q,pos + paramLen + 4,endComm-pos - paramLen - 4);
realParam := 'AND ' || realParam || realValue;
q := substr(q, 1, debComm) || realParam || substr(q, endComm + 2);
END LOOP;
RETURN q;
END;
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2, CONDS CLOB ) IS
p t_params;
FUNCTION QUERY_APPLY_PARAMS(sqlQuery VARCHAR2, useParams BOOLEAN DEFAULT FALSE) RETURN CLOB IS
q CLOB;
BEGIN
p.sqlcond := CONDS;
DEMANDE_CALCUL( tbl_name, p );
END;
q := sqlQuery;
IF NOT useParams THEN
RETURN q;
END IF;
IF UNICAEN_TBL.CALCUL_PROC_PARAMS.p1 IS NOT NULL THEN
q := QUERY_APPLY_PARAM(q, UNICAEN_TBL.CALCUL_PROC_PARAMS.p1, UNICAEN_TBL.CALCUL_PROC_PARAMS.v1);
END IF;
PROCEDURE DEMANDE_CALCUL( TBL_NAME VARCHAR2, PARAMS t_params ) IS
BEGIN
INSERT INTO tbl_dems (
ID,
TBL_NAME,
c1, v1,
c2, v2,
c3, v3,
c4, v4,
c5, v5,
sqlcond
) VALUES (
TBL_DEMS_ID_SEQ.NEXTVAL,
TBL_NAME,
PARAMS.c1, PARAMS.v1,
PARAMS.c2, PARAMS.v2,
PARAMS.c3, PARAMS.v3,
PARAMS.c4, PARAMS.v4,
PARAMS.c5, PARAMS.v5,
PARAMS.sqlcond
);
END;
IF UNICAEN_TBL.CALCUL_PROC_PARAMS.p2 IS NOT NULL THEN
q := QUERY_APPLY_PARAM(q, UNICAEN_TBL.CALCUL_PROC_PARAMS.p2, UNICAEN_TBL.CALCUL_PROC_PARAMS.v2);
END IF;
IF UNICAEN_TBL.CALCUL_PROC_PARAMS.p3 IS NOT NULL THEN
q := QUERY_APPLY_PARAM(q, UNICAEN_TBL.CALCUL_PROC_PARAMS.p3, UNICAEN_TBL.CALCUL_PROC_PARAMS.v3);
END IF;
IF UNICAEN_TBL.CALCUL_PROC_PARAMS.p4 IS NOT NULL THEN
q := QUERY_APPLY_PARAM(q, UNICAEN_TBL.CALCUL_PROC_PARAMS.p4, UNICAEN_TBL.CALCUL_PROC_PARAMS.v4);
END IF;
FUNCTION PARAMS_FROM_DEMS( TBL_NAME VARCHAR2 ) RETURN t_params IS
res t_params;
conds CLOB := '';
cond CLOB;
BEGIN
FOR d IN (
SELECT *
FROM tbl_dems
WHERE tbl_name = PARAMS_FROM_DEMS.TBL_NAME
)
LOOP
cond := '';
IF d.c1 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF d.v1 IS NULL THEN
cond := cond || d.c1 || ' IS NULL';
ELSE
cond := cond || d.c1 || '=' || d.v1;
END IF;
END IF;
IF d.c2 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF d.v2 IS NULL THEN
cond := cond || d.c2 || ' IS NULL';
ELSE
cond := cond || d.c2 || '=' || d.v2;
END IF;
END IF;
IF d.c3 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF d.v3 IS NULL THEN
cond := cond || d.c3 || ' IS NULL';
ELSE
cond := cond || d.c3 || '=' || d.v3;
END IF;
END IF;
IF d.c4 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF d.v4 IS NULL THEN
cond := cond || d.c4 || ' IS NULL';
ELSE
cond := cond || d.c4 || '=' || d.v4;
END IF;
END IF;
IF d.c5 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF d.v5 IS NULL THEN
cond := cond || d.c5 || ' IS NULL';
ELSE
cond := cond || d.c5 || '=' || d.v5;
END IF;
END IF;
IF d.sqlcond IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
cond := cond || '(' || d.sqlcond || ')';
END IF;
IF conds IS NOT NULL THEN
conds := conds || ' OR ';
END IF;
conds := conds || '(' || cond || ')';
END LOOP;
IF UNICAEN_TBL.CALCUL_PROC_PARAMS.p5 IS NOT NULL THEN
q := QUERY_APPLY_PARAM(q, UNICAEN_TBL.CALCUL_PROC_PARAMS.p5, UNICAEN_TBL.CALCUL_PROC_PARAMS.v5);
END IF;
res.sqlcond := conds;
DELETE FROM tbl_dems WHERE tbl_name = PARAMS_FROM_DEMS.TBL_NAME;
RETURN res;
RETURN q;
END;
FUNCTION PARAMS_TO_CONDS ( PARAMS UNICAEN_TBL.T_PARAMS, alias VARCHAR2 DEFAULT NULL ) RETURN CLOB IS
cond CLOB;
a VARCHAR2(30);
FUNCTION PARAMS_MAKE_FILTER(useParams BOOLEAN DEFAULT FALSE) RETURN VARCHAR2 IS
filter VARCHAR2(4000) DEFAULT '';
BEGIN
IF alias IS NULL THEN
a := '';
ELSE
a := alias || '.';
IF NOT useParams THEN
RETURN '1=1';
END IF;
IF params.c1 IS NOT NULL THEN
IF params.v1 IS NULL THEN
cond := cond || a || params.c1 || ' IS NULL';
IF unicaen_tbl.calcul_proc_params.p1 IS NOT NULL THEN
IF filter IS NOT NULL THEN
filter := filter || ' AND ';
END IF;
filter := filter || 'COALESCE(v.' || unicaen_tbl.calcul_proc_params.p1 || ', t.' || unicaen_tbl.calcul_proc_params.p1 || ') ';
IF unicaen_tbl.calcul_proc_params.v1 IS NULL THEN
filter := filter || 'IS NULL';
ELSE
cond := cond || a || params.c1 || '=' || params.v1;
filter := filter || '= q''[' || unicaen_tbl.calcul_proc_params.v1 || ']''';
END IF;
END IF;
IF params.c2 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF params.v2 IS NULL THEN
cond := cond || a || params.c2 || ' IS NULL';
IF unicaen_tbl.calcul_proc_params.p2 IS NOT NULL THEN
IF filter IS NOT NULL THEN
filter := filter || ' AND ';
END IF;
filter := filter || 'COALESCE(v.' || unicaen_tbl.calcul_proc_params.p2 || ', t.' || unicaen_tbl.calcul_proc_params.p2 || ') ';
IF unicaen_tbl.calcul_proc_params.v2 IS NULL THEN
filter := filter || 'IS NULL';
ELSE
cond := cond || a || params.c2 || '=' || params.v2;
filter := filter || '= q''[' || unicaen_tbl.calcul_proc_params.v2 || ']''';
END IF;
END IF;
IF params.c3 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF params.v3 IS NULL THEN
cond := cond || a || params.c3 || ' IS NULL';
IF unicaen_tbl.calcul_proc_params.p3 IS NOT NULL THEN
IF filter IS NOT NULL THEN
filter := filter || ' AND ';
END IF;
filter := filter || 'COALESCE(v.' || unicaen_tbl.calcul_proc_params.p3 || ', t.' || unicaen_tbl.calcul_proc_params.p3 || ') ';
IF unicaen_tbl.calcul_proc_params.v3 IS NULL THEN
filter := filter || 'IS NULL';
ELSE
cond := cond || a || params.c3 || '=' || params.v3;
filter := filter || '= q''[' || unicaen_tbl.calcul_proc_params.v3 || ']''';
END IF;
END IF;
IF params.c4 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF params.v4 IS NULL THEN
cond := cond || a || params.c4 || ' IS NULL';
IF unicaen_tbl.calcul_proc_params.p4 IS NOT NULL THEN
IF filter IS NOT NULL THEN
filter := filter || ' AND ';
END IF;
filter := filter || 'COALESCE(v.' || unicaen_tbl.calcul_proc_params.p4 || ', t.' || unicaen_tbl.calcul_proc_params.p4 || ') ';
IF unicaen_tbl.calcul_proc_params.v4 IS NULL THEN
filter := filter || 'IS NULL';
ELSE
cond := cond || a || params.c4 || '=' || params.v4;
filter := filter || '= q''[' || unicaen_tbl.calcul_proc_params.v4 || ']''';
END IF;
END IF;
IF params.c5 IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
IF params.v5 IS NULL THEN
cond := cond || a || params.c5 || ' IS NULL';
IF unicaen_tbl.calcul_proc_params.p5 IS NOT NULL THEN
IF filter IS NOT NULL THEN
filter := filter || ' AND ';
END IF;
filter := filter || 'COALESCE(v.' || unicaen_tbl.calcul_proc_params.p5 || ', t.' || unicaen_tbl.calcul_proc_params.p5 || ') ';
IF unicaen_tbl.calcul_proc_params.v5 IS NULL THEN
filter := filter || 'IS NULL';
ELSE
cond := cond || a || params.c5 || '=' || params.v5;
filter := filter || '= q''[' || unicaen_tbl.calcul_proc_params.v5 || ']''';
END IF;
END IF;
IF params.sqlcond IS NOT NULL THEN
IF cond IS NOT NULL THEN cond := cond || ' AND '; END IF;
cond := cond || '(' || params.sqlcond || ')';
IF filter = '' THEN
RETURN '1=1';
END IF;
IF cond IS NULL THEN cond := '1=1'; END IF;
RETURN cond;
RETURN filter;
END;
PROCEDURE CALCULER( TBL_NAME VARCHAR2 ) IS
p t_params;
PROCEDURE CALCULER(TBL_NAME VARCHAR2) IS
params t_params;
BEGIN
ANNULER_DEMANDES( TBL_NAME );
CALCULER(TBL_NAME, p);
ANNULER_DEMANDES(TBL_NAME);
CALCULER(TBL_NAME, params);
END;
PROCEDURE CALCULER( TBL_NAME VARCHAR2, CONDS CLOB ) IS
p t_params;
PROCEDURE CALCULER(TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2) IS
calcul_proc varchar2(30);
params t_params;
BEGIN
p.sqlcond := CONDS;
CALCULER(TBL_NAME, p);
IF NOT UNICAEN_TBL.ACTIV_CALCULS THEN RETURN; END IF;
SELECT custom_calcul_proc INTO calcul_proc FROM tbl WHERE tbl_name = CALCULER.TBL_NAME;
params.p1 := param;
params.v1 := value;
unicaen_tbl.calcul_proc_params := params;
IF calcul_proc IS NOT NULL THEN
EXECUTE IMMEDIATE
'BEGIN ' || calcul_proc || '(params.p1, params.v1); END;';
ELSE
EXECUTE IMMEDIATE
'BEGIN UNICAEN_TBL.C_' || TBL_NAME || '(TRUE); END;';
END IF;
END;
PROCEDURE CALCULER( TBL_NAME VARCHAR2, PARAMS t_params ) IS
PROCEDURE CALCULER(TBL_NAME VARCHAR2, params t_params) IS
calcul_proc varchar2(30);
BEGIN
IF NOT UNICAEN_TBL.ACTIV_CALCULS THEN RETURN; END IF;
SELECT custom_calcul_proc INTO calcul_proc FROM tbl WHERE tbl_name = CALCULER.TBL_NAME;
UNICAEN_TBL.CALCUL_PROC_PARAMS := PARAMS;
unicaen_tbl.calcul_proc_params := params;
IF calcul_proc IS NOT NULL THEN
EXECUTE IMMEDIATE
'BEGIN ' || calcul_proc || '(UNICAEN_TBL.CALCUL_PROC_PARAMS); END;'
;
'BEGIN ' || calcul_proc || '(CALCUL_PROC_PARAMS.p1, CALCUL_PROC_PARAMS.v1); END;';
ELSE
EXECUTE IMMEDIATE
'BEGIN UNICAEN_TBL.C_' || TBL_NAME || '(UNICAEN_TBL.CALCUL_PROC_PARAMS); END;'
;
'BEGIN UNICAEN_TBL.C_' || TBL_NAME || '(TRUE); END;';
END IF;
END;
PROCEDURE DEMANDE_CALCUL(TBL_NAME VARCHAR2, param VARCHAR2, value VARCHAR2) IS
BEGIN
dems(TBL_NAME)(param)(value) := TRUE;
END;
PROCEDURE ANNULER_DEMANDES IS
BEGIN
DELETE FROM tbl_dems;
dems.delete;
END;
PROCEDURE ANNULER_DEMANDES( TBL_NAME VARCHAR2 ) IS
PROCEDURE ANNULER_DEMANDES(TBL_NAME VARCHAR2) IS
BEGIN
DELETE FROM tbl_dems WHERE tbl_name = ANNULER_DEMANDES.tbl_name;
IF dems.exists(tbl_name) THEN
dems(tbl_name).delete;
END IF;
END;
FUNCTION HAS_DEMANDES RETURN BOOLEAN IS
has_dems NUMERIC;
BEGIN
SELECT count(*) INTO has_dems from tbl_dems where rownum = 1;
RETURN has_dems = 1;
RETURN dems.count > 0;
END;
PROCEDURE CALCULER_DEMANDES IS
dems t_params;
d t_dems;
tbl_name VARCHAR2(30);
param VARCHAR2(30);
value VARCHAR2(80);
BEGIN
FOR d IN (
SELECT DISTINCT tbl_name FROM tbl_dems
) LOOP
dems := PARAMS_FROM_DEMS( d.tbl_name );
calculer( d.tbl_name, dems );
d := dems;
dems.delete;
tbl_name := d.FIRST;
LOOP EXIT WHEN tbl_name IS NULL;
param := d(tbl_name).FIRST;
LOOP EXIT WHEN param IS NULL;
value := d(tbl_name)(param).FIRST;
LOOP EXIT WHEN value IS NULL;
calculer(tbl_name, param, value);
value := d(tbl_name)(param).NEXT(value);
END LOOP;
param := d(tbl_name).NEXT(param);
END LOOP;
tbl_name := d.NEXT(tbl_name);
END LOOP;
IF HAS_DEMANDES THEN -- pour les boucles !!
CALCULER_DEMANDES;
......
......@@ -13,7 +13,6 @@ class Privileges extends \UnicaenAuth\Provider\Privilege\Privileges
{
const UNICAEN_TBL_ADMIN = 'unicaen-tbl-admin';
const UNICAEN_TBL_UPDATE_ACTUPROC = 'unicaen-tbl-update-actuproc';
const UNICAEN_TBL_ACTUALISATION = 'unicaen-tbl-actualisation';
}
\ No newline at end of file
......@@ -200,7 +200,7 @@ class QueryGeneratorService extends AbstractService
*/
protected function makeProcDeclaration(TableauBord $tbl)
{
return " PROCEDURE C_" . strtoupper($tbl->getName()) . "(param VARCHAR2, value VARCHAR2);";
return " PROCEDURE C_" . strtoupper($tbl->getName()) . "(useParams BOOLEAN DEFAULT FALSE);";
}
......@@ -286,31 +286,22 @@ class QueryGeneratorService extends AbstractService
$view = str_replace('\'', '\'\'', $view);
$view = str_replace("\n", "\n ", $view);
$sql = " PROCEDURE C_$tableauBord(param VARCHAR2, value VARCHAR2) IS
$sql = " PROCEDURE C_$tableauBord(useParams BOOLEAN DEFAULT FALSE) IS
TYPE r_cursor IS REF CURSOR;
c r_cursor;
d $table%rowtype;
filter VARCHAR2(150);
viewQuery CLOB;
BEGIN
viewQuery := '$view';
IF param IS NULL THEN
filter := '1=1';
ELSIF value IS NULL THEN
filter := 'COALESCE(v.' || param || ', t.' || param || ') IS NULL';
ELSE
filter := 'COALESCE(v.' || param || ', t.' || param || ') = q''[' || value || ']''';
END IF;
OPEN c FOR '
SELECT
$cols
FROM