Skip to content

Commit 8f64d37

Browse files
committed
Supprime la vue SQL suivi_audit
1 parent 24cbb90 commit 8f64d37

File tree

4 files changed

+123
-1
lines changed

4 files changed

+123
-1
lines changed
Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,10 @@
1+
-- Deploy tet:2025-07-22-remove-view-action-audit-state to pg
2+
3+
BEGIN;
4+
5+
DROP VIEW IF EXISTS suivi_audit;
6+
DROP TRIGGER IF EXISTS upsert ON public.action_audit_state;
7+
DROP FUNCTION IF EXISTS labellisation.upsert_action_audit();
8+
DROP VIEW IF EXISTS action_audit_state;
9+
10+
COMMIT;
Lines changed: 105 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,105 @@
1+
-- Revert tet:2025-07-22-remove-view-action-audit-state from pg
2+
3+
BEGIN;
4+
5+
create or replace view action_audit_state as
6+
WITH action AS (
7+
SELECT ar_1.action_id
8+
FROM private.action_hierarchy ar_1
9+
WHERE ar_1.type = 'action'::action_type
10+
)
11+
SELECT ar.action_id,
12+
aas.id AS state_id,
13+
aas.statut,
14+
aas.avis,
15+
aas.ordre_du_jour,
16+
a.id AS audit_id,
17+
a.collectivite_id,
18+
a.referentiel
19+
FROM action ar
20+
LEFT JOIN labellisation.action_audit_state aas ON ar.action_id::text = aas.action_id::text
21+
JOIN labellisation.audit a ON aas.audit_id = a.id
22+
WHERE have_lecture_acces(a.collectivite_id) OR est_support() OR est_auditeur(a.collectivite_id, a.referentiel);
23+
24+
25+
create or replace function labellisation.upsert_action_audit() returns trigger
26+
security definer
27+
language plpgsql
28+
as
29+
$$
30+
declare
31+
found_audit audit;
32+
begin
33+
if not have_edition_acces(new.collectivite_id) and
34+
not private.est_auditeur(new.collectivite_id)
35+
then
36+
perform set_config('response.status', '403', true);
37+
raise 'L''utilisateur n''a pas de droit en édition sur la collectivité.';
38+
end if;
39+
40+
found_audit = labellisation.current_audit(
41+
new.collectivite_id,
42+
(select ar.referentiel
43+
from action_relation ar
44+
where ar.id = new.action_id)
45+
);
46+
47+
if found_audit.date_debut is null
48+
then
49+
raise 'Pas d''audit en cours.';
50+
end if;
51+
52+
if not (select bool_or(auth.uid() = auditeur) from audit_auditeur where audit_id = found_audit.id)
53+
then
54+
perform set_config('response.status', '403', true);
55+
raise 'L''utilisateur n''est pas auditeur sur l''audit de la collectivité.';
56+
end if;
57+
58+
insert into labellisation.action_audit_state (audit_id, action_id, collectivite_id, avis, ordre_du_jour, statut)
59+
values (found_audit.id, new.action_id, new.collectivite_id, coalesce(new.avis, ''), new.ordre_du_jour,
60+
new.statut)
61+
on conflict (action_id, audit_id) do update set avis = excluded.avis,
62+
ordre_du_jour = excluded.ordre_du_jour,
63+
statut = excluded.statut;
64+
return new;
65+
end
66+
$$;
67+
68+
69+
create trigger upsert
70+
instead of insert
71+
on public.action_audit_state
72+
for each row
73+
execute procedure labellisation.upsert_action_audit();
74+
75+
76+
create or replace view suivi_audit as
77+
SELECT c.id AS collectivite_id,
78+
ah.referentiel,
79+
ah.action_id,
80+
ah.have_children,
81+
ah.type,
82+
COALESCE(s.statut, 'non_audite'::audit_statut) AS statut,
83+
cs.statuts,
84+
s.avis,
85+
s.ordre_du_jour,
86+
cs.ordres_du_jour
87+
FROM collectivite c
88+
JOIN private.action_hierarchy ah ON true
89+
LEFT JOIN action_audit_state s ON s.action_id::text = ah.action_id::text AND s.collectivite_id = c.id
90+
LEFT JOIN LATERAL ( SELECT
91+
CASE
92+
WHEN s.statut IS NULL THEN COALESCE(array_agg(DISTINCT aas.statut), '{non_audite}'::audit_statut[])
93+
ELSE '{}'::audit_statut[]
94+
END AS statuts,
95+
CASE
96+
WHEN s.statut IS NULL THEN COALESCE(array_agg(DISTINCT aas.ordre_du_jour), '{f}'::boolean[])
97+
ELSE '{}'::boolean[]
98+
END AS ordres_du_jour
99+
FROM action_audit_state aas
100+
JOIN private.action_hierarchy iah ON iah.action_id::text = aas.action_id::text
101+
WHERE aas.collectivite_id = c.id AND iah.type = 'action'::action_type AND (aas.action_id::text = ANY (ah.descendants::text[]))) cs ON true
102+
WHERE (ah.type = 'axe'::action_type OR ah.type = 'sous-axe'::action_type OR ah.type = 'action'::action_type) AND (have_lecture_acces(c.id) OR est_support() OR est_auditeur_action(c.id, ah.action_id))
103+
ORDER BY (naturalsort(ah.action_id::text));
104+
105+
COMMIT;

data_layer/sqitch/sqitch.plan

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -888,4 +888,4 @@ delete_navigation_plans-rpc 2025-07-24T06:40:07Z System Administrator <root@Host
888888
collectivite/collectivite_relations 2025-08-18T16:30:40Z System Administrator <root@MacBook-Air-de-Thibaut-2.local> # ajout des relations entre collectivites
889889
@v4.73.0 2025-08-27T12:05:16Z System Administrator <root@MacBook-Air-de-Thibaut-2.local> # Ajout des relations entre collectivites
890890

891-
891+
2025-07-22-remove-view-action-audit-state 2025-07-22T16:00:42Z Frederic Arnoux <frederic.arnoux@beta.gouv.fr> # Remove view action_audit_state
Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,7 @@
1+
-- Verify tet:2025-07-22-remove-view-action-audit-state on pg
2+
3+
BEGIN;
4+
5+
-- XXX Add verifications here.
6+
7+
ROLLBACK;

0 commit comments

Comments
 (0)