mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 08:17:09 +00:00
110 lines
2.7 KiB
MySQL
110 lines
2.7 KiB
MySQL
|
|
-- Add procedure to decimate old nav data
|
||
|
|
--
|
||
|
|
-- New schema version: 0.6.3
|
||
|
|
--
|
||
|
|
-- ATTENTION:
|
||
|
|
--
|
||
|
|
-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT.
|
||
|
|
--
|
||
|
|
--
|
||
|
|
-- NOTE: This upgrade creates a new schema called `comparisons`.
|
||
|
|
-- NOTE: Each application starts a transaction, which must be committed
|
||
|
|
-- or rolled back.
|
||
|
|
--
|
||
|
|
-- This update adds a `comparisons` table to a `comparisons` schema.
|
||
|
|
-- The `comparisons.comparisons` table holds 4D prospect comparison data.
|
||
|
|
--
|
||
|
|
-- 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 pg_temp.show_notice (notice text) AS $$
|
||
|
|
BEGIN
|
||
|
|
RAISE NOTICE '%', notice;
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_database () AS $outer$
|
||
|
|
BEGIN
|
||
|
|
|
||
|
|
RAISE NOTICE 'Updating schema %', 'public';
|
||
|
|
SET search_path TO public;
|
||
|
|
|
||
|
|
-- BEGIN
|
||
|
|
|
||
|
|
CREATE SCHEMA IF NOT EXISTS comparisons
|
||
|
|
AUTHORIZATION postgres;
|
||
|
|
|
||
|
|
COMMENT ON SCHEMA comparisons
|
||
|
|
IS 'Holds 4D comparison data and logic';
|
||
|
|
|
||
|
|
CREATE TABLE IF NOT EXISTS comparisons.comparisons
|
||
|
|
(
|
||
|
|
type text COLLATE pg_catalog."default" NOT NULL,
|
||
|
|
baseline_pid text COLLATE pg_catalog."default" NOT NULL,
|
||
|
|
monitor_pid text COLLATE pg_catalog."default" NOT NULL,
|
||
|
|
data bytea,
|
||
|
|
meta jsonb NOT NULL DEFAULT '{}'::jsonb,
|
||
|
|
CONSTRAINT comparisons_pkey PRIMARY KEY (baseline_pid, monitor_pid, type)
|
||
|
|
)
|
||
|
|
|
||
|
|
TABLESPACE pg_default;
|
||
|
|
|
||
|
|
ALTER TABLE IF EXISTS comparisons.comparisons
|
||
|
|
OWNER to postgres;
|
||
|
|
|
||
|
|
-- END
|
||
|
|
|
||
|
|
END;
|
||
|
|
$outer$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$
|
||
|
|
DECLARE
|
||
|
|
row RECORD;
|
||
|
|
current_db_version TEXT;
|
||
|
|
BEGIN
|
||
|
|
|
||
|
|
SELECT value->>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version';
|
||
|
|
|
||
|
|
IF current_db_version >= '0.6.3' THEN
|
||
|
|
RAISE EXCEPTION
|
||
|
|
USING MESSAGE='Patch already applied';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
IF current_db_version != '0.6.2' THEN
|
||
|
|
RAISE EXCEPTION
|
||
|
|
USING MESSAGE='Invalid database version: ' || current_db_version,
|
||
|
|
HINT='Ensure all previous patches have been applied.';
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
CALL pg_temp.upgrade_database();
|
||
|
|
END;
|
||
|
|
$outer$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CALL pg_temp.upgrade();
|
||
|
|
|
||
|
|
CALL pg_temp.show_notice('Cleaning up');
|
||
|
|
DROP PROCEDURE pg_temp.upgrade_database ();
|
||
|
|
DROP PROCEDURE pg_temp.upgrade ();
|
||
|
|
|
||
|
|
CALL pg_temp.show_notice('Updating db_schema version');
|
||
|
|
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.6.3"}')
|
||
|
|
ON CONFLICT (key) DO UPDATE
|
||
|
|
SET value = public.info.value || '{"db_schema": "0.6.3"}' WHERE public.info.key = 'version';
|
||
|
|
|
||
|
|
|
||
|
|
CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes');
|
||
|
|
DROP PROCEDURE pg_temp.show_notice (notice text);
|
||
|
|
|
||
|
|
--
|
||
|
|
--NOTE Run `COMMIT;` now if all went well
|
||
|
|
--
|