.
This commit is contained in:
8
migrations/20250510182916_file.sql
Normal file
8
migrations/20250510182916_file.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
CREATE TABLE IF NOT EXISTS "file"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"filename" VARCHAR NOT NULL,
|
||||
"content_type" VARCHAR NOT NULL,
|
||||
"size" INT8 NOT NULL
|
||||
);
|
||||
|
||||
@@ -1 +0,0 @@
|
||||
DROP EXTENSION pg_uuidv7;
|
||||
@@ -1,4 +0,0 @@
|
||||
DROP TRIGGER trg_user_relation_update ON "user_relation";
|
||||
DROP FUNCTION fn_on_user_relation_update();
|
||||
DROP TABLE "user_relation";
|
||||
DROP TABLE "user";
|
||||
@@ -1,7 +1,7 @@
|
||||
CREATE TABLE IF NOT EXISTS "user"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"avatar_url" VARCHAR,
|
||||
"avatar_id" UUID REFERENCES "file" ("id") ON DELETE SET NULL,
|
||||
"username" VARCHAR NOT NULL UNIQUE,
|
||||
"display_name" VARCHAR,
|
||||
"email" VARCHAR NOT NULL,
|
||||
@@ -25,6 +25,38 @@ CREATE TABLE IF NOT EXISTS "user_relation"
|
||||
INSERT INTO "user" ("username", "display_name", "email", "password_hash", "bot", "system")
|
||||
VALUES ('system', 'System', 'system@lionarius.ru', '', TRUE, TRUE);
|
||||
|
||||
CREATE OR REPLACE FUNCTION check_avatar_is_image()
|
||||
RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
file_content_type VARCHAR;
|
||||
BEGIN
|
||||
-- Skip check if icon_id is null
|
||||
IF NEW.avatar_id IS NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- Retrieve content_type from file table
|
||||
SELECT content_type
|
||||
INTO file_content_type
|
||||
FROM file
|
||||
WHERE id = NEW.avatar_id;
|
||||
|
||||
-- Raise exception if content_type does not start with 'image/'
|
||||
IF file_content_type IS NULL OR file_content_type NOT LIKE 'image/%' THEN
|
||||
RAISE EXCEPTION 'avatar_id must reference a file with content_type starting with image/';
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_check_icon_is_image
|
||||
BEFORE INSERT OR UPDATE
|
||||
ON "user"
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION check_avatar_is_image();
|
||||
|
||||
CREATE OR REPLACE FUNCTION fn_on_user_relation_update()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
@@ -1 +0,0 @@
|
||||
DROP TABLE "server";
|
||||
@@ -3,7 +3,7 @@ CREATE TABLE IF NOT EXISTS "server"
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"owner_id" UUID NOT NULL REFERENCES "user" ("id"),
|
||||
"name" VARCHAR NOT NULL,
|
||||
"icon_url" VARCHAR
|
||||
"icon_id" UUID REFERENCES "file" ("id") ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "server_role"
|
||||
@@ -42,6 +42,38 @@ CREATE TABLE IF NOT EXISTS "server_invite"
|
||||
"expires_at" TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION check_icon_is_image()
|
||||
RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
file_content_type VARCHAR;
|
||||
BEGIN
|
||||
-- Skip check if icon_id is null
|
||||
IF NEW.icon_id IS NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- Retrieve content_type from file table
|
||||
SELECT content_type
|
||||
INTO file_content_type
|
||||
FROM file
|
||||
WHERE id = NEW.icon_id;
|
||||
|
||||
-- Raise exception if content_type does not start with 'image/'
|
||||
IF file_content_type IS NULL OR file_content_type NOT LIKE 'image/%' THEN
|
||||
RAISE EXCEPTION 'icon_id must reference a file with content_type starting with image/';
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trigger_check_icon_is_image
|
||||
BEFORE INSERT OR UPDATE
|
||||
ON "server"
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION check_icon_is_image();
|
||||
|
||||
CREATE OR REPLACE FUNCTION check_server_user_role_server_id()
|
||||
RETURNS TRIGGER AS
|
||||
$$
|
||||
@@ -1,2 +0,0 @@
|
||||
DROP TABLE "message";
|
||||
DROP TABLE "channel";
|
||||
@@ -20,11 +20,19 @@ CREATE TABLE IF NOT EXISTS "channel_recipient"
|
||||
CREATE TABLE IF NOT EXISTS "message"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"author_id" UUID NOT NULL REFERENCES "user" ("id"),
|
||||
"channel_id" UUID NOT NULL REFERENCES "channel" ("id"),
|
||||
"author_id" UUID NOT NULL REFERENCES "user" ("id") ON DELETE CASCADE,
|
||||
"channel_id" UUID NOT NULL REFERENCES "channel" ("id") ON DELETE CASCADE,
|
||||
"content" TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "message_attachment"
|
||||
(
|
||||
"message_id" UUID NOT NULL REFERENCES "message" ON DELETE CASCADE,
|
||||
"file_id" UUID NOT NULL REFERENCES "file" ON DELETE CASCADE,
|
||||
"order" INT2 NOT NULL,
|
||||
PRIMARY KEY ("message_id", "file_id")
|
||||
);
|
||||
|
||||
ALTER TABLE "channel"
|
||||
ADD COLUMN "last_message_id" UUID REFERENCES "message" ("id") ON DELETE SET NULL;
|
||||
|
||||
@@ -1,2 +0,0 @@
|
||||
DROP TABLE "message_attachment";
|
||||
DROP TABLE "file";
|
||||
@@ -1,16 +0,0 @@
|
||||
CREATE TABLE IF NOT EXISTS "file"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"filename" VARCHAR NOT NULL,
|
||||
"content_type" VARCHAR NOT NULL,
|
||||
"url" VARCHAR NOT NULL,
|
||||
"size" INT8 NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "message_attachment"
|
||||
(
|
||||
"message_id" UUID NOT NULL REFERENCES "message" ON DELETE CASCADE,
|
||||
"attachment_id" UUID NOT NULL REFERENCES "file" ON DELETE CASCADE,
|
||||
"order" INT2 NOT NULL,
|
||||
PRIMARY KEY ("message_id", "attachment_id")
|
||||
);
|
||||
35
migrations/20250517190855_util.sql
Normal file
35
migrations/20250517190855_util.sql
Normal file
@@ -0,0 +1,35 @@
|
||||
CREATE OR REPLACE FUNCTION get_users_that_can_see_user(target_user_id UUID)
|
||||
RETURNS TABLE (user_id UUID) AS $$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
-- Users directly related to the target user
|
||||
SELECT ur.user_id
|
||||
FROM user_relation ur
|
||||
WHERE ur.other_id = target_user_id
|
||||
|
||||
UNION
|
||||
|
||||
-- Users where target user is related to them
|
||||
SELECT ur.other_id AS user_id
|
||||
FROM user_relation ur
|
||||
WHERE ur.user_id = target_user_id
|
||||
|
||||
UNION
|
||||
|
||||
-- Users who share a server with the target user
|
||||
SELECT sm.user_id
|
||||
FROM server_member sm
|
||||
JOIN server_member sm2 ON sm.server_id = sm2.server_id
|
||||
WHERE sm2.user_id = target_user_id
|
||||
AND sm.user_id != target_user_id
|
||||
|
||||
UNION
|
||||
|
||||
-- Users who share a channel with the target user (DM or group)
|
||||
SELECT cr.user_id
|
||||
FROM channel_recipient cr
|
||||
JOIN channel_recipient cr2 ON cr.channel_id = cr2.channel_id
|
||||
WHERE cr2.user_id = target_user_id
|
||||
AND cr.user_id != target_user_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
Reference in New Issue
Block a user