heart2heart/src/db.js

200 lines
7.8 KiB
JavaScript

import pg from 'pg';
import fs from 'fs';
import { convertMsgType, logError } from './utils.js';
import { exec } from 'child_process';
const { Client } = pg;
const getClient = async () => {
const client = new Client({
user: process.env.POSTGRES_USER,
password: process.env.POSTGRES_PASSWORD,
host: process.env.POSTGRES_HOST,
port: process.env.POSTGRES_PORT,
database: process.env.POSTGRES_DB
});
await client.connect();
await client.query(fs.readFileSync('./scheme.psql').toString());
if ((await client.query("SELECT * FROM cities")).rowCount < 6079) {
await client.query("DELETE FROM cities");
//Not sure if pg has support for such kind of things, sooooooooo
exec(`psql -h ${process.env.POSTGRES_HOST} -p ${process.env.POSTGRES_PORT} -d ${process.env.POSTGRES_DB} -U ${process.env.POSTGRES_USER} -f ./cities.sql`, (error) => {
if (error) logError(error);
})
}
return client;
};
export const db = await getClient();
const getAmountOfUserPictures = async (roomId) => {
return (await db.query("SELECT COUNT(*) FROM media WHERE owner = $1 AND purpose = 'p'", [roomId])).rows[0].count;
};
const getCurrentUserAction = async (roomId) => {
return (await db.query('SELECT current_action FROM users WHERE room_id = $1', [roomId])).rows[0].current_action;
};
const setUserState = async (roomId, state) => {
await db.query("UPDATE users SET current_action = $1 WHERE room_id = $2", [state, roomId]);
};
const appendUserPictures = async (roomId, mxc, type) => {
await db.query("INSERT INTO media (owner, type, purpose, url) VALUES ($1, $2, 'p', $3)", [roomId, type, mxc]);
};
const eraseUser = async (roomId) => {
await db.query("DELETE FROM users WHERE room_id = $1", [roomId]);
};
const eraseUserLikes = async (roomId) => {
await db.query("DELETE FROM likes WHERE sender = $1 OR recipient = $1", [roomId]);
};
const eraseUserMedia = async (roomId) => {
await db.query("DELETE FROM media WHERE owner = $1", [roomId]);
};
const selectProfilesForUser = async (roomId) => {
let myInterest = (await db.query("SELECT interest FROM users WHERE room_id = $1", [roomId])).rows[0].interest;
let mySex = (await db.query("SELECT sex FROM users WHERE room_id = $1", [roomId])).rows[0].sex;
let userAge = (await db.query("SELECT age FROM users WHERE room_id = $1", [roomId])).rows[0].age;
//Selecting profiles other than user's and with difference in age +-2.
let user;
if (myInterest === 'b') // both, no matter what sex
user = (await db.query(`SELECT
room_id, name, age, sex, description, country, city FROM users
WHERE
age::numeric <@ ANY(ARRAY[numrange($1 - 2, $1 + 2)])
AND room_id != $2
AND (interest = $3 OR interest = 'b')
ORDER BY RANDOM()
LIMIT 1`, [userAge, roomId, mySex])
).rows[0];
else {
user = (await db.query(`SELECT
room_id, name, age, sex, description, country, city FROM users
WHERE
age::numeric <@ ANY(ARRAY[numrange($1 - 2, $1 + 2)])
AND room_id != $2
AND sex = $3
AND (interest = $4 OR interest = 'b')
ORDER BY RANDOM()
LIMIT 1`, [userAge, roomId, myInterest, mySex])
).rows[0];
}
if (!user) return null;
let media = await getUserProfilePictures(user.room_id);
user.media = media;
return user;
};
const setUserCurrentlyViewingProfile = async (roomId, anotherRoomId) => {
await db.query("UPDATE users SET currently_viewing = $1 WHERE room_id = $2", [anotherRoomId, roomId]);
};
const getUserCurrentlyViewingProfile = async (roomId) => {
return (await db.query("SELECT currently_viewing FROM users WHERE room_id = $1", [roomId])).rows[0].currently_viewing;
};
//Newlike is a room id of a user who was liked_profiles
const appendUserLikes = async (roomId, newLike) => {
//We need to delete likes that was read from both, so we can add a new (the same) like.
await db.query(`DELETE FROM likes l1
USING likes l2
WHERE l1.sender = l2.recipient
AND l1.recipient = l2.sender
AND l1.read = TRUE
AND l2.read = TRUE`);
await db.query("INSERT INTO likes (sender, recipient) VALUES ($1, $2) ON CONFLICT DO NOTHING", [roomId, newLike]);
};
const getUserLikes = async (roomId) => {
return (await db.query("SELECT recipient FROM likes WHERE sender = $1", [roomId])).rows[0].recipient;
};
const checkForMutualLike = async (roomId1, roomId2) => {
return (await db.query(`SELECT COUNT(*) > 0 AS value
FROM likes l1
JOIN likes l2 ON l1.sender = l2.recipient AND l1.recipient = l2.sender
WHERE (l1.read = FALSE OR l2.read = FALSE)
AND l1.sender = $1
AND l1.recipient = $2`, [roomId1, roomId2])).rows[0].value;
};
const getProfileInfo = async (roomId) => {
let user = (await db.query("SELECT mx_id, room_id, name, age, sex, description, country, city FROM users WHERE room_id = $1", [roomId])).rows[0];
if (!user) return null;
let media = await getUserProfilePictures(user.room_id);
user.media = media;
return user;
};
const getUserProfilePictures = async (roomId) => {
return (await db.query("SELECT url, type FROM media WHERE owner = $1 AND purpose = 'p'", [roomId])).rows;
};
const getAllLikesForUser = async (roomId) => {
return (await db.query("SELECT sender FROM likes WHERE recipient = $1 AND read = FALSE", [roomId])).rows;
};
const markLikeAsRead = async (roomId, recipient,) => {
await db.query("UPDATE likes SET read = TRUE WHERE sender = $1 AND recipient = $2", [roomId, recipient]);
};
const uploadMediaAsMessage = async (roomId, type, mxc) => {
await db.query("INSERT INTO media(owner, type, purpose, url) VALUES ($1, $2, 'm', $3)", [roomId, convertMsgType(type), mxc]);
};
const insertMessageIntoDB = async (roomId, recipient, type, content) => {
let rowAmount = (await db.query("INSERT INTO messages (sender, recipient, type, content) VALUES ($1, $2, $3, $4) ON CONFLICT(sender, recipient) DO NOTHING RETURNING *", [roomId, recipient, convertMsgType(type), content])).rowCount;
return rowAmount == 1;
};
const getUnreadMessages = async (roomId) => {
return (await db.query("SELECT (SELECT mx_id FROM users WHERE room_id = sender LIMIT 1), sender, type, content FROM messages WHERE recipient = $1 AND read = FALSE", [roomId])).rows
};
const markMessageAsRead = async (roomId, recipient) => {
return (await db.query("UPDATE messages SET read = TRUE WHERE sender = $1 AND recipient = $2", [roomId, recipient]));
}
const setUserLanguage = async (roomId, language) => {
await db.query("UPDATE users SET language = $1 WHERE room_id = $2", [language, roomId]);
}
const getUserLanguage = async (roomId) => {
return (await db.query("SELECT language FROM users WHERE room_id = $1", [roomId])).rows[0].language;
}
export {
eraseUser,
appendUserPictures,
setUserState,
getCurrentUserAction,
getAmountOfUserPictures,
selectProfilesForUser,
setUserCurrentlyViewingProfile,
getUserCurrentlyViewingProfile,
appendUserLikes,
getUserLikes,
checkForMutualLike,
getProfileInfo,
getAllLikesForUser,
markLikeAsRead,
eraseUserLikes,
eraseUserMedia,
uploadMediaAsMessage,
insertMessageIntoDB,
getUnreadMessages,
markMessageAsRead,
setUserLanguage,
getUserLanguage
};