From a2bd614b170859f4df1a58e8d287d7f1b45559cd Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Tue, 10 May 2022 21:57:53 +0200 Subject: [PATCH] Update database templates. * Optimise public.geometry_from_tstamp() * Remove index on public.real_time_inputs.meta->>'tstamp' * Fix adjust_planner() --- etc/db/database-template.sql | 15 +- etc/db/database-version.sql | 4 +- etc/db/schema-template.sql | 386 +++++++++++++++++------------------ 3 files changed, 199 insertions(+), 206 deletions(-) diff --git a/etc/db/database-template.sql b/etc/db/database-template.sql index 0ed46f5..5e9c08f 100644 --- a/etc/db/database-template.sql +++ b/etc/db/database-template.sql @@ -20,7 +20,7 @@ SET row_security = off; -- Name: dougal; Type: DATABASE; Schema: -; Owner: postgres -- -CREATE DATABASE dougal WITH TEMPLATE = template0 ENCODING = 'UTF8' LOCALE = 'en_GB.UTF-8'; +CREATE DATABASE dougal WITH TEMPLATE = template0 ENCODING = 'UTF8' LC_COLLATE = 'C' LC_CTYPE = 'en_GB.UTF-8'; ALTER DATABASE dougal OWNER TO postgres; @@ -153,12 +153,12 @@ CREATE FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, toleran AS $$ SELECT geometry, - extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts ) AS delta + extract('epoch' FROM tstamp - ts ) AS delta FROM real_time_inputs WHERE geometry IS NOT NULL AND - abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) < tolerance - ORDER BY abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) + tstamp BETWEEN (ts - tolerance * interval '1 second') AND (ts + tolerance * interval '1 second') + ORDER BY abs(extract('epoch' FROM tstamp - ts )) LIMIT 1; $$; @@ -428,13 +428,6 @@ ALTER TABLE ONLY public.queue_items ADD CONSTRAINT queue_items_pkey PRIMARY KEY (item_id); --- --- Name: meta_tstamp_idx; Type: INDEX; Schema: public; Owner: postgres --- - -CREATE INDEX meta_tstamp_idx ON public.real_time_inputs USING btree (((meta ->> 'tstamp'::text)) DESC); - - -- -- Name: tstamp_idx; Type: INDEX; Schema: public; Owner: postgres -- diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index 10e4844..d259719 100644 --- a/etc/db/database-version.sql +++ b/etc/db/database-version.sql @@ -1,3 +1,3 @@ -INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.5"}') +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.7"}') ON CONFLICT (key) DO UPDATE - SET value = public.info.value || '{"db_schema": "0.3.5"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.7"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index c3ebb29..6be07a9 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -70,174 +70,174 @@ If the path matches that of an existing entry, delete that entry (which cascades CREATE PROCEDURE _SURVEY__TEMPLATE_.adjust_planner() LANGUAGE plpgsql AS $$ -DECLARE - _planner_config jsonb; - _planned_line planned_lines%ROWTYPE; - _lag interval; - _last_sequence sequences_summary%ROWTYPE; - _deltatime interval; - _shotinterval interval; - _tstamp timestamptz; - _incr integer; -BEGIN + DECLARE + _planner_config jsonb; + _planned_line planned_lines%ROWTYPE; + _lag interval; + _last_sequence sequences_summary%ROWTYPE; + _deltatime interval; + _shotinterval interval; + _tstamp timestamptz; + _incr integer; + BEGIN - SET CONSTRAINTS planned_lines_pkey DEFERRED; + SET CONSTRAINTS planned_lines_pkey DEFERRED; - SELECT data->'planner' - INTO _planner_config - FROM file_data - WHERE data ? 'planner'; + SELECT data->'planner' + INTO _planner_config + FROM file_data + WHERE data ? 'planner'; - SELECT * - INTO _last_sequence - FROM sequences_summary - ORDER BY sequence DESC - LIMIT 1; + SELECT * + INTO _last_sequence + FROM sequences_summary + ORDER BY sequence DESC + LIMIT 1; - SELECT * - INTO _planned_line - FROM planned_lines - WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; + SELECT * + 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), - make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer) - ) - INTO _lag - FROM planned_lines - WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; + SELECT + COALESCE( + ((lead(ts0) OVER (ORDER BY sequence)) - ts1), + make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer) + ) + INTO _lag + FROM planned_lines + WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; - _incr = sign(_last_sequence.lsp - _last_sequence.fsp); + _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; + 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; + -- 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; + 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; + -- 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; - -- Adjust the start / end time of the planned lines by assuming that we are at - -- `defaultLineChangeDuration` minutes away from SOL of the first planned line. - UPDATE planned_lines - SET - ts0 = ts0 + _deltatime, - ts1 = ts1 + _deltatime; - END IF; + -- 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; + -- Adjust the start / end time of the planned lines by assuming that we are at + -- `defaultLineChangeDuration` minutes away from SOL of the first planned line. + UPDATE planned_lines + SET + 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; + 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; + -- 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 ( - SELECT * FROM events - WHERE - sequence = _last_sequence.sequence - AND ('FSP' = ANY(labels) OR 'FGSP' = ANY(labels)) - ORDER BY tstamp LIMIT 1 - ) - UPDATE planned_lines - SET - fsp = COALESCE(e.point, fsp), - ts0 = COALESCE(e.tstamp, ts0) - FROM e - WHERE planned_lines.sequence = _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 ( + SELECT * FROM event_log + WHERE + sequence = _last_sequence.sequence + AND ('FSP' = ANY(labels) OR 'FGSP' = ANY(labels)) + ORDER BY tstamp LIMIT 1 + ) + UPDATE planned_lines + SET + fsp = COALESCE(e.point, fsp), + 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); + -- 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; + RAISE NOTICE 'Estimating EOL from current shot interval: %', _shotinterval; - SELECT (abs(lsp-fsp) * _shotinterval + ts0) - ts1 - INTO _deltatime - FROM planned_lines - WHERE sequence = _last_sequence.sequence; + SELECT (abs(lsp-fsp) * _shotinterval + ts0) - ts1 + INTO _deltatime + FROM planned_lines + WHERE sequence = _last_sequence.sequence; - ---- Set ts1 for the current sequence - --UPDATE planned_lines - --SET - --ts1 = (abs(lsp-fsp) * _shotinterval) + ts0 - --WHERE sequence = _last_sequence.sequence; + ---- Set ts1 for the current sequence + --UPDATE planned_lines + --SET + --ts1 = (abs(lsp-fsp) * _shotinterval) + ts0 + --WHERE sequence = _last_sequence.sequence; - RAISE NOTICE 'Adjustment is %', _deltatime; + RAISE NOTICE 'Adjustment is %', _deltatime; - IF abs(EXTRACT(EPOCH FROM _deltatime)) < 8 THEN - RAISE NOTICE 'Adjustment too small (< 8 s), so not applying it'; - RETURN; - END IF; + IF abs(EXTRACT(EPOCH FROM _deltatime)) < 8 THEN + RAISE NOTICE 'Adjustment too small (< 8 s), so not applying it'; + RETURN; + END IF; - -- Adjust ts1 for the current sequence - UPDATE planned_lines - SET ts1 = ts1 + _deltatime - WHERE sequence = _last_sequence.sequence; + -- Adjust ts1 for the current sequence + 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 - WHERE sequence > _last_sequence.sequence; + -- Now shift all sequences after + UPDATE planned_lines + SET ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime + WHERE sequence > _last_sequence.sequence; - RAISE NOTICE 'Deleting planned sequences before %', _planned_line.sequence; - -- Remove all previous planner entries. - DELETE - FROM planned_lines - WHERE sequence < _last_sequence.sequence; + RAISE NOTICE 'Deleting planned sequences before %', _planned_line.sequence; + -- Remove all previous planner entries. + DELETE + FROM planned_lines + WHERE sequence < _last_sequence.sequence; - ELSE - -- No it isn't - RAISE NOTICE 'Sequence % is offline', _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 - --_tstamp := COALESCE(_last_sequence.ts1_final, _last_sequence.ts1); - -- So we need to adjust timestamps by: - _deltatime := _tstamp - _planned_line.ts1; + -- 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 + --_tstamp := COALESCE(_last_sequence.ts1_final, _last_sequence.ts1); + -- So we need to adjust timestamps by: + _deltatime := _tstamp - _planned_line.ts1; - RAISE NOTICE 'Planned end: %, actual end: % (%, %)', _planned_line.ts1, _tstamp, _planned_line.sequence, _last_sequence.sequence; - RAISE NOTICE 'Shifting times by % for sequences > %', _deltatime, _planned_line.sequence; - -- NOTE: This won't work if sequences are not, err… sequential. - -- NOTE: This has been known to happen in 2020. - UPDATE planned_lines - SET - ts0 = ts0 + _deltatime, - ts1 = ts1 + _deltatime - WHERE sequence > _planned_line.sequence; + RAISE NOTICE 'Planned end: %, actual end: % (%, %)', _planned_line.ts1, _tstamp, _planned_line.sequence, _last_sequence.sequence; + RAISE NOTICE 'Shifting times by % for sequences > %', _deltatime, _planned_line.sequence; + -- NOTE: This won't work if sequences are not, err… sequential. + -- NOTE: This has been known to happen in 2020. + UPDATE planned_lines + SET + 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; + 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 IF; -END; -$$; + END IF; + END; + $$; ALTER PROCEDURE _SURVEY__TEMPLATE_.adjust_planner() OWNER TO postgres; @@ -513,7 +513,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 @@ -611,15 +611,15 @@ ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgr CREATE PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(IN _seq integer) LANGUAGE plpgsql AS $$ -BEGIN + BEGIN -CALL handle_final_line_events(_seq, 'FSP', 'fsp'); -CALL handle_final_line_events(_seq, 'FGSP', 'fsp'); -CALL handle_final_line_events(_seq, 'LGSP', 'lsp'); -CALL handle_final_line_events(_seq, 'LSP', 'lsp'); + CALL handle_final_line_events(_seq, 'FSP', 'fsp'); + CALL handle_final_line_events(_seq, 'FGSP', 'fsp'); + CALL handle_final_line_events(_seq, 'LGSP', 'lsp'); + CALL handle_final_line_events(_seq, 'LSP', 'lsp'); -END; -$$; + END; + $$; ALTER PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(IN _seq integer) OWNER TO postgres; @@ -632,56 +632,56 @@ CREATE PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(IN _seq integer, IN LANGUAGE plpgsql AS $$ -DECLARE -_line final_lines_summary%ROWTYPE; -_column_value integer; -_tg_name text := 'final_line'; -_event event_log%ROWTYPE; -event_id integer; -BEGIN + DECLARE + _line final_lines_summary%ROWTYPE; + _column_value integer; + _tg_name text := 'final_line'; + _event event_log%ROWTYPE; + event_id integer; + BEGIN - SELECT * INTO _line FROM final_lines_summary WHERE sequence = _seq; - _event := label_in_sequence(_seq, _label); - _column_value := row_to_json(_line)->>_column; + 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; + --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'; + IF _event IS NULL THEN + --RAISE NOTICE 'We will populate the event log from the sequence data'; - INSERT INTO event_log (sequence, point, remarks, labels, meta) - VALUES ( - -- The sequence - _seq, - -- The shotpoint - _column_value, - -- Remark. Something like "FSP " - format('%s %s', _label, (SELECT meta->>'lineName' FROM final_lines WHERE sequence = _seq)), - -- Label - ARRAY[_label], - -- Meta. Something like {"auto" : {"FSP" : "final_line"}} - json_build_object('auto', json_build_object(_label, _tg_name)) - ); + INSERT INTO event_log (sequence, point, remarks, labels, meta) + VALUES ( + -- The sequence + _seq, + -- The shotpoint + _column_value, + -- Remark. Something like "FSP " + format('%s %s', _label, (SELECT meta->>'lineName' FROM final_lines WHERE sequence = _seq)), + -- Label + ARRAY[_label], + -- Meta. Something like {"auto" : {"FSP" : "final_line"}} + json_build_object('auto', json_build_object(_label, _tg_name)) + ); - 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; + 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 + 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 '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; - END IF; + END IF; - END IF; -END; -$$; + END IF; + END; + $$; ALTER PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(IN _seq integer, IN _label text, IN _column text) OWNER TO postgres; @@ -696,7 +696,7 @@ CREATE FUNCTION _SURVEY__TEMPLATE_.ij_error(line double precision, point double 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; @@ -711,13 +711,13 @@ DECLARE yoff numeric := (bp->'origin'->>'J')::numeric; E0 numeric := (bp->'origin'->>'easting')::numeric; N0 numeric := (bp->'origin'->>'northing')::numeric; - + error_i double precision; error_j double precision; BEGIN 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 $$; @@ -792,8 +792,8 @@ ALTER TABLE _SURVEY__TEMPLATE_.event_log OWNER TO postgres; CREATE FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) RETURNS _SURVEY__TEMPLATE_.event_log LANGUAGE sql AS $$ - SELECT * FROM event_log WHERE sequence = _sequence AND _label = ANY(labels); -$$; + SELECT * FROM event_log WHERE sequence = _sequence AND _label = ANY(labels); + $$; ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres;