Files
moshing-mammut/src/lib/server/db.ts

866 lines
24 KiB
TypeScript

import { IGNORE_USERS, MASTODON_INSTANCE } from '$env/static/private';
import { enableVerboseLog, log } from '$lib/log';
import type { Account, AccountAvatar, Post, SongThumbnailImage, Tag } from '$lib/mastodon/response';
import type { SongInfo } from '$lib/odesliResponse';
import { TimelineReader } from '$lib/server/timeline';
import sqlite3 from 'sqlite3';
type FilterParameter = {
$limit?: number | undefined | null;
$since?: string | undefined | null;
$before?: string | undefined | null;
[x: string]: string | number | undefined | null;
};
type PostRow = {
id: string;
content: string;
created_at: string;
url: string;
account_id: string;
acct: string;
username: string;
display_name: string;
account_url: string;
avatar: string;
};
type PostTagRow = {
post_id: string;
tag: string;
url: string;
};
type SongRow = {
post_url: string;
postedUrl: string;
overviewUrl?: string;
type: 'album' | 'song';
youtubeUrl?: string;
title?: string;
artistName?: string;
thumbnailUrl?: string;
thumbnailWidth?: number;
thumbnailHeight?: number;
};
type AccountAvatarRow = {
account_url: string;
file: string;
sizeDescriptor: string;
};
type SongThumbnailAvatarRow = {
song_thumbnailUrl: string;
file: string;
sizeDescriptor: string;
kind: number;
};
type Migration = {
id: number;
name: string;
statement: string;
};
const db: sqlite3.Database = new sqlite3.Database('moshingmammut.db');
// for the local masto instance, the instance name is *not* saved
// as part of the username or acct, so it needs to be stripped
const ignoredUsers: string[] =
IGNORE_USERS === undefined
? []
: IGNORE_USERS.split(',')
.map((u) => (u.startsWith('@') ? u.substring(1) : u))
.map((u) =>
u.endsWith('@' + MASTODON_INSTANCE)
? u.substring(0, u.length - ('@' + MASTODON_INSTANCE).length)
: u
);
let databaseReady = false;
if (enableVerboseLog) {
sqlite3.verbose();
db.on('change', (t, d, table, rowid) => {
log.verbose('DB change event', t, d, table, rowid);
});
db.on('trace', (sql) => {
log.verbose('Running', sql);
});
db.on('profile', (sql) => {
log.verbose('Finished', sql);
});
}
function applyDbMigration(migration: Migration): Promise<void> {
return new Promise((resolve, reject) => {
db.exec(migration.statement, (err) => {
if (err !== null) {
log.error(`Failed to apply migration ${migration.name}`, err);
reject(err);
return;
}
resolve();
});
});
}
async function applyMigration(migration: Migration) {
if (migration.id === 4) {
// When this is run, no posts will have added song data,
// so filtering won't help
const posts = await getPostsInternal(null, null, 10000);
let current = 0;
const total = posts.length.toString().padStart(4, '0');
for (const post of posts) {
current++;
if (post.songs && post.songs.length) {
continue;
}
log.info(
`Fetching songs for existing post ${current.toString().padStart(4, '0')} of ${total}`,
post.url
);
const songs = await TimelineReader.getSongInfoInPost(post);
await saveSongInfoData(post.url, songs);
log.debug(`Fetched ${songs.length} songs for existing post`, post.url);
}
log.debug(`Finished fetching songs`);
} else {
await applyDbMigration(migration);
}
}
db.on('open', () => {
log.info('Opened database');
db.serialize();
db.run('CREATE TABLE IF NOT EXISTS "migrations" ("id" integer,"name" TEXT, PRIMARY KEY (id))');
db.all('SELECT id FROM migrations', (err, rows: Migration[]) => {
if (err !== null) {
log.error('Could not fetch existing migrations', err);
databaseReady = true;
return;
}
log.debug('Already applied migrations', rows);
const appliedMigrations: Set<number> = new Set(rows.map((row) => row['id']));
const toApply = getMigrations().filter((m) => !appliedMigrations.has(m.id));
let remaining = toApply.length;
if (remaining === 0) {
databaseReady = true;
return;
}
for (const migration of toApply) {
applyMigration(migration).then(() => {
remaining--;
// This will set databaseReady to true before the migration has been inserted as applies,
// but that doesn't matter. It's only important that is has been applied
if (remaining === 0) {
databaseReady = true;
}
if (err !== null) {
log.error(`Failed to apply migration ${migration.name}`, err);
return;
}
db.run(
'INSERT INTO migrations (id, name) VALUES(?, ?)',
[migration.id, migration.name],
(e: Error) => {
if (e !== null) {
log.error(`Failed to mark migration ${migration.name} as applied`, e);
return;
}
log.info(`Applied migration ${migration.name}`);
}
);
});
}
});
});
db.on('error', (err) => {
log.error('Error opening database', err);
});
function getMigrations(): Migration[] {
return [
{
id: 1,
name: 'initial',
statement: `
CREATE TABLE accounts (
id TEXT NOT NULL PRIMARY KEY,
acct TEXT,
username TEXT,
display_name TEXT,
url TEXT,
avatar TEXT,
avatar_static TEXT
);
CREATE TABLE tags (url TEXT NOT NULL PRIMARY KEY, tag TEXT NOT NULL);
CREATE TABLE posts (
id TEXT NOT NULL PRIMARY KEY,
content TEXT,
created_at TEXT,
url TEXT NOT NULL,
account_id TEXT NOT NULL,
FOREIGN KEY (account_id) REFERENCES accounts(id)
);
CREATE TABLE poststags (
id integer PRIMARY KEY,
post_id TEXT NOT NULL,
tag_url TEXT NOT NULL,
FOREIGN KEY (post_id) REFERENCES posts(id),
FOREIGN KEY (tag_url) REFERENCES tags(url)
)`
},
{
id: 2,
name: 'urls as keys',
statement: `
CREATE TABLE accounts_new (
id TEXT NOT NULL,
acct TEXT,
username TEXT,
display_name TEXT,
url TEXT NOT NULL PRIMARY KEY,
avatar TEXT
);
INSERT INTO accounts_new (id, acct, username, display_name, url, avatar)
SELECT id, acct, username, display_name, url, avatar
FROM accounts;
DROP TABLE accounts;
ALTER TABLE accounts_new RENAME TO accounts;
CREATE TABLE posts_new (
id TEXT NOT NULL,
content TEXT,
created_at TEXT,
url TEXT NOT NULL PRIMARY KEY,
account_id TEXT NOT NULL,
FOREIGN KEY (account_id) REFERENCES accounts(url)
);
INSERT INTO posts_new (id, content, created_at, url, account_id)
SELECT p.id, p.content, p.created_at, p.url, accounts.url
FROM posts as p
JOIN accounts ON accounts.id = p.account_id;
DROP TABLE posts;
ALTER TABLE posts_new RENAME TO posts;
CREATE TABLE poststags_new (
id integer PRIMARY KEY,
post_id TEXT NOT NULL,
tag_url TEXT NOT NULL,
FOREIGN KEY (post_id) REFERENCES posts(url),
FOREIGN KEY (tag_url) REFERENCES tags(url)
);
INSERT INTO poststags_new (id, post_id, tag_url)
SELECT pt.id, posts.url, pt.tag_url
FROM poststags as pt
JOIN posts ON posts.id = pt.post_id;
DROP TABLE poststags;
ALTER TABLE poststags_new RENAME TO poststags;
`
},
{
id: 3,
name: 'song info for posts',
statement: `
CREATE TABLE songs (
id integer PRIMARY KEY,
postedUrl TEXT NOT NULL,
overviewUrl TEXT,
type TEXT CHECK ( type in ('album', 'song') ),
youtubeUrl TEXT,
title TEXT,
artistName TEXT,
thumbnailUrl TEXT,
post_url TEXT,
FOREIGN KEY (post_url) REFERENCES posts(url)
);`
},
{
id: 4,
name: 'song info for existing posts',
statement: ``
},
{
id: 5,
name: 'resized avatars',
statement: `
CREATE TABLE accountsavatars (
file TEXT NOT NULL PRIMARY KEY,
account_url TEXT NOT NULL,
sizeDescriptor TEXT NOT NULL,
FOREIGN KEY (account_url) REFERENCES accounts(url)
);`
},
{
id: 6,
name: 'resized song thumbnails',
statement: `
CREATE TABLE songsthumbnails (
file TEXT NOT NULL PRIMARY KEY,
song_thumbnailUrl TEXT NOT NULL,
sizeDescriptor TEXT NOT NULL,
kind INTEGER NOT NULL,
FOREIGN KEY (song_thumbnailUrl) REFERENCES songs(thumbnailUrl)
);`
},
{
id: 7,
name: 'song thumbnail size',
statement: `
ALTER TABLE songs ADD COLUMN thumbnailWidth INTEGER NULL;
ALTER TABLE songs ADD COLUMN thumbnailHeight INTEGER NULL;`
}
];
}
async function waitReady(): Promise<void> {
// Simpler than a semaphore and is really only needed on startup
return new Promise((resolve) => {
const interval = setInterval(() => {
log.verbose('Waiting for database to be ready');
if (databaseReady) {
log.verbose('DB is ready');
clearInterval(interval);
resolve();
}
}, 100);
});
}
function saveAccountData(account: Account): Promise<void> {
return new Promise<void>((resolve, reject) => {
db.run(
`
INSERT INTO accounts (id, acct, username, display_name, url, avatar)
VALUES(?, ?, ?, ?, ?, ?)
ON CONFLICT(url)
DO UPDATE SET
acct=excluded.acct,
username=excluded.username,
display_name=excluded.display_name,
id=excluded.id,
avatar=excluded.avatar;`,
[
account.id,
account.acct,
account.username,
account.display_name,
account.url,
account.avatar
],
(err) => {
if (err !== null) {
log.error(`Could not insert/update account ${account.id}`, err);
reject(err);
return;
}
resolve();
}
);
});
}
function savePostData(post: Post): Promise<void> {
return new Promise<void>((resolve, reject) => {
db.run(
`
INSERT INTO posts (id, content, created_at, url, account_id)
VALUES (?, ?, ?, ?, ?) ON CONFLICT(url) DO UPDATE SET
content=excluded.content,
created_at=excluded.created_at,
id=excluded.id,
account_id=excluded.account_id;`,
[post.id, post.content, post.created_at, post.url, post.account.url],
(postErr) => {
if (postErr !== null) {
log.error(`Could not insert post ${post.url}`, postErr);
reject(postErr);
return;
}
resolve();
}
);
});
}
function savePostTagData(post: Post): Promise<void> {
return new Promise<void>((resolve, reject) => {
if (!post.tags.length) {
resolve();
return;
}
db.parallelize(() => {
let remaining = post.tags.length;
for (const tag of post.tags) {
db.run(
`
INSERT INTO tags (url, tag) VALUES (?, ?)
ON CONFLICT(url) DO UPDATE SET
tag=excluded.tag;`,
[tag.url, tag.name],
(tagErr) => {
if (tagErr !== null) {
log.error(`Could not insert/update tag ${tag.url}`, tagErr);
reject(tagErr);
return;
}
db.run(
'INSERT INTO poststags (post_id, tag_url) VALUES (?, ?)',
[post.url, tag.url],
(posttagserr) => {
if (posttagserr !== null) {
log.error(`Could not insert poststags ${tag.url}, ${post.url}`, posttagserr);
reject(posttagserr);
return;
}
// Don't decrease on fail
remaining--;
// Only resolve after all have been inserted
if (remaining === 0) {
resolve();
}
}
);
}
);
}
});
});
}
function saveSongInfoData(postUrl: string, songs: SongInfo[]): Promise<void> {
return new Promise<void>((resolve, reject) => {
if (songs.length === 0) {
resolve();
return;
}
db.parallelize(() => {
let remaining = songs.length;
for (const song of songs) {
db.run(
`
INSERT INTO songs (postedUrl, overviewUrl, type, youtubeUrl, title, artistName, thumbnailUrl, post_url, thumbnailWidth, thumbnailHeight)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
`,
[
song.postedUrl,
song.pageUrl,
song.type,
song.youtubeUrl,
song.title,
song.artistName,
song.thumbnailUrl,
postUrl,
song.thumbnailWidth,
song.thumbnailHeight
],
(songErr) => {
if (songErr !== null) {
log.error(`Could not insert song ${song.postedUrl}`, songErr);
reject(songErr);
return;
}
// Don't decrease on fail
remaining--;
// Only resolve after all have been inserted
if (remaining === 0) {
resolve();
}
}
);
}
});
});
}
export async function savePost(post: Post, songs: SongInfo[]) {
log.debug(`Saving post ${post.url}`);
if (!databaseReady) {
await waitReady();
}
const account = post.account;
await saveAccountData(account);
log.debug(`Saved account data ${post.url}`);
await savePostData(post);
log.debug(`Saved post data ${post.url}`);
await savePostTagData(post);
log.debug(`Saved ${post.tags.length} tag data ${post.url}`);
await saveSongInfoData(post.url, songs);
log.debug(
`Saved ${songs.length} song info data ${post.url}`,
songs.map((s) => s.thumbnailHeight)
);
}
function getPostData(filterQuery: string, params: FilterParameter): Promise<PostRow[]> {
const sql = `SELECT posts.id, posts.content, posts.created_at, posts.url,
accounts.id AS account_id, accounts.acct, accounts.username, accounts.display_name,
accounts.url AS account_url, accounts.avatar
FROM posts
JOIN accounts ON posts.account_id = accounts.url
${filterQuery}
ORDER BY created_at DESC
LIMIT $limit`;
return new Promise((resolve, reject) => {
db.all(sql, params, (err, rows: PostRow[]) => {
if (err != null) {
log.error('Error loading posts', err);
reject(err);
return;
}
resolve(rows);
});
});
}
function getTagData(postIdsParams: string, postIds: string[]): Promise<Map<string, Tag[]>> {
return new Promise((resolve, reject) => {
db.all(
`SELECT post_id, tags.url, tags.tag
FROM poststags
JOIN tags ON poststags.tag_url = tags.url
WHERE post_id IN (${postIdsParams});`,
postIds,
(tagErr, tagRows: PostTagRow[]) => {
if (tagErr != null) {
log.error('Error loading post tags', tagErr);
reject(tagErr);
return;
}
const tagMap: Map<string, Tag[]> = tagRows.reduce((result: Map<string, Tag[]>, item) => {
const tag: Tag = {
url: item.url,
name: item.tag
};
result.set(item.post_id, [...(result.get(item.post_id) || []), tag]);
return result;
}, new Map());
resolve(tagMap);
}
);
});
}
function getSongData(postIdsParams: string, postIds: string[]): Promise<Map<string, SongInfo[]>> {
return new Promise((resolve, reject) => {
db.all(
`SELECT post_url, songs.postedUrl, songs.overviewUrl, songs.type, songs.youtubeUrl,
songs.title, songs.artistName, songs.thumbnailUrl, songs.post_url, songs.thumbnailWidth, songs.thumbnailHeight
FROM songs
WHERE post_url IN (${postIdsParams});`,
postIds,
(tagErr, tagRows: SongRow[]) => {
if (tagErr != null) {
log.error('Error loading post songs', tagErr);
reject(tagErr);
return;
}
const songMap: Map<string, SongInfo[]> = tagRows.reduce(
(result: Map<string, SongInfo[]>, item) => {
const info = {
pageUrl: item.overviewUrl,
youtubeUrl: item.youtubeUrl,
type: item.type,
title: item.title,
artistName: item.artistName,
thumbnailUrl: item.thumbnailUrl,
postedUrl: item.postedUrl,
thumbnailHeight: item.thumbnailHeight,
thumbnailWidth: item.thumbnailWidth
} as SongInfo;
result.set(item.post_url, [...(result.get(item.post_url) || []), info]);
return result;
},
new Map()
);
log.verbose('songMap', songMap);
resolve(songMap);
}
);
});
}
function getAvatarData(
accountUrlsParams: string,
accountUrls: string[]
): Promise<Map<string, AccountAvatar[]>> {
return new Promise((resolve, reject) => {
db.all(
`SELECT account_url, file, sizeDescriptor
FROM accountsavatars
WHERE account_url IN (${accountUrlsParams});`,
accountUrls,
(err, rows: AccountAvatarRow[]) => {
if (err != null) {
log.error('Error loading avatars', err);
reject(err);
return;
}
const avatarMap: Map<string, AccountAvatar[]> = rows.reduce(
(result: Map<string, AccountAvatar[]>, item) => {
const info: AccountAvatar = {
accountUrl: item.account_url,
file: item.file,
sizeDescriptor: item.sizeDescriptor
};
result.set(item.account_url, [...(result.get(item.account_url) || []), info]);
return result;
},
new Map()
);
resolve(avatarMap);
}
);
});
}
function getSongThumbnailData(
thumbUrlsParams: string,
thumbUrls: string[]
): Promise<Map<string, SongThumbnailImage[]>> {
return new Promise((resolve, reject) => {
db.all(
`SELECT song_thumbnailUrl, file, sizeDescriptor, kind
FROM songsthumbnails
WHERE song_thumbnailUrl IN (${thumbUrlsParams});`,
thumbUrls,
(err, rows: SongThumbnailAvatarRow[]) => {
if (err != null) {
log.error('Error loading avatars', err);
reject(err);
return;
}
const thumbnailMap: Map<string, SongThumbnailImage[]> = rows.reduce(
(result: Map<string, SongThumbnailImage[]>, item) => {
const info: SongThumbnailImage = {
songThumbnailUrl: item.song_thumbnailUrl,
file: item.file,
sizeDescriptor: item.sizeDescriptor,
kind: item.kind
};
result.set(item.song_thumbnailUrl, [
...(result.get(item.song_thumbnailUrl) || []),
info
]);
return result;
},
new Map()
);
resolve(thumbnailMap);
}
);
});
}
export async function getPosts(
since: string | null,
before: string | null,
limit: number
): Promise<Post[]> {
if (!databaseReady) {
await waitReady();
}
return await getPostsInternal(since, before, limit);
}
async function getPostsInternal(
since: string | null,
before: string | null,
limit: number
): Promise<Post[]> {
let filterQuery = '';
const params: FilterParameter = { $limit: limit };
if (since === null && before === null) {
filterQuery = '';
} else if (since !== null) {
filterQuery = 'WHERE posts.created_at > $since';
params.$since = since;
} else if (before !== null) {
// Setting both, before and since doesn't make sense, so this case is not explicitly handled
filterQuery = 'WHERE posts.created_at < $before';
params.$before = before;
}
ignoredUsers.forEach((ignoredUser, index) => {
const userParam = `$user_${index}`;
const acctParam = userParam + 'a';
const usernameParam = userParam + 'u';
const prefix = filterQuery === '' ? ' WHERE' : ' AND';
filterQuery += `${prefix} acct != ${acctParam} AND username != ${usernameParam} `;
params[acctParam] = ignoredUser;
params[usernameParam] = ignoredUser;
});
const rows = await getPostData(filterQuery, params);
if (rows.length === 0) {
// No need to check for tags and songs
return [];
}
const postIdsParams = rows.map(() => '?').join(', ');
const postIds = rows.map((r: PostRow) => r.url);
const tagMap = await getTagData(postIdsParams, postIds);
const songMap = await getSongData(postIdsParams, postIds);
for (const entry of songMap) {
for (const songInfo of entry[1]) {
const thumbs = await getSongThumbnails(songInfo);
songInfo.resizedThumbnails = thumbs;
}
}
const accountUrls = [...new Set(rows.map((r: PostRow) => r.account_url))];
const accountUrlsParams = accountUrls.map(() => '?').join(', ');
const avatars = await getAvatarData(accountUrlsParams, accountUrls);
const posts = rows.map((row) => {
return {
id: row.id,
content: row.content,
created_at: row.created_at,
url: row.url,
tags: tagMap.get(row.url) || [],
account: {
id: row.account_id,
acct: row.acct,
username: row.username,
display_name: row.display_name,
url: row.account_url,
avatar: row.avatar,
resizedAvatars: avatars.get(row.account_url) || []
} as Account,
songs: songMap.get(row.url) || []
} as Post;
});
return posts;
}
export async function removeAvatars(accountUrl: string): Promise<void> {
const params: FilterParameter = { $account: accountUrl };
const sql = `
DELETE
FROM accountsavatars
WHERE account_url = $account`;
await waitReady();
return new Promise((resolve, reject) => {
db.run(sql, params, (err) => {
if (err) {
reject(err);
return;
}
resolve();
});
});
}
export async function saveSongThumbnail(thumb: SongThumbnailImage): Promise<void> {
// Will be null if file already existed
if (thumb.file === null) {
return;
}
const params: FilterParameter = {
$songId: thumb.songThumbnailUrl,
$file: thumb.file,
$sizeDescriptor: thumb.sizeDescriptor,
$kind: thumb.kind.valueOf()
};
const sql = `
INSERT INTO songsthumbnails
(song_thumbnailUrl, file, sizeDescriptor, kind) VALUES ($songId, $file, $sizeDescriptor, $kind)
ON CONFLICT(file) DO UPDATE SET
song_thumbnailUrl=excluded.song_thumbnailUrl,
sizeDescriptor=excluded.sizeDescriptor,
kind=excluded.kind;`;
await waitReady();
return new Promise((resolve, reject) => {
db.run(sql, params, (err) => {
if (err) {
reject(err);
return;
}
resolve();
});
});
}
export async function saveAvatar(avatar: AccountAvatar): Promise<void> {
// Will be null if file already existed
if (avatar.file === null) {
return;
}
const params: FilterParameter = {
$accountUrl: avatar.accountUrl,
$file: avatar.file,
$sizeDescriptor: avatar.sizeDescriptor
};
const sql = `
INSERT INTO accountsavatars
(account_url, file, sizeDescriptor) VALUES ($accountUrl, $file, $sizeDescriptor)
ON CONFLICT(file) DO UPDATE SET
account_url=excluded.account_url,
sizeDescriptor=excluded.sizeDescriptor;`;
await waitReady();
return new Promise((resolve, reject) => {
db.run(sql, params, (err) => {
if (err) {
reject(err);
return;
}
resolve();
});
});
}
export async function getAvatars(
accountUrl: string,
limit: number | undefined
): Promise<AccountAvatar[]> {
// TODO: Refactor to use `getAvatarData`
await waitReady();
let limitFilter = '';
const params: FilterParameter = {
$account: accountUrl,
$limit: 100
};
if (limit !== undefined) {
limitFilter = 'LIMIT $limit';
params.$limit = limit;
}
const sql = `
SELECT account_url, file, sizeDescriptor
FROM accountsavatars
WHERE account_url = $account
${limitFilter};`;
return new Promise((resolve, reject) => {
db.all(sql, params, (err, rows: AccountAvatarRow[]) => {
if (err) {
reject(err);
return;
}
resolve(
rows.map((r) => {
return {
accountUrl: r.account_url,
file: r.file,
sizeDescriptor: r.sizeDescriptor
} as AccountAvatar;
})
);
});
});
}
export async function getSongThumbnails(song: SongInfo): Promise<SongThumbnailImage[]> {
if (!song.thumbnailUrl) {
return [];
}
const rows = await getSongThumbnailData('?', [song.thumbnailUrl]);
return rows.get(song.thumbnailUrl) ?? [];
}