Files
maternal-app/docs/maternal-app-db-migrations.md
2025-10-01 19:01:52 +00:00

12 KiB

Database Migration Scripts - Maternal Organization App

Migration Strategy

Naming Convention

  • Format: V{version}_{timestamp}_{description}.sql
  • Example: V001_20240110120000_create_users_table.sql
  • Rollback: R001_20240110120000_create_users_table.sql

Execution Order

Migrations must run sequentially. Each migration is recorded in a schema_migrations table to prevent re-execution.


Migration V001: Core Authentication Tables

Up Migration

-- V001_20240110120000_create_core_auth.sql

CREATE TABLE users (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('usr_' || nanoid()),
    email VARCHAR(255) UNIQUE NOT NULL,
    phone VARCHAR(20),
    password_hash VARCHAR(255) NOT NULL,
    name VARCHAR(100) NOT NULL,
    locale VARCHAR(10) DEFAULT 'en-US',
    timezone VARCHAR(50) DEFAULT 'UTC',
    email_verified BOOLEAN DEFAULT FALSE,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE device_registry (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('dev_' || nanoid()),
    user_id VARCHAR(20) NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    device_fingerprint VARCHAR(255) NOT NULL,
    platform VARCHAR(20) NOT NULL,
    trusted BOOLEAN DEFAULT FALSE,
    last_seen TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    UNIQUE(user_id, device_fingerprint)
);

CREATE INDEX idx_users_email ON users(email);
CREATE INDEX idx_devices_user ON device_registry(user_id);

Down Migration

-- R001_20240110120000_create_core_auth.sql
DROP TABLE device_registry;
DROP TABLE users;

Migration V002: Family Structure

Up Migration

-- V002_20240110130000_create_family_structure.sql

CREATE TABLE families (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('fam_' || nanoid()),
    name VARCHAR(100),
    share_code VARCHAR(10) UNIQUE DEFAULT upper(substr(md5(random()::text), 1, 6)),
    created_by VARCHAR(20) REFERENCES users(id),
    subscription_tier VARCHAR(20) DEFAULT 'free',
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE family_members (
    user_id VARCHAR(20) REFERENCES users(id) ON DELETE CASCADE,
    family_id VARCHAR(20) REFERENCES families(id) ON DELETE CASCADE,
    role VARCHAR(20) NOT NULL CHECK (role IN ('parent', 'caregiver', 'viewer')),
    permissions JSONB DEFAULT '{"canAddChildren": false, "canEditChildren": false, "canLogActivities": true, "canViewReports": true}'::jsonb,
    joined_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    PRIMARY KEY (user_id, family_id)
);

CREATE TABLE children (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('chd_' || nanoid()),
    family_id VARCHAR(20) NOT NULL REFERENCES families(id) ON DELETE CASCADE,
    name VARCHAR(100) NOT NULL,
    birth_date DATE NOT NULL,
    gender VARCHAR(20),
    photo_url TEXT,
    medical_info JSONB DEFAULT '{}'::jsonb,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    deleted_at TIMESTAMP
);

CREATE INDEX idx_families_share_code ON families(share_code);
CREATE INDEX idx_family_members_family ON family_members(family_id);
CREATE INDEX idx_children_family ON children(family_id);
CREATE INDEX idx_children_active ON children(deleted_at) WHERE deleted_at IS NULL;

Migration V003: Activity Tracking Tables

Up Migration

-- V003_20240110140000_create_activity_tracking.sql

CREATE TABLE activities (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('act_' || nanoid()),
    child_id VARCHAR(20) NOT NULL REFERENCES children(id) ON DELETE CASCADE,
    type VARCHAR(20) NOT NULL CHECK (type IN ('feeding', 'sleep', 'diaper', 'growth', 'medication', 'temperature')),
    started_at TIMESTAMP NOT NULL,
    ended_at TIMESTAMP,
    logged_by VARCHAR(20) NOT NULL REFERENCES users(id),
    notes TEXT,
    metadata JSONB DEFAULT '{}'::jsonb,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

-- Partitioned by month for scalability
CREATE TABLE activities_2024_01 PARTITION OF activities
    FOR VALUES FROM ('2024-01-01') TO ('2024-02-01');

CREATE INDEX idx_activities_child_time ON activities(child_id, started_at DESC);
CREATE INDEX idx_activities_type ON activities(type, started_at DESC);
CREATE INDEX idx_activities_metadata ON activities USING gin(metadata);

Migration V004: AI and Analytics Tables

Up Migration

-- V004_20240110150000_create_ai_analytics.sql

CREATE TABLE conversations (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('conv_' || nanoid()),
    user_id VARCHAR(20) NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    child_id VARCHAR(20) REFERENCES children(id) ON DELETE CASCADE,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    last_message_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE messages (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('msg_' || nanoid()),
    conversation_id VARCHAR(20) NOT NULL REFERENCES conversations(id) ON DELETE CASCADE,
    role VARCHAR(20) NOT NULL CHECK (role IN ('user', 'assistant')),
    content TEXT NOT NULL,
    metadata JSONB DEFAULT '{}'::jsonb,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE patterns (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('pat_' || nanoid()),
    child_id VARCHAR(20) NOT NULL REFERENCES children(id) ON DELETE CASCADE,
    type VARCHAR(50) NOT NULL,
    pattern_data JSONB NOT NULL,
    confidence DECIMAL(3,2),
    detected_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    expires_at TIMESTAMP
);

CREATE TABLE predictions (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('prd_' || nanoid()),
    child_id VARCHAR(20) NOT NULL REFERENCES children(id) ON DELETE CASCADE,
    type VARCHAR(50) NOT NULL,
    predicted_time TIMESTAMP NOT NULL,
    confidence DECIMAL(3,2),
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    outcome VARCHAR(20) -- 'correct', 'incorrect', 'pending'
);

CREATE INDEX idx_conversations_user ON conversations(user_id);
CREATE INDEX idx_messages_conversation ON messages(conversation_id);
CREATE INDEX idx_patterns_child_type ON patterns(child_id, type);
CREATE INDEX idx_predictions_child_time ON predictions(child_id, predicted_time);

Migration V005: Performance Optimization Indexes

Up Migration

-- V005_20240110160000_add_performance_indexes.sql

-- Composite indexes for common queries
CREATE INDEX idx_activities_daily_summary 
    ON activities(child_id, type, started_at) 
    WHERE ended_at IS NOT NULL;

CREATE INDEX idx_patterns_active 
    ON patterns(child_id, type, confidence) 
    WHERE expires_at > CURRENT_TIMESTAMP;

-- Text search for notes
CREATE INDEX idx_activities_notes_search 
    ON activities USING gin(to_tsvector('english', notes));

-- Covering index for dashboard query
CREATE INDEX idx_children_dashboard 
    ON children(family_id, id, name, birth_date) 
    WHERE deleted_at IS NULL;

Migration V006: Notification System

Up Migration

-- V006_20240110170000_create_notifications.sql

CREATE TABLE notification_preferences (
    user_id VARCHAR(20) PRIMARY KEY REFERENCES users(id) ON DELETE CASCADE,
    push_enabled BOOLEAN DEFAULT true,
    email_enabled BOOLEAN DEFAULT true,
    quiet_hours_start TIME,
    quiet_hours_end TIME,
    preferences JSONB DEFAULT '{}'::jsonb
);

CREATE TABLE scheduled_notifications (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('ntf_' || nanoid()),
    user_id VARCHAR(20) NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    child_id VARCHAR(20) REFERENCES children(id) ON DELETE CASCADE,
    type VARCHAR(50) NOT NULL,
    scheduled_for TIMESTAMP NOT NULL,
    payload JSONB NOT NULL,
    sent_at TIMESTAMP,
    status VARCHAR(20) DEFAULT 'pending'
);

CREATE INDEX idx_notifications_pending 
    ON scheduled_notifications(scheduled_for, status) 
    WHERE status = 'pending';

Migration V007: Audit and Compliance

Up Migration

-- V007_20240110180000_create_audit_compliance.sql

CREATE TABLE audit_log (
    id BIGSERIAL PRIMARY KEY,
    user_id VARCHAR(20),
    action VARCHAR(50) NOT NULL,
    entity_type VARCHAR(50),
    entity_id VARCHAR(20),
    changes JSONB,
    ip_address INET,
    user_agent TEXT,
    created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);

CREATE TABLE data_deletion_requests (
    id VARCHAR(20) PRIMARY KEY DEFAULT ('del_' || nanoid()),
    user_id VARCHAR(20) NOT NULL REFERENCES users(id),
    requested_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
    scheduled_for TIMESTAMP NOT NULL DEFAULT (CURRENT_TIMESTAMP + INTERVAL '30 days'),
    completed_at TIMESTAMP,
    status VARCHAR(20) DEFAULT 'pending'
);

-- Partition audit_log by month for retention management
CREATE TABLE audit_log_2024_01 PARTITION OF audit_log
    FOR VALUES FROM ('2024-01-01') TO ('2024-02-01');

CREATE INDEX idx_audit_user_action ON audit_log(user_id, action, created_at DESC);

Seed Data Script

-- seed_development_data.sql

-- Test users
INSERT INTO users (id, email, password_hash, name, locale) VALUES 
('usr_test1', 'test1@example.com', '$2b$10$...', 'Test Parent 1', 'en-US'),
('usr_test2', 'test2@example.com', '$2b$10$...', 'Test Parent 2', 'es-ES');

-- Test family
INSERT INTO families (id, name, created_by, share_code) VALUES 
('fam_test', 'Test Family', 'usr_test1', 'TEST01');

-- Family members
INSERT INTO family_members (user_id, family_id, role, permissions) VALUES 
('usr_test1', 'fam_test', 'parent', '{"canAddChildren": true, "canEditChildren": true, "canLogActivities": true, "canViewReports": true}'::jsonb),
('usr_test2', 'fam_test', 'parent', '{"canAddChildren": true, "canEditChildren": true, "canLogActivities": true, "canViewReports": true}'::jsonb);

-- Test children
INSERT INTO children (id, family_id, name, birth_date, gender) VALUES 
('chd_test1', 'fam_test', 'Emma', '2023-06-15', 'female'),
('chd_test2', 'fam_test', 'Liam', '2021-03-22', 'male');

Migration Runner Configuration

TypeORM Configuration

// ormconfig.ts
export default {
  type: 'postgres',
  host: process.env.DB_HOST,
  port: 5432,
  database: process.env.DB_NAME,
  migrations: ['src/migrations/*.sql'],
  cli: {
    migrationsDir: 'src/migrations'
  }
};

Knex Configuration

// knexfile.js
module.exports = {
  development: {
    client: 'postgresql',
    connection: process.env.DATABASE_URL,
    migrations: {
      directory: './migrations',
      tableName: 'schema_migrations'
    }
  }
};

Database Maintenance Scripts

Weekly Vacuum

-- maintenance/weekly_vacuum.sql
VACUUM ANALYZE activities;
VACUUM ANALYZE patterns;
VACUUM ANALYZE predictions;

Monthly Partition Creation

-- maintenance/create_next_month_partition.sql
CREATE TABLE IF NOT EXISTS activities_2024_02 
PARTITION OF activities 
FOR VALUES FROM ('2024-02-01') TO ('2024-03-01');

Archive Old Data

-- maintenance/archive_old_activities.sql
INSERT INTO activities_archive 
SELECT * FROM activities 
WHERE started_at < CURRENT_DATE - INTERVAL '1 year';

DELETE FROM activities 
WHERE started_at < CURRENT_DATE - INTERVAL '1 year';

Rollback Procedures

Full Rollback Script

#!/bin/bash
# rollback.sh

VERSION=$1
psql $DATABASE_URL -f "migrations/rollback/R${VERSION}.sql"
DELETE FROM schema_migrations WHERE version = $VERSION;

Emergency Recovery

-- emergency_recovery.sql
-- Point-in-time recovery to specific timestamp
SELECT pg_restore_point('before_migration');
-- Restore from backup if catastrophic failure

Performance Considerations

Index Strategy

  • Primary indexes on foreign keys
  • Composite indexes for common query patterns
  • Partial indexes for active records
  • GIN indexes for JSONB search
  • Covering indexes for dashboard queries

Partitioning Strategy

  • Activities table partitioned by month
  • Audit log partitioned by month
  • Automatic partition creation via cron job

Connection Pooling

-- Recommended PostgreSQL settings
max_connections = 200
shared_buffers = 256MB
effective_cache_size = 1GB
work_mem = 4MB