Update database templates to v0.3.12.

* Add midnight_shots view
* Add log_midnight_shots() procedure
This commit is contained in:
D. Berge
2022-05-13 18:55:43 +02:00
parent 4b832babfd
commit fdb5e0cbab
2 changed files with 142 additions and 20 deletions

View File

@@ -1,3 +1,3 @@
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.11"}') INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.12"}')
ON CONFLICT (key) DO UPDATE ON CONFLICT (key) DO UPDATE
SET value = public.info.value || '{"db_schema": "0.3.11"}' WHERE public.info.key = 'version'; SET value = public.info.value || '{"db_schema": "0.3.12"}' WHERE public.info.key = 'version';

View File

@@ -956,6 +956,76 @@ CREATE FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label t
ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres; ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres;
--
-- Name: log_midnight_shots(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots()
LANGUAGE sql
AS $$
CALL log_midnight_shots(NULL, NULL);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots() OWNER TO postgres;
--
-- Name: PROCEDURE log_midnight_shots(); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots() IS 'Overload taking no arguments (adds all missing events).';
--
-- Name: log_midnight_shots(date); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date)
LANGUAGE sql
AS $$
CALL log_midnight_shots(dt0, NULL);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date) OWNER TO postgres;
--
-- Name: PROCEDURE log_midnight_shots(IN dt0 date); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date) IS 'Overload taking only a dt0 (adds events on that date or after).';
--
-- Name: log_midnight_shots(date, date); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
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
FROM midnight_shots ms
WHERE
(dt0 IS NULL OR ms.tstamp >= dt0) AND
(dt1 IS NULL OR ms.tstamp <= dt1) AND
NOT EXISTS (
SELECT 1
FROM event_log el
WHERE ms.sequence = el.sequence AND ms.point = el.point AND el.labels @> ms.labels
);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) OWNER TO postgres;
--
-- Name: PROCEDURE log_midnight_shots(IN dt0 date, IN dt1 date); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) IS 'Add midnight shots between two dates dt0 and dt1 to the event_log, unless the events already exist.';
-- --
-- Name: replace_placeholders(text, timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: replace_placeholders(text, timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1529,6 +1599,76 @@ 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
--
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)))
), ts AS (
SELECT rs.sequence,
min(rs.tstamp) AS ts0,
max(rs.tstamp) AS ts1
FROM (_SURVEY__TEMPLATE_.raw_shots rs
JOIN straddlers USING (sequence))
GROUP BY rs.sequence, (date(rs.tstamp))
ORDER BY rs.sequence, (date(rs.tstamp))
), spts AS (
SELECT DISTINCT ts.sequence,
min(ts.ts1) OVER (PARTITION BY ts.sequence) AS ldsp,
max(ts.ts0) OVER (PARTITION BY ts.sequence) AS fdsp
FROM ts
ORDER BY ts.sequence
), evt AS (
SELECT rs.tstamp,
rs.sequence,
rs.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))))
UNION
SELECT rs.tstamp,
rs.sequence,
rs.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))))
ORDER BY 1
)
SELECT evt.tstamp,
evt.sequence,
evt.point,
evt.remarks,
evt.labels
FROM evt;
ALTER TABLE _SURVEY__TEMPLATE_.midnight_shots OWNER TO postgres;
-- --
-- Name: preplot_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: preplot_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1713,24 +1853,6 @@ 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
-- --