update release.sh to move sql files to version folder.
This commit is contained in:
65
sql/initial/000-initizalise.sql
Normal file
65
sql/initial/000-initizalise.sql
Normal file
@@ -0,0 +1,65 @@
|
||||
-- Role: role_administrator
|
||||
-- DROP ROLE IF EXISTS role_administrator;
|
||||
|
||||
CREATE ROLE role_administrator;
|
||||
|
||||
|
||||
-- Role: role_service
|
||||
-- DROP ROLE IF EXISTS role_service;
|
||||
|
||||
CREATE ROLE role_service;
|
||||
|
||||
|
||||
-- Role: role_maintainer
|
||||
-- DROP ROLE IF EXISTS role_maintainer;
|
||||
|
||||
CREATE ROLE role_maintainer;
|
||||
|
||||
|
||||
-- Role: support_role
|
||||
-- DROP ROLE IF EXISTS support_role;
|
||||
|
||||
CREATE ROLE role_support;
|
||||
|
||||
|
||||
-- User: services
|
||||
-- DROP USER IF EXISTS services;
|
||||
|
||||
CREATE USER services WITH PASSWORD 'password';
|
||||
|
||||
-- Assign role to the user
|
||||
GRANT role_service TO services;
|
||||
|
||||
|
||||
-- User: user_maintainer
|
||||
-- DROP USER IF EXISTS user_maintainer;
|
||||
|
||||
CREATE USER user_maintainer WITH PASSWORD 'password';
|
||||
|
||||
-- Assign role to the user
|
||||
GRANT role_maintainer TO user_maintainer;
|
||||
|
||||
|
||||
-- User: user_support
|
||||
-- DROP USER IF EXISTS user_support;
|
||||
|
||||
CREATE USER user_support WITH PASSWORD 'password';
|
||||
|
||||
-- Assign role to the user
|
||||
GRANT role_support TO user_support;
|
||||
|
||||
|
||||
-- Database: device_registry
|
||||
-- DROP DATABASE IF EXISTS device_registry;
|
||||
|
||||
CREATE DATABASE account_registry
|
||||
WITH
|
||||
OWNER = role_administrator
|
||||
ENCODING = 'UTF8'
|
||||
LC_COLLATE = 'en_US.utf8'
|
||||
LC_CTYPE = 'en_US.utf8'
|
||||
LOCALE_PROVIDER = 'libc'
|
||||
TABLESPACE = pg_default
|
||||
CONNECTION LIMIT = -1
|
||||
IS_TEMPLATE = False;
|
||||
|
||||
43
sql/initial/001-uuid_v7.sql
Normal file
43
sql/initial/001-uuid_v7.sql
Normal file
@@ -0,0 +1,43 @@
|
||||
-- FUNCTION: public.gen_uuid_v7(timestamp with time zone)
|
||||
|
||||
-- DROP FUNCTION IF EXISTS public.gen_uuid_v7(timestamp with time zone);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.gen_uuid_v7(p_timestamp timestamp with time zone)
|
||||
RETURNS uuid
|
||||
LANGUAGE 'sql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
AS
|
||||
$BODY$
|
||||
-- Replace the first 48 bits of a uuid v4 with the provided timestamp (in milliseconds) since 1970-01-01 UTC, and set the version to 7
|
||||
SELECT encode(set_bit(set_bit(overlay(uuid_send(gen_random_uuid()) PLACING substring(int8send((extract(EPOCH FROM p_timestamp) * 1000):: BIGINT) FROM 3) FROM 1 FOR 6), 52, 1), 53, 1), 'hex') ::uuid;
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.gen_uuid_v7(timestamp with time zone)
|
||||
OWNER TO role_administrator;
|
||||
|
||||
COMMENT
|
||||
ON FUNCTION public.gen_uuid_v7(timestamp with time zone)
|
||||
IS 'Generate a UUIDv7 value using a provided timestamp (in milliseconds since 1970-01-01 UTC) with 74 bits of randomness.';
|
||||
|
||||
|
||||
-- FUNCTION: public.gen_uuid_v7()
|
||||
|
||||
-- DROP FUNCTION IF EXISTS public.gen_uuid_v7();
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.gen_uuid_v7()
|
||||
RETURNS uuid
|
||||
LANGUAGE 'sql'
|
||||
COST 100
|
||||
VOLATILE PARALLEL UNSAFE
|
||||
AS
|
||||
$BODY$
|
||||
SELECT gen_uuid_v7(clock_timestamp());
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.gen_uuid_v7()
|
||||
OWNER TO role_administrator;
|
||||
|
||||
COMMENT
|
||||
ON FUNCTION public.gen_uuid_v7()
|
||||
IS 'Generate a UUIDv7 value with a 48-bit timestamp (millisecond precision) and 74 bits of randomness.';
|
||||
35
sql/initial/002-account.sql
Normal file
35
sql/initial/002-account.sql
Normal file
@@ -0,0 +1,35 @@
|
||||
-- Table: public.accounts
|
||||
-- DROP TABLE IF EXISTS public.accounts;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.accounts
|
||||
(
|
||||
id UUID DEFAULT gen_uuid_v7(),
|
||||
created_at timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
enabled boolean NOT NULL DEFAULT true,
|
||||
username VARCHAR(50) UNIQUE NOT NULL,
|
||||
password VARCHAR(255) NOT NULL,
|
||||
roles VARCHAR(255) NOT NULL,
|
||||
CONSTRAINT pk_contact_types PRIMARY KEY (id)
|
||||
);
|
||||
|
||||
ALTER TABLE IF EXISTS public.accounts
|
||||
OWNER to role_administrator;
|
||||
|
||||
|
||||
-- Index: idx_accounts_username
|
||||
-- DROP INDEX IF EXISTS public.idx_accounts_username;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_accounts_username
|
||||
ON public.accounts USING btree (username COLLATE pg_catalog."default" ASC NULLS LAST)
|
||||
TABLESPACE pg_default;
|
||||
|
||||
|
||||
-- Revoke all permissions from existing roles
|
||||
REVOKE ALL ON TABLE public.accounts FROM role_administrator, role_maintainer, role_support, services;
|
||||
|
||||
|
||||
-- Grant appropriate permissions
|
||||
GRANT ALL ON TABLE public.accounts TO role_administrator;
|
||||
GRANT SELECT, INSERT, UPDATE ON TABLE public.accounts TO role_maintainer, services;
|
||||
GRANT SELECT ON TABLE public.accounts TO role_support;
|
||||
26
sql/initial/003-account_audit.sql
Normal file
26
sql/initial/003-account_audit.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
-- Table: public.accounts_audit
|
||||
-- DROP TABLE IF EXISTS public.accounts_audit;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.accounts_audit
|
||||
(
|
||||
id uuid NOT NULL,
|
||||
timestamp timestamp with time zone NOT NULL,
|
||||
enabled boolean NOT NULL,
|
||||
username VARCHAR(50) NOT NULL,
|
||||
password VARCHAR(255) NOT NULL,
|
||||
roles VARCHAR(255) NOT NULL,
|
||||
CONSTRAINT pk_accounts_audit PRIMARY KEY (id, timestamp)
|
||||
) TABLESPACE pg_default;
|
||||
|
||||
ALTER TABLE IF EXISTS public.accounts_audit
|
||||
OWNER to role_administrator;
|
||||
|
||||
|
||||
-- Revoke all permissions from existing roles
|
||||
REVOKE ALL ON TABLE public.accounts_audit FROM role_administrator, role_maintainer, role_support, services;
|
||||
|
||||
|
||||
-- Grant appropriate permissions to each role
|
||||
GRANT ALL ON TABLE public.accounts_audit TO role_administrator;
|
||||
GRANT SELECT, INSERT ON TABLE public.accounts_audit TO services;
|
||||
GRANT SELECT ON TABLE public.accounts_audit TO role_maintainer, role_support;
|
||||
29
sql/initial/004-account_audit_function.sql
Normal file
29
sql/initial/004-account_audit_function.sql
Normal file
@@ -0,0 +1,29 @@
|
||||
-- FUNCTION: public.accounts_audit()
|
||||
-- DROP FUNCTION IF EXISTS public.accounts_audit();
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.accounts_audit()
|
||||
RETURNS trigger
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE NOT LEAKPROOF
|
||||
AS
|
||||
$BODY$
|
||||
BEGIN
|
||||
INSERT INTO accounts_audit (id, timestamp, enabled, username, password, roles)
|
||||
VALUES (NEW.id, NEW.updated_at, NEW.enabled, NEW.username, NEW.password, NEW.roles);
|
||||
RETURN NULL; -- result is ignored since this is an AFTER trigger
|
||||
END;
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.accounts_audit()
|
||||
OWNER TO role_administrator;
|
||||
|
||||
|
||||
-- Trigger: accounts_audit_trigger
|
||||
-- DROP TRIGGER IF EXISTS accounts_audit_trigger ON public.accounts;
|
||||
|
||||
CREATE OR REPLACE TRIGGER accounts_audit_trigger
|
||||
AFTER INSERT OR UPDATE
|
||||
ON public.accounts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION public.accounts_audit();
|
||||
Reference in New Issue
Block a user