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