blastoise/db.ts

968 lines
28 KiB
TypeScript

import { Database } from "bun:sqlite";
const DB_PATH = "./blastoise.db";
const SESSION_EXPIRY_DAYS = 7;
const GUEST_SESSION_EXPIRY_HOURS = 24;
const db = new Database(DB_PATH);
// Initialize tables
db.run(`
CREATE TABLE IF NOT EXISTS users (
id INTEGER PRIMARY KEY AUTOINCREMENT,
username TEXT UNIQUE NOT NULL,
password_hash TEXT NOT NULL,
is_admin INTEGER DEFAULT 0,
is_guest INTEGER DEFAULT 0,
created_at INTEGER DEFAULT (unixepoch())
)
`);
// Migration: add is_guest column if it doesn't exist
try {
db.run(`ALTER TABLE users ADD COLUMN is_guest INTEGER DEFAULT 0`);
} catch {}
db.run(`
CREATE TABLE IF NOT EXISTS sessions (
token TEXT PRIMARY KEY,
user_id INTEGER NOT NULL,
expires_at INTEGER NOT NULL,
created_at INTEGER DEFAULT (unixepoch()),
user_agent TEXT,
ip_address TEXT,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
)
`);
// Migration: add columns if they don't exist
try {
db.run(`ALTER TABLE sessions ADD COLUMN user_agent TEXT`);
} catch {}
try {
db.run(`ALTER TABLE sessions ADD COLUMN ip_address TEXT`);
} catch {}
db.run(`
CREATE TABLE IF NOT EXISTS permissions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
user_id INTEGER NOT NULL,
resource_type TEXT NOT NULL,
resource_id TEXT,
permission TEXT NOT NULL,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
UNIQUE(user_id, resource_type, resource_id, permission)
)
`);
// Types
export interface User {
id: number;
username: string;
password_hash: string;
is_admin: boolean;
is_guest: boolean;
created_at: number;
}
export interface Session {
token: string;
user_id: number;
expires_at: number;
created_at: number;
user_agent: string | null;
ip_address: string | null;
}
export interface Permission {
id: number;
user_id: number;
resource_type: string;
resource_id: string | null;
permission: string;
}
export interface Track {
id: string;
title: string | null;
artist: string | null;
album: string | null;
duration: number;
size: number;
created_at: number;
}
// User functions
export async function createUser(username: string, password: string): Promise<User> {
const password_hash = await Bun.password.hash(password);
// First user becomes admin
const userCount = db.query("SELECT COUNT(*) as count FROM users WHERE is_guest = 0").get() as { count: number };
const is_admin = userCount.count === 0 ? 1 : 0;
const result = db.query(
"INSERT INTO users (username, password_hash, is_admin, is_guest) VALUES (?, ?, ?, 0) RETURNING *"
).get(username, password_hash, is_admin) as any;
return { ...result, is_admin: !!result.is_admin, is_guest: false };
}
export function createGuestUser(ipAddress: string, userAgent: string): User {
const guestId = crypto.randomUUID().slice(0, 8);
const username = `guest_${guestId}`;
const password_hash = ""; // No password for guests
const result = db.query(
"INSERT INTO users (username, password_hash, is_admin, is_guest) VALUES (?, ?, 0, 1) RETURNING *"
).get(username, password_hash) as any;
return { ...result, is_admin: false, is_guest: true };
}
export function findUserById(id: number): User | null {
const result = db.query("SELECT * FROM users WHERE id = ?").get(id) as any;
if (!result) return null;
return { ...result, is_admin: !!result.is_admin, is_guest: !!result.is_guest };
}
export function findUserByUsername(username: string): User | null {
const result = db.query("SELECT * FROM users WHERE username = ?").get(username) as any;
if (!result) return null;
return { ...result, is_admin: !!result.is_admin, is_guest: !!result.is_guest };
}
export async function validatePassword(user: User, password: string): Promise<boolean> {
return Bun.password.verify(password, user.password_hash);
}
// Session functions
export function createSession(userId: number, userAgent?: string, ipAddress?: string, isGuest: boolean = false): string {
const token = crypto.randomUUID();
const expirySeconds = isGuest
? GUEST_SESSION_EXPIRY_HOURS * 60 * 60
: SESSION_EXPIRY_DAYS * 24 * 60 * 60;
const expires_at = Math.floor(Date.now() / 1000) + expirySeconds;
db.query("INSERT INTO sessions (token, user_id, expires_at, user_agent, ip_address) VALUES (?, ?, ?, ?, ?)")
.run(token, userId, expires_at, userAgent ?? null, ipAddress ?? null);
return token;
}
export function createGuestSession(userAgent?: string, ipAddress?: string): { user: User, token: string } {
const user = createGuestUser(ipAddress ?? "unknown", userAgent ?? "unknown");
const token = createSession(user.id, userAgent, ipAddress, true);
return { user, token };
}
export function validateSession(token: string, currentUserAgent?: string, currentIpAddress?: string): User | null {
const now = Math.floor(Date.now() / 1000);
const session = db.query(
"SELECT * FROM sessions WHERE token = ? AND expires_at > ?"
).get(token, now) as Session | null;
if (!session) return null;
const user = findUserById(session.user_id);
if (!user) return null;
// Invalidate if BOTH ip and user agent changed (potential session hijack)
if (currentUserAgent && currentIpAddress && session.user_agent && session.ip_address) {
const ipChanged = session.ip_address !== currentIpAddress;
const uaChanged = session.user_agent !== currentUserAgent;
if (ipChanged && uaChanged) {
console.log(`[AUTH] Session invalidated (ip+ua changed): session=${token} old_ip=${session.ip_address} new_ip=${currentIpAddress}`);
deleteSession(token);
return null;
}
}
// Sliding expiration - extend on each use
const expirySeconds = user.is_guest
? GUEST_SESSION_EXPIRY_HOURS * 60 * 60
: SESSION_EXPIRY_DAYS * 24 * 60 * 60;
const newExpiry = now + expirySeconds;
db.query("UPDATE sessions SET expires_at = ? WHERE token = ?").run(newExpiry, token);
return findUserById(session.user_id);
}
export function deleteSession(token: string): void {
db.query("DELETE FROM sessions WHERE token = ?").run(token);
}
export function deleteExpiredSessions(): void {
const now = Math.floor(Date.now() / 1000);
db.query("DELETE FROM sessions WHERE expires_at <= ?").run(now);
}
// Permission functions
export function hasPermission(
userId: number,
resourceType: string,
resourceId: string | null,
permission: string
): boolean {
const user = findUserById(userId);
if (!user) return false;
if (user.is_admin) return true;
const result = db.query(`
SELECT 1 FROM permissions
WHERE user_id = ?
AND resource_type = ?
AND (resource_id = ? OR resource_id IS NULL)
AND permission = ?
LIMIT 1
`).get(userId, resourceType, resourceId, permission);
return !!result;
}
export function grantPermission(
userId: number,
resourceType: string,
resourceId: string | null,
permission: string
): void {
db.query(`
INSERT OR IGNORE INTO permissions (user_id, resource_type, resource_id, permission)
VALUES (?, ?, ?, ?)
`).run(userId, resourceType, resourceId, permission);
}
export function revokePermission(
userId: number,
resourceType: string,
resourceId: string | null,
permission: string
): void {
db.query(`
DELETE FROM permissions
WHERE user_id = ? AND resource_type = ? AND resource_id IS ? AND permission = ?
`).run(userId, resourceType, resourceId, permission);
}
export function getUserPermissions(userId: number): Permission[] {
return db.query("SELECT * FROM permissions WHERE user_id = ?").all(userId) as Permission[];
}
export function getAllUsers(): Omit<User, 'password_hash'>[] {
const users = db.query("SELECT id, username, is_admin, is_guest, created_at FROM users WHERE is_guest = 0").all() as any[];
return users.map(u => ({ ...u, is_admin: !!u.is_admin, is_guest: false }));
}
export function getUserSessions(userId: number): Omit<Session, 'token'>[] {
return db.query(
"SELECT user_id, expires_at, created_at, user_agent, ip_address FROM sessions WHERE user_id = ? AND expires_at > ?"
).all(userId, Math.floor(Date.now() / 1000)) as Omit<Session, 'token'>[];
}
// Cleanup expired sessions periodically
setInterval(() => deleteExpiredSessions(), 60 * 60 * 1000); // Every hour
// Channel tables
db.run(`
CREATE TABLE IF NOT EXISTS channels (
id TEXT PRIMARY KEY,
name TEXT NOT NULL,
description TEXT DEFAULT '',
created_by INTEGER,
is_default INTEGER DEFAULT 0,
current_index INTEGER DEFAULT 0,
started_at INTEGER DEFAULT (unixepoch() * 1000),
paused INTEGER DEFAULT 0,
paused_at REAL DEFAULT 0,
playback_mode TEXT DEFAULT 'repeat-all',
created_at INTEGER DEFAULT (unixepoch()),
FOREIGN KEY (created_by) REFERENCES users(id) ON DELETE SET NULL
)
`);
db.run(`
CREATE TABLE IF NOT EXISTS channel_queue (
id INTEGER PRIMARY KEY AUTOINCREMENT,
channel_id TEXT NOT NULL,
track_id TEXT NOT NULL,
position INTEGER NOT NULL,
FOREIGN KEY (channel_id) REFERENCES channels(id) ON DELETE CASCADE,
UNIQUE(channel_id, position)
)
`);
// Create index for faster queue lookups
db.run(`CREATE INDEX IF NOT EXISTS idx_channel_queue_channel ON channel_queue(channel_id)`);
// Migration: add playback_mode column to channels
try {
db.run(`ALTER TABLE channels ADD COLUMN playback_mode TEXT DEFAULT 'repeat-all'`);
} catch {}
// Channel types
export interface ChannelRow {
id: string;
name: string;
description: string;
created_by: number | null;
is_default: number;
current_index: number;
started_at: number;
paused: number;
paused_at: number;
playback_mode: string;
created_at: number;
}
export interface ChannelQueueRow {
id: number;
channel_id: string;
track_id: string;
position: number;
}
// Channel CRUD functions
export function saveChannel(channel: {
id: string;
name: string;
description: string;
createdBy: number | null;
isDefault: boolean;
currentIndex: number;
startedAt: number;
paused: boolean;
pausedAt: number;
playbackMode: string;
}): void {
db.query(`
INSERT INTO channels (id, name, description, created_by, is_default, current_index, started_at, paused, paused_at, playback_mode)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
name = excluded.name,
description = excluded.description,
current_index = excluded.current_index,
started_at = excluded.started_at,
paused = excluded.paused,
paused_at = excluded.paused_at,
playback_mode = excluded.playback_mode
`).run(
channel.id,
channel.name,
channel.description,
channel.createdBy,
channel.isDefault ? 1 : 0,
channel.currentIndex,
channel.startedAt,
channel.paused ? 1 : 0,
channel.pausedAt,
channel.playbackMode
);
}
export function updateChannelState(channelId: string, state: {
currentIndex: number;
startedAt: number;
paused: boolean;
pausedAt: number;
playbackMode: string;
}): void {
db.query(`
UPDATE channels
SET current_index = ?, started_at = ?, paused = ?, paused_at = ?, playback_mode = ?
WHERE id = ?
`).run(state.currentIndex, state.startedAt, state.paused ? 1 : 0, state.pausedAt, state.playbackMode, channelId);
}
export function loadChannel(id: string): ChannelRow | null {
return db.query("SELECT * FROM channels WHERE id = ?").get(id) as ChannelRow | null;
}
export function loadAllChannels(): ChannelRow[] {
return db.query("SELECT * FROM channels").all() as ChannelRow[];
}
export function deleteChannelFromDb(id: string): void {
db.query("DELETE FROM channels WHERE id = ?").run(id);
}
export function updateChannelName(id: string, name: string): void {
db.query("UPDATE channels SET name = ? WHERE id = ?").run(name, id);
}
// Queue persistence functions
export function saveChannelQueue(channelId: string, trackIds: string[]): void {
db.query("BEGIN").run();
try {
db.query("DELETE FROM channel_queue WHERE channel_id = ?").run(channelId);
const insert = db.query(
"INSERT INTO channel_queue (channel_id, track_id, position) VALUES (?, ?, ?)"
);
for (let i = 0; i < trackIds.length; i++) {
insert.run(channelId, trackIds[i], i);
}
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function loadChannelQueue(channelId: string): string[] {
const rows = db.query(
"SELECT track_id FROM channel_queue WHERE channel_id = ? ORDER BY position"
).all(channelId) as { track_id: string }[];
return rows.map(r => r.track_id);
}
export function removeTrackFromQueues(trackId: string): void {
db.query("DELETE FROM channel_queue WHERE track_id = ?").run(trackId);
}
// Playlist tables
db.run(`
CREATE TABLE IF NOT EXISTS playlists (
id TEXT PRIMARY KEY,
name TEXT NOT NULL,
description TEXT DEFAULT '',
owner_id INTEGER NOT NULL,
is_public INTEGER DEFAULT 0,
share_token TEXT,
created_at INTEGER DEFAULT (unixepoch()),
updated_at INTEGER DEFAULT (unixepoch()),
FOREIGN KEY (owner_id) REFERENCES users(id) ON DELETE CASCADE
)
`);
db.run(`
CREATE TABLE IF NOT EXISTS playlist_tracks (
id INTEGER PRIMARY KEY AUTOINCREMENT,
playlist_id TEXT NOT NULL,
track_id TEXT NOT NULL,
position INTEGER NOT NULL,
FOREIGN KEY (playlist_id) REFERENCES playlists(id) ON DELETE CASCADE
)
`);
db.run(`CREATE INDEX IF NOT EXISTS idx_playlist_tracks_playlist ON playlist_tracks(playlist_id)`);
// Playlist types
export interface PlaylistRow {
id: string;
name: string;
description: string;
owner_id: number;
is_public: number;
share_token: string | null;
created_at: number;
updated_at: number;
}
export interface Playlist {
id: string;
name: string;
description: string;
ownerId: number;
isPublic: boolean;
shareToken: string | null;
trackIds: string[];
createdAt: number;
updatedAt: number;
}
// Playlist CRUD functions
export function createPlaylist(name: string, ownerId: number, description: string = ""): Playlist {
const id = crypto.randomUUID();
const now = Math.floor(Date.now() / 1000);
db.query(`
INSERT INTO playlists (id, name, description, owner_id, created_at, updated_at)
VALUES (?, ?, ?, ?, ?, ?)
`).run(id, name, description, ownerId, now, now);
return {
id,
name,
description,
ownerId,
isPublic: false,
shareToken: null,
trackIds: [],
createdAt: now,
updatedAt: now
};
}
export function getPlaylist(id: string): Playlist | null {
const row = db.query("SELECT * FROM playlists WHERE id = ?").get(id) as PlaylistRow | null;
if (!row) return null;
const tracks = db.query(
"SELECT track_id FROM playlist_tracks WHERE playlist_id = ? ORDER BY position"
).all(id) as { track_id: string }[];
return {
id: row.id,
name: row.name,
description: row.description,
ownerId: row.owner_id,
isPublic: !!row.is_public,
shareToken: row.share_token,
trackIds: tracks.map(t => t.track_id),
createdAt: row.created_at,
updatedAt: row.updated_at
};
}
export function getPlaylistsByUser(userId: number): Playlist[] {
const rows = db.query(
"SELECT * FROM playlists WHERE owner_id = ? ORDER BY name"
).all(userId) as PlaylistRow[];
return rows.map(row => {
const tracks = db.query(
"SELECT track_id FROM playlist_tracks WHERE playlist_id = ? ORDER BY position"
).all(row.id) as { track_id: string }[];
return {
id: row.id,
name: row.name,
description: row.description,
ownerId: row.owner_id,
isPublic: !!row.is_public,
shareToken: row.share_token,
trackIds: tracks.map(t => t.track_id),
createdAt: row.created_at,
updatedAt: row.updated_at
};
});
}
export function getPublicPlaylists(excludeUserId?: number): Playlist[] {
const query = excludeUserId
? "SELECT * FROM playlists WHERE is_public = 1 AND owner_id != ? ORDER BY name"
: "SELECT * FROM playlists WHERE is_public = 1 ORDER BY name";
const rows = excludeUserId
? db.query(query).all(excludeUserId) as PlaylistRow[]
: db.query(query).all() as PlaylistRow[];
return rows.map(row => {
const tracks = db.query(
"SELECT track_id FROM playlist_tracks WHERE playlist_id = ? ORDER BY position"
).all(row.id) as { track_id: string }[];
return {
id: row.id,
name: row.name,
description: row.description,
ownerId: row.owner_id,
isPublic: !!row.is_public,
shareToken: row.share_token,
trackIds: tracks.map(t => t.track_id),
createdAt: row.created_at,
updatedAt: row.updated_at
};
});
}
export function getPlaylistByShareToken(token: string): Playlist | null {
const row = db.query(
"SELECT * FROM playlists WHERE share_token = ?"
).get(token) as PlaylistRow | null;
if (!row) return null;
const tracks = db.query(
"SELECT track_id FROM playlist_tracks WHERE playlist_id = ? ORDER BY position"
).all(row.id) as { track_id: string }[];
return {
id: row.id,
name: row.name,
description: row.description,
ownerId: row.owner_id,
isPublic: !!row.is_public,
shareToken: row.share_token,
trackIds: tracks.map(t => t.track_id),
createdAt: row.created_at,
updatedAt: row.updated_at
};
}
export function updatePlaylist(id: string, updates: { name?: string; description?: string; isPublic?: boolean }): void {
const now = Math.floor(Date.now() / 1000);
const sets: string[] = ["updated_at = ?"];
const values: any[] = [now];
if (updates.name !== undefined) {
sets.push("name = ?");
values.push(updates.name);
}
if (updates.description !== undefined) {
sets.push("description = ?");
values.push(updates.description);
}
if (updates.isPublic !== undefined) {
sets.push("is_public = ?");
values.push(updates.isPublic ? 1 : 0);
}
values.push(id);
db.query(`UPDATE playlists SET ${sets.join(", ")} WHERE id = ?`).run(...values);
}
export function deletePlaylist(id: string): void {
db.query("DELETE FROM playlists WHERE id = ?").run(id);
}
export function setPlaylistTracks(playlistId: string, trackIds: string[]): void {
const now = Math.floor(Date.now() / 1000);
db.query("BEGIN").run();
try {
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ?").run(playlistId);
const insert = db.query(
"INSERT INTO playlist_tracks (playlist_id, track_id, position) VALUES (?, ?, ?)"
);
for (let i = 0; i < trackIds.length; i++) {
insert.run(playlistId, trackIds[i], i);
}
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function addTracksToPlaylist(playlistId: string, trackIds: string[]): void {
const now = Math.floor(Date.now() / 1000);
db.query("BEGIN").run();
try {
// Get current max position
const max = db.query(
"SELECT COALESCE(MAX(position), -1) as max_pos FROM playlist_tracks WHERE playlist_id = ?"
).get(playlistId) as { max_pos: number };
let pos = max.max_pos + 1;
const insert = db.query(
"INSERT INTO playlist_tracks (playlist_id, track_id, position) VALUES (?, ?, ?)"
);
for (const trackId of trackIds) {
insert.run(playlistId, trackId, pos++);
}
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function removeTrackFromPlaylist(playlistId: string, position: number): void {
const now = Math.floor(Date.now() / 1000);
db.query("BEGIN").run();
try {
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ? AND position = ?").run(playlistId, position);
// Reorder remaining tracks
db.query(`
UPDATE playlist_tracks
SET position = position - 1
WHERE playlist_id = ? AND position > ?
`).run(playlistId, position);
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function removeTracksFromPlaylist(playlistId: string, positions: number[]): void {
if (positions.length === 0) return;
const now = Math.floor(Date.now() / 1000);
// Sort descending to remove from end first (preserves indices)
const sorted = [...positions].sort((a, b) => b - a);
db.query("BEGIN").run();
try {
for (const pos of sorted) {
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ? AND position = ?").run(playlistId, pos);
// Reorder remaining tracks
db.query(`
UPDATE playlist_tracks
SET position = position - 1
WHERE playlist_id = ? AND position > ?
`).run(playlistId, pos);
}
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function movePlaylistTracks(playlistId: string, fromPositions: number[], toPosition: number): void {
if (fromPositions.length === 0) return;
const now = Math.floor(Date.now() / 1000);
const sorted = [...fromPositions].sort((a, b) => a - b);
db.query("BEGIN").run();
try {
// Get tracks to move
const tracksToMove: string[] = [];
for (const pos of sorted) {
const row = db.query(
"SELECT track_id FROM playlist_tracks WHERE playlist_id = ? AND position = ?"
).get(playlistId, pos) as { track_id: string } | null;
if (row) tracksToMove.push(row.track_id);
}
if (tracksToMove.length === 0) {
db.query("ROLLBACK").run();
return;
}
// Remove tracks from current positions (from end to preserve indices)
for (let i = sorted.length - 1; i >= 0; i--) {
const pos = sorted[i];
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ? AND position = ?").run(playlistId, pos);
db.query(`
UPDATE playlist_tracks
SET position = position - 1
WHERE playlist_id = ? AND position > ?
`).run(playlistId, pos);
}
// Adjust target for removed items
let adjustedTarget = toPosition;
for (const pos of sorted) {
if (pos < toPosition) adjustedTarget--;
}
// Make room at target position
db.query(`
UPDATE playlist_tracks
SET position = position + ?
WHERE playlist_id = ? AND position >= ?
`).run(tracksToMove.length, playlistId, adjustedTarget);
// Insert tracks at new position
const insert = db.query(
"INSERT INTO playlist_tracks (playlist_id, track_id, position) VALUES (?, ?, ?)"
);
for (let i = 0; i < tracksToMove.length; i++) {
insert.run(playlistId, tracksToMove[i], adjustedTarget + i);
}
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function insertTracksToPlaylistAt(playlistId: string, trackIds: string[], position: number): void {
if (trackIds.length === 0) return;
const now = Math.floor(Date.now() / 1000);
db.query("BEGIN").run();
try {
// Make room at position
db.query(`
UPDATE playlist_tracks
SET position = position + ?
WHERE playlist_id = ? AND position >= ?
`).run(trackIds.length, playlistId, position);
// Insert tracks
const insert = db.query(
"INSERT INTO playlist_tracks (playlist_id, track_id, position) VALUES (?, ?, ?)"
);
for (let i = 0; i < trackIds.length; i++) {
insert.run(playlistId, trackIds[i], position + i);
}
db.query("UPDATE playlists SET updated_at = ? WHERE id = ?").run(now, playlistId);
db.query("COMMIT").run();
} catch (e) {
db.query("ROLLBACK").run();
throw e;
}
}
export function generatePlaylistShareToken(playlistId: string): string {
const token = crypto.randomUUID().slice(0, 12);
db.query("UPDATE playlists SET share_token = ? WHERE id = ?").run(token, playlistId);
return token;
}
export function removePlaylistShareToken(playlistId: string): void {
db.query("UPDATE playlists SET share_token = NULL WHERE id = ?").run(playlistId);
}
// Slow queue table for yt-dlp playlist downloads
db.run(`
CREATE TABLE IF NOT EXISTS slow_queue (
id TEXT PRIMARY KEY,
url TEXT NOT NULL,
title TEXT NOT NULL,
user_id INTEGER NOT NULL,
status TEXT DEFAULT 'queued',
progress REAL DEFAULT 0,
error TEXT,
playlist_id TEXT,
playlist_name TEXT,
position INTEGER,
created_at INTEGER,
completed_at INTEGER,
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY (playlist_id) REFERENCES playlists(id) ON DELETE SET NULL
)
`);
db.run(`CREATE INDEX IF NOT EXISTS idx_slow_queue_user ON slow_queue(user_id)`);
db.run(`CREATE INDEX IF NOT EXISTS idx_slow_queue_status ON slow_queue(status)`);
// Slow queue types
export interface SlowQueueRow {
id: string;
url: string;
title: string;
user_id: number;
status: string;
progress: number;
error: string | null;
playlist_id: string | null;
playlist_name: string | null;
position: number | null;
created_at: number;
completed_at: number | null;
}
// Slow queue CRUD functions
export function saveSlowQueueItem(item: {
id: string;
url: string;
title: string;
userId: number;
status: string;
progress: number;
error?: string;
playlistId?: string;
playlistName?: string;
position?: number;
createdAt: number;
completedAt?: number;
}): void {
db.query(`
INSERT INTO slow_queue (id, url, title, user_id, status, progress, error, playlist_id, playlist_name, position, created_at, completed_at)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
ON CONFLICT(id) DO UPDATE SET
status = excluded.status,
progress = excluded.progress,
error = excluded.error,
completed_at = excluded.completed_at
`).run(
item.id,
item.url,
item.title,
item.userId,
item.status,
item.progress,
item.error ?? null,
item.playlistId ?? null,
item.playlistName ?? null,
item.position ?? null,
item.createdAt,
item.completedAt ?? null
);
}
export function updateSlowQueueItem(id: string, updates: {
status?: string;
progress?: number;
error?: string;
completedAt?: number;
}): void {
const sets: string[] = [];
const values: any[] = [];
if (updates.status !== undefined) {
sets.push("status = ?");
values.push(updates.status);
}
if (updates.progress !== undefined) {
sets.push("progress = ?");
values.push(updates.progress);
}
if (updates.error !== undefined) {
sets.push("error = ?");
values.push(updates.error);
}
if (updates.completedAt !== undefined) {
sets.push("completed_at = ?");
values.push(updates.completedAt);
}
if (sets.length === 0) return;
values.push(id);
db.query(`UPDATE slow_queue SET ${sets.join(", ")} WHERE id = ?`).run(...values);
}
export function loadSlowQueue(): SlowQueueRow[] {
return db.query(
"SELECT * FROM slow_queue WHERE status IN ('queued', 'downloading') ORDER BY created_at"
).all() as SlowQueueRow[];
}
export function deleteSlowQueueItem(id: string): void {
db.query("DELETE FROM slow_queue WHERE id = ?").run(id);
}
export function clearCompletedSlowQueue(maxAge: number = 3600): void {
const cutoff = Math.floor(Date.now() / 1000) - maxAge;
db.query(
"DELETE FROM slow_queue WHERE status IN ('complete', 'error', 'cancelled') AND completed_at < ?"
).run(cutoff);
}
export function getSlowQueueByUser(userId: number): SlowQueueRow[] {
return db.query(
"SELECT * FROM slow_queue WHERE user_id = ? ORDER BY created_at"
).all(userId) as SlowQueueRow[];
}
export function playlistNameExists(name: string, userId: number): boolean {
const result = db.query(
"SELECT 1 FROM playlists WHERE name = ? AND owner_id = ? LIMIT 1"
).get(name, userId);
return !!result;
}
export function generateUniquePlaylistName(baseName: string, userId: number): string {
if (!playlistNameExists(baseName, userId)) {
return baseName;
}
let counter = 2;
while (playlistNameExists(`${baseName} (${counter})`, userId)) {
counter++;
}
return `${baseName} (${counter})`;
}