diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index f9ee035..d4530ce 100644 --- a/etc/db/database-version.sql +++ b/etc/db/database-version.sql @@ -1,5 +1,5 @@ \connect dougal -INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.13"}') +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.2"}') ON CONFLICT (key) DO UPDATE - SET value = public.info.value || '{"db_schema": "0.3.13"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.4.2"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index bac1969..0f6ed68 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -2,8 +2,8 @@ -- PostgreSQL database dump -- --- Dumped from database version 14.2 --- Dumped by pg_dump version 14.2 +-- Dumped from database version 14.8 +-- Dumped by pg_dump version 14.9 SET statement_timeout = 0; SET lock_timeout = 0; @@ -70,173 +70,171 @@ 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 project_configuration()->'planner' + INTO _planner_config; - 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; - - _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; - -- 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; - - -- 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 event_log - WHERE - sequence = _last_sequence.sequence - AND ('FSP' = ANY(labels) OR 'FGSP' = ANY(labels)) - ORDER BY tstamp LIMIT 1 + SELECT + COALESCE( + ((lead(ts0) OVER (ORDER BY sequence)) - ts1), + make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer) ) - UPDATE planned_lines - SET - fsp = COALESCE(e.point, fsp), - ts0 = COALESCE(e.tstamp, ts0) - FROM e - WHERE planned_lines.sequence = _last_sequence.sequence; + INTO _lag + FROM planned_lines + WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line; - -- Shot interval - _shotinterval := (_last_sequence.ts1 - _last_sequence.ts0) / abs(_last_sequence.lsp - _last_sequence.fsp); + _incr = sign(_last_sequence.lsp - _last_sequence.fsp); - RAISE NOTICE 'Estimating EOL from current shot interval: %', _shotinterval; + RAISE NOTICE '_planner_config: %', _planner_config; + RAISE NOTICE '_last_sequence: %', _last_sequence; + RAISE NOTICE '_planned_line: %', _planned_line; + RAISE NOTICE '_incr: %', _incr; - SELECT (abs(lsp-fsp) * _shotinterval + ts0) - ts1 - INTO _deltatime - FROM planned_lines - WHERE sequence = _last_sequence.sequence; + -- 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; - ---- 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; - - IF abs(EXTRACT(EPOCH FROM _deltatime)) < 8 THEN - RAISE NOTICE 'Adjustment too small (< 8 s), so not applying it'; - RETURN; + 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; - -- Adjust ts1 for the current sequence - UPDATE planned_lines - SET ts1 = ts1 + _deltatime - WHERE sequence = _last_sequence.sequence; + -- 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; - -- Now shift all sequences after - UPDATE planned_lines - SET ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime - WHERE sequence > _last_sequence.sequence; + -- 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; - RAISE NOTICE 'Deleting planned sequences before %', _planned_line.sequence; - -- Remove all previous planner entries. - DELETE - FROM planned_lines - WHERE sequence < _last_sequence.sequence; + ELSE -- Yes it does + RAISE NOTICE 'Latest sequence does match a planned sequence: %, %', _planned_line.sequence, _planned_line.line; - ELSE - -- No it isn't - RAISE NOTICE 'Sequence % is offline', _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; - -- 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; + -- 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; - 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; + -- Shot interval + _shotinterval := (_last_sequence.ts1 - _last_sequence.ts0) / abs(_last_sequence.lsp - _last_sequence.fsp); - 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 'Estimating EOL from current shot interval: %', _shotinterval; + + 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; + + 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; + + -- 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; + + 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; + + -- 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 '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; $$; @@ -367,8 +365,8 @@ COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.augment_event_data(IN maxspan numeric) I CREATE FUNCTION _SURVEY__TEMPLATE_.binning_parameters() RETURNS jsonb LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE AS $$ -SELECT data->'binning' binning FROM file_data WHERE data->>'binning' IS NOT NULL LIMIT 1; -$$; + SELECT project_configuration()->'binning' binning; + $$; ALTER FUNCTION _SURVEY__TEMPLATE_.binning_parameters() OWNER TO postgres; @@ -671,7 +669,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 @@ -854,7 +852,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; @@ -869,13 +867,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 $$; @@ -1042,6 +1040,39 @@ ALTER PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.log_midnight_shots(IN dt0 date, IN dt1 date) IS 'Add midnight shots between two dates dt0 and dt1 to the event_log, unless the events already exist.'; +-- +-- Name: project_configuration(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.project_configuration() RETURNS jsonb + LANGUAGE plpgsql + AS $$ + DECLARE + schema_name text; + configuration jsonb; + BEGIN + + SELECT nspname + INTO schema_name + FROM pg_namespace + WHERE oid = ( + SELECT pronamespace + FROM pg_proc + WHERE oid = 'project_configuration'::regproc::oid + ); + + SELECT meta + INTO configuration + FROM public.projects + WHERE schema = schema_name; + + RETURN configuration; + END + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.project_configuration() OWNER TO postgres; + -- -- Name: replace_placeholders(text, timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- diff --git a/etc/db/upgrades/upgrade27-v0.4.0-add-project_configuration-function.sql b/etc/db/upgrades/upgrade27-v0.4.0-add-project_configuration-function.sql new file mode 100644 index 0000000..5bb93c2 --- /dev/null +++ b/etc/db/upgrades/upgrade27-v0.4.0-add-project_configuration-function.sql @@ -0,0 +1,122 @@ +-- Fix wrong number of missing shots in summary views +-- +-- New schema version: 0.4.0 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects all schemas in the database. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This adapts the schema to the change in how project configurations are +-- handled (https://gitlab.com/wgp/dougal/software/-/merge_requests/29) +-- by creating a project_configuration() function which returns the +-- current project's configuration data. +-- +-- To apply, run as the dougal user: +-- +-- psql <>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version'; + + IF current_db_version >= '0.4.0' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.3.12' AND current_db_version != '0.3.13' THEN + RAISE EXCEPTION + USING MESSAGE='Invalid database version: ' || current_db_version, + HINT='Ensure all previous patches have been applied.'; + END IF; + + FOR row IN + SELECT schema_name FROM information_schema.schemata + WHERE schema_name LIKE 'survey_%' + ORDER BY schema_name + LOOP + CALL pg_temp.upgrade_survey_schema(row.schema_name); + END LOOP; +END; +$outer$ LANGUAGE plpgsql; + +CALL pg_temp.upgrade(); + +CALL pg_temp.show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade (); + +CALL pg_temp.show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.0"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.4.0"}' WHERE public.info.key = 'version'; + + +CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes'); +DROP PROCEDURE pg_temp.show_notice (notice text); + +-- +--NOTE Run `COMMIT;` now if all went well +-- diff --git a/etc/db/upgrades/upgrade28-v0.4.1-use-project-configuration-in-adjust_planner.sql b/etc/db/upgrades/upgrade28-v0.4.1-use-project-configuration-in-adjust_planner.sql new file mode 100644 index 0000000..35f1e80 --- /dev/null +++ b/etc/db/upgrades/upgrade28-v0.4.1-use-project-configuration-in-adjust_planner.sql @@ -0,0 +1,264 @@ +-- Fix wrong number of missing shots in summary views +-- +-- New schema version: 0.4.1 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects all schemas in the database. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This modifies adjust_planner() to use project_configuration() +-- +-- To apply, run as the dougal user: +-- +-- psql <'planner' + INTO _planner_config; + + 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 + 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); + + 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; + -- 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; + + -- 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 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); + + 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; + + ---- 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; + + 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; + + -- 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; + + 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; + + 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; + + END IF; + + END IF; + END; + $$; + + +END; +$outer$ LANGUAGE plpgsql; + +CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$ +DECLARE + row RECORD; + current_db_version TEXT; +BEGIN + + SELECT value->>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version'; + + IF current_db_version >= '0.4.1' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.4.0' THEN + RAISE EXCEPTION + USING MESSAGE='Invalid database version: ' || current_db_version, + HINT='Ensure all previous patches have been applied.'; + END IF; + + FOR row IN + SELECT schema_name FROM information_schema.schemata + WHERE schema_name LIKE 'survey_%' + ORDER BY schema_name + LOOP + CALL pg_temp.upgrade_survey_schema(row.schema_name); + END LOOP; +END; +$outer$ LANGUAGE plpgsql; + +CALL pg_temp.upgrade(); + +CALL pg_temp.show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade (); + +CALL pg_temp.show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.1"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.4.1"}' WHERE public.info.key = 'version'; + + +CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes'); +DROP PROCEDURE pg_temp.show_notice (notice text); + +-- +--NOTE Run `COMMIT;` now if all went well +-- diff --git a/etc/db/upgrades/upgrade29-v0.4.2-use-project-configuration-in-binning_parameters.sql b/etc/db/upgrades/upgrade29-v0.4.2-use-project-configuration-in-binning_parameters.sql new file mode 100644 index 0000000..cf5ec86 --- /dev/null +++ b/etc/db/upgrades/upgrade29-v0.4.2-use-project-configuration-in-binning_parameters.sql @@ -0,0 +1,98 @@ +-- Fix wrong number of missing shots in summary views +-- +-- New schema version: 0.4.2 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects all schemas in the database. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This modifies binning_parameters() to use project_configuration() +-- +-- To apply, run as the dougal user: +-- +-- psql <'binning' binning; + $$; + +END; +$outer$ LANGUAGE plpgsql; + +CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$ +DECLARE + row RECORD; + current_db_version TEXT; +BEGIN + + SELECT value->>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version'; + + IF current_db_version >= '0.4.2' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.4.1' THEN + RAISE EXCEPTION + USING MESSAGE='Invalid database version: ' || current_db_version, + HINT='Ensure all previous patches have been applied.'; + END IF; + + FOR row IN + SELECT schema_name FROM information_schema.schemata + WHERE schema_name LIKE 'survey_%' + ORDER BY schema_name + LOOP + CALL pg_temp.upgrade_survey_schema(row.schema_name); + END LOOP; +END; +$outer$ LANGUAGE plpgsql; + +CALL pg_temp.upgrade(); + +CALL pg_temp.show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade (); + +CALL pg_temp.show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.2"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.4.2"}' WHERE public.info.key = 'version'; + + +CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes'); +DROP PROCEDURE pg_temp.show_notice (notice text); + +-- +--NOTE Run `COMMIT;` now if all went well +-- diff --git a/lib/www/server/index.js b/lib/www/server/index.js index 4470562..09221bd 100755 --- a/lib/www/server/index.js +++ b/lib/www/server/index.js @@ -1,6 +1,6 @@ #!/usr/bin/node -const { INFO, DEBUG } = require('DOUGAL_ROOT/debug')(__filename); +const { ERROR, INFO, DEBUG } = require('DOUGAL_ROOT/debug')(__filename); async function main () { // Check that we're running against the correct database version diff --git a/lib/www/server/package.json b/lib/www/server/package.json index 0ccd1f3..7ed6630 100644 --- a/lib/www/server/package.json +++ b/lib/www/server/package.json @@ -11,7 +11,7 @@ "license": "UNLICENSED", "private": true, "config": { - "db_schema": "^0.3.11", + "db_schema": "^0.4.2", "api": "^0.4.0" }, "engines": {