472 lines
16 KiB
TypeScript
472 lines
16 KiB
TypeScript
import { Database } from "bun:sqlite";
|
|
|
|
const DB_PATH = "./musicroom.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)
|
|
)
|
|
`);
|
|
|
|
// Content-addressed tracks table
|
|
db.run(`
|
|
CREATE TABLE IF NOT EXISTS tracks (
|
|
id TEXT PRIMARY KEY,
|
|
title TEXT,
|
|
artist TEXT,
|
|
album TEXT,
|
|
duration REAL NOT NULL,
|
|
size INTEGER NOT NULL,
|
|
created_at INTEGER DEFAULT (unixepoch())
|
|
)
|
|
`);
|
|
|
|
// User playlists
|
|
db.run(`
|
|
CREATE TABLE IF NOT EXISTS playlists (
|
|
id TEXT PRIMARY KEY,
|
|
owner_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
name TEXT NOT NULL,
|
|
description TEXT,
|
|
visibility TEXT DEFAULT 'private' CHECK (visibility IN ('private', 'public', 'registered')),
|
|
created_at INTEGER DEFAULT (unixepoch()),
|
|
updated_at INTEGER DEFAULT (unixepoch())
|
|
)
|
|
`);
|
|
|
|
db.run(`
|
|
CREATE TABLE IF NOT EXISTS playlist_tracks (
|
|
playlist_id TEXT NOT NULL REFERENCES playlists(id) ON DELETE CASCADE,
|
|
track_id TEXT NOT NULL REFERENCES tracks(id),
|
|
position INTEGER NOT NULL,
|
|
added_at INTEGER DEFAULT (unixepoch()),
|
|
added_by INTEGER REFERENCES users(id),
|
|
PRIMARY KEY (playlist_id, position)
|
|
)
|
|
`);
|
|
|
|
db.run(`CREATE INDEX IF NOT EXISTS idx_playlist_tracks_track ON playlist_tracks(track_id)`);
|
|
db.run(`CREATE INDEX IF NOT EXISTS idx_playlists_owner ON playlists(owner_id)`);
|
|
db.run(`CREATE INDEX IF NOT EXISTS idx_playlists_visibility ON playlists(visibility)`);
|
|
|
|
// 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;
|
|
}
|
|
|
|
export interface Playlist {
|
|
id: string;
|
|
owner_id: number;
|
|
name: string;
|
|
description: string | null;
|
|
visibility: "private" | "public" | "registered";
|
|
created_at: number;
|
|
updated_at: number;
|
|
}
|
|
|
|
export interface PlaylistTrack {
|
|
playlist_id: string;
|
|
track_id: string;
|
|
position: number;
|
|
added_at: number;
|
|
added_by: number | null;
|
|
}
|
|
|
|
// 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
|
|
|
|
// Track functions
|
|
export function upsertTrack(track: Omit<Track, "created_at">): void {
|
|
db.query(`
|
|
INSERT INTO tracks (id, title, artist, album, duration, size)
|
|
VALUES (?, ?, ?, ?, ?, ?)
|
|
ON CONFLICT(id) DO UPDATE SET
|
|
title = COALESCE(excluded.title, title),
|
|
artist = COALESCE(excluded.artist, artist),
|
|
album = COALESCE(excluded.album, album)
|
|
`).run(track.id, track.title, track.artist, track.album, track.duration, track.size);
|
|
}
|
|
|
|
export function getTrack(id: string): Track | null {
|
|
return db.query("SELECT * FROM tracks WHERE id = ?").get(id) as Track | null;
|
|
}
|
|
|
|
export function getAllTracks(): Track[] {
|
|
return db.query("SELECT * FROM tracks ORDER BY title").all() as Track[];
|
|
}
|
|
|
|
// Playlist functions
|
|
export function createPlaylist(
|
|
ownerId: number,
|
|
name: string,
|
|
visibility: Playlist["visibility"] = "private",
|
|
description?: string
|
|
): Playlist {
|
|
const id = crypto.randomUUID();
|
|
db.query(`
|
|
INSERT INTO playlists (id, owner_id, name, description, visibility)
|
|
VALUES (?, ?, ?, ?, ?)
|
|
`).run(id, ownerId, name, description ?? null, visibility);
|
|
return getPlaylist(id)!;
|
|
}
|
|
|
|
export function getPlaylist(id: string): Playlist | null {
|
|
return db.query("SELECT * FROM playlists WHERE id = ?").get(id) as Playlist | null;
|
|
}
|
|
|
|
export function updatePlaylist(
|
|
id: string,
|
|
updates: Partial<Pick<Playlist, "name" | "description" | "visibility">>
|
|
): void {
|
|
const fields: string[] = [];
|
|
const values: any[] = [];
|
|
|
|
if (updates.name !== undefined) { fields.push("name = ?"); values.push(updates.name); }
|
|
if (updates.description !== undefined) { fields.push("description = ?"); values.push(updates.description); }
|
|
if (updates.visibility !== undefined) { fields.push("visibility = ?"); values.push(updates.visibility); }
|
|
|
|
if (fields.length === 0) return;
|
|
|
|
fields.push("updated_at = unixepoch()");
|
|
values.push(id);
|
|
|
|
db.query(`UPDATE playlists SET ${fields.join(", ")} WHERE id = ?`).run(...values);
|
|
}
|
|
|
|
export function deletePlaylist(id: string): void {
|
|
db.query("DELETE FROM playlists WHERE id = ?").run(id);
|
|
}
|
|
|
|
export function getUserPlaylists(userId: number): Playlist[] {
|
|
return db.query("SELECT * FROM playlists WHERE owner_id = ? ORDER BY updated_at DESC").all(userId) as Playlist[];
|
|
}
|
|
|
|
export function getVisiblePlaylists(userId: number | null, isGuest: boolean): Playlist[] {
|
|
if (userId === null || isGuest) {
|
|
// Guests/unauthenticated: public only
|
|
return db.query("SELECT * FROM playlists WHERE visibility = 'public' ORDER BY updated_at DESC").all() as Playlist[];
|
|
}
|
|
// Logged in: own + public + registered
|
|
return db.query(`
|
|
SELECT * FROM playlists
|
|
WHERE owner_id = ? OR visibility IN ('public', 'registered')
|
|
ORDER BY updated_at DESC
|
|
`).all(userId) as Playlist[];
|
|
}
|
|
|
|
export function canViewPlaylist(playlist: Playlist, userId: number | null, isGuest: boolean): boolean {
|
|
if (playlist.visibility === "public") return true;
|
|
if (userId === null) return false;
|
|
if (playlist.owner_id === userId) return true;
|
|
if (playlist.visibility === "registered" && !isGuest) return true;
|
|
return false;
|
|
}
|
|
|
|
export function canEditPlaylist(playlist: Playlist, userId: number | null): boolean {
|
|
return userId !== null && playlist.owner_id === userId;
|
|
}
|
|
|
|
// Playlist track functions
|
|
export function getPlaylistTracks(playlistId: string): (Track & { position: number })[] {
|
|
return db.query(`
|
|
SELECT t.*, pt.position
|
|
FROM playlist_tracks pt
|
|
JOIN tracks t ON t.id = pt.track_id
|
|
WHERE pt.playlist_id = ?
|
|
ORDER BY pt.position
|
|
`).all(playlistId) as (Track & { position: number })[];
|
|
}
|
|
|
|
export function addTrackToPlaylist(playlistId: string, trackId: string, addedBy: number | null, position?: number): void {
|
|
// If no position, add at end
|
|
if (position === undefined) {
|
|
const max = db.query("SELECT MAX(position) as max FROM playlist_tracks WHERE playlist_id = ?").get(playlistId) as { max: number | null };
|
|
position = (max?.max ?? -1) + 1;
|
|
} else {
|
|
// Shift existing tracks
|
|
db.query("UPDATE playlist_tracks SET position = position + 1 WHERE playlist_id = ? AND position >= ?").run(playlistId, position);
|
|
}
|
|
|
|
db.query(`
|
|
INSERT INTO playlist_tracks (playlist_id, track_id, position, added_by)
|
|
VALUES (?, ?, ?, ?)
|
|
`).run(playlistId, trackId, position, addedBy);
|
|
|
|
db.query("UPDATE playlists SET updated_at = unixepoch() WHERE id = ?").run(playlistId);
|
|
}
|
|
|
|
export function removeTrackFromPlaylist(playlistId: string, position: number): void {
|
|
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ? AND position = ?").run(playlistId, position);
|
|
// Shift remaining tracks down
|
|
db.query("UPDATE playlist_tracks SET position = position - 1 WHERE playlist_id = ? AND position > ?").run(playlistId, position);
|
|
db.query("UPDATE playlists SET updated_at = unixepoch() WHERE id = ?").run(playlistId);
|
|
}
|
|
|
|
export function reorderPlaylistTrack(playlistId: string, fromPos: number, toPos: number): void {
|
|
if (fromPos === toPos) return;
|
|
|
|
// Get the track being moved
|
|
const track = db.query("SELECT track_id FROM playlist_tracks WHERE playlist_id = ? AND position = ?").get(playlistId, fromPos) as { track_id: string } | null;
|
|
if (!track) return;
|
|
|
|
// Remove from old position
|
|
db.query("DELETE FROM playlist_tracks WHERE playlist_id = ? AND position = ?").run(playlistId, fromPos);
|
|
|
|
if (fromPos < toPos) {
|
|
// Moving down: shift tracks between fromPos+1 and toPos up
|
|
db.query("UPDATE playlist_tracks SET position = position - 1 WHERE playlist_id = ? AND position > ? AND position <= ?").run(playlistId, fromPos, toPos);
|
|
} else {
|
|
// Moving up: shift tracks between toPos and fromPos-1 down
|
|
db.query("UPDATE playlist_tracks SET position = position + 1 WHERE playlist_id = ? AND position >= ? AND position < ?").run(playlistId, toPos, fromPos);
|
|
}
|
|
|
|
// Insert at new position
|
|
db.query("INSERT INTO playlist_tracks (playlist_id, track_id, position) VALUES (?, ?, ?)").run(playlistId, track.track_id, toPos);
|
|
db.query("UPDATE playlists SET updated_at = unixepoch() WHERE id = ?").run(playlistId);
|
|
}
|