Update schema.

* Report also schema in projects_summary
* Add notify triggers to events_timed, events_seq
This commit is contained in:
D. Berge
2020-09-14 23:54:48 +02:00
parent 5980b7d231
commit 94c3ed1584

View File

@@ -90,6 +90,82 @@ All values are returned as being of type "text" and need casting before use.
'; ';
--
-- Name: events_timed_seq_match(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
IF EXISTS (SELECT 1 FROM events_timed_seq WHERE id = NEW.id) THEN
DELETE FROM events_timed_seq WHERE id = NEW.id;
END IF;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id = NEW.id AND sequence IS NOT NULL AND point IS NOT NULL);
RETURN NULL;
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() OWNER TO postgres;
--
-- Name: events_timed_seq_update_all(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all()
LANGUAGE sql
AS $$
TRUNCATE events_timed_seq;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id IS NOT NULL AND sequence IS NOT NULL AND point IS NOT NULL);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgres;
-- --
-- Name: reset_events_serials(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: reset_events_serials(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -340,98 +416,6 @@ Events that occur within a sequence can be associated with dynamically, via a vi
'; ';
--
-- Name: preplot_points; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.preplot_points (
line integer NOT NULL,
point integer NOT NULL,
class character(1) NOT NULL,
ntba boolean DEFAULT false NOT NULL,
geometry public.geometry(Point,_EPSG__CODE_) NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.preplot_points OWNER TO postgres;
--
-- Name: TABLE preplot_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.preplot_points IS 'The preplot_points table holds each individual sailline preplot.
This is at present the only category for which we hold all individual positions.
We do this in order to be able to detect shots that do not have a preplot and
missed shots in acquisition and deliverable lines.
';
--
-- Name: COLUMN preplot_points.ntba; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON COLUMN _SURVEY__TEMPLATE_.preplot_points.ntba IS 'Not to be acquired. A value of True causes this preplot not to be reported as a missed shot and not to be taken into account in completion stats.';
--
-- Name: raw_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.raw_lines (
sequence integer NOT NULL,
line integer NOT NULL,
remarks text DEFAULT ''::text NOT NULL,
ntbp boolean DEFAULT false NOT NULL,
incr boolean NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines OWNER TO postgres;
--
-- Name: raw_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS
WITH summary AS (
SELECT DISTINCT rs.sequence,
first_value(rs.point) OVER w AS fsp,
last_value(rs.point) OVER w AS lsp,
first_value(rs.tstamp) OVER w AS ts0,
last_value(rs.tstamp) OVER w AS ts1,
count(rs.point) OVER w AS num_points,
count(pp.point) OVER w AS num_preplots,
public.st_distance(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) AS length,
((public.st_azimuth(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth
FROM (_SURVEY__TEMPLATE_.raw_shots rs
LEFT JOIN _SURVEY__TEMPLATE_.preplot_points pp USING (line, point))
WINDOW w AS (PARTITION BY rs.sequence ORDER BY rs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
)
SELECT rl.sequence,
rl.line,
s.fsp,
s.lsp,
s.ts0,
s.ts1,
(s.ts1 - s.ts0) AS duration,
s.num_points,
s.num_preplots,
(( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.preplot_points
WHERE ((preplot_points.line = rl.line) AND (((preplot_points.point >= s.fsp) AND (preplot_points.point <= s.lsp)) OR ((preplot_points.point >= s.lsp) AND (preplot_points.point <= s.fsp))))) - s.num_preplots) AS missing_shots,
s.length,
s.azimuth,
rl.remarks,
rl.ntbp
FROM (summary s
JOIN _SURVEY__TEMPLATE_.raw_lines rl USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres;
-- --
-- Name: events_timed_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: events_timed_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -451,88 +435,6 @@ ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres;
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_seq IS 'If a timed event is within a sequence, this references the point shot at or just before the event time. Note that if the shotpoint time is changed after the event has been created, the event will not update automatically. For that, a trigger or cron event that periodically refreshes the entire table will be necessary.'; COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_seq IS 'If a timed event is within a sequence, this references the point shot at or just before the event time. Note that if the shotpoint time is changed after the event has been created, the event will not update automatically. For that, a trigger or cron event that periodically refreshes the entire table will be necessary.';
--
-- Name: events_timed_seq_match(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
IF EXISTS (SELECT 1 FROM events_timed_seq WHERE id = NEW.id) THEN
DELETE FROM events_timed_seq WHERE id = NEW.id;
END IF;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id = NEW.id AND sequence IS NOT NULL AND point IS NOT NULL);
RETURN NULL;
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() OWNER TO postgres;
--
-- Name: events_timed events_timed_seq_match_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_timed_seq_match_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match();
--
-- Name: events_timed_seq_update_all(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all()
LANGUAGE sql
AS $$
TRUNCATE events_timed_seq;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id IS NOT NULL AND sequence IS NOT NULL AND point IS NOT NULL);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgres;
-- --
-- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
@@ -784,6 +686,41 @@ CREATE TABLE _SURVEY__TEMPLATE_.final_shots (
ALTER TABLE _SURVEY__TEMPLATE_.final_shots OWNER TO postgres; ALTER TABLE _SURVEY__TEMPLATE_.final_shots OWNER TO postgres;
--
-- Name: preplot_points; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.preplot_points (
line integer NOT NULL,
point integer NOT NULL,
class character(1) NOT NULL,
ntba boolean DEFAULT false NOT NULL,
geometry public.geometry(Point,_EPSG__CODE_) NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.preplot_points OWNER TO postgres;
--
-- Name: TABLE preplot_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.preplot_points IS 'The preplot_points table holds each individual sailline preplot.
This is at present the only category for which we hold all individual positions.
We do this in order to be able to detect shots that do not have a preplot and
missed shots in acquisition and deliverable lines.
';
--
-- Name: COLUMN preplot_points.ntba; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON COLUMN _SURVEY__TEMPLATE_.preplot_points.ntba IS 'Not to be acquired. A value of True causes this preplot not to be reported as a missed shot and not to be taken into account in completion stats.';
-- --
-- Name: final_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: final_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1053,6 +990,22 @@ CREATE VIEW _SURVEY__TEMPLATE_.preplot_summary AS
ALTER TABLE _SURVEY__TEMPLATE_.preplot_summary OWNER TO postgres; ALTER TABLE _SURVEY__TEMPLATE_.preplot_summary OWNER TO postgres;
--
-- Name: raw_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.raw_lines (
sequence integer NOT NULL,
line integer NOT NULL,
remarks text DEFAULT ''::text NOT NULL,
ntbp boolean DEFAULT false NOT NULL,
incr boolean NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines OWNER TO postgres;
-- --
-- Name: project_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: project_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1073,6 +1026,7 @@ CREATE VIEW _SURVEY__TEMPLATE_.project_summary AS
) )
SELECT project.pid, SELECT project.pid,
project.name, project.name,
project.schema,
( SELECT count(*) AS count ( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.preplot_lines FROM _SURVEY__TEMPLATE_.preplot_lines
WHERE (preplot_lines.class = 'V'::bpchar)) AS lines, WHERE (preplot_lines.class = 'V'::bpchar)) AS lines,
@@ -1116,6 +1070,47 @@ CREATE TABLE _SURVEY__TEMPLATE_.raw_lines_files (
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_files OWNER TO postgres; ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_files OWNER TO postgres;
--
-- Name: raw_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS
WITH summary AS (
SELECT DISTINCT rs.sequence,
first_value(rs.point) OVER w AS fsp,
last_value(rs.point) OVER w AS lsp,
first_value(rs.tstamp) OVER w AS ts0,
last_value(rs.tstamp) OVER w AS ts1,
count(rs.point) OVER w AS num_points,
count(pp.point) OVER w AS num_preplots,
public.st_distance(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) AS length,
((public.st_azimuth(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth
FROM (_SURVEY__TEMPLATE_.raw_shots rs
LEFT JOIN _SURVEY__TEMPLATE_.preplot_points pp USING (line, point))
WINDOW w AS (PARTITION BY rs.sequence ORDER BY rs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
)
SELECT rl.sequence,
rl.line,
s.fsp,
s.lsp,
s.ts0,
s.ts1,
(s.ts1 - s.ts0) AS duration,
s.num_points,
s.num_preplots,
(( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.preplot_points
WHERE ((preplot_points.line = rl.line) AND (((preplot_points.point >= s.fsp) AND (preplot_points.point <= s.lsp)) OR ((preplot_points.point >= s.lsp) AND (preplot_points.point <= s.fsp))))) - s.num_preplots) AS missing_shots,
s.length,
s.azimuth,
rl.remarks,
rl.ntbp
FROM (summary s
JOIN _SURVEY__TEMPLATE_.raw_lines rl USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres;
-- --
-- Name: raw_lines_summary_geometry; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: raw_lines_summary_geometry; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1428,6 +1423,27 @@ CREATE INDEX events_seq_sequence_idx ON _SURVEY__TEMPLATE_.events_seq USING btre
CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (tstamp); CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (tstamp);
--
-- Name: events_seq events_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_.events_seq FOR EACH ROW EXECUTE FUNCTION public.notify('event');
--
-- Name: events_timed events_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_.events_timed FOR EACH ROW EXECUTE FUNCTION public.notify('event');
--
-- Name: events_timed events_timed_seq_match_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_timed_seq_match_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match();
-- --
-- Name: events_seq_labels events_seq_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: events_seq_labels events_seq_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -1468,6 +1484,22 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels
ADD CONSTRAINT events_timed_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE; ADD CONSTRAINT events_timed_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: events_timed_seq events_timed_seq_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_seq
ADD CONSTRAINT events_timed_seq_id_fkey FOREIGN KEY (id) REFERENCES _SURVEY__TEMPLATE_.events_timed(id) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- Name: events_timed_seq events_timed_seq_sequence_point_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_seq
ADD CONSTRAINT events_timed_seq_sequence_point_fkey FOREIGN KEY (sequence, point) REFERENCES _SURVEY__TEMPLATE_.raw_shots(sequence, point) ON UPDATE CASCADE ON DELETE CASCADE;
-- --
-- Name: file_data file_data_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: file_data file_data_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --