Files
relay/server/db/db.js

780 lines
22 KiB
JavaScript

const { Client } = require("pg");
const crypto = require("crypto");
const { callback } = require("pg/lib/native/query");
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 {
// Create Accounts Table
await client.query(`
CREATE TABLE IF NOT EXISTS Accounts (
user_id SERIAL PRIMARY KEY,
username VARCHAR(255) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_username ON Accounts (username);
`);
} catch (e) {
console.error("Failed to create Accounts table: ", e);
}
try {
// Create Conversations Table
await client.query(`
CREATE TABLE IF NOT EXISTS Conversations (
conversation_id SERIAL PRIMARY KEY,
conversation_type VARCHAR(10) NOT NULL CHECK (conversation_type IN ('direct', 'group')),
name VARCHAR(255),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_conversation_type ON Conversations (conversation_type);
`);
} catch (e) {
console.error("Failed to create Conversations table: ", e);
}
try {
// Create Messages Table
await client.query(`
CREATE TABLE IF NOT EXISTS Messages (
message_id SERIAL PRIMARY KEY,
conversation_id INT REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
user_id INT REFERENCES Accounts(user_id) ON DELETE CASCADE,
content TEXT NOT NULL,
attachment_urls TEXT[],
sent_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
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);
`);
} catch (e) {
console.error("Failed to create Messages table: ", e);
}
try {
// Create Memberships Table
await client.query(`
CREATE TABLE IF NOT EXISTS Memberships (
conversation_id INT REFERENCES Conversations(conversation_id) ON DELETE CASCADE,
user_id INT REFERENCES Accounts(user_id) ON DELETE CASCADE,
joined_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
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);
`);
} catch (e) {
console.error("Failed to create Memberships table: ", e);
}
try {
await client.query(`
CREATE TABLE IF NOT EXISTS Contacts (
contact_id SERIAL PRIMARY KEY,
user_id INT REFERENCES Accounts(user_id) ON DELETE CASCADE,
contact_user_id INT NOT NULL REFERENCES Accounts(user_id) ON DELETE CASCADE,
read BOOLEAN NOT NULL DEFAULT FALSE,
last_active TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_contact UNIQUE (user_id, contact_user_id)
);
CREATE INDEX IF NOT EXISTS idx_contacts_user_id ON Contacts (user_id);
CREATE INDEX IF NOT EXISTS idx_contacts_contact_user_id ON Contacts (contact_user_id);
`);
console.log("Contacts table created successfully.");
} catch (e) {
console.error("Failed to create Contacts table: ", e);
}
}
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) {
console.log("GETUSERID: ", result.rows[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 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 result = await client.query(query, [
conversation_id,
senderId,
content,
attachmentUrls,
]);
console.log("insertmessageresult: ", result.rows);
return result.rows[0];
} catch (e) {
console.error("Failed to insert message ", e);
}
}
async function createGroup(user_id, groupname) {
const query = `
INSERT INTO Conversations (conversation_type, name)
VALUES ('group', $1)
RETURNING conversation_id AS group_id;
`;
try {
const result = await client.query(query, [groupname]);
const group_id = result.rows[0].group_id;
const contact_user_id = await addMemberToGroup(group_id, user_id);
return { group_id, contact_user_id };
} catch (e) {
console.error("Failed to create conversation ", e);
return null;
}
}
async function addMemberToGroup(conversation_id, user_id) {
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 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}`,
);
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 getConversationId(senderUsername, receiverUsername) {
console.log(
`kldsdfjklsdfjklsdjfkl , senderUsername: ${senderUsername}, receiverUsername: ${receiverUsername}`,
);
const query = `
SELECT conversation_id FROM Conversations
WHERE conversation_type = 'direct'
AND EXISTS (
SELECT 1 FROM Memberships WHERE conversation_id = Conversations.conversation_id AND user_id = $1
)
AND EXISTS (
SELECT 1 FROM Memberships WHERE conversation_id = Conversations.conversation_id AND user_id = $2
)
LIMIT 1;
`;
try {
const result = await client.query(query, [
senderUsername,
receiverUsername,
]);
if (result.rowCount > 0) {
return result.rows[0].conversation_id;
} else {
console.log("No conversation found between these users.");
return null;
}
} catch (e) {
console.error("Failed to get conversation id ", e);
}
}
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 insertContact(userUsername, receiverUsername, read) {
const query = `
WITH sender AS (
SELECT user_id
FROM Accounts
WHERE LOWER(username) = $1
LIMIT 1
),
receiver AS (
SELECT user_id
FROM Accounts
WHERE LOWER(username) = $2
LIMIT 1
),
existing_conversation AS (
SELECT conversation_id
FROM Conversations
WHERE conversation_type = 'direct'
AND EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = Conversations.conversation_id
AND user_id = (SELECT user_id FROM sender)
)
AND EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = Conversations.conversation_id
AND user_id = (SELECT user_id FROM receiver)
)
LIMIT 1
),
new_conversation AS (
INSERT INTO Conversations (conversation_type)
SELECT 'direct'
WHERE NOT EXISTS (SELECT 1 FROM existing_conversation)
RETURNING conversation_id
),
final_conversation AS (
SELECT conversation_id FROM existing_conversation
UNION ALL
SELECT conversation_id FROM new_conversation
),
insert_memberships AS (
INSERT INTO Memberships (conversation_id, user_id)
SELECT conversation_id, user_id
FROM final_conversation, sender
WHERE NOT EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = final_conversation.conversation_id
AND user_id = sender.user_id
)
UNION ALL
SELECT conversation_id, user_id
FROM final_conversation, receiver
WHERE NOT EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = final_conversation.conversation_id
AND user_id = receiver.user_id
)
),
insert_contact AS (
INSERT INTO Contacts (user_id, contact_user_id, read, last_active)
SELECT (SELECT user_id FROM sender), (SELECT user_id FROM receiver), $3, CURRENT_TIMESTAMP
ON CONFLICT DO NOTHING
RETURNING contact_id AS id, contact_user_id AS user_id, last_active, (SELECT conversation_id FROM final_conversation) AS conversation_id
)
SELECT
ic.id,
ic.user_id,
a.username AS username,
ic.last_active,
'direct' AS type,
ic.conversation_id
FROM insert_contact ic
JOIN Accounts a ON a.user_id = ic.user_id;
`;
try {
const result = await client.query(query, [
userUsername,
receiverUsername,
read,
]);
if (result.rows.length > 0) {
return result.rows[0];
}
return null;
} catch (e) {
console.error("Failed to insert contact:", e);
return null;
}
}
async function getConversationId(senderUsername, receiverUsername) {
const query = `
SELECT conversation_id FROM Conversations
WHERE conversation_type = 'direct'
AND EXISTS (
SELECT 1 FROM Memberships WHERE conversation_id = Conversations.conversation_id AND user_id = (SELECT user_id FROM Accounts WHERE username = $1)
)
AND EXISTS (
SELECT 1 FROM Memberships WHERE conversation_id = Conversations.conversation_id AND user_id = (SELECT user_id FROM Accounts WHERE username = $2)
)
LIMIT 1;
`;
try {
const result = await client.query(query, [
senderUsername,
receiverUsername,
]);
if (result.rowCount > 0) {
return result.rows[0].conversation_id;
} else {
console.log("No conversation found between these users.");
return null;
}
} catch (e) {
console.error("Failed to get conversation id ", e);
return null;
}
}
async function getContacts(user_id) {
const contactsQuery = `
SELECT
c.contact_id AS id,
c.contact_user_id AS user_id,
a.username AS username,
c.last_active,
m.conversation_id,
'direct' AS type
FROM Contacts c
JOIN Accounts a ON a.user_id = c.contact_user_id
JOIN Memberships m ON m.user_id = c.contact_user_id AND m.conversation_id = (
SELECT conversation_id
FROM Conversations
WHERE conversation_type = 'direct'
AND EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = Conversations.conversation_id
AND user_id = $1
)
AND EXISTS (
SELECT 1
FROM Memberships
WHERE conversation_id = Conversations.conversation_id
AND user_id = c.contact_user_id
)
LIMIT 1
)
WHERE c.user_id = $1
ORDER BY c.last_active DESC;
`;
const groupsQuery = `
SELECT
c.conversation_id AS id,
c.name AS username,
c.created_at AS last_active,
c.conversation_type AS type
FROM Memberships m
JOIN Conversations c ON m.conversation_id = c.conversation_id
WHERE m.user_id = $1 AND c.conversation_type = 'group'
ORDER BY c.created_at DESC;
`;
try {
const contactsResult = await client.query(contactsQuery, [user_id]);
const groupsResult = await client.query(groupsQuery, [user_id]);
const contacts = contactsResult.rows;
const groups = groupsResult.rows.map((group) => ({
username: group.username,
last_active: group.last_active,
type: group.type,
conversation_id: group.id,
}));
// Combine contacts and groups
const combinedContacts = [...contacts, ...groups];
return combinedContacts;
} catch (e) {
console.error("Failed to get contacts and groups:", e);
return [];
}
}
async function deleteContact(user_id, contact_id) {
const query = `
DELETE FROM Contacts
WHERE (user_id = $1 AND contact_id = $2)
`;
try {
const result = await client.query(query, [user_id, contact_id]);
if (result.rowCount === 0) {
console.log("No matching contact found with:", {
user_id,
contact_id,
});
} else {
console.log("Successfully deleted contact for: ", user_id);
}
} catch (e) {
console.error("Failed to remove contact ", e);
}
}
async function updateContactStatus(userUsername, contact_user_id, read) {
const query = `
WITH users AS (
SELECT
(SELECT user_id FROM Accounts WHERE username = $2) as user_id,
(SELECT user_id FROM Accounts WHERE username = $3) as contact_user_id
)
UPDATE Contacts SET read = $1
WHERE user_id = (SELECT user_id FROM users)
AND contact_user_id = (SELECT contact_user_id FROM users);
`;
try {
await client.query(query, [read, userUsername, contact_user_id]);
await updateContactLastActive(userUsername, contact_user_id);
console.log("Successfully updated contact status");
} catch (e) {
console.error("Failed to update contact status ", e);
}
}
async function updateContactLastActive(userUsername, receiverUsername) {
const timestamp = getTime();
const query = `
UPDATE Contacts
SET last_active = $1
WHERE user_id = (SELECT user_id FROM Accounts WHERE username = $2)
AND contact_user_id = (SELECT user_id FROM Accounts WHERE username = $3);
`;
try {
await client.query(query, [timestamp, userUsername, receiverUsername]);
console.log("Successfully updated contact last active time");
} catch (e) {
console.error("Failed to update contact last active time ", e);
}
}
async function getConversationsForUser(user_id) {
const query = `
SELECT conversation_id
FROM Memberships
WHERE user_id = $1;
`;
try {
const result = await client.query(query, [user_id]);
const conversationIds = result.rows.map((row) => row.conversation_id);
console.log("getconversationsforuser: ", conversationIds);
return conversationIds;
} catch (e) {
console.error("Failed to get conversations for user ", e);
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, message_id) {
const checkMessageOwnershipQuery = `
SELECT user_id FROM Messages WHERE message_id = $1;
`;
const deleteMessageQuery = `
DELETE FROM Messages WHERE message_id = $1;
`;
try {
const checkResult = await client.query(checkMessageOwnershipQuery, [
message_id,
]);
if (checkResult.rows.length === 0) {
return { message: "Message not found." };
}
const messageOwnerId = checkResult.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");
}
} catch (e) {
console.error("Failed to delete message ", e);
}
}
async function getMembers(conversation_id) {
const query = `
SELECT
a.user_id,
a.username
FROM Memberships m
JOIN Accounts a ON m.user_id = a.user_id
WHERE m.conversation_id = $1;
`;
try {
const result = await client.query(query, [conversation_id]);
const members = result.rows;
if (members.length > 0) {
console.log(`Members of conversation_id ${conversation_id}:`, members);
return members;
} else {
console.log(`No members found for conversation_id ${conversation_id}.`);
return [];
}
} catch (e) {
console.error(
`Failed to get members for conversation_id ${conversation_id}`,
e,
);
return null;
}
}
function getTime() {
return new Date();
}
module.exports = {
client,
insertUser,
insertMessage,
checkUserExist,
changePassword,
getPassword,
insertContact,
deleteContact,
getMessages,
getUserId,
getContacts,
updateContactStatus,
updateContactLastActive,
createGroup,
addMemberToGroup,
addMemberToGroupByUsername,
getConversationsForUser,
contactSuggestion,
deleteMessage,
getMembers,
};