mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 13:07:08 +00:00
Merge branch '268-inline-crossline-errors-no-longer-being-calculated' into 'devel'
Resolve "Inline/crossline errors no longer being calculated" Closes #268 See merge request wgp/dougal/software!39
This commit is contained in:
@@ -1,5 +1,5 @@
|
|||||||
\connect dougal
|
\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
|
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';
|
||||||
|
|||||||
@@ -2,8 +2,8 @@
|
|||||||
-- PostgreSQL database dump
|
-- PostgreSQL database dump
|
||||||
--
|
--
|
||||||
|
|
||||||
-- Dumped from database version 14.2
|
-- Dumped from database version 14.8
|
||||||
-- Dumped by pg_dump version 14.2
|
-- Dumped by pg_dump version 14.9
|
||||||
|
|
||||||
SET statement_timeout = 0;
|
SET statement_timeout = 0;
|
||||||
SET lock_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()
|
CREATE PROCEDURE _SURVEY__TEMPLATE_.adjust_planner()
|
||||||
LANGUAGE plpgsql
|
LANGUAGE plpgsql
|
||||||
AS $$
|
AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
_planner_config jsonb;
|
_planner_config jsonb;
|
||||||
_planned_line planned_lines%ROWTYPE;
|
_planned_line planned_lines%ROWTYPE;
|
||||||
_lag interval;
|
_lag interval;
|
||||||
_last_sequence sequences_summary%ROWTYPE;
|
_last_sequence sequences_summary%ROWTYPE;
|
||||||
_deltatime interval;
|
_deltatime interval;
|
||||||
_shotinterval interval;
|
_shotinterval interval;
|
||||||
_tstamp timestamptz;
|
_tstamp timestamptz;
|
||||||
_incr integer;
|
_incr integer;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
||||||
SET CONSTRAINTS planned_lines_pkey DEFERRED;
|
SET CONSTRAINTS planned_lines_pkey DEFERRED;
|
||||||
|
|
||||||
SELECT data->'planner'
|
SELECT project_configuration()->'planner'
|
||||||
INTO _planner_config
|
INTO _planner_config;
|
||||||
FROM file_data
|
|
||||||
WHERE data ? 'planner';
|
|
||||||
|
|
||||||
SELECT *
|
SELECT *
|
||||||
INTO _last_sequence
|
INTO _last_sequence
|
||||||
FROM sequences_summary
|
FROM sequences_summary
|
||||||
ORDER BY sequence DESC
|
ORDER BY sequence DESC
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
|
|
||||||
SELECT *
|
SELECT *
|
||||||
INTO _planned_line
|
INTO _planned_line
|
||||||
FROM planned_lines
|
FROM planned_lines
|
||||||
WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line;
|
WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line;
|
||||||
|
|
||||||
SELECT
|
SELECT
|
||||||
COALESCE(
|
COALESCE(
|
||||||
((lead(ts0) OVER (ORDER BY sequence)) - ts1),
|
((lead(ts0) OVER (ORDER BY sequence)) - ts1),
|
||||||
make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer)
|
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
|
INTO _lag
|
||||||
SET
|
FROM planned_lines
|
||||||
fsp = COALESCE(e.point, fsp),
|
WHERE sequence = _last_sequence.sequence AND line = _last_sequence.line;
|
||||||
ts0 = COALESCE(e.tstamp, ts0)
|
|
||||||
FROM e
|
|
||||||
WHERE planned_lines.sequence = _last_sequence.sequence;
|
|
||||||
|
|
||||||
-- Shot interval
|
_incr = sign(_last_sequence.lsp - _last_sequence.fsp);
|
||||||
_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 '_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
|
-- Does the latest sequence match a planned sequence?
|
||||||
INTO _deltatime
|
IF _planned_line IS NULL THEN -- No it doesn't
|
||||||
FROM planned_lines
|
RAISE NOTICE 'Latest sequence shot does not match a planned sequence';
|
||||||
WHERE sequence = _last_sequence.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
|
IF _planned_line.sequence <= _last_sequence.sequence THEN
|
||||||
--UPDATE planned_lines
|
RAISE NOTICE 'Renumbering the planned sequences starting from %', _planned_line.sequence + 1;
|
||||||
--SET
|
-- Renumber the planned sequences starting from last shot sequence number + 1
|
||||||
--ts1 = (abs(lsp-fsp) * _shotinterval) + ts0
|
UPDATE planned_lines
|
||||||
--WHERE sequence = _last_sequence.sequence;
|
SET sequence = sequence + _last_sequence.sequence - _planned_line.sequence + 1;
|
||||||
|
|
||||||
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;
|
END IF;
|
||||||
|
|
||||||
-- Adjust ts1 for the current sequence
|
-- The correction to make to the first planned line's ts0 will be based on either the last
|
||||||
UPDATE planned_lines
|
-- sequence's EOL + default line change time or the current time, whichever is later.
|
||||||
SET ts1 = ts1 + _deltatime
|
_deltatime := GREATEST(COALESCE(_last_sequence.ts1_final, _last_sequence.ts1) + make_interval(mins => (_planner_config->>'defaultLineChangeDuration')::integer), current_timestamp) - _planned_line.ts0;
|
||||||
WHERE sequence = _last_sequence.sequence;
|
|
||||||
|
|
||||||
-- Now shift all sequences after
|
-- Is the first of the planned lines start time in the past? (±5 mins)
|
||||||
UPDATE planned_lines
|
IF _planned_line.ts0 < (current_timestamp - make_interval(mins => 5)) THEN
|
||||||
SET ts0 = ts0 + _deltatime, ts1 = ts1 + _deltatime
|
RAISE NOTICE 'First planned line is in the past. Adjusting times by %', _deltatime;
|
||||||
WHERE sequence > _last_sequence.sequence;
|
-- 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;
|
ELSE -- Yes it does
|
||||||
-- Remove all previous planner entries.
|
RAISE NOTICE 'Latest sequence does match a planned sequence: %, %', _planned_line.sequence, _planned_line.line;
|
||||||
DELETE
|
|
||||||
FROM planned_lines
|
|
||||||
WHERE sequence < _last_sequence.sequence;
|
|
||||||
|
|
||||||
ELSE
|
-- Is it online?
|
||||||
-- No it isn't
|
IF EXISTS(SELECT 1 FROM raw_lines_files WHERE sequence = _last_sequence.sequence AND hash = '*online*') THEN
|
||||||
RAISE NOTICE 'Sequence % is offline', _last_sequence.sequence;
|
-- Yes it is
|
||||||
|
RAISE NOTICE 'Sequence % is online', _last_sequence.sequence;
|
||||||
|
|
||||||
-- We were supposed to finish at _planned_line.ts1 but we finished at:
|
-- Let us get the SOL from the events log if we can
|
||||||
_tstamp := GREATEST(COALESCE(_last_sequence.ts1_final, _last_sequence.ts1), current_timestamp);
|
RAISE NOTICE 'Trying to set fsp, ts0 from events log FSP, FGSP';
|
||||||
-- WARNING Next line is for testing only
|
WITH e AS (
|
||||||
--_tstamp := COALESCE(_last_sequence.ts1_final, _last_sequence.ts1);
|
SELECT * FROM event_log
|
||||||
-- So we need to adjust timestamps by:
|
WHERE
|
||||||
_deltatime := _tstamp - _planned_line.ts1;
|
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;
|
-- Shot interval
|
||||||
RAISE NOTICE 'Shifting times by % for sequences > %', _deltatime, _planned_line.sequence;
|
_shotinterval := (_last_sequence.ts1 - _last_sequence.ts0) / abs(_last_sequence.lsp - _last_sequence.fsp);
|
||||||
-- 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;
|
RAISE NOTICE 'Estimating EOL from current shot interval: %', _shotinterval;
|
||||||
-- Remove all previous planner entries.
|
|
||||||
DELETE
|
SELECT (abs(lsp-fsp) * _shotinterval + ts0) - ts1
|
||||||
FROM planned_lines
|
INTO _deltatime
|
||||||
WHERE sequence <= _last_sequence.sequence;
|
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 IF;
|
|
||||||
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
|
CREATE FUNCTION _SURVEY__TEMPLATE_.binning_parameters() RETURNS jsonb
|
||||||
LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE
|
LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE
|
||||||
AS $$
|
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;
|
ALTER FUNCTION _SURVEY__TEMPLATE_.binning_parameters() OWNER TO postgres;
|
||||||
@@ -671,7 +669,7 @@ BEGIN
|
|||||||
id <> NEW.id
|
id <> NEW.id
|
||||||
AND label = NEW.label
|
AND label = NEW.label
|
||||||
AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence);
|
AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence);
|
||||||
|
|
||||||
DELETE
|
DELETE
|
||||||
FROM events_timed_labels
|
FROM events_timed_labels
|
||||||
WHERE
|
WHERE
|
||||||
@@ -854,7 +852,7 @@ CREATE FUNCTION _SURVEY__TEMPLATE_.ij_error(line double precision, point double
|
|||||||
DECLARE
|
DECLARE
|
||||||
bp jsonb := binning_parameters();
|
bp jsonb := binning_parameters();
|
||||||
ij public.geometry := to_binning_grid(geom, bp);
|
ij public.geometry := to_binning_grid(geom, bp);
|
||||||
|
|
||||||
theta numeric := (bp->>'theta')::numeric * pi() / 180;
|
theta numeric := (bp->>'theta')::numeric * pi() / 180;
|
||||||
I_inc numeric DEFAULT 1;
|
I_inc numeric DEFAULT 1;
|
||||||
J_inc numeric DEFAULT 1;
|
J_inc numeric DEFAULT 1;
|
||||||
@@ -869,13 +867,13 @@ DECLARE
|
|||||||
yoff numeric := (bp->'origin'->>'J')::numeric;
|
yoff numeric := (bp->'origin'->>'J')::numeric;
|
||||||
E0 numeric := (bp->'origin'->>'easting')::numeric;
|
E0 numeric := (bp->'origin'->>'easting')::numeric;
|
||||||
N0 numeric := (bp->'origin'->>'northing')::numeric;
|
N0 numeric := (bp->'origin'->>'northing')::numeric;
|
||||||
|
|
||||||
error_i double precision;
|
error_i double precision;
|
||||||
error_j double precision;
|
error_j double precision;
|
||||||
BEGIN
|
BEGIN
|
||||||
error_i := (public.st_x(ij) - line) * I_width;
|
error_i := (public.st_x(ij) - line) * I_width;
|
||||||
error_j := (public.st_y(ij) - point) * J_width;
|
error_j := (public.st_y(ij) - point) * J_width;
|
||||||
|
|
||||||
RETURN public.ST_MakePoint(error_i, error_j);
|
RETURN public.ST_MakePoint(error_i, error_j);
|
||||||
END
|
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.';
|
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
|
-- Name: replace_placeholders(text, timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||||
--
|
--
|
||||||
|
|||||||
@@ -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 <<EOF
|
||||||
|
-- \i $THIS_FILE
|
||||||
|
-- COMMIT;
|
||||||
|
-- EOF
|
||||||
|
--
|
||||||
|
-- NOTE: It can be applied multiple times without ill effect.
|
||||||
|
--
|
||||||
|
|
||||||
|
BEGIN;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
||||||
|
BEGIN
|
||||||
|
RAISE NOTICE '%', notice;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
RAISE NOTICE 'Updating schema %', schema_name;
|
||||||
|
-- We need to set the search path because some of the trigger
|
||||||
|
-- functions reference other tables in survey schemas assuming
|
||||||
|
-- they are in the search path.
|
||||||
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION 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
|
||||||
|
$$;
|
||||||
|
|
||||||
|
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.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
|
||||||
|
--
|
||||||
@@ -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 <<EOF
|
||||||
|
-- \i $THIS_FILE
|
||||||
|
-- COMMIT;
|
||||||
|
-- EOF
|
||||||
|
--
|
||||||
|
-- NOTE: It can be applied multiple times without ill effect.
|
||||||
|
--
|
||||||
|
|
||||||
|
BEGIN;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
||||||
|
BEGIN
|
||||||
|
RAISE NOTICE '%', notice;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
RAISE NOTICE 'Updating schema %', schema_name;
|
||||||
|
-- We need to set the search path because some of the trigger
|
||||||
|
-- functions reference other tables in survey schemas assuming
|
||||||
|
-- they are in the search path.
|
||||||
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
||||||
|
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE 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
|
||||||
|
|
||||||
|
SET CONSTRAINTS planned_lines_pkey DEFERRED;
|
||||||
|
|
||||||
|
SELECT project_configuration()->'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
|
||||||
|
--
|
||||||
@@ -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 <<EOF
|
||||||
|
-- \i $THIS_FILE
|
||||||
|
-- COMMIT;
|
||||||
|
-- EOF
|
||||||
|
--
|
||||||
|
-- NOTE: It can be applied multiple times without ill effect.
|
||||||
|
--
|
||||||
|
|
||||||
|
BEGIN;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
||||||
|
BEGIN
|
||||||
|
RAISE NOTICE '%', notice;
|
||||||
|
END;
|
||||||
|
$$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
RAISE NOTICE 'Updating schema %', schema_name;
|
||||||
|
-- We need to set the search path because some of the trigger
|
||||||
|
-- functions reference other tables in survey schemas assuming
|
||||||
|
-- they are in the search path.
|
||||||
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION binning_parameters() RETURNS jsonb
|
||||||
|
LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE
|
||||||
|
AS $$
|
||||||
|
SELECT project_configuration()->'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
|
||||||
|
--
|
||||||
@@ -1,6 +1,6 @@
|
|||||||
#!/usr/bin/node
|
#!/usr/bin/node
|
||||||
|
|
||||||
const { INFO, DEBUG } = require('DOUGAL_ROOT/debug')(__filename);
|
const { ERROR, INFO, DEBUG } = require('DOUGAL_ROOT/debug')(__filename);
|
||||||
|
|
||||||
async function main () {
|
async function main () {
|
||||||
// Check that we're running against the correct database version
|
// Check that we're running against the correct database version
|
||||||
|
|||||||
@@ -11,7 +11,7 @@
|
|||||||
"license": "UNLICENSED",
|
"license": "UNLICENSED",
|
||||||
"private": true,
|
"private": true,
|
||||||
"config": {
|
"config": {
|
||||||
"db_schema": "^0.3.11",
|
"db_schema": "^0.4.2",
|
||||||
"api": "^0.4.0"
|
"api": "^0.4.0"
|
||||||
},
|
},
|
||||||
"engines": {
|
"engines": {
|
||||||
|
|||||||
Reference in New Issue
Block a user