mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 10:57:07 +00:00
Merge branch '177-refactor-users-code' into 'devel'
Refactor users code Closes #177 and #176 See merge request wgp/dougal/software!57
This commit is contained in:
109
etc/db/upgrades/upgrade37-v0.6.0-add-keystore-table.sql
Normal file
109
etc/db/upgrades/upgrade37-v0.6.0-add-keystore-table.sql
Normal file
@@ -0,0 +1,109 @@
|
||||
-- Fix final_lines_summary view
|
||||
--
|
||||
-- New schema version: 0.6.0
|
||||
--
|
||||
-- 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 `keystore` table, intended for storing arbitrary
|
||||
-- key / value pairs which, unlike, the `info` tables, is not meant to
|
||||
-- be directly accessible via the API. Its main purpose as of this writing
|
||||
-- is to store user definitions (see #176, #177, #180).
|
||||
--
|
||||
-- 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';
|
||||
|
||||
CREATE TABLE IF NOT EXISTS keystore (
|
||||
type TEXT NOT NULL, -- A class of data to be stored
|
||||
key TEXT NOT NULL, -- A key that is unique for the class and access type
|
||||
last_modified TIMESTAMP -- To detect update conflicts
|
||||
DEFAULT CURRENT_TIMESTAMP,
|
||||
data jsonb,
|
||||
PRIMARY KEY (type, key) -- Composite primary key
|
||||
);
|
||||
|
||||
-- Create a function to update the last_modified timestamp
|
||||
CREATE OR REPLACE FUNCTION update_last_modified()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.last_modified = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Create a trigger that calls the function before each update
|
||||
CREATE OR REPLACE TRIGGER update_keystore_last_modified
|
||||
BEFORE UPDATE ON keystore
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_last_modified();
|
||||
|
||||
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.0' THEN
|
||||
RAISE EXCEPTION
|
||||
USING MESSAGE='Patch already applied';
|
||||
END IF;
|
||||
|
||||
IF current_db_version != '0.5.3' 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.0"}')
|
||||
ON CONFLICT (key) DO UPDATE
|
||||
SET value = public.info.value || '{"db_schema": "0.6.0"}' 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
|
||||
--
|
||||
107
etc/db/upgrades/upgrade38-v0.6.1-add-default-user.sql
Normal file
107
etc/db/upgrades/upgrade38-v0.6.1-add-default-user.sql
Normal file
@@ -0,0 +1,107 @@
|
||||
-- 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';
|
||||
|
||||
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
|
||||
--
|
||||
Reference in New Issue
Block a user