Python_scripts/15_POLICE/v_infraction_rnn.py

85 lines
3.3 KiB
Python

#!/usr/bin/env python3
# -*- coding: UTF-8 -*-
from pycen import con_odk
sql = '''
DROP VIEW IF EXISTS police.v_infraction_rnn;
CREATE VIEW police.v_infraction_rnn AS
WITH photos AS (
SELECT infraction_rnn.json_data ->> '__Submissions-id'::text AS "__Submissions-id",
json_agg((('https://odk2.cen-isere.fr/v1/projects/6/forms/infraction_rnn/submissions/'::text || (infraction_rnn.json_data ->> '__Submissions-id'::text)) || '/attachments/'::text) || (infraction_rnn.json_data ->> 'photos'::text)) AS photos
FROM (
select row_to_json(t.*) json_data
from police.infraction_rnn_photos_repeat_data t
) infraction_rnn
GROUP BY (infraction_rnn.json_data ->> '__Submissions-id'::text)
), strip_infra AS (
SELECT inf_1.json_data ->> '__Submissions-id'::text AS "__Submissions-id",
inf_1.json_data ->> '__id'::text AS __id,
json_strip_nulls(inf_1.json_data) AS json_data
FROM (
select row_to_json(t.*) json_data
from police.infraction_rnn_multiple_infract_data t
) inf_1
), key_infra AS (
SELECT strip_infra.json_data ->> '__Submissions-id'::text AS "__Submissions-id",
strip_infra.json_data ->> '__id'::text AS __id,
json_object_keys(strip_infra.json_data) AS data_keys
FROM strip_infra
), key_infra_agg AS (
SELECT key_infra."__Submissions-id",
key_infra.__id,
array_agg(key_infra.data_keys) AS data_keys
FROM key_infra
GROUP BY key_infra.__id, key_infra."__Submissions-id"
)
SELECT inf.json_data ->> '__id'::text AS id_infraction,
split_part(sub.data_id, ':'::text, 2)::uuid AS id_submission,
sub."submitterName" AS digitiser,
sub.catego_controle,
sub.catego_sensibil,
sub.autre_catego_sensi,
sub.autre_type_sanct,
inf.json_data ->> 'catego_infract'::text AS catego_infract,
inf.json_data ->> key_infra_agg.data_keys[1] AS nature_infra,
CASE
WHEN split_part(key_infra_agg.data_keys[3], '_'::text, 1) = 'natinf'::text
THEN inf.json_data ->> key_infra_agg.data_keys[2]
ELSE NULL::text
END AS code_catego,
CASE
WHEN split_part(key_infra_agg.data_keys[3], '_'::text, 1) = 'natinf'::text
THEN inf.json_data ->> key_infra_agg.data_keys[3]
ELSE inf.json_data ->> key_infra_agg.data_keys[2]
END AS code_infra,
inf.json_data ->> 'descrpt_infract'::text AS descrpt_infract,
sub."Commentaire_remarque_nombre_de_tentes",
sub."Conformit_du_contr_le",
sub.day AS date,
sub.heure,
sub.infract_nb,
sub.nat_operation,
sub.nature_pers,
sub.nb_pers_control,
sub.nb_pers_sensibil,
sub.nb_verb,
sub.nom_agent,
sub.type_sanct,
ph.photos,
sub."submissionDate" AS date_saisie,
sub."updatedAt" AS date_maj,
st_force2d(st_geomfromgeojson(replace(COALESCE(sub.geom, sub.point_carte), '\\'::text, ''::text)))::geometry(Geometry,4326) AS geom
FROM police.infraction_rnn_submissions_data sub
JOIN strip_infra inf ON sub.data_id = inf."__Submissions-id"
JOIN key_infra_agg ON inf.__id = key_infra_agg.__id
JOIN photos ph ON sub.data_id = ph."__Submissions-id"
ORDER BY (split_part(sub.data_id, ':'::text, 2)::uuid), (inf.json_data ->> '__id'::text)
;
GRANT SELECT ON TABLE police.v_infraction_rnn TO grp_police;
'''
with con_odk.begin() as cnx:
cnx.execute(sql)