diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 9b4a798..31653d3 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -1003,8 +1003,10 @@ COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date) IS 'Over CREATE PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) LANGUAGE sql AS $$ - INSERT INTO event_log (sequence, point, remarks, labels) - SELECT sequence, point, remarks, labels + INSERT INTO event_log (sequence, point, remarks, labels, meta) + SELECT + sequence, point, remarks, labels, + '{"auto": true, "insertedBy": "log_midnight_shots"}'::jsonb FROM midnight_shots ms WHERE (dt0 IS NULL OR ms.tstamp >= dt0) AND @@ -1014,6 +1016,20 @@ CREATE PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) FROM event_log el WHERE ms.sequence = el.sequence AND ms.point = el.point AND el.labels @> ms.labels ); + + -- Delete any midnight shots that might have been inserted in the log + -- but are no longer relevant according to the final_shots data. + -- We operate on event_log, so the deletion is traceable. + DELETE + FROM event_log + WHERE id IN ( + SELECT id + FROM event_log el + LEFT JOIN midnight_shots ms USING (sequence, point) + WHERE + '{LDSP,FDSP}'::text[] && el.labels -- &&: Do the arrays overlap? + AND ms.sequence IS NULL + ); $$; @@ -1599,42 +1615,24 @@ ALTER TABLE _SURVEY__TEMPLATE_.labels OWNER TO postgres; COMMENT ON TABLE _SURVEY__TEMPLATE_.labels IS 'Labels to attach to events, shots, or anything else really. Each level consists of a (unique) name and a JSON object with arbitrary label properties (intended to be used for label descriptions, colours, etc.)'; --- --- Name: raw_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE TABLE _SURVEY__TEMPLATE_.raw_shots ( - sequence integer NOT NULL, - line integer NOT NULL, - point integer NOT NULL, - objref integer NOT NULL, - tstamp timestamp with time zone NOT NULL, - hash text NOT NULL, - geometry public.geometry(Point,_EPSG__CODE_), - meta jsonb DEFAULT '{}'::jsonb NOT NULL -); - - -ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres; - -- -- Name: midnight_shots; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- CREATE VIEW _SURVEY__TEMPLATE_.midnight_shots AS WITH straddlers AS ( - SELECT raw_shots.sequence - FROM _SURVEY__TEMPLATE_.raw_shots - GROUP BY raw_shots.sequence - HAVING (min(date(raw_shots.tstamp)) <> max(date(raw_shots.tstamp))) + SELECT final_shots.sequence + FROM _SURVEY__TEMPLATE_.final_shots + GROUP BY final_shots.sequence + HAVING (min(date(final_shots.tstamp)) <> max(date(final_shots.tstamp))) ), ts AS ( - SELECT rs.sequence, - min(rs.tstamp) AS ts0, - max(rs.tstamp) AS ts1 - FROM (_SURVEY__TEMPLATE_.raw_shots rs + SELECT fs.sequence, + min(fs.tstamp) AS ts0, + max(fs.tstamp) AS ts1 + FROM (_SURVEY__TEMPLATE_.final_shots fs JOIN straddlers USING (sequence)) - GROUP BY rs.sequence, (date(rs.tstamp)) - ORDER BY rs.sequence, (date(rs.tstamp)) + GROUP BY fs.sequence, (date(fs.tstamp)) + ORDER BY fs.sequence, (date(fs.tstamp)) ), spts AS ( SELECT DISTINCT ts.sequence, min(ts.ts1) OVER (PARTITION BY ts.sequence) AS ldsp, @@ -1642,21 +1640,21 @@ CREATE VIEW _SURVEY__TEMPLATE_.midnight_shots AS FROM ts ORDER BY ts.sequence ), evt AS ( - SELECT rs.tstamp, - rs.sequence, - rs.point, + SELECT fs.tstamp, + fs.sequence, + fs.point, 'Last shotpoint of the day'::text AS remarks, '{LDSP}'::text[] AS labels - FROM (_SURVEY__TEMPLATE_.raw_shots rs - JOIN spts ON (((rs.sequence = spts.sequence) AND (rs.tstamp = spts.ldsp)))) + FROM (_SURVEY__TEMPLATE_.final_shots fs + JOIN spts ON (((fs.sequence = spts.sequence) AND (fs.tstamp = spts.ldsp)))) UNION - SELECT rs.tstamp, - rs.sequence, - rs.point, + SELECT fs.tstamp, + fs.sequence, + fs.point, 'First shotpoint of the day'::text AS remarks, '{FDSP}'::text[] AS labels - FROM (_SURVEY__TEMPLATE_.raw_shots rs - JOIN spts ON (((rs.sequence = spts.sequence) AND (rs.tstamp = spts.fdsp)))) + FROM (_SURVEY__TEMPLATE_.final_shots fs + JOIN spts ON (((fs.sequence = spts.sequence) AND (fs.tstamp = spts.fdsp)))) ORDER BY 1 ) SELECT evt.tstamp, @@ -1853,6 +1851,24 @@ Missing points are reported regardless of the underlying preplot NTBA status.'; +-- +-- Name: raw_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE TABLE _SURVEY__TEMPLATE_.raw_shots ( + sequence integer NOT NULL, + line integer NOT NULL, + point integer NOT NULL, + objref integer NOT NULL, + tstamp timestamp with time zone NOT NULL, + hash text NOT NULL, + geometry public.geometry(Point,_EPSG__CODE_), + meta jsonb DEFAULT '{}'::jsonb NOT NULL +); + + +ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres; + -- -- Name: missing_sequence_raw_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres --