.
This commit is contained in:
1
migrations/20250510183101_uuidv7.down.sql
Normal file
1
migrations/20250510183101_uuidv7.down.sql
Normal file
@@ -0,0 +1 @@
|
||||
DROP EXTENSION pg_uuidv7;
|
||||
1
migrations/20250510183101_uuidv7.up.sql
Normal file
1
migrations/20250510183101_uuidv7.up.sql
Normal file
@@ -0,0 +1 @@
|
||||
CREATE EXTENSION IF NOT EXISTS pg_uuidv7;
|
||||
4
migrations/20250510183102_user.down.sql
Normal file
4
migrations/20250510183102_user.down.sql
Normal file
@@ -0,0 +1,4 @@
|
||||
DROP TRIGGER trg_user_relation_update ON "user_relation";
|
||||
DROP FUNCTION fn_on_user_relation_update();
|
||||
DROP TABLE "user_relation";
|
||||
DROP TABLE "user";
|
||||
46
migrations/20250510183102_user.up.sql
Normal file
46
migrations/20250510183102_user.up.sql
Normal file
@@ -0,0 +1,46 @@
|
||||
CREATE TABLE IF NOT EXISTS "user"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"avatar_url" VARCHAR,
|
||||
"username" VARCHAR NOT NULL UNIQUE,
|
||||
"display_name" VARCHAR,
|
||||
"email" VARCHAR NOT NULL,
|
||||
"password_hash" VARCHAR NOT NULL,
|
||||
"bot" BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
"system" BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
"settings" JSONB NOT NULL DEFAULT '{}'::JSONB
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "user_relation"
|
||||
(
|
||||
"user_id" UUID NOT NULL CHECK (user_id <> other_id) REFERENCES "user" ("id") ON DELETE CASCADE,
|
||||
"other_id" UUID NOT NULL CHECK (user_id <> other_id) REFERENCES "user" ("id") ON DELETE CASCADE,
|
||||
"type" INT2 NOT NULL,
|
||||
"created_at" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||||
"updated_at" TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||||
PRIMARY KEY ("user_id", "other_id")
|
||||
);
|
||||
|
||||
-- create system account
|
||||
INSERT INTO "user" ("username", "display_name", "email", "password_hash", "bot", "system")
|
||||
VALUES ('system', 'System', 'system@lionarius.ru', '', TRUE, TRUE);
|
||||
|
||||
CREATE OR REPLACE FUNCTION fn_on_user_relation_update()
|
||||
RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
IF (TG_OP = 'UPDATE') THEN
|
||||
NEW.updated_at := now();
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE TRIGGER trg_user_relation_update
|
||||
BEFORE UPDATE
|
||||
ON "user_relation"
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION fn_on_user_relation_update();
|
||||
1
migrations/20250510183125_server.down.sql
Normal file
1
migrations/20250510183125_server.down.sql
Normal file
@@ -0,0 +1 @@
|
||||
DROP TABLE "server";
|
||||
77
migrations/20250510183125_server.up.sql
Normal file
77
migrations/20250510183125_server.up.sql
Normal file
@@ -0,0 +1,77 @@
|
||||
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
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "server_role"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"server_id" UUID NOT NULL REFERENCES "server" ("id") ON DELETE CASCADE,
|
||||
"name" VARCHAR NOT NULL,
|
||||
"color" VARCHAR,
|
||||
"display" BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
"permissions" JSONB NOT NULL DEFAULT '{}'::JSONB,
|
||||
"position" SMALLINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "server_member"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"server_id" UUID NOT NULL REFERENCES "server" ("id") ON DELETE CASCADE,
|
||||
"user_id" UUID NOT NULL REFERENCES "user" ("id") ON DELETE CASCADE,
|
||||
"nickname" VARCHAR,
|
||||
"avatar_url" VARCHAR,
|
||||
UNIQUE ("server_id", "user_id")
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "server_member_role"
|
||||
(
|
||||
"member_id" UUID NOT NULL REFERENCES "server_member" ("id") ON DELETE CASCADE,
|
||||
"role_id" UUID NOT NULL REFERENCES "server_role" ("id") ON DELETE CASCADE,
|
||||
PRIMARY KEY ("member_id", "role_id")
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS "server_invite"
|
||||
(
|
||||
"code" VARCHAR NOT NULL PRIMARY KEY,
|
||||
"server_id" UUID NOT NULL REFERENCES "server" ("id") ON DELETE CASCADE,
|
||||
"inviter_id" UUID REFERENCES "user" ("id") ON DELETE SET NULL,
|
||||
"expires_at" TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION check_server_user_role_server_id()
|
||||
RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
member_server_id UUID;
|
||||
role_server_id UUID;
|
||||
BEGIN
|
||||
-- Get server_id from server_user
|
||||
SELECT server_id
|
||||
INTO member_server_id
|
||||
FROM server_member
|
||||
WHERE id = NEW.member_id;
|
||||
|
||||
-- Get server_id from server_role
|
||||
SELECT server_id
|
||||
INTO role_server_id
|
||||
FROM server_role
|
||||
WHERE id = NEW.role_id;
|
||||
|
||||
-- Check if server_ids match
|
||||
IF member_server_id != role_server_id THEN
|
||||
RAISE EXCEPTION 'Cannot assign role from a different server: server_user server_id (%) does not match server_role server_id (%)', member_server_id, role_server_id;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER enforce_server_user_role_server_id
|
||||
BEFORE INSERT OR UPDATE
|
||||
ON server_member_role
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION check_server_user_role_server_id();
|
||||
2
migrations/20250510184011_channel_message.down.sql
Normal file
2
migrations/20250510184011_channel_message.down.sql
Normal file
@@ -0,0 +1,2 @@
|
||||
DROP TABLE "message";
|
||||
DROP TABLE "channel";
|
||||
97
migrations/20250510184011_channel_message.up.sql
Normal file
97
migrations/20250510184011_channel_message.up.sql
Normal file
@@ -0,0 +1,97 @@
|
||||
CREATE TABLE IF NOT EXISTS "channel"
|
||||
(
|
||||
"id" UUID NOT NULL PRIMARY KEY DEFAULT uuid_generate_v7(),
|
||||
"name" VARCHAR NOT NULL,
|
||||
"type" INT2 NOT NULL,
|
||||
"position" INT2 NOT NULL,
|
||||
"server_id" UUID REFERENCES "server" ("id") ON DELETE CASCADE, -- only for server channels
|
||||
"parent" UUID REFERENCES "channel" ("id") ON DELETE SET NULL, -- only for server channels
|
||||
"owner_id" UUID REFERENCES "user" ("id") ON DELETE SET NULL -- only for group channels
|
||||
);
|
||||
|
||||
-- only for dm or group channels
|
||||
CREATE TABLE IF NOT EXISTS "channel_recipient"
|
||||
(
|
||||
"channel_id" UUID NOT NULL REFERENCES "channel" ("id") ON DELETE CASCADE,
|
||||
"user_id" UUID NOT NULL REFERENCES "user" ("id") ON DELETE CASCADE,
|
||||
PRIMARY KEY ("channel_id", "user_id")
|
||||
);
|
||||
|
||||
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"),
|
||||
"content" TEXT NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE "channel"
|
||||
ADD COLUMN "last_message_id" UUID REFERENCES "message" ("id") ON DELETE SET NULL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION create_dm_channel(
|
||||
user1_id UUID,
|
||||
user2_id UUID,
|
||||
channel_type INT2
|
||||
)
|
||||
RETURNS UUID
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
new_channel_id UUID;
|
||||
channel_name VARCHAR;
|
||||
BEGIN
|
||||
-- Validate parameters
|
||||
IF user1_id IS NULL OR user2_id IS NULL THEN
|
||||
RAISE EXCEPTION 'Both user IDs must be provided';
|
||||
END IF;
|
||||
|
||||
IF user1_id = user2_id THEN
|
||||
RAISE EXCEPTION 'Cannot create a DM channel with the same user';
|
||||
END IF;
|
||||
|
||||
-- Check if users exist
|
||||
IF NOT exists (SELECT 1 FROM "user" WHERE id = user1_id) OR
|
||||
NOT exists (SELECT 1 FROM "user" WHERE id = user2_id) THEN
|
||||
RAISE EXCEPTION 'One or both users do not exist';
|
||||
END IF;
|
||||
|
||||
-- Check if DM already exists between these users
|
||||
IF exists (SELECT 1
|
||||
FROM channel c
|
||||
JOIN channel_recipient cr1 ON c.id = cr1.channel_id AND cr1.user_id = user1_id
|
||||
JOIN channel_recipient cr2 ON c.id = cr2.channel_id AND cr2.user_id = user2_id
|
||||
WHERE c.type = channel_type
|
||||
AND (SELECT count(*) FROM channel_recipient WHERE channel_id = c.id) = 2) THEN
|
||||
-- Find and return the existing channel ID
|
||||
SELECT c.id
|
||||
INTO new_channel_id
|
||||
FROM channel c
|
||||
JOIN channel_recipient cr1 ON c.id = cr1.channel_id AND cr1.user_id = user1_id
|
||||
JOIN channel_recipient cr2 ON c.id = cr2.channel_id AND cr2.user_id = user2_id
|
||||
WHERE c.type = channel_type
|
||||
AND (SELECT count(*) FROM channel_recipient WHERE channel_id = c.id) = 2
|
||||
LIMIT 1;
|
||||
|
||||
RAISE NOTICE 'DM channel already exists between these users with ID: %', new_channel_id;
|
||||
RETURN new_channel_id;
|
||||
END IF;
|
||||
|
||||
-- Generate channel name (conventionally uses user IDs in DMs)
|
||||
channel_name := concat(user1_id, '-', user2_id);
|
||||
|
||||
-- Create new channel
|
||||
INSERT INTO "channel" ("name", "type", "position")
|
||||
VALUES (channel_name, channel_type, 0)
|
||||
RETURNING id INTO new_channel_id;
|
||||
|
||||
-- Add both users as recipients
|
||||
INSERT INTO "channel_recipient" ("channel_id", "user_id")
|
||||
VALUES (new_channel_id, user1_id),
|
||||
(new_channel_id, user2_id);
|
||||
|
||||
RAISE NOTICE 'DM channel created with ID: %', new_channel_id;
|
||||
RETURN new_channel_id;
|
||||
END;
|
||||
$$;
|
||||
2
migrations/20250510184916_file.down.sql
Normal file
2
migrations/20250510184916_file.down.sql
Normal file
@@ -0,0 +1,2 @@
|
||||
DROP TABLE "message_attachment";
|
||||
DROP TABLE "file";
|
||||
16
migrations/20250510184916_file.up.sql
Normal file
16
migrations/20250510184916_file.up.sql
Normal file
@@ -0,0 +1,16 @@
|
||||
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")
|
||||
);
|
||||
Reference in New Issue
Block a user