Skip to content

Commit b1f2322

Browse files
Email de bilan contrôle hebdomadaire aux unités (#3528)
## Linked issues - Resolve #3004
2 parents d2135d6 + ae38541 commit b1f2322

File tree

20 files changed

+2112
-295
lines changed

20 files changed

+2112
-295
lines changed
Lines changed: 141 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,141 @@
1+
DROP MATERIALIZED VIEW analytics_controls_full_data;
2+
3+
CREATE MATERIALIZED VIEW public.analytics_controls_full_data AS
4+
5+
WITH controls_gears AS (
6+
SELECT
7+
id,
8+
array_agg(COALESCE(gear->>'gearCode', 'Aucun engin')) AS gears
9+
FROM mission_actions
10+
LEFT JOIN LATERAL jsonb_array_elements(
11+
CASE WHEN jsonb_typeof(gear_onboard) = 'array'
12+
THEN gear_onboard ELSE '[]'
13+
END
14+
) AS gear
15+
ON true
16+
WHERE action_type IN ('SEA_CONTROL', 'LAND_CONTROL', 'AIR_CONTROL') GROUP BY id
17+
),
18+
19+
controls_species AS (
20+
SELECT
21+
id,
22+
array_agg(COALESCE(species->>'speciesCode', 'Aucune capture')) AS species
23+
FROM mission_actions
24+
LEFT JOIN LATERAL jsonb_array_elements(
25+
CASE WHEN jsonb_typeof(species_onboard) = 'array'
26+
THEN species_onboard ELSE '[]'
27+
END
28+
) AS species
29+
ON true
30+
WHERE action_type IN ('SEA_CONTROL', 'LAND_CONTROL', 'AIR_CONTROL') GROUP BY id
31+
),
32+
33+
action_infractions AS (
34+
SELECT
35+
id,
36+
jsonb_array_elements(
37+
CASE WHEN jsonb_typeof(logbook_infractions) = 'array' THEN logbook_infractions ELSE '[]' END ||
38+
CASE WHEN jsonb_typeof(gear_infractions) = 'array' THEN gear_infractions ELSE '[]' END ||
39+
CASE WHEN jsonb_typeof(species_infractions) = 'array' THEN species_infractions ELSE '[]' END ||
40+
CASE WHEN jsonb_typeof(other_infractions) = 'array' THEN other_infractions ELSE '[]' END
41+
) AS mission_infraction
42+
FROM mission_actions
43+
WHERE
44+
action_type IN ('SEA_CONTROL', 'LAND_CONTROL', 'AIR_CONTROL') AND
45+
jsonb_array_length(
46+
CASE WHEN jsonb_typeof(logbook_infractions) = 'array' THEN logbook_infractions ELSE '[]' END ||
47+
CASE WHEN jsonb_typeof(gear_infractions) = 'array' THEN gear_infractions ELSE '[]' END ||
48+
CASE WHEN jsonb_typeof(species_infractions) = 'array' THEN species_infractions ELSE '[]' END ||
49+
CASE WHEN jsonb_typeof(other_infractions) = 'array' THEN other_infractions ELSE '[]' END
50+
) > 0
51+
),
52+
53+
controls_infractions_details AS (
54+
SELECT
55+
id,
56+
mission_infraction->>'natinf' AS infraction_natinf,
57+
mission_infraction->>'infractionType' AS infraction_type,
58+
mission_infraction->>'comments' AS infraction_comments
59+
FROM action_infractions
60+
),
61+
62+
controls_infraction_natinf_category AS (
63+
SELECT
64+
controls_infractions_details.*,
65+
infractions.infraction_category
66+
FROM controls_infractions_details
67+
LEFT JOIN infractions
68+
ON infractions.natinf_code::VARCHAR = controls_infractions_details.infraction_natinf
69+
),
70+
71+
controls_infraction_natinfs_array AS (
72+
SELECT
73+
id,
74+
true AS infraction,
75+
'Pêche' = ANY(ARRAY_AGG(infraction_category)) AS fishing_infraction,
76+
ARRAY_AGG(DISTINCT infraction_category) FILTER (WHERE infraction_category IS NOT NULL) AS infraction_categories,
77+
ARRAY_AGG(DISTINCT infraction_natinf) FILTER (WHERE infraction_natinf IS NOT NULL) AS infraction_natinfs,
78+
ARRAY_AGG(DISTINCT infraction_type) FILTER (WHERE infraction_type IS NOT NULL) AS infraction_types,
79+
STRING_AGG(NULLIF(infraction_comments, ''), ' - ') AS infraction_comments
80+
FROM controls_infraction_natinf_category
81+
GROUP BY id
82+
)
83+
84+
SELECT
85+
a.id,
86+
a.vessel_id,
87+
a.mission_id,
88+
cu.id AS control_unit_id,
89+
action_type AS control_type,
90+
action_datetime_utc AS control_datetime_utc,
91+
EXTRACT(year FROM action_datetime_utc) AS control_year,
92+
cu.name AS control_unit,
93+
adm.name AS administration,
94+
a.cfr,
95+
a.ircs,
96+
a.external_immatriculation,
97+
a.vessel_name,
98+
a.flag_state,
99+
a.district_code,
100+
COALESCE(a.facade, 'Hors façade') AS facade,
101+
COALESCE(a.longitude, ports.longitude) AS longitude,
102+
COALESCE(a.latitude, ports.latitude) AS latitude,
103+
port_locode,
104+
ports.region AS port_department,
105+
ports.port_name,
106+
vessel_targeted,
107+
COALESCE(inf.infraction, false) AS infraction,
108+
COALESCE(inf.fishing_infraction, false) AS fishing_infraction,
109+
COALESCE('WITH_RECORD' = ANY(inf.infraction_types), false) AS infraction_report,
110+
COALESCE(infraction_categories, '{Aucune infraction}'::VARCHAR[]) AS infraction_categories,
111+
COALESCE(infraction_natinfs, '{Aucune infraction}'::VARCHAR[]) AS infraction_natinfs,
112+
COALESCE(seizure_and_diversion, false) AS seizure_and_diversion,
113+
species,
114+
gears,
115+
CASE WHEN a.fao_areas = '{}' THEN '{Aucune zone FAO}' ELSE a.fao_areas END AS fao_areas,
116+
COALESCE(segment->>'segment', 'Hors segment') AS segment,
117+
NULLIF(
118+
(
119+
CASE WHEN inf.infraction_comments IS NOT NULL THEN inf.infraction_comments || ' - ' ELSE '' END ||
120+
CASE WHEN licences_and_logbook_observations IS NOT NULL THEN licences_and_logbook_observations || ' - ' ELSE '' END ||
121+
CASE WHEN species_observations IS NOT NULL THEN species_observations || ' - ' ELSE '' END ||
122+
CASE WHEN other_comments IS NOT NULL THEN other_comments ELSE '' END
123+
),
124+
''
125+
) as comments,
126+
a.number_of_vessels_flown_over,
127+
COALESCE(a.flight_goals, '{}'::VARCHAR[]) AS flight_goals
128+
FROM mission_actions a
129+
LEFT JOIN LATERAL jsonb_array_elements(CASE WHEN jsonb_typeof(segments) = 'array' THEN segments ELSE '[]' END) AS segment on true
130+
LEFT JOIN controls_infraction_natinfs_array inf ON inf.id = a.id
131+
LEFT JOIN controls_gears ON controls_gears.id=a.id
132+
LEFT JOIN controls_species ON controls_species.id=a.id
133+
LEFT JOIN ports ON ports.locode = a.port_locode
134+
JOIN analytics_missions m ON a.mission_id = m.id
135+
LEFT JOIN analytics_missions_control_units mcu ON m.id = mcu.mission_id
136+
LEFT JOIN analytics_control_units cu ON mcu.control_unit_id = cu.id
137+
LEFT JOIN analytics_administrations adm ON cu.administration_id = adm.id
138+
WHERE NOT a.is_deleted AND NOT m.deleted
139+
ORDER BY action_datetime_utc;
140+
141+
CREATE INDEX ON analytics_controls_full_data USING BRIN(control_datetime_utc);
Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
CREATE TABLE public.emails_sent_to_control_units (
2+
id SERIAL PRIMARY KEY,
3+
control_unit_id INTEGER NOT NULL,
4+
control_unit_name VARCHAR NOT NULL,
5+
email_address VARCHAR NOT NULL,
6+
sending_datetime_utc TIMESTAMP NOT NULL,
7+
actions_min_datetime_utc TIMESTAMP NOT NULL,
8+
actions_max_datetime_utc TIMESTAMP NOT NULL,
9+
number_of_actions INTEGER NOT NULL,
10+
success BOOLEAN NOT NULL,
11+
error_code INTEGER,
12+
error_message VARCHAR
13+
);

datascience/.env.template

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -71,3 +71,9 @@ PREFECT_SERVER_URL=
7171

7272
# data.gouv.fr
7373
DATAGOUV_API_KEY=
74+
75+
# Test modes
76+
IS_INTEGRATION=
77+
TEST_MODE=
78+
PNO_TEST_MODE=
79+
WEEKLY_CONTROL_REPORT_EMAIL_TEST_MODE=

datascience/config.py

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -68,6 +68,17 @@
6868
"y",
6969
)
7070

