mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 09:27:07 +00:00
109 lines
2.7 KiB
PL/PgSQL
109 lines
2.7 KiB
PL/PgSQL
-- Fix final_lines_summary view
|
|
--
|
|
-- New schema version: 0.6.1
|
|
--
|
|
-- 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 a default user to the system (see #176, #177, #180).
|
|
-- The default user can only be invoked by connecting from localhost.
|
|
--
|
|
-- This user has full access to every project via the organisations
|
|
-- permissions wildcard: `{"*": {read: true, write: true, edit: true}}`
|
|
-- and can be used to bootstrap the system by creating other users
|
|
-- and assigning organisational permissions.
|
|
--
|
|
-- 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;
|
|
|
|
INSERT INTO keystore (type, key, data)
|
|
VALUES ('user', '6f1e7159-4ca0-4ae4-ab4e-89078166cc10', '
|
|
{
|
|
"id": "6f1e7159-4ca0-4ae4-ab4e-89078166cc10",
|
|
"ip": "127.0.0.0/24",
|
|
"name": "☠️",
|
|
"colour": "red",
|
|
"active": true,
|
|
"organisations": {
|
|
"*": {
|
|
"read": true,
|
|
"write": true,
|
|
"edit": true
|
|
}
|
|
}
|
|
}
|
|
'::jsonb)
|
|
ON CONFLICT (type, key) DO NOTHING;
|
|
|
|
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.1' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Patch already applied';
|
|
END IF;
|
|
|
|
IF current_db_version != '0.6.0' 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.1"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.6.1"}' 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
|
|
--
|