mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 12:27:07 +00:00
* Adds label_in_sequence() function NOTE: This function is already defined in schema-template.sql but seemingly never got pushed into production. Fixes #211.
159 lines
4.3 KiB
PL/PgSQL
159 lines
4.3 KiB
PL/PgSQL
-- Fix not being able to edit a time-based event.
|
|
--
|
|
-- New schema version: 0.3.5
|
|
--
|
|
-- 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.
|
|
--
|
|
-- The function label_in_sequence(integer, text) was missing for the
|
|
-- production schemas. This patch (re-)defines the function as well
|
|
-- as other function that depend on it (otherwise it does not get
|
|
-- picked up).
|
|
--
|
|
-- 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 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 $$
|
|
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 label_in_sequence(_sequence integer, _label text) RETURNS event_log
|
|
LANGUAGE sql
|
|
AS $inner$
|
|
SELECT * FROM event_log WHERE sequence = _sequence AND _label = ANY(labels);
|
|
$inner$;
|
|
|
|
-- We need to redefine the functions / procedures that call label_in_sequence
|
|
|
|
CREATE OR REPLACE PROCEDURE handle_final_line_events(IN _seq integer, IN _label text, IN _column text)
|
|
LANGUAGE plpgsql
|
|
AS $inner$
|
|
|
|
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;
|
|
|
|
--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';
|
|
|
|
INSERT INTO event_log (sequence, point, remarks, labels, meta)
|
|
VALUES (
|
|
-- The sequence
|
|
_seq,
|
|
-- The shotpoint
|
|
_column_value,
|
|
-- Remark. Something like "FSP <linename>"
|
|
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;
|
|
|
|
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;
|
|
|
|
END IF;
|
|
|
|
END IF;
|
|
END;
|
|
$inner$;
|
|
|
|
CREATE OR REPLACE PROCEDURE final_line_post_import(IN _seq integer)
|
|
LANGUAGE plpgsql
|
|
AS $inner$
|
|
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');
|
|
|
|
END;
|
|
$inner$;
|
|
|
|
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_18 () AS $$
|
|
DECLARE
|
|
row RECORD;
|
|
BEGIN
|
|
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;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CALL pg_temp.upgrade_18();
|
|
|
|
CALL show_notice('Cleaning up');
|
|
DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text);
|
|
DROP PROCEDURE pg_temp.upgrade_18 ();
|
|
|
|
CALL show_notice('Updating db_schema version');
|
|
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.5"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.3.5"}' WHERE public.info.key = 'version';
|
|
|
|
|
|
CALL show_notice('All done. You may now run "COMMIT;" to persist the changes');
|
|
DROP PROCEDURE show_notice (notice text);
|
|
|
|
--
|
|
--NOTE Run `COMMIT;` now if all went well
|
|
--
|