Update schema (events).

Some columns have been renamed:

* ts0 → tstamp
* shotNumber → point

The ts1 column from events_timed has been removed.

Labels attached to a sequence / shot without an event
have been removed. All labels are now associated with events.

Changes to event views.
This commit is contained in:
D. Berge
2020-08-22 20:19:39 +02:00
parent a588bfcb68
commit 1b549655fa

View File

@@ -226,15 +226,25 @@ CREATE VIEW _SURVEY__TEMPLATE_.events_midnight_shot AS
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,
SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
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,
SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
l.name AS label
FROM ((s
JOIN _SURVEY__TEMPLATE_.raw_shots rs ON ((rs.tstamp = s.ts0)))
@@ -251,7 +261,7 @@ CREATE TABLE _SURVEY__TEMPLATE_.events_seq (
id integer NOT NULL,
remarks text NOT NULL,
sequence integer NOT NULL,
shot_number integer NOT NULL
point integer NOT NULL
);
@@ -265,44 +275,24 @@ COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq IS 'Events associated with a spec
--
-- Name: events_seq_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- Name: events_seq_timed; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_seq_labels (
id integer NOT NULL,
label text NOT NULL
);
CREATE VIEW _SURVEY__TEMPLATE_.events_seq_timed AS
SELECT s.sequence,
s.point,
s.id,
s.remarks,
rs.line,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry
FROM (_SURVEY__TEMPLATE_.events_seq s
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point));
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_labels OWNER TO postgres;
--
-- Name: TABLE events_seq_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_labels IS 'Associates labels with events in events_seq.';
--
-- Name: events_seq_shots_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels (
sequence integer NOT NULL,
shot_number integer NOT NULL,
label text NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels OWNER TO postgres;
--
-- Name: TABLE events_seq_shots_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels IS 'Associates labels with shots. This is intended for cases where a shot needs a label but no accompanying comment (FSP, LSP, etc.) so it makes no sense to add an entry in events_seq. It does require that the referenced sequence exist in raw_lines.
';
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_timed OWNER TO postgres;
--
-- Name: events_timed; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
@@ -311,8 +301,7 @@ COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels IS 'Associates label
CREATE TABLE _SURVEY__TEMPLATE_.events_timed (
id integer NOT NULL,
remarks text NOT NULL,
ts0 timestamp with time zone NOT NULL,
ts1 timestamp with time zone
tstamp timestamp with time zone NOT NULL
);
@@ -330,42 +319,6 @@ Events that occur within a sequence can be associated with dynamically, via a vi
';
--
-- Name: events_timed_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_timed_labels (
id integer NOT NULL,
label text NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_labels OWNER TO postgres;
--
-- Name: TABLE events_timed_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_labels IS 'Associates labels with events in events_timed.';
--
-- Name: final_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.final_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_.final_shots OWNER TO postgres;
--
-- Name: preplot_points; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -447,112 +400,160 @@ CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres;
--
-- Name: events_timed_seq; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_timed_seq AS
WITH seqs AS (
SELECT e.id,
e.remarks,
e.tstamp,
rls.sequence,
rls.fsp,
rls.lsp,
rls.ts0,
rls.ts1
FROM (_SURVEY__TEMPLATE_.events_timed e
LEFT JOIN _SURVEY__TEMPLATE_.raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT seqs.sequence,
seqs.id,
seqs.remarks,
seqs.tstamp,
seqs.fsp,
seqs.lsp,
seqs.ts0,
seqs.ts1,
shots.line,
shots.point,
shots.objref,
shots.tstamp AS shot_tstamp,
shots.hash,
shots.geometry
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry
FROM _SURVEY__TEMPLATE_.raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1) shots USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres;
--
-- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events AS
WITH seqs AS (
SELECT e.id,
e.remarks,
e.ts0,
e.ts1,
rls.sequence
FROM (_SURVEY__TEMPLATE_.events_timed e
LEFT JOIN _SURVEY__TEMPLATE_.raw_lines_summary rls ON (((e.ts0 >= rls.ts0) AND (e.ts0 <= rls.ts1))))
), events_timed_sequences AS (
SELECT seqs.sequence,
seqs.id,
seqs.remarks,
seqs.ts0,
seqs.ts1,
shots.line,
shots.point,
shots.objref,
shots.tstamp,
shots.hash,
shots.geometry
FROM (seqs
LEFT JOIN LATERAL ( SELECT fs.sequence,
fs.line,
fs.point,
fs.objref,
fs.tstamp,
fs.hash,
fs.geometry
FROM _SURVEY__TEMPLATE_.final_shots fs
ORDER BY (seqs.ts0 OPERATOR(public.<->) fs.tstamp)
LIMIT 1) shots USING (sequence))
)
SELECT 'timed'::text AS source,
events_timed_sequences.id,
events_timed_sequences.sequence,
events_timed_sequences.point AS shot_number,
events_timed_sequences.ts0,
events_timed_sequences.ts1,
NULL::text AS label,
events_timed_sequences.remarks
FROM events_timed_sequences
SELECT 'sequence'::text AS type,
false AS virtual,
s.sequence,
s.point,
s.id,
s.remarks,
s.line,
s.objref,
s.tstamp,
s.hash,
s.geometry
FROM _SURVEY__TEMPLATE_.events_seq_timed s
UNION
SELECT 'timed_labels'::text AS source,
etl.id,
ets.sequence,
ets.point AS shot_number,
ets.ts0,
ets.ts1,
etl.label,
NULL::text AS remarks
FROM (_SURVEY__TEMPLATE_.events_timed_labels etl
JOIN events_timed_sequences ets USING (id))
SELECT 'timed'::text AS type,
false AS virtual,
t.sequence,
t.point,
t.id,
t.remarks,
t.line,
t.objref,
t.tstamp,
t.hash,
t.geometry
FROM _SURVEY__TEMPLATE_.events_timed_seq t
UNION
SELECT 'shot_labels'::text AS source,
NULL::integer AS id,
essl.sequence,
essl.shot_number,
rs.tstamp AS ts0,
NULL::timestamp with time zone AS ts1,
essl.label,
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,
es.sequence,
es.shot_number,
rs.tstamp AS ts0,
NULL::timestamp with time zone AS ts1,
NULL::text AS label,
es.remarks
FROM (_SURVEY__TEMPLATE_.events_seq es
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((es.sequence = rs.sequence) AND (es.shot_number = rs.point))))
UNION
SELECT 'seq_labels'::text AS source,
esl.id,
es.sequence,
es.shot_number,
rs.tstamp AS ts0,
NULL::timestamp with time zone AS ts1,
esl.label,
NULL::text AS remarks
FROM ((_SURVEY__TEMPLATE_.events_seq_labels esl
JOIN _SURVEY__TEMPLATE_.events_seq es USING (id))
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((es.sequence = rs.sequence) AND (es.shot_number = rs.point))));
SELECT 'midnight shot'::text AS type,
true AS virtual,
v1.sequence,
v1.point,
((v1.sequence * 100000) + v1.point) AS id,
''::text AS remarks,
v1.line,
v1.objref,
v1.tstamp,
v1.hash,
v1.geometry
FROM _SURVEY__TEMPLATE_.events_midnight_shot v1;
ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres;
--
-- Name: events_seq_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_seq_labels (
id integer NOT NULL,
label text NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_labels OWNER TO postgres;
--
-- Name: TABLE events_seq_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_labels IS 'Associates labels with events in events_seq.';
--
-- Name: events_timed_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_timed_labels (
id integer NOT NULL,
label text NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_labels OWNER TO postgres;
--
-- Name: TABLE events_timed_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_labels IS 'Associates labels with events in events_timed.';
--
-- Name: events_labels; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_labels AS
SELECT 'timed'::text AS type,
events_timed_labels.id,
events_timed_labels.label
FROM _SURVEY__TEMPLATE_.events_timed_labels
UNION
SELECT 'sequence'::text AS type,
events_seq_labels.id,
events_seq_labels.label
FROM _SURVEY__TEMPLATE_.events_seq_labels
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;
ALTER TABLE _SURVEY__TEMPLATE_.events_labels OWNER TO postgres;
--
-- Name: events_seq_id_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -674,6 +675,23 @@ CREATE TABLE _SURVEY__TEMPLATE_.final_lines_files (
ALTER TABLE _SURVEY__TEMPLATE_.final_lines_files OWNER TO postgres;
--
-- Name: final_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.final_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_.final_shots OWNER TO postgres;
--
-- Name: final_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -986,14 +1004,6 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq
ADD CONSTRAINT events_seq_pkey PRIMARY KEY (id);
--
-- Name: events_seq_shots_labels events_seq_shots_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
ADD CONSTRAINT events_seq_shots_labels_pkey PRIMARY KEY (sequence, shot_number, label);
--
-- Name: events_timed_labels events_timed_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -1125,7 +1135,7 @@ CREATE INDEX events_seq_sequence_idx ON _SURVEY__TEMPLATE_.events_seq USING btre
-- Name: events_timed_ts0_idx; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (ts0);
CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (tstamp);
--
@@ -1152,22 +1162,6 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq
ADD CONSTRAINT events_seq_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: events_seq_shots_labels events_seq_shots_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
ADD CONSTRAINT events_seq_shots_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: events_seq_shots_labels events_seq_shots_labels_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
ADD CONSTRAINT events_seq_shots_labels_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: events_timed_labels events_timed_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--