Skip to content

Commit

Permalink
#1195: Mise à jour du système de mise à jour des agrégats des avis po…
Browse files Browse the repository at this point in the history
…ur utiliser le stockage optimisé des avis
  • Loading branch information
ldubost authored and raphj committed Dec 21, 2022
1 parent d3ba794 commit fb47d7a
Show file tree
Hide file tree
Showing 3 changed files with 90 additions and 88 deletions.
79 changes: 36 additions & 43 deletions aggregates/calc.sql
Original file line number Diff line number Diff line change
@@ -1,61 +1,54 @@
delete from avis_byday where date_format(day,'%Y%m') = @MONTH;
insert ignore into avis_byday
select cast(xwd_creation_date as date) as day, xws_value as demarche, count(*) as count,
sum(CASE WHEN score.xwi_value=3 THEN 1 ELSE 0 END) as avis3,
sum(CASE WHEN score.xwi_value=2 THEN 1 ELSE 0 END) as avis2,
sum(CASE WHEN score.xwi_value=1 THEN 1 ELSE 0 END) as avis1,
sum(CASE WHEN facile.xwi_value=3 THEN 1 ELSE 0 END) as facile3,
sum(CASE WHEN facile.xwi_value=2 THEN 1 ELSE 0 END) as facile2,
sum(CASE WHEN facile.xwi_value=1 THEN 1 ELSE 0 END) as facile1,
sum(CASE WHEN compr.xwi_value=3 THEN 1 ELSE 0 END) as compr3,
sum(CASE WHEN compr.xwi_value=2 THEN 1 ELSE 0 END) as compr2,
sum(CASE WHEN compr.xwi_value=1 THEN 1 ELSE 0 END) as compr1,
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche, count(*) as count,
sum(CASE WHEN avis.avis_score=3 THEN 1 ELSE 0 END) as avis3,
sum(CASE WHEN avis.avis_score=2 THEN 1 ELSE 0 END) as avis2,
sum(CASE WHEN avis.avis_score=1 THEN 1 ELSE 0 END) as avis1,
sum(CASE WHEN avis.avis_facile=3 THEN 1 ELSE 0 END) as facile3,
sum(CASE WHEN avis.avis_facile=2 THEN 1 ELSE 0 END) as facile2,
sum(CASE WHEN avis.avis_facile=1 THEN 1 ELSE 0 END) as facile1,
sum(CASE WHEN avis.avis_comprehensible=3 THEN 1 ELSE 0 END) as compr3,
sum(CASE WHEN avis.avis_comprehensible=2 THEN 1 ELSE 0 END) as compr2,
sum(CASE WHEN avis.avis_comprehensible=1 THEN 1 ELSE 0 END) as compr1,
null, null, null, null, null, null, null,
null, null, null, null, null, null,
null, null, null,
null
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikiintegers score on (xwo_id=score.xwi_id and score.xwi_name='score' )
left outer join xwikiintegers facile on (xwo_id=facile.xwi_id and facile.xwi_name='facile')
left outer join xwikiintegers compr on (xwo_id=compr.xwi_id and compr.xwi_name='comprehensible')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m') = @MONTH
from avis
where date_format(avis.avis_date,'%Y%m') = @MONTH
group by 1,2;
update avis_byday agg JOIN (
select cast(xwd_creation_date as date) as day, xws_value as demarche,
sum(CASE WHEN diff.xwl_value='manque-d-informations' THEN 1 ELSE 0 END) as diff_manquedinformations,
sum(CASE WHEN diff.xwl_value='dysfonctionnement' THEN 1 ELSE 0 END) as diff_dysfonctionnement,
sum(CASE WHEN diff.xwl_value='mobile' THEN 1 ELSE 0 END) as diff_mobile,
sum(CASE WHEN diff.xwl_value='pieces-jointes' THEN 1 ELSE 0 END) as diff_piecesjointes,
sum(CASE WHEN diff.xwl_value='suite' THEN 1 ELSE 0 END) as diff_suite,
sum(CASE WHEN diff.xwl_value='autre' THEN 1 ELSE 0 END) as diff_autre
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikilistitems diff on (xwo_id=xwl_id and xwl_name='difficultes')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m') = @MONTH
group by 1,2) data ON agg.day = data.day AND agg.demarche = data.demarche
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche,
sum(CASE WHEN diff.value='manque-d-informations' THEN 1 ELSE 0 END) as diff_manquedinformations,
sum(CASE WHEN diff.value='dysfonctionnement' THEN 1 ELSE 0 END) as diff_dysfonctionnement,
sum(CASE WHEN diff.value='mobile' THEN 1 ELSE 0 END) as diff_mobile,
sum(CASE WHEN diff.value='pieces-jointes' THEN 1 ELSE 0 END) as diff_piecesjointes,
sum(CASE WHEN diff.value='suite' THEN 1 ELSE 0 END) as diff_suite,
sum(CASE WHEN diff.value='autre' THEN 1 ELSE 0 END) as diff_autre
from avis
LEFT OUTER JOIN avis_difficultes diff on (avis.xwo_id=diff.avis_id)
where date_format(avis.avis_date,'%Y%m') = @MONTH
group by 1,2) data
ON agg.day = data.day AND agg.demarche = data.demarche
SET agg.diff_manquedinformations = data.diff_manquedinformations,
agg.diff_dysfonctionnement = data.diff_dysfonctionnement,
agg.diff_mobile = data.diff_mobile,
agg.diff_piecesjointes = data.diff_piecesjointes,
agg.diff_suite = data.diff_suite,
agg.diff_autre = data.diff_autre;
update avis_byday agg JOIN (
select cast(xwd_creation_date as date) as day, xws_value as demarche,
sum(CASE WHEN aide.xwl_value='proche' THEN 1 ELSE 0 END) as aide_proche,
sum(CASE WHEN aide.xwl_value='association' THEN 1 ELSE 0 END) as aide_association,
sum(CASE WHEN aide.xwl_value='agent' THEN 1 ELSE 0 END) as aide_agent,
sum(CASE WHEN aide.xwl_value='internet' THEN 1 ELSE 0 END) as aide_internet,
sum(CASE WHEN aide.xwl_value='autre' THEN 1 ELSE 0 END) as aide_autre,
sum(CASE WHEN aide.xwl_value='aucune' THEN 1 ELSE 0 END) as aide_aucune
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikilistitems aide on (xwo_id=xwl_id and xwl_name='aide')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m') = @MONTH
group by 1,2) data ON agg.day = data.day AND agg.demarche = data.demarche
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche,
sum(CASE WHEN aide.value='proche' THEN 1 ELSE 0 END) as aide_proche,
sum(CASE WHEN aide.value='association' THEN 1 ELSE 0 END) as aide_association,
sum(CASE WHEN aide.value='agent' THEN 1 ELSE 0 END) as aide_agent,
sum(CASE WHEN aide.value='internet' THEN 1 ELSE 0 END) as aide_internet,
sum(CASE WHEN aide.value='autre' THEN 1 ELSE 0 END) as aide_autre,
sum(CASE WHEN aide.value='aucune' THEN 1 ELSE 0 END) as aide_aucune
from avis
LEFT OUTER JOIN avis_aide aide on (avis.xwo_id=aide.avis_id)
where date_format(avis.avis_date,'%Y%m') = @MONTH
group by 1,2) data
ON agg.day = data.day AND agg.demarche = data.demarche
SET agg.aide_proche = data.aide_proche,
agg.aide_association = data.aide_association,
agg.aide_agent = data.aide_agent,
Expand Down
20 changes: 18 additions & 2 deletions aggregates/calcbymonth.sh
Original file line number Diff line number Diff line change
@@ -1,6 +1,22 @@
#!/bin/sh
LEN=0
if [ "$#" -gt 0 ];
then
LEN=${#1}
fi
if [ "$LEN" -eq "6" ];
then
PERIOD=$1
echo "Running script for $PERIOD"
mysql -u root xwiki -e "set @MONTH=$PERIOD; source $(dirname "$0")/calc.sql;"
elif [ "$LEN" -eq "4" ];
then
YEAR=$1
for MONTH in 01 02 03 04 05 06 07 08 09 10 11 12; do
echo $MONTH;
mysql -u root xwiki -e "set @MONTH=$YEAR$MONTH; source $(dirname "$0")/calc.sql;"
PERIOD=$YEAR$MONTH
echo "Running script for $PERIOD"
mysql -u root xwiki -e "set @MONTH=$PERIOD; source $(dirname "$0")/calc.sql;"
done
else
echo "Missing year or month parameter"
fi
79 changes: 36 additions & 43 deletions aggregates/update.sql
Original file line number Diff line number Diff line change
@@ -1,61 +1,54 @@
delete from avis_byday where day >= cast(date_add(now(), interval -1 day) as date);
insert ignore into avis_byday
select cast(xwd_creation_date as date) as day, xws_value as demarche, count(*) as count,
sum(CASE WHEN score.xwi_value=3 THEN 1 ELSE 0 END) as avis3,
sum(CASE WHEN score.xwi_value=2 THEN 1 ELSE 0 END) as avis2,
sum(CASE WHEN score.xwi_value=1 THEN 1 ELSE 0 END) as avis1,
sum(CASE WHEN facile.xwi_value=3 THEN 1 ELSE 0 END) as facile3,
sum(CASE WHEN facile.xwi_value=2 THEN 1 ELSE 0 END) as facile2,
sum(CASE WHEN facile.xwi_value=1 THEN 1 ELSE 0 END) as facile1,
sum(CASE WHEN compr.xwi_value=3 THEN 1 ELSE 0 END) as compr3,
sum(CASE WHEN compr.xwi_value=2 THEN 1 ELSE 0 END) as compr2,
sum(CASE WHEN compr.xwi_value=1 THEN 1 ELSE 0 END) as compr1,
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche, count(*) as count,
sum(CASE WHEN avis.avis_score=3 THEN 1 ELSE 0 END) as avis3,
sum(CASE WHEN avis.avis_score=2 THEN 1 ELSE 0 END) as avis2,
sum(CASE WHEN avis.avis_score=1 THEN 1 ELSE 0 END) as avis1,
sum(CASE WHEN avis.avis_facile=3 THEN 1 ELSE 0 END) as facile3,
sum(CASE WHEN avis.avis_facile=2 THEN 1 ELSE 0 END) as facile2,
sum(CASE WHEN avis.avis_facile=1 THEN 1 ELSE 0 END) as facile1,
sum(CASE WHEN avis.avis_comprehensible=3 THEN 1 ELSE 0 END) as compr3,
sum(CASE WHEN avis.avis_comprehensible=2 THEN 1 ELSE 0 END) as compr2,
sum(CASE WHEN avis.avis_comprehensible=1 THEN 1 ELSE 0 END) as compr1,
null, null, null, null, null, null, null,
null, null, null, null, null, null,
null, null, null,
null
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikiintegers score on (xwo_id=score.xwi_id and score.xwi_name='score' )
left outer join xwikiintegers facile on (xwo_id=facile.xwi_id and facile.xwi_name='facile')
left outer join xwikiintegers compr on (xwo_id=compr.xwi_id and compr.xwi_name='comprehensible')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
from avis
where date_format(avis.avis_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
group by 1,2;
update avis_byday agg JOIN (
select cast(xwd_creation_date as date) as day, xws_value as demarche,
sum(CASE WHEN diff.xwl_value='manque-d-informations' THEN 1 ELSE 0 END) as diff_manquedinformations,
sum(CASE WHEN diff.xwl_value='dysfonctionnement' THEN 1 ELSE 0 END) as diff_dysfonctionnement,
sum(CASE WHEN diff.xwl_value='mobile' THEN 1 ELSE 0 END) as diff_mobile,
sum(CASE WHEN diff.xwl_value='pieces-jointes' THEN 1 ELSE 0 END) as diff_piecesjointes,
sum(CASE WHEN diff.xwl_value='suite' THEN 1 ELSE 0 END) as diff_suite,
sum(CASE WHEN diff.xwl_value='autre' THEN 1 ELSE 0 END) as diff_autre
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikilistitems diff on (xwo_id=xwl_id and xwl_name='difficultes')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
group by 1,2) data ON agg.day = data.day AND agg.demarche = data.demarche
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche,
sum(CASE WHEN diff.value='manque-d-informations' THEN 1 ELSE 0 END) as diff_manquedinformations,
sum(CASE WHEN diff.value='dysfonctionnement' THEN 1 ELSE 0 END) as diff_dysfonctionnement,
sum(CASE WHEN diff.value='mobile' THEN 1 ELSE 0 END) as diff_mobile,
sum(CASE WHEN diff.value='pieces-jointes' THEN 1 ELSE 0 END) as diff_piecesjointes,
sum(CASE WHEN diff.value='suite' THEN 1 ELSE 0 END) as diff_suite,
sum(CASE WHEN diff.value='autre' THEN 1 ELSE 0 END) as diff_autre
from avis
LEFT OUTER JOIN avis_difficultes diff on (avis.xwo_id=diff.avis_id)
where date_format(avis.avis_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
group by 1,2) data
ON agg.day = data.day AND agg.demarche = data.demarche
SET agg.diff_manquedinformations = data.diff_manquedinformations,
agg.diff_dysfonctionnement = data.diff_dysfonctionnement,
agg.diff_mobile = data.diff_mobile,
agg.diff_piecesjointes = data.diff_piecesjointes,
agg.diff_suite = data.diff_suite,
agg.diff_autre = data.diff_autre;
update avis_byday agg JOIN (
select cast(xwd_creation_date as date) as day, xws_value as demarche,
sum(CASE WHEN aide.xwl_value='proche' THEN 1 ELSE 0 END) as aide_proche,
sum(CASE WHEN aide.xwl_value='association' THEN 1 ELSE 0 END) as aide_association,
sum(CASE WHEN aide.xwl_value='agent' THEN 1 ELSE 0 END) as aide_agent,
sum(CASE WHEN aide.xwl_value='internet' THEN 1 ELSE 0 END) as aide_internet,
sum(CASE WHEN aide.xwl_value='autre' THEN 1 ELSE 0 END) as aide_autre,
sum(CASE WHEN aide.xwl_value='aucune' THEN 1 ELSE 0 END) as aide_aucune
from xwikidoc use index (doc_creation_date), xwikistrings demarche,
xwikiobjects avis left outer join xwikilistitems aide on (xwo_id=xwl_id and xwl_name='aide')
where xwd_fullname=xwo_name and xwo_classname='Avis.Code.AvisClass'
and xwo_id=xws_id and xws_name='demarche'
and date_format(xwd_creation_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
group by 1,2) data ON agg.day = data.day AND agg.demarche = data.demarche
select cast(avis.avis_date as date) as day, avis.avis_demarche as demarche,
sum(CASE WHEN aide.value='proche' THEN 1 ELSE 0 END) as aide_proche,
sum(CASE WHEN aide.value='association' THEN 1 ELSE 0 END) as aide_association,
sum(CASE WHEN aide.value='agent' THEN 1 ELSE 0 END) as aide_agent,
sum(CASE WHEN aide.value='internet' THEN 1 ELSE 0 END) as aide_internet,
sum(CASE WHEN aide.value='autre' THEN 1 ELSE 0 END) as aide_autre,
sum(CASE WHEN aide.value='aucune' THEN 1 ELSE 0 END) as aide_aucune
from avis
LEFT OUTER JOIN avis_aide aide on (avis.xwo_id=aide.avis_id)
where date_format(avis.avis_date,'%Y%m%d') in (date_format(now(), '%Y%m%d'), date_format(date_add(now(), interval -1 day), '%Y%m%d'))
group by 1,2) data
ON agg.day = data.day AND agg.demarche = data.demarche
SET agg.aide_proche = data.aide_proche,
agg.aide_association = data.aide_association,
agg.aide_agent = data.aide_agent,
Expand Down

0 comments on commit fb47d7a

Please sign in to comment.