Python_scripts/15_POLICE/v_infraction_rnn.py

81 lines
2.6 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
json_data->>'__Submissions-id'::text "__Submissions-id",
json_agg('https://odk2.cen-isere.fr/v1/projects/6/forms/infraction_rnn/submissions/'||(json_data->>'__Submissions-id'::text)||'/attachments/'||(json_data->>'photos')::text) photos
FROM police.infraction_rnn
WHERE tablename = 'photos_repeat'
group by json_data->>'__Submissions-id'::text
), strip_infra as (
SELECT
inf.json_data->>'__Submissions-id' "__Submissions-id",
json_data->>'__id' "__id",
json_strip_nulls(inf.json_data) json_data
FROM police.infraction_rnn inf
WHERE inf.tablename = 'multiple_infract'
), key_infra as (
select
json_data->>'__Submissions-id' "__Submissions-id",
json_data->>'__id' "__id",
json_object_keys(json_data::json) data_keys
from strip_infra
), key_infra_agg as (
select
"__Submissions-id","__id", array_agg(data_keys) data_keys
from key_infra
group by 2,1
)
SELECT
inf.json_data->>'__id'::text id_infraction,
split_part(sub.data_id,':',2)::uuid id_submission,
"submitterName" digitiser,
catego_controle,
catego_sensibil,
autre_catego_sensi,
autre_type_sanct,
inf.json_data->>'catego_infract'::text catego_infract,
inf.json_data->>key_infra_agg.data_keys[1] nature_infra,
case when SPLIT_PART(key_infra_agg.data_keys[3],'_',1) = 'natinf'
then inf.json_data->>key_infra_agg.data_keys[2]
else null
end code_catego,
case when SPLIT_PART(key_infra_agg.data_keys[3],'_',1) = 'natinf'
then inf.json_data->>key_infra_agg.data_keys[3]
else inf.json_data->>key_infra_agg.data_keys[2]
end code_infra,
inf.json_data->>'descrpt_infract'::text descrpt_infract,
"Commentaire_remarque_nombre_de_tentes",
"Conformit_du_contr_le",
"day" "date",
"heure",
infract_nb,
nat_operation,
nature_pers,
nb_pers_control,
nb_pers_sensibil,
nb_verb,
nom_agent,
type_sanct,
ph.photos,
"submissionDate" date_saisie,
"updatedAt" date_maj,
st_force2d(st_geomfromgeojson(replace(COALESCE(geom,point_carte),'\\','')))::geometry(geometry, 4326) AS geom
FROM police.infraction_rnn_submissions_data AS sub
JOIN strip_infra inf ON sub.data_id::text = inf."__Submissions-id"::text
join key_infra_agg on inf.__id = key_infra_agg.__id
JOIN photos ph ON sub.data_id::text = ph."__Submissions-id"::text
ORDER BY 2,1 ;
GRANT SELECT ON TABLE police.infraction_rnn TO grp_police;
'''
with con_odk.begin() as cnx:
cnx.execute(sql)