289 lines
13 KiB
Markdown
289 lines
13 KiB
Markdown
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 small site stylesheet (`site.css`) for project‑specific tweaks (no frameworks)
|
||
- 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)
|
||
- site.css # Site-specific styles (tiny utilities like transitions)
|
||
- 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.
|
||
- Place any site-specific CSS (e.g., small transitions like fade utilities) in `site.css`.
|
||
- 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 to `tracks` for details.
|
||
- Sorting for display can use `ORDER BY rank` (FTS) or `artist,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`
|
||
- 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.
|
||
|
||
---
|
||
|
||
## 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.
|
||
|
||
---
|
||
|
||
## TODOs / UX Elements Roadmap
|
||
|
||
Overview
|
||
- Views are "base" (replace main content) or "overlay" (stacked dialog) via `UX.replace(...)` and `UX.openOverlay(...)` in `script.js`.
|
||
- Each view pairs an HTML template in `index.html` (e.g., `tpl-...`) with a creator in `script.js` (e.g., `create...View(db)`), returning `{ kind, el, onShow?, destroy? }`.
|
||
- Use Bulma form/table/pagination patterns. Keep DOM small; paginate and debounce queries.
|
||
|
||
Shared Tasks
|
||
- [x] Add small table/list renderer util in `script.js` to build rows safely (uses `escapeHtml`). Implemented via `createTableRenderer`.
|
||
- [x] Add shared pagination component (Prev/Next, page size select). Propagate `LIMIT/OFFSET`. Implemented via `createPagination`.
|
||
- [x] Add common keyboard handlers: Enter to open selection; Esc to close overlays (already wired globally). Implemented via shared `Keyboard` helper in `script.js`.
|
||
- [x] Add loading/empty-state helpers for lists. Implemented via `createAsyncListState` utility.
|
||
|
||
Primary Navigation (Hub)
|
||
- [x] `tpl-nav` (base): Landing hub to choose "Search", "Browse Artists", "Browse Albums", "Browse Years", "Browse Genres", "Stats".
|
||
- [x] `createNavView(db)`: Buttons/cards trigger `UX.replace(...)` to corresponding base views.
|
||
- [x] Accessibility: initial focus on first action; arrow-key navigation across items; visible focus states.
|
||
|
||
Search (Existing)
|
||
- [x] `tpl-search` (base): Input is focusable; shows results area.
|
||
- [x] Implement query execution with FTS join; debounce 250 ms; paginate results. Wired into the new table + pagination helpers.
|
||
- SQL: `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 ? ORDER BY rank LIMIT ? OFFSET ?`.
|
||
- [x] Column sorts (toggle rank vs artist,title,year).
|
||
- [x] Row activation opens Track overlay.
|
||
|
||
Browse Artists
|
||
- [x] `tpl-browse-artists` (base): Alphabetical list, A–Z quick jump, mini filter box; paginated.
|
||
- [x] `createBrowseArtistsView(db)`: Loads pages; clicking row opens Artist overlay.
|
||
- SQL: `SELECT id, name FROM artists ORDER BY name LIMIT ? OFFSET ?`.
|
||
- [x] Optional prefix search using FTS prefix (`WHERE f MATCH 'artist:abc*'`) to accelerate filter. Browse Artists view now favors FTS when filters include ≥2 characters.
|
||
|
||
Browse Albums
|
||
- [x] `tpl-browse-albums` (base): List or grid with title, artist badge, year; paginated and sortable by artist/year/title.
|
||
- [x] `createBrowseAlbumsView(db)`: Clicking item opens Album overlay.
|
||
- SQL: `SELECT al.id, al.title, al.year, a.name AS artist FROM albums al JOIN artists a ON a.id=al.artist_id ORDER BY a.name, al.year, al.title LIMIT ? OFFSET ?`.
|
||
|
||
Browse Years
|
||
- [x] `tpl-browse-years` (base): Year histogram (counts) with list of tracks/albums when a year is selected; paginated.
|
||
- [x] `createBrowseYearsView(db)`: Selecting a year shows tracks; rows open Album/Track overlays.
|
||
- SQL (counts): `SELECT year, COUNT(*) AS cnt FROM tracks WHERE year IS NOT NULL GROUP BY year ORDER BY year`.
|
||
- SQL (tracks by year): `SELECT t.id, t.title, a.name AS artist, IFNULL(al.title,'') AS album, t.genre FROM tracks t JOIN artists a ON a.id=t.artist_id LEFT JOIN albums al ON al.id=t.album_id WHERE t.year=? ORDER BY a.name, t.title LIMIT ? OFFSET ?`.
|
||
|
||
Browse Genres
|
||
- [x] `tpl-browse-genres` (base): Genre chips with counts → selecting shows paginated tracks.
|
||
- [x] `createBrowseGenresView(db)`: Genre list with counts; selecting lists tracks; rows open Track overlay.
|
||
- SQL (counts): `SELECT genre, COUNT(*) AS cnt FROM tracks WHERE genre IS NOT NULL AND genre!='' GROUP BY genre ORDER BY cnt DESC, genre`.
|
||
- SQL (tracks by genre): `SELECT t.id, t.title, a.name AS artist, IFNULL(al.title,'') AS album, t.year FROM tracks t JOIN artists a ON a.id=t.artist_id LEFT JOIN albums al ON al.id=t.album_id WHERE t.genre=? ORDER BY a.name, t.title LIMIT ? OFFSET ?`.
|
||
|
||
Stats
|
||
- [x] `tpl-stats` (base): Lightweight metrics (totals, top artists, year distribution) linking into browse views.
|
||
- [x] `createStatsView(db)`: Render summary cards; links navigate via `UX.replace(...)` with preselected filters.
|
||
- SQL (examples): totals from `COUNT(*)` on artists/albums/tracks; top artists via `SELECT a.name, COUNT(*) cnt FROM tracks t JOIN artists a ON a.id=t.artist_id GROUP BY a.id ORDER BY cnt DESC LIMIT 20`.
|
||
|
||
Artist Overlay
|
||
- [x] `tpl-artist` (overlay): Header: name + counts; tabs: Albums | Top Tracks.
|
||
- [x] `createArtistOverlay(db, artistId)`: Load artist name, counts, then tab content.
|
||
- SQL (albums): `SELECT id, title, year FROM albums WHERE artist_id=? ORDER BY year, title`.
|
||
- SQL (top tracks): `SELECT id, title, year, genre FROM tracks WHERE artist_id=? ORDER BY year, title LIMIT 100`.
|
||
- [x] Actions: clicking album opens Album overlay; clicking track opens Track overlay.
|
||
|
||
Album Overlay
|
||
- [x] `tpl-album` (overlay): Header with album title, artist, year; tracklist table with `track_no`, `title`, `duration_sec`, `bitrate_kbps`.
|
||
- [x] `createAlbumOverlay(db, albumId)`: Load album+artist header; then tracklist.
|
||
- SQL (header): `SELECT al.title, al.year, a.name AS artist FROM albums al JOIN artists a ON a.id=al.artist_id WHERE al.id=?`.
|
||
- SQL (tracks): `SELECT id, track_no, title, duration_sec, bitrate_kbps FROM tracks WHERE album_id=? ORDER BY track_no, title`.
|
||
- [x] Row activation opens Track overlay.
|
||
|
||
Track Overlay
|
||
- [x] `tpl-track` (overlay): Show title, artist, album, year, genre, duration, bitrate, samplerate, channels, filesize, sha1 (if present), and `relpath` with a Copy button.
|
||
- [x] `createTrackOverlay(db, trackId)`: Load detail from join; add Copy action for `relpath`.
|
||
- SQL: `SELECT t.*, a.name AS artist, al.title AS album FROM tracks t JOIN artists a ON a.id=t.artist_id LEFT JOIN albums al ON al.id=t.album_id WHERE t.id=?`.
|
||
|
||
Filters (Optional)
|
||
- [ ] `tpl-filters` (overlay): Advanced filters (year range, min bitrate, genre multi-select) applied to current base view.
|
||
- [ ] `createFiltersOverlay(db, onApply)`: Applies constraints and refreshes the invoking view.
|
||
|
||
Help/Meta Overlays
|
||
- [ ] `tpl-keyboard-shortcuts` (overlay): " / focus search", "Esc close overlay", "j/k navigate" if list navigation is added.
|
||
- [ ] `tpl-about` (overlay): About/help, privacy note.
|
||
- [ ] `tpl-error` (overlay): Friendly error with retry; used by views on failure.
|
||
|
||
Implementation Notes
|
||
- Use template IDs in `index.html` and instantiate via existing `instantiateTemplate` helper.
|
||
- Overlays must add `ux-view--overlay` class (done by UX manager) and include a close button that calls `UX.closeTop()`.
|
||
- Keep queries read-only; always `LIMIT ? OFFSET ?` for lists; avoid `SELECT *` except for single-row detail.
|
||
- Respect accessibility: label–input associations, `aria-live` only for async status, focus returned to opener on overlay close.
|
||
- Performance: debounce search 200–300 ms; cache prepared statements if beneficial; do not pre-render large lists.
|
||
- UX manager now guards against race conditions during fades: `UX.replace` updates `currentBase` before the fade-in completes and checks that the previous element is still connected before trying to animate it out.
|