From 0727e7db69a0b7f90d8d9542874c2fa0df0d3c79 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Tue, 15 Mar 2022 14:17:28 +0100 Subject: [PATCH] Update database templates to schema v0.3.1 --- etc/db/README.md | 1 + etc/db/database-template.sql | 255 ++++++++-- etc/db/database-version.sql | 3 + etc/db/schema-template.sql | 894 ++++++++++++++--------------------- 4 files changed, 575 insertions(+), 578 deletions(-) create mode 100644 etc/db/database-version.sql diff --git a/etc/db/README.md b/etc/db/README.md index fb7ff46..106fd20 100644 --- a/etc/db/README.md +++ b/etc/db/README.md @@ -30,6 +30,7 @@ Ensure that the following packages are installed: ```bash psql -U postgres <./database-template.sql +psql -U postgres <./database-version.sql ``` --- diff --git a/etc/db/database-template.sql b/etc/db/database-template.sql index 67c5fcc..fec22c7 100644 --- a/etc/db/database-template.sql +++ b/etc/db/database-template.sql @@ -2,8 +2,8 @@ -- PostgreSQL database dump -- --- Dumped from database version 12.4 --- Dumped by pg_dump version 12.4 +-- Dumped from database version 14.2 +-- Dumped by pg_dump version 14.1 SET statement_timeout = 0; SET lock_timeout = 0; @@ -82,7 +82,7 @@ CREATE EXTENSION IF NOT EXISTS btree_gist WITH SCHEMA public; -- --- Name: EXTENSION btree_gist; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION btree_gist; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION btree_gist IS 'support for indexing common datatypes in GiST'; @@ -96,26 +96,12 @@ CREATE EXTENSION IF NOT EXISTS postgis WITH SCHEMA public; -- --- Name: EXTENSION postgis; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis IS 'PostGIS geometry, geography, and raster spatial types and functions'; --- --- Name: postgis_raster; Type: EXTENSION; Schema: -; Owner: - --- - -CREATE EXTENSION IF NOT EXISTS postgis_raster WITH SCHEMA public; - - --- --- Name: EXTENSION postgis_raster; Type: COMMENT; Schema: -; Owner: --- - -COMMENT ON EXTENSION postgis_raster IS 'PostGIS raster types and functions'; - - -- -- Name: postgis_sfcgal; Type: EXTENSION; Schema: -; Owner: - -- @@ -124,7 +110,7 @@ CREATE EXTENSION IF NOT EXISTS postgis_sfcgal WITH SCHEMA public; -- --- Name: EXTENSION postgis_sfcgal; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis_sfcgal; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis_sfcgal IS 'PostGIS SFCGAL functions'; @@ -138,12 +124,26 @@ CREATE EXTENSION IF NOT EXISTS postgis_topology WITH SCHEMA topology; -- --- Name: EXTENSION postgis_topology; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis_topology; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis_topology IS 'PostGIS topology spatial types and functions'; +-- +-- Name: queue_item_status; Type: TYPE; Schema: public; Owner: postgres +-- + +CREATE TYPE public.queue_item_status AS ENUM ( + 'queued', + 'cancelled', + 'failed', + 'sent' +); + + +ALTER TYPE public.queue_item_status OWNER TO postgres; + -- -- Name: notify(); Type: FUNCTION; Schema: public; Owner: postgres -- @@ -182,23 +182,110 @@ $$; ALTER FUNCTION public.notify() OWNER TO postgres; +-- +-- Name: sequence_shot_from_tstamp(timestamp with time zone); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, OUT sequence numeric, OUT point numeric, OUT delta numeric) RETURNS record + LANGUAGE sql + AS $$ + SELECT * FROM public.sequence_shot_from_tstamp(ts, 3); + $$; + + +ALTER FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, OUT sequence numeric, OUT point numeric, OUT delta numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION sequence_shot_from_tstamp(ts timestamp with time zone, OUT sequence numeric, OUT point numeric, OUT delta numeric); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, OUT sequence numeric, OUT point numeric, OUT delta numeric) IS 'Get sequence and shotpoint from timestamp. + +Overloaded form in which the tolerance value is implied and defaults to three seconds.'; + + +-- +-- Name: sequence_shot_from_tstamp(timestamp with time zone, numeric); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT sequence numeric, OUT point numeric, OUT delta numeric) RETURNS record + LANGUAGE sql + AS $$ + SELECT + (meta->>'_sequence')::numeric AS sequence, + (meta->>'_point')::numeric AS point, + extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts ) AS delta + FROM real_time_inputs + WHERE + meta ? '_sequence' AND + abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) < tolerance + ORDER BY abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) + LIMIT 1; + $$; + + +ALTER FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT sequence numeric, OUT point numeric, OUT delta numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION sequence_shot_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT sequence numeric, OUT point numeric, OUT delta numeric); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.sequence_shot_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT sequence numeric, OUT point numeric, OUT delta numeric) IS 'Get sequence and shotpoint from timestamp. + +Given a timestamp this function returns the closest shot to it within the given tolerance value. + +This uses the `real_time_inputs` table and it does not give an indication of which project the shotpoint belongs to. It is assumed that a single project is being acquired at a given time.'; + + -- -- Name: set_survey(text); Type: PROCEDURE; Schema: public; Owner: postgres -- -CREATE PROCEDURE public.set_survey(project_id text) +CREATE PROCEDURE public.set_survey(IN project_id text) LANGUAGE sql AS $$ SELECT set_config('search_path', (SELECT schema||',public' FROM public.projects WHERE pid = lower(project_id)), false); $$; -ALTER PROCEDURE public.set_survey(project_id text) OWNER TO postgres; +ALTER PROCEDURE public.set_survey(IN project_id text) OWNER TO postgres; + +-- +-- Name: update_timestamp(); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.update_timestamp() RETURNS trigger + LANGUAGE plpgsql + AS $$ + BEGIN + IF NEW.updated_on IS NOT NULL THEN + NEW.updated_on := current_timestamp; + END IF; + RETURN NEW; + EXCEPTION + WHEN undefined_column THEN RETURN NEW; + END; +$$; + + +ALTER FUNCTION public.update_timestamp() OWNER TO postgres; SET default_tablespace = ''; SET default_table_access_method = heap; +-- +-- Name: info; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.info ( + key text NOT NULL, + value jsonb +); + + +ALTER TABLE public.info OWNER TO postgres; + -- -- Name: projects; Type: TABLE; Schema: public; Owner: postgres -- @@ -213,6 +300,46 @@ CREATE TABLE public.projects ( ALTER TABLE public.projects OWNER TO postgres; +-- +-- Name: queue_items; Type: TABLE; Schema: public; Owner: postgres +-- + +CREATE TABLE public.queue_items ( + item_id integer NOT NULL, + status public.queue_item_status DEFAULT 'queued'::public.queue_item_status NOT NULL, + payload jsonb NOT NULL, + results jsonb DEFAULT '{}'::jsonb NOT NULL, + created_on timestamp with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + updated_on timestamp with time zone DEFAULT CURRENT_TIMESTAMP NOT NULL, + not_before timestamp with time zone DEFAULT '1970-01-01 00:00:00+00'::timestamp with time zone NOT NULL, + parent_id integer +); + + +ALTER TABLE public.queue_items OWNER TO postgres; + +-- +-- Name: queue_items_item_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres +-- + +CREATE SEQUENCE public.queue_items_item_id_seq + AS integer + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.queue_items_item_id_seq OWNER TO postgres; + +-- +-- Name: queue_items_item_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: postgres +-- + +ALTER SEQUENCE public.queue_items_item_id_seq OWNED BY public.queue_items.item_id; + + -- -- Name: real_time_inputs; Type: TABLE; Schema: public; Owner: postgres -- @@ -227,16 +354,19 @@ CREATE TABLE public.real_time_inputs ( ALTER TABLE public.real_time_inputs OWNER TO postgres; -- --- Name: info; Type: TABLE; Schema: public; Owner: postgres +-- Name: queue_items item_id; Type: DEFAULT; Schema: public; Owner: postgres -- -CREATE TABLE public.info ( - key text NOT NULL, - value jsonb -); +ALTER TABLE ONLY public.queue_items ALTER COLUMN item_id SET DEFAULT nextval('public.queue_items_item_id_seq'::regclass); -ALTER TABLE public.info OWNER TO postgres; +-- +-- Name: info info_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- + +ALTER TABLE ONLY public.info + ADD CONSTRAINT info_pkey PRIMARY KEY (key); + -- -- Name: projects projects_name_key; Type: CONSTRAINT; Schema: public; Owner: postgres @@ -262,14 +392,12 @@ ALTER TABLE ONLY public.projects ADD CONSTRAINT projects_schema_key UNIQUE (schema); - -- --- Name: info info_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres +-- Name: queue_items queue_items_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres -- -ALTER TABLE ONLY public.info - ADD CONSTRAINT info_pkey PRIMARY KEY (key); - +ALTER TABLE ONLY public.queue_items + ADD CONSTRAINT queue_items_pkey PRIMARY KEY (item_id); -- @@ -279,6 +407,13 @@ ALTER TABLE ONLY public.info CREATE INDEX tstamp_idx ON public.real_time_inputs USING btree (tstamp DESC); +-- +-- Name: info info_tg; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER info_tg AFTER INSERT OR DELETE OR UPDATE ON public.info FOR EACH ROW EXECUTE FUNCTION public.notify('info'); + + -- -- Name: projects projects_tg; Type: TRIGGER; Schema: public; Owner: postgres -- @@ -286,6 +421,20 @@ CREATE INDEX tstamp_idx ON public.real_time_inputs USING btree (tstamp DESC); CREATE TRIGGER projects_tg AFTER INSERT OR DELETE OR UPDATE ON public.projects FOR EACH ROW EXECUTE FUNCTION public.notify('project'); +-- +-- Name: queue_items queue_items_tg0; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER queue_items_tg0 BEFORE INSERT OR UPDATE ON public.queue_items FOR EACH ROW EXECUTE FUNCTION public.update_timestamp(); + + +-- +-- Name: queue_items queue_items_tg1; Type: TRIGGER; Schema: public; Owner: postgres +-- + +CREATE TRIGGER queue_items_tg1 AFTER INSERT OR DELETE OR UPDATE ON public.queue_items FOR EACH ROW EXECUTE FUNCTION public.notify('queue_items'); + + -- -- Name: real_time_inputs real_time_inputs_tg; Type: TRIGGER; Schema: public; Owner: postgres -- @@ -294,10 +443,46 @@ CREATE TRIGGER real_time_inputs_tg AFTER INSERT ON public.real_time_inputs FOR E -- --- Name: info info_tg; Type: TRIGGER; Schema: public; Owner: postgres +-- Name: queue_items queue_items_parent_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres -- -CREATE TRIGGER info_tg AFTER INSERT OR DELETE OR UPDATE ON public.info FOR EACH ROW EXECUTE FUNCTION public.notify('info'); +ALTER TABLE ONLY public.queue_items + ADD CONSTRAINT queue_items_parent_id_fkey FOREIGN KEY (parent_id) REFERENCES public.queue_items(item_id); + + +-- +-- Name: TABLE layer; Type: ACL; Schema: topology; Owner: postgres +-- + +REVOKE SELECT ON TABLE topology.layer FROM "204800"; + + +-- +-- Name: TABLE topology; Type: ACL; Schema: topology; Owner: postgres +-- + +REVOKE SELECT ON TABLE topology.topology FROM "204800"; + + +-- +-- Name: TABLE geography_columns; Type: ACL; Schema: public; Owner: postgres +-- + +REVOKE SELECT ON TABLE public.geography_columns FROM "204800"; + + +-- +-- Name: TABLE geometry_columns; Type: ACL; Schema: public; Owner: postgres +-- + +REVOKE SELECT ON TABLE public.geometry_columns FROM "204800"; + + +-- +-- Name: TABLE spatial_ref_sys; Type: ACL; Schema: public; Owner: postgres +-- + +REVOKE SELECT ON TABLE public.spatial_ref_sys FROM "204800"; -- diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql new file mode 100644 index 0000000..d22e56f --- /dev/null +++ b/etc/db/database-version.sql @@ -0,0 +1,3 @@ +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.1"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.3.1"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 24a6a97..d0cedf0 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -2,8 +2,8 @@ -- PostgreSQL database dump -- --- Dumped from database version 12.6 --- Dumped by pg_dump version 12.6 +-- Dumped from database version 14.2 +-- Dumped by pg_dump version 14.2 SET statement_timeout = 0; SET lock_timeout = 0; @@ -29,7 +29,7 @@ ALTER SCHEMA _SURVEY__TEMPLATE_ OWNER TO postgres; -- Name: add_file(text, text); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text) +CREATE PROCEDURE _SURVEY__TEMPLATE_.add_file(IN path_in text, IN hash_in text) LANGUAGE plpgsql AS $$ BEGIN @@ -50,13 +50,13 @@ END; $$; -ALTER PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text) OWNER TO postgres; +ALTER PROCEDURE _SURVEY__TEMPLATE_.add_file(IN path_in text, IN hash_in text) OWNER TO postgres; -- --- Name: PROCEDURE add_file(path_in text, hash_in text); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: PROCEDURE add_file(IN path_in text, IN hash_in text); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text) IS 'Adds a new file to the survey. +COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.add_file(IN path_in text, IN hash_in text) IS 'Adds a new file to the survey. If the hash matches that of an existing entry, update the path of that entry to point to the new path. We assume that the file has been renamed. @@ -98,7 +98,7 @@ BEGIN INTO _planned_line FROM planned_lines WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; - + SELECT COALESCE( ((lead(ts0) OVER (ORDER BY sequence)) - ts1), @@ -107,31 +107,31 @@ BEGIN INTO _lag FROM planned_lines WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; - + _incr = sign(_last_sequence.lsp - _last_sequence.fsp); - + RAISE NOTICE '_planner_config: %', _planner_config; RAISE NOTICE '_last_sequence: %', _last_sequence; RAISE NOTICE '_planned_line: %', _planned_line; RAISE NOTICE '_incr: %', _incr; - + -- Does the latest sequence match a planned sequence? IF _planned_line IS NULL THEN -- No it doesn't RAISE NOTICE 'Latest sequence shot does not match a planned sequence'; SELECT * INTO _planned_line FROM planned_lines ORDER BY sequence ASC LIMIT 1; RAISE NOTICE '_planned_line: %', _planned_line; - + IF _planned_line.sequence <= _last_sequence.sequence THEN RAISE NOTICE 'Renumbering the planned sequences starting from %', _planned_line.sequence + 1; -- Renumber the planned sequences starting from last shot sequence number + 1 UPDATE planned_lines SET sequence = sequence + _last_sequence.sequence - _planned_line.sequence + 1; END IF; - + -- The correction to make to the first planned line's ts0 will be based on either the last -- sequence's EOL + default line change time or the current time, whichever is later. _deltatime := GREATEST(COALESCE(_last_sequence.ts1_final, _last_sequence.ts1) + make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer), current_timestamp) - _planned_line.ts0; - + -- Is the first of the planned lines start time in the past? (±5 mins) IF _planned_line.ts0 < (current_timestamp - make_interval(mins => 5)) THEN RAISE NOTICE 'First planned line is in the past. Adjusting times by %', _deltatime; @@ -142,15 +142,15 @@ BEGIN ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime; END IF; - + ELSE -- Yes it does RAISE NOTICE 'Latest sequence does match a planned sequence: %, %', _planned_line.sequence, _planned_line.line; - + -- Is it online? IF EXISTS(SELECT 1 FROM raw_lines_files WHERE sequence = _last_sequence.sequence AND hash = '*online*') THEN -- Yes it is RAISE NOTICE 'Sequence % is online', _last_sequence.sequence; - + -- Let us get the SOL from the events log if we can RAISE NOTICE 'Trying to set fsp, ts0 from events log FSP, FGSP'; WITH e AS ( @@ -166,12 +166,12 @@ BEGIN ts0 = COALESCE(e.tstamp, ts0) FROM e WHERE planned_lines.sequence = _last_sequence.sequence; - + -- Shot interval _shotinterval := (_last_sequence.ts1 - _last_sequence.ts0) / abs(_last_sequence.lsp - _last_sequence.fsp); - + RAISE NOTICE 'Estimating EOL from current shot interval: %', _shotinterval; - + SELECT (abs(lsp-fsp) * _shotinterval + ts0) - ts1 INTO _deltatime FROM planned_lines @@ -182,10 +182,10 @@ BEGIN --SET --ts1 = (abs(lsp-fsp) * _shotinterval) + ts0 --WHERE sequence = _last_sequence.sequence; - + RAISE NOTICE 'Adjustment is %', _deltatime; - - IF EXTRACT(EPOCH FROM _deltatime) < 8 THEN + + IF abs(EXTRACT(EPOCH FROM _deltatime)) < 8 THEN RAISE NOTICE 'Adjustment too small (< 8 s), so not applying it'; RETURN; END IF; @@ -194,7 +194,7 @@ BEGIN UPDATE planned_lines SET ts1 = ts1 + _deltatime WHERE sequence = _last_sequence.sequence; - + -- Now shift all sequences after UPDATE planned_lines SET ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime @@ -205,11 +205,11 @@ BEGIN DELETE FROM planned_lines WHERE sequence < _last_sequence.sequence; - + ELSE -- No it isn't RAISE NOTICE 'Sequence % is offline', _last_sequence.sequence; - + -- We were supposed to finish at _planned_line.ts1 but we finished at: _tstamp := GREATEST(COALESCE(_last_sequence.ts1_final, _last_sequence.ts1), current_timestamp); -- WARNING Next line is for testing only @@ -226,15 +226,15 @@ BEGIN ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime WHERE sequence > _planned_line.sequence; - + RAISE NOTICE 'Deleting planned sequences up to %', _planned_line.sequence; -- Remove all previous planner entries. DELETE FROM planned_lines WHERE sequence <= _last_sequence.sequence; - + END IF; - + END IF; END; $$; @@ -315,6 +315,113 @@ $$; ALTER FUNCTION _SURVEY__TEMPLATE_.clear_shot_qc() OWNER TO postgres; +-- +-- Name: event_log_full_insert(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_log_full_insert() RETURNS trigger + LANGUAGE plpgsql + AS $$ + BEGIN + NEW.id := COALESCE(NEW.id, NEW.uid); + NEW.validity := tstzrange(current_timestamp, NULL); + NEW.meta = COALESCE(NEW.meta, '{}'::jsonb); + NEW.labels = COALESCE(NEW.labels, ARRAY[]::text[]); + IF cardinality(NEW.labels) > 0 THEN + -- Remove duplicates + SELECT array_agg(DISTINCT elements) + INTO NEW.labels + FROM (SELECT unnest(NEW.labels) AS elements) AS labels; + END IF; + RETURN NEW; + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_log_full_insert() OWNER TO postgres; + +-- +-- Name: event_log_update(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_log_update() RETURNS trigger + LANGUAGE plpgsql + AS $$ + BEGIN + IF (TG_OP = 'INSERT') THEN + + -- Complete the tstamp if possible + IF NEW.sequence IS NOT NULL AND NEW.point IS NOT NULL AND NEW.tstamp IS NULL THEN + SELECT COALESCE( + tstamp_from_sequence_shot(NEW.sequence, NEW.point), + tstamp_interpolate(NEW.sequence, NEW.point) + ) + INTO NEW.tstamp; + END IF; + + -- Any id that is provided will be ignored. The generated + -- id will match uid. + INSERT INTO event_log_full + (tstamp, sequence, point, remarks, labels, meta) + VALUES (NEW.tstamp, NEW.sequence, NEW.point, NEW.remarks, NEW.labels, NEW.meta); + + RETURN NEW; + + ELSIF (TG_OP = 'UPDATE') THEN + -- Set end of validity and create a new entry with id + -- matching that of the old entry. + + -- NOTE: Do not allow updating an event that has meta.readonly = true + IF EXISTS + (SELECT * + FROM event_log_full + WHERE id = OLD.id AND (meta->>'readonly')::boolean IS TRUE) + THEN + RAISE check_violation USING MESSAGE = 'Cannot modify read-only entry'; + RETURN NULL; + END IF; + + -- If the sequence / point has changed, and no new tstamp is provided, get one + IF NEW.sequence <> OLD.sequence OR NEW.point <> OLD.point + AND NEW.sequence IS NOT NULL AND NEW.point IS NOT NULL + AND NEW.tstamp IS NULL OR NEW.tstamp = OLD.tstamp THEN + SELECT COALESCE( + tstamp_from_sequence_shot(NEW.sequence, NEW.point), + tstamp_interpolate(NEW.sequence, NEW.point) + ) + INTO NEW.tstamp; + END IF; + + UPDATE event_log_full + SET validity = tstzrange(lower(validity), current_timestamp) + WHERE validity @> current_timestamp AND id = OLD.id; + + -- Any attempt to modify id will be ignored. + INSERT INTO event_log_full + (id, tstamp, sequence, point, remarks, labels, meta) + VALUES (OLD.id, NEW.tstamp, NEW.sequence, NEW.point, NEW.remarks, NEW.labels, NEW.meta); + + RETURN NEW; + + ELSIF (TG_OP = 'DELETE') THEN + -- Set end of validity. + + -- NOTE: We *do* allow deleting an event that has meta.readonly = true + -- This could be of interest if for instance we wanted to keep the history + -- of QC results for a point, provided that the QC routines write to + -- event_log and not event_log_full + UPDATE event_log_full + SET validity = tstzrange(lower(validity), current_timestamp) + WHERE validity @> current_timestamp AND id = OLD.id; + + RETURN NULL; + END IF; + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_log_update() OWNER TO postgres; + -- -- Name: events_seq_labels_single(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -332,7 +439,7 @@ BEGIN id <> NEW.id AND label = NEW.label AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence); - + DELETE FROM events_timed_labels WHERE @@ -427,7 +534,7 @@ ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgr -- Name: final_line_post_import(integer); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(_seq integer) +CREATE PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(IN _seq integer) LANGUAGE plpgsql AS $$ BEGIN @@ -441,13 +548,13 @@ END; $$; -ALTER PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(_seq integer) OWNER TO postgres; +ALTER PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(IN _seq integer) OWNER TO postgres; -- -- Name: handle_final_line_events(integer, text, text); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(_seq integer, _label text, _column text) +CREATE PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(IN _seq integer, IN _label text, IN _column text) LANGUAGE plpgsql AS $$ @@ -462,14 +569,14 @@ BEGIN SELECT * INTO _line FROM final_lines_summary WHERE sequence = _seq; _event := label_in_sequence(_seq, _label); _column_value := row_to_json(_line)->>_column; - + --RAISE NOTICE '% is %', _label, _event; --RAISE NOTICE 'Line is %', _line; --RAISE NOTICE '% is % (%)', _column, _column_value, _label; - + IF _event IS NULL THEN --RAISE NOTICE 'We will populate the event log from the sequence data'; - + SELECT id INTO event_id FROM events_seq WHERE sequence = _seq AND point = _column_value ORDER BY id LIMIT 1; IF event_id IS NULL THEN --RAISE NOTICE '… but there is no existing event so we create a new one for sequence % and point %', _line.sequence, _column_value; @@ -482,370 +589,83 @@ BEGIN --RAISE NOTICE 'Remove any other auto-inserted % labels in sequence %', _label, _seq; DELETE FROM events_seq_labels WHERE label = _label AND id = (SELECT id FROM events_seq WHERE sequence = _seq AND meta->'auto' ? _label); - + --RAISE NOTICE 'We now add a label to the event (id, label) = (%, %)', event_id, _label; INSERT INTO events_seq_labels (id, label) VALUES (event_id, _label) ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING; - + --RAISE NOTICE 'And also clear the %: % flag from meta.auto for any existing events for sequence %', _label, _tg_name, _seq; UPDATE events_seq SET meta = meta #- ARRAY['auto', _label] WHERE meta->'auto' ? _label AND sequence = _seq AND id <> event_id; - + --RAISE NOTICE 'Finally, flag the event as having been had label % auto-created by %', _label, _tg_name; UPDATE events_seq SET meta = jsonb_set(jsonb_set(meta, '{auto}', COALESCE(meta->'auto', '{}')), ARRAY['auto', _label], to_jsonb(_tg_name)) WHERE id = event_id; - + ELSE --RAISE NOTICE 'We may populate the sequence meta from the event log'; --RAISE NOTICE 'Unless the event log was populated by us previously'; --RAISE NOTICE 'Populated by us previously? %', _event.meta->'auto'->>_label = _tg_name; - + IF _event.meta->'auto'->>_label IS DISTINCT FROM _tg_name THEN --RAISE NOTICE 'Adding % found in events log to final_line meta', _label; UPDATE final_lines SET meta = jsonb_set(meta, ARRAY[_label], to_jsonb(_event.point)) WHERE sequence = _seq; - + --RAISE NOTICE 'Clearing the %: % flag from meta.auto for any existing events in sequence %', _label, _tg_name, _seq; UPDATE events_seq SET meta = meta #- ARRAY['auto', _label] WHERE sequence = _seq AND meta->'auto'->>_label = _tg_name; - + END IF; - + END IF; END; $$; -ALTER PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(_seq integer, _label text, _column text) OWNER TO postgres; - -SET default_tablespace = ''; - -SET default_table_access_method = heap; +ALTER PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(IN _seq integer, IN _label text, IN _column text) OWNER TO postgres; -- --- Name: labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: ij_error(double precision, double precision, public.geometry); Type: FUNCTION; 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_), - meta jsonb DEFAULT '{}'::jsonb NOT NULL -); - - -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 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 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))) - 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 --- - -CREATE TABLE _SURVEY__TEMPLATE_.events_seq ( - id serial NOT NULL, - remarks text NOT NULL, - sequence integer NOT NULL, - point integer NOT NULL, - meta jsonb DEFAULT '{}'::jsonb NOT NULL -); - - -ALTER TABLE _SURVEY__TEMPLATE_.events_seq OWNER TO postgres; - --- --- Name: TABLE events_seq; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq IS 'Events associated with a specific sequence / shot number. The sequence must exist in raw_lines but the shot number need not (yet) exist. This is intended so that people can make entries ahead of time.'; - - --- --- 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_seq_timed; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -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, - s.meta, - rs.geometry - FROM (_SURVEY__TEMPLATE_.events_seq s - LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point)); - - -ALTER TABLE _SURVEY__TEMPLATE_.events_seq_timed OWNER TO postgres; - --- --- Name: events_timed; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE TABLE _SURVEY__TEMPLATE_.events_timed ( - id serial NOT NULL, - remarks text NOT NULL, - tstamp timestamp with time zone NOT NULL, - meta jsonb DEFAULT '{}'::jsonb NOT NULL -); - - -ALTER TABLE _SURVEY__TEMPLATE_.events_timed OWNER TO postgres; - --- --- Name: TABLE events_timed; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed IS 'Events associated with a specific timestamp. The timestamp may or may not be within an acquisition sequence. - -This table actually supports intervals (start + end times) but this is not intended to be used for the time being. - -Events that occur within a sequence can be associated with dynamically, via a view. -'; - - --- --- 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_timed_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE TABLE _SURVEY__TEMPLATE_.events_timed_seq ( - id integer NOT NULL, - sequence integer NOT NULL, - point integer NOT NULL -); - - -ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres; - --- --- Name: TABLE events_timed_seq; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: 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.'; - - --- --- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE VIEW _SURVEY__TEMPLATE_.events AS - WITH qc AS ( - SELECT rs.sequence, - rs.point, - ARRAY[jsonb_array_elements_text(q.labels)] AS labels - FROM _SURVEY__TEMPLATE_.raw_shots rs, - LATERAL jsonb_path_query(rs.meta, '$."qc".*."labels"'::jsonpath) q(labels) - ) - 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.meta, - (public.st_asgeojson(public.st_transform(s.geometry, 4326)))::jsonb AS geometry, - ARRAY( SELECT esl.label - FROM _SURVEY__TEMPLATE_.events_seq_labels esl - WHERE (esl.id = s.id)) AS labels - FROM _SURVEY__TEMPLATE_.events_seq_timed s -UNION - SELECT 'timed'::text AS type, - false AS virtual, - rs.sequence, - rs.point, - t.id, - t.remarks, - rs.line, - rs.objref, - t.tstamp, - rs.hash, - t.meta, - (t.meta -> 'geometry'::text) AS geometry, - ARRAY( SELECT etl.label - FROM _SURVEY__TEMPLATE_.events_timed_labels etl - WHERE (etl.id = t.id)) AS labels - FROM ((_SURVEY__TEMPLATE_.events_timed t - LEFT JOIN _SURVEY__TEMPLATE_.events_timed_seq ts USING (id)) - LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point)) -UNION - 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, - '{}'::jsonb AS meta, - (public.st_asgeojson(public.st_transform(v1.geometry, 4326)))::jsonb AS geometry, - ARRAY[v1.label] AS labels - FROM _SURVEY__TEMPLATE_.events_midnight_shot v1 -UNION - SELECT 'qc'::text AS type, - true AS virtual, - rs.sequence, - rs.point, - ((10000000 + (rs.sequence * 100000)) + rs.point) AS id, - (q.remarks)::text AS remarks, - rs.line, - rs.objref, - rs.tstamp, - rs.hash, - '{}'::jsonb AS meta, - (public.st_asgeojson(public.st_transform(rs.geometry, 4326)))::jsonb AS geometry, - ('{QC}'::text[] || qc.labels) AS labels - FROM (_SURVEY__TEMPLATE_.raw_shots rs - LEFT JOIN qc USING (sequence, point)), - LATERAL jsonb_path_query(rs.meta, '$."qc".*."results"'::jsonpath) q(remarks) - WHERE (rs.meta ? 'qc'::text); - - -ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres; - --- --- Name: label_in_sequence(integer, text); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) RETURNS _SURVEY__TEMPLATE_.events - LANGUAGE sql +CREATE FUNCTION _SURVEY__TEMPLATE_.ij_error(line double precision, point double precision, geom public.geometry) RETURNS public.geometry + LANGUAGE plpgsql STABLE LEAKPROOF AS $$ - SELECT * FROM events WHERE sequence = _sequence AND _label = ANY(labels); -$$; +DECLARE + bp jsonb := binning_parameters(); + ij public.geometry := to_binning_grid(geom, bp); + theta numeric := (bp->>'theta')::numeric * pi() / 180; + I_inc numeric DEFAULT 1; + J_inc numeric DEFAULT 1; + I_width numeric := (bp->>'I_width')::numeric; + J_width numeric := (bp->>'J_width')::numeric; -ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres; + a numeric := (I_inc/I_width) * cos(theta); + b numeric := (I_inc/I_width) * -sin(theta); + c numeric := (J_inc/J_width) * sin(theta); + d numeric := (J_inc/J_width) * cos(theta); + xoff numeric := (bp->'origin'->>'I')::numeric; + yoff numeric := (bp->'origin'->>'J')::numeric; + E0 numeric := (bp->'origin'->>'easting')::numeric; + N0 numeric := (bp->'origin'->>'northing')::numeric; --- --- Name: reset_events_serials(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() RETURNS void - LANGUAGE plpgsql - AS $$ + error_i double precision; + error_j double precision; BEGIN -PERFORM setval('events_timed_id_seq', (SELECT max(id)+1 FROM events_timed)); -PERFORM setval('events_seq_id_seq', (SELECT max(id)+1 FROM events_seq)); -END; + error_i := (public.st_x(ij) - line) * I_width; + error_j := (public.st_y(ij) - point) * J_width; + + RETURN public.ST_MakePoint(error_i, error_j); +END $$; -ALTER FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() OWNER TO postgres; +ALTER FUNCTION _SURVEY__TEMPLATE_.ij_error(line double precision, point double precision, geom public.geometry) OWNER TO postgres; -- -- Name: to_binning_grid(public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres @@ -910,47 +730,78 @@ $$; ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp jsonb) OWNER TO postgres; -- --- Name: events_labels; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: tstamp_from_sequence_shot(numeric, numeric); Type: FUNCTION; 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 -UNION - SELECT 'qc'::text AS type, - ((10000000 + (rs.sequence * 100000)) + rs.point) AS id, - 'QC'::text AS label - FROM _SURVEY__TEMPLATE_.raw_shots rs, - LATERAL jsonb_path_query(rs.meta, '$."qc".*."results"'::jsonpath) q(q) - WHERE (rs.meta ? 'qc'::text) -UNION - SELECT 'qc'::text AS type, - ((10000000 + (rs.sequence * 100000)) + rs.point) AS id, - jsonb_array_elements_text(l.l) AS label - FROM _SURVEY__TEMPLATE_.raw_shots rs, - LATERAL jsonb_path_query(rs.meta, '$."qc".*."labels"'::jsonpath) l(l) - WHERE (rs.meta ? 'qc'::text); +CREATE FUNCTION _SURVEY__TEMPLATE_.tstamp_from_sequence_shot(s numeric, p numeric, OUT ts timestamp with time zone) RETURNS timestamp with time zone + LANGUAGE sql + AS $$ + SELECT tstamp FROM raw_shots WHERE sequence = s AND point = p LIMIT 1; + $$; -ALTER TABLE _SURVEY__TEMPLATE_.events_labels OWNER TO postgres; +ALTER FUNCTION _SURVEY__TEMPLATE_.tstamp_from_sequence_shot(s numeric, p numeric, OUT ts timestamp with time zone) OWNER TO postgres; -- --- Name: events_seq_id_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: FUNCTION tstamp_from_sequence_shot(s numeric, p numeric, OUT ts timestamp with time zone); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE SEQUENCE _SURVEY__TEMPLATE_.events_seq_id_seq +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.tstamp_from_sequence_shot(s numeric, p numeric, OUT ts timestamp with time zone) IS 'Get the timestamp of an existing shotpoint.'; + + +-- +-- Name: tstamp_interpolate(numeric, numeric); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.tstamp_interpolate(s numeric, p numeric) RETURNS timestamp with time zone + LANGUAGE plpgsql + AS $$ + DECLARE + ts0 timestamptz; + ts1 timestamptz; + pt0 numeric; + pt1 numeric; + BEGIN + + SELECT tstamp, point + INTO ts0, pt0 + FROM raw_shots + WHERE sequence = s AND point < p + ORDER BY point DESC LIMIT 1; + + + SELECT tstamp, point + INTO ts1, pt1 + FROM raw_shots + WHERE sequence = s AND point > p + ORDER BY point ASC LIMIT 1; + + RETURN (ts1-ts0)/abs(pt1-pt0)*abs(p-pt0)+ts0; + + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.tstamp_interpolate(s numeric, p numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION tstamp_interpolate(s numeric, p numeric); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.tstamp_interpolate(s numeric, p numeric) IS 'Interpolate a timestamp given sequence and point values. + +It will try to find the points immediately before and after in the sequence and interpolate into the gap, which may consist of multiple missed shots. + +If called on an existing shotpoint it will return an interpolated timestamp as if the shotpoint did not exist, as opposed to returning its actual timestamp. + +Returns NULL if it is not possible to interpolate.'; + + +-- +-- Name: event_log_uid_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE SEQUENCE _SURVEY__TEMPLATE_.event_log_uid_seq AS integer START WITH 1 INCREMENT BY 1 @@ -959,36 +810,52 @@ CREATE SEQUENCE _SURVEY__TEMPLATE_.events_seq_id_seq CACHE 1; -ALTER TABLE _SURVEY__TEMPLATE_.events_seq_id_seq OWNER TO postgres; +ALTER TABLE _SURVEY__TEMPLATE_.event_log_uid_seq OWNER TO postgres; + +SET default_tablespace = ''; + +SET default_table_access_method = heap; -- --- Name: events_seq_id_seq; Type: SEQUENCE OWNED BY; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log_full; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -ALTER SEQUENCE _SURVEY__TEMPLATE_.events_seq_id_seq OWNED BY _SURVEY__TEMPLATE_.events_seq.id; +CREATE TABLE _SURVEY__TEMPLATE_.event_log_full ( + uid integer DEFAULT nextval('_SURVEY__TEMPLATE_.event_log_uid_seq'::regclass) NOT NULL, + id integer NOT NULL, + tstamp timestamp with time zone, + sequence integer, + point integer, + remarks text DEFAULT ''::text NOT NULL, + labels text[] DEFAULT ARRAY[]::text[] NOT NULL, + meta jsonb DEFAULT '{}'::jsonb NOT NULL, + validity tstzrange NOT NULL, + CONSTRAINT event_log_full_check CHECK ((((tstamp IS NOT NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)) OR ((tstamp IS NOT NULL) AND (sequence IS NULL) AND (point IS NULL)) OR ((tstamp IS NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)))), + CONSTRAINT event_log_full_validity_check CHECK ((NOT isempty(validity))) +); +ALTER TABLE _SURVEY__TEMPLATE_.event_log_full OWNER TO postgres; + -- --- Name: events_timed_id_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE SEQUENCE _SURVEY__TEMPLATE_.events_timed_id_seq - AS integer - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +CREATE VIEW _SURVEY__TEMPLATE_.event_log AS + SELECT event_log_full.id, + event_log_full.tstamp, + event_log_full.sequence, + event_log_full.point, + event_log_full.remarks, + event_log_full.labels, + event_log_full.meta, + (event_log_full.uid <> event_log_full.id) AS has_edits, + lower(event_log_full.validity) AS modified_on + FROM _SURVEY__TEMPLATE_.event_log_full + WHERE (event_log_full.validity @> CURRENT_TIMESTAMP); -ALTER TABLE _SURVEY__TEMPLATE_.events_timed_id_seq OWNER TO postgres; - --- --- Name: events_timed_id_seq; Type: SEQUENCE OWNED BY; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER SEQUENCE _SURVEY__TEMPLATE_.events_timed_id_seq OWNED BY _SURVEY__TEMPLATE_.events_timed.id; - +ALTER TABLE _SURVEY__TEMPLATE_.event_log OWNER TO postgres; -- -- Name: file_data; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres @@ -1254,6 +1121,25 @@ 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 -- @@ -1438,6 +1324,24 @@ Missing points are reported regardless of the underlying preplot NTBA 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 -- @@ -1835,6 +1739,32 @@ CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_saillines AS ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_saillines OWNER TO postgres; +-- +-- Name: sequences_detail; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.sequences_detail AS + SELECT rl.sequence, + rl.line AS sailline, + rs.line, + rs.point, + rs.tstamp, + rs.objref AS objrefraw, + fs.objref AS objreffinal, + public.st_transform(pp.geometry, 4326) AS geometrypreplot, + public.st_transform(rs.geometry, 4326) AS geometryraw, + public.st_transform(fs.geometry, 4326) AS geometryfinal, + _SURVEY__TEMPLATE_.ij_error((rs.line)::double precision, (rs.point)::double precision, rs.geometry) AS errorraw, + _SURVEY__TEMPLATE_.ij_error((rs.line)::double precision, (rs.point)::double precision, fs.geometry) AS errorfinal, + json_build_object('preplot', pp.meta, 'raw', rs.meta, 'final', fs.meta) AS meta + FROM (((_SURVEY__TEMPLATE_.raw_lines rl + JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence)) + JOIN _SURVEY__TEMPLATE_.preplot_points pp ON (((rs.line = pp.line) AND (rs.point = pp.point)))) + LEFT JOIN _SURVEY__TEMPLATE_.final_shots fs ON (((rl.sequence = fs.sequence) AND (rs.point = fs.point)))); + + +ALTER TABLE _SURVEY__TEMPLATE_.sequences_detail OWNER TO postgres; + -- -- Name: sequences_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -1873,49 +1803,11 @@ CREATE VIEW _SURVEY__TEMPLATE_.sequences_summary AS ALTER TABLE _SURVEY__TEMPLATE_.sequences_summary OWNER TO postgres; -- --- Name: events_seq id; Type: DEFAULT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log_full event_log_full_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq ALTER COLUMN id SET DEFAULT nextval('_SURVEY__TEMPLATE_.events_seq_id_seq'::regclass); - - --- --- Name: events_timed id; Type: DEFAULT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed ALTER COLUMN id SET DEFAULT nextval('_SURVEY__TEMPLATE_.events_timed_id_seq'::regclass); - - --- --- Name: events_seq_labels events_seq_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels - ADD CONSTRAINT events_seq_labels_pkey PRIMARY KEY (id, label); - - --- --- Name: events_seq events_seq_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq - ADD CONSTRAINT events_seq_pkey PRIMARY KEY (id); - - --- --- Name: events_timed_labels events_timed_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels - ADD CONSTRAINT events_timed_labels_pkey PRIMARY KEY (id, label); - - --- --- Name: events_timed events_timed_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed - ADD CONSTRAINT events_timed_pkey PRIMARY KEY (id); +ALTER TABLE ONLY _SURVEY__TEMPLATE_.event_log_full + ADD CONSTRAINT event_log_full_pkey PRIMARY KEY (uid); -- @@ -2039,59 +1931,31 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_shots -- --- Name: events_seq_sequence_idx; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log_id; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE INDEX events_seq_sequence_idx ON _SURVEY__TEMPLATE_.events_seq USING btree (sequence); +CREATE INDEX event_log_id ON _SURVEY__TEMPLATE_.event_log_full USING btree (id); -- --- Name: events_timed_ts0_idx; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log_full event_log_full_insert_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (tstamp); +CREATE TRIGGER event_log_full_insert_tg BEFORE INSERT ON _SURVEY__TEMPLATE_.event_log_full FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.event_log_full_insert(); -- --- Name: events_seq_labels events_seq_labels_single_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log_full event_log_full_notify_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_seq_labels FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single(); +CREATE TRIGGER event_log_full_notify_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_.event_log_full FOR EACH ROW EXECUTE FUNCTION public.notify('event'); -- --- Name: events_timed_labels events_seq_labels_single_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- Name: event_log event_log_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- -CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed_labels FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single(); - - --- --- 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_timed events_timed_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -CREATE TRIGGER events_timed_tg BEFORE INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.assoc_tstamp(); +CREATE TRIGGER event_log_tg INSTEAD OF INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_.event_log FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.event_log_update(); -- @@ -2157,62 +2021,6 @@ CREATE TRIGGER raw_lines_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLAT CREATE TRIGGER raw_shots_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_.raw_shots FOR EACH STATEMENT EXECUTE FUNCTION public.notify('raw_shots'); --- --- Name: events_seq_labels events_seq_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels - ADD CONSTRAINT events_seq_labels_id_fkey FOREIGN KEY (id) REFERENCES _SURVEY__TEMPLATE_.events_seq(id) ON UPDATE CASCADE ON DELETE CASCADE; - - --- --- Name: events_seq_labels events_seq_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels - ADD CONSTRAINT events_seq_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE; - - --- --- Name: events_seq events_seq_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -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_timed_labels events_timed_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels - ADD CONSTRAINT events_timed_labels_id_fkey FOREIGN KEY (id) REFERENCES _SURVEY__TEMPLATE_.events_timed(id) ON UPDATE CASCADE ON DELETE CASCADE; - - --- --- Name: events_timed_labels events_timed_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres --- - -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; - - --- --- 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 --