Files
diplom/migrations/20250510184011_channel_message.sql
2025-06-03 11:42:51 +03:00

164 lines
6.1 KiB
PL/PgSQL

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") 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;
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;
$$;
CREATE OR REPLACE FUNCTION create_group_channel(
p_creator_id UUID, -- The user initiating the group creation (will be owner)
p_recipient_user_ids UUID[], -- Array of all user IDs for the group (must include creator)
p_group_channel_type INT2 -- The channel type identifier for groups (e.g., 1)
)
RETURNS UUID
LANGUAGE plpgsql
AS
$$
DECLARE
new_channel_id UUID;
existing_channel_id UUID;
final_channel_name VARCHAR;
unique_sorted_recipient_ids UUID[];
num_recipients INT;
uid UUID;
-- Threshold for detailed name vs. summary name
MAX_MEMBERS_FOR_DETAILED_NAME CONSTANT INT := 3;
BEGIN
-- Validate and process recipient IDs
IF p_recipient_user_ids IS NULL OR array_length(p_recipient_user_ids, 1) IS NULL THEN
RAISE EXCEPTION 'Recipient user IDs array must be provided and not empty.';
END IF;
-- Get unique, sorted recipient IDs for consistent checking and to avoid duplicates.
SELECT array_agg(DISTINCT u ORDER BY u) INTO unique_sorted_recipient_ids FROM unnest(p_recipient_user_ids) u;
num_recipients := array_length(unique_sorted_recipient_ids, 1);
-- Validate minimum number of recipients for a group
IF num_recipients < 1 THEN -- Groups typically have at least 2 members
RAISE EXCEPTION 'Group channels (type %) must have at least 2 recipients. Found %.', p_group_channel_type, num_recipients;
END IF;
-- Create new group channel
INSERT INTO "channel" ("name", "type", "position", "owner_id", "server_id", "parent")
VALUES ('Group',
p_group_channel_type,
0, -- Default position
p_creator_id,
NULL, -- Not a server channel
NULL -- Not a nested server channel
)
RETURNING id INTO new_channel_id;
-- Add all recipients to the channel_recipient table
INSERT INTO "channel_recipient" ("channel_id", "user_id")
VALUES (new_channel_id, p_creator_id);
INSERT INTO "channel_recipient" ("channel_id", "user_id")
SELECT new_channel_id, r_id
FROM unnest(unique_sorted_recipient_ids) AS r_id;
RAISE NOTICE 'Group channel (type %) named "%" created with ID: % by owner % for recipients: %',
p_group_channel_type, final_channel_name, new_channel_id, p_creator_id, unique_sorted_recipient_ids;
RETURN new_channel_id;
END;
$$;