feat: iterating on database design

This commit is contained in:
Yadunand Prem 2025-07-07 09:35:09 -04:00
commit 4b527be796
No known key found for this signature in database
4 changed files with 903 additions and 0 deletions

140
devenv.lock Normal file
View File

@ -0,0 +1,140 @@
{
"nodes": {
"devenv": {
"locked": {
"dir": "src/modules",
"lastModified": 1749416335,
"owner": "cachix",
"repo": "devenv",
"rev": "e8fffc7d61259f27c27b0fbe39a052a604807a2e",
"type": "github"
},
"original": {
"dir": "src/modules",
"owner": "cachix",
"repo": "devenv",
"type": "github"
}
},
"fenix": {
"inputs": {
"nixpkgs": [
"nixpkgs"
],
"rust-analyzer-src": "rust-analyzer-src"
},
"locked": {
"lastModified": 1751784058,
"owner": "nix-community",
"repo": "fenix",
"rev": "632549aad97975cbcdf19d0cf291e5d107208e51",
"type": "github"
},
"original": {
"owner": "nix-community",
"repo": "fenix",
"type": "github"
}
},
"flake-compat": {
"flake": false,
"locked": {
"lastModified": 1747046372,
"owner": "edolstra",
"repo": "flake-compat",
"rev": "9100a0f413b0c601e0533d1d94ffd501ce2e7885",
"type": "github"
},
"original": {
"owner": "edolstra",
"repo": "flake-compat",
"type": "github"
}
},
"git-hooks": {
"inputs": {
"flake-compat": "flake-compat",
"gitignore": "gitignore",
"nixpkgs": [
"nixpkgs"
]
},
"locked": {
"lastModified": 1747372754,
"owner": "cachix",
"repo": "git-hooks.nix",
"rev": "80479b6ec16fefd9c1db3ea13aeb038c60530f46",
"type": "github"
},
"original": {
"owner": "cachix",
"repo": "git-hooks.nix",
"type": "github"
}
},
"gitignore": {
"inputs": {
"nixpkgs": [
"git-hooks",
"nixpkgs"
]
},
"locked": {
"lastModified": 1709087332,
"owner": "hercules-ci",
"repo": "gitignore.nix",
"rev": "637db329424fd7e46cf4185293b9cc8c88c95394",
"type": "github"
},
"original": {
"owner": "hercules-ci",
"repo": "gitignore.nix",
"type": "github"
}
},
"nixpkgs": {
"locked": {
"lastModified": 1746807397,
"owner": "cachix",
"repo": "devenv-nixpkgs",
"rev": "c5208b594838ea8e6cca5997fbf784b7cca1ca90",
"type": "github"
},
"original": {
"owner": "cachix",
"ref": "rolling",
"repo": "devenv-nixpkgs",
"type": "github"
}
},
"root": {
"inputs": {
"devenv": "devenv",
"fenix": "fenix",
"git-hooks": "git-hooks",
"nixpkgs": "nixpkgs",
"pre-commit-hooks": [
"git-hooks"
]
}
},
"rust-analyzer-src": {
"flake": false,
"locked": {
"lastModified": 1751744599,
"owner": "rust-lang",
"repo": "rust-analyzer",
"rev": "2d518c73d9a9de0dc96d013db7fd98b964f3a7de",
"type": "github"
},
"original": {
"owner": "rust-lang",
"ref": "nightly",
"repo": "rust-analyzer",
"type": "github"
}
}
},
"root": "root",
"version": 7
}

22
devenv.nix Normal file
View File

@ -0,0 +1,22 @@
{
pkgs,
lib,
config,
inputs,
...
}:
{
packages = with pkgs; [
git
bun
cargo-generate
];
# https://devenv.sh/languages/
languages.rust = {
enable = true;
channel = "stable";
};
}

8
devenv.yaml Normal file
View File

@ -0,0 +1,8 @@
inputs:
fenix:
url: github:nix-community/fenix
inputs:
nixpkgs:
follows: nixpkgs
nixpkgs:
url: github:cachix/devenv-nixpkgs/rolling

733
docs/architecture.md Normal file
View File

