mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 08:17:09 +00:00
107 lines
3.0 KiB
PL/PgSQL
107 lines
3.0 KiB
PL/PgSQL
-- Fix final_lines_summary view
|
|
--
|
|
-- New schema version: 0.6.2
|
|
--
|
|
-- ATTENTION:
|
|
--
|
|
-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT.
|
|
--
|
|
--
|
|
-- NOTE: This upgrade only affects the `public` schema.
|
|
-- NOTE: Each application starts a transaction, which must be committed
|
|
-- or rolled back.
|
|
--
|
|
-- This update adds an "organisations" section to the configuration,
|
|
-- with a default configured organisation of "WGP" with full access.
|
|
-- This is so that projects can be made accessible after migrating
|
|
-- to the new permissions architecture.
|
|
--
|
|
-- In addition, projects with an id starting with "eq" are assumed to
|
|
-- be Equinor projects, and an additional organisation is added with
|
|
-- read-only access. This is intended for clients, which should be
|
|
-- assigned to the "Equinor organisation".
|
|
--
|
|
-- Finally, we assign the vessel to the "WGP" organisation (full access)
|
|
-- so that we can actually use administrative endpoints.
|
|
--
|
|
-- 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;
|
|
|
|
-- Add "organisations" section to configurations, if not already present
|
|
UPDATE projects
|
|
SET
|
|
meta = jsonb_set(meta, '{organisations}', '{"WGP": {"read": true, "write": true, "edit": true}}'::jsonb, true)
|
|
WHERE meta->'organisations' IS NULL;
|
|
|
|
-- Add (or overwrite!) "organisations.Equinor" giving read-only access (can be changed later via API)
|
|
UPDATE projects
|
|
SET
|
|
meta = jsonb_set(meta, '{organisations, Equinor}', '{"read": true, "write": false, "edit": false}'::jsonb, true)
|
|
WHERE pid LIKE 'eq%';
|
|
|
|
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.2' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Patch already applied';
|
|
END IF;
|
|
|
|
IF current_db_version != '0.6.1' 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.2"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.6.2"}' 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
|
|
--
|