mirror of
https://github.com/thiloho/archtika.git
synced 2025-11-22 02:41:35 +01:00
Initial commit
This commit is contained in:
3
rest-api/.env
Normal file
3
rest-api/.env
Normal file
@@ -0,0 +1,3 @@
|
||||
DATABASE_URL="postgres://postgres@localhost:15432/archtika?sslmode=disable"
|
||||
PGRST_DB_URI="postgres://authenticator@localhost:15432/archtika?sslmode=disable"
|
||||
JWT_SECRET="a42kVyAhTImYxZeebZkApoAZLmf0VtDA"
|
||||
125
rest-api/db/migrations/20240719071602_main_tables.sql
Normal file
125
rest-api/db/migrations/20240719071602_main_tables.sql
Normal file
@@ -0,0 +1,125 @@
|
||||
-- migrate:up
|
||||
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),
|
||||
password_hash CHAR(60) NOT NULL,
|
||||
role NAME NOT NULL DEFAULT 'authenticated_user'
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_content (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
owner_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,
|
||||
project_name VARCHAR(50) NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_media (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
content_id UUID REFERENCES internal.cms_content(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.cms_settings (
|
||||
content_id UUID PRIMARY KEY REFERENCES internal.cms_content(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.cms_media(id) ON DELETE SET NULL,
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_header (
|
||||
content_id UUID PRIMARY KEY REFERENCES internal.cms_content(id) ON DELETE CASCADE,
|
||||
logo_type TEXT CHECK (logo_type IN ('text', 'image')) NOT NULL DEFAULT 'text',
|
||||
logo_text VARCHAR(255),
|
||||
logo_image UUID REFERENCES internal.cms_media(id) ON DELETE SET NULL,
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_home (
|
||||
content_id UUID PRIMARY KEY REFERENCES internal.cms_content(id) ON DELETE CASCADE,
|
||||
main_content TEXT,
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_article (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
content_id UUID REFERENCES internal.cms_content(id) ON DELETE CASCADE NOT NULL,
|
||||
title VARCHAR(255) NOT NULL,
|
||||
meta_description VARCHAR(500),
|
||||
meta_author VARCHAR(255),
|
||||
cover_image UUID REFERENCES internal.cms_media(id) ON DELETE SET NULL,
|
||||
publication_date DATE NOT NULL DEFAULT CURRENT_DATE,
|
||||
main_content TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_footer (
|
||||
content_id UUID PRIMARY KEY REFERENCES internal.cms_content(id) ON DELETE CASCADE,
|
||||
additional_text VARCHAR(255),
|
||||
last_modified_at TIMESTAMPTZ,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_collab (
|
||||
content_id UUID REFERENCES internal.cms_content(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,
|
||||
last_modified_by UUID REFERENCES internal.user(id) ON DELETE SET NULL,
|
||||
PRIMARY KEY (content_id, user_id)
|
||||
);
|
||||
|
||||
CREATE TABLE internal.cms_change_log (
|
||||
content_id UUID REFERENCES internal.cms_content(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 (content_id, user_id, timestamp)
|
||||
);
|
||||
|
||||
-- migrate:down
|
||||
DROP TABLE internal.cms_change_log;
|
||||
DROP TABLE internal.cms_collab;
|
||||
DROP TABLE internal.cms_footer;
|
||||
DROP TABLE internal.cms_article;
|
||||
DROP TABLE internal.cms_home;
|
||||
DROP TABLE internal.cms_header;
|
||||
DROP TABLE internal.cms_settings;
|
||||
DROP TABLE internal.cms_media;
|
||||
DROP TABLE internal.cms_content;
|
||||
DROP SCHEMA api;
|
||||
|
||||
DROP TABLE internal.user;
|
||||
DROP SCHEMA internal;
|
||||
|
||||
DROP ROLE authenticator;
|
||||
DROP ROLE anon;
|
||||
DROP ROLE authenticated_user;
|
||||
@@ -0,0 +1,14 @@
|
||||
-- migrate:up
|
||||
CREATE FUNCTION pgrst_watch() RETURNS event_trigger AS $$
|
||||
BEGIN
|
||||
NOTIFY pgrst, 'reload schema';
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE EVENT TRIGGER pgrst_watch
|
||||
ON ddl_command_end
|
||||
EXECUTE FUNCTION pgrst_watch();
|
||||
|
||||
-- migrate:down
|
||||
DROP EVENT TRIGGER pgrst_watch;
|
||||
DROP FUNCTION pgrst_watch();
|
||||
@@ -0,0 +1,161 @@
|
||||
-- migrate:up
|
||||
CREATE EXTENSION pgcrypto;
|
||||
CREATE EXTENSION pgjwt;
|
||||
|
||||
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;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ 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();
|
||||
|
||||
|
||||
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'));
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER 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 $$
|
||||
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)
|
||||
);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
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);
|
||||
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';
|
||||
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);
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[a-z]' THEN
|
||||
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';
|
||||
END IF;
|
||||
|
||||
IF register.password !~ '[0-9]' THEN
|
||||
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';
|
||||
END IF;
|
||||
|
||||
INSERT INTO internal.user (username, password_hash)
|
||||
VALUES (register.username, register.password)
|
||||
RETURNING id INTO user_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
|
||||
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;
|
||||
IF _role IS NULL THEN
|
||||
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;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
|
||||
CREATE FUNCTION
|
||||
api.delete_account(password TEXT, OUT was_deleted BOOLEAN) AS $$
|
||||
DECLARE
|
||||
_username TEXT := current_setting('request.jwt.claims', true)::json->>'username';
|
||||
_role NAME;
|
||||
BEGIN
|
||||
SELECT internal.user_role(_username, delete_account.password) INTO _role;
|
||||
IF _role IS NULL THEN
|
||||
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;
|
||||
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.register(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 internal.user_role(TEXT, TEXT);
|
||||
|
||||
DROP TRIGGER encrypt_pass ON internal.user;
|
||||
DROP FUNCTION internal.encrypt_pass();
|
||||
|
||||
DROP TRIGGER ensure_user_role_exists ON internal.user;
|
||||
DROP FUNCTION internal.check_role_exists();
|
||||
|
||||
DROP EXTENSION pgjwt;
|
||||
DROP EXTENSION pgcrypto;
|
||||
@@ -0,0 +1,140 @@
|
||||
-- migrate:up
|
||||
CREATE VIEW api.user
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT id, username
|
||||
FROM internal.user;
|
||||
|
||||
CREATE VIEW api.cms_content
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_content;
|
||||
|
||||
CREATE VIEW api.cms_media
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_media;
|
||||
|
||||
CREATE VIEW api.cms_settings
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_settings;
|
||||
|
||||
CREATE VIEW api.cms_header
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_header;
|
||||
|
||||
CREATE view api.cms_home
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_home;
|
||||
|
||||
CREATE VIEW api.cms_article
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_article;
|
||||
|
||||
CREATE VIEW api.cms_footer
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_footer;
|
||||
|
||||
CREATE VIEW api.cms_collab
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_collab;
|
||||
|
||||
CREATE VIEW api.cms_change_log
|
||||
WITH (security_invoker = on)
|
||||
AS
|
||||
SELECT *
|
||||
FROM internal.cms_change_log;
|
||||
|
||||
CREATE FUNCTION
|
||||
api.create_project(content_type VARCHAR(10), project_name VARCHAR(50), OUT content_id UUID) AS $$
|
||||
DECLARE
|
||||
_content_id UUID;
|
||||
BEGIN
|
||||
INSERT INTO internal.cms_content (content_type, project_name)
|
||||
VALUES (create_project.content_type, create_project.project_name)
|
||||
RETURNING id INTO _content_id;
|
||||
|
||||
INSERT INTO internal.cms_settings (content_id)
|
||||
VALUES (_content_id);
|
||||
|
||||
INSERT INTO internal.cms_header (content_id, logo_text)
|
||||
VALUES (_content_id, 'archtika ' || create_project.content_type);
|
||||
|
||||
INSERT INTO internal.cms_home (content_id, main_content)
|
||||
VALUES
|
||||
(_content_id, '## Main content comes in here');
|
||||
|
||||
INSERT INTO internal.cms_article (content_id, title, meta_description, meta_author, main_content)
|
||||
VALUES
|
||||
(_content_id, 'First article', 'This is the first sample article', 'Author Name', '## First article'),
|
||||
(_content_id, 'Second article', 'This is the second sample article', 'Author Name', '## Second article');
|
||||
|
||||
INSERT INTO internal.cms_footer (content_id, additional_text)
|
||||
VALUES (_content_id, 'This website was created with archtika');
|
||||
|
||||
content_id := _content_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.create_project(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.user TO authenticated_user;
|
||||
GRANT SELECT, UPDATE, DELETE ON internal.cms_content TO authenticated_user;
|
||||
GRANT SELECT, UPDATE, DELETE ON api.cms_content TO authenticated_user;
|
||||
GRANT SELECT, INSERT ON internal.cms_media TO authenticated_user;
|
||||
GRANT SELECT, INSERT ON api.cms_media TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON internal.cms_settings TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON api.cms_settings TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON internal.cms_header TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON api.cms_header TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON internal.cms_home TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON api.cms_home TO authenticated_user;
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.cms_article TO authenticated_user;
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.cms_article TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON internal.cms_footer TO authenticated_user;
|
||||
GRANT SELECT, UPDATE ON api.cms_footer TO authenticated_user;
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.cms_collab TO authenticated_user;
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.cms_collab TO authenticated_user;
|
||||
GRANT SELECT ON internal.cms_change_log TO authenticated_user;
|
||||
GRANT SELECT ON api.cms_change_log TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
REVOKE SELECT ON internal.user FROM authenticated_user;
|
||||
REVOKE SELECT, UPDATE, DELETE ON internal.cms_content FROM authenticated_user;
|
||||
REVOKE SELECT, INSERT ON internal.cms_media FROM authenticated_user;
|
||||
REVOKE SELECT, UPDATE ON internal.cms_settings FROM authenticated_user;
|
||||
REVOKE SELECT, UPDATE ON internal.cms_header FROM authenticated_user;
|
||||
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.cms_article FROM authenticated_user;
|
||||
REVOKE SELECT, UPDATE ON internal.cms_footer FROM authenticated_user;
|
||||
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.cms_collab FROM authenticated_user;
|
||||
REVOKE SELECT ON internal.cms_change_log FROM authenticated_user;
|
||||
|
||||
DROP FUNCTION api.create_project(VARCHAR(10), VARCHAR(50));
|
||||
|
||||
DROP VIEW api.cms_change_log;
|
||||
DROP VIEW api.cms_collab;
|
||||
DROP VIEW api.cms_footer;
|
||||
DROP VIEW api.cms_home;
|
||||
DROP VIEW api.cms_article;
|
||||
DROP VIEW api.cms_header;
|
||||
DROP VIEW api.cms_settings;
|
||||
DROP VIEW api.cms_media;
|
||||
DROP VIEW api.cms_content;
|
||||
DROP VIEW api.user;
|
||||
208
rest-api/db/migrations/20240724191017_row_level_security.sql
Normal file
208
rest-api/db/migrations/20240724191017_row_level_security.sql
Normal file
@@ -0,0 +1,208 @@
|
||||
-- migrate:up
|
||||
ALTER TABLE internal.user ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_content ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_media ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_settings ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_header ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_home ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_article ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_footer ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE POLICY view_own_user ON internal.user
|
||||
FOR SELECT
|
||||
USING (id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID);
|
||||
|
||||
CREATE POLICY view_own_projects ON internal.cms_content
|
||||
FOR SELECT
|
||||
USING (owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID);
|
||||
|
||||
CREATE POLICY update_own_project ON internal.cms_content
|
||||
FOR UPDATE
|
||||
USING (owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID);
|
||||
|
||||
CREATE POLICY delete_own_project ON internal.cms_content
|
||||
FOR DELETE
|
||||
USING (owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID);
|
||||
|
||||
|
||||
CREATE POLICY view_own_media ON internal.cms_media
|
||||
FOR SELECT
|
||||
USING (user_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID);
|
||||
|
||||
CREATE POLICY insert_own_media ON internal.cms_media
|
||||
FOR INSERT
|
||||
WITH CHECK (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_media.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
CREATE POLICY view_own_settings ON internal.cms_settings
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_settings.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY update_own_settings ON internal.cms_settings
|
||||
FOR UPDATE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_settings.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
CREATE POLICY view_own_header ON internal.cms_header
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_header.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY update_own_header ON internal.cms_header
|
||||
FOR UPDATE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_header.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
CREATE POLICY view_own_home ON internal.cms_home
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_home.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY update_own_home ON internal.cms_home
|
||||
FOR UPDATE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_home.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
CREATE POLICY view_own_articles ON internal.cms_article
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_article.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY update_own_article ON internal.cms_article
|
||||
FOR UPDATE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_article.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY delete_own_article ON internal.cms_article
|
||||
FOR DELETE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_article.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY insert_own_article ON internal.cms_article
|
||||
FOR INSERT
|
||||
WITH CHECK (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_article.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
CREATE POLICY view_own_footer ON internal.cms_footer
|
||||
FOR SELECT
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_footer.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
CREATE POLICY update_own_footer ON internal.cms_footer
|
||||
FOR UPDATE
|
||||
USING (
|
||||
EXISTS (
|
||||
SELECT 1
|
||||
FROM internal.cms_content
|
||||
WHERE internal.cms_content.id = internal.cms_footer.content_id
|
||||
AND internal.cms_content.owner_id = (current_setting('request.jwt.claims', true)::json->>'user_id')::UUID
|
||||
)
|
||||
);
|
||||
|
||||
|
||||
-- migrate:down
|
||||
DROP POLICY view_own_user ON internal.user;
|
||||
DROP POLICY view_own_projects ON internal.cms_content;
|
||||
DROP POLICY delete_own_project ON internal.cms_content;
|
||||
DROP POLICY update_own_project ON internal.cms_content;
|
||||
DROP POLICY view_own_media ON internal.cms_media;
|
||||
DROP POLICY insert_own_media ON internal.cms_media;
|
||||
DROP POLICY view_own_settings ON internal.cms_settings;
|
||||
DROP POLICY update_own_settings ON internal.cms_settings;
|
||||
DROP POLICY view_own_header ON internal.cms_header;
|
||||
DROP POLICY update_own_header ON internal.cms_header;
|
||||
DROP POLICY view_own_home ON internal.cms_home;
|
||||
DROP POLICY update_own_home ON internal.cms_home;
|
||||
DROP POLICY view_own_articles ON internal.cms_article;
|
||||
DROP POLICY update_own_article ON internal.cms_article;
|
||||
DROP POLICY delete_own_article ON internal.cms_article;
|
||||
DROP POLICY insert_own_article ON internal.cms_article;
|
||||
DROP POLICY view_own_footer ON internal.cms_footer;
|
||||
DROP POLICY update_own_footer ON internal.cms_footer;
|
||||
|
||||
ALTER TABLE internal.user DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_content DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_media DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_settings DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_header DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_home DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_article DISABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE internal.cms_footer DISABLE ROW LEVEL SECURITY;
|
||||
3
rest-api/postgrest.conf
Normal file
3
rest-api/postgrest.conf
Normal file
@@ -0,0 +1,3 @@
|
||||
db-schemas = "api"
|
||||
db-anon-role = "anon"
|
||||
openapi-mode = "ignore-privileges"
|
||||
Reference in New Issue
Block a user