diff --git a/.github/workflows/demo-server-deploy.yml b/.github/workflows/demo-server-deploy.yml index 08d9fda..1d79a3d 100644 --- a/.github/workflows/demo-server-deploy.yml +++ b/.github/workflows/demo-server-deploy.yml @@ -2,8 +2,8 @@ name: Deploy app to demo server (demo.archtika.com) on: workflow_run: - workflows: ['Playwright tests'] - types: [completed] + workflows: [ 'Playwright tests' ] + types: [ completed ] env: SERVER_USER: root SERVER_IP: 128.140.75.240 diff --git a/.github/workflows/playwright.yml b/.github/workflows/playwright.yml index 42f7764..a110f8e 100644 --- a/.github/workflows/playwright.yml +++ b/.github/workflows/playwright.yml @@ -2,8 +2,9 @@ name: Playwright tests on: push: - branches: - - main + branches: [ main ] + pull_request: + branches: [ main ] jobs: test: diff --git a/flake.nix b/flake.nix index e1dcdd7..da7d60f 100644 --- a/flake.nix +++ b/flake.nix @@ -27,6 +27,7 @@ shellHook = '' alias dbmate="${pkgs.dbmate}/bin/dbmate --no-dump-schema --url postgres://postgres@localhost:15432/archtika?sslmode=disable" alias formatsql="${pkgs.pgformatter}/bin/pg_format -s 2 -f 2 -U 2 -i db/migrations/*.sql" + alias dbconnect="${pkgs.postgresql_16}/bin/psql postgres://postgres@localhost:15432/archtika" ''; }; web = pkgs.mkShell { diff --git a/nix/demo-server/default.nix b/nix/demo-server/default.nix index 86b7fe7..db2b97b 100644 --- a/nix/demo-server/default.nix +++ b/nix/demo-server/default.nix @@ -23,7 +23,7 @@ nixpkgs.config.allowUnfree = true; networking = { - hostName = "archtika-demo-server"; + hostName = "archtika-qs"; networkmanager.enable = true; firewall = { allowedTCPPorts = [ @@ -65,8 +65,8 @@ services.archtika = { enable = true; package = localArchtikaPackage; - jwtSecret = "a42kVyAhTImYxZeebZkApoAZLmf0VtDA"; - domain = "demo.archtika.com"; + jwtSecret = /var/lib/archtika-jwt-secret.txt; + domain = "qs.archtika.com"; acmeEmail = "thilo.hohlt@tutanota.com"; dnsProvider = "porkbun"; dnsEnvironmentFile = /var/lib/porkbun.env; diff --git a/nix/demo-server/hardware-configuration.nix b/nix/demo-server/hardware-configuration.nix index b53eac3..1e06801 100644 --- a/nix/demo-server/hardware-configuration.nix +++ b/nix/demo-server/hardware-configuration.nix @@ -1,41 +1,32 @@ # Do not modify this file! It was generated by ‘nixos-generate-config’ # and may be overwritten by future invocations. Please make changes # to /etc/nixos/configuration.nix instead. -{ - config, - lib, - pkgs, - modulesPath, - ... -}: +{ config, lib, pkgs, modulesPath, ... }: { - imports = [ (modulesPath + "/profiles/qemu-guest.nix") ]; + imports = + [ (modulesPath + "/profiles/qemu-guest.nix") + ]; - boot.initrd.availableKernelModules = [ - "xhci_pci" - "virtio_scsi" - "sr_mod" - ]; + boot.initrd.availableKernelModules = [ "xhci_pci" "virtio_scsi" "sr_mod" ]; boot.initrd.kernelModules = [ ]; boot.kernelModules = [ ]; boot.extraModulePackages = [ ]; - fileSystems."/" = { - device = "/dev/disk/by-uuid/af7c3a41-3427-4354-8bf5-bd98698792c5"; - fsType = "ext4"; - }; + fileSystems."/" = + { device = "/dev/disk/by-uuid/04fa460b-c39f-47f8-bece-c044d767209c"; + fsType = "ext4"; + }; - fileSystems."/boot" = { - device = "/dev/disk/by-uuid/BA3C-CCAF"; - fsType = "vfat"; - options = [ - "fmask=0077" - "dmask=0077" + fileSystems."/boot" = + { device = "/dev/disk/by-uuid/BA11-3E3D"; + fsType = "vfat"; + options = [ "fmask=0077" "dmask=0077" ]; + }; + + swapDevices = + [ { device = "/dev/disk/by-uuid/abace260-6904-4b38-8532-0235f77cb2bf"; } ]; - }; - - swapDevices = [ { device = "/dev/disk/by-uuid/a58e9054-0b76-4da5-ae13-0d73515ec41e"; } ]; # Enables DHCP on each ethernet and wireless interface. In case of scripted networking # (the default) this is the recommended approach. When using systemd-networkd it's diff --git a/nix/dev-vm.nix b/nix/dev-vm.nix index 773664a..48bacd4 100644 --- a/nix/dev-vm.nix +++ b/nix/dev-vm.nix @@ -68,7 +68,7 @@ ]; locations = { "/" = { - root = "/var/www/archtika-websites"; + root = "/var/www/archtika-websites/"; index = "index.html"; tryFiles = "$uri $uri/ $uri.html $uri/index.html index.html =404"; extraConfig = '' diff --git a/rest-api/db/migrations/20240719071602_main_tables.sql b/rest-api/db/migrations/20240719071602_main_tables.sql index 6ec5c94..0a1ca79 100644 --- a/rest-api/db/migrations/20240719071602_main_tables.sql +++ b/rest-api/db/migrations/20240719071602_main_tables.sql @@ -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,14 +34,16 @@ 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 ( 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, + user_id UUID REFERENCES internal.user (id) ON DELETE SET NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID, blob BYTEA NOT NULL, mimetype TEXT NOT NULL, original_name TEXT NOT NULL, @@ -70,19 +76,35 @@ 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, + last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), + last_modified_by UUID REFERENCES internal.user (id) ON DELETE SET 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, 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, + UNIQUE (website_id, category, article_weight) ); CREATE TABLE internal.footer ( @@ -92,6 +114,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, @@ -102,25 +131,17 @@ CREATE TABLE internal.collab ( 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, - 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) -); - -- migrate:down -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 +152,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; + diff --git a/rest-api/db/migrations/20240720073454_automatic_schema_cache_reloading.sql b/rest-api/db/migrations/20240720073454_automatic_schema_cache_reloading.sql index 29cbcf9..83b1001 100644 --- a/rest-api/db/migrations/20240720073454_automatic_schema_cache_reloading.sql +++ b/rest-api/db/migrations/20240720073454_automatic_schema_cache_reloading.sql @@ -1,6 +1,6 @@ -- migrate:up CREATE FUNCTION pgrst_watch () - RETURNS event_trigger + RETURNS EVENT_TRIGGER AS $$ BEGIN NOTIFY pgrst, diff --git a/rest-api/db/migrations/20240720074103_user_management_roles_jwt.sql b/rest-api/db/migrations/20240720074103_user_management_roles_jwt.sql index c2a106e..a3c4505 100644 --- a/rest-api/db/migrations/20240720074103_user_management_roles_jwt.sql +++ b/rest-api/db/migrations/20240720074103_user_management_roles_jwt.sql @@ -7,18 +7,17 @@ CREATE FUNCTION internal.check_role_exists () RETURNS TRIGGER AS $$ BEGIN - IF NOT EXISTS ( + 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; + r.rolname = NEW.role)) THEN + RAISE foreign_key_violation + USING message = 'Unknown database role: ' || NEW.role; + END IF; + RETURN NULL; END $$ LANGUAGE plpgsql; @@ -45,23 +44,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 +66,47 @@ 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 + 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 + ELSIF (EXISTS ( + SELECT + 1 + FROM + internal.user AS u + WHERE + u.username = register.username)) THEN RAISE unique_violation USING message = 'Username is already taken'; + ELSIF (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); + ELSIF register.pass !~ '[a-z]' THEN + RAISE invalid_parameter_value + USING message = 'Password must contain at least one lowercase letter'; + ELSIF register.pass !~ '[A-Z]' THEN + RAISE invalid_parameter_value + USING message = 'Password must contain at least one uppercase letter'; + ELSIF register.pass !~ '[0-9]' THEN + RAISE invalid_parameter_value + USING message = 'Password must contain at least one number'; + ELSIF 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 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) +CREATE FUNCTION api.login (username TEXT, pass TEXT, OUT token TEXT) AS $$ DECLARE _role NAME; @@ -122,11 +114,11 @@ 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'; - END IF; + ELSE SELECT id INTO _user_id FROM @@ -136,26 +128,28 @@ BEGIN _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 IF; END; $$ 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'; - END IF; + ELSE DELETE FROM internal.user AS u WHERE u.username = _username; was_deleted := TRUE; + END IF; END; $$ LANGUAGE plpgsql @@ -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; diff --git a/rest-api/db/migrations/20240720132802_exposed_views_functions.sql b/rest-api/db/migrations/20240720132802_exposed_views_functions.sql index d273c65..1611e91 100644 --- a/rest-api/db/migrations/20240720132802_exposed_views_functions.sql +++ b/rest-api/db/migrations/20240720132802_exposed_views_functions.sql @@ -2,8 +2,7 @@ CREATE VIEW api.account WITH ( security_invoker = ON ) AS SELECT - id, - username + * FROM internal.user WHERE @@ -23,109 +22,72 @@ 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; - CREATE FUNCTION api.create_website (content_type VARCHAR(10), title VARCHAR(50), OUT website_id UUID) 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 +97,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 +109,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 `/`, 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 `/`, 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,29 +147,35 @@ 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; -GRANT SELECT ON internal.change_log TO authenticated_user; - -GRANT SELECT ON api.change_log TO authenticated_user; - -- migrate:down DROP FUNCTION api.create_website (VARCHAR(10), VARCHAR(50)); -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; diff --git a/rest-api/db/migrations/20240724191017_row_level_security.sql b/rest-api/db/migrations/20240724191017_row_level_security.sql index 071e102..ae41e55 100644 --- a/rest-api/db/migrations/20240724191017_row_level_security.sql +++ b/rest-api/db/migrations/20240724191017_row_level_security.sql @@ -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.'; + USING message = 'Insufficient permissions'; 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); @@ -79,14 +81,6 @@ CREATE POLICY delete_website ON internal.website 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)); - -CREATE POLICY insert_media ON internal.media - 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)); @@ -127,6 +121,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 +145,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)); @@ -160,10 +186,6 @@ 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; @@ -184,10 +206,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 +250,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; diff --git a/rest-api/db/migrations/20240803163047_website_overview_view.sql b/rest-api/db/migrations/20240803163047_website_overview_view.sql deleted file mode 100644 index 9978e88..0000000 --- a/rest-api/db/migrations/20240803163047_website_overview_view.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240805132306_last_modified_triggers.sql b/rest-api/db/migrations/20240805132306_last_modified_triggers.sql index a830e5a..ea8794b 100644 --- a/rest-api/db/migrations/20240805132306_last_modified_triggers.sql +++ b/rest-api/db/migrations/20240805132306_last_modified_triggers.sql @@ -2,35 +2,35 @@ CREATE FUNCTION internal.update_last_modified () RETURNS TRIGGER AS $$ +DECLARE + _user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID; BEGIN - NEW.last_modified_at = CLOCK_TIMESTAMP(); - NEW.last_modified_by = (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID; + IF (NOT EXISTS ( + SELECT + id + FROM + internal.user + WHERE + id = _user_id)) THEN + RETURN COALESCE(NEW, OLD); + END IF; + IF TG_OP != 'DELETE' THEN + NEW.last_modified_at = CLOCK_TIMESTAMP(); + NEW.last_modified_by = _user_id; + END IF; IF TG_TABLE_NAME != 'website' THEN UPDATE internal.website SET - last_modified_at = NEW.last_modified_at, - last_modified_by = NEW.last_modified_by + last_modified_at = CLOCK_TIMESTAMP(), + last_modified_by = _user_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; + id = COALESCE(NEW.website_id, OLD.website_id); END IF; - RETURN NEW; + RETURN COALESCE(NEW, OLD); END; $$ -LANGUAGE plpgsql -SECURITY DEFINER; +LANGUAGE plpgsql; CREATE TRIGGER update_website_last_modified BEFORE UPDATE ON internal.website @@ -57,13 +57,23 @@ CREATE TRIGGER update_article_last_modified FOR EACH ROW EXECUTE FUNCTION internal.update_last_modified (); +CREATE TRIGGER update_docs_category_modified + BEFORE INSERT OR UPDATE OR DELETE ON internal.docs_category + 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 (); +CREATE TRIGGER update_legal_information_last_modified + BEFORE INSERT 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 + BEFORE INSERT OR UPDATE OR DELETE ON internal.collab FOR EACH ROW EXECUTE FUNCTION internal.update_last_modified (); @@ -78,8 +88,12 @@ DROP TRIGGER update_home_last_modified ON internal.home; DROP TRIGGER update_article_last_modified ON internal.article; +DROP TRIGGER update_docs_category_modified ON internal.docs_category; + 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 (); diff --git a/rest-api/db/migrations/20240808141708_collaborator_not_owner.sql b/rest-api/db/migrations/20240808141708_collaborator_not_owner.sql index c9240eb..bf46316 100644 --- a/rest-api/db/migrations/20240808141708_collaborator_not_owner.sql +++ b/rest-api/db/migrations/20240808141708_collaborator_not_owner.sql @@ -3,22 +3,20 @@ CREATE FUNCTION internal.check_user_not_website_owner () RETURNS TRIGGER AS $$ BEGIN - IF EXISTS ( + IF (EXISTS ( SELECT 1 FROM - internal.website + internal.website AS w 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; + 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; + RETURN NULL; END; $$ -LANGUAGE plpgsql -SECURITY DEFINER; +LANGUAGE plpgsql; CREATE CONSTRAINT TRIGGER check_user_not_website_owner AFTER INSERT ON internal.collab diff --git a/rest-api/db/migrations/20240810115846_image_upload_function.sql b/rest-api/db/migrations/20240810115846_image_upload_function.sql index e0fbf25..e94d73a 100644 --- a/rest-api/db/migrations/20240810115846_image_upload_function.sql +++ b/rest-api/db/migrations/20240810115846_image_upload_function.sql @@ -10,25 +10,27 @@ 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'; + ELSIF (_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'; + ELSIF 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)); + ELSE + INSERT INTO internal.media (website_id, blob, mimetype, original_name) + VALUES (_website_id, $1, _mimetype, _original_filename) + RETURNING + id INTO file_id; 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 @@ -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 @@ -70,6 +72,8 @@ SECURITY DEFINER; GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user; +GRANT EXECUTE ON FUNCTION api.retrieve_file (UUID) TO anon; + GRANT EXECUTE ON FUNCTION api.retrieve_file (UUID) TO authenticated_user; -- migrate:down diff --git a/rest-api/db/migrations/20240814175120_full_text_search.sql b/rest-api/db/migrations/20240814175120_full_text_search.sql deleted file mode 100644 index 7a8e3a3..0000000 --- a/rest-api/db/migrations/20240814175120_full_text_search.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240825133549_adjust_upload_function.sql b/rest-api/db/migrations/20240825133549_adjust_upload_function.sql deleted file mode 100644 index 1723a01..0000000 --- a/rest-api/db/migrations/20240825133549_adjust_upload_function.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240827090504_categories_and_publication.sql b/rest-api/db/migrations/20240827090504_categories_and_publication.sql deleted file mode 100644 index a44ab59..0000000 --- a/rest-api/db/migrations/20240827090504_categories_and_publication.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240828132309_adjust_website_overview_view.sql b/rest-api/db/migrations/20240828132309_adjust_website_overview_view.sql deleted file mode 100644 index 75d7865..0000000 --- a/rest-api/db/migrations/20240828132309_adjust_website_overview_view.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240829085258_docs_articles_weight.sql b/rest-api/db/migrations/20240829085258_docs_articles_weight.sql deleted file mode 100644 index f61f7f2..0000000 --- a/rest-api/db/migrations/20240829085258_docs_articles_weight.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240829095918_adjust_website_overview.sql b/rest-api/db/migrations/20240829095918_adjust_website_overview.sql deleted file mode 100644 index 27583fd..0000000 --- a/rest-api/db/migrations/20240829095918_adjust_website_overview.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240829180521_adjust_website_overview_categorized_articles_sort.sql b/rest-api/db/migrations/20240829180521_adjust_website_overview_categorized_articles_sort.sql deleted file mode 100644 index e62b2b1..0000000 --- a/rest-api/db/migrations/20240829180521_adjust_website_overview_categorized_articles_sort.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240830062353_optional_publication_date.sql b/rest-api/db/migrations/20240830062353_optional_publication_date.sql deleted file mode 100644 index 8ab6c0b..0000000 --- a/rest-api/db/migrations/20240830062353_optional_publication_date.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240830112106_website_view_publication_status.sql b/rest-api/db/migrations/20240830112106_website_view_publication_status.sql deleted file mode 100644 index c305909..0000000 --- a/rest-api/db/migrations/20240830112106_website_view_publication_status.sql +++ /dev/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; - diff --git a/rest-api/db/migrations/20240901135831_restrict_file_operations.sql b/rest-api/db/migrations/20240901135831_restrict_file_operations.sql deleted file mode 100644 index 98ffa23..0000000 --- a/rest-api/db/migrations/20240901135831_restrict_file_operations.sql +++ /dev/null @@ -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; - diff --git a/rest-api/db/migrations/20240911070907_change_log.sql b/rest-api/db/migrations/20240911070907_change_log.sql new file mode 100644 index 0000000..be5574e --- /dev/null +++ b/rest-api/db/migrations/20240911070907_change_log.sql @@ -0,0 +1,149 @@ +-- migrate:up +CREATE EXTENSION hstore; + +CREATE TABLE internal.change_log ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid (), + website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE, + user_id UUID REFERENCES internal.user (id) ON DELETE SET NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id') ::UUID, + username VARCHAR(16) NOT NULL DEFAULT (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'username'), + tstamp TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), + table_name TEXT NOT NULL, + operation TEXT NOT NULL, + old_value HSTORE, + new_value HSTORE +); + +CREATE FUNCTION internal.track_changes () + RETURNS TRIGGER + AS $$ +DECLARE + _website_id UUID; + _user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID; +BEGIN + IF (NOT EXISTS ( + SELECT + id + FROM + internal.user + WHERE + id = _user_id) OR (to_jsonb (OLD.*) - 'last_modified_at' - 'last_modified_by') = (to_jsonb (NEW.*) - 'last_modified_at' - 'last_modified_by')) THEN + RETURN NULL; + END IF; + IF TG_TABLE_NAME = 'website' THEN + _website_id := NEW.id; + ELSE + _website_id := COALESCE(NEW.website_id, OLD.website_id); + END IF; + IF TG_OP = 'INSERT' THEN + INSERT INTO internal.change_log (website_id, table_name, operation, new_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (NEW)); + ELSIF (TG_OP = 'UPDATE' + AND EXISTS ( + SELECT + id + FROM + internal.website + WHERE + id = _website_id)) THEN + INSERT INTO internal.change_log (website_id, table_name, operation, old_value, new_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD) - HSTORE (NEW), HSTORE (NEW) - HSTORE (OLD)); + ELSIF (TG_OP = 'DELETE' + AND EXISTS ( + SELECT + id + FROM + internal.website + WHERE + id = _website_id)) THEN + INSERT INTO internal.change_log (website_id, table_name, operation, old_value) + VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD)); + END IF; + RETURN NULL; +END; +$$ +LANGUAGE plpgsql +SECURITY DEFINER; + +CREATE TRIGGER website_track_changes + AFTER UPDATE ON internal.website + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER settings_track_changes + AFTER UPDATE ON internal.settings + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER header_track_changes + AFTER UPDATE ON internal.header + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER home_track_changes + AFTER UPDATE ON internal.home + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER article_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.article + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER docs_category_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.docs_category + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER footer_track_changes + AFTER UPDATE ON internal.footer + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER legal_information_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.legal_information + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE TRIGGER collab_track_changes + AFTER INSERT OR UPDATE OR DELETE ON internal.collab + FOR EACH ROW + EXECUTE FUNCTION internal.track_changes (); + +CREATE VIEW api.change_log WITH ( security_invoker = ON +) AS +SELECT + * +FROM + internal.change_log; + +GRANT SELECT ON internal.change_log TO authenticated_user; + +GRANT SELECT ON api.change_log TO authenticated_user; + +-- migrate:down +DROP TRIGGER website_track_changes ON internal.website; + +DROP TRIGGER settings_track_changes ON internal.settings; + +DROP TRIGGER header_track_changes ON internal.header; + +DROP TRIGGER home_track_changes ON internal.home; + +DROP TRIGGER article_track_changes ON internal.article; + +DROP TRIGGER docs_category_track_changes ON internal.docs_category; + +DROP TRIGGER footer_track_changes ON internal.footer; + +DROP TRIGGER legal_information_track_changes ON internal.legal_information; + +DROP TRIGGER collab_track_changes ON internal.collab; + +DROP FUNCTION internal.track_changes (); + +DROP VIEW api.change_log; + +DROP TABLE internal.change_log; + +DROP EXTENSION hstore; + diff --git a/web-app/package-lock.json b/web-app/package-lock.json index 2346dee..97b6ede 100644 --- a/web-app/package-lock.json +++ b/web-app/package-lock.json @@ -8,7 +8,7 @@ "name": "web-app", "version": "0.0.1", "dependencies": { - "github-slugger": "2.0.0", + "fast-diff": "1.3.0", "highlight.js": "11.10.0", "isomorphic-dompurify": "2.14.0", "marked": "14.0.0", @@ -28,6 +28,7 @@ "eslint-config-prettier": "9.1.0", "eslint-plugin-svelte": "2.43.0", "globals": "15.9.0", + "pg-to-ts": "4.1.1", "prettier": "3.3.3", "prettier-plugin-svelte": "3.2.6", "svelte": "5.0.0-next.220", @@ -1631,6 +1632,16 @@ "dequal": "^2.0.3" } }, + "node_modules/assert-options": { + "version": "0.8.0", + "resolved": "https://registry.npmjs.org/assert-options/-/assert-options-0.8.0.tgz", + "integrity": "sha512-qSELrEaEz4sGwTs4Qh+swQkjiHAysC4rot21+jzXU86dJzNG+FDqBzyS3ohSoTRf4ZLA3FSwxQdiuNl5NXUtvA==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=10.0.0" + } + }, "node_modules/asynckit": { "version": "0.4.0", "resolved": "https://registry.npmjs.org/asynckit/-/asynckit-0.4.0.tgz", @@ -1700,6 +1711,16 @@ "node": ">=8.0.0" } }, + "node_modules/buffer-writer": { + "version": "2.0.0", + "resolved": "https://registry.npmjs.org/buffer-writer/-/buffer-writer-2.0.0.tgz", + "integrity": "sha512-a7ZpuTZU1TRtnwyCNW3I5dc0wWNC3VR9S++Ewyk2HHZdrO3CQJqSpd+95Us590V6AL7JqUAH2IwZ/398PmNFgw==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=4" + } + }, "node_modules/builtin-modules": { "version": "3.3.0", "resolved": "https://registry.npmjs.org/builtin-modules/-/builtin-modules-3.3.0.tgz", @@ -1781,6 +1802,100 @@ "fsevents": "~2.3.2" } }, + "node_modules/cliui": { + "version": "8.0.1", + "resolved": "https://registry.npmjs.org/cliui/-/cliui-8.0.1.tgz", + "integrity": "sha512-BSeNnyus75C4//NQ9gQt1/csTXyo/8Sb+afLAkzAptFuMsod9HFokGNudZpi/oQV73hnVK+sR+5PVRMd+Dr7YQ==", + "dev": true, + "license": "ISC", + "dependencies": { + "string-width": "^4.2.0", + "strip-ansi": "^6.0.1", + "wrap-ansi": "^7.0.0" + }, + "engines": { + "node": ">=12" + } + }, + "node_modules/cliui/node_modules/ansi-regex": { + "version": "5.0.1", + "resolved": "https://registry.npmjs.org/ansi-regex/-/ansi-regex-5.0.1.tgz", + "integrity": "sha512-quJQXlTSUGL2LH9SUXo8VwsY4soanhgo6LNSm84E1LBcE8s3O0wpdiRzyR9z/ZZJMlMWv37qOOb9pdJlMUEKFQ==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=8" + } + }, + "node_modules/cliui/node_modules/ansi-styles": { + "version": "4.3.0", + "resolved": "https://registry.npmjs.org/ansi-styles/-/ansi-styles-4.3.0.tgz", + "integrity": "sha512-zbB9rCJAT1rbjiVDb2hqKFHNYLxgtk8NURxZ3IZwD3F6NtxbXZQCnnSi1Lkx+IDohdPlFp222wVALIheZJQSEg==", + "dev": true, + "license": "MIT", + "dependencies": { + "color-convert": "^2.0.1" + }, + "engines": { + "node": ">=8" + }, + "funding": { + "url": "https://github.com/chalk/ansi-styles?sponsor=1" + } + }, + "node_modules/cliui/node_modules/emoji-regex": { + "version": "8.0.0", + "resolved": "https://registry.npmjs.org/emoji-regex/-/emoji-regex-8.0.0.tgz", + "integrity": "sha512-MSjYzcWNOA0ewAHpz0MxpYFvwg6yjy1NG3xteoqz644VCo/RPgnr1/GGt+ic3iJTzQ8Eu3TdM14SawnVUmGE6A==", + "dev": true, + "license": "MIT" + }, + "node_modules/cliui/node_modules/string-width": { + "version": "4.2.3", + "resolved": "https://registry.npmjs.org/string-width/-/string-width-4.2.3.tgz", + "integrity": "sha512-wKyQRQpjJ0sIp62ErSZdGsjMJWsap5oRNihHhu6G7JVO/9jIB6UyevL+tXuOqrng8j/cxKTWyWUwvSTriiZz/g==", + "dev": true, + "license": "MIT", + "dependencies": { + "emoji-regex": "^8.0.0", + "is-fullwidth-code-point": "^3.0.0", + "strip-ansi": "^6.0.1" + }, + "engines": { + "node": ">=8" + } + }, + "node_modules/cliui/node_modules/strip-ansi": { + "version": "6.0.1", + "resolved": "https://registry.npmjs.org/strip-ansi/-/strip-ansi-6.0.1.tgz", + "integrity": "sha512-Y38VPSHcqkFrCpFnQ9vuSXmquuv5oXOKpGeT6aGrr3o3Gc9AlVa6JBfUSOCnbxGGZF+/0ooI7KrPuUSztUdU5A==", + "dev": true, + "license": "MIT", + "dependencies": { + "ansi-regex": "^5.0.1" + }, + "engines": { + "node": ">=8" + } + }, + "node_modules/cliui/node_modules/wrap-ansi": { + "version": "7.0.0", + "resolved": "https://registry.npmjs.org/wrap-ansi/-/wrap-ansi-7.0.0.tgz", + "integrity": "sha512-YVGIj2kamLSTxw6NsZjoBxfSwsn0ycdesmc4p+Q21c5zPuZ1pl+NfxVdxPtdHvmNVOQ6XSYG4AUtyt/Fi7D16Q==", + "dev": true, + "license": "MIT", + "dependencies": { + "ansi-styles": "^4.0.0", + "string-width": "^4.1.0", + "strip-ansi": "^6.0.0" + }, + "engines": { + "node": ">=10" + }, + "funding": { + "url": "https://github.com/chalk/wrap-ansi?sponsor=1" + } + }, "node_modules/color-convert": { "version": "2.0.1", "resolved": "https://registry.npmjs.org/color-convert/-/color-convert-2.0.1.tgz", @@ -1813,6 +1928,20 @@ "node": ">= 0.8" } }, + "node_modules/commander": { + "version": "2.20.3", + "resolved": "https://registry.npmjs.org/commander/-/commander-2.20.3.tgz", + "integrity": "sha512-GpVkmM8vF2vQUkj2LvZmD35JxeJOLCwJ9cUkugyk2nuhbv3+mJvpLYYt+0+USMxE+oj+ey/lJEnhZw75x/OMcQ==", + "dev": true, + "license": "MIT" + }, + "node_modules/commandpost": { + "version": "1.4.0", + "resolved": "https://registry.npmjs.org/commandpost/-/commandpost-1.4.0.tgz", + "integrity": "sha512-aE2Y4MTFJ870NuB/+2z1cXBhSBBzRydVVjzhFC4gtenEhpnj15yu0qptWGJsO9YGrcPZ3ezX8AWb1VA391MKpQ==", + "dev": true, + "license": "MIT" + }, "node_modules/commondir": { "version": "1.0.1", "resolved": "https://registry.npmjs.org/commondir/-/commondir-1.0.1.tgz", @@ -1985,6 +2114,43 @@ "dev": true, "license": "MIT" }, + "node_modules/editorconfig": { + "version": "0.15.3", + "resolved": "https://registry.npmjs.org/editorconfig/-/editorconfig-0.15.3.tgz", + "integrity": "sha512-M9wIMFx96vq0R4F+gRpY3o2exzb8hEj/n9S8unZtHSvYjibBp/iMufSzvmOcV/laG0ZtuTVGtiJggPOSW2r93g==", + "dev": true, + "license": "MIT", + "dependencies": { + "commander": "^2.19.0", + "lru-cache": "^4.1.5", + "semver": "^5.6.0", + "sigmund": "^1.0.1" + }, + "bin": { + "editorconfig": "bin/editorconfig" + } + }, + "node_modules/editorconfig/node_modules/lru-cache": { + "version": "4.1.5", + "resolved": "https://registry.npmjs.org/lru-cache/-/lru-cache-4.1.5.tgz", + "integrity": "sha512-sWZlbEP2OsHNkXrMl5GYk/jKk70MBng6UU4YI/qGDYbgf6YbP4EvmqISbXCoJiRKs+1bSpFHVgQxvJ17F2li5g==", + "dev": true, + "license": "ISC", + "dependencies": { + "pseudomap": "^1.0.2", + "yallist": "^2.1.2" + } + }, + "node_modules/editorconfig/node_modules/semver": { + "version": "5.7.2", + "resolved": "https://registry.npmjs.org/semver/-/semver-5.7.2.tgz", + "integrity": "sha512-cBznnQ9KjJqU67B52RMC65CMarK2600WFnbkcaiwWq3xy/5haFJlshgnpjovMVJ+Hff49d8GEn0b87C5pDQ10g==", + "dev": true, + "license": "ISC", + "bin": { + "semver": "bin/semver" + } + }, "node_modules/emoji-regex": { "version": "9.2.2", "resolved": "https://registry.npmjs.org/emoji-regex/-/emoji-regex-9.2.2.tgz", @@ -2050,6 +2216,16 @@ "@esbuild/win32-x64": "0.21.5" } }, + "node_modules/escalade": { + "version": "3.2.0", + "resolved": "https://registry.npmjs.org/escalade/-/escalade-3.2.0.tgz", + "integrity": "sha512-WUj2qlxaQtO4g6Pq5c29GTcWGDyd8itL8zTlipgECz3JesAiiOKotd8JU6otB3PACgG6xkJUyVhboMS+bje/jA==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=6" + } + }, "node_modules/escape-string-regexp": { "version": "4.0.0", "resolved": "https://registry.npmjs.org/escape-string-regexp/-/escape-string-regexp-4.0.0.tgz", @@ -2373,6 +2549,12 @@ "dev": true, "license": "MIT" }, + "node_modules/fast-diff": { + "version": "1.3.0", + "resolved": "https://registry.npmjs.org/fast-diff/-/fast-diff-1.3.0.tgz", + "integrity": "sha512-VxPP4NqbUjj6MaAOafWeUn2cXWLcCtljklUtZf0Ind4XQ+QPtmA0b18zZy0jIQx+ExRVCR/ZQpBmik5lXshNsw==", + "license": "Apache-2.0" + }, "node_modules/fast-glob": { "version": "3.3.2", "resolved": "https://registry.npmjs.org/fast-glob/-/fast-glob-3.3.2.tgz", @@ -2541,11 +2723,15 @@ "url": "https://github.com/sponsors/ljharb" } }, - "node_modules/github-slugger": { - "version": "2.0.0", - "resolved": "https://registry.npmjs.org/github-slugger/-/github-slugger-2.0.0.tgz", - "integrity": "sha512-IaOQ9puYtjrkq7Y0Ygl9KDZnrf/aiUJYUpVf89y8kyaxbRG7Y1SrX/jaumrv81vc61+kiMempujsM3Yw7w5qcw==", - "license": "ISC" + "node_modules/get-caller-file": { + "version": "2.0.5", + "resolved": "https://registry.npmjs.org/get-caller-file/-/get-caller-file-2.0.5.tgz", + "integrity": "sha512-DyFP3BM/3YHTQOCUL/w0OZHR0lpKeGrxotcHWcqNEdnltqFwXVfhEBQ94eIo34AfQpo0rGki4cyIiftY06h2Fg==", + "dev": true, + "license": "ISC", + "engines": { + "node": "6.* || 8.* || >= 10.*" + } }, "node_modules/glob": { "version": "10.4.5", @@ -3077,6 +3263,13 @@ "url": "https://github.com/sponsors/sindresorhus" } }, + "node_modules/lodash": { + "version": "4.17.21", + "resolved": "https://registry.npmjs.org/lodash/-/lodash-4.17.21.tgz", + "integrity": "sha512-v2kDEe57lecTulaDIuNTPy3Ry4gLGJ6Z1O3vE1krgXZNrsQ+LFTGHVxVjcXPs17LhbZVGedAJv8XZ1tvj5FvSg==", + "dev": true, + "license": "MIT" + }, "node_modules/lodash.merge": { "version": "4.6.2", "resolved": "https://registry.npmjs.org/lodash.merge/-/lodash.merge-4.6.2.tgz", @@ -3361,6 +3554,13 @@ "dev": true, "license": "BlueOak-1.0.0" }, + "node_modules/packet-reader": { + "version": "1.0.0", + "resolved": "https://registry.npmjs.org/packet-reader/-/packet-reader-1.0.0.tgz", + "integrity": "sha512-HAKu/fG3HpHFO0AA8WE8q2g+gBJaZ9MG7fcKk+IJPLTGAD6Psw4443l+9DGRbOIh3/aXr7Phy0TjilYivJo5XQ==", + "dev": true, + "license": "MIT" + }, "node_modules/parent-module": { "version": "1.0.1", "resolved": "https://registry.npmjs.org/parent-module/-/parent-module-1.0.1.tgz", @@ -3440,6 +3640,142 @@ "url": "https://github.com/sponsors/isaacs" } }, + "node_modules/pg": { + "version": "8.8.0", + "resolved": "https://registry.npmjs.org/pg/-/pg-8.8.0.tgz", + "integrity": "sha512-UXYN0ziKj+AeNNP7VDMwrehpACThH7LUl/p8TDFpEUuSejCUIwGSfxpHsPvtM6/WXFy6SU4E5RG4IJV/TZAGjw==", + "dev": true, + "license": "MIT", + "dependencies": { + "buffer-writer": "2.0.0", + "packet-reader": "1.0.0", + "pg-connection-string": "^2.5.0", + "pg-pool": "^3.5.2", + "pg-protocol": "^1.5.0", + "pg-types": "^2.1.0", + "pgpass": "1.x" + }, + "engines": { + "node": ">= 8.0.0" + }, + "peerDependencies": { + "pg-native": ">=3.0.1" + }, + "peerDependenciesMeta": { + "pg-native": { + "optional": true + } + } + }, + "node_modules/pg-connection-string": { + "version": "2.6.4", + "resolved": "https://registry.npmjs.org/pg-connection-string/-/pg-connection-string-2.6.4.tgz", + "integrity": "sha512-v+Z7W/0EO707aNMaAEfiGnGL9sxxumwLl2fJvCQtMn9Fxsg+lPpPkdcyBSv/KFgpGdYkMfn+EI1Or2EHjpgLCA==", + "dev": true, + "license": "MIT" + }, + "node_modules/pg-int8": { + "version": "1.0.1", + "resolved": "https://registry.npmjs.org/pg-int8/-/pg-int8-1.0.1.tgz", + "integrity": "sha512-WCtabS6t3c8SkpDBUlb1kjOs7l66xsGdKpIPZsg4wR+B3+u9UAum2odSsF9tnvxg80h4ZxLWMy4pRjOsFIqQpw==", + "dev": true, + "license": "ISC", + "engines": { + "node": ">=4.0.0" + } + }, + "node_modules/pg-minify": { + "version": "1.6.2", + "resolved": "https://registry.npmjs.org/pg-minify/-/pg-minify-1.6.2.tgz", + "integrity": "sha512-1KdmFGGTP6jplJoI8MfvRlfvMiyBivMRP7/ffh4a11RUFJ7kC2J0ZHlipoKiH/1hz+DVgceon9U2qbaHpPeyPg==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=8.0" + } + }, + "node_modules/pg-pool": { + "version": "3.6.2", + "resolved": "https://registry.npmjs.org/pg-pool/-/pg-pool-3.6.2.tgz", + "integrity": "sha512-Htjbg8BlwXqSBQ9V8Vjtc+vzf/6fVUuak/3/XXKA9oxZprwW3IMDQTGHP+KDmVL7rtd+R1QjbnCFPuTHm3G4hg==", + "dev": true, + "license": "MIT", + "peerDependencies": { + "pg": ">=8.0" + } + }, + "node_modules/pg-promise": { + "version": "10.15.4", + "resolved": "https://registry.npmjs.org/pg-promise/-/pg-promise-10.15.4.tgz", + "integrity": "sha512-BKlHCMCdNUmF6gagVbehRWSEiVcZzPVltEx14OJExR9Iz9/1R6KETDWLLGv2l6yRqYFnEZZy1VDjRhArzeIGrw==", + "dev": true, + "license": "MIT", + "dependencies": { + "assert-options": "0.8.0", + "pg": "8.8.0", + "pg-minify": "1.6.2", + "spex": "3.2.0" + }, + "engines": { + "node": ">=12.0" + } + }, + "node_modules/pg-protocol": { + "version": "1.6.1", + "resolved": "https://registry.npmjs.org/pg-protocol/-/pg-protocol-1.6.1.tgz", + "integrity": "sha512-jPIlvgoD63hrEuihvIg+tJhoGjUsLPn6poJY9N5CnlPd91c2T18T/9zBtLxZSb1EhYxBRoZJtzScCaWlYLtktg==", + "dev": true, + "license": "MIT" + }, + "node_modules/pg-to-ts": { + "version": "4.1.1", + "resolved": "https://registry.npmjs.org/pg-to-ts/-/pg-to-ts-4.1.1.tgz", + "integrity": "sha512-wc/ZXMMQrxu42mnl6eEdMgT31S9rvA/Oh9I9PchovUwoJLzEg0osGQjxiQOLjAdz3Ti45o749XREJ2s+xncZ6w==", + "dev": true, + "license": "MIT", + "dependencies": { + "lodash": "^4.17.21", + "pg-promise": "^10.11.1", + "typescript-formatter": "^7.0.1", + "yargs": "^17.3.1" + }, + "bin": { + "pg-to-ts": "dist/cli.js" + }, + "engines": { + "node": ">=8.15.1" + }, + "peerDependencies": { + "typescript": ">=4.1" + } + }, + "node_modules/pg-types": { + "version": "2.2.0", + "resolved": "https://registry.npmjs.org/pg-types/-/pg-types-2.2.0.tgz", + "integrity": "sha512-qTAAlrEsl8s4OiEQY69wDvcMIdQN6wdz5ojQiOy6YRMuynxenON0O5oCpJI6lshc6scgAY8qvJ2On/p+CXY0GA==", + "dev": true, + "license": "MIT", + "dependencies": { + "pg-int8": "1.0.1", + "postgres-array": "~2.0.0", + "postgres-bytea": "~1.0.0", + "postgres-date": "~1.0.4", + "postgres-interval": "^1.1.0" + }, + "engines": { + "node": ">=4" + } + }, + "node_modules/pgpass": { + "version": "1.0.5", + "resolved": "https://registry.npmjs.org/pgpass/-/pgpass-1.0.5.tgz", + "integrity": "sha512-FdW9r/jQZhSeohs1Z3sI1yxFQNFvMcnmfuj4WBMUTxOrAyLMaTcE1aAMBiTlbMNaXvBCQuVi0R7hd8udDSP7ug==", + "dev": true, + "license": "MIT", + "dependencies": { + "split2": "^4.1.0" + } + }, "node_modules/picocolors": { "version": "1.0.1", "resolved": "https://registry.npmjs.org/picocolors/-/picocolors-1.0.1.tgz", @@ -3624,6 +3960,49 @@ "node": ">=4" } }, + "node_modules/postgres-array": { + "version": "2.0.0", + "resolved": "https://registry.npmjs.org/postgres-array/-/postgres-array-2.0.0.tgz", + "integrity": "sha512-VpZrUqU5A69eQyW2c5CA1jtLecCsN2U/bD6VilrFDWq5+5UIEVO7nazS3TEcHf1zuPYO/sqGvUvW62g86RXZuA==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=4" + } + }, + "node_modules/postgres-bytea": { + "version": "1.0.0", + "resolved": "https://registry.npmjs.org/postgres-bytea/-/postgres-bytea-1.0.0.tgz", + "integrity": "sha512-xy3pmLuQqRBZBXDULy7KbaitYqLcmxigw14Q5sj8QBVLqEwXfeybIKVWiqAXTlcvdvb0+xkOtDbfQMOf4lST1w==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=0.10.0" + } + }, + "node_modules/postgres-date": { + "version": "1.0.7", + "resolved": "https://registry.npmjs.org/postgres-date/-/postgres-date-1.0.7.tgz", + "integrity": "sha512-suDmjLVQg78nMK2UZ454hAG+OAW+HQPZ6n++TNDUX+L0+uUlLywnoxJKDou51Zm+zTCjrCl0Nq6J9C5hP9vK/Q==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=0.10.0" + } + }, + "node_modules/postgres-interval": { + "version": "1.2.0", + "resolved": "https://registry.npmjs.org/postgres-interval/-/postgres-interval-1.2.0.tgz", + "integrity": "sha512-9ZhXKM/rw350N1ovuWHbGxnGh/SNJ4cnxHiM0rxE4VN41wsg8P8zWn9hv/buK00RP4WvlOyr/RBDiptyxVbkZQ==", + "dev": true, + "license": "MIT", + "dependencies": { + "xtend": "^4.0.0" + }, + "engines": { + "node": ">=0.10.0" + } + }, "node_modules/prelude-ls": { "version": "1.2.1", "resolved": "https://registry.npmjs.org/prelude-ls/-/prelude-ls-1.2.1.tgz", @@ -3661,6 +4040,13 @@ "svelte": "^3.2.0 || ^4.0.0-next.0 || ^5.0.0-next.0" } }, + "node_modules/pseudomap": { + "version": "1.0.2", + "resolved": "https://registry.npmjs.org/pseudomap/-/pseudomap-1.0.2.tgz", + "integrity": "sha512-b/YwNhb8lk1Zz2+bXXpS/LK9OisiZZ1SNsSLxN1x2OXVEhW2Ckr/7mWE5vrC1ZTiJlD9g19jWszTmJsB+oEpFQ==", + "dev": true, + "license": "ISC" + }, "node_modules/psl": { "version": "1.9.0", "resolved": "https://registry.npmjs.org/psl/-/psl-1.9.0.tgz", @@ -3716,6 +4102,16 @@ "node": ">=8.10.0" } }, + "node_modules/require-directory": { + "version": "2.1.1", + "resolved": "https://registry.npmjs.org/require-directory/-/require-directory-2.1.1.tgz", + "integrity": "sha512-fGxEI7+wsG9xrvdjsrlmL22OMTTiHRwAMroiEeMgq8gzoLC/PQr7RsRDSTLUg/bZAZtF+TVIkHc6/4RIKrui+Q==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=0.10.0" + } + }, "node_modules/requires-port": { "version": "1.0.0", "resolved": "https://registry.npmjs.org/requires-port/-/requires-port-1.0.0.tgz", @@ -3974,6 +4370,13 @@ "node": ">=8" } }, + "node_modules/sigmund": { + "version": "1.0.1", + "resolved": "https://registry.npmjs.org/sigmund/-/sigmund-1.0.1.tgz", + "integrity": "sha512-fCvEXfh6NWpm+YSuY2bpXb/VIihqWA6hLsgboC+0nl71Q7N7o2eaCW8mJa/NLvQhs6jpd3VZV4UiUQlV6+lc8g==", + "dev": true, + "license": "ISC" + }, "node_modules/signal-exit": { "version": "4.1.0", "resolved": "https://registry.npmjs.org/signal-exit/-/signal-exit-4.1.0.tgz", @@ -4028,6 +4431,26 @@ "node": ">=0.10.0" } }, + "node_modules/spex": { + "version": "3.2.0", + "resolved": "https://registry.npmjs.org/spex/-/spex-3.2.0.tgz", + "integrity": "sha512-9srjJM7NaymrpwMHvSmpDeIK5GoRMX/Tq0E8aOlDPS54dDnDUIp30DrP9SphMPEETDLzEM9+4qo+KipmbtPecg==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=4.5" + } + }, + "node_modules/split2": { + "version": "4.2.0", + "resolved": "https://registry.npmjs.org/split2/-/split2-4.2.0.tgz", + "integrity": "sha512-UcjcJOWknrNkF6PLX83qcHM6KHgVKNkV62Y8a5uYDVv9ydGQVwAHMKqHdJje1VTWpljG0WYpCDhrCdAOYH4TWg==", + "dev": true, + "license": "ISC", + "engines": { + "node": ">= 10.x" + } + }, "node_modules/string-width": { "version": "5.1.2", "resolved": "https://registry.npmjs.org/string-width/-/string-width-5.1.2.tgz", @@ -4517,6 +4940,26 @@ } } }, + "node_modules/typescript-formatter": { + "version": "7.2.2", + "resolved": "https://registry.npmjs.org/typescript-formatter/-/typescript-formatter-7.2.2.tgz", + "integrity": "sha512-V7vfI9XArVhriOTYHPzMU2WUnm5IMdu9X/CPxs8mIMGxmTBFpDABlbkBka64PZJ9/xgQeRpK8KzzAG4MPzxBDQ==", + "dev": true, + "license": "MIT", + "dependencies": { + "commandpost": "^1.0.0", + "editorconfig": "^0.15.0" + }, + "bin": { + "tsfmt": "bin/tsfmt" + }, + "engines": { + "node": ">= 4.2.0" + }, + "peerDependencies": { + "typescript": "^2.1.6 || >=2.7.0-dev || >=2.8.0-dev || >=2.9.0-dev || >=3.0.0-dev" + } + }, "node_modules/undici-types": { "version": "6.13.0", "resolved": "https://registry.npmjs.org/undici-types/-/undici-types-6.13.0.tgz", @@ -4857,6 +5300,33 @@ "integrity": "sha512-JZnDKK8B0RCDw84FNdDAIpZK+JuJw+s7Lz8nksI7SIuU3UXJJslUthsi+uWBUYOwPFwW7W7PRLRfUKpxjtjFCw==", "license": "MIT" }, + "node_modules/xtend": { + "version": "4.0.2", + "resolved": "https://registry.npmjs.org/xtend/-/xtend-4.0.2.tgz", + "integrity": "sha512-LKYU1iAXJXUgAXn9URjiu+MWhyUXHsvfp7mcuYm9dSUKK0/CjtrUwFAxD82/mCWbtLsGjFIad0wIsod4zrTAEQ==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=0.4" + } + }, + "node_modules/y18n": { + "version": "5.0.8", + "resolved": "https://registry.npmjs.org/y18n/-/y18n-5.0.8.tgz", + "integrity": "sha512-0pfFzegeDWJHJIAmTLRP2DwHjdF5s7jo9tuztdQxAhINCdvS+3nGINqPd00AphqJR/0LhANUS6/+7SCb98YOfA==", + "dev": true, + "license": "ISC", + "engines": { + "node": ">=10" + } + }, + "node_modules/yallist": { + "version": "2.1.2", + "resolved": "https://registry.npmjs.org/yallist/-/yallist-2.1.2.tgz", + "integrity": "sha512-ncTzHV7NvsQZkYe1DW7cbDLm0YpzHmZF5r/iyP3ZnQtMiJ+pjzisCiMNI+Sj+xQF5pXhSHxSB3uDbsBTzY/c2A==", + "dev": true, + "license": "ISC" + }, "node_modules/yaml": { "version": "1.10.2", "resolved": "https://registry.npmjs.org/yaml/-/yaml-1.10.2.tgz", @@ -4867,6 +5337,80 @@ "node": ">= 6" } }, + "node_modules/yargs": { + "version": "17.7.2", + "resolved": "https://registry.npmjs.org/yargs/-/yargs-17.7.2.tgz", + "integrity": "sha512-7dSzzRQ++CKnNI/krKnYRV7JKKPUXMEh61soaHKg9mrWEhzFWhFnxPxGl+69cD1Ou63C13NUPCnmIcrvqCuM6w==", + "dev": true, + "license": "MIT", + "dependencies": { + "cliui": "^8.0.1", + "escalade": "^3.1.1", + "get-caller-file": "^2.0.5", + "require-directory": "^2.1.1", + "string-width": "^4.2.3", + "y18n": "^5.0.5", + "yargs-parser": "^21.1.1" + }, + "engines": { + "node": ">=12" + } + }, + "node_modules/yargs-parser": { + "version": "21.1.1", + "resolved": "https://registry.npmjs.org/yargs-parser/-/yargs-parser-21.1.1.tgz", + "integrity": "sha512-tVpsJW7DdjecAiFpbIB1e3qxIQsE6NoPc5/eTdrbbIC4h0LVsWhnoa3g+m2HclBIujHzsxZ4VJVA+GUuc2/LBw==", + "dev": true, + "license": "ISC", + "engines": { + "node": ">=12" + } + }, + "node_modules/yargs/node_modules/ansi-regex": { + "version": "5.0.1", + "resolved": "https://registry.npmjs.org/ansi-regex/-/ansi-regex-5.0.1.tgz", + "integrity": "sha512-quJQXlTSUGL2LH9SUXo8VwsY4soanhgo6LNSm84E1LBcE8s3O0wpdiRzyR9z/ZZJMlMWv37qOOb9pdJlMUEKFQ==", + "dev": true, + "license": "MIT", + "engines": { + "node": ">=8" + } + }, + "node_modules/yargs/node_modules/emoji-regex": { + "version": "8.0.0", + "resolved": "https://registry.npmjs.org/emoji-regex/-/emoji-regex-8.0.0.tgz", + "integrity": "sha512-MSjYzcWNOA0ewAHpz0MxpYFvwg6yjy1NG3xteoqz644VCo/RPgnr1/GGt+ic3iJTzQ8Eu3TdM14SawnVUmGE6A==", + "dev": true, + "license": "MIT" + }, + "node_modules/yargs/node_modules/string-width": { + "version": "4.2.3", + "resolved": "https://registry.npmjs.org/string-width/-/string-width-4.2.3.tgz", + "integrity": "sha512-wKyQRQpjJ0sIp62ErSZdGsjMJWsap5oRNihHhu6G7JVO/9jIB6UyevL+tXuOqrng8j/cxKTWyWUwvSTriiZz/g==", + "dev": true, + "license": "MIT", + "dependencies": { + "emoji-regex": "^8.0.0", + "is-fullwidth-code-point": "^3.0.0", + "strip-ansi": "^6.0.1" + }, + "engines": { + "node": ">=8" + } + }, + "node_modules/yargs/node_modules/strip-ansi": { + "version": "6.0.1", + "resolved": "https://registry.npmjs.org/strip-ansi/-/strip-ansi-6.0.1.tgz", + "integrity": "sha512-Y38VPSHcqkFrCpFnQ9vuSXmquuv5oXOKpGeT6aGrr3o3Gc9AlVa6JBfUSOCnbxGGZF+/0ooI7KrPuUSztUdU5A==", + "dev": true, + "license": "MIT", + "dependencies": { + "ansi-regex": "^5.0.1" + }, + "engines": { + "node": ">=8" + } + }, "node_modules/yocto-queue": { "version": "0.1.0", "resolved": "https://registry.npmjs.org/yocto-queue/-/yocto-queue-0.1.0.tgz", diff --git a/web-app/package.json b/web-app/package.json index 524b70b..44c0c95 100644 --- a/web-app/package.json +++ b/web-app/package.json @@ -10,7 +10,8 @@ "check": "svelte-kit sync && svelte-check --tsconfig ./tsconfig.json", "check:watch": "svelte-kit sync && svelte-check --tsconfig ./tsconfig.json --watch", "lint": "prettier --check . && eslint .", - "format": "prettier --write ." + "format": "prettier --write .", + "gents": "pg-to-ts generate -c postgres://postgres@localhost:15432/archtika -o src/lib/db-schema.ts -s internal" }, "devDependencies": { "@playwright/test": "1.40.0", @@ -26,6 +27,7 @@ "eslint-config-prettier": "9.1.0", "eslint-plugin-svelte": "2.43.0", "globals": "15.9.0", + "pg-to-ts": "4.1.1", "prettier": "3.3.3", "prettier-plugin-svelte": "3.2.6", "svelte": "5.0.0-next.220", @@ -36,7 +38,7 @@ }, "type": "module", "dependencies": { - "github-slugger": "2.0.0", + "fast-diff": "1.3.0", "highlight.js": "11.10.0", "isomorphic-dompurify": "2.14.0", "marked": "14.0.0", diff --git a/web-app/src/app.d.ts b/web-app/src/app.d.ts index fd9a3e9..1966d68 100644 --- a/web-app/src/app.d.ts +++ b/web-app/src/app.d.ts @@ -1,9 +1,6 @@ // See https://kit.svelte.dev/docs/types#app // for information about these interfaces -interface User { - id: string; - username: string; -} +import type { User } from "$lib/db-schema"; declare global { namespace App { diff --git a/web-app/src/hooks.server.ts b/web-app/src/hooks.server.ts index b30a999..51a677c 100644 --- a/web-app/src/hooks.server.ts +++ b/web-app/src/hooks.server.ts @@ -1,5 +1,6 @@ import { redirect } from "@sveltejs/kit"; import { API_BASE_PREFIX } from "$lib/server/utils"; +import type { User } from "$lib/db-schema"; export const handle = async ({ event, resolve }) => { if (!event.url.pathname.startsWith("/api/")) { @@ -21,7 +22,7 @@ export const handle = async ({ event, resolve }) => { throw redirect(303, "/"); } - const user = await userData.json(); + const user: User = await userData.json(); event.locals.user = user; } diff --git a/web-app/src/lib/components/DateTime.svelte b/web-app/src/lib/components/DateTime.svelte index d569147..b2ba649 100644 --- a/web-app/src/lib/components/DateTime.svelte +++ b/web-app/src/lib/components/DateTime.svelte @@ -1,5 +1,5 @@ {text} -