From 9c293d100b5836e770ea2db0eaa9d8b373cf495f Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sat, 26 Oct 2024 23:39:02 +0200 Subject: [PATCH 01/11] Trigger actions From cc3381d1ad1a8a2712424195aae32f7e959c1181 Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 00:24:02 +0200 Subject: [PATCH 02/11] Trigger actions From 2f9d49daa8fbb3e53a38d0aa706316a320565537 Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 00:47:34 +0200 Subject: [PATCH 03/11] Trigger actions From 99699e7b8ba65b615035e927ce042eb21252f9b9 Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 01:35:10 +0200 Subject: [PATCH 04/11] Trigger actions From c33d563bb79d1301172c4e58dc8fff69c81dda9e Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 01:50:42 +0200 Subject: [PATCH 05/11] Trigger actions From 924c000f4be95a79ee849d22fcc99177c0b42447 Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 02:01:18 +0200 Subject: [PATCH 06/11] Trigger actions From f7180ebd92c5adba57cdf6c494e338beb840f9ae Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Sun, 27 Oct 2024 02:11:10 +0200 Subject: [PATCH 07/11] Use single worker for more reliable tests --- web-app/playwright.config.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/web-app/playwright.config.ts b/web-app/playwright.config.ts index 89f8750..1204801 100644 --- a/web-app/playwright.config.ts +++ b/web-app/playwright.config.ts @@ -11,6 +11,7 @@ const config: PlaywrightTestConfig = { }, testDir: "./tests", testMatch: /(.+\.)?(test|spec)\.ts/, + workers: 1, retries: 3, // https://github.com/NixOS/nixpkgs/issues/288826 projects: [ From 037165947b0e4dab316399312ee13f50feade39d Mon Sep 17 00:00:00 2001 From: thiloho <123883702+thiloho@users.noreply.github.com> Date: Wed, 30 Oct 2024 21:33:44 +0100 Subject: [PATCH 08/11] Ability to bulk import or export articles as gzip, handle domain prefix logic in API and other smaller improvements --- nix/dev-vm.nix | 8 ++ nix/module.nix | 8 ++ .../migrations/20240719071602_main_tables.sql | 21 ++- .../20240810115846_image_upload_function.sql | 2 +- .../20240920090915_custom_domain_prefix.sql | 75 +++++++++-- .../20241006165029_administrator.sql | 4 +- .../20241011092744_filesystem_triggers.sql | 23 +++- .../20241029160539_export_articles.sql | 49 +++++++ web-app/package.json | 2 +- web-app/src/lib/components/DateTime.svelte | 34 +++-- web-app/src/lib/components/Modal.svelte | 8 ++ web-app/src/lib/db-schema.ts | 83 ++++++------ .../src/lib/templates/blog/BlogArticle.svelte | 1 + .../src/lib/templates/blog/BlogIndex.svelte | 4 +- web-app/src/lib/templates/common/Head.svelte | 6 +- web-app/src/lib/templates/common/Nav.svelte | 8 +- .../src/lib/templates/docs/DocsArticle.svelte | 1 + web-app/src/lib/utils.ts | 2 +- .../routes/(authenticated)/+page.server.ts | 17 +-- .../src/routes/(authenticated)/+page.svelte | 8 +- .../(authenticated)/account/+page.server.ts | 2 +- .../(authenticated)/manage/+page.server.ts | 4 +- .../[websiteId]/articles/+page.server.ts | 21 +++ .../website/[websiteId]/articles/+page.svelte | 60 +++++++-- .../[websiteId]/categories/+page.svelte | 9 +- .../legal-information/+page.server.ts | 8 +- .../website/[websiteId]/logs/+page.svelte | 19 ++- .../[websiteId]/publish/+page.server.ts | 126 +++++------------- .../website/[websiteId]/publish/+page.svelte | 2 +- web-app/template-styles/common-styles.css | 6 + web-app/tests/articles.spec.ts | 9 +- web-app/tests/manage.spec.ts | 2 +- 32 files changed, 409 insertions(+), 223 deletions(-) create mode 100644 rest-api/db/migrations/20241029160539_export_articles.sql diff --git a/nix/dev-vm.nix b/nix/dev-vm.nix index 42aef6c..c54902c 100644 --- a/nix/dev-vm.nix +++ b/nix/dev-vm.nix @@ -99,6 +99,14 @@ }; }; + systemd.services.postgresql = { + path = with pkgs; [ + # Tar and gzip are needed for tar.gz exports + gnutar + gzip + ]; + }; + services.getty.autologinUser = "dev"; system.stateVersion = "24.05"; diff --git a/nix/module.nix b/nix/module.nix index 84eeb8e..ffdf468 100644 --- a/nix/module.nix +++ b/nix/module.nix @@ -169,6 +169,14 @@ in extraPlugins = with pkgs.postgresql16Packages; [ pgjwt ]; }; + systemd.services.postgresql = { + path = with pkgs; [ + # Tar and gzip are needed for tar.gz exports + gnutar + gzip + ]; + }; + services.nginx = { enable = true; recommendedProxySettings = true; diff --git a/rest-api/db/migrations/20240719071602_main_tables.sql b/rest-api/db/migrations/20240719071602_main_tables.sql index fd0ef7c..aadffe2 100644 --- a/rest-api/db/migrations/20240719071602_main_tables.sql +++ b/rest-api/db/migrations/20240719071602_main_tables.sql @@ -1,4 +1,6 @@ -- migrate:up +CREATE EXTENSION unaccent; + CREATE SCHEMA internal; CREATE SCHEMA api; @@ -27,6 +29,17 @@ GRANT USAGE ON SCHEMA internal TO authenticated_user; ALTER DEFAULT PRIVILEGES REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC; +CREATE FUNCTION internal.immutable_unaccent (TEXT) + RETURNS TEXT + AS $$ + SELECT + unaccent ($1); +$$ +LANGUAGE sql +IMMUTABLE; + +GRANT EXECUTE ON FUNCTION internal.immutable_unaccent TO authenticated_user; + CREATE TABLE internal.user ( id UUID PRIMARY KEY DEFAULT gen_random_uuid (), username VARCHAR(16) UNIQUE NOT NULL CHECK (LENGTH(username) >= 3 AND username ~ '^[a-zA-Z0-9_-]+$'), @@ -91,7 +104,7 @@ 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_name VARCHAR(50) NOT NULL CHECK (TRIM(category_name) != '' AND category_name != 'Uncategorized'), category_weight INT CHECK (category_weight >= 0) NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), last_modified_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(), @@ -105,6 +118,7 @@ CREATE TABLE internal.article ( 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, title VARCHAR(100) NOT NULL CHECK (TRIM(title) != ''), + slug VARCHAR(100) GENERATED ALWAYS AS (REGEXP_REPLACE(REGEXP_REPLACE(REGEXP_REPLACE(REGEXP_REPLACE(LOWER(TRIM(REGEXP_REPLACE(internal.immutable_unaccent (title), '\s+', '-', 'g'))), '[^\w-]', '', 'g'), '-+', '-', 'g'), '^-+', '', 'g'), '-+$', '', 'g')) STORED, 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, @@ -115,6 +129,7 @@ CREATE TABLE internal.article ( 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, + UNIQUE (website_id, slug), UNIQUE (website_id, category, article_weight) ); @@ -168,6 +183,8 @@ DROP TABLE internal.user; DROP SCHEMA api; +DROP FUNCTION internal.immutable_unaccent; + DROP SCHEMA internal; DROP ROLE anon; @@ -180,3 +197,5 @@ DROP ROLE authenticator; ALTER DEFAULT PRIVILEGES GRANT EXECUTE ON FUNCTIONS TO PUBLIC; +DROP EXTENSION unaccent; + diff --git a/rest-api/db/migrations/20240810115846_image_upload_function.sql b/rest-api/db/migrations/20240810115846_image_upload_function.sql index a3e9495..b6668b8 100644 --- a/rest-api/db/migrations/20240810115846_image_upload_function.sql +++ b/rest-api/db/migrations/20240810115846_image_upload_function.sql @@ -1,5 +1,5 @@ -- migrate:up -CREATE DOMAIN "*/*" AS bytea; +CREATE DOMAIN "*/*" AS BYTEA; CREATE FUNCTION api.upload_file (BYTEA, OUT file_id UUID) AS $$ diff --git a/rest-api/db/migrations/20240920090915_custom_domain_prefix.sql b/rest-api/db/migrations/20240920090915_custom_domain_prefix.sql index cfdd78f..b7a96d5 100644 --- a/rest-api/db/migrations/20240920090915_custom_domain_prefix.sql +++ b/rest-api/db/migrations/20240920090915_custom_domain_prefix.sql @@ -1,7 +1,7 @@ -- migrate:up CREATE TABLE internal.domain_prefix ( website_id UUID PRIMARY KEY REFERENCES internal.website (id) ON DELETE CASCADE, - prefix VARCHAR(16) UNIQUE NOT NULL CHECK (LENGTH(prefix) >= 3 AND prefix ~ '^[a-z]+(-[a-z]+)*$'), + prefix VARCHAR(16) UNIQUE NOT NULL CHECK (LENGTH(prefix) >= 3 AND prefix ~ '^[a-z]+(-[a-z]+)*$' AND prefix != 'previews'), 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 @@ -14,9 +14,9 @@ SELECT FROM internal.domain_prefix; -GRANT SELECT, INSERT (website_id, prefix), UPDATE (website_id, prefix), DELETE ON internal.domain_prefix TO authenticated_user; +GRANT SELECT ON internal.domain_prefix TO authenticated_user; -GRANT SELECT, INSERT, UPDATE, DELETE ON api.domain_prefix TO authenticated_user; +GRANT SELECT ON api.domain_prefix TO authenticated_user; ALTER TABLE internal.domain_prefix ENABLE ROW LEVEL SECURITY; @@ -24,17 +24,64 @@ CREATE POLICY view_domain_prefix ON internal.domain_prefix FOR SELECT USING (internal.user_has_website_access (website_id, 10)); -CREATE POLICY update_domain_prefix ON internal.domain_prefix - FOR UPDATE - USING (internal.user_has_website_access (website_id, 30)); +CREATE FUNCTION api.set_domain_prefix (website_id UUID, prefix VARCHAR(16), OUT was_set BOOLEAN) +AS $$ +DECLARE + _has_access BOOLEAN; + _old_domain_prefix VARCHAR(16); + _base_path CONSTANT TEXT := '/var/www/archtika-websites/'; + _old_path TEXT; + _new_path TEXT; +BEGIN + _has_access = internal.user_has_website_access (set_domain_prefix.website_id, 30); + SELECT + d.prefix INTO _old_domain_prefix + FROM + internal.domain_prefix AS d + WHERE + d.website_id = set_domain_prefix.website_id; + INSERT INTO internal.domain_prefix (website_id, prefix) + VALUES (set_domain_prefix.website_id, set_domain_prefix.prefix) + ON CONFLICT ON CONSTRAINT domain_prefix_pkey + DO UPDATE SET + prefix = EXCLUDED.prefix; + _old_path = _base_path || COALESCE(_old_domain_prefix, set_domain_prefix.website_id::TEXT); + _new_path = _base_path || set_domain_prefix.prefix; + IF _old_path != _new_path THEN + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''mv -T %s %s''', _old_path, _new_path); + END IF; + was_set := TRUE; +END; +$$ +LANGUAGE plpgsql +SECURITY DEFINER; -CREATE POLICY delete_domain_prefix ON internal.domain_prefix - FOR DELETE - USING (internal.user_has_website_access (website_id, 30)); +GRANT EXECUTE ON FUNCTION api.set_domain_prefix TO authenticated_user; -CREATE POLICY insert_domain_prefix ON internal.domain_prefix - FOR INSERT - WITH CHECK (internal.user_has_website_access (website_id, 30)); +CREATE FUNCTION api.delete_domain_prefix (website_id UUID, OUT was_deleted BOOLEAN) +AS $$ +DECLARE + _has_access BOOLEAN; + _old_domain_prefix VARCHAR(16); + _base_path CONSTANT TEXT := '/var/www/archtika-websites/'; + _old_path TEXT; + _new_path TEXT; +BEGIN + _has_access = internal.user_has_website_access (delete_domain_prefix.website_id, 30); + DELETE FROM internal.domain_prefix AS d + WHERE d.website_id = delete_domain_prefix.website_id + RETURNING + prefix INTO _old_domain_prefix; + _old_path = _base_path || _old_domain_prefix; + _new_path = _base_path || delete_domain_prefix.website_id; + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''mv -T %s %s''', _old_path, _new_path); + was_deleted := TRUE; +END; +$$ +LANGUAGE plpgsql +SECURITY DEFINER; + +GRANT EXECUTE ON FUNCTION api.delete_domain_prefix TO authenticated_user; CREATE TRIGGER update_domain_prefix_last_modified BEFORE INSERT OR UPDATE OR DELETE ON internal.domain_prefix @@ -51,6 +98,10 @@ DROP TRIGGER track_changes_domain_prefix ON internal.domain_prefix; DROP TRIGGER update_domain_prefix_last_modified ON internal.domain_prefix; +DROP FUNCTION api.set_domain_prefix; + +DROP FUNCTION api.delete_domain_prefix; + DROP VIEW api.domain_prefix; DROP TABLE internal.domain_prefix; diff --git a/rest-api/db/migrations/20241006165029_administrator.sql b/rest-api/db/migrations/20241006165029_administrator.sql index 4e28b0b..3d151f7 100644 --- a/rest-api/db/migrations/20241006165029_administrator.sql +++ b/rest-api/db/migrations/20241006165029_administrator.sql @@ -42,9 +42,7 @@ BEGIN w.user_id = $1 GROUP BY w.id, - w.title - ORDER BY - storage_size_bytes DESC', _union_queries); + w.title', _union_queries); RETURN QUERY EXECUTE _query USING _user_id; END; diff --git a/rest-api/db/migrations/20241011092744_filesystem_triggers.sql b/rest-api/db/migrations/20241011092744_filesystem_triggers.sql index 7c396f5..52fe174 100644 --- a/rest-api/db/migrations/20241011092744_filesystem_triggers.sql +++ b/rest-api/db/migrations/20241011092744_filesystem_triggers.sql @@ -8,6 +8,7 @@ DECLARE _base_path CONSTANT TEXT := '/var/www/archtika-websites/'; _preview_path TEXT; _prod_path TEXT; + _article_slug TEXT; BEGIN IF TG_TABLE_NAME = 'website' THEN _website_id := OLD.id; @@ -17,7 +18,7 @@ BEGIN SELECT d.prefix INTO _domain_prefix FROM - internal.domain_prefix d + internal.domain_prefix AS d WHERE d.website_id = _website_id; _preview_path := _base_path || 'previews/' || _website_id; @@ -25,11 +26,20 @@ BEGIN IF TG_TABLE_NAME = 'website' THEN EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -rf %s''', _preview_path); EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -rf %s''', _prod_path); - ELSE + ELSIF TG_TABLE_NAME = 'article' THEN + SELECT + a.slug INTO _article_slug + FROM + internal.article AS a + WHERE + a.id = OLD.id; + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -f %s/articles/%s.html''', _preview_path, _article_slug); + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -f %s/articles/%s.html''', _prod_path, _article_slug); + ELSIF TG_TABLE_NAME = 'legal_information' THEN EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -f %s/legal-information.html''', _preview_path); EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''rm -f %s/legal-information.html''', _prod_path); END IF; - RETURN OLD; + RETURN COALESCE(NEW, OLD); END; $$ LANGUAGE plpgsql @@ -40,6 +50,11 @@ CREATE TRIGGER _cleanup_filesystem_website FOR EACH ROW EXECUTE FUNCTION internal.cleanup_filesystem (); +CREATE TRIGGER _cleanup_filesystem_article + BEFORE UPDATE OR DELETE ON internal.article + FOR EACH ROW + EXECUTE FUNCTION internal.cleanup_filesystem (); + CREATE TRIGGER _cleanup_filesystem_legal_information BEFORE DELETE ON internal.legal_information FOR EACH ROW @@ -48,6 +63,8 @@ CREATE TRIGGER _cleanup_filesystem_legal_information -- migrate:down DROP TRIGGER _cleanup_filesystem_website ON internal.website; +DROP TRIGGER _cleanup_filesystem_article ON internal.article; + DROP TRIGGER _cleanup_filesystem_legal_information ON internal.legal_information; DROP FUNCTION internal.cleanup_filesystem; diff --git a/rest-api/db/migrations/20241029160539_export_articles.sql b/rest-api/db/migrations/20241029160539_export_articles.sql new file mode 100644 index 0000000..a4eb7a2 --- /dev/null +++ b/rest-api/db/migrations/20241029160539_export_articles.sql @@ -0,0 +1,49 @@ +-- migrate:up +CREATE FUNCTION api.export_articles_zip (website_id UUID) + RETURNS "*/*" + AS $$ +DECLARE + _has_access BOOLEAN; + _headers TEXT; + _article RECORD; + _markdown_dir TEXT := '/tmp/website-' || export_articles_zip.website_id; +BEGIN + _has_access = internal.user_has_website_access (export_articles_zip.website_id, 20); + + SELECT + FORMAT('[{ "Content-Type": "application/gzip" },' + '{ "Content-Disposition": "attachment; filename=\"%s\"" }]', + 'archtika-export-articles-' || export_articles_zip.website_id || '.tar.gz') INTO _headers; + PERFORM + SET_CONFIG('response.headers', _headers, TRUE); + + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''mkdir -p %s''', _markdown_dir || '/articles'); + + FOR _article IN ( + SELECT a.id, a.website_id, a.slug, a.main_content + FROM internal.article AS a + WHERE a.website_id = export_articles_zip.website_id) + LOOP + EXECUTE FORMAT( + 'COPY (SELECT %L) TO ''%s''', + _article.main_content, + _markdown_dir || '/articles/' || _article.slug || '.md' + ); + END LOOP; + + EXECUTE FORMAT('COPY (SELECT '''') TO PROGRAM ''tar -czf %s -C %s articles && rm %s''', + _markdown_dir || '/export.tar.gz', + _markdown_dir, + _markdown_dir || '/articles/*.md' + ); + + RETURN pg_read_binary_file(_markdown_dir || '/export.tar.gz'); +END; +$$ +LANGUAGE plpgsql +SECURITY DEFINER; + +GRANT EXECUTE ON FUNCTION api.export_articles_zip TO authenticated_user; + +-- migrate:down +DROP FUNCTION api.export_articles_zip; diff --git a/web-app/package.json b/web-app/package.json index 8715dbd..352d9bb 100644 --- a/web-app/package.json +++ b/web-app/package.json @@ -11,7 +11,7 @@ "check:watch": "svelte-kit sync && svelte-check --tsconfig ./tsconfig.json --watch", "lint": "prettier --check . && eslint .", "format": "prettier --write .", - "gents": "pg-to-ts generate -c postgres://postgres@localhost:15432/archtika -o src/lib/db-schema.ts -s internal" + "gents": "pg-to-ts generate -c postgres://postgres@localhost:15432/archtika -o src/lib/db-schema.ts -s internal --datesAsStrings" }, "devDependencies": { "@playwright/test": "1.47.0", diff --git a/web-app/src/lib/components/DateTime.svelte b/web-app/src/lib/components/DateTime.svelte index b2ba649..3682077 100644 --- a/web-app/src/lib/components/DateTime.svelte +++ b/web-app/src/lib/components/DateTime.svelte @@ -1,16 +1,30 @@ -