Ability to bulk import or export articles as gzip, handle domain prefix logic in API and other smaller improvements

This commit is contained in:
thiloho
2024-10-30 21:33:44 +01:00
parent f7180ebd92
commit 037165947b
32 changed files with 409 additions and 223 deletions

View File

@@ -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;

View File

@@ -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 $$

View File

@@ -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;

View File

@@ -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;

View File

@@ -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;

View File

@@ -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;