6.1 KiB
6.1 KiB
This repository contains a static web app for searching a large music metadata database (no server/API calls). It uses:
- Bulma (
bulma.min.css
) for UI (https://bulma.io/documentation/) - A single HTML file (
index.html
) - A single JS file (
script.js
) - A client-side SQLite database (WASM) fetched as a static asset (paged with HTTP Range if available)
Keep implementation details minimal; this file orients agents to project structure, constraints, and the data model.
Goals (for agents)
- Provide a responsive search UI over a large SQLite metadata DB entirely in-browser.
- No server-side code; all queries run client-side.
- Fast startup, predictable UX, minimal dependencies.
Non-Goals
- Hosting or streaming audio files.
- Write access to the DB.
- Complex build systems or frameworks.
Repository Layout (expected)
/
+- index.html # Single-page app shell
+- bulma.min.css # Bulma CSS (pinned)
+- script.js # All app logic
+- /assets/
¦ +- mp3com-meta.sqlite # Metadata DB (read-only)
+- AGENTS.md
- If subfolders are added later (icons, fonts), prefer
/assets/...
. - Do not introduce bundlers unless requested.
UI/UX Conventions
- Use Bulma components (containers, navbar, form controls, tables, pagination).
- Default to semantic HTML + Bulma classes; avoid inline styles.
- Accessibility: ensure focus states, label–input associations, and ARIA for dynamic content.
Data Access (Client-Side)
- Use SQLite compiled to WebAssembly in the browser.
- Prefer an HTTP VFS (range requests) to avoid fetching the entire DB up front.
- Queries should be read-only; no schema migrations/run-time writes.
Minimal runtime expectations
- One network fetch for the WASM runtime.
- The DB file (
/assets/mp3com-meta.sqlite
) fetched lazily by page(s) as needed.
Database Schema (authoritative)
PRAGMA foreign_keys=ON;
CREATE TABLE IF NOT EXISTS artists(
id INTEGER PRIMARY KEY,
name TEXT NOT NULL COLLATE NOCASE UNIQUE
);
CREATE TABLE IF NOT EXISTS albums(
id INTEGER PRIMARY KEY,
artist_id INTEGER NOT NULL REFERENCES artists(id),
title TEXT COLLATE NOCASE,
year INTEGER,
UNIQUE(artist_id, title, year)
);
CREATE TABLE IF NOT EXISTS tracks(
id INTEGER PRIMARY KEY,
artist_id INTEGER NOT NULL REFERENCES artists(id),
album_id INTEGER REFERENCES albums(id),
title TEXT NOT NULL COLLATE NOCASE,
track_no INTEGER,
year INTEGER,
genre TEXT,
duration_sec INTEGER,
bitrate_kbps INTEGER,
samplerate_hz INTEGER,
channels INTEGER,
filesize_bytes INTEGER,
sha1 TEXT, -- optional; may be NULL
relpath TEXT NOT NULL
);
-- External-content FTS5 (search over key text fields)
CREATE VIRTUAL TABLE IF NOT EXISTS fts_tracks USING fts5(
title, artist, album, genre,
content='tracks', content_rowid='id',
tokenize = 'unicode61 remove_diacritics 2',
prefix='2 3 4'
);
-- Keep FTS index in sync
CREATE TRIGGER IF NOT EXISTS tracks_ai AFTER INSERT ON tracks BEGIN
INSERT INTO fts_tracks(rowid,title,artist,album,genre)
VALUES (new.id,
new.title,
(SELECT name FROM artists WHERE id=new.artist_id),
(SELECT title FROM albums WHERE id=new.album_id),
new.genre);
END;
CREATE TRIGGER IF NOT EXISTS tracks_ad AFTER DELETE ON tracks BEGIN
INSERT INTO fts_tracks(fts_tracks, rowid) VALUES('delete', old.id);
END;
CREATE TRIGGER IF NOT EXISTS tracks_au AFTER UPDATE ON tracks BEGIN
INSERT INTO fts_tracks(fts_tracks, rowid) VALUES('delete', old.id);
INSERT INTO fts_tracks(rowid,title,artist,album,genre)
VALUES (new.id,
new.title,
(SELECT name FROM artists WHERE id=new.artist_id),
(SELECT title FROM albums WHERE id=new.album_id),
new.genre);
END;
CREATE INDEX IF NOT EXISTS idx_tracks_artist_id ON tracks(artist_id);
CREATE INDEX IF NOT EXISTS idx_tracks_album_id ON tracks(album_id);
CREATE INDEX IF NOT EXISTS idx_tracks_year ON tracks(year);
Notes
- Text search should use
fts_tracks MATCH ?
and join back totracks
for details. - Sorting for display can use
ORDER BY rank
(FTS) orartist,title,year
.
Example Queries (for agents)
-
Free text:
SELECT t.id, a.name AS artist, t.title, IFNULL(al.title,'') AS album, t.year, t.genre FROM fts_tracks f JOIN tracks t ON t.id=f.rowid JOIN artists a ON a.id=t.artist_id LEFT JOIN albums al ON al.id=t.album_id WHERE f MATCH ? -- e.g., 'queen "bohemian rhapsody"' ORDER BY rank LIMIT 50;
-
By artist prefix (fast via FTS
prefix
):WHERE f MATCH 'artist:beatl*'
-
Count by year:
SELECT year, COUNT(*) FROM tracks GROUP BY year ORDER BY year;
Local Development
-
Serve statically (to enable range requests and avoid file:// issues):
- Python:
python3 -m http.server 8000
- Node:
npx http-server -p 8000
- Python:
-
Open
http://localhost:8000/
-
Ensure the server sends
Accept-Ranges: bytes
for/assets/mp3com-meta.sqlite
.
Performance Guidance
- Keep initial DOM minimal; render results incrementally (virtualized list if needed).
- Debounce search input (e.g., 200–300 ms).
- Use
LIMIT
/pagination; avoid SELECT * on large result sets. - Cache prepared statements in JS if the WASM wrapper allows.
Quality Bar
- No console errors.
- Basic keyboard navigation works.
- Layout adapts from mobile ? desktop via Bulma columns.
- Reasonable query latency for common searches (<300ms after warm-up).
Security & Privacy
- No third-party trackers.
- Only static file loads; no credentials.
- If adding analytics, prefer privacy-preserving, self-hosted options and document them.
How to Extend (if requested later)
- Autocomplete table (prebuilt) for artists/albums.
- Sharded DBs by initial letter with a tiny manifest.
- Export results (CSV) client-side.
Agent Etiquette
- Do not introduce new build steps or frameworks unless explicitly asked.
- Keep diffs small and focused.
- When editing
index.html
/script.js
, include inline comments explaining assumptions. - Verify changes against the schema above.