Return event labels directly from events view.

This speeds up the query by orders of magnitude.
This commit is contained in:
D. Berge
2020-09-23 16:30:56 +02:00
parent 0e5e54b680
commit 33c23c1239
2 changed files with 44 additions and 7 deletions

View File

@@ -451,7 +451,10 @@ CREATE VIEW _SURVEY__TEMPLATE_.events AS
s.objref,
s.tstamp,
s.hash,
s.geometry
s.geometry,
ARRAY( SELECT esl.label
FROM _SURVEY__TEMPLATE_.events_seq_labels esl
WHERE (esl.id = s.id)) AS labels
FROM _SURVEY__TEMPLATE_.events_seq_timed s
UNION
SELECT 'timed'::text AS type,
@@ -464,7 +467,10 @@ UNION
rs.objref,
t.tstamp,
rs.hash,
rs.geometry
rs.geometry,
ARRAY( SELECT etl.label
FROM _SURVEY__TEMPLATE_.events_timed_labels etl
WHERE (etl.id = ts.id)) AS labels
FROM ((_SURVEY__TEMPLATE_.events_timed t
LEFT JOIN _SURVEY__TEMPLATE_.events_timed_seq ts USING (id))
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point))
@@ -479,8 +485,26 @@ UNION
v1.objref,
v1.tstamp,
v1.hash,
v1.geometry
FROM _SURVEY__TEMPLATE_.events_midnight_shot v1;
v1.geometry,
ARRAY[v1.label] AS labels
FROM _SURVEY__TEMPLATE_.events_midnight_shot v1
UNION
SELECT 'qc'::text AS type,
true AS virtual,
rs.sequence,
rs.point,
((10000000 + (rs.sequence * 100000)) + rs.point) AS id,
(q.q)::text AS remarks,
rs.line,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
ARRAY['QC'::text, jsonb_array_elements_text(l.l)] AS labels
FROM _SURVEY__TEMPLATE_.raw_shots rs,
LATERAL jsonb_path_query(rs.meta, '$."qc".*."results"'::jsonpath) q(q),
LATERAL jsonb_path_query(rs.meta, '$."qc".*."labels"'::jsonpath) l(l)
WHERE (rs.meta ? 'qc'::text);
ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres;
@@ -541,7 +565,21 @@ UNION
SELECT 'midnight shot'::text AS type,
((events_midnight_shot.sequence * 100000) + events_midnight_shot.point) AS id,
events_midnight_shot.label
FROM _SURVEY__TEMPLATE_.events_midnight_shot;
FROM _SURVEY__TEMPLATE_.events_midnight_shot
UNION
SELECT 'qc'::text AS type,
((10000000 + (rs.sequence * 100000)) + rs.point) AS id,
'QC'::text AS label
FROM _SURVEY__TEMPLATE_.raw_shots rs,
LATERAL jsonb_path_query(rs.meta, '$."qc".*."results"'::jsonpath) q(q)
WHERE (rs.meta ? 'qc'::text)
UNION
SELECT 'qc'::text AS type,
((10000000 + (rs.sequence * 100000)) + rs.point) AS id,
jsonb_array_elements_text(l.l) AS label
FROM _SURVEY__TEMPLATE_.raw_shots rs,
LATERAL jsonb_path_query(rs.meta, '$."qc".*."labels"'::jsonpath) l(l)
WHERE (rs.meta ? 'qc'::text);
ALTER TABLE _SURVEY__TEMPLATE_.events_labels OWNER TO postgres;