mirror of
https://github.com/thiloho/archtika.git
synced 2025-11-22 02:41:35 +01:00
Add postgres sql file formatting via pg_format
This commit is contained in:
@@ -27,6 +27,10 @@
|
||||
dbmate
|
||||
postgrest
|
||||
];
|
||||
|
||||
shellHook = ''
|
||||
alias formatsql="${pkgs.pgformatter}/bin/pg_format -s 2 -f 2 -U 2 -i db/migrations/*.sql"
|
||||
'';
|
||||
};
|
||||
web = pkgs.mkShell { packages = with pkgs; [ nodejs_22 ]; };
|
||||
}
|
||||
|
||||
@@ -2,129 +2,143 @@
|
||||
CREATE SCHEMA api;
|
||||
|
||||
CREATE ROLE anon NOLOGIN NOINHERIT;
|
||||
|
||||
GRANT USAGE ON SCHEMA api TO anon;
|
||||
|
||||
CREATE ROLE authenticated_user NOLOGIN NOINHERIT;
|
||||
|
||||
GRANT USAGE ON SCHEMA api TO authenticated_user;
|
||||
|
||||
CREATE ROLE authenticator LOGIN NOINHERIT NOCREATEDB NOCREATEROLE NOSUPERUSER;
|
||||
|
||||
GRANT anon TO authenticator;
|
||||
|
||||
GRANT authenticated_user TO authenticator;
|
||||
|
||||
CREATE SCHEMA internal;
|
||||
|
||||
CREATE TABLE internal.user (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
username VARCHAR(16) UNIQUE NOT NULL CHECK (length(username) >= 3),
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
|
||||
username VARCHAR(16) UNIQUE NOT NULL CHECK (LENGTH(username) >= 3),
|
||||
password_hash CHAR(60) NOT NULL,
|
||||
role NAME NOT NULL DEFAULT 'authenticated_user'
|
||||
);
|
||||
|
||||
CREATE TABLE internal.website (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id UUID REFERENCES internal.user(id) ON DELETE CASCADE NOT NULL DEFAULT (current_setting('request.jwt.claims', true)::JSON->>'user_id')::UUID,
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE NOT NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
content_type VARCHAR(10) CHECK (content_type IN ('Blog', 'Docs')) NOT NULL,
|
||||
title VARCHAR(50) NOT NULL CHECK (trim(title) != ''),
|
||||
title VARCHAR(50) NOT NULL CHECK (TRIM(title) != ''),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.media (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
website_id UUID REFERENCES internal.website(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES internal.user(id) ON DELETE CASCADE NOT NULL DEFAULT (current_setting('request.jwt.claims', true)::JSON->>'user_id')::UUID,
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
|
||||
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE NOT NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
original_name TEXT NOT NULL,
|
||||
file_system_path TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP()
|
||||
);
|
||||
|
||||
CREATE TABLE internal.settings (
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
accent_color_light_theme CHAR(7) CHECK (accent_color_light_theme ~ '^#[a-fA-F0-9]{6}$') NOT NULL DEFAULT '#a5d8ff',
|
||||
accent_color_dark_theme CHAR(7) CHECK (accent_color_dark_theme ~ '^#[a-fA-F0-9]{6}$') NOT NULL DEFAULT '#114678',
|
||||
favicon_image UUID REFERENCES internal.media(id) ON DELETE SET NULL,
|
||||
favicon_image UUID REFERENCES internal.media (id) ON DELETE SET NULL,
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.header (
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
logo_type TEXT CHECK (logo_type IN ('text', 'image')) NOT NULL DEFAULT 'text',
|
||||
logo_text VARCHAR(50),
|
||||
logo_image UUID REFERENCES internal.media(id) ON DELETE SET NULL,
|
||||
logo_image UUID REFERENCES internal.media (id) ON DELETE SET NULL,
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL,
|
||||
CONSTRAINT logo_content_check CHECK (
|
||||
(logo_type = 'text' AND logo_text IS NOT NULL AND trim(logo_text) != '') OR
|
||||
(logo_type = 'image' AND logo_image IS NOT NULL)
|
||||
)
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL,
|
||||
CONSTRAINT logo_content_check CHECK ((logo_type = 'text' AND logo_text IS NOT NULL AND TRIM(logo_text) != '') OR (logo_type = 'image' AND logo_image IS NOT NULL))
|
||||
);
|
||||
|
||||
CREATE TABLE internal.home (
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
main_content TEXT NOT NULL CHECK (trim(main_content) != ''),
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
main_content TEXT NOT NULL CHECK (TRIM(main_content) != ''),
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.article (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
website_id UUID REFERENCES internal.website(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES internal.user(id) ON DELETE SET NULL,
|
||||
title VARCHAR(100) NOT NULL CHECK (trim(title) != ''),
|
||||
meta_description VARCHAR(250) CHECK (trim(meta_description) != ''),
|
||||
meta_author VARCHAR(100) CHECK (trim(meta_author) != ''),
|
||||
cover_image UUID REFERENCES internal.media(id) ON DELETE SET NULL,
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
|
||||
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE SET NULL,
|
||||
title VARCHAR(100) NOT NULL CHECK (TRIM(title) != ''),
|
||||
meta_description VARCHAR(250) CHECK (TRIM(meta_description) != ''),
|
||||
meta_author VARCHAR(100) CHECK (TRIM(meta_author) != ''),
|
||||
cover_image UUID REFERENCES internal.media (id) ON DELETE SET NULL,
|
||||
publication_date DATE NOT NULL DEFAULT CURRENT_DATE,
|
||||
main_content TEXT CHECK (trim(main_content) != ''),
|
||||
main_content TEXT CHECK (TRIM(main_content) != ''),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.footer (
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
additional_text VARCHAR(250) NOT NULL CHECK (trim(additional_text) != ''),
|
||||
website_id UUID PRIMARY KEY REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
additional_text VARCHAR(250) NOT NULL CHECK (TRIM(additional_text) != ''),
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.collab (
|
||||
website_id UUID REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES internal.user(id) ON DELETE CASCADE,
|
||||
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE,
|
||||
permission_level INTEGER CHECK (permission_level IN (10, 20, 30)) NOT NULL DEFAULT 10,
|
||||
added_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL,
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL,
|
||||
PRIMARY KEY (website_id, user_id)
|
||||
);
|
||||
|
||||
CREATE TABLE internal.change_log (
|
||||
website_id UUID REFERENCES internal.website(id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES internal.user(id) ON DELETE CASCADE DEFAULT (current_setting('request.jwt.claims', true)::JSON->>'user_id')::UUID,
|
||||
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
change_summary VARCHAR(255) NOT NULL,
|
||||
previous_value JSONB,
|
||||
new_value JSONB,
|
||||
timestamp TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
PRIMARY KEY (website_id, user_id, timestamp)
|
||||
PRIMARY KEY (website_id, user_id, TIMESTAMP)
|
||||
);
|
||||
|
||||
-- migrate:down
|
||||
DROP TABLE internal.change_log;
|
||||
|
||||
DROP TABLE internal.collab;
|
||||
|
||||
DROP TABLE internal.footer;
|
||||
|
||||
DROP TABLE internal.article;
|
||||
|
||||
DROP TABLE internal.home;
|
||||
|
||||
DROP TABLE internal.header;
|
||||
|
||||
DROP TABLE internal.settings;
|
||||
|
||||
DROP TABLE internal.media;
|
||||
|
||||
DROP TABLE internal.website;
|
||||
|
||||
DROP SCHEMA api;
|
||||
|
||||
DROP TABLE internal.user;
|
||||
|
||||
DROP SCHEMA internal;
|
||||
|
||||
DROP ROLE authenticator;
|
||||
|
||||
DROP ROLE anon;
|
||||
|
||||
DROP ROLE authenticated_user;
|
||||
|
||||
|
||||
@@ -1,14 +1,19 @@
|
||||
-- migrate:up
|
||||
CREATE FUNCTION pgrst_watch() RETURNS event_trigger AS $$
|
||||
CREATE FUNCTION pgrst_watch ()
|
||||
RETURNS event_trigger
|
||||
AS $$
|
||||
BEGIN
|
||||
NOTIFY pgrst, 'reload schema';
|
||||
NOTIFY pgrst,
|
||||
'reload schema';
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE EVENT TRIGGER pgrst_watch
|
||||
ON ddl_command_end
|
||||
EXECUTE FUNCTION pgrst_watch();
|
||||
CREATE EVENT TRIGGER pgrst_watch ON ddl_command_end
|
||||
EXECUTE FUNCTION pgrst_watch ();
|
||||
|
||||
-- migrate:down
|
||||
DROP EVENT TRIGGER pgrst_watch;
|
||||
DROP FUNCTION pgrst_watch();
|
||||
|
||||
DROP FUNCTION pgrst_watch ();
|
||||
|
||||
|
||||
@@ -1,161 +1,188 @@
|
||||
-- migrate:up
|
||||
CREATE EXTENSION pgcrypto;
|
||||
|
||||
CREATE EXTENSION pgjwt;
|
||||
|
||||
CREATE FUNCTION
|
||||
internal.check_role_exists() RETURNS TRIGGER AS $$
|
||||
CREATE FUNCTION internal.check_role_exists ()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT 1 FROM pg_roles AS r WHERE r.rolname = NEW.role) THEN
|
||||
RAISE foreign_key_violation USING MESSAGE =
|
||||
'Unknown database role: ' || NEW.role;
|
||||
IF NOT EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
pg_roles AS r
|
||||
WHERE
|
||||
r.rolname = NEW.role) THEN
|
||||
RAISE foreign_key_violation
|
||||
USING message = 'Unknown database role: ' || NEW.role;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE CONSTRAINT TRIGGER ensure_user_role_exists
|
||||
AFTER INSERT OR UPDATE ON internal.user
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.check_role_exists();
|
||||
AFTER INSERT OR UPDATE ON internal.user
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.check_role_exists ();
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
internal.encrypt_pass() RETURNS TRIGGER AS $$
|
||||
CREATE FUNCTION internal.encrypt_pass ()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
IF TG_OP = 'INSERT' OR NEW.password_hash != OLD.password_hash THEN
|
||||
NEW.password_hash = crypt(NEW.password_hash, gen_salt('bf'));
|
||||
NEW.password_hash = CRYPT(NEW.password_hash, GEN_SALT('bf'));
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER encrypt_pass
|
||||
BEFORE INSERT OR UPDATE ON internal.user
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.encrypt_pass();
|
||||
BEFORE INSERT OR UPDATE ON internal.user
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.encrypt_pass ();
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
internal.user_role(username TEXT, password TEXT) RETURNS NAME AS $$
|
||||
CREATE FUNCTION internal.user_role (username TEXT, PASSWORD TEXT)
|
||||
RETURNS NAME
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN (
|
||||
SELECT role FROM internal.user AS u
|
||||
WHERE u.username = user_role.username
|
||||
AND u.password_hash = crypt(user_role.password, u.password_hash)
|
||||
);
|
||||
SELECT
|
||||
ROLE
|
||||
FROM
|
||||
internal.user AS u
|
||||
WHERE
|
||||
u.username = user_role.username
|
||||
AND u.password_hash = CRYPT(user_role.password, u.password_hash));
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
api.register(username TEXT, password TEXT, OUT user_id UUID) AS $$
|
||||
CREATE FUNCTION api.register (username TEXT, PASSWORD TEXT, OUT user_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_username_length_min CONSTANT INT := 3;
|
||||
_username_length_max CONSTANT INT := 16;
|
||||
_password_length_min CONSTANT INT := 12;
|
||||
_password_length_max CONSTANT INT := 128;
|
||||
BEGIN
|
||||
IF LENGTH(register.username) NOT BETWEEN _username_length_min AND _username_length_max THEN
|
||||
RAISE string_data_length_mismatch USING MESSAGE = format('Username must be between %s and %s characters long', _username_length_min, _username_length_max);
|
||||
IF LENGTH(register.username)
|
||||
NOT BETWEEN _username_length_min AND _username_length_max THEN
|
||||
RAISE string_data_length_mismatch
|
||||
USING message = FORMAT('Username must be between %s and %s characters long', _username_length_min, _username_length_max);
|
||||
END IF;
|
||||
|
||||
IF EXISTS (SELECT 1 FROM internal.user AS u WHERE u.username = register.username) THEN
|
||||
RAISE unique_violation USING MESSAGE = 'Username is already taken';
|
||||
IF EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.user AS u
|
||||
WHERE
|
||||
u.username = register.username) THEN
|
||||
RAISE unique_violation
|
||||
USING message = 'Username is already taken';
|
||||
END IF;
|
||||
|
||||
IF LENGTH(register.password) NOT BETWEEN _password_length_min AND _password_length_max THEN
|
||||
RAISE string_data_length_mismatch USING MESSAGE = format('Password must be between %s and %s characters long', _password_length_min, _password_length_max);
|
||||
IF LENGTH(register.password)
|
||||
NOT BETWEEN _password_length_min AND _password_length_max THEN
|
||||
RAISE string_data_length_mismatch
|
||||
USING message = FORMAT('Password must be between %s and %s characters long', _password_length_min, _password_length_max);
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[a-z]' THEN
|
||||
RAISE invalid_parameter_value USING MESSAGE = 'Password must contain at least one lowercase letter';
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one lowercase letter';
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[A-Z]' THEN
|
||||
RAISE invalid_parameter_value USING MESSAGE = 'Password must contain at least one uppercase letter';
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one uppercase letter';
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[0-9]' THEN
|
||||
RAISE invalid_parameter_value USING MESSAGE = 'Password must contain at least one number';
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one number';
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[!@#$%^&*(),.?":{}|<>]' THEN
|
||||
RAISE invalid_parameter_value USING MESSAGE = 'Password must contain at least one special character';
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one special character';
|
||||
END IF;
|
||||
|
||||
INSERT INTO internal.user (username, password_hash)
|
||||
VALUES (register.username, register.password)
|
||||
RETURNING id INTO user_id;
|
||||
RETURNING
|
||||
id INTO user_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
api.login(username TEXT, password TEXT, OUT token TEXT) AS $$
|
||||
CREATE FUNCTION api.login (username TEXT, PASSWORD TEXT, OUT token TEXT)
|
||||
AS $$
|
||||
DECLARE
|
||||
_role NAME;
|
||||
_user_id UUID;
|
||||
_exp INTEGER;
|
||||
BEGIN
|
||||
SELECT internal.user_role(login.username, login.password) INTO _role;
|
||||
SELECT
|
||||
internal.user_role (login.username, login.password) INTO _role;
|
||||
IF _role IS NULL THEN
|
||||
RAISE invalid_password USING MESSAGE = 'Invalid username or password';
|
||||
RAISE invalid_password
|
||||
USING message = 'Invalid username or password';
|
||||
END IF;
|
||||
|
||||
SELECT id INTO _user_id
|
||||
FROM internal.user AS u
|
||||
WHERE u.username = login.username;
|
||||
|
||||
_exp := extract(EPOCH FROM CLOCK_TIMESTAMP())::INTEGER + 86400;
|
||||
|
||||
SELECT sign(
|
||||
json_build_object(
|
||||
'role', _role,
|
||||
'user_id', _user_id,
|
||||
'username', login.username,
|
||||
'exp', _exp
|
||||
),
|
||||
current_setting('app.jwt_secret')
|
||||
) INTO token;
|
||||
SELECT
|
||||
id INTO _user_id
|
||||
FROM
|
||||
internal.user AS u
|
||||
WHERE
|
||||
u.username = login.username;
|
||||
_exp := EXTRACT(EPOCH FROM CLOCK_TIMESTAMP())::INTEGER + 86400;
|
||||
SELECT
|
||||
SIGN(JSON_BUILD_OBJECT('role', _role, 'user_id', _user_id, 'username', login.username, 'exp', _exp), CURRENT_SETTING('app.jwt_secret')) INTO token;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
api.delete_account(password TEXT, OUT was_deleted BOOLEAN) AS $$
|
||||
CREATE FUNCTION api.delete_account (PASSWORD TEXT, OUT was_deleted BOOLEAN)
|
||||
AS $$
|
||||
DECLARE
|
||||
_username TEXT := current_setting('request.jwt.claims', true)::json->>'username';
|
||||
_username TEXT := CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'username';
|
||||
_role NAME;
|
||||
BEGIN
|
||||
SELECT internal.user_role(_username, delete_account.password) INTO _role;
|
||||
SELECT
|
||||
internal.user_role (_username, delete_account.password) INTO _role;
|
||||
IF _role IS NULL THEN
|
||||
RAISE invalid_password USING MESSAGE = 'Invalid password';
|
||||
RAISE invalid_password
|
||||
USING message = 'Invalid password';
|
||||
END IF;
|
||||
|
||||
DELETE FROM internal.user AS u
|
||||
WHERE u.username = _username;
|
||||
|
||||
was_deleted := TRUE;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.register (TEXT, TEXT) TO anon;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.register(TEXT, TEXT) TO anon;
|
||||
GRANT EXECUTE ON FUNCTION api.login(TEXT, TEXT) TO anon;
|
||||
GRANT EXECUTE ON FUNCTION api.login (TEXT, TEXT) TO anon;
|
||||
|
||||
-- migrate:down
|
||||
DROP FUNCTION api.register(TEXT, TEXT);
|
||||
DROP FUNCTION api.login(TEXT, TEXT);
|
||||
DROP FUNCTION api.delete_account(TEXT);
|
||||
DROP FUNCTION api.register (TEXT, TEXT);
|
||||
|
||||
DROP FUNCTION internal.user_role(TEXT, TEXT);
|
||||
DROP FUNCTION api.login (TEXT, TEXT);
|
||||
|
||||
DROP FUNCTION api.delete_account (TEXT);
|
||||
|
||||
DROP FUNCTION internal.user_role (TEXT, TEXT);
|
||||
|
||||
DROP TRIGGER encrypt_pass ON internal.user;
|
||||
DROP FUNCTION internal.encrypt_pass();
|
||||
|
||||
DROP FUNCTION internal.encrypt_pass ();
|
||||
|
||||
DROP TRIGGER ensure_user_role_exists ON internal.user;
|
||||
DROP FUNCTION internal.check_role_exists();
|
||||
|
||||
DROP FUNCTION internal.check_role_exists ();
|
||||
|
||||
DROP EXTENSION pgjwt;
|
||||
|
||||
DROP EXTENSION pgcrypto;
|
||||
|
||||
|
||||
@@ -1,20 +1,27 @@
|
||||
-- migrate:up
|
||||
CREATE VIEW api.account
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT id, username
|
||||
FROM internal.user
|
||||
WHERE id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID;
|
||||
CREATE VIEW api.account WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
username
|
||||
FROM
|
||||
internal.user
|
||||
WHERE
|
||||
id = (
|
||||
CURRENT_SETTING(
|
||||
'request.jwt.claims', TRUE
|
||||
)::JSON ->> 'user_id')::UUID;
|
||||
|
||||
CREATE VIEW api.user
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT id, username
|
||||
FROM internal.user;
|
||||
CREATE VIEW api.user WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
username
|
||||
FROM
|
||||
internal.user;
|
||||
|
||||
CREATE VIEW api.website
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
@@ -23,11 +30,11 @@ SELECT
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.website;
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
CREATE VIEW api.media
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.media WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
@@ -35,11 +42,11 @@ SELECT
|
||||
original_name,
|
||||
file_system_path,
|
||||
created_at
|
||||
FROM internal.media;
|
||||
FROM
|
||||
internal.media;
|
||||
|
||||
CREATE VIEW api.settings
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.settings WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
accent_color_light_theme,
|
||||
@@ -47,11 +54,11 @@ SELECT
|
||||
favicon_image,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.settings;
|
||||
FROM
|
||||
internal.settings;
|
||||
|
||||
CREATE VIEW api.header
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.header WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
logo_type,
|
||||
@@ -59,21 +66,21 @@ SELECT
|
||||
logo_image,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.header;
|
||||
FROM
|
||||
internal.header;
|
||||
|
||||
CREATE view api.home
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.home WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
main_content,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.home;
|
||||
FROM
|
||||
internal.home;
|
||||
|
||||
CREATE VIEW api.article
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
@@ -87,21 +94,21 @@ SELECT
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.article;
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
CREATE VIEW api.footer
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.footer WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
additional_text,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.footer;
|
||||
FROM
|
||||
internal.footer;
|
||||
|
||||
CREATE VIEW api.collab
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.collab WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
user_id,
|
||||
@@ -109,11 +116,11 @@ SELECT
|
||||
added_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM internal.collab;
|
||||
FROM
|
||||
internal.collab;
|
||||
|
||||
CREATE VIEW api.change_log
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.change_log WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
user_id,
|
||||
@@ -121,29 +128,26 @@ SELECT
|
||||
previous_value,
|
||||
new_value,
|
||||
timestamp
|
||||
FROM internal.change_log;
|
||||
FROM
|
||||
internal.change_log;
|
||||
|
||||
CREATE FUNCTION
|
||||
api.create_website(content_type VARCHAR(10), title VARCHAR(50), OUT website_id UUID) AS $$
|
||||
CREATE FUNCTION api.create_website (content_type VARCHAR(10), title VARCHAR(50), OUT website_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_website_id UUID;
|
||||
_user_id UUID;
|
||||
BEGIN
|
||||
_user_id := (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID;
|
||||
|
||||
_user_id := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
INSERT INTO internal.website (content_type, title)
|
||||
VALUES (create_website.content_type, create_website.title)
|
||||
RETURNING id INTO _website_id;
|
||||
|
||||
RETURNING
|
||||
id INTO _website_id;
|
||||
INSERT INTO internal.settings (website_id)
|
||||
VALUES (_website_id);
|
||||
|
||||
INSERT INTO internal.header (website_id, logo_text)
|
||||
VALUES (_website_id, 'archtika ' || create_website.content_type);
|
||||
|
||||
INSERT INTO internal.home (website_id, main_content)
|
||||
VALUES
|
||||
(_website_id, '
|
||||
VALUES (_website_id, '
|
||||
## About
|
||||
|
||||
archtika is a FLOSS, modern, performant and lightweight CMS (Content Mangement System) in the form of a web application. It allows you to easily create, manage and publish minimal, responsive and SEO friendly blogging and documentation websites with official, professionally designed templates.
|
||||
@@ -158,61 +162,99 @@ The web application uses SvelteKit with SSR (Server Side Rendering) and Svelte v
|
||||
|
||||
NGINX is used to deploy the websites, serving the static site files from the `/var/www/archtika-websites` directory. The static files can be found in this directory via the path `<user_id>/<website_id>`, which is dynamically created by the web application.
|
||||
');
|
||||
|
||||
INSERT INTO internal.footer (website_id, additional_text)
|
||||
VALUES (_website_id, 'archtika is a free, open, modern, performant and lightweight CMS');
|
||||
|
||||
website_id := _website_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.create_website(VARCHAR(10), VARCHAR(50)) TO authenticated_user;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.create_website (VARCHAR(10), VARCHAR(50)) TO authenticated_user;
|
||||
|
||||
-- Security invoker only works on views if the user has access to the underlying table
|
||||
GRANT SELECT ON internal.user TO authenticated_user;
|
||||
|
||||
GRANT SELECT ON api.account TO authenticated_user;
|
||||
|
||||
GRANT SELECT ON api.user TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON internal.website TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT ON internal.media TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT ON api.media TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON internal.settings TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON api.settings TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON internal.header TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON api.header TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON internal.home TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON api.home TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.article TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON internal.footer TO authenticated_user;
|
||||
|
||||
GRANT SELECT, UPDATE ON api.footer TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.collab TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.collab TO authenticated_user;
|
||||
|
||||
GRANT SELECT ON internal.change_log TO authenticated_user;
|
||||
|
||||
GRANT SELECT ON api.change_log TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
REVOKE SELECT ON internal.user FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, UPDATE, DELETE ON internal.website FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, INSERT ON internal.media FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, UPDATE ON internal.settings FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, UPDATE ON internal.header FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.article FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, UPDATE ON internal.footer FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.collab FROM authenticated_user;
|
||||
|
||||
REVOKE SELECT ON internal.change_log FROM authenticated_user;
|
||||
|
||||
DROP FUNCTION api.create_website(VARCHAR(10), VARCHAR(50));
|
||||
DROP FUNCTION api.create_website (VARCHAR(10), VARCHAR(50));
|
||||
|
||||
DROP VIEW api.change_log;
|
||||
|
||||
DROP VIEW api.collab;
|
||||
|
||||
DROP VIEW api.footer;
|
||||
|
||||
DROP VIEW api.home;
|
||||
|
||||
DROP VIEW api.article;
|
||||
|
||||
DROP VIEW api.header;
|
||||
|
||||
DROP VIEW api.settings;
|
||||
|
||||
DROP VIEW api.media;
|
||||
|
||||
DROP VIEW api.website;
|
||||
|
||||
DROP VIEW api.user;
|
||||
|
||||
DROP VIEW api.account;
|
||||
|
||||
|
||||
@@ -1,201 +1,218 @@
|
||||
-- migrate:up
|
||||
ALTER TABLE internal.user ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.website ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.media ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.settings ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.header ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.home ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.article ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.footer ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.collab ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE FUNCTION internal.user_has_website_access(
|
||||
website_id UUID,
|
||||
required_permission INTEGER,
|
||||
collaborator_permission_level INTEGER DEFAULT NULL,
|
||||
collaborator_user_id UUID DEFAULT NULL,
|
||||
article_user_id UUID DEFAULT NULL,
|
||||
raise_error BOOLEAN DEFAULT true
|
||||
)
|
||||
RETURNS BOOLEAN AS $$
|
||||
CREATE FUNCTION internal.user_has_website_access (website_id UUID, required_permission INTEGER, collaborator_permission_level INTEGER DEFAULT NULL, collaborator_user_id UUID DEFAULT NULL, article_user_id UUID DEFAULT NULL, raise_error BOOLEAN DEFAULT TRUE)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
_user_id UUID;
|
||||
_has_access BOOLEAN;
|
||||
BEGIN
|
||||
_user_id := (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID;
|
||||
|
||||
SELECT EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.website
|
||||
WHERE id = website_id AND user_id = _user_id
|
||||
) INTO _has_access;
|
||||
|
||||
_user_id := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
SELECT
|
||||
EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.website
|
||||
WHERE
|
||||
id = website_id
|
||||
AND user_id = _user_id) INTO _has_access;
|
||||
IF _has_access THEN
|
||||
RETURN _has_access;
|
||||
END IF;
|
||||
|
||||
SELECT EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.collab c
|
||||
WHERE c.website_id = user_has_website_access.website_id
|
||||
AND c.user_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
SELECT
|
||||
EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.collab c
|
||||
WHERE
|
||||
c.website_id = user_has_website_access.website_id
|
||||
AND c.user_id = (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID
|
||||
AND c.permission_level >= user_has_website_access.required_permission
|
||||
AND (
|
||||
user_has_website_access.article_user_id IS NULL
|
||||
OR
|
||||
(
|
||||
c.permission_level = 30
|
||||
OR
|
||||
user_has_website_access.article_user_id = _user_id
|
||||
)
|
||||
)
|
||||
AND (
|
||||
user_has_website_access.collaborator_permission_level IS NULL
|
||||
OR
|
||||
(
|
||||
user_has_website_access.collaborator_user_id != _user_id
|
||||
AND
|
||||
user_has_website_access.collaborator_permission_level < 30
|
||||
)
|
||||
)
|
||||
) INTO _has_access;
|
||||
|
||||
AND (user_has_website_access.article_user_id IS NULL
|
||||
OR (c.permission_level = 30
|
||||
OR user_has_website_access.article_user_id = _user_id))
|
||||
AND (user_has_website_access.collaborator_permission_level IS NULL
|
||||
OR (user_has_website_access.collaborator_user_id != _user_id
|
||||
AND user_has_website_access.collaborator_permission_level < 30))) INTO _has_access;
|
||||
IF NOT _has_access AND user_has_website_access.raise_error THEN
|
||||
RAISE insufficient_privilege USING MESSAGE = 'You do not have the required permissions for this action.';
|
||||
RAISE insufficient_privilege
|
||||
USING message = 'You do not have the required permissions for this action.';
|
||||
END IF;
|
||||
|
||||
RETURN _has_access;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
CREATE POLICY view_user ON internal.user
|
||||
FOR SELECT
|
||||
USING (true);
|
||||
FOR SELECT
|
||||
USING (TRUE);
|
||||
|
||||
CREATE POLICY view_websites ON internal.website
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(id, 10, raise_error => false));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (id, 10, raise_error => FALSE));
|
||||
|
||||
CREATE POLICY update_website ON internal.website
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(id, 20));
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (id, 20));
|
||||
|
||||
CREATE POLICY delete_website ON internal.website
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access(id, 40));
|
||||
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (id, 40));
|
||||
|
||||
CREATE POLICY view_media ON internal.media
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY insert_media ON internal.media
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_settings ON internal.settings
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_settings ON internal.settings
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_header ON internal.header
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_header ON internal.header
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_home ON internal.home
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_home ON internal.home
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_articles ON internal.article
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_article ON internal.article
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 20));
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY delete_article ON internal.article
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access(website_id, 20, article_user_id => user_id));
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 20, article_user_id => user_id));
|
||||
|
||||
CREATE POLICY insert_article ON internal.article
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_footer ON internal.footer
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_footer ON internal.footer
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 20));
|
||||
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_collaborations ON internal.collab
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access(website_id, 10));
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY insert_collaborations ON internal.collab
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access(website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
|
||||
CREATE POLICY update_collaborations ON internal.collab
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access(website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
|
||||
CREATE POLICY delete_collaborations ON internal.collab
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access(website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 30, collaborator_permission_level => permission_level, collaborator_user_id => user_id));
|
||||
|
||||
-- migrate:down
|
||||
DROP POLICY view_user ON internal.user;
|
||||
|
||||
DROP POLICY view_websites ON internal.website;
|
||||
|
||||
DROP POLICY delete_website ON internal.website;
|
||||
|
||||
DROP POLICY update_website ON internal.website;
|
||||
|
||||
DROP POLICY view_media ON internal.media;
|
||||
|
||||
DROP POLICY insert_media ON internal.media;
|
||||
|
||||
DROP POLICY view_settings ON internal.settings;
|
||||
|
||||
DROP POLICY update_settings ON internal.settings;
|
||||
|
||||
DROP POLICY view_header ON internal.header;
|
||||
|
||||
DROP POLICY update_header ON internal.header;
|
||||
|
||||
DROP POLICY view_home ON internal.home;
|
||||
|
||||
DROP POLICY update_home ON internal.home;
|
||||
|
||||
DROP POLICY view_articles ON internal.article;
|
||||
|
||||
DROP POLICY update_article ON internal.article;
|
||||
|
||||
DROP POLICY delete_article ON internal.article;
|
||||
|
||||
DROP POLICY insert_article ON internal.article;
|
||||
|
||||
DROP POLICY view_footer ON internal.footer;
|
||||
|
||||
DROP POLICY update_footer ON internal.footer;
|
||||
|
||||
DROP POLICY view_collaborations ON internal.collab;
|
||||
|
||||
DROP POLICY insert_collaborations ON internal.collab;
|
||||
|
||||
DROP POLICY update_collaborations ON internal.collab;
|
||||
|
||||
DROP POLICY delete_collaborations ON internal.collab;
|
||||
DROP FUNCTION internal.user_has_website_access(UUID, INTEGER, INTEGER, UUID, UUID, BOOLEAN);
|
||||
|
||||
DROP FUNCTION internal.user_has_website_access (UUID, INTEGER, INTEGER, UUID, UUID, BOOLEAN);
|
||||
|
||||
ALTER TABLE internal.user DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.website DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.media DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.settings DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.header DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.home DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.article DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.footer DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.collab DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
|
||||
@@ -1,7 +1,6 @@
|
||||
-- migrate:up
|
||||
CREATE VIEW api.website_overview
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
@@ -16,25 +15,23 @@ SELECT
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT json_agg(
|
||||
json_build_object(
|
||||
'title', a.title,
|
||||
'meta_description', a.meta_description,
|
||||
'meta_author', a.meta_author,
|
||||
'cover_image', a.cover_image,
|
||||
'publication_date', a.publication_date,
|
||||
'main_content', a.main_content
|
||||
)
|
||||
)
|
||||
FROM internal.article a
|
||||
WHERE a.website_id = w.id
|
||||
) AS articles
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'title', a.title, 'meta_description', a.meta_description, 'meta_author', a.meta_author, 'cover_image', a.cover_image, 'publication_date', a.publication_date, 'main_content', a.main_content
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles
|
||||
FROM
|
||||
internal.website w
|
||||
JOIN internal.settings s ON w.id = s.website_id
|
||||
JOIN internal.header h ON w.id = h.website_id
|
||||
JOIN internal.home ho ON w.id = ho.website_id
|
||||
JOIN internal.footer f ON w.id = f.website_id;
|
||||
JOIN internal.settings s ON w.id = s.website_id
|
||||
JOIN internal.header h ON w.id = h.website_id
|
||||
JOIN internal.home ho ON w.id = ho.website_id
|
||||
JOIN internal.footer f ON w.id = f.website_id;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
@@ -42,3 +39,4 @@ GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
REVOKE SELECT ON api.website_overview FROM authenticated_user;
|
||||
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
|
||||
@@ -1,72 +1,86 @@
|
||||
-- migrate:up
|
||||
CREATE FUNCTION internal.update_last_modified()
|
||||
RETURNS TRIGGER AS $$
|
||||
CREATE FUNCTION internal.update_last_modified ()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
NEW.last_modified_at = CLOCK_TIMESTAMP();
|
||||
NEW.last_modified_by = (current_setting('request.jwt.claims', true)::JSON->>'user_id')::UUID;
|
||||
|
||||
NEW.last_modified_by = (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
IF TG_TABLE_NAME != 'website' THEN
|
||||
UPDATE internal.website
|
||||
UPDATE
|
||||
internal.website
|
||||
SET
|
||||
last_modified_at = NEW.last_modified_at,
|
||||
last_modified_by = NEW.last_modified_by
|
||||
WHERE id =
|
||||
CASE
|
||||
WHEN TG_TABLE_NAME = 'settings' THEN NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'header' THEN NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'home' THEN NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'article' THEN NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'footer' THEN NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'collab' THEN NEW.website_id
|
||||
WHERE
|
||||
id = CASE WHEN TG_TABLE_NAME = 'settings' THEN
|
||||
NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'header' THEN
|
||||
NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'home' THEN
|
||||
NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'article' THEN
|
||||
NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'footer' THEN
|
||||
NEW.website_id
|
||||
WHEN TG_TABLE_NAME = 'collab' THEN
|
||||
NEW.website_id
|
||||
END;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
CREATE TRIGGER update_website_last_modified
|
||||
BEFORE UPDATE ON internal.website
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.website
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_settings_last_modified
|
||||
BEFORE UPDATE ON internal.settings
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.settings
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_header_last_modified
|
||||
BEFORE UPDATE ON internal.header
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.header
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_home_last_modified
|
||||
BEFORE UPDATE ON internal.home
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.home
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_article_last_modified
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON internal.article
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON internal.article
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_footer_last_modified
|
||||
BEFORE UPDATE ON internal.footer
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.footer
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_collab_last_modified
|
||||
BEFORE UPDATE ON internal.collab
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified();
|
||||
BEFORE UPDATE ON internal.collab
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
-- migrate:down
|
||||
DROP TRIGGER update_website_last_modified ON internal.website;
|
||||
|
||||
DROP TRIGGER update_settings_last_modified ON internal.settings;
|
||||
|
||||
DROP TRIGGER update_header_last_modified ON internal.header;
|
||||
|
||||
DROP TRIGGER update_home_last_modified ON internal.home;
|
||||
|
||||
DROP TRIGGER update_article_last_modified ON internal.article;
|
||||
|
||||
DROP TRIGGER update_footer_last_modified ON internal.footer;
|
||||
|
||||
DROP TRIGGER update_collab_last_modified ON internal.collab;
|
||||
|
||||
DROP FUNCTION internal.update_last_modified();
|
||||
DROP FUNCTION internal.update_last_modified ();
|
||||
|
||||
|
||||
@@ -1,24 +1,32 @@
|
||||
-- migrate:up
|
||||
CREATE FUNCTION internal.check_user_not_website_owner()
|
||||
RETURNS TRIGGER AS $$
|
||||
CREATE FUNCTION internal.check_user_not_website_owner ()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
IF EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.website
|
||||
WHERE id = NEW.website_id AND user_id = NEW.user_id
|
||||
) THEN
|
||||
RAISE foreign_key_violation USING MESSAGE = 'User cannot be added as a collaborator to their own website';
|
||||
END IF;
|
||||
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.website
|
||||
WHERE
|
||||
id = NEW.website_id
|
||||
AND user_id = NEW.user_id) THEN
|
||||
RAISE foreign_key_violation
|
||||
USING message = 'User cannot be added as a collaborator to their own website';
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
CREATE CONSTRAINT TRIGGER check_user_not_website_owner
|
||||
AFTER INSERT ON internal.collab
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.check_user_not_website_owner();
|
||||
AFTER INSERT ON internal.collab
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.check_user_not_website_owner ();
|
||||
|
||||
-- migrate:down
|
||||
DROP TRIGGER check_user_not_website_owner ON internal.collab;
|
||||
DROP FUNCTION internal.check_user_not_website_owner();
|
||||
|
||||
DROP FUNCTION internal.check_user_not_website_owner ();
|
||||
|
||||
|
||||
Reference in New Issue
Block a user