Show logs and usernames for deleted users and remove svg mimetype for client side

This commit is contained in:
thiloho
2024-09-14 15:12:08 +02:00
parent 79d1c9f5c7
commit 5f38500b9c
11 changed files with 119 additions and 95 deletions

View File

@@ -43,7 +43,7 @@ CREATE TABLE internal.website (
CREATE TABLE internal.media ( CREATE TABLE internal.media (
id UUID PRIMARY KEY DEFAULT gen_random_uuid (), id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE NOT NULL, 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, blob BYTEA NOT NULL,
mimetype TEXT NOT NULL, mimetype TEXT NOT NULL,
original_name TEXT NOT NULL, original_name TEXT NOT NULL,

View File

@@ -7,18 +7,17 @@ CREATE FUNCTION internal.check_role_exists ()
RETURNS TRIGGER RETURNS TRIGGER
AS $$ AS $$
BEGIN BEGIN
IF NOT EXISTS ( IF (NOT EXISTS (
SELECT SELECT
1 1
FROM FROM
pg_roles AS r pg_roles AS r
WHERE WHERE
r.rolname = NEW.role) THEN r.rolname = NEW.role)) THEN
RAISE foreign_key_violation RAISE foreign_key_violation
USING message = 'Unknown database role: ' || NEW.role; USING message = 'Unknown database role: ' || NEW.role;
END IF;
RETURN NULL; RETURN NULL;
END IF;
RETURN NEW;
END END
$$ $$
LANGUAGE plpgsql; LANGUAGE plpgsql;
@@ -67,43 +66,42 @@ DECLARE
_password_length_min CONSTANT INT := 12; _password_length_min CONSTANT INT := 12;
_password_length_max CONSTANT INT := 128; _password_length_max CONSTANT INT := 128;
BEGIN BEGIN
CASE WHEN LENGTH(register.username) IF (LENGTH(register.username)
NOT BETWEEN _username_length_min AND _username_length_max THEN NOT BETWEEN _username_length_min AND _username_length_max) THEN
RAISE string_data_length_mismatch RAISE string_data_length_mismatch
USING message = FORMAT('Username must be between %s and %s characters long', _username_length_min, _username_length_max); USING message = FORMAT('Username must be between %s and %s characters long', _username_length_min, _username_length_max);
WHEN EXISTS ( ELSIF (EXISTS (
SELECT SELECT
1 1
FROM FROM
internal.user AS u internal.user AS u
WHERE WHERE
u.username = register.username) THEN u.username = register.username)) THEN
RAISE unique_violation RAISE unique_violation
USING message = 'Username is already taken'; USING message = 'Username is already taken';
WHEN LENGTH(register.pass) NOT BETWEEN _password_length_min AND _password_length_max THEN ELSIF (LENGTH(register.pass)
NOT BETWEEN _password_length_min AND _password_length_max) THEN
RAISE string_data_length_mismatch RAISE string_data_length_mismatch
USING message = FORMAT('Password must be between %s and %s characters long', _password_length_min, _password_length_max); USING message = FORMAT('Password must be between %s and %s characters long', _password_length_min, _password_length_max);
WHEN register.pass !~ '[a-z]' THEN ELSIF register.pass !~ '[a-z]' THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'Password must contain at least one lowercase letter'; USING message = 'Password must contain at least one lowercase letter';
WHEN register.pass !~ '[A-Z]' THEN ELSIF register.pass !~ '[A-Z]' THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'Password must contain at least one uppercase letter'; USING message = 'Password must contain at least one uppercase letter';
WHEN register.pass !~ '[0-9]' THEN ELSIF register.pass !~ '[0-9]' THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'Password must contain at least one number'; USING message = 'Password must contain at least one number';
WHEN register.pass !~ '[!@#$%^&*(),.?":{}|<>]' THEN ELSIF register.pass !~ '[!@#$%^&*(),.?":{}|<>]' THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'Password must contain at least one special character'; USING message = 'Password must contain at least one special character';
ELSE ELSE
INSERT INSERT INTO internal.user (username, password_hash)
INTO internal.user (username, password_hash)
VALUES (register.username, register.pass) VALUES (register.username, register.pass)
RETURNING RETURNING
id INTO user_id; id INTO user_id;
END END IF;
CASE; END;
END;
$$ $$
LANGUAGE plpgsql LANGUAGE plpgsql
SECURITY DEFINER; SECURITY DEFINER;
@@ -120,7 +118,7 @@ BEGIN
IF _role IS NULL THEN IF _role IS NULL THEN
RAISE invalid_password RAISE invalid_password
USING message = 'Invalid username or password'; USING message = 'Invalid username or password';
END IF; ELSE
SELECT SELECT
id INTO _user_id id INTO _user_id
FROM FROM
@@ -130,6 +128,7 @@ BEGIN
_exp := EXTRACT(EPOCH FROM CLOCK_TIMESTAMP())::INTEGER + 86400; _exp := EXTRACT(EPOCH FROM CLOCK_TIMESTAMP())::INTEGER + 86400;
SELECT SELECT
SIGN(JSON_BUILD_OBJECT('role', _role, 'user_id', _user_id, 'username', login.username, 'exp', _exp), CURRENT_SETTING('app.jwt_secret')) INTO token; 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; END;
$$ $$
LANGUAGE plpgsql LANGUAGE plpgsql
@@ -146,10 +145,11 @@ BEGIN
IF _role IS NULL THEN IF _role IS NULL THEN
RAISE invalid_password RAISE invalid_password
USING message = 'Invalid password'; USING message = 'Invalid password';
END IF; ELSE
DELETE FROM internal.user AS u DELETE FROM internal.user AS u
WHERE u.username = _username; WHERE u.username = _username;
was_deleted := TRUE; was_deleted := TRUE;
END IF;
END; END;
$$ $$
LANGUAGE plpgsql LANGUAGE plpgsql

View File

@@ -2,19 +2,32 @@
CREATE FUNCTION internal.update_last_modified () CREATE FUNCTION internal.update_last_modified ()
RETURNS TRIGGER RETURNS TRIGGER
AS $$ AS $$
DECLARE
_user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
BEGIN BEGIN
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_at = CLOCK_TIMESTAMP();
NEW.last_modified_by = (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID; NEW.last_modified_by = _user_id;
END IF;
IF TG_TABLE_NAME != 'website' THEN IF TG_TABLE_NAME != 'website' THEN
UPDATE UPDATE
internal.website internal.website
SET SET
last_modified_at = CLOCK_TIMESTAMP(), last_modified_at = CLOCK_TIMESTAMP(),
last_modified_by = (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID last_modified_by = _user_id
WHERE WHERE
id = COALESCE(NEW.website_id, OLD.website_id); id = COALESCE(NEW.website_id, OLD.website_id);
END IF; END IF;
RETURN NEW; RETURN COALESCE(NEW, OLD);
END; END;
$$ $$
LANGUAGE plpgsql; LANGUAGE plpgsql;

View File

@@ -3,18 +3,17 @@ CREATE FUNCTION internal.check_user_not_website_owner ()
RETURNS TRIGGER RETURNS TRIGGER
AS $$ AS $$
BEGIN BEGIN
IF EXISTS ( IF (EXISTS (
SELECT SELECT
1 1
FROM FROM
internal.website AS w internal.website AS w
WHERE WHERE
w.id = NEW.website_id w.id = NEW.website_id AND w.user_id = NEW.user_id)) THEN
AND w.user_id = NEW.user_id) THEN
RAISE foreign_key_violation RAISE foreign_key_violation
USING message = 'User cannot be added as a collaborator to their own website'; USING message = 'User cannot be added as a collaborator to their own website';
END IF; END IF;
RETURN NEW; RETURN NULL;
END; END;
$$ $$
LANGUAGE plpgsql; LANGUAGE plpgsql;

View File

@@ -16,21 +16,21 @@ BEGIN
IF OCTET_LENGTH($1) = 0 THEN IF OCTET_LENGTH($1) = 0 THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'No file data was provided'; USING message = 'No file data was provided';
END IF; ELSIF (_mimetype IS NULL
IF _mimetype IS NULL OR _mimetype NOT IN ( OR _mimetype NOT IN (
SELECT SELECT
UNNEST(_allowed_mimetypes)) THEN UNNEST(_allowed_mimetypes))) THEN
RAISE invalid_parameter_value RAISE invalid_parameter_value
USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp'; USING message = 'Invalid MIME type. Allowed types are: png, jpg, webp';
END IF; ELSIF OCTET_LENGTH($1) > _max_file_size THEN
IF OCTET_LENGTH($1) > _max_file_size THEN
RAISE program_limit_exceeded RAISE program_limit_exceeded
USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024)); USING message = FORMAT('File size exceeds the maximum limit of %s MB', _max_file_size / (1024 * 1024));
END IF; ELSE
INSERT INTO internal.media (website_id, blob, mimetype, original_name) INSERT INTO internal.media (website_id, blob, mimetype, original_name)
VALUES (_website_id, $1, _mimetype, _original_filename) VALUES (_website_id, $1, _mimetype, _original_filename)
RETURNING RETURNING
id INTO file_id; id INTO file_id;
END IF;
END; END;
$$ $$
LANGUAGE plpgsql LANGUAGE plpgsql

View File

@@ -4,7 +4,8 @@ CREATE EXTENSION hstore;
CREATE TABLE internal.change_log ( CREATE TABLE internal.change_log (
id UUID PRIMARY KEY DEFAULT gen_random_uuid (), id UUID PRIMARY KEY DEFAULT gen_random_uuid (),
website_id UUID REFERENCES internal.website (id) ON DELETE CASCADE, 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, 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(), tstamp TIMESTAMPTZ NOT NULL DEFAULT CLOCK_TIMESTAMP(),
table_name TEXT NOT NULL, table_name TEXT NOT NULL,
operation TEXT NOT NULL, operation TEXT NOT NULL,
@@ -17,9 +18,16 @@ CREATE FUNCTION internal.track_changes ()
AS $$ AS $$
DECLARE DECLARE
_website_id UUID; _website_id UUID;
_user_id UUID := (CURRENT_SETTING('request.jwt.claims', TRUE)::JSON ->> 'user_id')::UUID;
BEGIN BEGIN
IF (to_jsonb (OLD.*) - 'last_modified_at') = (to_jsonb (NEW.*) - 'last_modified_at') THEN IF (NOT EXISTS (
RETURN NEW; 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; END IF;
IF TG_TABLE_NAME = 'website' THEN IF TG_TABLE_NAME = 'website' THEN
_website_id := NEW.id; _website_id := NEW.id;
@@ -29,31 +37,28 @@ BEGIN
IF TG_OP = 'INSERT' THEN IF TG_OP = 'INSERT' THEN
INSERT INTO internal.change_log (website_id, table_name, operation, new_value) INSERT INTO internal.change_log (website_id, table_name, operation, new_value)
VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (NEW)); VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (NEW));
RETURN NEW; ELSIF (TG_OP = 'UPDATE'
ELSIF TG_OP = 'UPDATE'
AND EXISTS ( AND EXISTS (
SELECT SELECT
id id
FROM FROM
internal.website internal.website
WHERE WHERE
id = _website_id) THEN id = _website_id)) THEN
INSERT INTO internal.change_log (website_id, table_name, operation, old_value, new_value) 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)); VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD) - HSTORE (NEW), HSTORE (NEW) - HSTORE (OLD));
RETURN NEW; ELSIF (TG_OP = 'DELETE'
ELSIF TG_OP = 'DELETE'
AND EXISTS ( AND EXISTS (
SELECT SELECT
id id
FROM FROM
internal.website internal.website
WHERE WHERE
id = _website_id) THEN id = _website_id)) THEN
INSERT INTO internal.change_log (website_id, table_name, operation, old_value) INSERT INTO internal.change_log (website_id, table_name, operation, old_value)
VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD)); VALUES (_website_id, TG_TABLE_NAME, TG_OP, HSTORE (OLD));
RETURN NEW;
END IF; END IF;
RETURN NEW; RETURN NULL;
END; END;
$$ $$
LANGUAGE plpgsql LANGUAGE plpgsql