71+
# Must be set to true to send prior notifications to the FMC, and
72+
# not to real addressees (control units)
73+
WEEKLY_CONTROL_REPORT_EMAIL_TEST_MODE = os.getenv(
74+
"WEEKLY_CONTROL_REPORT_EMAIL_TEST_MODE", "False"
75+
).lower() in (
76+
"true",
77+
"t",
78+
"yes",
79+
"y",
80+
)
81+
7182
# Flow execution configuration
7283
DOCKER_IMAGE = "docker.pkg.github.com/mtes-mct/monitorfish/monitorfish-pipeline"
7384
MONITORFISH_VERSION = os.getenv("MONITORFISH_VERSION")
Lines changed: 16 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,16 @@
1+
h1 {
2+
font-size: 1.999rem;
3+
}
4+
5+
h2 {
6+
font-size: 1.414rem;
7+
}
8+
9+
body {
10+
text-align: unset;
11+
max-width: 54rem;
12+
}
13+
14+
strong {
15+
font-weight: bold;
16+
}
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
<!DOCTYPE html>
2+
<html lang="fr">
3+
<head>
4+
<title>Bilan hebdomadaire contrôle des pêches</title>
5+
<meta charset="UTF-8">
6+
<style>
7+
{% include "splendid.css" %}
8+
{% include "email_to_control_units.css" %}
9+
</style>
10+
</head>
11+
<body>
12+
<header>
13+
<h1>Bilan hebdomadaire contrôle des pêches</h1>
14+
</header>
15+
<hr />
16+
<main>
17+
<section>
18+
<p>Bonjour,</p>
19+
<p>Vous trouverez ci-dessous les données des actions de <strong>contrôle des pêches</strong> effectuées par votre unité
20+
(<strong>{{ control_unit_name }}</strong>) <strong>entre le {{ from_date }} et le {{ to_date }}</strong> que vous avez rapportés au Centre National de Surveillance des Pêches (CNSP).</p>
21+
<p>Seuls les contrôles et surveillances dont les données sont complètes sont transmis dans ce bilan hebdomadaire. Si certaines données n'ont pas encore été transmises (par ex. l'établissement d'un PV ou non),
22+
il est normal que le contrôle ne figure pas encore dans le rapport.</p>
23+
<p>Si des données sont manquantes, incorrectes ou incomplètes, ou pour toute remarque concernant ce bilan, n'hésitez pas à <strong>contacter le CNSP : <a href="mailto:{{ cnsp_france_email_address }}">{{ cnsp_france_email_address }}</a></strong>.</p>
24+
</section>
25+
<hr />
26+
<section>
27+
<h2>Contrôles à quai</h2>
28+
{{ land_controls }}
29+
30+
<h2>Contrôles en mer</h2>
31+
{{ sea_controls }}
32+
33+
<h2>Contrôles aériens</h2>
34+
{{ air_controls }}
35+
36+
<h2>Surveillances aériennes</h2>
37+
{{ air_surveillances }}
38+
</section>
39+
</main>
40+
<footer class="no-vertical-margin">
41+
<hr/>
42+
<p>Centre National de Surveillance des Pêches - Tél : +33 2 97 29 34 27</p>
43+
</footer>
44+
</body>
45+
</html>
Lines changed: 42 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
from dataclasses import dataclass
2+
from datetime import datetime
3+
from typing import List
4+
5+
import pandas as pd
6+
7+
from src.pipeline.helpers.dates import Period
8+
9+
10+
@dataclass
11+
class ControlUnitWithEmails:
12+
control_unit_id: int
13+
control_unit_name: str
14+
emails: List[str]
15+
16+
17+
@dataclass
18+
class ControlUnitActions:
19+
"""
20+
Control unit and its fisheries control actions between two dates.
21+
"""
22+
23+
control_unit: ControlUnitWithEmails
24+
period: Period
25+
land_controls: pd.DataFrame
26+
sea_controls: pd.DataFrame
27+
air_controls: pd.DataFrame
28+
air_surveillances: pd.DataFrame
29+
30+
31+
@dataclass
32+
class ControlUnitActionsSentMessage:
33+
control_unit_id: int
34+
control_unit_name: str
35+
email_address: str
36+
sending_datetime_utc: datetime
37+
actions_min_datetime_utc: datetime
38+
actions_max_datetime_utc: datetime
39+
number_of_actions: int
40+
success: bool
41+
error_code: int
42+
error_message: str

