1281 lines
38 KiB
JavaScript
1281 lines
38 KiB
JavaScript
const { Client } = require("pg");
|
|
require("dotenv").config();
|
|
const client = new Client({
|
|
user: process.env.PG_USER,
|
|
password: process.env.PG_PASSWORD,
|
|
database: process.env.PG_DATABASE,
|
|
host: process.env.PG_HOST,
|
|
port: 5432,
|
|
});
|
|
|
|
client
|
|
.connect()
|
|
.then(() => {
|
|
createTables()
|
|
.then(() => {
|
|
//client.end();
|
|
console.log("Tables created successfully");
|
|
})
|
|
.catch((e) => {
|
|
//client.end();
|
|
console.error("Failed to create tables ", e);
|
|
});
|
|
console.log(
|
|
`Successfully connected to database: ${process.env.PG_DATABASE}`,
|
|
);
|
|
})
|
|
.catch((err) =>
|
|
console.error(
|
|
`Failed to connect to database: ${process.env.PG_DATABASE}, ${err}`,
|
|
),
|
|
);
|
|
|
|
// Creating database tables
|
|
async function createTables() {
|
|
try {
|
|
// Enable UUID extension
|
|
await client.query(`
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
`);
|
|
console.log("Successfully enabled UUID extension");
|
|
|
|
// Create Accounts Table with UUID
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS Accounts (
|
|
user_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
username VARCHAR(255) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
CREATE INDEX IF NOT EXISTS idx_username ON Accounts (username);
|
|
`);
|
|
console.log("Successfully created Accounts table");
|
|
|
|
// Create Conversations Table with UUID
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS Conversations (
|
|
conversation_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
|
conversation_type VARCHAR(10) NOT NULL CHECK (conversation_type IN ('direct', 'group')),
|
|
name VARCHAR(255),
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
last_active TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
CREATE INDEX IF NOT EXISTS idx_conversation_type ON Conversations (conversation_type);
|
|
`);
|
|
console.log("Successfully created Conversations table");
|
|
|
|
// Create Messages Table with SERIAL but referencing UUID
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS Messages (
|
|
message_id SERIAL PRIMARY KEY,
|
|
conversation_id UUID REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
|
|
user_id UUID REFERENCES Accounts(user_id) ON DELETE CASCADE,
|
|
content TEXT NOT NULL,
|
|
attachment_urls TEXT[],
|
|
sent_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
CREATE INDEX IF NOT EXISTS idx_messages_conversation_id ON Messages (conversation_id);
|
|
CREATE INDEX IF NOT EXISTS idx_messages_user_id ON Messages (user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_messages_conversation_sent_at ON Messages (conversation_id, sent_at);
|
|
`);
|
|
console.log("Successfully created Messages table");
|
|
|
|
// Create Memberships Table referencing UUID
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS Memberships (
|
|
conversation_id UUID NOT NULL REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
|
|
user_id UUID REFERENCES Accounts(user_id) ON DELETE CASCADE,
|
|
joined_at TIMESTAMPTZ DEFAULT NOW(),
|
|
PRIMARY KEY (conversation_id, user_id)
|
|
);
|
|
CREATE INDEX IF NOT EXISTS idx_memberships_conversation_id ON Memberships (conversation_id);
|
|
CREATE INDEX IF NOT EXISTS idx_memberships_user_id ON Memberships (user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_memberships_conversation_joined_at ON Memberships (conversation_id, joined_at);
|
|
`);
|
|
console.log("Successfully created Memberships table");
|
|
|
|
// Create Contacts Table with SERIAL but referencing UUID
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS Contacts (
|
|
contact_id SERIAL PRIMARY KEY,
|
|
user_id UUID REFERENCES Accounts(user_id) ON DELETE CASCADE,
|
|
conversation_id UUID NOT NULL REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
|
|
read BOOLEAN NOT NULL DEFAULT FALSE,
|
|
last_active TIMESTAMPTZ DEFAULT NOW(),
|
|
CONSTRAINT unique_contact UNIQUE (user_id, conversation_id)
|
|
);
|
|
CREATE INDEX IF NOT EXISTS idx_contacts_user_id ON Contacts (user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_contacts_conversation_id ON Contacts (conversation_id);
|
|
CREATE INDEX IF NOT EXISTS idx_contacts_contact_id ON Contacts (contact_id);
|
|
`);
|
|
console.log("Successfully created Contacts table");
|
|
|
|
// Create GroupAdmins Table with Trigger, referencing UUID
|
|
await client.query(`
|
|
-- Create the GroupAdmins table with owner flag
|
|
CREATE TABLE IF NOT EXISTS GroupAdmins (
|
|
conversation_id UUID NOT NULL REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
|
|
user_id UUID NOT NULL REFERENCES Accounts(user_id) ON DELETE CASCADE,
|
|
granted_by UUID NOT NULL REFERENCES Accounts(user_id) ON DELETE CASCADE,
|
|
granted_at TIMESTAMPTZ DEFAULT NOW(),
|
|
is_owner BOOLEAN DEFAULT FALSE,
|
|
PRIMARY KEY (conversation_id, user_id),
|
|
-- Ensure only one owner per group
|
|
CONSTRAINT single_owner EXCLUDE USING btree (conversation_id WITH =)
|
|
WHERE (is_owner = true)
|
|
);
|
|
|
|
-- Create indexes
|
|
CREATE INDEX IF NOT EXISTS idx_group_admins_conversation_id ON GroupAdmins (conversation_id);
|
|
CREATE INDEX IF NOT EXISTS idx_group_admins_user_id ON GroupAdmins (user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_group_admins_owner ON GroupAdmins (conversation_id) WHERE is_owner = true;
|
|
|
|
-- Create the validation function
|
|
CREATE OR REPLACE FUNCTION validate_admin_grant()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
-- Check if this is the first admin (owner) of the group
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM GroupAdmins
|
|
WHERE conversation_id = NEW.conversation_id
|
|
) THEN
|
|
-- First admin must be self-granted and marked as owner
|
|
IF NEW.granted_by != NEW.user_id THEN
|
|
RAISE EXCEPTION 'First admin must be self-granted';
|
|
END IF;
|
|
NEW.is_owner := true;
|
|
ELSE
|
|
-- For non-owner admins, verify that the granter is an admin
|
|
IF NOT EXISTS (
|
|
SELECT 1 FROM GroupAdmins
|
|
WHERE conversation_id = NEW.conversation_id
|
|
AND user_id = NEW.granted_by
|
|
) THEN
|
|
RAISE EXCEPTION 'Only existing admins can grant admin privileges';
|
|
END IF;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
`);
|
|
console.log("Successfully created GroupAdmins table with trigger");
|
|
} catch (e) {
|
|
console.error("Failed to create tables: ", e);
|
|
throw e;
|
|
}
|
|
|
|
console.log("All tables created successfully");
|
|
}
|
|
|
|
async function insertUser(username, passwordHash) {
|
|
const query = `
|
|
INSERT INTO Accounts (username, password_hash)
|
|
VALUES ($1, $2)
|
|
RETURNING user_id;
|
|
`;
|
|
try {
|
|
const result = await client.query(query, [username, passwordHash]);
|
|
return result.rows[0].user_id;
|
|
} catch (e) {
|
|
console.error("Failed to insert user ", e);
|
|
}
|
|
}
|
|
|
|
async function getUserId(username) {
|
|
const query = `
|
|
SELECT user_id, username AS dbUsername FROM Accounts
|
|
WHERE LOWER(username) = $1;
|
|
`;
|
|
try {
|
|
const result = await client.query(query, [username]);
|
|
if (result.rows.length > 0) {
|
|
return result.rows[0];
|
|
} else {
|
|
console.log("No user found with username: ", username);
|
|
return null;
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to get user id", e);
|
|
}
|
|
}
|
|
|
|
async function insertMessage(
|
|
senderId,
|
|
conversation_id,
|
|
content,
|
|
attachmentUrls,
|
|
) {
|
|
console.log(
|
|
`senderId: ${senderId}, conversation_id: ${conversation_id}, content: ${content}, attachmentUrl: ${attachmentUrls}`,
|
|
);
|
|
|
|
const checkMembershipQuery = `
|
|
SELECT 1 FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2
|
|
LIMIT 1;
|
|
`;
|
|
|
|
const query = `
|
|
INSERT INTO Messages (conversation_id, user_id, content, attachment_urls)
|
|
VALUES ($1, $2, $3, $4)
|
|
RETURNING message_id, content, sent_at, attachment_urls, user_id AS sender_id, conversation_id;
|
|
`;
|
|
try {
|
|
const checkResult = await client.query(checkMembershipQuery, [
|
|
conversation_id,
|
|
senderId,
|
|
]);
|
|
if (checkResult.rows.length === 0) {
|
|
console.error("User is not a member of the conversation");
|
|
return [];
|
|
}
|
|
const result = await client.query(query, [
|
|
conversation_id,
|
|
senderId,
|
|
content,
|
|
attachmentUrls,
|
|
]);
|
|
updateConversationLastActive(conversation_id, senderId);
|
|
return result.rows[0];
|
|
} catch (e) {
|
|
console.error("Failed to insert message ", e);
|
|
}
|
|
}
|
|
|
|
async function createGroup(user_id, groupName) {
|
|
const createConversationQuery = `
|
|
INSERT INTO Conversations (conversation_type, name)
|
|
VALUES ('group', $1)
|
|
RETURNING conversation_id AS group_id;
|
|
`;
|
|
|
|
const insertGroupAdminQuery = `
|
|
INSERT INTO GroupAdmins (conversation_id, user_id, granted_by, is_owner)
|
|
VALUES ($1, $2, $3, true)
|
|
RETURNING granted_at;
|
|
`;
|
|
|
|
try {
|
|
const createConversation = await client.query(createConversationQuery, [
|
|
groupName,
|
|
]);
|
|
const group_id = createConversation.rows[0].group_id;
|
|
|
|
// Make the creator the owner and first admin
|
|
const insertGroupAdmin = await client.query(insertGroupAdminQuery, [
|
|
group_id,
|
|
user_id,
|
|
user_id,
|
|
]);
|
|
|
|
if (insertGroupAdmin.rowCount > 0) {
|
|
const contact_user_id = await addMemberToGroupById(group_id, user_id);
|
|
insertContactById(user_id, group_id, true);
|
|
return { group_id, contact_user_id };
|
|
}
|
|
console.error("Failed to insert group admin");
|
|
} catch (e) {
|
|
console.error("Failed to create conversation ", e);
|
|
return null;
|
|
}
|
|
}
|
|
|
|
async function addMemberToGroupById(conversation_id, user_id) {
|
|
// const isAdminResult = await isAdmin(user_id, conversation_id);
|
|
// if (!isAdminResult) {
|
|
// return { errorMessage: "You are not an admin of the conversation" };
|
|
// }
|
|
|
|
const query = `
|
|
INSERT INTO Memberships (conversation_id, user_id)
|
|
VALUES ($1, $2)
|
|
ON CONFLICT DO NOTHING;
|
|
`;
|
|
try {
|
|
await client.query(query, [conversation_id, user_id]);
|
|
console.log(
|
|
`Added user_id ${user_id} to conversation_id ${conversation_id}`,
|
|
);
|
|
return user_id;
|
|
} catch (e) {
|
|
console.error("Failed to add member to group ", e);
|
|
return null;
|
|
}
|
|
}
|
|
|
|
async function addMemberToGroupByUsername(conversation_id, username) {
|
|
// const { user_id } = await getUserId(username);
|
|
// if (!user_id) {
|
|
// return null;
|
|
// }
|
|
// const isAdminResult = await isAdmin(user_id, conversation_id);
|
|
// if (!isAdminResult) {
|
|
// console.error("You are not an admin of the conversation");
|
|
// return null;
|
|
// }
|
|
|
|
const query = `
|
|
WITH user_id_query AS (
|
|
SELECT user_id
|
|
FROM Accounts
|
|
WHERE LOWER(username) = $1
|
|
LIMIT 1
|
|
),
|
|
insert_membership AS (
|
|
INSERT INTO Memberships (conversation_id, user_id)
|
|
SELECT $2, user_id
|
|
FROM user_id_query
|
|
WHERE NOT EXISTS (
|
|
SELECT 1
|
|
FROM Memberships
|
|
WHERE conversation_id = $2 AND user_id = (SELECT user_id FROM user_id_query)
|
|
)
|
|
)
|
|
SELECT (SELECT user_id FROM user_id_query) AS added_user_id;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [username, conversation_id]);
|
|
if (result.rows.length > 0) {
|
|
console.log(
|
|
`Added user with username ${username} to conversation_id ${conversation_id}`,
|
|
);
|
|
const added_user_id = result.rows[0].added_user_id;
|
|
insertContactById(added_user_id, conversation_id, true);
|
|
return result.rows[0].added_user_id;
|
|
} else {
|
|
console.log(
|
|
`User with username ${username} not found or already in group.`,
|
|
);
|
|
return null;
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to add member to group by username", e);
|
|
}
|
|
}
|
|
|
|
async function getMessages(user_id, conversation_id, limit = 50, cursor = 0) {
|
|
const checkMembershipQuery = `
|
|
SELECT 1 FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2
|
|
LIMIT 1;
|
|
`;
|
|
|
|
try {
|
|
const checkResult = await client.query(checkMembershipQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
]);
|
|
if (checkResult.rows.length === 0) {
|
|
console.error("User is not a member of the conversation");
|
|
return [];
|
|
}
|
|
|
|
let query;
|
|
let params;
|
|
|
|
if (cursor) {
|
|
query = `
|
|
SELECT
|
|
m.message_id,
|
|
m.content AS message,
|
|
m.sent_at,
|
|
m.attachment_urls,
|
|
a.username AS sender
|
|
FROM Messages m
|
|
JOIN Accounts a ON m.user_id = a.user_id
|
|
WHERE m.conversation_id = $1
|
|
AND m.message_id < $2
|
|
ORDER BY m.message_id DESC
|
|
LIMIT $3;
|
|
`;
|
|
params = [conversation_id, cursor, limit];
|
|
} else {
|
|
query = `
|
|
SELECT
|
|
m.message_id,
|
|
m.content AS message,
|
|
m.sent_at,
|
|
m.attachment_urls,
|
|
a.username AS sender
|
|
FROM Messages m
|
|
JOIN Accounts a ON m.user_id = a.user_id
|
|
WHERE m.conversation_id = $1
|
|
ORDER BY m.message_id DESC
|
|
LIMIT $2;
|
|
`;
|
|
params = [conversation_id, limit];
|
|
}
|
|
|
|
console.log(
|
|
`Get messages for user_id: ${user_id}, conversation_id: ${conversation_id}`,
|
|
);
|
|
|
|
const results = await client.query(query, params);
|
|
let messages = results.rows;
|
|
if (!cursor) {
|
|
messages = messages.reverse();
|
|
}
|
|
|
|
return messages;
|
|
} catch (e) {
|
|
console.error("Failed to get messages ", e);
|
|
return [];
|
|
}
|
|
}
|
|
|
|
async function checkUserExist(username) {
|
|
const query = `
|
|
SELECT 1 FROM Accounts
|
|
WHERE LOWER(username) = LOWER($1)
|
|
LIMIT 1;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [username]);
|
|
return result.rows.length > 0;
|
|
} catch (e) {
|
|
console.error("Failed to check if user exists ", e);
|
|
return false;
|
|
}
|
|
}
|
|
|
|
async function getPassword(username) {
|
|
console.log(`Get password for: ${username}`);
|
|
const query = `
|
|
SELECT password_hash FROM Accounts
|
|
WHERE LOWER(username) = LOWER($1);
|
|
`;
|
|
try {
|
|
const result = await client.query(query, [username]);
|
|
if (result.rows.length > 0) {
|
|
return result.rows[0].password_hash;
|
|
} else {
|
|
console.log("No user found with username: ", username);
|
|
return null;
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to get user password ", e);
|
|
}
|
|
}
|
|
|
|
async function changePassword(username, newPasswordHash) {
|
|
const query = `
|
|
UPDATE Accounts
|
|
SET password_hash = $1
|
|
WHERE username = $2;
|
|
`;
|
|
try {
|
|
await client.query(query, [newPasswordHash, username]);
|
|
} catch (e) {
|
|
console.error("Failed to change password ", e);
|
|
}
|
|
}
|
|
|
|
async function insertContactById(senderId, conversation_id, read) {
|
|
// First check if contact already exists
|
|
const checkQuery = `
|
|
SELECT contact_id, conversation_id, user_id, read, last_active
|
|
FROM Contacts
|
|
WHERE user_id = $1 AND conversation_id = $2
|
|
`;
|
|
|
|
try {
|
|
// Check if contact already exists
|
|
const existingContact = await client.query(checkQuery, [
|
|
senderId,
|
|
conversation_id,
|
|
]);
|
|
if (existingContact.rows.length > 0) {
|
|
console.log("Contact already exists:", senderId, conversation_id);
|
|
return existingContact.rows[0];
|
|
}
|
|
|
|
// If contact doesn't exist, create new one
|
|
const insertQuery = `
|
|
INSERT INTO Contacts (user_id, conversation_id, read)
|
|
VALUES($1, $2, $3)
|
|
RETURNING contact_id, conversation_id, user_id, read, last_active
|
|
`;
|
|
|
|
const result = await client.query(insertQuery, [
|
|
senderId,
|
|
conversation_id,
|
|
read,
|
|
]);
|
|
console.log("Insert contact by id:", senderId, conversation_id);
|
|
return result.rows[0] || null;
|
|
} catch (error) {
|
|
console.error("Failed to insert contact by IDs:", error);
|
|
return null;
|
|
}
|
|
}
|
|
|
|
async function insertContact(initiatorId, receiverId, contactUsername, read) {
|
|
try {
|
|
let conversation_id;
|
|
|
|
// Check if the user is creating a contact for themselves
|
|
const isSelfContact = initiatorId === receiverId;
|
|
|
|
if (isSelfContact) {
|
|
// For self-contacts, check if a conversation already exists for the user alone
|
|
const findSelfConversationQuery = `
|
|
SELECT c.conversation_id
|
|
FROM Conversations c
|
|
JOIN Memberships m ON c.conversation_id = m.conversation_id
|
|
WHERE c.conversation_type = 'direct'
|
|
AND m.user_id = $1
|
|
AND (
|
|
SELECT COUNT(*)
|
|
FROM Memberships
|
|
WHERE conversation_id = c.conversation_id
|
|
) = 1
|
|
LIMIT 1;
|
|
`;
|
|
|
|
const selfConversationResult = await client.query(
|
|
findSelfConversationQuery,
|
|
[initiatorId],
|
|
);
|
|
conversation_id = selfConversationResult.rows[0]?.conversation_id;
|
|
|
|
if (!conversation_id) {
|
|
// Create a new conversation for the user alone
|
|
const createConversationQuery = `
|
|
INSERT INTO Conversations (conversation_type)
|
|
VALUES ('direct')
|
|
RETURNING conversation_id;
|
|
`;
|
|
const newConversationResult = await client.query(
|
|
createConversationQuery,
|
|
);
|
|
|
|
if (!newConversationResult) {
|
|
console.error("Failed to create new conversation for self-contact");
|
|
return null;
|
|
}
|
|
|
|
conversation_id = newConversationResult.rows[0].conversation_id;
|
|
|
|
// Add the user as the only member of the conversation
|
|
const createMembershipQuery = `
|
|
INSERT INTO Memberships (conversation_id, user_id)
|
|
VALUES ($1, $2)
|
|
ON CONFLICT (conversation_id, user_id) DO NOTHING;
|
|
`;
|
|
await client.query(createMembershipQuery, [
|
|
conversation_id,
|
|
initiatorId,
|
|
]);
|
|
}
|
|
} else {
|
|
// For regular contacts, check if a conversation already exists between the two users
|
|
const findConversationQuery = `
|
|
SELECT c.conversation_id
|
|
FROM Conversations c
|
|
JOIN Memberships m1 ON c.conversation_id = m1.conversation_id
|
|
JOIN Memberships m2 ON c.conversation_id = m2.conversation_id
|
|
WHERE c.conversation_type = 'direct'
|
|
AND (
|
|
(m1.user_id = $1 AND m2.user_id = $2)
|
|
OR
|
|
(m1.user_id = $2 AND m2.user_id = $1)
|
|
)
|
|
LIMIT 1;
|
|
`;
|
|
|
|
const conversationResult = await client.query(findConversationQuery, [
|
|
initiatorId,
|
|
receiverId,
|
|
]);
|
|
conversation_id = conversationResult.rows[0]?.conversation_id;
|
|
|
|
if (!conversation_id) {
|
|
// Create a new conversation for the two users
|
|
const createConversationQuery = `
|
|
INSERT INTO Conversations (conversation_type)
|
|
VALUES ('direct')
|
|
RETURNING conversation_id;
|
|
`;
|
|
const newConversationResult = await client.query(
|
|
createConversationQuery,
|
|
);
|
|
|
|
if (!newConversationResult) {
|
|
console.error("Failed to create new conversation");
|
|
return null;
|
|
}
|
|
|
|
conversation_id = newConversationResult.rows[0].conversation_id;
|
|
|
|
// Add both users as members of the conversation
|
|
const createMembershipsQuery = `
|
|
INSERT INTO Memberships (conversation_id, user_id)
|
|
VALUES ($1, $2), ($1, $3)
|
|
ON CONFLICT (conversation_id, user_id) DO NOTHING;
|
|
`;
|
|
await client.query(createMembershipsQuery, [
|
|
conversation_id,
|
|
initiatorId,
|
|
receiverId,
|
|
]);
|
|
}
|
|
}
|
|
|
|
// Insert the contact for the initiator
|
|
const contact = await insertContactById(initiatorId, conversation_id, read);
|
|
if (!contact.contact_id) {
|
|
console.error("Failed to insert contact by id");
|
|
return null;
|
|
}
|
|
|
|
// Retrieve the last message, last active time, and last message sender
|
|
const lastMessageQuery = `
|
|
SELECT DISTINCT ON (m.conversation_id)
|
|
m.content AS last_message,
|
|
m.sent_at AS last_message_time,
|
|
a.username AS last_message_sender
|
|
FROM Messages m
|
|
JOIN Accounts a ON m.user_id = a.user_id
|
|
WHERE m.conversation_id = $1
|
|
ORDER BY m.conversation_id, m.sent_at DESC
|
|
`;
|
|
const lastMessageResult = await client.query(lastMessageQuery, [
|
|
conversation_id,
|
|
]);
|
|
let lastMessage, lastMessageTime, lastMessageSender;
|
|
|
|
if (lastMessageResult.rows.length > 0) {
|
|
lastMessage = lastMessageResult.rows[0].last_message;
|
|
lastMessageTime = lastMessageResult.rows[0].last_message_time;
|
|
lastMessageSender = lastMessageResult.rows[0].last_message_sender;
|
|
}
|
|
|
|
// Return formatted result with contact's user_id, last message, last active time, and last message sender
|
|
return {
|
|
id: contact.contact_id,
|
|
user_id: receiverId, // Now using the contact's user_id instead of the initiator's
|
|
username: contactUsername,
|
|
last_active: contact.last_active,
|
|
conversation_id: contact.conversation_id,
|
|
type: "direct",
|
|
read: contact.read,
|
|
last_message: lastMessage || null,
|
|
last_message_time: lastMessageTime || null,
|
|
last_message_sender: lastMessageSender || null,
|
|
};
|
|
} catch (error) {
|
|
console.error("Failed to insert contact:", error);
|
|
throw error;
|
|
}
|
|
}
|
|
|
|
async function getLatestMessage(conversation_id) {
|
|
const query = `
|
|
SELECT DISTINCT ON (m.conversation_id)
|
|
m.content AS last_message,
|
|
m.sent_at AS last_message_time,
|
|
a.username AS last_message_sender
|
|
FROM Messages m
|
|
JOIN Accounts a ON m.user_id = a.user_id
|
|
WHERE m.conversation_id = $1
|
|
ORDER BY m.conversation_id, m.sent_at DESC
|
|
LIMIT 1;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [conversation_id]);
|
|
|
|
return {
|
|
last_message: result.rows[0].last_message || null,
|
|
last_message_time: result.rows[0].last_message_time || null,
|
|
last_message_sender: result.rows[0].last_message_sender || null,
|
|
};
|
|
} catch (error) {
|
|
console.error("Failed to get latest message:", error);
|
|
return {
|
|
last_message: null,
|
|
last_message_time: null,
|
|
last_message_sender: null,
|
|
};
|
|
}
|
|
}
|
|
|
|
async function checkMembership(user_id, conversation_id) {
|
|
const query = `
|
|
SELECT EXISTS (
|
|
SELECT 1
|
|
FROM Memberships
|
|
WHERE user_id = $1
|
|
AND conversation_id = $2
|
|
) AS is_member;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [user_id, conversation_id]);
|
|
return result.rows[0].is_member;
|
|
} catch (error) {
|
|
console.error("Error checking membership:", error);
|
|
return false;
|
|
}
|
|
}
|
|
|
|
async function getContacts(user_id) {
|
|
const contactsQuery = `
|
|
WITH DirectContacts AS (
|
|
SELECT
|
|
c.contact_id AS id,
|
|
a.user_id AS user_id,
|
|
a.username AS username,
|
|
conv.last_active,
|
|
c.conversation_id,
|
|
conv.conversation_type AS type,
|
|
c.read
|
|
FROM Contacts c
|
|
JOIN Conversations conv ON c.conversation_id = conv.conversation_id
|
|
JOIN Memberships m ON m.conversation_id = c.conversation_id
|
|
JOIN Accounts a ON a.user_id = m.user_id
|
|
WHERE c.user_id = $1
|
|
AND conv.conversation_type = 'direct'
|
|
AND (a.user_id != $1 OR (SELECT COUNT(*) FROM Memberships WHERE conversation_id = c.conversation_id) = 1)
|
|
ORDER BY c.conversation_id, conv.last_active DESC
|
|
),
|
|
GroupContacts AS (
|
|
SELECT
|
|
c.contact_id AS id,
|
|
NULL::uuid AS user_id,
|
|
conv.name AS username,
|
|
conv.last_active,
|
|
c.conversation_id,
|
|
conv.conversation_type AS type,
|
|
c.read
|
|
FROM Contacts c
|
|
JOIN Conversations conv ON c.conversation_id = conv.conversation_id
|
|
WHERE c.user_id = $1
|
|
AND conv.conversation_type = 'group'
|
|
ORDER BY c.conversation_id, conv.last_active DESC
|
|
)
|
|
SELECT * FROM DirectContacts
|
|
UNION ALL
|
|
SELECT * FROM GroupContacts
|
|
ORDER BY last_active DESC;
|
|
`;
|
|
|
|
try {
|
|
// Execute the query with the user_id parameter
|
|
const contactsResult = await client.query(contactsQuery, [user_id]);
|
|
console.log(contactsResult.rows); // Debugging: log the results to verify
|
|
|
|
// Map the results to a more friendly format and fetch the latest message for each conversation
|
|
const contacts = await Promise.all(
|
|
contactsResult.rows.map(async (row) => {
|
|
const latestMessage = await getLatestMessage(row.conversation_id);
|
|
return {
|
|
id: row.id,
|
|
user_id: row.user_id,
|
|
username: row.username,
|
|
last_active: row.last_active,
|
|
conversation_id: row.conversation_id,
|
|
type: row.type,
|
|
read: row.read,
|
|
last_message: latestMessage.last_message || null,
|
|
last_message_time: latestMessage.last_message_time || null,
|
|
last_message_sender: latestMessage.last_message_sender || null,
|
|
};
|
|
}),
|
|
);
|
|
|
|
return contacts;
|
|
} catch (error) {
|
|
console.error("Failed to get contacts:", error);
|
|
return [];
|
|
}
|
|
}
|
|
|
|
async function deleteContact(user_id, conversation_id) {
|
|
// Check if the conversation is a group
|
|
const checkConversationTypeQuery = `
|
|
SELECT conversation_type FROM Conversations WHERE conversation_id = $1;
|
|
`;
|
|
|
|
try {
|
|
const conversationTypeResult = await client.query(
|
|
checkConversationTypeQuery,
|
|
[conversation_id],
|
|
);
|
|
if (conversationTypeResult.rows.length === 0) {
|
|
console.log(
|
|
"No conversation found with conversation_id: ",
|
|
conversation_id,
|
|
);
|
|
return {
|
|
message: "No conversation found with conversation_id: ",
|
|
conversation_id,
|
|
};
|
|
}
|
|
|
|
const conversationType = conversationTypeResult.rows[0].conversation_type;
|
|
|
|
if (conversationType === "group") {
|
|
console.log(" Remove the user from the group in the Memberships table");
|
|
const removeUserFromGroupQuery = `
|
|
DELETE FROM Memberships WHERE conversation_id = $1 AND user_id = $2;
|
|
`;
|
|
|
|
const removeConversationContactQuery = `
|
|
DELETE FROM Contacts WHERE conversation_id = $1 AND user_id = $2
|
|
`;
|
|
|
|
const removeContact = await client.query(removeConversationContactQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
]);
|
|
if (removeContact.rowCount === 0) {
|
|
console.log("No matching contact found with: ", {
|
|
conversation_id,
|
|
user_id,
|
|
});
|
|
return {
|
|
message: `No matching contact found with conversation id: ${conversation_id}, user id: ${user_id}`,
|
|
};
|
|
}
|
|
|
|
const removeConversationResult = await client.query(
|
|
removeUserFromGroupQuery,
|
|
[conversation_id, user_id],
|
|
);
|
|
if (removeConversationResult.rowCount === 0) {
|
|
console.log("No matching membership found with:", {
|
|
conversation_id,
|
|
user_id,
|
|
});
|
|
return {
|
|
message: `No matching membership found with conversation id: ${conversation_id} , user id: ${user_id}`,
|
|
};
|
|
} else {
|
|
console.log("Successfully removed user from group for: ", user_id);
|
|
}
|
|
} else {
|
|
// For direct conversations, proceed with deleting the contact
|
|
const query = `
|
|
DELETE FROM Contacts WHERE (user_id = $1 AND conversation_id = $2);
|
|
`;
|
|
const result = await client.query(query, [user_id, conversation_id]);
|
|
if (result.rowCount === 0) {
|
|
console.log("No matching contact found with:", {
|
|
user_id,
|
|
conversation_id,
|
|
});
|
|
return {
|
|
message: `No matching contact found with user id: ${user_id}, conversation id: ${conversation_id}`,
|
|
};
|
|
} else {
|
|
console.log("Successfully deleted contact for: ", user_id);
|
|
}
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to remove contact or user from group ", e);
|
|
}
|
|
}
|
|
|
|
async function updateContactStatus(user_id, conversation_id, read) {
|
|
const query = `
|
|
UPDATE Contacts SET read = $1
|
|
WHERE user_id = $2
|
|
AND conversation_id = $3;
|
|
`;
|
|
try {
|
|
await client.query(query, [read, user_id, conversation_id]);
|
|
await updateContactLastActive(user_id, conversation_id);
|
|
console.log(
|
|
`Successfully updated contact status, user_id: ${user_id}, conversation_id: ${conversation_id}, read: ${read}: `,
|
|
);
|
|
} catch (e) {
|
|
console.error("Failed to update contact status ", e);
|
|
}
|
|
}
|
|
|
|
async function updateContactLastActive(user_id, contact_id) {
|
|
const query = `
|
|
UPDATE Contacts
|
|
SET last_active = NOW()
|
|
WHERE user_id = $1
|
|
AND contact_id = $2;
|
|
`;
|
|
try {
|
|
await client.query(query, [user_id, contact_id]);
|
|
console.log("Successfully updated contact last active time");
|
|
} catch (e) {
|
|
console.error("Failed to update contact last active time ", e);
|
|
}
|
|
}
|
|
|
|
async function updateConversationLastActive(conversation_id, userId) {
|
|
const checkMembershipQuery = `
|
|
SELECT 1 FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2
|
|
LIMIT 1;
|
|
`;
|
|
|
|
const checkResult = await client.query(checkMembershipQuery, [
|
|
conversation_id,
|
|
userId,
|
|
]);
|
|
if (checkResult.rows.length === 0) {
|
|
console.error("User is not a member of the conversation");
|
|
}
|
|
|
|
const query = `
|
|
UPDATE Conversations
|
|
SET last_active = NOW()
|
|
WHERE conversation_id = $1
|
|
`;
|
|
try {
|
|
await client.query(query, [conversation_id]);
|
|
console.log("Successfully update conversation last active time");
|
|
} catch (e) {
|
|
console.error("Failed to update conversation last active time ", e);
|
|
}
|
|
}
|
|
|
|
async function getConversationsForUser(user_id) {
|
|
const query = `
|
|
SELECT DISTINCT m.conversation_id
|
|
FROM Memberships m
|
|
JOIN Conversations c ON m.conversation_id = c.conversation_id
|
|
WHERE m.user_id = $1
|
|
AND c.conversation_type = 'group';
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [user_id]);
|
|
return result.rows.map((row) => row.conversation_id);
|
|
} catch (error) {
|
|
console.error("Failed to get group conversations for user:", error);
|
|
return [];
|
|
}
|
|
}
|
|
|
|
async function contactSuggestion(username) {
|
|
const query = `
|
|
SELECT username FROM accounts
|
|
WHERE LOWER(username) LIKE $1
|
|
LIMIT 5;
|
|
`;
|
|
try {
|
|
const result = await client.query(query, [`%${username.toLowerCase()}%`]);
|
|
return result.rows.map((row) => row.username);
|
|
} catch (e) {
|
|
console.error("Failed to fetch contact suggestions", e);
|
|
return [];
|
|
}
|
|
}
|
|
|
|
async function deleteMessage(user_id, conversation_id, message_id) {
|
|
const checkMessageOwnershipQuery = `
|
|
SELECT user_id FROM Messages WHERE message_id = $1;
|
|
`;
|
|
|
|
const deleteMessageQuery = `
|
|
DELETE FROM Messages WHERE message_id = $1;
|
|
`;
|
|
|
|
try {
|
|
const isAdminResult = await isAdmin(user_id, conversation_id);
|
|
if (!isAdminResult) {
|
|
const ownershipResult = await client.query(checkMessageOwnershipQuery, [
|
|
message_id,
|
|
]);
|
|
if (ownershipResult.rows.length === 0) {
|
|
return { message: "Message not found." };
|
|
}
|
|
const messageOwnerId = ownershipResult.rows[0].user_id;
|
|
if (user_id !== messageOwnerId) {
|
|
console.error("User is not authorized to delete this message");
|
|
return { message: "It's not your message bro" };
|
|
}
|
|
}
|
|
const deleteResult = await client.query(deleteMessageQuery, [message_id]);
|
|
if (deleteResult.rowCount > 0) {
|
|
console.log("Message deleted successfully");
|
|
} else {
|
|
console.log("Failed to delete message");
|
|
return { message: "Failed to delete message" };
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to delete message ", e);
|
|
}
|
|
}
|
|
|
|
async function getMembers(conversation_id) {
|
|
const query = `
|
|
SELECT
|
|
a.user_id,
|
|
a.username,
|
|
CASE
|
|
WHEN ga.user_id IS NOT NULL THEN TRUE
|
|
ELSE FALSE
|
|
END AS isAdmin,
|
|
COALESCE(ga.is_owner, FALSE) AS isOwner
|
|
FROM Memberships m
|
|
JOIN Accounts a ON m.user_id = a.user_id
|
|
LEFT JOIN GroupAdmins ga ON m.user_id = ga.user_id AND m.conversation_id = ga.conversation_id
|
|
WHERE m.conversation_id = $1;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [conversation_id]);
|
|
const members = result.rows;
|
|
if (members.length > 0) {
|
|
return members;
|
|
} else {
|
|
return [];
|
|
}
|
|
} catch (e) {
|
|
console.error(
|
|
`Failed to get members for conversation_id ${conversation_id}`,
|
|
e,
|
|
);
|
|
return [];
|
|
}
|
|
}
|
|
|
|
async function isAdmin(user_id, conversation_id) {
|
|
const query = `
|
|
SELECT 1 FROM GroupAdmins
|
|
WHERE user_id = $1
|
|
AND conversation_id = $2;
|
|
`;
|
|
try {
|
|
const result = await client.query(query, [user_id, conversation_id]);
|
|
return result.rows.length > 0;
|
|
} catch (e) {
|
|
console.error("Failed to check admin status", e);
|
|
return false;
|
|
}
|
|
}
|
|
|
|
async function getGroupAdmins(conversation_id) {
|
|
const query = `
|
|
SELECT user_id, granted_by
|
|
FROM GroupAdmins
|
|
WHERE conversation_id = $1;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [conversation_id]);
|
|
const admins = result.rows.map((row) => ({
|
|
user_id: row.user_id,
|
|
granted_by: row.granted_by,
|
|
}));
|
|
return admins;
|
|
} catch (e) {
|
|
console.error(
|
|
`Failed to get admins for conversation_id ${conversation_id}`,
|
|
e,
|
|
);
|
|
return null;
|
|
}
|
|
}
|
|
|
|
async function removeUserFromGroupById(conversation_id, user_id) {
|
|
const removeUserFromGroupQuery = `
|
|
DELETE FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2;
|
|
`;
|
|
|
|
try {
|
|
// Check if the user being removed is the owner
|
|
const isOwner = await isGroupOwner(user_id, conversation_id);
|
|
if (isOwner) {
|
|
return { message: "Cannot remove the group owner" };
|
|
}
|
|
|
|
const removeMembershipResult = await client.query(
|
|
removeUserFromGroupQuery,
|
|
[conversation_id, user_id],
|
|
);
|
|
|
|
if (removeMembershipResult.rowCount === 0) {
|
|
return {
|
|
message: `No membership found for user_id: ${user_id} in conversation_id: ${conversation_id}`,
|
|
};
|
|
}
|
|
|
|
// Also remove from GroupAdmins if they were an admin
|
|
await client.query(
|
|
`
|
|
DELETE FROM GroupAdmins
|
|
WHERE conversation_id = $1 AND user_id = $2;
|
|
`,
|
|
[conversation_id, user_id],
|
|
);
|
|
|
|
return null;
|
|
} catch (e) {
|
|
console.error("Failed to remove user from group ", e);
|
|
return {
|
|
message: `Failed to remove user_id: ${user_id} from conversation_id: ${conversation_id}`,
|
|
error: e.message,
|
|
};
|
|
}
|
|
}
|
|
|
|
async function isConversationMember(user_id, conversation_id) {
|
|
const query = `
|
|
SELECT EXISTS (
|
|
SELECT 1
|
|
FROM Memberships
|
|
WHERE user_id = $1
|
|
AND conversation_id = $2
|
|
) AS is_member;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [user_id, conversation_id]);
|
|
return result.rows[0].is_member;
|
|
} catch (e) {
|
|
console.error(
|
|
`Failed to verify membership for user_id: ${user_id} in conversation_id: ${conversation_id}`,
|
|
e,
|
|
);
|
|
return false;
|
|
}
|
|
}
|
|
|
|
async function addAdministrator(conversation_id, user_id, granted_by) {
|
|
const checkMembershipQuery = `
|
|
SELECT 1 FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2
|
|
LIMIT 1;
|
|
`;
|
|
|
|
const addAdminQuery = `
|
|
INSERT INTO GroupAdmins (conversation_id, user_id, granted_by, is_owner)
|
|
VALUES ($1, $2, $3, false)
|
|
RETURNING granted_at;
|
|
`;
|
|
|
|
try {
|
|
// Check if the granter is the owner
|
|
const isOwner = await isGroupOwner(granted_by, conversation_id);
|
|
if (!isOwner) {
|
|
console.error("Only the group owner can add administrators");
|
|
return { message: "Only the group owner can add administrators" };
|
|
}
|
|
|
|
// Check if user is a member
|
|
const membershipCheck = await client.query(checkMembershipQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
]);
|
|
if (membershipCheck.rows.length === 0) {
|
|
console.error("User is not a member of the conversation");
|
|
return { message: "User is not a member of this conversation" };
|
|
}
|
|
|
|
const result = await client.query(addAdminQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
granted_by,
|
|
]);
|
|
console.log("User added as admin successfully");
|
|
return result.rows[0].granted_at;
|
|
} catch (e) {
|
|
console.error("Failed to add administrator ", e);
|
|
return { message: "Failed to add administrator" };
|
|
}
|
|
}
|
|
|
|
async function removeAdministrator(conversation_id, user_id, removed_by) {
|
|
const removeAdminQuery = `
|
|
DELETE FROM GroupAdmins
|
|
WHERE conversation_id = $1
|
|
AND user_id = $2
|
|
RETURNING user_id;
|
|
`;
|
|
|
|
const checkMembershipQuery = `
|
|
SELECT 1 FROM Memberships
|
|
WHERE conversation_id = $1 AND user_id = $2
|
|
LIMIT 1;
|
|
`;
|
|
|
|
try {
|
|
const isOwner = await isGroupOwner(removed_by, conversation_id);
|
|
if (!isOwner) {
|
|
console.error("Only the group owner can remove administrators");
|
|
return { message: "Only the group owner can remove administrators" };
|
|
}
|
|
|
|
const membershipCheck = await client.query(checkMembershipQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
]);
|
|
if (membershipCheck.rows.length === 0) {
|
|
console.error("User is not a member of the conversation");
|
|
return { message: "User is not a member of this group" };
|
|
}
|
|
|
|
const removeAdminResult = await client.query(removeAdminQuery, [
|
|
conversation_id,
|
|
user_id,
|
|
]);
|
|
if (removeAdminResult.rows.length > 0) {
|
|
return null;
|
|
} else {
|
|
return { message: "User is not an administrator of this group" };
|
|
}
|
|
} catch (e) {
|
|
console.error("Failed to remove administrator ", e);
|
|
return { message: "Failed to remove administrator" };
|
|
}
|
|
}
|
|
|
|
async function isGroupOwner(user_id, conversation_id) {
|
|
const query = `
|
|
SELECT EXISTS (
|
|
SELECT 1 FROM GroupAdmins
|
|
WHERE conversation_id = $1
|
|
AND user_id = $2
|
|
AND is_owner = true
|
|
) AS is_owner;
|
|
`;
|
|
|
|
try {
|
|
const result = await client.query(query, [conversation_id, user_id]);
|
|
return result.rows[0].is_owner;
|
|
} catch (e) {
|
|
console.error("Failed to check owner status", e);
|
|
return false;
|
|
}
|
|
}
|
|
|
|
module.exports = {
|
|
client,
|
|
insertUser,
|
|
insertMessage,
|
|
checkUserExist,
|
|
changePassword,
|
|
getPassword,
|
|
insertContact,
|
|
deleteContact,
|
|
getMessages,
|
|
getUserId,
|
|
getContacts,
|
|
updateContactStatus,
|
|
createGroup,
|
|
addMemberToGroupByUsername,
|
|
getConversationsForUser,
|
|
contactSuggestion,
|
|
deleteMessage,
|
|
getMembers,
|
|
removeUserFromGroupById,
|
|
isConversationMember,
|
|
isAdmin,
|
|
addAdministrator,
|
|
removeAdministrator,
|
|
};
|