Serve and create images from within postgresql

This commit is contained in:
thiloho
2024-08-10 17:09:12 +02:00
parent 77338f9cc2
commit 0866e2631d
9 changed files with 158 additions and 171 deletions

View File

@@ -38,8 +38,9 @@ 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,
blob BYTEA NOT NULL,
mimetype TEXT NOT NULL,
original_name TEXT NOT NULL,
file_system_path TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP()
);

View File

@@ -33,18 +33,6 @@ SELECT
FROM
internal.website;
CREATE VIEW api.media WITH ( security_invoker = ON
) AS
SELECT
id,
website_id,
user_id,
original_name,
file_system_path,
created_at
FROM
internal.media;
CREATE VIEW api.settings WITH ( security_invoker = ON
) AS
SELECT
@@ -183,10 +171,6 @@ GRANT SELECT, UPDATE, DELETE ON internal.website TO authenticated_user;
GRANT SELECT, UPDATE, DELETE ON api.website TO authenticated_user;
GRANT SELECT, INSERT ON internal.media TO authenticated_user;
GRANT SELECT, INSERT ON api.media TO authenticated_user;
GRANT SELECT, UPDATE ON internal.settings TO authenticated_user;
GRANT SELECT, UPDATE ON api.settings TO authenticated_user;
@@ -216,24 +200,6 @@ GRANT SELECT ON internal.change_log TO authenticated_user;
GRANT SELECT ON api.change_log TO authenticated_user;
-- migrate:down
REVOKE SELECT ON internal.user FROM authenticated_user;
REVOKE SELECT, UPDATE, DELETE ON internal.website FROM authenticated_user;
REVOKE SELECT, INSERT ON internal.media FROM authenticated_user;
REVOKE SELECT, UPDATE ON internal.settings FROM authenticated_user;
REVOKE SELECT, UPDATE ON internal.header FROM authenticated_user;
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.article FROM authenticated_user;
REVOKE SELECT, UPDATE ON internal.footer FROM authenticated_user;
REVOKE SELECT, INSERT, UPDATE, DELETE ON internal.collab FROM authenticated_user;
REVOKE SELECT ON internal.change_log FROM authenticated_user;
DROP FUNCTION api.create_website (VARCHAR(10), VARCHAR(50));
DROP VIEW api.change_log;
@@ -250,8 +216,6 @@ DROP VIEW api.header;
DROP VIEW api.settings;
DROP VIEW api.media;
DROP VIEW api.website;
DROP VIEW api.user;

View File

@@ -36,7 +36,5 @@ FROM
GRANT SELECT ON api.website_overview TO authenticated_user;
-- migrate:down
REVOKE SELECT ON api.website_overview FROM authenticated_user;
DROP VIEW api.website_overview;

View File

@@ -0,0 +1,77 @@
-- migrate:up
CREATE DOMAIN "*/*" AS 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/svg+xml', 'image/jpeg', 'image/webp'];
_max_file_size INT := 5 * 1024 * 1024;
BEGIN
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;
CREATE FUNCTION api.retrieve_file (id UUID)
RETURNS "*/*"
AS $$
DECLARE
_headers TEXT;
_blob BYTEA;
BEGIN
SELECT
FORMAT('[{ "Content-Type": "%s" },'
'{ "Content-Disposition": "inline; filename=\"%s\"" },'
'{ "Cache-Control": "max-age=259200" }]', m.mimetype, m.original_name)
FROM
internal.media m
WHERE
m.id = retrieve_file.id INTO _headers;
PERFORM
SET_CONFIG('response.headers', _headers, TRUE);
SELECT
m.blob
FROM
internal.media m
WHERE
m.id = retrieve_file.id INTO _blob;
IF FOUND THEN
RETURN _blob;
ELSE
RAISE invalid_parameter_value
USING message = 'Invalid file id';
END IF;
END;
$$
LANGUAGE plpgsql
SECURITY DEFINER;
GRANT EXECUTE ON FUNCTION api.upload_file (BYTEA) TO authenticated_user;
GRANT EXECUTE ON FUNCTION api.retrieve_file (UUID) TO authenticated_user;
-- migrate:down
DROP FUNCTION api.upload_file (BYTEA);
DROP FUNCTION api.retrieve_file (UUID);
DROP DOMAIN "*/*";