datascience/src/pipeline/entities/missions.py

Lines changed: 16 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -80,3 +80,19 @@ def from_poseidon_infraction_field(infraction: int):
8080
class Infraction:
8181
natinf: int
8282
comments: str
83+
84+
85+
class FlightGoal(Enum):
86+
VMS_AIS_CHECK = "VMS_AIS_CHECK"
87+
UNAUTHORIZED_FISHING = "UNAUTHORIZED_FISHING"
88+
CLOSED_AREA = "CLOSED_AREA"
89+
90+
@property
91+
def label(self):
92+
labels = {
93+
"VMS_AIS_CHECK": "Vérif. AIS/VMS",
94+
"UNAUTHORIZED_FISHING": "Pêche interdite",
95+
"CLOSED_AREA": "Zone fermée",
96+
}
97+
98+
return labels[self.name]

datascience/src/pipeline/flows/distribute_pnos.py

Lines changed: 1 addition & 46 deletions
Original file line numberDiff line numberDiff line change
@@ -11,7 +11,6 @@
1111
import prefect.engine
1212
import prefect.engine.signals
1313
import prefect.exceptions
14-
import requests
1514
import weasyprint
1615
from jinja2 import Environment, FileSystemLoader, Template, select_autoescape
1716
from prefect import Flow, Parameter, case, flatten, task, unmapped
@@ -28,7 +27,6 @@
2827
EMAIL_TEMPLATES_LOCATION,
2928
LIBERTE_EGALITE_FRATERNITE_LOGO_PATH,
3029
MARIANNE_LOGO_PATH,
31-
MONITORENV_API_ENDPOINT,
3230
MONITORFISH_EMAIL_ADDRESS,
3331
PNO_TEST_EMAIL,
3432
SE_MER_LOGO_PATH,
@@ -56,11 +54,11 @@
5654
resize_pdf_to_A4,
5755
send_email_or_sms_or_fax_message,
5856
)
59-
from src.pipeline.processing import remove_nones_from_list
6057
from src.pipeline.shared_tasks.control_flow import (
6158
check_flow_not_running,
6259
filter_results,
6360
)
61+
from src.pipeline.shared_tasks.control_units import fetch_control_units_contacts
6462
from src.pipeline.shared_tasks.dates import get_utcnow, make_timedelta
6563
from src.pipeline.shared_tasks.infrastructure import execute_statement
6664
from src.pipeline.shared_tasks.pnos import (
@@ -114,49 +112,6 @@ def extract_pnos_to_generate(
114112
return (pnos, generation_needed)
115113

116114

117-
@task(checkpoint=False)
118-
def fetch_control_units_contacts() -> pd.DataFrame:
119-
r = requests.get(MONITORENV_API_ENDPOINT + "control_units")
120-
121-
r.raise_for_status()
122-
df = pd.DataFrame(r.json())
123-
124-
columns = {
125-
"id": "control_unit_id",
126-
"controlUnitContacts": "control_unit_contacts",
127-
"isArchived": "is_archived",
128-
}
129-
130-
df = df[columns.keys()].rename(columns=columns)
131-
132-
contacts = (
133-
df.loc[~df.is_archived, ["control_unit_id", "control_unit_contacts"]]
134-
.explode("control_unit_contacts")
135-
.dropna()
136-
.reset_index(drop=True)
137-
)
138-
contacts["email"] = contacts["control_unit_contacts"].apply(
139-
lambda x: x.get("email") if x.get("isEmailSubscriptionContact") else None
140-
)
141-
142-
contacts["phone"] = contacts["control_unit_contacts"].apply(
143-
lambda x: x.get("phone") if x.get("isSmsSubscriptionContact") else None
144-
)
145-
146-
email_and_phone_contacts = (
147-
contacts[["control_unit_id", "email", "phone"]]
148-
.dropna(subset=["email", "phone"], how="all")
149-
.groupby("control_unit_id")
150-
.agg({"email": "unique", "phone": "unique"})
151-
.rename(columns={"email": "emails", "phone": "phone_numbers"})
152-
.map(remove_nones_from_list)
153-
.map(sorted)
154-
.reset_index()
155-
)
156-
157-
return email_and_phone_contacts
158-
159-
160115
@task(checkpoint=False)
161116
def to_pnos_to_render(pnos: pd.DataFrame) -> List[PnoToRender]:
162117
records = pnos.to_dict(orient="records")

0 commit comments

Comments
 (0)