import * as crypto from 'crypto'; import ConcurrentQueue from "../../concurrent-queue/concurrent-queue"; import * as sqlite from 'sqlite'; import * as sqlite3 from 'sqlite3'; import { Channel, GuildMetadataWithIds, Member, Message, Resource, SocketConfig } from "./data-types"; export default class PersonalDB { private transactions = new ConcurrentQueue(1); private constructor( private readonly db: sqlite.Database ) {} public static async create(filePath: string): Promise { return new PersonalDB( await sqlite.open({ driver: sqlite3.Database, filename: filePath }) ); } async open(): Promise { await this.db.open(); } async close(): Promise { await this.db.close(); } async beginTransaction(): Promise { await this.db.run('BEGIN TRANSACTION'); } async rollbackTransaction(): Promise { await this.db.run('ROLLBACK'); } async commitTransaction(): Promise { await this.db.run('COMMIT'); } async queueTransaction(func: (() => Promise)): Promise { await this.transactions.push(async () => { try { await this.beginTransaction(); await func(); await this.commitTransaction(); } catch (e) { await this.rollbackTransaction(); throw e; } }); } async init(): Promise { await this.queueTransaction(async () => { // NOTE: Guild ID is not shared between instances of corDis await this.db.run(` CREATE TABLE IF NOT EXISTS guilds ( id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT , name TEXT , icon_resource_id TEXT , member_id TEXT ) `); await this.db.run(` CREATE TABLE IF NOT EXISTS guild_sockets ( id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT , guild_id INTEGER NOT NULL , url TEXT NOT NULL , cert TEXT NOT NULL , public_key TEXT NOT NULL , private_key TEXT NOT NULL , FOREIGN KEY (guild_id) REFERENCES guilds(id) ) `); await this.db.run(` CREATE TABLE IF NOT EXISTS members ( id TEXT NOT NULL , guild_id INTEGER NOT NULL REFERENCES guilds(id) , display_name TEXT NOT NULL , status TEXT NOT NULL , avatar_resource_id TEXT NOT NULL , role_name TEXT , role_color TEXT , role_priority INTEGER , privileges TEXT , CONSTRAINT members_id_guild_id_con UNIQUE (id, guild_id) ) `); await this.db.run(` CREATE TABLE IF NOT EXISTS channels ( id TEXT NOT NULL , guild_id INTEGER NOT NULL REFERENCES guilds(id) , "index" INTEGER NOT NULL , name TEXT NOT NULL , flavor_text TEXT , CONSTRAINT channels_id_guild_id_con UNIQUE (id, guild_id) ) `); await this.db.run(` CREATE TABLE IF NOT EXISTS resources ( id TEXT NOT NULL , guild_id INTEGER NOT NULL REFERENCES guilds(id) , hash BLOB NOT NULL , data BLOB NOT NULL , data_size INTEGER NOT NULL , last_used INTEGER NOT NULL , CONSTRAINT resources_id_guild_id_con UNIQUE (id, guild_id) ) `); await this.db.run('CREATE INDEX IF NOT EXISTS resources_data_size_idx ON resources (data_size)'); // note: no foreign key on resource_id since we may not have cached the resource yet await this.db.run(` CREATE TABLE IF NOT EXISTS messages ( id TEXT NOT NULL , guild_id INTEGER NOT NULL REFERENCES guilds(id) , channel_id TEXT NOT NULL REFERENCES channels(id) , member_id TEXT NOT NULL REFERENCES members(id) , sent_dtg INTEGER NOT NULL , text TEXT , resource_id TEXT , resource_name TEXT , resource_width INTEGER , resource_height INTEGER , resource_preview_id TEXT , CONSTRAINT messages_id_guild_id_con UNIQUE (id, guild_id) ) `); await this.db.run('CREATE INDEX IF NOT EXISTS messages_id_idx ON messages (id)'); await this.db.run('CREATE INDEX IF NOT EXISTS messages_sent_dtg_idx ON messages (sent_dtg)'); }); } // dangerous! async reset(): Promise { await this.queueTransaction(async () => { await this.db.run('DROP TABLE IF EXISTS guilds'); await this.db.run('DROP TABLE IF EXISTS guild_sockets'); await this.db.run('DROP TABLE IF EXISTS members'); await this.db.run('DROP TABLE IF EXISTS channels'); await this.db.run('DROP TABLE IF EXISTS resources'); await this.db.run('DROP TABLE IF EXISTS messages'); }); } // Guilds async addGuild(name: string, iconResourceId: string, memberId: string): Promise { let result = await this.db.run( `INSERT INTO guilds (name, icon_resource_id, member_id) VALUES (:name, :icon_resource_id, :member_id)`, { ':name': name, ':icon_resource_id': iconResourceId, ':member_id': memberId } ); if (result.changes !== 1) throw new Error('unable to add guild'); if (result.lastID === undefined) throw new Error('unable to get guild last id'); return result.lastID as number; } async removeGuild(guildId: number): Promise { let result = await this.db.run( `DELETE FROM guilds WHERE id=:id`, { ':id': guildId } ); if (result?.changes !== 1) throw new Error('unable to remove guild'); } async updateGuildName(guildId: number, newName: string): Promise { let result = await this.db.run( `UPDATE guilds SET name=:name WHERE id=:guild_id`, { ':guild_id': guildId, ':name': newName } ); if (result?.changes !== 1) throw new Error('unable to update guild name'); } async updateGuildIcon(guildId: number, newIconResourceId: string): Promise { let result = await this.db.run( `UPDATE guilds SET icon_resource_id=:icon_resource_id WHERE id=:guild_id`, { ':guild_id': guildId, ':icon_resource_id': newIconResourceId } ); if (result?.changes !== 1) throw new Error('unable to update guild icon'); } async fetchGuild(guildId: number): Promise { let result = await this.db.get( `SELECT * FROM guilds WHERE id=:id`, { ':id': guildId } ); if (!result) throw new Error('unable to fetch guild'); return GuildMetadataWithIds.fromDBData(result); } async fetchGuilds(): Promise { let result = await this.db.all('SELECT * FROM guilds'); return result.map(dataGuild => GuildMetadataWithIds.fromDBData(dataGuild)); } // Guild Sockets async addGuildSocket(guildId: number, url: string, cert: string, publicKey: crypto.KeyObject, privateKey: crypto.KeyObject): Promise { let publicKeyPem = publicKey.export({ type: 'spki', format: 'pem' }); let privateKeyPem = privateKey.export({ type: 'pkcs8', format: 'pem' }); let result = await this.db.run( `INSERT INTO guild_sockets (guild_id, url, cert, public_key, private_key) VALUES (:guild_id, :url, :cert, :public_key, :private_key)`, { ':guild_id': guildId, ':url': url, ':cert': cert, ':public_key': publicKeyPem, ':private_key': privateKeyPem } ); if (result.changes !== 1) throw new Error('unable to add guild'); return result.lastID as number; } async removeGuildSocket(guildId: number, guildSocketId: number): Promise { let result = await this.db.run( `DELETE FROM guild_sockets WHERE id=:guild_socket_id AND guild_id=:guild_id`, { ':guild_id': guildId, ':guild_socket_id': guildSocketId } ); if (result?.changes !== 1) throw new Error('unable to remove guild'); } async removeGuildSockets(guildId: number): Promise { let result = await this.db.run( `DELETE FROM guild_sockets WHERE guild_id=:guild_id`, { ':guild_id': guildId } ); if (result?.changes !== 1) throw new Error('unable to remove guild'); } async fetchGuildSockets(guildId: number): Promise { let result = await this.db.all( `SELECT * FROM guild_sockets WHERE guild_id=:guild_id`, { ':guild_id': guildId } ); return result.map(dataGuildSocket => SocketConfig.fromDBData(dataGuildSocket)); } async fetchGuildSocket(guildId: number, guildSocketId: number): Promise { let result = await this.db.get( `SELECT * FROM guild_sockets WHERE id=:guild_socket_id AND guild_id=:guild_id`, { ':guild_socket_id': guildSocketId, ':guild_id': guildId } ); if (!result) throw new Error('unable to fetch specific guild socket'); return SocketConfig.fromDBData(result); } // Members async addMembers(guildId: number, members: Member[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `INSERT INTO members ( id, guild_id, display_name, status, avatar_resource_id , role_name, role_color, role_priority, privileges ) VALUES ( :id, :guild_id, :display_name, :status, :avatar_resource_id , :role_name, :role_color, :role_priority, :privileges )` ); for (let member of members) { await stmt.run({ ':id': member.id, ':guild_id': guildId, ':display_name': member.displayName, ':status': member.status, ':avatar_resource_id': member.avatarResourceId , ':role_name': member.roleName, ':role_color': member.roleColor, ':role_priority': member.rolePriority, ':privileges': member.privileges.join(',') }); } await stmt.finalize(); }); } async updateMembers(guildId: number, newMembers: Member[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `UPDATE members SET display_name=:display_name, status=:status, avatar_resource_id=:avatar_resource_id , role_name=:role_name, role_color=:role_color, role_priority=:role_priority, privileges=:privileges WHERE id=:id AND guild_id=:guild_id` ); for (let member of newMembers) { await stmt.run({ ':id': member.id, ':guild_id': guildId, ':display_name': member.displayName, ':status': member.status, ':avatar_resource_id': member.avatarResourceId , ':role_name': member.roleName, ':role_color': member.roleColor, ':role_priority': member.rolePriority, ':privileges': member.privileges.join(',') }); } await stmt.finalize(); }) } async deleteMembers(guildId: number, deletedMembers: Member[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `DELETE FROM members WHERE id=:id AND guild_id=:guild_id` ); for (let member of deletedMembers) { await stmt.run({ ':id': member.id, ':guild_id': guildId }); } await stmt.finalize(); }) } async fetchMembers(guildId: number): Promise { let result = await this.db.all('SELECT * FROM members WHERE guild_id=:guild_id', { ':guild_id': guildId }); if (result.length === 0) return null; return result.map(dataMember => Member.fromDBData(dataMember)); } async clearAllMembersStatus(guildId: number): Promise { await this.db.run(`UPDATE members SET status='unknown' WHERE guild_id=:guild_id`, { ':guild_id': guildId }); } // Channels async addChannels(guildId: number, channels: Channel[]) { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `INSERT INTO channels ( id, guild_id, "index", name, flavor_text ) VALUES ( :id, :guild_id, :index, :name, :flavor_text )` ); for (let channel of channels) { await stmt.run({ ':id': channel.id, ':guild_id': guildId, ':index': channel.index, ':name': channel.name, ':flavor_text': channel.flavorText }); } await stmt.finalize(); }); } async updateChannels(guildId: number, newChannels: Channel[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `UPDATE channels SET "index"=:index, name=:name, flavor_text=:flavor_text WHERE id=:id AND guild_id=:guild_id` ); for (let channel of newChannels) { await stmt.run({ ':id': channel.id, ':guild_id': guildId, ':index': channel.index, ':name': channel.name, ':flavor_text': channel.flavorText }); } await stmt.finalize(); }) } async deleteChannels(guildId: number, deletedChannels: Channel[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `DELETE FROM channels WHERE id=:id AND guild_id=:guild_id` ); for (let channel of deletedChannels) { await stmt.run({ ':id': channel.id, ':guild_id': guildId }); } await stmt.finalize(); }) } async fetchChannels(guildId: number): Promise { let result = await this.db.all('SELECT * FROM channels WHERE guild_id=:guild_id', { ':guild_id': guildId }); if (result.length === 0) return null; return result.map(dataMember => Channel.fromDBData(dataMember)); } // Resources async addResources(guildId: number, resources: Resource[]) { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `INSERT INTO resources ( id, guild_id, hash, data, data_size, last_used ) VALUES ( :id, :guild_id, :hash, :data, :data_size, :last_used )` ); for (let resource of resources) { await stmt.run({ ':id': resource.id, ':guild_id': guildId, ':hash': resource.hash, ':data': resource.data, ':data_size': resource.data.length, ':last_used': Date.now() }); } await stmt.finalize(); }); } async updateResources(guildId: number, newResources: Resource[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `UPDATE resources SET hash=:hash, data=:data, data_size=:data_size, last_used=:last_used WHERE id=:id AND guild_id=:guild_id` ); for (let resource of newResources) { await stmt.run({ ':id': resource.id, ':guild_id': guildId, ':hash': resource.hash, ':data': resource.data, ':data_size': resource.data.length, ':last_used': Date.now() }); } await stmt.finalize(); }) } async deleteResources(guildId: number, deletedResources: Resource[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `DELETE FROM resources WHERE id=:id AND guild_id=:guild_id` ); for (let resource of deletedResources) { await stmt.run({ ':id': resource.id, ':guild_id': guildId }); } await stmt.finalize(); }) } async fetchResource(guildId: number, resourceId: string): Promise { let result = await this.db.get( `SELECT * FROM resources WHERE id=:id AND guild_id=:guild_id`, { ':id': resourceId, ':guild_id': guildId } ); if (!result) return null; return Resource.fromDBData(result); } // Messages async addMessages(guildId: number, messages: Message[]) { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `INSERT INTO messages ( id, guild_id, channel_id, member_id, sent_dtg, text , resource_id, resource_name, resource_width, resource_height, resource_preview_id ) VALUES ( :id, :guild_id, :channel_id, :member_id, :sent_dtg, :text , :resource_id, :resource_name, :resource_width, :resource_height, :resource_preview_id )` ); for (let message of messages) { await stmt.run({ ':id': message.id, ':guild_id': guildId, ':channel_id': message.channel.id, ':member_id': message.member.id, ':sent_dtg': message.sent.getTime(), ':text': message.text, ':resource_id': message.resourceId, ':resource_name': message.resourceName, ':resource_width': message.resourceWidth, ':resource_height': message.resourceHeight, ':resource_preview_id': message.resourcePreviewId }); } await stmt.finalize(); }); } async updateMessages(guildId: number, newMessages: Message[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `UPDATE resources SET hash=:hash, data=:data, data_size=:data_size, last_used=:last_used WHERE id=:id AND guild_id=:guild_id` ); for (let message of newMessages) { await stmt.run({ ':id': message.id, ':guild_id': guildId, ':channel_id': message.channel.id, ':member_id': message.member.id, ':sent_dtg': message.sent.getTime(), ':text': message.text, ':resource_id': message.resourceId, ':resource_name': message.resourceName, ':resource_width': message.resourceWidth, ':resource_height': message.resourceHeight, ':resource_preview_id': message.resourcePreviewId }); } await stmt.finalize(); }) } async deleteMessages(guildId: number, deletedMessages: Message[]): Promise { await this.queueTransaction(async () => { let stmt = await this.db.prepare( `DELETE FROM resources WHERE id=:id AND guild_id=:guild_id` ); for (let message of deletedMessages) { await stmt.run({ ':id': message.id, ':guild_id': guildId }); } await stmt.finalize(); }) } async fetchMessagesRecent(guildId: number, channelId: string, number: number): Promise { let messages = await this.db.all(` SELECT * FROM ( SELECT * FROM "messages" WHERE "guild_id"=:guild_id AND "channel_id"=:channel_id ORDER BY "sent_dtg" DESC LIMIT :number ) AS "r" ORDER BY "r"."sent_dtg" ASC `, { ':guild_id': guildId, ':channel_id': channelId, ':number': number }); if (messages.length === 0) return null; return messages.map(dataMessage => Message.fromDBData(dataMessage)); } async fetchMessagesBefore(guildId: number, channelId: string, messageId: string, number: number): Promise { let messages = await this.db.all(` SELECT * FROM ( SELECT * FROM "messages" WHERE "guild_id"=:guild_id AND "channel_id"=:channel_id AND "sent_dtg" < (SELECT "sent_dtg" FROM "messages" WHERE "id"=:message_id) ORDER BY "sent_dtg" DESC LIMIT :number ) AS "r" ORDER BY "r"."sent_dtg" ASC `, { ':guild_id': guildId, ':channel_id': channelId, ':message_id': messageId, ':number': number }); if (messages.length === 0) return null; return messages.map(dataMessage => Message.fromDBData(dataMessage)); } async fetchMessagesAfter(guildId: number, channelId: string, messageId: string, number: number): Promise { let messages = await this.db.all(` SELECT * FROM "messages" WHERE "guild_id"=:guild_id AND "channel_id"=:channel_id AND "sent_dtg" > (SELECT "sent_dtg" FROM "messages" WHERE "id"=:message_id) ORDER BY "sent_dtg" ASC LIMIT :number `, { ':guild_id': guildId, ':channel_id': channelId, ':message_id': messageId, ':number': number }); if (messages.length === 0) return null; return messages.map(dataMessage => Message.fromDBData(dataMessage)); } }