From 2ee9b0cac845b59ed991a39518333ebcedee6fd3 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Thu, 13 Aug 2020 23:44:25 +0200 Subject: [PATCH] Add midnight shot synthetic event. It inserts `LDSP` and `FDSP` labels, if those exist in the `labels` table, on the last and first shotpoints of the day when a sequence is shot through midnight. The server timezone is always set to UTC so the midnight shot implicitly refers to UTC through this. --- etc/db/schema-template.sql | 118 ++++++++++++++++++++++++++----------- 1 file changed, 82 insertions(+), 36 deletions(-) diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index ccdcfea..e70c75f 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -172,6 +172,77 @@ NOTE: The proper way of doing this would be to define an EngineeringCRS in the s SET default_tablespace = ''; +-- +-- Name: labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE TABLE _SURVEY__TEMPLATE_.labels ( + name text NOT NULL, + data jsonb NOT NULL +); + + +ALTER TABLE _SURVEY__TEMPLATE_.labels OWNER TO postgres; + +-- +-- Name: TABLE labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: 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_) +); + + +ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres; + +-- +-- Name: events_midnight_shot; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.events_midnight_shot AS + WITH t AS ( + SELECT rs.sequence, + min(rs.tstamp) AS ts0, + max(rs.tstamp) AS ts1 + FROM _SURVEY__TEMPLATE_.raw_shots rs + GROUP BY rs.sequence, (date(rs.tstamp)) + ), s AS ( + SELECT t0.sequence, + t0.ts1, + t1.ts0 + FROM (t t0 + JOIN t t1 ON (((t0.sequence = t1.sequence) AND (date(t0.ts0) < date(t1.ts1))))) + ) + SELECT s.sequence, + rs.point AS shot_number, + l.name AS label + FROM ((s + JOIN _SURVEY__TEMPLATE_.raw_shots rs ON ((rs.tstamp = s.ts1))) + JOIN _SURVEY__TEMPLATE_.labels l ON ((l.name = 'LDSP'::text))) +UNION ALL + SELECT s.sequence, + rs.point AS shot_number, + l.name AS label + FROM ((s + JOIN _SURVEY__TEMPLATE_.raw_shots rs ON ((rs.tstamp = s.ts0))) + JOIN _SURVEY__TEMPLATE_.labels l ON ((l.name = 'FDSP'::text))); + + +ALTER TABLE _SURVEY__TEMPLATE_.events_midnight_shot OWNER TO postgres; + -- -- Name: events_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -317,23 +388,6 @@ CREATE TABLE _SURVEY__TEMPLATE_.raw_lines ( ALTER TABLE _SURVEY__TEMPLATE_.raw_lines OWNER TO postgres; --- --- 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_) -); - - -ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres; - -- -- Name: raw_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -431,6 +485,17 @@ UNION NULL::text AS remarks FROM (_SURVEY__TEMPLATE_.events_seq_shots_labels essl LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((essl.sequence = rs.sequence) AND (essl.shot_number = rs.point)))) +UNION + SELECT 'midnight'::text AS source, + NULL::integer AS id, + ems.sequence, + ems.shot_number, + rs.tstamp AS ts0, + NULL::timestamp with time zone AS ts1, + ems.label, + NULL::text AS remarks + FROM (_SURVEY__TEMPLATE_.events_midnight_shot ems + LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((ems.sequence = rs.sequence) AND (ems.shot_number = rs.point)))) UNION SELECT 'seq'::text AS source, es.id, @@ -718,25 +783,6 @@ CREATE TABLE _SURVEY__TEMPLATE_.info ( ALTER TABLE _SURVEY__TEMPLATE_.info OWNER TO postgres; --- --- Name: labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE TABLE _SURVEY__TEMPLATE_.labels ( - name text NOT NULL, - data jsonb NOT NULL -); - - -ALTER TABLE _SURVEY__TEMPLATE_.labels OWNER TO postgres; - --- --- Name: TABLE labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: 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: preplot_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres --