-
Notifications
You must be signed in to change notification settings - Fork 7
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Facilite l'accès au plan depuis un axe
- Ajoute un type aux plans - Ajoute la possibilité de restreindre un plan ou une fiche aux utilisateurs hors collectivité.
- Loading branch information
1 parent
23d525e
commit b1484af
Showing
4 changed files
with
702 additions
and
0 deletions.
There are no files selected for viewing
369 changes: 369 additions & 0 deletions
369
data_layer/sqitch/deploy/plan_action/confidentialite.sql
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,369 @@ | ||
-- Deploy tet:plan_action/confidentialite to pg | ||
|
||
BEGIN; | ||
|
||
create type plan_action_type_categorie as enum ('Plans transverses', 'Plans thématiques'); | ||
|
||
create table plan_action_type | ||
( | ||
id serial primary key, | ||
categorie plan_action_type_categorie not null, | ||
type text not null, | ||
unique (categorie, type) | ||
); | ||
alter table plan_action_type enable row level security; | ||
|
||
insert into plan_action_type (categorie, type) | ||
values ('Plans transverses', 'Projet de Territoire (dont Agenda 2030, Développement Durable)'), | ||
('Plans transverses', 'Plan de Transition Écologique (dont COT et Plan Territoire Engagé)'), | ||
('Plans transverses', 'Plan CTE/CRTE'), | ||
('Plans transverses', 'Plan Climat Air Énergie Territorial'), | ||
('Plans transverses', 'Plan Économie Circulaire & Déchets (dont PLPDMA, Territoire Econome en Ressources)'), | ||
('Plans transverses', 'Autre'), | ||
('Plans thématiques', 'Plan Urbanisme/habitat (dont SCoT, PLU, PLH, Programme d’Aménagement)'), | ||
('Plans thématiques', 'Plan Energies (dont TEPOS)'), | ||
('Plans thématiques', 'Plan Bâtiment (dont patrimoine public)'), | ||
('Plans thématiques', 'Plan Mobilité'), | ||
('Plans thématiques', 'Plan Agriculture/Alimentation'), | ||
('Plans thématiques', 'Plan Eau'), | ||
('Plans thématiques', 'Plan Biodiversité'), | ||
('Plans thématiques', 'Autre'); | ||
|
||
alter table axe add column plan integer references axe; | ||
comment on column axe.plan is 'Lien direct vers le plan pour éviter la récursivité quand on veut le récupérer'; | ||
|
||
create function upsert_axe_trigger_plan() returns trigger | ||
security definer | ||
language plpgsql | ||
as $$ | ||
declare axe_parent axe; | ||
begin | ||
axe_parent = new; | ||
while axe_parent.parent is not null | ||
loop | ||
select parent.* | ||
from axe | ||
join axe parent on axe.parent = parent.id | ||
where axe.id = axe_parent.id | ||
limit 1 into axe_parent; | ||
end loop; | ||
new.plan = axe_parent.id; | ||
return new; | ||
end; | ||
$$; | ||
|
||
create trigger axe_modifie_plan | ||
before insert or update | ||
on axe | ||
for each row | ||
execute procedure upsert_axe_trigger_plan(); | ||
|
||
-- Ajouter les plans aux axes déjà existants | ||
do $$ | ||
declare | ||
axes axe[]; | ||
a axe; | ||
a_parent axe; | ||
begin | ||
select array_agg(axe.*) from axe into axes; | ||
if axes is not null then -- Pour passer en CI | ||
foreach a in Array axes loop | ||
a_parent = a; | ||
while a_parent.parent is not null | ||
loop | ||
select parent.* | ||
from axe | ||
join axe parent on axe.parent = parent.id | ||
where axe.id = a_parent.id | ||
limit 1 into a_parent; | ||
end loop; | ||
update axe set plan = a_parent.id where id = a.id; | ||
end loop; | ||
end if; | ||
end; | ||
$$; | ||
|
||
alter table axe add column type integer references plan_action_type; | ||
comment on column axe.type is 'Type du plan'; | ||
|
||
alter table axe add column restreint boolean default false; | ||
comment on column axe.restreint is 'Vrai si le plan est restreint.'; | ||
|
||
alter table fiche_action add column restreint boolean default false; | ||
comment on column fiche_action.restreint is 'Vrai si la fiche est restreinte.'; | ||
|
||
alter policy allow_read on axe using( | ||
case when axe.restreint=true | ||
then have_lecture_acces(collectivite_id) or est_support() | ||
else can_read_acces_restreint(collectivite_id) | ||
end); | ||
|
||
create or replace function peut_lire_la_fiche(fiche_id integer) returns boolean | ||
security definer | ||
language plpgsql | ||
as | ||
$$ | ||
declare collectivite_id integer; | ||
begin | ||
select fa.collectivite_id | ||
from fiche_action fa | ||
where fa.id = fiche_id limit 1 | ||
into collectivite_id; | ||
|
||
if ( -- Fiche restreinte ? | ||
select fa.restreint = true -- null = false | ||
from fiche_action fa | ||
where fa.id = peut_lire_la_fiche.fiche_id | ||
) or ( -- ou plan restreint ? | ||
-- La fiche peut être dans plusieurs plans, | ||
-- il faut que tous ses plans soient restreints pour que la fiche le soit aussi | ||
select bool_and(plan.restreint = true) -- null = false | ||
from fiche_action_axe faa | ||
join axe on faa.axe_id = axe.id | ||
join axe plan on axe.plan = plan.id | ||
where faa.fiche_id = peut_lire_la_fiche.fiche_id | ||
) then | ||
return have_lecture_acces(collectivite_id) or est_support(); | ||
|
||
else -- Collectivité restreinte ? | ||
return can_read_acces_restreint((collectivite_id)); | ||
|
||
end if; | ||
end; | ||
$$; | ||
|
||
create or replace view private.fiche_resume | ||
(plans, titre, id, statut, collectivite_id, pilotes, modified_at, date_fin_provisoire, niveau_priorite) as | ||
SELECT p.plans, | ||
fa.titre, | ||
fa.id, | ||
fa.statut, | ||
fa.collectivite_id, | ||
(SELECT array_agg(ROW (pil.nom, pil.collectivite_id, pil.tag_id, pil.user_id)::personne) AS array_agg | ||
FROM (SELECT COALESCE(pt.nom, concat(dcp.prenom, ' ', dcp.nom)) AS nom, | ||
pt.collectivite_id, | ||
fap.tag_id, | ||
fap.user_id | ||
FROM fiche_action_pilote fap | ||
LEFT JOIN personne_tag pt ON fap.tag_id = pt.id | ||
LEFT JOIN dcp ON fap.user_id = dcp.user_id | ||
WHERE fap.fiche_id = fa.id) pil) AS pilotes, | ||
fa.modified_at, | ||
fa.date_fin_provisoire, | ||
fa.niveau_priorite | ||
FROM fiche_action fa | ||
LEFT JOIN (SELECT faa.fiche_id, | ||
array_agg(distinct plan.*) AS plans | ||
from fiche_action_axe faa | ||
join axe on faa.axe_id = axe.id | ||
join axe plan on axe.plan = plan.id | ||
GROUP BY faa.fiche_id) p ON p.fiche_id = fa.id | ||
GROUP BY fa.titre, fa.id, fa.statut, fa.collectivite_id, p.plans | ||
ORDER BY (naturalsort(fa.titre::text)); | ||
|
||
-- TODO faire pareil que private.fiche_resume avec private.indicateur_resume | ||
|
||
create or replace function plan_action_tableau_de_bord(collectivite_id integer, plan_id integer DEFAULT NULL::integer, sans_plan boolean DEFAULT false) returns plan_action_tableau_de_bord | ||
stable | ||
language plpgsql | ||
as | ||
$$ | ||
declare | ||
tableau_de_bord plan_action_tableau_de_bord; | ||
begin | ||
if can_read_acces_restreint(collectivite_id) then | ||
with | ||
fiches as (select distinct fa.*, | ||
case | ||
when fa.statut not in ('À venir', 'En cours', 'En pause') | ||
then 'NC' | ||
when fa.amelioration_continue | ||
then 'Action en amélioration continue' | ||
when fa.date_fin_provisoire is null | ||
then 'Date de fin non renseignée' | ||
when fa.date_fin_provisoire < now() | ||
then 'Échéance dépassée' | ||
when fa.date_fin_provisoire < (now() + interval '3 months') | ||
then 'Échéance dans moins de trois mois' | ||
when fa.date_fin_provisoire < (now() + interval '1 year') | ||
then 'Échéance entre trois mois et 1 an' | ||
else 'Échéance dans plus d’un an' | ||
end as echeance | ||
from fiche_action fa | ||
left join fiche_action_axe faa on faa.fiche_id = fa.id | ||
left join axe on faa.axe_id = axe.id | ||
where case | ||
when plan_action_tableau_de_bord.plan_id is not null | ||
then axe.plan = plan_action_tableau_de_bord.plan_id | ||
when sans_plan | ||
then faa is null | ||
else true | ||
end | ||
and fa.collectivite_id = plan_action_tableau_de_bord.collectivite_id), | ||
personnes as (select * | ||
from personnes_collectivite(plan_action_tableau_de_bord.collectivite_id)) | ||
select plan_action_tableau_de_bord.collectivite_id, | ||
plan_action_tableau_de_bord.plan_id, | ||
(select array_agg((t.*)::graphique_tranche) as statuts | ||
from (select coalesce(statut::text, 'NC') as id, count(*) as value | ||
from fiches | ||
group by coalesce(statut::text, 'NC')) t), | ||
(select array_agg((t.*)::graphique_tranche) as pilotes | ||
from (select coalesce(p.nom, 'NC') as id, count(f.*) as value | ||
from fiches f | ||
left join fiche_action_pilote fap on fap.fiche_id = f.id | ||
left join personnes p on fap.user_id = p.user_id or fap.tag_id = p.tag_id | ||
group by coalesce(p.nom, 'NC')) t), | ||
(select array_agg((t.*)::graphique_tranche) as referents | ||
from (select coalesce(p.nom, 'NC') as id, count(f.*) as value | ||
from fiches f | ||
left join fiche_action_referent far on far.fiche_id = f.id | ||
left join personnes p on far.user_id = p.user_id or far.tag_id = p.tag_id | ||
group by coalesce(p.nom, 'NC')) t), | ||
(select array_agg((t.*)::graphique_tranche) as priorites | ||
from (select coalesce(niveau_priorite::text, 'NC') as id, count(*) as value | ||
from fiches | ||
group by coalesce(niveau_priorite::text, 'NC')) t), | ||
(select array_agg((t.*)::graphique_tranche) as echeances | ||
from (select echeance as id, count(*) as value | ||
from fiches | ||
where echeance <> 'NC' | ||
group by echeance) t) | ||
into tableau_de_bord; | ||
return tableau_de_bord; | ||
else | ||
perform set_config('response.status', '403', true); | ||
raise 'L''utilisateur n''a pas de droit en lecture sur la collectivité.'; | ||
end if; | ||
end; | ||
$$; | ||
|
||
create or replace function filter_fiches_action(collectivite_id integer, sans_plan boolean DEFAULT false, axes_id integer[] DEFAULT NULL::integer[], sans_pilote boolean DEFAULT false, pilotes personne[] DEFAULT NULL::personne[], sans_referent boolean DEFAULT false, referents personne[] DEFAULT NULL::personne[], sans_niveau boolean DEFAULT false, niveaux_priorite fiche_action_niveaux_priorite[] DEFAULT NULL::fiche_action_niveaux_priorite[], sans_statut boolean DEFAULT false, statuts fiche_action_statuts[] DEFAULT NULL::fiche_action_statuts[], sans_thematique boolean DEFAULT false, thematiques thematique[] DEFAULT NULL::thematique[], sans_sous_thematique boolean DEFAULT false, sous_thematiques sous_thematique[] DEFAULT NULL::sous_thematique[], sans_budget boolean DEFAULT false, budget_min integer DEFAULT NULL::integer, budget_max integer DEFAULT NULL::integer, sans_date boolean DEFAULT false, date_debut timestamp with time zone DEFAULT NULL::timestamp with time zone, date_fin timestamp with time zone DEFAULT NULL::timestamp with time zone, echeance fiche_action_echeances DEFAULT NULL::fiche_action_echeances, "limit" integer DEFAULT 10) returns SETOF fiche_resume | ||
stable | ||
security definer | ||
language plpgsql | ||
as | ||
$$ | ||
# variable_conflict use_variable | ||
begin | ||
if not can_read_acces_restreint(filter_fiches_action.collectivite_id) then | ||
perform set_config('response.status', '403', true); | ||
raise 'L''utilisateur n''a pas de droit en lecture sur la collectivité.'; | ||
end if; | ||
|
||
return query | ||
select fr.* | ||
from fiche_resume fr | ||
join fiche_action fa on fr.id = fa.id | ||
where fr.collectivite_id = filter_fiches_action.collectivite_id | ||
and case -- axes_id | ||
when sans_plan then | ||
fr.id not in (select distinct fiche_id from fiche_action_axe) | ||
when axes_id is null then true | ||
else fr.id in ( | ||
select faa.fiche_id | ||
from fiche_action_axe faa | ||
join axe on faa.axe_id = axe.id | ||
join axe plan on axe.plan = plan.id | ||
where plan.id in (select * from unnest(axes_id)) | ||
) | ||
end | ||
and case -- pilotes | ||
when sans_pilote then | ||
fr.id not in (select distinct fiche_id from fiche_action_pilote) | ||
when pilotes is null then true | ||
else fr.id in | ||
(select fap.fiche_id | ||
from fiche_action_pilote fap | ||
where fap.tag_id in (select (pi::personne).tag_id from unnest(pilotes) pi) | ||
or fap.user_id in (select (pi::personne).user_id from unnest(pilotes) pi)) | ||
end | ||
and case -- referents | ||
when sans_referent then | ||
fr.id not in (select distinct fiche_id from fiche_action_referent) | ||
when referents is null then true | ||
else fr.id in | ||
(select far.fiche_id | ||
from fiche_action_referent far | ||
where far.tag_id in (select (re::personne).tag_id from unnest(referents) re) | ||
or far.user_id in (select (re::personne).user_id from unnest(referents) re)) | ||
end | ||
and case -- niveaux_priorite | ||
when sans_niveau then fa.niveau_priorite is null | ||
when niveaux_priorite is null then true | ||
else fa.niveau_priorite in (select * from unnest(niveaux_priorite::fiche_action_niveaux_priorite[])) | ||
end | ||
and case -- statuts | ||
when sans_statut then fa.statut is null | ||
when statuts is null then true | ||
else fr.statut in (select * from unnest(statuts::fiche_action_statuts[])) | ||
end | ||
and case -- thematiques | ||
when sans_thematique then | ||
fr.id not in (select distinct fiche_id from fiche_action_thematique) | ||
when thematiques is null then true | ||
else fr.id in | ||
(select fat.fiche_id | ||
from fiche_action_thematique fat | ||
where fat.thematique in (select * from unnest(thematiques::thematique[]) th)) | ||
end | ||
and case -- sous_thematiques | ||
when sans_sous_thematique then | ||
fr.id not in (select distinct fiche_id from fiche_action_sous_thematique) | ||
when sous_thematiques is null then true | ||
else fr.id in | ||
(select fast.fiche_id | ||
from fiche_action_sous_thematique fast | ||
where fast.thematique_id in (select (sth::sous_thematique).id | ||
from unnest(sous_thematiques::sous_thematique[]) sth)) | ||
end | ||
and case -- budget_min | ||
when sans_budget then fa.budget_previsionnel is null | ||
when budget_min is null then true | ||
when fa.budget_previsionnel is null then false | ||
else fa.budget_previsionnel>=budget_min | ||
end | ||
and case -- budget_max | ||
when sans_budget then fa.budget_previsionnel is null | ||
when budget_max is null then true | ||
when fa.budget_previsionnel is null then false | ||
else fa.budget_previsionnel<=budget_max | ||
end | ||
and case -- date_debut | ||
when sans_date then fa.date_debut is null | ||
when filter_fiches_action.date_debut is null then true | ||
when fa.date_debut is null then false | ||
else fa.date_debut<=filter_fiches_action.date_debut | ||
end | ||
and case -- date_fin | ||
when sans_date then fa.date_fin_provisoire is null | ||
when date_fin is null then true | ||
when fa.date_fin_provisoire is null then false | ||
else fa.date_fin_provisoire<=date_fin | ||
end | ||
and case -- echeances | ||
when echeance is null then true | ||
when echeance = 'Action en amélioration continue' | ||
then fa.amelioration_continue | ||
when echeance = 'Sans échéance' | ||
then fa.date_fin_provisoire is null | ||
when echeance = 'Échéance dépassée' | ||
then fa.date_fin_provisoire>now() | ||
when echeance = 'Échéance dans moins de trois mois' | ||
then fa.date_fin_provisoire < (now() + interval '3 months') | ||
when echeance = 'Échéance entre trois mois et 1 an' | ||
then fa.date_fin_provisoire >= (now() + interval '3 months') | ||
and fa.date_fin_provisoire < (now() + interval '1 year') | ||
when echeance = 'Échéance dans plus d’un an' | ||
then fa.date_fin_provisoire > (now() + interval '1 year') | ||
else false | ||
end | ||
order by naturalsort(fr.titre) | ||
limit filter_fiches_action."limit"; | ||
end; | ||
$$; | ||
|
||
-- TODO faire pareil que filter_fiches_action avec filter_indicateurs | ||
|
||
|
||
COMMIT; |
Oops, something went wrong.