Update database schema template.

* midnight_shots uses final_shots rather than raw_shots
* log_midnight_shots removes stale midnight events
This commit is contained in:
D. Berge
2022-05-15 13:28:15 +02:00
parent aff974c03f
commit 105fee0623

View File

@@ -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) CREATE PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date)
LANGUAGE sql LANGUAGE sql
AS $$ AS $$
INSERT INTO event_log (sequence, point, remarks, labels) INSERT INTO event_log (sequence, point, remarks, labels, meta)
SELECT sequence, point, remarks, labels SELECT
sequence, point, remarks, labels,
'{"auto": true, "insertedBy": "log_midnight_shots"}'::jsonb
FROM midnight_shots ms FROM midnight_shots ms
WHERE WHERE
(dt0 IS NULL OR ms.tstamp >= dt0) AND (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 FROM event_log el
WHERE ms.sequence = el.sequence AND ms.point = el.point AND el.labels @> ms.labels 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.)'; 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 -- Name: midnight_shots; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
CREATE VIEW _SURVEY__TEMPLATE_.midnight_shots AS CREATE VIEW _SURVEY__TEMPLATE_.midnight_shots AS
WITH straddlers AS ( WITH straddlers AS (
SELECT raw_shots.sequence SELECT final_shots.sequence
FROM _SURVEY__TEMPLATE_.raw_shots FROM _SURVEY__TEMPLATE_.final_shots
GROUP BY raw_shots.sequence GROUP BY final_shots.sequence
HAVING (min(date(raw_shots.tstamp)) <> max(date(raw_shots.tstamp))) HAVING (min(date(final_shots.tstamp)) <> max(date(final_shots.tstamp)))
), ts AS ( ), ts AS (
SELECT rs.sequence, SELECT fs.sequence,
min(rs.tstamp) AS ts0, min(fs.tstamp) AS ts0,
max(rs.tstamp) AS ts1 max(fs.tstamp) AS ts1
FROM (_SURVEY__TEMPLATE_.raw_shots rs FROM (_SURVEY__TEMPLATE_.final_shots fs
JOIN straddlers USING (sequence)) JOIN straddlers USING (sequence))
GROUP BY rs.sequence, (date(rs.tstamp)) GROUP BY fs.sequence, (date(fs.tstamp))
ORDER BY rs.sequence, (date(rs.tstamp)) ORDER BY fs.sequence, (date(fs.tstamp))
), spts AS ( ), spts AS (
SELECT DISTINCT ts.sequence, SELECT DISTINCT ts.sequence,
min(ts.ts1) OVER (PARTITION BY ts.sequence) AS ldsp, min(ts.ts1) OVER (PARTITION BY ts.sequence) AS ldsp,
@@ -1642,21 +1640,21 @@ CREATE VIEW _SURVEY__TEMPLATE_.midnight_shots AS
FROM ts FROM ts
ORDER BY ts.sequence ORDER BY ts.sequence
), evt AS ( ), evt AS (
SELECT rs.tstamp, SELECT fs.tstamp,
rs.sequence, fs.sequence,
rs.point, fs.point,
'Last shotpoint of the day'::text AS remarks, 'Last shotpoint of the day'::text AS remarks,
'{LDSP}'::text[] AS labels '{LDSP}'::text[] AS labels
FROM (_SURVEY__TEMPLATE_.raw_shots rs FROM (_SURVEY__TEMPLATE_.final_shots fs
JOIN spts ON (((rs.sequence = spts.sequence) AND (rs.tstamp = spts.ldsp)))) JOIN spts ON (((fs.sequence = spts.sequence) AND (fs.tstamp = spts.ldsp))))
UNION UNION
SELECT rs.tstamp, SELECT fs.tstamp,
rs.sequence, fs.sequence,
rs.point, fs.point,
'First shotpoint of the day'::text AS remarks, 'First shotpoint of the day'::text AS remarks,
'{FDSP}'::text[] AS labels '{FDSP}'::text[] AS labels
FROM (_SURVEY__TEMPLATE_.raw_shots rs FROM (_SURVEY__TEMPLATE_.final_shots fs
JOIN spts ON (((rs.sequence = spts.sequence) AND (rs.tstamp = spts.fdsp)))) JOIN spts ON (((fs.sequence = spts.sequence) AND (fs.tstamp = spts.fdsp))))
ORDER BY 1 ORDER BY 1
) )
SELECT evt.tstamp, SELECT evt.tstamp,
@@ -1853,6 +1851,24 @@ Missing points are reported regardless of the underlying preplot NTBA
status.'; 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 -- Name: missing_sequence_raw_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --