-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* feat: connexion à l'API de wekan et récupération de sa config * feat: import d'établissements via CSV, récupération et création de carte * feat: meilleure gestion des cas d'absence de données durant l'import wekan * renommage des variables pour fiches CRP et SF * feat: meilleure gestion des cas d'absence de données au moment de la création d'une carte * utiliser token admin pour l'édition d'une carte * ficheSFField dans fichier d'exemple de config wekan * fix: codacy recommendations * fix: golden file tests update * feat: gestion commune des erreurs de l'API wekan * feat: obtenir toutes les cartes d'un tableau Wekan * feat: ajout des champs nécessaires pour l'export wekan (#82) * $ go mod tidy * first shot * wip * modification traitement last_procol * ajout redressements * fix view score0 * mise à jour tests * update tests * mise à jour tests suite merge master * suppression fichier inutile (et vide) * corrige l'ordre des scores * update tests * fix selectConcerning qui vient quand ça l'arrange * $ test -u Co-authored-by: fcoufour <[email protected]>
- Loading branch information
Showing
66 changed files
with
1,369 additions
and
129 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,148 @@ | ||
drop materialized view v_summaries; | ||
drop materialized view v_last_effectif; | ||
drop materialized view v_diane_variation_ca; | ||
drop materialized view v_last_procol; | ||
drop materialized view v_alert_etablissement; | ||
drop materialized view v_hausse_urssaf; | ||
|
||
create materialized view v_alert_etablissement as | ||
select siret, min(libelle_liste) as first_list, | ||
max(libelle_liste) as last_list, | ||
first(alert order by batch desc) as last_alert | ||
from score0 | ||
where alert in ('Alerte seuil F1', 'Alerte seuil F2') | ||
group by siret; | ||
|
||
create unique index idx_v_alert_etablissement_siret | ||
on v_alert_etablissement (siret); | ||
|
||
create materialized view v_last_procol as | ||
select siret, | ||
case | ||
when 'liquidation' = any(array_agg(action_procol)) | ||
then 'liquidation' | ||
when 'redressement' = any(array_agg(action_procol)) | ||
then case | ||
when 'redressement_plan_continuation' = any(array_agg(action_procol || '_' || stade_procol)) | ||
then 'plan_continuation' | ||
else 'redressement' | ||
end | ||
when 'sauvegarde' = any(array_agg(action_procol)) | ||
then case | ||
when 'sauvegarde_plan_continuation' = any(array_agg(action_procol || '_' || stade_procol)) | ||
then 'plan_sauvegarde' | ||
else 'sauvegarde' | ||
end | ||
end as last_procol, | ||
max(date_effet) as date_effet, | ||
jsonb_agg( | ||
jsonb_build_object('date_effet', date_effet, 'action', action_procol, 'stade', stade_procol) order by date_effet desc | ||
) as procol_history | ||
from etablissement_procol0 | ||
group by siret; | ||
|
||
create unique index idx_v_last_procol | ||
on v_last_procol (siret); | ||
|
||
create materialized view v_diane_variation_ca as | ||
with diane as (SELECT | ||
siren, | ||
arrete_bilan_diane, | ||
exercice_diane::int, | ||
lag(arrete_bilan_diane,1) OVER (partition by siren order by arrete_bilan_diane) prev_arrete_bilan_diane, | ||
chiffre_affaire, | ||
lag(chiffre_affaire,1) OVER (partition by siren order by arrete_bilan_diane) prev_chiffre_affaire, | ||
resultat_expl, | ||
lag(resultat_expl,1) OVER (partition by siren order by arrete_bilan_diane) prev_resultat_expl, | ||
excedent_brut_d_exploitation, | ||
lag(excedent_brut_d_exploitation,1) OVER (partition by siren order by arrete_bilan_diane) prev_excedent_brut_d_exploitation | ||
from entreprise_diane0 | ||
order by siren, arrete_bilan_diane desc) | ||
select siren, | ||
first(arrete_bilan_diane) as arrete_bilan, | ||
first(exercice_diane) as exercice_diane, | ||
first(prev_chiffre_affaire) as prev_chiffre_affaire, | ||
first(chiffre_affaire) as chiffre_affaire, | ||
first(chiffre_affaire / prev_chiffre_affaire) as variation_ca, | ||
first(resultat_expl) as resultat_expl, | ||
first(prev_resultat_expl) as prev_resultat_expl, | ||
first(excedent_brut_d_exploitation) as excedent_brut_d_exploitation, | ||
first(prev_excedent_brut_d_exploitation) as prev_excedent_brut_d_exploitation | ||
from diane | ||
where coalesce(prev_chiffre_affaire,0) != 0 and coalesce(chiffre_affaire,0) != 0 and | ||
arrete_bilan_diane - '1 year'::interval = prev_arrete_bilan_diane | ||
group by siren; | ||
|
||
create unique index idx_v_diane_variation_ca_siren | ||
on v_diane_variation_ca (siren); | ||
|
||
create materialized view v_last_effectif as | ||
select siret, last(effectif order by periode) as effectif, | ||
last(periode order by periode) as periode | ||
from etablissement_periode_urssaf0 where effectif is not null | ||
group by siret; | ||
|
||
create unique index idx_v_last_effectif_siret | ||
on v_last_effectif (siret); | ||
create index idx_v_last_effectif_effectif | ||
on v_last_effectif (effectif); | ||
|
||
create materialized view v_hausse_urssaf as | ||
select siret, (array_agg(part_patronale + part_salariale order by periode desc))[0:3] as dette, | ||
case when first(part_salariale order by periode desc) > 100 then true else false end as presence_part_salariale | ||
from etablissement_periode_urssaf0 | ||
group by siret; | ||
|
||
create unique index idx_v_hausse_urssaf_siret | ||
on v_hausse_urssaf (siret); | ||
|
||
create materialized view v_summaries as | ||
with last_liste as (select first(libelle order by batch desc, algo desc) as last_liste from liste) | ||
select | ||
r.roles, et.siret, et.siren, en.raison_sociale, et.commune, | ||
d.libelle as libelle_departement, et.departement as code_departement, | ||
s.score as valeur_score, | ||
s.detail as detail_score, | ||
aet.first_list = l.last_liste as first_alert, | ||
aen.first_list as first_list_entreprise, | ||
l.last_liste as liste, | ||
di.chiffre_affaire, di.arrete_bilan, di.exercice_diane, di.variation_ca, di.resultat_expl, ef.effectif, | ||
n.libelle_n5, n.libelle_n1, et.code_activite, coalesce(ep.last_procol, 'in_bonis') as last_procol, | ||
coalesce(ap.ap, false) as activite_partielle, | ||
ap.heure_consomme as apconso_heure_consomme, | ||
ap.montant as apconso_montant, | ||
u.dette[1] > u.dette[2] or u.dette[2] > u.dette[3] as hausse_urssaf, | ||
u.dette[1] as dette_urssaf, | ||
s.alert, | ||
et.siege, g.raison_sociale as raison_sociale_groupe, | ||
ti.code_commune is not null as territoire_industrie | ||
from last_liste l | ||
inner join etablissement0 et on true | ||
inner join entreprise0 en on en.siren = et.siren | ||
inner join v_etablissement_raison_sociale etrs on etrs.id_etablissement = et.id | ||
inner join v_roles r on et.siren = r.siren | ||
inner join departements d on d.code = et.departement | ||
left join v_naf n on n.code_n5 = et.code_activite | ||
left join score0 s on et.siret = s.siret and s.libelle_liste = l.last_liste | ||
left join v_alert_etablissement aet on aet.siret = et.siret | ||
left join v_alert_entreprise aen on aen.siren = et.siren | ||
left join v_last_effectif ef on ef.siret = et.siret | ||
left join v_hausse_urssaf u on u.siret = et.siret | ||
left join v_apdemande ap on ap.siret = et.siret | ||
left join v_last_procol ep on ep.siret = et.siret | ||
left join v_diane_variation_ca di on di.siren = et.siren | ||
left join entreprise_ellisphere0 g on g.siren = et.siren | ||
left join terrind ti on ti.code_commune = et.code_commune; | ||
|
||
create index idx_v_summaries_raison_sociale on v_summaries using gin (siret gin_trgm_ops, raison_sociale gin_trgm_ops); | ||
create index idx_v_summaries_siren on v_summaries (siren); | ||
create index idx_v_summaries_siret on v_summaries (siret); | ||
create index idx_v_summaries_order_raison_sociale on v_summaries (raison_sociale, siret); | ||
create index idx_v_summaries_roles on v_summaries using gin (roles); | ||
create index idx_v_summaries_score on v_summaries ( | ||
valeur_score desc, | ||
siret, | ||
siege, | ||
effectif, | ||
code_departement, | ||
last_procol) where alert != 'Pas d''alerte'; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,4 @@ | ||
alter table score add redressements text[] default '{}'; | ||
alter table score add alert_pre_redressements text; | ||
create or replace view score0 as | ||
select * from score where version = 0; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,75 @@ | ||
CREATE OR REPLACE FUNCTION public.get_score( | ||
roles_users text[], | ||
nblimit integer, | ||
nboffset integer, | ||
libelle_liste text, | ||
siret_expression text, | ||
raison_sociale_expression text, | ||
ignore_roles boolean, | ||
ignore_zone boolean, | ||
username text, | ||
siege_uniquement boolean, | ||
order_by text, | ||
alert_only boolean, | ||
last_procol text[], | ||
departements text[], | ||
suivi boolean, | ||
effectif_min integer, | ||
effectif_max integer, | ||
sirens text[], | ||
activites text[]) | ||
RETURNS TABLE(siret text, siren text, raison_sociale text, commune text, libelle_departement text, code_departement text, valeur_score real, detail_score jsonb, first_alert boolean, chiffre_affaire real, arrete_bilan date, exercice_diane integer, variation_ca real, resultat_expl real, effectif real, libelle_n5 text, libelle_n1 text, code_activite text, last_procol text, activite_partielle boolean, apconso_heure_consomme integer, apconso_montant integer, hausse_urssaf boolean, dette_urssaf real, alert text, nb_total bigint, nb_f1 bigint, nb_f2 bigint, visible boolean, in_zone boolean, followed boolean, followed_enterprise boolean, siege boolean, raison_sociale_groupe text, territoire_industrie boolean, comment text, category text, since timestamp without time zone, urssaf boolean, dgefp boolean, score boolean, bdf boolean) | ||
LANGUAGE 'sql' | ||
COST 100 | ||
IMMUTABLE PARALLEL UNSAFE | ||
ROWS 1000 | ||
|
||
AS $BODY$ | ||
select | ||
s.siret, s.siren, s.raison_sociale, s.commune, | ||
s.libelle_departement, s.code_departement, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then sc.score end as valeur_score, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then sc.detail end as detail_score, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then s.first_alert end as first_alert, | ||
s.chiffre_affaire, s.arrete_bilan, s.exercice_diane, s.variation_ca, s.resultat_expl, s.effectif, | ||
s.libelle_n5, s.libelle_n1, s.code_activite, s.last_procol, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).dgefp then s.activite_partielle end as activite_partielle, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).dgefp then s.apconso_heure_consomme end as apconso_heure_consomme, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).dgefp then s.apconso_montant end as apconso_montant, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).urssaf then s.hausse_urssaf end as hausse_urssaf, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).urssaf then s.dette_urssaf end as dette_urssaf, | ||
case when (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then sc.alert end, | ||
count(*) over () as nb_total, | ||
count(case when sc.alert='Alerte seuil F1' and (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then 1 end) over () as nb_f1, | ||
count(case when sc.alert='Alerte seuil F2' and (permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score then 1 end) over () as nb_f2, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).visible, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).in_zone, | ||
f.id is not null as followed_etablissement, | ||
fe.siren is not null as followed_entreprise, | ||
s.siege, s.raison_sociale_groupe, territoire_industrie, | ||
f.comment, f.category, f.since, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).urssaf, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).dgefp, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).score, | ||
(permissions($1, s.roles, s.first_list_entreprise, s.code_departement, fe.siren is not null)).bdf | ||
from v_summaries s | ||
inner join score0 sc on sc.siret = s.siret and sc.libelle_liste = $4 and sc.alert != 'Pas d''alerte' | ||
left join v_naf n on n.code_n5 = s.code_activite | ||
left join etablissement_follow f on f.active and f.siret = s.siret and f.username = $9 | ||
left join v_entreprise_follow fe on fe.siren = s.siren and fe.username = $9 | ||
where | ||
(s.roles && $1 or $7) | ||
and (s.code_departement=any($1) or $8) | ||
and (s.siege or not $10) | ||
and (s.last_procol = any($13) or $13 is null) | ||
and (s.code_departement=any($14) or $14 is null) | ||
and (s.effectif >= $16 or $16 is null) | ||
and (s.effectif <= $17 or $17 is null) | ||
and (fe.siren is not null = $15 or $15 is null) | ||
and (s.raison_sociale ilike $6 or s.siret ilike $5 or coalesce($5, $6) is null) | ||
and 'score' = any($1) | ||
and (n.code_n1 = any($19) or $19 is null) | ||
order by sc.alert, sc.score desc, sc.siret | ||
limit $2 offset $3 | ||
$BODY$; | ||
|
Oops, something went wrong.