Skip to content

Commit

Permalink
Corrige les vues stats locales_labellisation_par_niveau et evolution_…
Browse files Browse the repository at this point in the history
…nombre_labellisations qui ne donnaient pas les mêmes résultats sur le nombre de 1ère étoiles.

Ajoute également l'expiration d'une labellisation qui est de 4 ans.
  • Loading branch information
amandinejacquelin committed Apr 23, 2024
1 parent 33eecd2 commit a9473d3
Show file tree
Hide file tree
Showing 13 changed files with 939 additions and 438 deletions.
270 changes: 106 additions & 164 deletions data_layer/sqitch/deploy/stats/locales.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,172 +2,114 @@

BEGIN;

-- locales_evolution_collectivite_avec_minimum_fiches
drop view stats_locales_evolution_collectivite_avec_minimum_fiches;
drop materialized view stats.locales_evolution_collectivite_avec_minimum_fiches;

create materialized view stats.locales_evolution_collectivite_avec_minimum_fiches as
with fiche_collectivite as (select mb.first_day as mois,
c.collectivite_id,
c.region_code,
c.departement_code,
coalesce(count(*) filter (where fa.created_at <= mb.last_day), 0::bigint) as fiches
from stats.monthly_bucket mb
join stats.collectivite c on true
left join fiche_action fa using (collectivite_id)
group by mb.first_day, c.collectivite_id, c.departement_code, c.region_code)
select fiche_collectivite.mois,
null::character varying(2) as code_region,
null::character varying(2) as code_departement,
count(*) filter (where fiche_collectivite.fiches > 5) as collectivites
from fiche_collectivite
group by fiche_collectivite.mois
union all
select fiche_collectivite.mois,
fiche_collectivite.region_code as code_region,
null::character varying as code_departement,
count(*) filter (where fiche_collectivite.fiches > 5) as collectivites
from fiche_collectivite
group by fiche_collectivite.mois, fiche_collectivite.region_code
union all
select fiche_collectivite.mois,
null::character varying as code_region,
fiche_collectivite.departement_code as code_departement,
count(*) filter (where fiche_collectivite.fiches > 5) as collectivites
from fiche_collectivite
group by fiche_collectivite.mois, fiche_collectivite.departement_code
order by 1;

create view stats_locales_evolution_collectivite_avec_minimum_fiches
as
select *
from stats.locales_evolution_collectivite_avec_minimum_fiches;


-- locales_evolution_nombre_fiches
drop view stats_locales_evolution_nombre_fiches;
drop materialized view stats.locales_evolution_nombre_fiches;

create materialized view stats.locales_evolution_nombre_fiches as
select mb.first_day as mois,
null::character varying(2) as code_region,
null::character varying(2) as code_departement,
count(*) filter (where fa.created_at <= mb.last_day) as fiches
from stats.monthly_bucket mb
join stats.collectivite ca on true
join fiche_action fa using (collectivite_id)
group by mb.first_day
union all
select mb.first_day as mois,
ca.region_code as code_region,
null::character varying as code_departement,
count(*) filter (where fa.created_at <= mb.last_day) as fiches
from stats.monthly_bucket mb
join stats.collectivite ca on true
left join fiche_action fa using (collectivite_id)
group by mb.first_day, ca.region_code
union all
select mb.first_day as mois,
null::character varying as code_region,
ca.departement_code as code_departement,
count(*) filter (where fa.created_at <= mb.last_day) as fiches
from stats.monthly_bucket mb
join stats.collectivite ca on true
left join fiche_action fa using (collectivite_id)
group by mb.first_day, ca.departement_code
order by 1;

create view stats_locales_evolution_nombre_fiches
create or replace function
stats.refresh_stats_locales()
returns void
as
select *
from stats.locales_evolution_nombre_fiches;

-- évolution des activation
drop view stats_locales_evolution_total_activation;
drop materialized view stats.locales_evolution_total_activation;
create materialized view stats.locales_evolution_total_activation
$$
begin
refresh materialized view stats.locales_evolution_total_activation;
refresh materialized view stats.locales_collectivite_actives_et_total_par_type;
refresh materialized view stats.locales_evolution_utilisateur;
refresh materialized view stats.locales_evolution_nombre_utilisateur_par_collectivite;
refresh materialized view stats.locales_pourcentage_completude;
refresh materialized view stats.locales_tranche_completude;
refresh materialized view stats.evolution_nombre_fiches;
refresh materialized view stats.locales_evolution_collectivite_avec_minimum_fiches;
refresh materialized view stats.locales_engagement_collectivite;
refresh materialized view stats.locales_evolution_indicateur_referentiel;
refresh materialized view stats.locales_evolution_resultat_indicateur_personnalise;
refresh materialized view stats.locales_evolution_resultat_indicateur_referentiel;
refresh materialized view stats.locales_evolution_nombre_fiches;
refresh materialized view stats.locales_evolution_collectivite_avec_indicateur_referentiel;
end
$$ language plpgsql;

drop view stats_locales_labellisation_par_niveau;
drop materialized view stats.locales_labellisation_par_niveau;

