diff --git a/docs/architecture.md b/docs/architecture.md index a22bb8e..56c03a6 100644 --- a/docs/architecture.md +++ b/docs/architecture.md @@ -90,14 +90,29 @@ CREATE TABLE habit_tracker.habit_completions ( ### Intake Tracker Schema Tables -#### Metrics Table +#### Intake Metrics Table ```sql -CREATE TABLE intake_tracker.metrics ( +CREATE TABLE intake_tracker.intake_metrics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE, metric_type VARCHAR(50) NOT NULL, -- 'water', 'weight', 'steps', 'sleep_hours' - value DECIMAL(10,2) NOT NULL, unit VARCHAR(20) NOT NULL, -- 'ml', 'kg', 'steps', 'hours' + display_name VARCHAR(100) NOT NULL, + target_value DECIMAL(10,2), -- optional daily target + is_cumulative BOOLEAN NOT NULL DEFAULT TRUE, -- true for water/steps, false for weight + created_at TIMESTAMP DEFAULT NOW(), + updated_at TIMESTAMP DEFAULT NOW(), + active BOOLEAN DEFAULT TRUE, + UNIQUE(user_id, metric_type) +); +``` + +#### Intake Records Table +```sql +CREATE TABLE intake_tracker.intake_records ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + intake_metric_id UUID NOT NULL REFERENCES intake_tracker.intake_metrics(id) ON DELETE CASCADE, + value DECIMAL(10,2) NOT NULL, recorded_at TIMESTAMP NOT NULL DEFAULT NOW(), notes TEXT, created_at TIMESTAMP DEFAULT NOW() @@ -108,17 +123,15 @@ CREATE TABLE intake_tracker.metrics ( ```sql CREATE TABLE intake_tracker.daily_summaries ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), - user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE, - metric_type VARCHAR(50) NOT NULL, + intake_metric_id UUID NOT NULL REFERENCES intake_tracker.intake_metrics(id) ON DELETE CASCADE, date DATE NOT NULL, total_value DECIMAL(10,2) NOT NULL, - unit VARCHAR(20) NOT NULL, entry_count INTEGER NOT NULL, first_entry_at TIMESTAMP, last_entry_at TIMESTAMP, created_at TIMESTAMP DEFAULT NOW(), updated_at TIMESTAMP DEFAULT NOW(), - UNIQUE(user_id, metric_type, date) + UNIQUE(intake_metric_id, date) ); ``` @@ -164,7 +177,13 @@ ADD CONSTRAINT check_interval_days CHECK ( ### Intake Tracker Constraints ```sql -- Intake tracker constraints -ALTER TABLE intake_tracker.metrics +ALTER TABLE intake_tracker.intake_metrics +ADD CONSTRAINT check_positive_target CHECK (target_value IS NULL OR target_value > 0), +ADD CONSTRAINT check_positive_min CHECK (min_value IS NULL OR min_value >= 0), +ADD CONSTRAINT check_positive_max CHECK (max_value IS NULL OR max_value > 0), +ADD CONSTRAINT check_min_max_order CHECK (min_value IS NULL OR max_value IS NULL OR min_value <= max_value); + +ALTER TABLE intake_tracker.intake_records ADD CONSTRAINT check_positive_value CHECK (value > 0), ADD CONSTRAINT check_recorded_at_not_future CHECK (recorded_at <= NOW()); @@ -184,12 +203,15 @@ ADD CONSTRAINT check_positive_count CHECK (entry_count > 0); 6. Deleting a user cascades to delete their habits and completions #### Intake Tracker -1. Each metric entry belongs to exactly one user -2. Metric values must be positive -3. Recorded timestamp cannot be in the future -4. Daily summaries are automatically maintained -5. Metric entries are immutable (no updates, only inserts) -6. Deleting a user cascades to delete their metrics and summaries +1. Each intake metric definition belongs to exactly one user +2. Each user can have only one metric definition per metric type +3. Intake record values must be positive +4. Recorded timestamp cannot be in the future +5. Daily summaries are automatically maintained +6. Intake records are immutable (no updates, only inserts) +7. Target, min, and max values are optional but must be positive if set +8. Deleting a user cascades to delete their metrics and records +9. Deleting a metric definition cascades to delete its records and summaries ## Performance Optimization @@ -209,11 +231,13 @@ CREATE INDEX idx_completions_habit_date ON habit_tracker.habit_completions(habit CREATE INDEX idx_user_settings_user_key ON shared.user_settings(user_id, key); -- Intake tracker indexes -CREATE INDEX idx_metrics_user_id ON intake_tracker.metrics(user_id); -CREATE INDEX idx_metrics_user_type ON intake_tracker.metrics(user_id, metric_type); -CREATE INDEX idx_metrics_recorded_at ON intake_tracker.metrics(recorded_at); -CREATE INDEX idx_metrics_user_type_date ON intake_tracker.metrics(user_id, metric_type, recorded_at); -CREATE INDEX idx_daily_summaries_user_type_date ON intake_tracker.daily_summaries(user_id, metric_type, date); +CREATE INDEX idx_intake_metrics_user_id ON intake_tracker.intake_metrics(user_id); +CREATE INDEX idx_intake_metrics_user_type ON intake_tracker.intake_metrics(user_id, metric_type); +CREATE INDEX idx_intake_metrics_active ON intake_tracker.intake_metrics(active) WHERE active = true; +CREATE INDEX idx_intake_records_metric_id ON intake_tracker.intake_records(intake_metric_id); +CREATE INDEX idx_intake_records_recorded_at ON intake_tracker.intake_records(recorded_at); +CREATE INDEX idx_intake_records_metric_date ON intake_tracker.intake_records(intake_metric_id, recorded_at); +CREATE INDEX idx_daily_summaries_metric_date ON intake_tracker.daily_summaries(intake_metric_id, date); CREATE INDEX idx_daily_summaries_date ON intake_tracker.daily_summaries(date); ``` @@ -250,19 +274,34 @@ INSERT INTO habit_tracker.habit_completions (habit_id, completed_at, notes) VALUES ('habit-uuid', '2024-01-15 08:30:00', 'Morning dose'); ``` -### Recording Intake Metrics +### Creating Intake Metrics ```sql --- Record water intake -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit, notes) -VALUES ('user-uuid', 'water', 500, 'ml', 'Morning hydration'); +-- Create water intake metric +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, target_value, is_cumulative) +VALUES ('user-uuid', 'water', 'ml', 'Water Intake', 2000, true); + +-- Create weight tracking metric +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, min_value, max_value, is_cumulative) +VALUES ('user-uuid', 'weight', 'kg', 'Body Weight', 50, 150, false); + +-- Create steps tracking metric +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, target_value, is_cumulative) +VALUES ('user-uuid', 'steps', 'steps', 'Daily Steps', 10000, true); +``` + +### Recording Intake Data +```sql +-- Record water intake (assuming metric already exists) +INSERT INTO intake_tracker.intake_records (intake_metric_id, value, notes) +VALUES ('water-metric-uuid', 500, 'Morning hydration'); -- Record weight -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit) -VALUES ('user-uuid', 'weight', 70.5, 'kg'); +INSERT INTO intake_tracker.intake_records (intake_metric_id, value) +VALUES ('weight-metric-uuid', 70.5); -- Record steps with specific time -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit, recorded_at) -VALUES ('user-uuid', 'steps', 8432, 'steps', '2024-01-15 18:00:00'); +INSERT INTO intake_tracker.intake_records (intake_metric_id, value, recorded_at) +VALUES ('steps-metric-uuid', 8432, '2024-01-15 18:00:00'); ``` ### Common Queries @@ -299,29 +338,51 @@ GROUP BY h.id HAVING MAX(hc.completed_at) IS NULL OR MAX(hc.completed_at) + INTERVAL '1 day' * h.interval_days <= NOW(); +-- Get user's active intake metrics +SELECT * FROM intake_tracker.intake_metrics +WHERE user_id = 'user-uuid' AND active = true +ORDER BY display_name; + -- Get today's water intake -SELECT SUM(value) as total_water_ml -FROM intake_tracker.metrics -WHERE user_id = 'user-uuid' -AND metric_type = 'water' -AND recorded_at >= CURRENT_DATE -AND recorded_at < CURRENT_DATE + INTERVAL '1 day'; +SELECT SUM(ir.value) as total_water_ml, im.target_value, im.unit +FROM intake_tracker.intake_records ir +JOIN intake_tracker.intake_metrics im ON ir.intake_metric_id = im.id +WHERE im.user_id = 'user-uuid' +AND im.metric_type = 'water' +AND ir.recorded_at >= CURRENT_DATE +AND ir.recorded_at < CURRENT_DATE + INTERVAL '1 day' +GROUP BY im.target_value, im.unit; -- Get daily summaries for water intake this week -SELECT date, total_value, entry_count -FROM intake_tracker.daily_summaries -WHERE user_id = 'user-uuid' -AND metric_type = 'water' -AND date >= CURRENT_DATE - INTERVAL '7 days' -ORDER BY date; +SELECT ds.date, ds.total_value, ds.entry_count, im.target_value, im.unit +FROM intake_tracker.daily_summaries ds +JOIN intake_tracker.intake_metrics im ON ds.intake_metric_id = im.id +WHERE im.user_id = 'user-uuid' +AND im.metric_type = 'water' +AND ds.date >= CURRENT_DATE - INTERVAL '7 days' +ORDER BY ds.date; -- Get latest weight entry -SELECT value, unit, recorded_at -FROM intake_tracker.metrics -WHERE user_id = 'user-uuid' -AND metric_type = 'weight' -ORDER BY recorded_at DESC +SELECT ir.value, im.unit, ir.recorded_at, im.min_value, im.max_value +FROM intake_tracker.intake_records ir +JOIN intake_tracker.intake_metrics im ON ir.intake_metric_id = im.id +WHERE im.user_id = 'user-uuid' +AND im.metric_type = 'weight' +ORDER BY ir.recorded_at DESC LIMIT 1; + +-- Check if daily target is met +SELECT im.display_name, im.target_value, COALESCE(SUM(ir.value), 0) as current_total, + CASE WHEN im.target_value IS NOT NULL AND COALESCE(SUM(ir.value), 0) >= im.target_value + THEN 'target_met' ELSE 'target_not_met' END as status +FROM intake_tracker.intake_metrics im +LEFT JOIN intake_tracker.intake_records ir ON im.id = ir.intake_metric_id + AND ir.recorded_at >= CURRENT_DATE + AND ir.recorded_at < CURRENT_DATE + INTERVAL '1 day' +WHERE im.user_id = 'user-uuid' +AND im.is_cumulative = true +AND im.active = true +GROUP BY im.id, im.display_name, im.target_value; ``` ## Migration Scripts @@ -401,12 +462,26 @@ CREATE INDEX idx_completions_habit_date ON habit_tracker.habit_completions(habit CREATE INDEX idx_user_settings_user_key ON shared.user_settings(user_id, key); -- Create intake tracker tables -CREATE TABLE intake_tracker.metrics ( +CREATE TABLE intake_tracker.intake_metrics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE, metric_type VARCHAR(50) NOT NULL, - value DECIMAL(10,2) NOT NULL, unit VARCHAR(20) NOT NULL, + display_name VARCHAR(100) NOT NULL, + target_value DECIMAL(10,2), + min_value DECIMAL(10,2), + max_value DECIMAL(10,2), + is_cumulative BOOLEAN NOT NULL DEFAULT TRUE, + created_at TIMESTAMP DEFAULT NOW(), + updated_at TIMESTAMP DEFAULT NOW(), + active BOOLEAN DEFAULT TRUE, + UNIQUE(user_id, metric_type) +); + +CREATE TABLE intake_tracker.intake_records ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + intake_metric_id UUID NOT NULL REFERENCES intake_tracker.intake_metrics(id) ON DELETE CASCADE, + value DECIMAL(10,2) NOT NULL, recorded_at TIMESTAMP NOT NULL DEFAULT NOW(), notes TEXT, created_at TIMESTAMP DEFAULT NOW() @@ -414,21 +489,25 @@ CREATE TABLE intake_tracker.metrics ( CREATE TABLE intake_tracker.daily_summaries ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), - user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE, - metric_type VARCHAR(50) NOT NULL, + intake_metric_id UUID NOT NULL REFERENCES intake_tracker.intake_metrics(id) ON DELETE CASCADE, date DATE NOT NULL, total_value DECIMAL(10,2) NOT NULL, - unit VARCHAR(20) NOT NULL, entry_count INTEGER NOT NULL, first_entry_at TIMESTAMP, last_entry_at TIMESTAMP, created_at TIMESTAMP DEFAULT NOW(), updated_at TIMESTAMP DEFAULT NOW(), - UNIQUE(user_id, metric_type, date) + UNIQUE(intake_metric_id, date) ); -- Add intake tracker constraints -ALTER TABLE intake_tracker.metrics +ALTER TABLE intake_tracker.intake_metrics +ADD CONSTRAINT check_positive_target CHECK (target_value IS NULL OR target_value > 0), +ADD CONSTRAINT check_positive_min CHECK (min_value IS NULL OR min_value >= 0), +ADD CONSTRAINT check_positive_max CHECK (max_value IS NULL OR max_value > 0), +ADD CONSTRAINT check_min_max_order CHECK (min_value IS NULL OR max_value IS NULL OR min_value <= max_value); + +ALTER TABLE intake_tracker.intake_records ADD CONSTRAINT check_positive_value CHECK (value > 0), ADD CONSTRAINT check_recorded_at_not_future CHECK (recorded_at <= NOW()); @@ -437,11 +516,13 @@ ADD CONSTRAINT check_positive_total CHECK (total_value > 0), ADD CONSTRAINT check_positive_count CHECK (entry_count > 0); -- Create intake tracker indexes -CREATE INDEX idx_metrics_user_id ON intake_tracker.metrics(user_id); -CREATE INDEX idx_metrics_user_type ON intake_tracker.metrics(user_id, metric_type); -CREATE INDEX idx_metrics_recorded_at ON intake_tracker.metrics(recorded_at); -CREATE INDEX idx_metrics_user_type_date ON intake_tracker.metrics(user_id, metric_type, recorded_at); -CREATE INDEX idx_daily_summaries_user_type_date ON intake_tracker.daily_summaries(user_id, metric_type, date); +CREATE INDEX idx_intake_metrics_user_id ON intake_tracker.intake_metrics(user_id); +CREATE INDEX idx_intake_metrics_user_type ON intake_tracker.intake_metrics(user_id, metric_type); +CREATE INDEX idx_intake_metrics_active ON intake_tracker.intake_metrics(active) WHERE active = true; +CREATE INDEX idx_intake_records_metric_id ON intake_tracker.intake_records(intake_metric_id); +CREATE INDEX idx_intake_records_recorded_at ON intake_tracker.intake_records(recorded_at); +CREATE INDEX idx_intake_records_metric_date ON intake_tracker.intake_records(intake_metric_id, recorded_at); +CREATE INDEX idx_daily_summaries_metric_date ON intake_tracker.daily_summaries(intake_metric_id, date); CREATE INDEX idx_daily_summaries_date ON intake_tracker.daily_summaries(date); ``` @@ -465,11 +546,17 @@ INSERT INTO habit_tracker.habits (user_id, name, frequency_type, interval_days) ('user-uuid', 'Grocery shopping', 'interval', 3); -- Create sample intake metrics (replace user-uuid with actual user ID) -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit, notes) VALUES -('user-uuid', 'water', 500, 'ml', 'Morning glass'), -('user-uuid', 'water', 300, 'ml', 'After workout'), -('user-uuid', 'weight', 70.5, 'kg', 'Morning weigh-in'), -('user-uuid', 'steps', 8432, 'steps', 'Daily walk'); +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, target_value, is_cumulative) VALUES +('user-uuid', 'water', 'ml', 'Water Intake', 2000, true), +('user-uuid', 'weight', 'kg', 'Body Weight', NULL, false), +('user-uuid', 'steps', 'steps', 'Daily Steps', 10000, true); + +-- Create sample intake records (replace metric-uuid with actual metric IDs) +INSERT INTO intake_tracker.intake_records (intake_metric_id, value, notes) VALUES +('water-metric-uuid', 500, 'Morning glass'), +('water-metric-uuid', 300, 'After workout'), +('weight-metric-uuid', 70.5, 'Morning weigh-in'), +('steps-metric-uuid', 8432, 'Daily walk'); ``` ## Cross-System Integration @@ -499,11 +586,12 @@ FROM habit_tracker.habits WHERE id = 'habit-uuid' AND goal_type IS NOT NULL; -- 2. Check if goal is met in intake tracker -SELECT COALESCE(SUM(value), 0) as current_total -FROM intake_tracker.metrics -WHERE user_id = 'user-uuid' -AND metric_type = 'water' -AND recorded_at >= CURRENT_DATE; +SELECT COALESCE(SUM(ir.value), 0) as current_total +FROM intake_tracker.intake_records ir +JOIN intake_tracker.intake_metrics im ON ir.intake_metric_id = im.id +WHERE im.user_id = 'user-uuid' +AND im.metric_type = 'water' +AND ir.recorded_at >= CURRENT_DATE; -- 3. Auto-complete habit if goal is met INSERT INTO habit_tracker.habit_completions (habit_id, notes) @@ -533,9 +621,13 @@ WHERE 2000 >= 2000; -- goal_target comparison INSERT INTO habit_tracker.habits (user_id, name, frequency_type, goal_type, goal_target, goal_unit) VALUES ('user-uuid', 'Drink enough water', 'daily', 'water', 2000, 'ml'); +-- First create the metric definition +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, target_value, is_cumulative) +VALUES ('user-uuid', 'water', 'ml', 'Water Intake', 2000, true); + -- Record water intake -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit) -VALUES ('user-uuid', 'water', 500, 'ml'); +INSERT INTO intake_tracker.intake_records (intake_metric_id, value) +VALUES ('water-metric-uuid', 500); -- API logic checks if daily goal is met and auto-completes habit ``` @@ -546,9 +638,13 @@ VALUES ('user-uuid', 'water', 500, 'ml'); INSERT INTO habit_tracker.habits (user_id, name, frequency_type, goal_type, goal_target, goal_unit) VALUES ('user-uuid', 'Get 10k steps', 'daily', 'steps', 10000, 'steps'); +-- First create the metric definition +INSERT INTO intake_tracker.intake_metrics (user_id, metric_type, unit, display_name, target_value, is_cumulative) +VALUES ('user-uuid', 'steps', 'steps', 'Daily Steps', 10000, true); + -- Steps can be recorded from fitness tracker -INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit) -VALUES ('user-uuid', 'steps', 8432, 'steps'); +INSERT INTO intake_tracker.intake_records (intake_metric_id, value) +VALUES ('steps-metric-uuid', 8432); ``` ## Future Considerations