1+ BEGIN ;
2+
3+ -- Track per-user progress on a book
4+ CREATE TABLE IF NOT EXISTS user_book_progress (
5+ id BIGSERIAL PRIMARY KEY ,
6+ user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE ,
7+ book_id BIGINT NOT NULL REFERENCES books(id) ON DELETE CASCADE ,
8+ status TEXT NOT NULL DEFAULT ' reading' , -- not_started|reading|paused|finished
9+ current_page INT ,
10+ percent NUMERIC (5 ,2 ), -- denorm
11+ started_at TIMESTAMPTZ DEFAULT NOW(),
12+ finished_at TIMESTAMPTZ ,
13+ updated_at TIMESTAMPTZ DEFAULT NOW(),
14+ UNIQUE (user_id, book_id)
15+ );
16+
17+ CREATE INDEX IF NOT EXISTS idx_user_book_progress_user ON user_book_progress(user_id);
18+ CREATE INDEX IF NOT EXISTS idx_user_book_progress_book ON user_book_progress(book_id);
19+
20+ -- stores each update with deltas for history and reporting
21+ CREATE TABLE IF NOT EXISTS reading_logs (
22+ id BIGSERIAL PRIMARY KEY ,
23+ user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE ,
24+ book_id BIGINT NOT NULL REFERENCES books(id) ON DELETE CASCADE ,
25+ club_id BIGINT REFERENCES clubs(id) ON DELETE SET NULL ,
26+ assignment_id BIGINT , -- forward ref; not FK to avoid circular on create order
27+ pages_delta INT , -- how many pages were read in this session
28+ from_page INT ,
29+ to_page INT ,
30+ minutes INT ,
31+ note TEXT ,
32+ created_at TIMESTAMPTZ DEFAULT NOW()
33+ );
34+
35+ CREATE INDEX IF NOT EXISTS idx_reading_logs_user ON reading_logs(user_id);
36+ CREATE INDEX IF NOT EXISTS idx_reading_logs_book ON reading_logs(book_id);
37+ CREATE INDEX IF NOT EXISTS idx_reading_logs_club ON reading_logs(club_id);
38+
39+ -- Club-level assignments (what the club is reading now / history)
40+ CREATE TABLE IF NOT EXISTS club_book_assignments (
41+ id BIGSERIAL PRIMARY KEY ,
42+ club_id BIGINT NOT NULL REFERENCES clubs(id) ON DELETE CASCADE ,
43+ book_id BIGINT NOT NULL REFERENCES books(id) ON DELETE CASCADE ,
44+ status TEXT NOT NULL DEFAULT ' active' , -- active|completed|archived
45+ start_date DATE DEFAULT CURRENT_DATE ,
46+ due_date DATE ,
47+ completed_at TIMESTAMPTZ ,
48+ target_page INT , -- "checkpoint" page for the club
49+ checkpoint TEXT , -- description
50+ created_at TIMESTAMPTZ DEFAULT NOW(),
51+ updated_at TIMESTAMPTZ DEFAULT NOW()
52+ );
53+
54+ CREATE INDEX IF NOT EXISTS idx_club_assignments_club ON club_book_assignments(club_id);
55+ CREATE INDEX IF NOT EXISTS idx_club_assignments_book ON club_book_assignments(book_id);
56+
57+ -- trigger to keep updated_at current
58+ CREATE OR REPLACE FUNCTION set_updated_at () RETURNS TRIGGER AS $$
59+ BEGIN
60+ NEW .updated_at = NOW();
61+ RETURN NEW;
62+ END;
63+ $$ LANGUAGE plpgsql;
64+
65+ DROP TRIGGER IF EXISTS trg_user_book_progress_updated ON user_book_progress;
66+ CREATE TRIGGER trg_user_book_progress_updated BEFORE UPDATE ON user_book_progress
67+ FOR EACH ROW EXECUTE FUNCTION set_updated_at();
68+
69+ DROP TRIGGER IF EXISTS trg_club_assignments_updated ON club_book_assignments;
70+ CREATE TRIGGER trg_club_assignments_updated BEFORE UPDATE ON club_book_assignments
71+ FOR EACH ROW EXECUTE FUNCTION set_updated_at();
72+
73+ COMMIT ;
0 commit comments