create materialized view stats.locales_labellisation_par_niveau as
WITH latest_labellisation AS (
SELECT l.collectivite_id,
l.referentiel,
(
SELECT ll.etoiles
FROM labellisation ll
WHERE ll.collectivite_id = l.collectivite_id
AND ll.referentiel = l.referentiel
AND ll.obtenue_le > (now() - interval '4 years')
ORDER BY ll.obtenue_le DESC
LIMIT 1
) AS etoiles
FROM labellisation l
GROUP BY l.collectivite_id, l.referentiel
),
labellisation_locales AS (
SELECT l.etoiles,
l.referentiel,
c.region_code,
c.departement_code
FROM latest_labellisation l
JOIN stats.collectivite c USING (collectivite_id)
WHERE l.etoiles is not null and l.etoiles>0
)
SELECT NULL::character varying(2) AS code_region,
NULL::character varying(2) AS code_departement,
labellisation_locales.referentiel,
labellisation_locales.etoiles,
count(*) AS labellisations
FROM labellisation_locales
GROUP BY labellisation_locales.referentiel, labellisation_locales.etoiles
UNION ALL
SELECT r.code AS code_region,
NULL::character varying AS code_departement,
l.referentiel,
l.etoiles,
COALESCE(count(l.*), 0::bigint) AS labellisations
FROM imports.region r
JOIN labellisation_locales l ON l.region_code::text = r.code::text
GROUP BY l.referentiel, l.etoiles, r.code
UNION ALL
SELECT NULL::character varying AS code_region,
d.code AS code_departement,
l.referentiel,
l.etoiles,
COALESCE(count(l.*), 0::bigint) AS labellisations
FROM imports.departement d
JOIN labellisation_locales l ON l.departement_code::text = d.code::text
GROUP BY l.referentiel, l.etoiles, d.code;

create view stats_locales_labellisation_par_niveau as
SELECT code_region,
code_departement,
referentiel,
etoiles,
labellisations
FROM stats.locales_labellisation_par_niveau;

create or replace function
stats.refresh_stats_locales()
returns void
as
select -- permet de filtrer
m.first_day as mois,
null:: varchar(2) as code_region,
null::varchar(2) as code_departement,

-- stats nationales
(select count(*) as count
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day) as total,
(select count(*) filter (where stats.is_fiscalite_propre(cu.nature_collectivite)) as count
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day) as total_epci,
(select count(*) filter (where cu.type_collectivite = 'syndicat'::type_collectivite) as count
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day) as total_syndicat,
(select count(*) filter (where cu.type_collectivite = 'commune'::type_collectivite) as count
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day) as total_commune,
(select count(*) filter (where cu.type_collectivite != 'commune'::type_collectivite
and cu.type_collectivite != 'syndicat'::type_collectivite
and not stats.is_fiscalite_propre(cu.nature_collectivite)) as count
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day) as total_autre
from stats.monthly_bucket m

union all

select m.first_day as mois,
r.code,
null,
(select count(*) filter ( where cu.region_code = r.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where stats.is_fiscalite_propre(cu.nature_collectivite) and cu.region_code = r.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite = 'syndicat' and cu.region_code = r.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite = 'commune' and cu.region_code = r.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite != 'commune'::type_collectivite
and cu.type_collectivite != 'syndicat'::type_collectivite
and not stats.is_fiscalite_propre(cu.nature_collectivite)
and cu.region_code = r.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day)

from imports.region r
join stats.monthly_bucket m on true

union all

select m.first_day as mois,
null,
d.code,
(select count(*) filter ( where departement_code = d.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where stats.is_fiscalite_propre(cu.nature_collectivite) and departement_code = d.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite = 'syndicat' and departement_code = d.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite = 'commune' and departement_code = d.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day),
(select count(*) filter ( where cu.type_collectivite != 'commune'::type_collectivite
and cu.type_collectivite != 'syndicat'::type_collectivite
and not stats.is_fiscalite_propre(cu.nature_collectivite)
and departement_code = d.code)
from stats.collectivite_utilisateur cu
where cu.date_activation <= m.last_day)

from imports.departement d
join stats.monthly_bucket m on true;
$$
begin
refresh materialized view stats.locales_evolution_total_activation;
refresh materialized view stats.locales_collectivite_actives_et_total_par_type;
refresh materialized view stats.locales_evolution_utilisateur;
refresh materialized view stats.locales_evolution_nombre_utilisateur_par_collectivite;
refresh materialized view stats.locales_pourcentage_completude;
refresh materialized view stats.locales_tranche_completude;
refresh materialized view stats.evolution_nombre_fiches;
refresh materialized view stats.locales_evolution_collectivite_avec_minimum_fiches;
refresh materialized view stats.locales_engagement_collectivite;
refresh materialized view stats.locales_labellisation_par_niveau;
refresh materialized view stats.locales_evolution_indicateur_referentiel;
refresh materialized view stats.locales_evolution_resultat_indicateur_personnalise;
refresh materialized view stats.locales_evolution_resultat_indicateur_referentiel;
refresh materialized view stats.locales_evolution_nombre_fiches;
refresh materialized view stats.locales_evolution_collectivite_avec_indicateur_referentiel;
end
$$ language plpgsql;

create view stats_locales_evolution_total_activation as
select *
from stats.locales_evolution_total_activation;

COMMIT;
Loading

0 comments on commit a9473d3

Please sign in to comment.