mirror of
https://github.com/thiloho/archtika.git
synced 2025-11-22 10:51:36 +01:00
Add TypeScript definitions via pg-to-ts and refactor migrations
This commit is contained in:
@@ -1,21 +1,25 @@
|
||||
-- migrate:up
|
||||
CREATE SCHEMA internal;
|
||||
|
||||
CREATE SCHEMA api;
|
||||
|
||||
CREATE ROLE authenticator LOGIN NOINHERIT NOCREATEDB NOCREATEROLE NOSUPERUSER;
|
||||
|
||||
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;
|
||||
GRANT USAGE ON SCHEMA api TO anon;
|
||||
|
||||
GRANT USAGE ON SCHEMA api TO authenticated_user;
|
||||
|
||||
GRANT USAGE ON SCHEMA internal TO authenticated_user;
|
||||
|
||||
ALTER DEFAULT PRIVILEGES REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
|
||||
|
||||
CREATE TABLE internal.user (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
|
||||
@@ -30,8 +34,10 @@ CREATE TABLE internal.website (
|
||||
content_type VARCHAR(10) CHECK (content_type IN ('Blog', 'Docs')) NOT NULL,
|
||||
title VARCHAR(50) NOT NULL CHECK (TRIM(title) != ''),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
|
||||
is_published BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
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,
|
||||
title_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', title)) STORED
|
||||
);
|
||||
|
||||
CREATE TABLE internal.media (
|
||||
@@ -70,19 +76,32 @@ CREATE TABLE internal.home (
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.docs_category (
|
||||
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 DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
category_name VARCHAR(50) NOT NULL CHECK (TRIM(category_name) != ''),
|
||||
category_weight INTEGER CHECK (category_weight >= 0) NOT NULL,
|
||||
UNIQUE (website_id, category_name),
|
||||
UNIQUE (website_id, category_weight)
|
||||
);
|
||||
|
||||
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,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE SET NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
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,
|
||||
publication_date DATE DEFAULT CURRENT_DATE,
|
||||
main_content TEXT CHECK (TRIM(main_content) != ''),
|
||||
category UUID REFERENCES internal.docs_category (id) ON DELETE SET NULL,
|
||||
article_weight INTEGER CHECK (article_weight IS NULL OR article_weight >= 0),
|
||||
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,
|
||||
title_description_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', COALESCE(title, '') || ' ' || COALESCE(meta_description, ''))) STORED
|
||||
);
|
||||
|
||||
CREATE TABLE internal.footer (
|
||||
@@ -92,6 +111,13 @@ CREATE TABLE internal.footer (
|
||||
last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE internal.legal_information (
|
||||
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
|
||||
);
|
||||
|
||||
CREATE TABLE internal.collab (
|
||||
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE,
|
||||
user_id UUID REFERENCES internal.user (id) ON DELETE CASCADE,
|
||||
@@ -117,10 +143,14 @@ DROP TABLE internal.change_log;
|
||||
|
||||
DROP TABLE internal.collab;
|
||||
|
||||
DROP TABLE internal.legal_information;
|
||||
|
||||
DROP TABLE internal.footer;
|
||||
|
||||
DROP TABLE internal.article;
|
||||
|
||||
DROP TABLE internal.docs_category;
|
||||
|
||||
DROP TABLE internal.home;
|
||||
|
||||
DROP TABLE internal.header;
|
||||
@@ -131,15 +161,17 @@ DROP TABLE internal.media;
|
||||
|
||||
DROP TABLE internal.website;
|
||||
|
||||
DROP SCHEMA api;
|
||||
|
||||
DROP TABLE internal.user;
|
||||
|
||||
DROP SCHEMA internal;
|
||||
DROP SCHEMA api;
|
||||
|
||||
DROP ROLE authenticator;
|
||||
DROP SCHEMA internal;
|
||||
|
||||
DROP ROLE anon;
|
||||
|
||||
DROP ROLE authenticated_user;
|
||||
|
||||
DROP ROLE authenticator;
|
||||
|
||||
ALTER DEFAULT PRIVILEGES GRANT EXECUTE ON FUNCTIONS TO PUBLIC;
|
||||
|
||||
|
||||
@@ -1,6 +1,6 @@
|
||||
-- migrate:up
|
||||
CREATE FUNCTION pgrst_watch ()
|
||||
RETURNS event_trigger
|
||||
RETURNS EVENT_TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
NOTIFY pgrst,
|
||||
|
||||
@@ -45,23 +45,21 @@ CREATE TRIGGER encrypt_pass
|
||||
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, pass TEXT, OUT role_name 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 INTO role_name
|
||||
FROM
|
||||
internal.user AS u
|
||||
WHERE
|
||||
u.username = user_role.username
|
||||
AND u.password_hash = CRYPT(user_role.pass, u.password_hash);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE FUNCTION api.register (username TEXT, PASSWORD TEXT, OUT user_id UUID)
|
||||
CREATE FUNCTION api.register (username TEXT, pass TEXT, OUT user_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_username_length_min CONSTANT INT := 3;
|
||||
@@ -69,52 +67,48 @@ DECLARE
|
||||
_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
|
||||
CASE WHEN 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);
|
||||
WHEN 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
|
||||
USING message = 'Username is already taken';
|
||||
WHEN LENGTH(register.pass) 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);
|
||||
WHEN register.pass !~ '[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;
|
||||
WHEN register.pass !~ '[A-Z]' THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one uppercase letter';
|
||||
WHEN register.pass !~ '[0-9]' THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one number';
|
||||
WHEN register.pass !~ '[!@#$%^&*(),.?":{}|<>]' THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Password must contain at least one special character';
|
||||
ELSE
|
||||
INSERT
|
||||
INTO internal.user (username, password_hash)
|
||||
VALUES (register.username, register.pass)
|
||||
RETURNING
|
||||
id INTO user_id;
|
||||
END
|
||||
CASE;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
CREATE FUNCTION api.login (username TEXT, PASSWORD TEXT, OUT token TEXT)
|
||||
CREATE FUNCTION api.login (username TEXT, pass TEXT, OUT token TEXT)
|
||||
AS $$
|
||||
DECLARE
|
||||
_role NAME;
|
||||
@@ -122,7 +116,7 @@ DECLARE
|
||||
_exp INTEGER;
|
||||
BEGIN
|
||||
SELECT
|
||||
internal.user_role (login.username, login.password) INTO _role;
|
||||
internal.user_role (login.username, login.pass) INTO _role;
|
||||
IF _role IS NULL THEN
|
||||
RAISE invalid_password
|
||||
USING message = 'Invalid username or password';
|
||||
@@ -141,14 +135,14 @@ $$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
CREATE FUNCTION api.delete_account (PASSWORD TEXT, OUT was_deleted BOOLEAN)
|
||||
CREATE FUNCTION api.delete_account (pass 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;
|
||||
internal.user_role (_username, delete_account.pass) INTO _role;
|
||||
IF _role IS NULL THEN
|
||||
RAISE invalid_password
|
||||
USING message = 'Invalid password';
|
||||
@@ -165,7 +159,13 @@ 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.delete_account (TEXT) TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP TRIGGER encrypt_pass ON internal.user;
|
||||
|
||||
DROP TRIGGER ensure_user_role_exists ON internal.user;
|
||||
|
||||
DROP FUNCTION api.register (TEXT, TEXT);
|
||||
|
||||
DROP FUNCTION api.login (TEXT, TEXT);
|
||||
@@ -174,12 +174,8 @@ 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;
|
||||
|
||||
@@ -2,8 +2,7 @@
|
||||
CREATE VIEW api.account WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
username
|
||||
*
|
||||
FROM
|
||||
internal.user
|
||||
WHERE
|
||||
@@ -23,99 +22,70 @@ FROM
|
||||
CREATE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
content_type,
|
||||
title,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
CREATE VIEW api.settings WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
accent_color_light_theme,
|
||||
accent_color_dark_theme,
|
||||
favicon_image,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.settings;
|
||||
|
||||
CREATE VIEW api.header WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
logo_type,
|
||||
logo_text,
|
||||
logo_image,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.header;
|
||||
|
||||
CREATE VIEW api.home WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
main_content,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.home;
|
||||
|
||||
CREATE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
CREATE VIEW api.docs_category WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
internal.docs_category;
|
||||
|
||||
CREATE VIEW api.footer WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
additional_text,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.footer;
|
||||
|
||||
CREATE VIEW api.legal_information WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
internal.legal_information;
|
||||
|
||||
CREATE VIEW api.collab WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
user_id,
|
||||
permission_level,
|
||||
added_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
*
|
||||
FROM
|
||||
internal.collab;
|
||||
|
||||
CREATE VIEW api.change_log WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
user_id,
|
||||
change_summary,
|
||||
previous_value,
|
||||
new_value,
|
||||
timestamp
|
||||
*
|
||||
FROM
|
||||
internal.change_log;
|
||||
|
||||
@@ -123,9 +93,8 @@ CREATE FUNCTION api.create_website (content_type VARCHAR(10), title VARCHAR(50),
|
||||
AS $$
|
||||
DECLARE
|
||||
_website_id UUID;
|
||||
_user_id UUID;
|
||||
_user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
BEGIN
|
||||
_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
|
||||
@@ -135,8 +104,7 @@ BEGIN
|
||||
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, '
|
||||
## About
|
||||
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.
|
||||
|
||||
@@ -148,8 +116,7 @@ For the backend, PostgreSQL is used in combination with PostgREST to create a RE
|
||||
|
||||
The web application uses SvelteKit with SSR (Server Side Rendering) and Svelte version 5, currently in beta.
|
||||
|
||||
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.
|
||||
');
|
||||
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;
|
||||
@@ -187,10 +154,18 @@ GRANT SELECT, INSERT, UPDATE, DELETE ON internal.article TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.docs_category TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.docs_category 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.legal_information TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.legal_information 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;
|
||||
@@ -206,10 +181,14 @@ DROP VIEW api.change_log;
|
||||
|
||||
DROP VIEW api.collab;
|
||||
|
||||
DROP VIEW api.legal_information;
|
||||
|
||||
DROP VIEW api.footer;
|
||||
|
||||
DROP VIEW api.home;
|
||||
|
||||
DROP VIEW api.docs_category;
|
||||
|
||||
DROP VIEW api.article;
|
||||
|
||||
DROP VIEW api.header;
|
||||
|
||||
@@ -13,29 +13,30 @@ ALTER TABLE internal.home ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.article ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.docs_category ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.footer ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.legal_information 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, OUT has_access BOOLEAN)
|
||||
AS $$
|
||||
DECLARE
|
||||
_user_id UUID;
|
||||
_has_access BOOLEAN;
|
||||
_user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
BEGIN
|
||||
_user_id := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
SELECT
|
||||
EXISTS (
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.website
|
||||
internal.website AS w
|
||||
WHERE
|
||||
id = website_id
|
||||
AND user_id = _user_id) INTO _has_access;
|
||||
IF _has_access THEN
|
||||
RETURN _has_access;
|
||||
w.id = user_has_website_access.website_id
|
||||
AND w.user_id = _user_id) INTO has_access;
|
||||
IF has_access THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
SELECT
|
||||
EXISTS (
|
||||
@@ -45,24 +46,25 @@ BEGIN
|
||||
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.user_id = _user_id
|
||||
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;
|
||||
IF NOT _has_access AND user_has_website_access.raise_error THEN
|
||||
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.';
|
||||
END IF;
|
||||
RETURN _has_access;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION internal.user_has_website_access (UUID, INTEGER, INTEGER, UUID, UUID, BOOLEAN) TO authenticated_user;
|
||||
|
||||
CREATE POLICY view_user ON internal.user
|
||||
FOR SELECT
|
||||
USING (TRUE);
|
||||
@@ -127,6 +129,22 @@ CREATE POLICY insert_article ON internal.article
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_categories ON internal.docs_category
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_category ON internal.docs_category
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY delete_category ON internal.docs_category
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 20, article_user_id => user_id));
|
||||
|
||||
CREATE POLICY insert_category ON internal.docs_category
|
||||
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));
|
||||
@@ -135,6 +153,22 @@ CREATE POLICY update_footer ON internal.footer
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY view_legal_information ON internal.legal_information
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_legal_information ON internal.legal_information
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
CREATE POLICY delete_legal_information ON internal.legal_information
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
CREATE POLICY insert_legal_information ON internal.legal_information
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
CREATE POLICY view_collaborations ON internal.collab
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
@@ -184,10 +218,26 @@ DROP POLICY delete_article ON internal.article;
|
||||
|
||||
DROP POLICY insert_article ON internal.article;
|
||||
|
||||
DROP POLICY view_categories ON internal.docs_category;
|
||||
|
||||
DROP POLICY update_category ON internal.docs_category;
|
||||
|
||||
DROP POLICY delete_category ON internal.docs_category;
|
||||
|
||||
DROP POLICY insert_category ON internal.docs_category;
|
||||
|
||||
DROP POLICY view_footer ON internal.footer;
|
||||
|
||||
DROP POLICY update_footer ON internal.footer;
|
||||
|
||||
DROP POLICY insert_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY delete_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY update_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY view_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY view_collaborations ON internal.collab;
|
||||
|
||||
DROP POLICY insert_collaborations ON internal.collab;
|
||||
@@ -212,7 +262,11 @@ ALTER TABLE internal.home DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.article DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.docs_category DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.footer DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.legal_information DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
ALTER TABLE internal.collab DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
|
||||
@@ -1,40 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
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
|
||||
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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
@@ -12,25 +12,12 @@ BEGIN
|
||||
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
|
||||
END;
|
||||
id = NEW.website_id;
|
||||
END IF;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER update_website_last_modified
|
||||
BEFORE UPDATE ON internal.website
|
||||
@@ -62,6 +49,11 @@ CREATE TRIGGER update_footer_last_modified
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_legal_information_last_modified
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON internal.legal_information
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION internal.update_last_modified ();
|
||||
|
||||
CREATE TRIGGER update_collab_last_modified
|
||||
BEFORE UPDATE ON internal.collab
|
||||
FOR EACH ROW
|
||||
@@ -80,6 +72,8 @@ DROP TRIGGER update_article_last_modified ON internal.article;
|
||||
|
||||
DROP TRIGGER update_footer_last_modified ON internal.footer;
|
||||
|
||||
DROP TRIGGER update_legal_information_last_modified ON internal.legal_information;
|
||||
|
||||
DROP TRIGGER update_collab_last_modified ON internal.collab;
|
||||
|
||||
DROP FUNCTION internal.update_last_modified ();
|
||||
|
||||
@@ -7,10 +7,10 @@ BEGIN
|
||||
SELECT
|
||||
1
|
||||
FROM
|
||||
internal.website
|
||||
internal.website AS w
|
||||
WHERE
|
||||
id = NEW.website_id
|
||||
AND user_id = NEW.user_id) THEN
|
||||
w.id = NEW.website_id
|
||||
AND w.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;
|
||||
|
||||
@@ -10,7 +10,9 @@ DECLARE
|
||||
_original_filename TEXT := _headers ->> 'x-original-filename';
|
||||
_allowed_mimetypes TEXT[] := ARRAY['image/png', 'image/jpeg', 'image/webp'];
|
||||
_max_file_size INT := 5 * 1024 * 1024;
|
||||
_has_access BOOLEAN;
|
||||
BEGIN
|
||||
_has_access = internal.user_has_website_access (_website_id, 20);
|
||||
IF OCTET_LENGTH($1) = 0 THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'No file data was provided';
|
||||
@@ -19,7 +21,7 @@ BEGIN
|
||||
SELECT
|
||||
UNNEST(_allowed_mimetypes)) THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, svg, jpg, webp';
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp';
|
||||
END IF;
|
||||
IF OCTET_LENGTH($1) > _max_file_size THEN
|
||||
RAISE program_limit_exceeded
|
||||
@@ -46,7 +48,7 @@ BEGIN
|
||||
'{ "Content-Disposition": "inline; filename=\"%s\"" },'
|
||||
'{ "Cache-Control": "max-age=259200" }]', m.mimetype, m.original_name)
|
||||
FROM
|
||||
internal.media m
|
||||
internal.media AS m
|
||||
WHERE
|
||||
m.id = retrieve_file.id INTO _headers;
|
||||
PERFORM
|
||||
|
||||
@@ -1,90 +0,0 @@
|
||||
-- migrate:up
|
||||
ALTER TABLE internal.website
|
||||
ADD COLUMN title_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', title)) STORED;
|
||||
|
||||
CREATE OR REPLACE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
content_type,
|
||||
title,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_search -- New column
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
ADD COLUMN title_description_search TSVECTOR GENERATED ALWAYS AS (TO_TSVECTOR('english', COALESCE(title, '') || ' ' || COALESCE(meta_description, ''))) STORED;
|
||||
|
||||
CREATE OR REPLACE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_description_search -- New column
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.article;
|
||||
|
||||
CREATE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
DROP COLUMN title_description_search;
|
||||
|
||||
DROP VIEW api.website;
|
||||
|
||||
CREATE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
content_type,
|
||||
title,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
ALTER TABLE internal.website
|
||||
DROP COLUMN title_search;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
@@ -1,74 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE FUNCTION api.upload_file (BYTEA, OUT file_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_headers JSON := CURRENT_SETTING('request.headers', TRUE)::JSON;
|
||||
_website_id UUID := (_headers ->> 'x-website-id')::UUID;
|
||||
_mimetype TEXT := _headers ->> 'x-mimetype';
|
||||
_original_filename TEXT := _headers ->> 'x-original-filename';
|
||||
_allowed_mimetypes TEXT[] := ARRAY['image/png', 'image/jpeg', 'image/webp'];
|
||||
_max_file_size INT := 5 * 1024 * 1024;
|
||||
BEGIN
|
||||
IF OCTET_LENGTH($1) = 0 THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'No file data was provided';
|
||||
END IF;
|
||||
IF _mimetype IS NULL OR _mimetype NOT IN (
|
||||
SELECT
|
||||
UNNEST(_allowed_mimetypes)) THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp';
|
||||
END IF;
|
||||
IF OCTET_LENGTH($1) > _max_file_size THEN
|
||||
RAISE program_limit_exceeded
|
||||
USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024));
|
||||
END IF;
|
||||
INSERT INTO internal.media (website_id, blob, mimetype, original_name)
|
||||
VALUES (_website_id, $1, _mimetype, _original_filename)
|
||||
RETURNING
|
||||
id INTO file_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP FUNCTION api.upload_file (BYTEA);
|
||||
|
||||
CREATE FUNCTION api.upload_file (BYTEA, OUT file_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_headers JSON := CURRENT_SETTING('request.headers', TRUE)::JSON;
|
||||
_website_id UUID := (_headers ->> 'x-website-id')::UUID;
|
||||
_mimetype TEXT := _headers ->> 'x-mimetype';
|
||||
_original_filename TEXT := _headers ->> 'x-original-filename';
|
||||
_allowed_mimetypes TEXT[] := ARRAY['image/png', 'image/jpeg', 'image/webp'];
|
||||
_max_file_size INT := 5 * 1024 * 1024;
|
||||
BEGIN
|
||||
IF OCTET_LENGTH($1) = 0 THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'No file data was provided';
|
||||
END IF;
|
||||
IF _mimetype IS NULL OR _mimetype NOT IN (
|
||||
SELECT
|
||||
UNNEST(_allowed_mimetypes)) THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, svg, jpg, webp';
|
||||
END IF;
|
||||
IF OCTET_LENGTH($1) > _max_file_size THEN
|
||||
RAISE program_limit_exceeded
|
||||
USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024));
|
||||
END IF;
|
||||
INSERT INTO internal.media (website_id, blob, mimetype, original_name)
|
||||
VALUES (_website_id, $1, _mimetype, _original_filename)
|
||||
RETURNING
|
||||
id INTO file_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user;
|
||||
|
||||
@@ -1,120 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE TABLE internal.docs_category (
|
||||
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 DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID,
|
||||
category_name VARCHAR(50) NOT NULL CHECK (TRIM(category_name) != ''),
|
||||
category_weight INTEGER CHECK (category_weight >= 0) NOT NULL,
|
||||
UNIQUE (website_id, category_name),
|
||||
UNIQUE (website_id, category_weight)
|
||||
);
|
||||
|
||||
ALTER TABLE internal.website
|
||||
ADD COLUMN is_published BOOLEAN NOT NULL DEFAULT FALSE;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
ADD COLUMN category UUID REFERENCES internal.docs_category (id) ON DELETE SET NULL;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
ALTER COLUMN user_id SET DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
|
||||
|
||||
ALTER TABLE internal.docs_category ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE POLICY view_categories ON internal.docs_category
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_category ON internal.docs_category
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE POLICY delete_category ON internal.docs_category
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 20, article_user_id => user_id));
|
||||
|
||||
CREATE POLICY insert_category ON internal.docs_category
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 20));
|
||||
|
||||
CREATE VIEW api.docs_category WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
category_name,
|
||||
category_weight
|
||||
FROM
|
||||
internal.docs_category;
|
||||
|
||||
CREATE OR REPLACE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_description_search,
|
||||
category -- New column
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.docs_category TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.docs_category TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP POLICY view_categories ON internal.docs_category;
|
||||
|
||||
DROP POLICY update_category ON internal.docs_category;
|
||||
|
||||
DROP POLICY delete_category ON internal.docs_category;
|
||||
|
||||
DROP POLICY insert_category ON internal.docs_category;
|
||||
|
||||
DROP VIEW api.article;
|
||||
|
||||
CREATE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_description_search
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
DROP VIEW api.docs_category;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
DROP COLUMN category;
|
||||
|
||||
DROP TABLE internal.docs_category;
|
||||
|
||||
ALTER TABLE internal.website
|
||||
DROP COLUMN is_published;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
ALTER COLUMN user_id DROP DEFAULT;
|
||||
|
||||
@@ -1,108 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
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
|
||||
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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
@@ -1,56 +0,0 @@
|
||||
-- migrate:up
|
||||
ALTER TABLE internal.article
|
||||
ADD COLUMN article_weight INTEGER CHECK (article_weight IS NULL
|
||||
OR article_weight >= 0);
|
||||
|
||||
CREATE OR REPLACE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_description_search,
|
||||
category,
|
||||
article_weight -- New column
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.article;
|
||||
|
||||
CREATE VIEW api.article WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
website_id,
|
||||
user_id,
|
||||
title,
|
||||
meta_description,
|
||||
meta_author,
|
||||
cover_image,
|
||||
publication_date,
|
||||
main_content,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_description_search,
|
||||
category
|
||||
FROM
|
||||
internal.article;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
DROP COLUMN article_weight;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.article TO authenticated_user;
|
||||
|
||||
@@ -1,140 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC NULLS LAST
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
@@ -1,140 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
) ORDER BY a.article_weight DESC NULLS LAST
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC NULLS LAST
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC NULLS LAST
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
@@ -1,15 +0,0 @@
|
||||
-- migrate:up
|
||||
ALTER TABLE internal.article
|
||||
ALTER COLUMN publication_date DROP NOT NULL;
|
||||
|
||||
-- migrate:down
|
||||
UPDATE
|
||||
internal.article
|
||||
SET
|
||||
publication_date = CURRENT_DATE
|
||||
WHERE
|
||||
publication_date IS NULL;
|
||||
|
||||
ALTER TABLE internal.article
|
||||
ALTER COLUMN publication_date SET NOT NULL;
|
||||
|
||||
@@ -1,37 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
content_type,
|
||||
title,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_search,
|
||||
is_published -- New column
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website;
|
||||
|
||||
CREATE OR REPLACE VIEW api.website WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
id,
|
||||
user_id,
|
||||
content_type,
|
||||
title,
|
||||
created_at,
|
||||
last_modified_at,
|
||||
last_modified_by,
|
||||
title_search
|
||||
FROM
|
||||
internal.website;
|
||||
|
||||
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
|
||||
|
||||
@@ -1,76 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE FUNCTION api.upload_file (BYTEA, OUT file_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_headers JSON := CURRENT_SETTING('request.headers', TRUE)::JSON;
|
||||
_website_id UUID := (_headers ->> 'x-website-id')::UUID;
|
||||
_mimetype TEXT := _headers ->> 'x-mimetype';
|
||||
_original_filename TEXT := _headers ->> 'x-original-filename';
|
||||
_allowed_mimetypes TEXT[] := ARRAY['image/png', 'image/jpeg', 'image/webp'];
|
||||
_max_file_size INT := 5 * 1024 * 1024;
|
||||
_has_access BOOLEAN;
|
||||
BEGIN
|
||||
_has_access = internal.user_has_website_access (_website_id, 20);
|
||||
IF OCTET_LENGTH($1) = 0 THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'No file data was provided';
|
||||
END IF;
|
||||
IF _mimetype IS NULL OR _mimetype NOT IN (
|
||||
SELECT
|
||||
UNNEST(_allowed_mimetypes)) THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp';
|
||||
END IF;
|
||||
IF OCTET_LENGTH($1) > _max_file_size THEN
|
||||
RAISE program_limit_exceeded
|
||||
USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024));
|
||||
END IF;
|
||||
INSERT INTO internal.media (website_id, blob, mimetype, original_name)
|
||||
VALUES (_website_id, $1, _mimetype, _original_filename)
|
||||
RETURNING
|
||||
id INTO file_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP FUNCTION api.upload_file (BYTEA);
|
||||
|
||||
CREATE FUNCTION api.upload_file (BYTEA, OUT file_id UUID)
|
||||
AS $$
|
||||
DECLARE
|
||||
_headers JSON := CURRENT_SETTING('request.headers', TRUE)::JSON;
|
||||
_website_id UUID := (_headers ->> 'x-website-id')::UUID;
|
||||
_mimetype TEXT := _headers ->> 'x-mimetype';
|
||||
_original_filename TEXT := _headers ->> 'x-original-filename';
|
||||
_allowed_mimetypes TEXT[] := ARRAY['image/png', 'image/jpeg', 'image/webp'];
|
||||
_max_file_size INT := 5 * 1024 * 1024;
|
||||
BEGIN
|
||||
IF OCTET_LENGTH($1) = 0 THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'No file data was provided';
|
||||
END IF;
|
||||
IF _mimetype IS NULL OR _mimetype NOT IN (
|
||||
SELECT
|
||||
UNNEST(_allowed_mimetypes)) THEN
|
||||
RAISE invalid_parameter_value
|
||||
USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp';
|
||||
END IF;
|
||||
IF OCTET_LENGTH($1) > _max_file_size THEN
|
||||
RAISE program_limit_exceeded
|
||||
USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024));
|
||||
END IF;
|
||||
INSERT INTO internal.media (website_id, blob, mimetype, original_name)
|
||||
VALUES (_website_id, $1, _mimetype, _original_filename)
|
||||
RETURNING
|
||||
id INTO file_id;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql
|
||||
SECURITY DEFINER;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user;
|
||||
|
||||
@@ -1,55 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE TABLE internal.legal_information (
|
||||
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
|
||||
);
|
||||
|
||||
CREATE VIEW api.legal_information WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
website_id,
|
||||
main_content,
|
||||
last_modified_at,
|
||||
last_modified_by
|
||||
FROM
|
||||
internal.legal_information;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON internal.legal_information TO authenticated_user;
|
||||
|
||||
GRANT SELECT, INSERT, UPDATE, DELETE ON api.legal_information TO authenticated_user;
|
||||
|
||||
ALTER TABLE internal.legal_information ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE POLICY view_legal_information ON internal.legal_information
|
||||
FOR SELECT
|
||||
USING (internal.user_has_website_access (website_id, 10));
|
||||
|
||||
CREATE POLICY update_legal_information ON internal.legal_information
|
||||
FOR UPDATE
|
||||
USING (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
CREATE POLICY delete_legal_information ON internal.legal_information
|
||||
FOR DELETE
|
||||
USING (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
CREATE POLICY insert_legal_information ON internal.legal_information
|
||||
FOR INSERT
|
||||
WITH CHECK (internal.user_has_website_access (website_id, 30));
|
||||
|
||||
-- migrate:down
|
||||
DROP POLICY insert_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY delete_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY update_legal_information ON internal.legal_information;
|
||||
|
||||
DROP POLICY view_legal_information ON internal.legal_information;
|
||||
|
||||
ALTER TABLE internal.legal_information DISABLE ROW LEVEL SECURITY;
|
||||
|
||||
DROP VIEW api.legal_information;
|
||||
|
||||
DROP TABLE internal.legal_information;
|
||||
|
||||
@@ -1,142 +0,0 @@
|
||||
-- migrate:up
|
||||
CREATE OR REPLACE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
) ORDER BY a.article_weight DESC NULLS LAST
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC NULLS LAST
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_articles,
|
||||
li.main_content legal_information_main_content
|
||||
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
|
||||
LEFT JOIN internal.legal_information li ON w.id = li.website_id;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
-- migrate:down
|
||||
DROP VIEW api.website_overview;
|
||||
|
||||
CREATE VIEW api.website_overview WITH ( security_invoker = ON
|
||||
) AS
|
||||
SELECT
|
||||
w.id,
|
||||
w.user_id,
|
||||
w.content_type,
|
||||
w.title,
|
||||
s.accent_color_light_theme,
|
||||
s.accent_color_dark_theme,
|
||||
s.favicon_image,
|
||||
h.logo_type,
|
||||
h.logo_text,
|
||||
h.logo_image,
|
||||
ho.main_content,
|
||||
f.additional_text,
|
||||
(
|
||||
SELECT
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
)
|
||||
)
|
||||
FROM
|
||||
internal.article a
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
) AS articles,
|
||||
CASE WHEN w.content_type = 'Docs' THEN
|
||||
(
|
||||
SELECT
|
||||
JSON_OBJECT_AGG(
|
||||
COALESCE(
|
||||
category_name, 'Uncategorized'
|
||||
), articles
|
||||
)
|
||||
FROM (
|
||||
SELECT
|
||||
dc.category_name,
|
||||
dc.category_weight AS category_weight,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'id', a.id, '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, 'created_at', a.created_at, 'last_modified_at', a.last_modified_at
|
||||
) ORDER BY a.article_weight DESC NULLS LAST
|
||||
) AS articles
|
||||
FROM
|
||||
internal.article a
|
||||
LEFT JOIN internal.docs_category dc ON a.category = dc.id
|
||||
WHERE
|
||||
a.website_id = w.id
|
||||
GROUP BY
|
||||
dc.id,
|
||||
dc.category_name,
|
||||
dc.category_weight
|
||||
ORDER BY
|
||||
category_weight DESC NULLS LAST
|
||||
) AS categorized_articles)
|
||||
ELSE
|
||||
NULL
|
||||
END AS categorized_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;
|
||||
|
||||
GRANT SELECT ON api.website_overview TO authenticated_user;
|
||||
|
||||
Reference in New Issue
Block a user