-- 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 --