From 54b457b4eadda63e5f7d3012520a2a0c610f8506 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Sun, 27 Feb 2022 17:48:43 +0100 Subject: [PATCH] Add database upgrade file 12. Migrates data from old event tables to new. --- .../upgrade12-v0.3.0-migrate-events.sql | 98 +++++++++++++++++++ 1 file changed, 98 insertions(+) create mode 100644 etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql diff --git a/etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql b/etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql new file mode 100644 index 0000000..83f89ef --- /dev/null +++ b/etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql @@ -0,0 +1,98 @@ +-- Migrate events to new schema +-- +-- New schema version: 0.3.0 +-- +-- NOTE: This upgrade affects all schemas in the database. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This migrates the data from the old event log tables to the new schema. +-- It is a *very* good idea to review the data manually after the migration +-- as issues with the logs that had gone unnoticed may become evident now. +-- +-- WARNING: If data exists in the new event tables, IT WILL BE TRUNCATED. +-- +-- Other than that, this migration is fairly benign as it does not modify +-- the old data. +-- +-- To apply, run as the dougal user: +-- +-- psql <>'virtual' = TRUE means that the event was created algorithmically + -- and should not be user editable. + INSERT INTO event_log_full (tstamp, sequence, point, remarks, labels, meta) + SELECT + tstamp, sequence, point, remarks, labels, + meta || json_build_object('geometry', geometry, 'readonly', virtual)::jsonb + FROM events; + + -- We purposefully bypass event_log here + UPDATE event_log_full SET meta = meta - 'geometry' WHERE meta->>'geometry' IS NULL; + UPDATE event_log_full SET meta = meta - 'readonly' WHERE (meta->'readonly')::boolean IS false; + +END +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE PROCEDURE pg_temp.upgrade_database () 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_database(); + +CALL show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade_database (); + +CALL show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.0"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.3.0"}' 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 +--