Skip to content

Commit

Permalink
Make analytics_actions view robust to nulls on actionNumberOfControls
Browse files Browse the repository at this point in the history
  • Loading branch information
VincentAntoine committed Jul 18, 2023
1 parent 1936f87 commit f8329cc
Showing 1 changed file with 62 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
DROP MATERIALIZED VIEW analytics_actions;

CREATE MATERIALIZED VIEW public.analytics_actions AS

SELECT
a.id,
a.mission_id,
action_start_datetime_utc,
EXTRACT(year FROM action_start_datetime_utc) AS year,
m.start_datetime_utc AS mission_start_datetime_utc,
m.end_datetime_utc AS mission_end_datetime_utc,
mission_type,
action_type,
COALESCE(m.facade, 'Hors façade') AS mission_facade,
cu.name AS control_unit,
adm.name AS administration,
cu.name ILIKE 'ulam%' OR (
adm.name = 'DIRM / DM' AND
cu.name ILIKE 'PAM%'
) AS is_aff_mar,
(
cu.name ILIKE 'ulam%' OR (
adm.name = 'DIRM / DM' AND
cu.name ILIKE 'PAM%'
)
) OR adm.name IN ('Gendarmerie Nationale', 'Gendarmerie Maritime', 'Douane', 'Marine Nationale') AS is_aem,
CASE
WHEN cu.name ILIKE 'ulam%' OR (adm.name = 'DIRM / DM' AND cu.name ILIKE 'PAM%') THEN 'Affaires Maritimes'
WHEN adm.name IN ('Gendarmerie Nationale', 'Gendarmerie Maritime', 'Douane', 'Marine Nationale') THEN adm.name
ELSE 'Administrations hors AEM'
END AS administration_aem,
COALESCE(a.facade, 'Hors façade') AS action_facade,
COALESCE(a.department, 'Hors département') AS action_department,
CASE WHEN COALESCE(t1->>'theme', '') = '' THEN 'Aucun thème' ELSE t1->>'theme' END AS theme_level_1,
CASE WHEN TRIM(BOTH '"' FROM (COALESCE(theme_level_2, 'null')::VARCHAR)) IN ('', 'null') THEN 'Aucun sous-thème' ELSE TRIM(BOTH '"' FROM (theme_level_2::VARCHAR)) END AS theme_level_2,
CASE WHEN action_type = 'CONTROL' THEN ST_X(geom_element.geom) END AS longitude,
CASE WHEN action_type = 'CONTROL' THEN ST_Y(geom_element.geom) END AS latitude,
CASE WHEN action_type = 'CONTROL' THEN CASE WHEN jsonb_array_length(a.value->'infractions') > 0 THEN true ELSE false END END AS infraction,
(a.value->>'actionNumberOfControls')::DOUBLE PRECISION AS number_of_controls,
CASE WHEN action_type = 'SURVEILLANCE' THEN COALESCE((a.value->>'duration')::DOUBLE PRECISION, EXTRACT(epoch FROM m.end_datetime_utc - m.start_datetime_utc) / 3600) END AS surveillance_duration,
m.observations_cacem
FROM env_actions a
LEFT JOIN ST_Dump(a.geom) AS geom_element
ON true
LEFT JOIN LATERAL jsonb_array_elements(a.value->'themes') t1 ON true
LEFT JOIN LATERAL jsonb_array_elements(t1->'subThemes') theme_level_2 ON true
JOIN missions m
ON a.mission_id = m.id
LEFT JOIN LATERAL unnest(mission_types) mission_type ON true
LEFT JOIN missions_control_units mcu
ON mcu.mission_id = m.id
LEFT JOIN control_units cu
ON cu.id = mcu.control_unit_id
LEFT JOIN administrations adm
ON adm.id = cu.administration_id
WHERE
NOT m.deleted AND
m.closed AND
action_type IN ('CONTROL', 'SURVEILLANCE')
ORDER BY action_start_datetime_utc DESC;

CREATE INDEX ON analytics_actions USING BRIN(action_start_datetime_utc);

0 comments on commit f8329cc

Please sign in to comment.