View File

@@ -83,6 +83,7 @@ export interface ChangeLog {
id: string; id: string;
website_id: string | null; website_id: string | null;
user_id: string | null; user_id: string | null;
username: string;
tstamp: Date; tstamp: Date;
table_name: string; table_name: string;
operation: string; operation: string;
@@ -93,6 +94,7 @@ export interface ChangeLogInput {
id?: string; id?: string;
website_id?: string | null; website_id?: string | null;
user_id?: string | null; user_id?: string | null;
username?: string;
tstamp?: Date; tstamp?: Date;
table_name: string; table_name: string;
operation: string; operation: string;
@@ -105,6 +107,7 @@ const change_log = {
"id", "id",
"website_id", "website_id",
"user_id", "user_id",
"username",
"tstamp", "tstamp",
"table_name", "table_name",
"operation", "operation",
@@ -320,7 +323,7 @@ const legal_information = {
export interface Media { export interface Media {
id: string; id: string;
website_id: string; website_id: string;
user_id: string; user_id: string | null;
blob: string; blob: string;
mimetype: string; mimetype: string;
original_name: string; original_name: string;
@@ -329,7 +332,7 @@ export interface Media {
export interface MediaInput { export interface MediaInput {
id?: string; id?: string;
website_id: string; website_id: string;
user_id?: string; user_id?: string | null;
blob: string; blob: string;
mimetype: string; mimetype: string;
original_name: string; original_name: string;

View File

@@ -15,7 +15,7 @@ import type {
LegalInformation LegalInformation
} from "$lib/db-schema"; } from "$lib/db-schema";
export const ALLOWED_MIME_TYPES = ["image/jpeg", "image/png", "image/svg+xml", "image/webp"]; export const ALLOWED_MIME_TYPES = ["image/jpeg", "image/png", "image/webp"];
export const slugify = (string: string) => { export const slugify = (string: string) => {
return string return string

View File

@@ -69,10 +69,10 @@
</h2> </h2>
<ul class="unpadded"> <ul class="unpadded">
{#each data.collaborators as { website_id, user_id, permission_level, user: { username } } (`${website_id}-${user_id}`)} {#each data.collaborators as { website_id, user_id, permission_level, user } (`${website_id}-${user_id}`)}
<li class="collaborator-card"> <li class="collaborator-card">
<p> <p>
<strong>{username} ({permission_level})</strong> <strong>{user?.username} ({permission_level})</strong>
</p> </p>
<div class="collaborator-card__actions"> <div class="collaborator-card__actions">

View File

@@ -9,10 +9,10 @@ export const load: PageServerLoad = async ({ parent, fetch, params, cookies, url
const searchParams = new URLSearchParams(); const searchParams = new URLSearchParams();
const baseFetchUrl = `${API_BASE_PREFIX}/change_log?website_id=eq.${params.websiteId}&select=id,table_name,operation,tstamp,old_value,new_value,user!inner(username)&order=tstamp.desc`; const baseFetchUrl = `${API_BASE_PREFIX}/change_log?website_id=eq.${params.websiteId}&select=id,table_name,operation,tstamp,old_value,new_value,user_id,username&order=tstamp.desc`;
if (userFilter && userFilter !== "all") { if (userFilter && userFilter !== "all") {
searchParams.append("user.username", `eq.${userFilter}`); searchParams.append("username", `eq.${userFilter}`);
} }
if (resourceFilter && resourceFilter !== "all") { if (resourceFilter && resourceFilter !== "all") {

View File

@@ -126,9 +126,13 @@
</tr> </tr>
</thead> </thead>
<tbody> <tbody>
{#each data.changeLog as { id, table_name, operation, tstamp, old_value, new_value, user }} {#each data.changeLog as { id, table_name, operation, tstamp, old_value, new_value, user_id, username }}
<tr> <tr>
<td>{user.username}</td> <td>
<span style:text-decoration={user_id ? "" : "line-through"}>
{username}
</span>
</td>
<td>{table_name}</td> <td>{table_name}</td>
<td>{operation}</td> <td>{operation}</td>
<td> <td>