mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 08:27:08 +00:00
Add database upgrade file 12.
Migrates data from old event tables to new.
This commit is contained in:
98
etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql
Normal file
98
etc/db/upgrades/upgrade12-v0.3.0-migrate-events.sql
Normal file
@@ -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 <<EOF
|
||||
-- \i $THIS_FILE
|
||||
-- COMMIT;
|
||||
-- EOF
|
||||
--
|
||||
-- NOTE: It can take a while if run on a large database.
|
||||
-- NOTE: It can be applied multiple times without ill effect.
|
||||
-- NOTE: This will lock the new event tables while the transaction is active.
|
||||
--
|
||||
-- WARNING: This is a minor (not patch) version change, meaning that it requires
|
||||
-- an upgrade and restart of the backend server.
|
||||
|
||||
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);
|
||||
|
||||
TRUNCATE event_log_full;
|
||||
|
||||
-- NOTE: meta->>'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
|
||||
--
|
||||
Reference in New Issue
Block a user