@ -0,0 +1,733 @@
# Database Architecture
## Overview
This system uses a PostgreSQL database with a multi-schema architecture to support multiple tools while enabling cross-tool data sharing and unified dashboards. Each tool has its own schema, with a shared schema for common functionality like user management.
## Schema Structure
### Shared Schema (`shared`)
Contains common functionality used across all tools:
- User management
- Cross-tool settings and preferences
- Shared utilities
### Tool-Specific Schemas
Each tool has its own schema:
- `habit_tracker` - Binary habit completion tracking
- `intake_tracker` - Quantitative metrics tracking (water, steps, weight, etc.)
- `food_tracker` - Complex food intake and nutrition tracking (planned)
- `future_tool_1` - Placeholder for future tools
## Database Setup
```sql
-- Enable UUID extension
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- Create schemas
CREATE SCHEMA IF NOT EXISTS shared;
CREATE SCHEMA IF NOT EXISTS habit_tracker;
CREATE SCHEMA IF NOT EXISTS intake_tracker;
```
## Table Definitions
### Shared Schema Tables
#### Users Table
```sql
CREATE TABLE shared.users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
username VARCHAR(50) UNIQUE NOT NULL,
email VARCHAR(255) UNIQUE NOT NULL,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
```
#### User Settings Table
```sql
CREATE TABLE shared.user_settings (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
key VARCHAR(100) NOT NULL,
value JSONB,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
UNIQUE(user_id, key)
);
```
### Habit Tracker Schema Tables
#### Habits Table
```sql
CREATE TABLE habit_tracker.habits (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
description TEXT,
frequency_type VARCHAR(20) NOT NULL CHECK (frequency_type IN ('daily', 'interval', 'multi_daily')),
target_count INTEGER NOT NULL DEFAULT 1,
interval_days INTEGER, -- NULL for daily/multi_daily, required for interval
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
active BOOLEAN DEFAULT TRUE
);
```
#### Habit Completions Table
```sql
CREATE TABLE habit_tracker.habit_completions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
habit_id UUID NOT NULL REFERENCES habit_tracker.habits(id) ON DELETE CASCADE,
completed_at TIMESTAMP NOT NULL DEFAULT NOW(),
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
```
### Intake Tracker Schema Tables
#### Metrics Table
```sql
CREATE TABLE intake_tracker.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'
recorded_at TIMESTAMP NOT NULL DEFAULT NOW(),
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
```
#### Daily Summaries Table
```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,
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)
);
```
## Habit Types
### Daily Habits
**Purpose**: Habits that should be completed once every day
**Examples**: Taking vitamins, morning meditation, reading
**Configuration**:
- `frequency_type = 'daily'`
- `target_count = 1`
- `interval_days = NULL`
### Multi-Daily Habits
**Purpose**: Habits that should be completed multiple times per day
**Examples**: Brushing teeth (2x), drinking water (8x), taking breaks (5x)
**Configuration**:
- `frequency_type = 'multi_daily'`
- `target_count = N` (number of times per day)
- `interval_days = NULL`
### Interval Habits
**Purpose**: Habits that should be completed X days after the last completion
**Examples**: Cleaning house (every 7 days), car maintenance (every 30 days)
**Configuration**:
- `frequency_type = 'interval'`
- `target_count = 1`
- `interval_days = X` (days between completions)
## Constraints and Business Rules
### Table Constraints
```sql
-- Habits table constraints
ALTER TABLE habit_tracker.habits
ADD CONSTRAINT check_target_count CHECK (target_count > 0),
ADD CONSTRAINT check_interval_days CHECK (
(frequency_type = 'interval' AND interval_days IS NOT NULL AND interval_days > 0)
OR (frequency_type != 'interval' AND interval_days IS NULL)
);
```
### Intake Tracker Constraints
```sql
-- Intake tracker constraints
ALTER TABLE intake_tracker.metrics
ADD CONSTRAINT check_positive_value CHECK (value > 0),
ADD CONSTRAINT check_recorded_at_not_future CHECK (recorded_at <= NOW());
ALTER TABLE intake_tracker.daily_summaries
ADD CONSTRAINT check_positive_total CHECK (total_value > 0),
ADD CONSTRAINT check_positive_count CHECK (entry_count > 0);
```
### Business Rules
#### Habit Tracker
1. Each habit belongs to exactly one user
2. Interval habits must have `interval_days > 0`
3. Daily and multi-daily habits must have `interval_days = NULL`
4. Target count must be positive
5. Completions are immutable (no updates, only inserts)
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
## Performance Optimization
### Indexes
```sql
-- Primary access patterns
CREATE INDEX idx_habits_user_id ON habit_tracker.habits(user_id);
CREATE INDEX idx_habits_active ON habit_tracker.habits(active) WHERE active = true;
CREATE INDEX idx_completions_habit_id ON habit_tracker.habit_completions(habit_id);
CREATE INDEX idx_completions_completed_at ON habit_tracker.habit_completions(completed_at);
-- Composite indexes for common queries
CREATE INDEX idx_habits_user_active ON habit_tracker.habits(user_id, active) WHERE active = true;
CREATE INDEX idx_completions_habit_date ON habit_tracker.habit_completions(habit_id, completed_at);
-- User settings access
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_daily_summaries_date ON intake_tracker.daily_summaries(date);
```
### Query Optimization
- Use composite indexes for user-specific queries
- Partition completions table by month for large datasets (future scaling)
- Consider materialized views for streak calculations and statistics
## Usage Examples
### Creating Habits
```sql
-- Daily vitamin habit
INSERT INTO habit_tracker.habits (user_id, name, frequency_type, target_count)
VALUES ('user-uuid', 'Take vitamins', 'daily', 1);
-- Twice-daily teeth brushing
INSERT INTO habit_tracker.habits (user_id, name, frequency_type, target_count)
VALUES ('user-uuid', 'Brush teeth', 'multi_daily', 2);
-- Weekly house cleaning
INSERT INTO habit_tracker.habits (user_id, name, frequency_type, interval_days)
VALUES ('user-uuid', 'Clean house', 'interval', 7);
```
### Recording Completions
```sql
-- Complete a habit
INSERT INTO habit_tracker.habit_completions (habit_id, notes)
VALUES ('habit-uuid', 'Completed during lunch break');
-- Complete with specific timestamp
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
```sql
-- Record water intake
INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit, notes)
VALUES ('user-uuid', 'water', 500, 'ml', 'Morning hydration');
-- Record weight
INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit)
VALUES ('user-uuid', 'weight', 70.5, 'kg');
-- 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');
```
### Common Queries
```sql
-- Get user's active habits
SELECT * FROM habit_tracker.habits
WHERE user_id = 'user-uuid' AND active = true
ORDER BY created_at;
-- Get today's completions for a habit
SELECT * FROM habit_tracker.habit_completions
WHERE habit_id = 'habit-uuid'
AND completed_at >= CURRENT_DATE
AND completed_at < CURRENT_DATE + INTERVAL '1 day';
-- Check if daily habit is completed today
SELECT COUNT(*) as completions_today
FROM habit_tracker.habit_completions hc
JOIN habit_tracker.habits h ON hc.habit_id = h.id
WHERE h.user_id = 'user-uuid'
AND h.frequency_type = 'daily'
AND hc.completed_at >= CURRENT_DATE;
-- Get habits due for interval-based completion
SELECT h.*,
MAX(hc.completed_at) as last_completed,
MAX(hc.completed_at) + INTERVAL '1 day' * h.interval_days as next_due
FROM habit_tracker.habits h
LEFT JOIN habit_tracker.habit_completions hc ON h.id = hc.habit_id
WHERE h.user_id = 'user-uuid'
AND h.frequency_type = 'interval'
AND h.active = true
GROUP BY h.id
HAVING MAX(hc.completed_at) IS NULL
OR MAX(hc.completed_at) + INTERVAL '1 day' * h.interval_days <= NOW();
-- 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';
-- 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;
-- 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
LIMIT 1;
```
## Migration Scripts
### Initial Setup
```sql
-- Create database (run as superuser)
CREATE DATABASE personal_system;
-- Connect to database and run setup
\c personal_system;
-- Enable extensions
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- Create schemas
CREATE SCHEMA IF NOT EXISTS shared;
CREATE SCHEMA IF NOT EXISTS habit_tracker;
CREATE SCHEMA IF NOT EXISTS intake_tracker;
-- Create shared tables
CREATE TABLE shared.users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
username VARCHAR(50) UNIQUE NOT NULL,
email VARCHAR(255) UNIQUE NOT NULL,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
CREATE TABLE shared.user_settings (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
key VARCHAR(100) NOT NULL,
value JSONB,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
UNIQUE(user_id, key)
);
-- Create habit tracker tables
CREATE TABLE habit_tracker.habits (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
description TEXT,
frequency_type VARCHAR(20) NOT NULL CHECK (frequency_type IN ('daily', 'interval', 'multi_daily')),
target_count INTEGER NOT NULL DEFAULT 1,
interval_days INTEGER,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
active BOOLEAN DEFAULT TRUE
);
CREATE TABLE habit_tracker.habit_completions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
habit_id UUID NOT NULL REFERENCES habit_tracker.habits(id) ON DELETE CASCADE,
completed_at TIMESTAMP NOT NULL DEFAULT NOW(),
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
-- Add constraints
ALTER TABLE habit_tracker.habits
ADD CONSTRAINT check_target_count CHECK (target_count > 0),
ADD CONSTRAINT check_interval_days CHECK (
(frequency_type = 'interval' AND interval_days IS NOT NULL AND interval_days > 0)
OR (frequency_type != 'interval' AND interval_days IS NULL)
);
-- Create habit tracker indexes
CREATE INDEX idx_habits_user_id ON habit_tracker.habits(user_id);
CREATE INDEX idx_habits_active ON habit_tracker.habits(active) WHERE active = true;
CREATE INDEX idx_completions_habit_id ON habit_tracker.habit_completions(habit_id);
CREATE INDEX idx_completions_completed_at ON habit_tracker.habit_completions(completed_at);
CREATE INDEX idx_habits_user_active ON habit_tracker.habits(user_id, active) WHERE active = true;
CREATE INDEX idx_completions_habit_date ON habit_tracker.habit_completions(habit_id, completed_at);
CREATE INDEX idx_user_settings_user_key ON shared.user_settings(user_id, key);
-- Create intake tracker tables
CREATE TABLE intake_tracker.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,
recorded_at TIMESTAMP NOT NULL DEFAULT NOW(),
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
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,
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)
);
-- Add intake tracker constraints
ALTER TABLE intake_tracker.metrics
ADD CONSTRAINT check_positive_value CHECK (value > 0),
ADD CONSTRAINT check_recorded_at_not_future CHECK (recorded_at <= NOW());
ALTER TABLE intake_tracker.daily_summaries
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_daily_summaries_date ON intake_tracker.daily_summaries(date);
```
### Sample Data
```sql
-- Create a test user
INSERT INTO shared.users (username, email)
VALUES ('testuser', 'test@example.com');
-- Get user ID (replace with actual UUID in production)
-- SELECT id FROM shared.users WHERE username = 'testuser';
-- Create sample habits (replace user-uuid with actual user ID)
INSERT INTO habit_tracker.habits (user_id, name, frequency_type, target_count) VALUES
('user-uuid', 'Take vitamins', 'daily', 1),
('user-uuid', 'Brush teeth', 'multi_daily', 2),
('user-uuid', 'Exercise', 'daily', 1);
INSERT INTO habit_tracker.habits (user_id, name, frequency_type, interval_days) VALUES
('user-uuid', 'Clean house', 'interval', 7),
('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');
```
## Cross-System Integration
### Goal-Based Habits (Optional Enhancement)
The system supports linking habits to quantitative goals through optional fields:
```sql
-- Optional goal tracking fields for habits
ALTER TABLE habit_tracker.habits
ADD COLUMN goal_type VARCHAR(50), -- 'water_intake', 'step_count', etc.
ADD COLUMN goal_target DECIMAL,
ADD COLUMN goal_unit VARCHAR(20);
```
### Integration Patterns
#### API-Level Integration
Cross-system relationships are handled at the application layer rather than database foreign keys:
```sql
-- Example: Goal-based habit completion
-- 1. Check if habit has a goal
SELECT goal_type, goal_target, goal_unit
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;
-- 3. Auto-complete habit if goal is met
INSERT INTO habit_tracker.habit_completions (habit_id, notes)
SELECT 'habit-uuid', 'Auto-completed: 2L water goal reached'
WHERE 2000 >= 2000; -- goal_target comparison
```
#### Cross-System Use Cases
1. **Goal-Driven Habits**: "Drink 2L water daily" auto-completes when water intake reaches 2L
2. **Progress Tracking**: Dashboard shows habit streaks alongside metric trends
3. **Unified Reporting**: Weekly summaries combine habit completion rates with metric averages
4. **Threshold Alerts**: Notifications when metrics fall below habit-related targets
#### Data Sharing Best Practices
- **Loose Coupling**: Systems communicate through shared user IDs and metric types
- **Event-Driven**: Consider publishing events when goals are met or habits completed
- **API Aggregation**: Combine data from multiple schemas in API responses
- **Separate Concerns**: Each system optimized for its domain while supporting integration
### Example Integration Scenarios
#### Water Intake Habit
```sql
-- Create goal-based habit
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');
-- Record water intake
INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit)
VALUES ('user-uuid', 'water', 500, 'ml');
-- API logic checks if daily goal is met and auto-completes habit
```
#### Fitness Integration
```sql
-- Create step-based habit
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');
-- Steps can be recorded from fitness tracker
INSERT INTO intake_tracker.metrics (user_id, metric_type, value, unit)
VALUES ('user-uuid', 'steps', 8432, 'steps');
```
## Future Considerations
### Scaling
- Partition `habit_completions` by month when data grows large
- Implement read replicas for dashboard queries
- Consider caching for frequently accessed habit status
### Additional Features
- Habit streaks (consecutive completions)
- Habit statistics and analytics
- Habit templates and sharing
- Reminder/notification system
- Habit dependencies and chains
### Cross-Tool Integration
- Link habits to calendar events
- Connect with fitness/health tracking tools
- Integration with task management systems
- Shared reporting and dashboard capabilities
## Food Tracker Schema (Future Implementation)
### Overview
The food tracker system will handle complex nutritional tracking including multiple foods per meal, recipes, and comprehensive nutritional analysis. This system is designed to be more sophisticated than the simple intake tracker.
### Schema Design
#### Food Database
```sql
CREATE SCHEMA food_tracker;
-- Master food database
CREATE TABLE food_tracker.foods (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL,
brand VARCHAR(100),
barcode VARCHAR(50),
category VARCHAR(50), -- 'vegetables', 'proteins', 'grains', etc.
serving_size_grams DECIMAL(8,2) NOT NULL DEFAULT 100,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- Nutritional information per 100g
CREATE TABLE food_tracker.food_nutrition (
food_id UUID PRIMARY KEY REFERENCES food_tracker.foods(id) ON DELETE CASCADE,
calories DECIMAL(8,2) NOT NULL,
protein_g DECIMAL(8,2) NOT NULL DEFAULT 0,
carbs_g DECIMAL(8,2) NOT NULL DEFAULT 0,
fat_g DECIMAL(8,2) NOT NULL DEFAULT 0,
fiber_g DECIMAL(8,2) NOT NULL DEFAULT 0,
sugar_g DECIMAL(8,2) NOT NULL DEFAULT 0,
sodium_mg DECIMAL(8,2) NOT NULL DEFAULT 0,
potassium_mg DECIMAL(8,2) NOT NULL DEFAULT 0,
calcium_mg DECIMAL(8,2) NOT NULL DEFAULT 0,
iron_mg DECIMAL(8,2) NOT NULL DEFAULT 0,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
```
#### Meal Tracking
```sql
-- User's meals
CREATE TABLE food_tracker.meals (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
meal_type VARCHAR(20) NOT NULL CHECK (meal_type IN ('breakfast', 'lunch', 'dinner', 'snack')),
consumed_at TIMESTAMP NOT NULL DEFAULT NOW(),
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
-- Individual food items within meals
CREATE TABLE food_tracker.meal_items (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
meal_id UUID NOT NULL REFERENCES food_tracker.meals(id) ON DELETE CASCADE,
food_id UUID NOT NULL REFERENCES food_tracker.foods(id),
quantity_grams DECIMAL(8,2) NOT NULL,
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
```
#### Recipe Support
```sql
-- User-created recipes
CREATE TABLE food_tracker.recipes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
description TEXT,
servings INTEGER NOT NULL DEFAULT 1,
prep_time_minutes INTEGER,
cook_time_minutes INTEGER,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- Ingredients in recipes
CREATE TABLE food_tracker.recipe_ingredients (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
recipe_id UUID NOT NULL REFERENCES food_tracker.recipes(id) ON DELETE CASCADE,
food_id UUID NOT NULL REFERENCES food_tracker.foods(id),
quantity_grams DECIMAL(8,2) NOT NULL,
notes TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
-- Allow meals to include recipes
ALTER TABLE food_tracker.meal_items
ADD COLUMN recipe_id UUID REFERENCES food_tracker.recipes(id),
ADD COLUMN recipe_servings DECIMAL(4,2) DEFAULT 1,
ADD CONSTRAINT check_food_or_recipe CHECK (
(food_id IS NOT NULL AND recipe_id IS NULL) OR
(food_id IS NULL AND recipe_id IS NOT NULL)
);
```
#### Daily Nutritional Summaries
```sql
-- Cached daily nutrition totals for performance
CREATE TABLE food_tracker.daily_nutrition (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES shared.users(id) ON DELETE CASCADE,
date DATE NOT NULL,
total_calories DECIMAL(8,2) NOT NULL DEFAULT 0,
total_protein_g DECIMAL(8,2) NOT NULL DEFAULT 0,
total_carbs_g DECIMAL(8,2) NOT NULL DEFAULT 0,
total_fat_g DECIMAL(8,2) NOT NULL DEFAULT 0,
total_fiber_g DECIMAL(8,2) NOT NULL DEFAULT 0,
total_sugar_g DECIMAL(8,2) NOT NULL DEFAULT 0,
total_sodium_mg DECIMAL(8,2) NOT NULL DEFAULT 0,
meal_count INTEGER NOT NULL DEFAULT 0,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
UNIQUE(user_id, date)
);
```
### Performance Optimization
```sql
-- Food tracker indexes
CREATE INDEX idx_foods_name ON food_tracker.foods(name);
CREATE INDEX idx_foods_category ON food_tracker.foods(category);
CREATE INDEX idx_foods_barcode ON food_tracker.foods(barcode) WHERE barcode IS NOT NULL;
CREATE INDEX idx_meals_user_date ON food_tracker.meals(user_id, consumed_at);
CREATE INDEX idx_meals_user_type ON food_tracker.meals(user_id, meal_type);
CREATE INDEX idx_meal_items_meal_id ON food_tracker.meal_items(meal_id);
CREATE INDEX idx_meal_items_food_id ON food_tracker.meal_items(food_id);
CREATE INDEX idx_recipes_user_id ON food_tracker.recipes(user_id);
CREATE INDEX idx_recipe_ingredients_recipe_id ON food_tracker.recipe_ingredients(recipe_id);
CREATE INDEX idx_daily_nutrition_user_date ON food_tracker.daily_nutrition(user_id, date);
```
### Business Rules
1. **Food Database**: Centralized food database with nutritional info per 100g
2. **Meals**: Users can create meals with multiple food items
3. **Portions**: All quantities stored in grams for consistency
4. **Recipes**: Users can create reusable recipes with calculated nutrition
5. **Daily Summaries**: Automatically maintained for performance
6. **Immutable Entries**: Meal items are immutable once created
7. **Flexible Structure**: Support for both individual foods and complex recipes
### Integration with Other Systems
- **Habit Tracker**: "Eat healthy" habits can be linked to calorie/macro targets
- **Intake Tracker**: Water intake can be displayed alongside food intake
- **Goals**: Daily nutrition goals can trigger habit completions
### Future Enhancements
- **Barcode Scanning**: Mobile app integration for quick food entry
- **Restaurant Database**: Integration with restaurant nutritional databases
- **Meal Planning**: Weekly meal planning and grocery lists
- **Photo Recognition**: AI-powered food identification from photos
- **Macro Tracking**: Detailed macronutrient analysis and goals
- **Export Integration**: Connect with fitness apps and wearables