mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 09:47:08 +00:00
100 lines
2.8 KiB
PL/PgSQL
100 lines
2.8 KiB
PL/PgSQL
-- Drop old event tables.
|
|
--
|
|
-- New schema version: 0.3.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 completes the migration from the old event logging mechanism by
|
|
-- DROPPING THE OLD DATABASE OBJECTS, MAKING THE MIGRATION IRREVERSIBLE,
|
|
-- other than by restoring from backup and manually transferring any new
|
|
-- data that may have been created in the meanwhile.
|
|
--
|
|
-- 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 database while the transaction is active.
|
|
--
|
|
-- WARNING: Applying this upgrade drops the old tables. Ensure that you
|
|
-- have migrated the data first.
|
|
--
|
|
-- NOTE: This is a patch version change so it does not require a
|
|
-- backend restart.
|
|
|
|
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);
|
|
|
|
DROP FUNCTION IF EXISTS
|
|
label_in_sequence(integer,text), reset_events_serials();
|
|
|
|
DROP VIEW IF EXISTS
|
|
events_midnight_shot, events_seq_timed, events_labels, "events";
|
|
|
|
DROP TABLE IF EXISTS
|
|
events_seq_labels, events_timed_labels, events_timed_seq, events_seq, events_timed;
|
|
|
|
DROP SEQUENCE IF EXISTS
|
|
events_seq_id_seq, events_timed_id_seq;
|
|
|
|
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.1"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.3.1"}' 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
|
|
--
|