mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 13:07:08 +00:00
Add database upgrade file
This commit is contained in:
171
etc/db/upgrades/upgrade03-53f71f70→4d977848.sql
Normal file
171
etc/db/upgrades/upgrade03-53f71f70→4d977848.sql
Normal file
@@ -0,0 +1,171 @@
|
||||
-- Upgrade the database from commit 53f71f70 to 4d977848.
|
||||
--
|
||||
-- NOTE: This upgrade must be applied to every schema in the database.
|
||||
-- NOTE: Each application starts a transaction, which must be committed
|
||||
-- or rolled back.
|
||||
--
|
||||
-- This adds:
|
||||
--
|
||||
-- * label_in_sequence (_sequence integer, _label text):
|
||||
-- Returns events containing the specified label.
|
||||
--
|
||||
-- * handle_final_line_events (_seq integer, _label text, _column text):
|
||||
-- - If _label does not exist in the events for sequence _seq:
|
||||
-- it adds a new _label label at the shotpoint obtained from
|
||||
-- final_lines_summary[_column].
|
||||
-- - If _label does exist (and hasn't been auto-added by this function
|
||||
-- in a previous run), it will add information about it to the final
|
||||
-- line's metadata.
|
||||
--
|
||||
-- * final_line_post_import (_seq integer):
|
||||
-- Calls handle_final_line_events() on the given sequence to check
|
||||
-- for FSP, FGSP, LGSP and LSP labels.
|
||||
--
|
||||
-- * events_seq_labels_single ():
|
||||
-- Trigger function to ensure that labels that have the attribute
|
||||
-- `model.multiple` set to `false` occur at most only once per
|
||||
-- sequence. If a new instance is added to a sequence, the previous
|
||||
-- instance is deleted.
|
||||
--
|
||||
-- * Trigger on events_seq_labels that calls events_seq_labels_single().
|
||||
--
|
||||
-- * Trigger on events_timed_labels that calls events_seq_labels_single().
|
||||
--
|
||||
-- To apply, run as the dougal user, for every schema in the database:
|
||||
--
|
||||
-- psql <<EOF
|
||||
-- SET search_path TO survey_*,public;
|
||||
-- \i $THIS_FILE
|
||||
-- COMMIT;
|
||||
-- EOF
|
||||
--
|
||||
-- NOTE: It will fail harmlessly if applied twice.
|
||||
|
||||
|
||||
BEGIN;
|
||||
|
||||
CREATE OR REPLACE FUNCTION label_in_sequence (_sequence integer, _label text)
|
||||
RETURNS events
|
||||
LANGUAGE sql
|
||||
AS $$
|
||||
SELECT * FROM events WHERE sequence = _sequence AND _label = ANY(labels);
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE handle_final_line_events (_seq integer, _label text, _column text)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
|
||||
DECLARE
|
||||
_line final_lines_summary%ROWTYPE;
|
||||
_column_value integer;
|
||||
_tg_name text := 'final_line';
|
||||
_event events%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';
|
||||
|
||||
SELECT id INTO event_id FROM events_seq WHERE sequence = _seq AND point = _column_value ORDER BY id LIMIT 1;
|
||||
IF event_id IS NULL THEN
|
||||
--RAISE NOTICE '… but there is no existing event so we create a new one for sequence % and point %', _line.sequence, _column_value;
|
||||
INSERT INTO events_seq (sequence, point, remarks)
|
||||
VALUES (_line.sequence, _column_value, format('%s %s', _label, (SELECT meta->>'lineName' FROM final_lines WHERE sequence = _seq)))
|
||||
RETURNING id INTO event_id;
|
||||
--RAISE NOTICE 'Created event_id %', event_id;
|
||||
END IF;
|
||||
|
||||
--RAISE NOTICE 'Remove any other auto-inserted % labels in sequence %', _label, _seq;
|
||||
DELETE FROM events_seq_labels
|
||||
WHERE label = _label AND id = (SELECT id FROM events_seq WHERE sequence = _seq AND meta->'auto' ? _label);
|
||||
|
||||
--RAISE NOTICE 'We now add a label to the event (id, label) = (%, %)', event_id, _label;
|
||||
INSERT INTO events_seq_labels (id, label) VALUES (event_id, _label) ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING;
|
||||
|
||||
--RAISE NOTICE 'And also clear the %: % flag from meta.auto for any existing events for sequence %', _label, _tg_name, _seq;
|
||||
UPDATE events_seq
|
||||
SET meta = meta #- ARRAY['auto', _label]
|
||||
WHERE meta->'auto' ? _label AND sequence = _seq AND id <> event_id;
|
||||
|
||||
--RAISE NOTICE 'Finally, flag the event as having been had label % auto-created by %', _label, _tg_name;
|
||||
UPDATE events_seq
|
||||
SET meta = jsonb_set(jsonb_set(meta, '{auto}', COALESCE(meta->'auto', '{}')), ARRAY['auto', _label], to_jsonb(_tg_name))
|
||||
WHERE id = event_id;
|
||||
|
||||
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;
|
||||
|
||||
--RAISE NOTICE 'Clearing the %: % flag from meta.auto for any existing events in sequence %', _label, _tg_name, _seq;
|
||||
UPDATE events_seq
|
||||
SET meta = meta #- ARRAY['auto', _label]
|
||||
WHERE sequence = _seq AND meta->'auto'->>_label = _tg_name;
|
||||
|
||||
END IF;
|
||||
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE PROCEDURE final_line_post_import (_seq integer)
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
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;
|
||||
$$;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION events_seq_labels_single ()
|
||||
RETURNS trigger
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE _sequence integer;
|
||||
BEGIN
|
||||
IF EXISTS(SELECT 1 FROM labels WHERE name = NEW.label AND (data->'model'->'multiple')::boolean IS FALSE) THEN
|
||||
SELECT sequence INTO _sequence FROM events WHERE id = NEW.id;
|
||||
DELETE
|
||||
FROM events_seq_labels
|
||||
WHERE
|
||||
id <> NEW.id
|
||||
AND label = NEW.label
|
||||
AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence);
|
||||
|
||||
DELETE
|
||||
FROM events_timed_labels
|
||||
WHERE
|
||||
id <> NEW.id
|
||||
AND label = NEW.label
|
||||
AND id IN (SELECT id FROM events_timed_seq WHERE sequence = _sequence);
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON events_seq_labels FOR EACH ROW EXECUTE FUNCTION events_seq_labels_single();
|
||||
CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON events_timed_labels FOR EACH ROW EXECUTE FUNCTION events_seq_labels_single();
|
||||
|
||||
--
|
||||
--NOTE Run `COMMIT;` now if all went well
|
||||
--
|
||||
|
||||
Reference in New Issue
Block a user