Basic post display
This commit is contained in:
250
src/lib/server/db.ts
Normal file
250
src/lib/server/db.ts
Normal file
@ -0,0 +1,250 @@
|
||||
import type { Account, Post, Tag } from '$lib/mastodon/response';
|
||||
import sqlite3 from 'sqlite3';
|
||||
const { MODE } = import.meta.env;
|
||||
|
||||
const db: sqlite3.Database = new sqlite3.Database('moshingmammut.db');
|
||||
|
||||
if (MODE === 'development') {
|
||||
sqlite3.verbose();
|
||||
db.on('change', (t, d, table, rowid) => {
|
||||
console.debug('DB change event', t, d, table, rowid);
|
||||
})
|
||||
|
||||
db.on('trace', (sql) => {
|
||||
console.debug('Running', sql);
|
||||
});
|
||||
|
||||
db.on('profile', (sql) => {
|
||||
console.debug('Finished', sql);
|
||||
});
|
||||
}
|
||||
|
||||
interface Migration {
|
||||
id: number,
|
||||
name: string,
|
||||
statement: string
|
||||
}
|
||||
|
||||
db.on('open', () => {
|
||||
console.log('Opened database');
|
||||
db.run('CREATE TABLE IF NOT EXISTS "migrations" ("id" integer,"name" TEXT, PRIMARY KEY (id))');
|
||||
db.serialize();
|
||||
db.all('SELECT id FROM migrations', (err, rows) => {
|
||||
if (err !== null) {
|
||||
console.error('Could not fetch existing migrations', err);
|
||||
return;
|
||||
}
|
||||
console.debug('Already applied migrations', rows);
|
||||
const appliedMigrations: Set<number> = new Set(rows.map((row: any) => row['id']));
|
||||
const toApply = getMigrations().filter(m => !appliedMigrations.has(m.id));
|
||||
for (let migration of toApply) {
|
||||
db.exec(migration.statement, (err) => {
|
||||
if (err !== null) {
|
||||
console.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) {
|
||||
console.error(`Failed to mark migration ${migration.name} as applied`, e);
|
||||
return;
|
||||
}
|
||||
console.info(`Applied migration ${migration.name}`);
|
||||
});
|
||||
});
|
||||
}
|
||||
});
|
||||
});
|
||||
db.on('error', (err) => {
|
||||
console.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)
|
||||
)`
|
||||
}];
|
||||
}
|
||||
|
||||
export function savePost(post: Post): void {
|
||||
console.debug(`Saving post ${post.url}`);
|
||||
const account = post.account;
|
||||
db.run(`
|
||||
INSERT INTO accounts (id, acct, username, display_name, url, avatar, avatar_static)
|
||||
VALUES(?, ?, ?, ?, ?, ?, ?)
|
||||
ON CONFLICT(id)
|
||||
DO UPDATE SET
|
||||
acct=excluded.acct,
|
||||
username=excluded.username,
|
||||
display_name=excluded.display_name,
|
||||
url=excluded.url,
|
||||
avatar=excluded.avatar,
|
||||
avatar_static=excluded.avatar_static;`,
|
||||
[
|
||||
account.id,
|
||||
account.acct,
|
||||
account.username,
|
||||
account.display_name,
|
||||
account.url,
|
||||
account.avatar,
|
||||
account.avatar_static
|
||||
],
|
||||
(err) => {
|
||||
if (err !== null) {
|
||||
console.error(`Could not insert/update account ${account.id}`, err);
|
||||
return;
|
||||
}
|
||||
db.run(`
|
||||
INSERT INTO posts (id, content, created_at, url, account_id)
|
||||
VALUES (?, ?, ?, ?, ?) ON CONFLICT(id) DO UPDATE SET
|
||||
content=excluded.content,
|
||||
created_at=excluded.created_at,
|
||||
url=excluded.url,
|
||||
account_id=excluded.account_id;`,
|
||||
[
|
||||
post.id,
|
||||
post.content,
|
||||
post.created_at,
|
||||
post.url,
|
||||
post.account.id
|
||||
],
|
||||
(postErr) => {
|
||||
if (postErr !== null) {
|
||||
console.error(`Could not insert post ${post.url}`, postErr);
|
||||
return;
|
||||
}
|
||||
|
||||
db.parallelize(() => {
|
||||
for (let 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) {
|
||||
console.error(`Could not insert/update tag ${tag.url}`, tagErr);
|
||||
return;
|
||||
}
|
||||
db.run('INSERT INTO poststags (post_id, tag_url) VALUES (?, ?)',
|
||||
[post.id, tag.url],
|
||||
(posttagserr) => {
|
||||
if (posttagserr !== null) {
|
||||
console.error(`Could not insert poststags ${tag.url}, ${post.url}`, posttagserr);
|
||||
return;
|
||||
}
|
||||
}
|
||||
);
|
||||
}
|
||||
);
|
||||
}
|
||||
});
|
||||
});
|
||||
});
|
||||
}
|
||||
|
||||
export async function getPosts(since: string | null, limit: number) {
|
||||
let promise = await new Promise<Post[]>((resolve, reject) => {
|
||||
let filter_query;
|
||||
let params: any = { $limit: limit };
|
||||
if (since === null) {
|
||||
filter_query = '';
|
||||
} else {
|
||||
filter_query = 'WHERE posts.created_at > $since';
|
||||
params.$since = since;
|
||||
console.debug('Filtering by created_at > ', since);
|
||||
}
|
||||
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.id
|
||||
${filter_query}
|
||||
ORDER BY created_at DESC
|
||||
LIMIT $limit`;
|
||||
db.all(
|
||||
sql,
|
||||
params,
|
||||
(err, rows: any[]) => {
|
||||
if (err != null) {
|
||||
console.error('Error loading posts', err);
|
||||
reject(err);
|
||||
return;
|
||||
}
|
||||
const postIdsParams = rows.map(() => '?').join(', ');
|
||||
db.all(
|
||||
`SELECT post_id, tags.url, tags.tag
|
||||
FROM poststags
|
||||
JOIN tags ON poststags.tag_url = tags.url
|
||||
WHERE post_id IN (${postIdsParams});`,
|
||||
rows.map((r: any) => r.id),
|
||||
(tagErr, tagRows: any[]) => {
|
||||
if (tagErr != null) {
|
||||
console.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());
|
||||
const posts = rows.map(row => {
|
||||
return {
|
||||
id: row.id,
|
||||
content: row.content,
|
||||
created_at: row.created_at,
|
||||
url: row.url,
|
||||
tags: tagMap.get(row.id) || [],
|
||||
account: {
|
||||
id: row.account_id,
|
||||
acct: row.acct,
|
||||
username: row.username,
|
||||
display_name: row.display_name,
|
||||
url: row.account_url,
|
||||
avatar: row.avatar,
|
||||
avatar_static: ''
|
||||
} as Account
|
||||
} as Post
|
||||
});
|
||||
resolve(posts);
|
||||
}
|
||||
);
|
||||
}
|
||||
);
|
||||
});
|
||||
return promise;
|
||||
}
|
||||
|
Reference in New Issue
Block a user