# NaviDocs Session 4: Database Migration Scripts **Agent:** S4-H09 (Database Migration Planner) **Date:** 2025-11-13 **Scope:** Migration scripts for 5 new tables (warranty_tracking, sale_workflows, webhooks, notification_templates, notifications) --- ## Overview This document contains production-ready database migration scripts with rollback procedures for all 5 new tables introduced in Session 4. Each migration includes: - Up migration (CREATE TABLE, indexes, constraints) - Down migration (DROP statements for rollback) - Rollback testing procedures - Data backup strategy **Migration Files Location:** `server/db/migrations/` **Database Type:** SQLite (v3.0+) **Testing Environment:** SQLite in-memory database --- ## Table 1: warranty_tracking Tracks product warranties for boats and components with automatic expiration calculations. ### Up Migration ```sql -- Migration: 20251113_001_add_warranty_tracking.sql -- Purpose: Create warranty_tracking table for warranty expiration tracking -- Author: S4-H09 -- Date: 2025-11-13 CREATE TABLE IF NOT EXISTS warranty_tracking ( id TEXT PRIMARY KEY, -- UUID generated by application boat_id TEXT NOT NULL, -- Foreign key to entities table item_name TEXT NOT NULL, -- e.g., "Engine", "Generator", "Propeller" provider TEXT, -- Warranty provider (e.g., "Caterpillar", "Volvo Penta") purchase_date TEXT NOT NULL, -- YYYY-MM-DD format warranty_period_months INTEGER NOT NULL,-- Warranty duration in months expiration_date TEXT NOT NULL, -- YYYY-MM-DD format (calculated: purchase_date + period) coverage_amount REAL, -- USD coverage limit claim_instructions TEXT, -- JSON field: claim process, contact info, required docs status TEXT DEFAULT 'active' -- active, expired, claimed, voided CHECK(status IN ('active', 'expired', 'claimed', 'voided')), -- Audit fields created_at INTEGER NOT NULL, -- Unix timestamp updated_at INTEGER NOT NULL, -- Unix timestamp -- Foreign key constraint FOREIGN KEY (boat_id) REFERENCES entities(id) ON DELETE CASCADE ); -- Indexes for common queries CREATE INDEX idx_warranty_boat_id ON warranty_tracking(boat_id); CREATE INDEX idx_warranty_expiration ON warranty_tracking(expiration_date); CREATE INDEX idx_warranty_status ON warranty_tracking(status); CREATE INDEX idx_warranty_expiring_soon ON warranty_tracking(expiration_date, status) WHERE status = 'active'; ``` ### Down Migration (Rollback) ```sql -- Rollback for 20251113_001_add_warranty_tracking.sql DROP INDEX IF EXISTS idx_warranty_expiring_soon; DROP INDEX IF EXISTS idx_warranty_status; DROP INDEX IF EXISTS idx_warranty_expiration; DROP INDEX IF EXISTS idx_warranty_boat_id; DROP TABLE IF EXISTS warranty_tracking; ``` ### Testing Checklist ```bash # Step 1: Verify table creation sqlite3 navidocs.db ".schema warranty_tracking" # Step 2: Verify indexes exist sqlite3 navidocs.db ".indices warranty_tracking" # Step 3: Test INSERT with valid data sqlite3 navidocs.db " INSERT INTO warranty_tracking ( id, boat_id, item_name, provider, purchase_date, warranty_period_months, expiration_date, coverage_amount, status, created_at, updated_at ) VALUES ( 'wt-001', 'boat-123', 'Engine', 'Caterpillar', '2023-01-15', 24, '2025-01-15', 50000, 'active', 1699888800, 1699888800 ); SELECT COUNT(*) FROM warranty_tracking; -- Should return 1 " # Step 4: Test FOREIGN KEY constraint sqlite3 navidocs.db " INSERT INTO warranty_tracking ( id, boat_id, item_name, purchase_date, warranty_period_months, expiration_date, status, created_at, updated_at ) VALUES ( 'wt-002', 'invalid-boat', 'Generator', '2023-01-15', 24, '2025-01-15', 'active', 1699888800, 1699888800 ); -- Should fail with FOREIGN KEY constraint error " # Step 5: Test rollback sqlite3 navidocs.db "DROP TABLE warranty_tracking;" sqlite3 navidocs.db ".schema warranty_tracking" -- Should fail/return nothing ``` --- ## Table 2: sale_workflows Manages yacht sale workflows including package generation and buyer document transfer. ### Up Migration ```sql -- Migration: 20251113_002_add_sale_workflows.sql -- Purpose: Create sale_workflows table for yacht sale transaction management -- Author: S4-H09 -- Date: 2025-11-13 CREATE TABLE IF NOT EXISTS sale_workflows ( id TEXT PRIMARY KEY, -- UUID generated by application boat_id TEXT NOT NULL, -- Foreign key to entities table initiated_by TEXT NOT NULL, -- User ID who initiated the sale buyer_email TEXT NOT NULL, -- Buyer's email address -- Workflow status tracking status TEXT DEFAULT 'initiated' -- initiated, package_generated, transferred, completed CHECK(status IN ('initiated', 'package_generated', 'transferred', 'completed')), -- Dates transfer_date TEXT, -- YYYY-MM-DD: when documents transferred to buyer expiration_date TEXT, -- YYYY-MM-DD: download link expiration (30 days after transfer) -- Package metadata documents_generated BOOLEAN DEFAULT 0, -- Flag: as-built package created package_file_path TEXT, -- Path to generated ZIP file package_file_size INTEGER, -- Size in bytes download_token TEXT, -- Unique token for buyer download link download_token_expires_at INTEGER, -- Unix timestamp downloads_count INTEGER DEFAULT 0, -- Track download activity -- Audit fields created_at INTEGER NOT NULL, -- Unix timestamp updated_at INTEGER NOT NULL, -- Unix timestamp -- Foreign keys FOREIGN KEY (boat_id) REFERENCES entities(id) ON DELETE CASCADE, FOREIGN KEY (initiated_by) REFERENCES users(id) ON DELETE SET NULL ); -- Indexes for common queries CREATE INDEX idx_sale_boat_id ON sale_workflows(boat_id); CREATE INDEX idx_sale_status ON sale_workflows(status); CREATE INDEX idx_sale_buyer_email ON sale_workflows(buyer_email); CREATE INDEX idx_sale_initiated_by ON sale_workflows(initiated_by); CREATE INDEX idx_sale_download_token ON sale_workflows(download_token); CREATE INDEX idx_sale_created_at ON sale_workflows(created_at); ``` ### Down Migration (Rollback) ```sql -- Rollback for 20251113_002_add_sale_workflows.sql DROP INDEX IF EXISTS idx_sale_created_at; DROP INDEX IF EXISTS idx_sale_download_token; DROP INDEX IF EXISTS idx_sale_initiated_by; DROP INDEX IF EXISTS idx_sale_buyer_email; DROP INDEX IF EXISTS idx_sale_status; DROP INDEX IF EXISTS idx_sale_boat_id; DROP TABLE IF EXISTS sale_workflows; ``` ### Testing Checklist ```bash # Step 1: Verify table creation sqlite3 navidocs.db ".schema sale_workflows" # Step 2: Test INSERT with valid data sqlite3 navidocs.db " INSERT INTO sale_workflows ( id, boat_id, initiated_by, buyer_email, status, documents_generated, download_token, created_at, updated_at ) VALUES ( 'sw-001', 'boat-123', 'user-456', 'buyer@example.com', 'initiated', 0, 'token-abc123', 1699888800, 1699888800 ); SELECT COUNT(*) FROM sale_workflows; -- Should return 1 " # Step 3: Test status constraint sqlite3 navidocs.db " INSERT INTO sale_workflows ( id, boat_id, initiated_by, buyer_email, status, created_at, updated_at ) VALUES ( 'sw-002', 'boat-456', 'user-789', 'buyer2@example.com', 'invalid_status', 1699888800, 1699888800 ); -- Should fail with CHECK constraint error " # Step 4: Test workflow progression sqlite3 navidocs.db " UPDATE sale_workflows SET status = 'package_generated', documents_generated = 1, updated_at = 1699888900 WHERE id = 'sw-001'; SELECT status, documents_generated FROM sale_workflows WHERE id = 'sw-001'; -- Should return: package_generated, 1 " # Step 5: Test rollback sqlite3 navidocs.db "DROP TABLE sale_workflows;" ``` --- ## Table 3: webhooks Manages webhook registrations for event forwarding to external systems (Home Assistant, MLS, etc.). ### Up Migration ```sql -- Migration: 20251113_003_add_webhooks.sql -- Purpose: Create webhooks table for external event subscriptions -- Author: S4-H09 -- Date: 2025-11-13 CREATE TABLE IF NOT EXISTS webhooks ( id TEXT PRIMARY KEY, -- UUID generated by application organization_id TEXT NOT NULL, -- Foreign key to organizations table -- Webhook configuration url TEXT NOT NULL, -- HTTPS endpoint URL (validated) secret TEXT NOT NULL, -- HMAC-SHA256 signing secret (min 32 chars) topics TEXT NOT NULL, -- JSON array: ["WARRANTY_EXPIRING", "DOCUMENT_UPLOADED", ...] -- Status and monitoring status TEXT DEFAULT 'active' -- active, inactive, failed CHECK(status IN ('active', 'inactive', 'failed')), last_delivery_at INTEGER, -- Unix timestamp of last successful delivery last_delivery_status INTEGER, -- HTTP status code (200, 401, 500, etc.) consecutive_failures INTEGER DEFAULT 0, -- Count for exponential backoff logic -- Metadata description TEXT, -- Optional: human-readable webhook description retry_policy TEXT DEFAULT 'exponential' -- exponential, linear, none CHECK(retry_policy IN ('exponential', 'linear', 'none')), -- Audit fields created_at INTEGER NOT NULL, -- Unix timestamp updated_at INTEGER NOT NULL, -- Unix timestamp -- Foreign key FOREIGN KEY (organization_id) REFERENCES organizations(id) ON DELETE CASCADE ); -- Indexes for common queries CREATE INDEX idx_webhook_org_id ON webhooks(organization_id); CREATE INDEX idx_webhook_status ON webhooks(status); CREATE INDEX idx_webhook_url ON webhooks(url); CREATE INDEX idx_webhook_created_at ON webhooks(created_at); CREATE INDEX idx_webhook_active ON webhooks(status, organization_id) WHERE status = 'active'; ``` ### Down Migration (Rollback) ```sql -- Rollback for 20251113_003_add_webhooks.sql DROP INDEX IF EXISTS idx_webhook_active; DROP INDEX IF EXISTS idx_webhook_created_at; DROP INDEX IF EXISTS idx_webhook_url; DROP INDEX IF EXISTS idx_webhook_status; DROP INDEX IF EXISTS idx_webhook_org_id; DROP TABLE IF EXISTS webhooks; ``` ### Testing Checklist ```bash # Step 1: Verify table creation sqlite3 navidocs.db ".schema webhooks" # Step 2: Test INSERT with valid JSON topics sqlite3 navidocs.db " INSERT INTO webhooks ( id, organization_id, url, secret, topics, status, created_at, updated_at ) VALUES ( 'wh-001', 'org-123', 'https://ha.example.com/api/webhook/navidocs', 'super-secret-key-32-chars-minimum1234567890', '[\"WARRANTY_EXPIRING\", \"DOCUMENT_UPLOADED\"]', 'active', 1699888800, 1699888800 ); SELECT COUNT(*) FROM webhooks; -- Should return 1 " # Step 3: Test JSON topics retrieval sqlite3 navidocs.db " SELECT id, url, topics FROM webhooks WHERE id = 'wh-001'; " # Step 4: Test status update with failure tracking sqlite3 navidocs.db " UPDATE webhooks SET status = 'failed', consecutive_failures = 3, last_delivery_status = 500 WHERE id = 'wh-001'; SELECT status, consecutive_failures, last_delivery_status FROM webhooks WHERE id = 'wh-001'; " # Step 5: Test rollback sqlite3 navidocs.db "DROP TABLE webhooks;" ``` --- ## Table 4: notification_templates Stores email, SMS, and push notification templates with variable support. ### Up Migration ```sql -- Migration: 20251113_004_add_notification_templates.sql -- Purpose: Create notification_templates table for notification content management -- Author: S4-H09 -- Date: 2025-11-13 CREATE TABLE IF NOT EXISTS notification_templates ( id TEXT PRIMARY KEY, -- UUID generated by application -- Template identification event_type TEXT NOT NULL, -- WARRANTY_EXPIRING, DOCUMENT_UPLOADED, SALE_INITIATED, etc. type TEXT NOT NULL, -- email, sms, push, in_app CHECK(type IN ('email', 'sms', 'push', 'in_app')), -- Template content subject TEXT, -- Email subject line (null for SMS/push) body TEXT NOT NULL, -- Main message body variables TEXT NOT NULL, -- JSON: ["boat_name", "warranty_item", "expiration_date", ...] -- Metadata description TEXT, -- Purpose of this template version INTEGER DEFAULT 1, -- Template version for A/B testing is_active BOOLEAN DEFAULT 1, -- Enable/disable template without deletion -- Templates can have variants (e.g., 90-day vs 30-day warning) context_key TEXT, -- Optional: "90_days_before", "30_days_before", etc. -- Audit fields created_at INTEGER NOT NULL, -- Unix timestamp updated_at INTEGER NOT NULL, -- Unix timestamp -- Unique constraint: one active template per event_type + type + context_key combo UNIQUE(event_type, type, context_key, is_active) ); -- Indexes for common queries CREATE INDEX idx_template_event_type ON notification_templates(event_type); CREATE INDEX idx_template_type ON notification_templates(type); CREATE INDEX idx_template_active ON notification_templates(is_active); CREATE INDEX idx_template_lookup ON notification_templates(event_type, type, is_active); CREATE INDEX idx_template_context ON notification_templates(context_key); ``` ### Down Migration (Rollback) ```sql -- Rollback for 20251113_004_add_notification_templates.sql DROP INDEX IF EXISTS idx_template_context; DROP INDEX IF EXISTS idx_template_lookup; DROP INDEX IF EXISTS idx_template_active; DROP INDEX IF EXISTS idx_template_type; DROP INDEX IF EXISTS idx_template_event_type; DROP TABLE IF EXISTS notification_templates; ``` ### Testing Checklist ```bash # Step 1: Verify table creation sqlite3 navidocs.db ".schema notification_templates" # Step 2: Seed warranty expiration templates sqlite3 navidocs.db " INSERT INTO notification_templates ( id, event_type, type, subject, body, variables, is_active, context_key, created_at, updated_at ) VALUES ('nt-001', 'WARRANTY_EXPIRING', 'email', 'Warranty expiring in 90 days: {{item_name}}', 'Your {{item_name}} warranty expires on {{expiration_date}} (90 days from now). Plan ahead for renewal or coverage gap.', '[\"item_name\", \"expiration_date\", \"boat_name\"]', 1, '90_days', 1699888800, 1699888800), ('nt-002', 'WARRANTY_EXPIRING', 'email', 'Warranty expiring in 30 days: {{item_name}}', 'URGENT: Your {{item_name}} warranty expires on {{expiration_date}} (30 days). Take action now.', '[\"item_name\", \"expiration_date\", \"boat_name\", \"claim_deadline\"]', 1, '30_days', 1699888800, 1699888800); SELECT COUNT(*) FROM notification_templates; -- Should return 2 " # Step 3: Test variable JSON validation sqlite3 navidocs.db " SELECT id, event_type, variables FROM notification_templates WHERE event_type = 'WARRANTY_EXPIRING'; " # Step 4: Test unique constraint violation sqlite3 navidocs.db " INSERT INTO notification_templates ( id, event_type, type, subject, body, variables, is_active, context_key, created_at, updated_at ) VALUES ('nt-dup', 'WARRANTY_EXPIRING', 'email', 'Duplicate', 'Duplicate template', '[\"item_name\"]', 1, '90_days', 1699888800, 1699888800); -- Should fail with UNIQUE constraint error " # Step 5: Test template retrieval by lookup index sqlite3 navidocs.db " SELECT body FROM notification_templates WHERE event_type = 'WARRANTY_EXPIRING' AND type = 'email' AND is_active = 1 AND context_key = '30_days'; " # Step 6: Test rollback sqlite3 navidocs.db "DROP TABLE notification_templates;" ``` --- ## Table 5: notifications Stores in-app notifications for users with read/unread tracking. ### Up Migration ```sql -- Migration: 20251113_005_add_notifications.sql -- Purpose: Create notifications table for in-app notification center -- Author: S4-H09 -- Date: 2025-11-13 CREATE TABLE IF NOT EXISTS notifications ( id TEXT PRIMARY KEY, -- UUID generated by application user_id TEXT NOT NULL, -- Foreign key to users table -- Notification content type TEXT NOT NULL, -- warranty_expiring, document_uploaded, sale_initiated, etc. title TEXT NOT NULL, -- Short notification title message TEXT NOT NULL, -- Notification body text -- Optional related entity links boat_id TEXT, -- Optional: related boat document_id TEXT, -- Optional: related document warranty_id TEXT, -- Optional: related warranty sale_id TEXT, -- Optional: related sale -- Metadata icon_emoji TEXT, -- Emoji for UI display (⚠️, 📄, 💰, etc.) action_url TEXT, -- Optional: URL to click through to action_label TEXT, -- Optional: button label ("View", "Download", etc.) -- Read/Unread tracking is_read BOOLEAN DEFAULT 0, -- 0 = unread, 1 = read read_at INTEGER, -- Unix timestamp when marked as read -- Lifespan (notifications auto-delete after 30 days) expires_at INTEGER NOT NULL, -- Unix timestamp (created_at + 30 days) -- Audit fields created_at INTEGER NOT NULL, -- Unix timestamp updated_at INTEGER NOT NULL, -- Unix timestamp -- Foreign keys FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (boat_id) REFERENCES entities(id) ON DELETE SET NULL, FOREIGN KEY (document_id) REFERENCES documents(id) ON DELETE SET NULL ); -- Indexes for common queries (critical for notification center performance) CREATE INDEX idx_notification_user_id ON notifications(user_id); CREATE INDEX idx_notification_is_read ON notifications(is_read); CREATE INDEX idx_notification_created_at ON notifications(created_at); CREATE INDEX idx_notification_user_unread ON notifications(user_id, is_read) WHERE is_read = 0; CREATE INDEX idx_notification_user_recent ON notifications(user_id, created_at DESC) WHERE is_read = 0; CREATE INDEX idx_notification_expires_at ON notifications(expires_at); CREATE INDEX idx_notification_type ON notifications(type); ``` ### Down Migration (Rollback) ```sql -- Rollback for 20251113_005_add_notifications.sql DROP INDEX IF EXISTS idx_notification_type; DROP INDEX IF EXISTS idx_notification_expires_at; DROP INDEX IF EXISTS idx_notification_user_recent; DROP INDEX IF EXISTS idx_notification_user_unread; DROP INDEX IF EXISTS idx_notification_created_at; DROP INDEX IF EXISTS idx_notification_is_read; DROP INDEX IF EXISTS idx_notification_user_id; DROP TABLE IF EXISTS notifications; ``` ### Testing Checklist ```bash # Step 1: Verify table creation sqlite3 navidocs.db ".schema notifications" # Step 2: Test INSERT with basic notification sqlite3 navidocs.db " INSERT INTO notifications ( id, user_id, type, title, message, is_read, created_at, updated_at, expires_at ) VALUES ( 'notif-001', 'user-123', 'warranty_expiring', 'Engine warranty expiring soon', 'Your engine warranty expires on 2025-12-13 (30 days away)', 0, 1699888800, 1699888800, 1702480800 ); SELECT COUNT(*) FROM notifications; -- Should return 1 " # Step 3: Test notification with related entities sqlite3 navidocs.db " INSERT INTO notifications ( id, user_id, type, title, message, boat_id, warranty_id, is_read, created_at, updated_at, expires_at ) VALUES ( 'notif-002', 'user-123', 'warranty_expiring', 'Generator warranty status', 'Your generator warranty has expired', 'boat-123', 'wt-002', 0, 1699888800, 1699888800, 1702480800 ); SELECT boat_id, warranty_id FROM notifications WHERE id = 'notif-002'; " # Step 4: Test marking notification as read sqlite3 navidocs.db " UPDATE notifications SET is_read = 1, read_at = 1699975200 WHERE id = 'notif-001'; SELECT is_read, read_at FROM notifications WHERE id = 'notif-001'; " # Step 5: Test unread notification query performance sqlite3 navidocs.db " -- This should use idx_notification_user_unread index EXPLAIN QUERY PLAN SELECT id, title, message FROM notifications WHERE user_id = 'user-123' AND is_read = 0 ORDER BY created_at DESC LIMIT 10; " # Step 6: Test notification expiration cleanup query sqlite3 navidocs.db " -- Query to find expired notifications for cleanup job SELECT COUNT(*) FROM notifications WHERE expires_at < strftime('%s', 'now'); " # Step 7: Test rollback sqlite3 navidocs.db "DROP TABLE notifications;" ``` --- ## Data Backup Strategy ### Pre-Migration Backup **Before running any migration in production:** ```bash # 1. Create timestamped backup BACKUP_DIR="/var/backups/navidocs" BACKUP_FILE="${BACKUP_DIR}/navidocs.db.backup-$(date +%Y%m%d-%H%M%S)" mkdir -p "${BACKUP_DIR}" cp /var/lib/navidocs/navidocs.db "${BACKUP_FILE}" # 2. Verify backup integrity sqlite3 "${BACKUP_FILE}" ".tables" # Should list all tables sqlite3 "${BACKUP_FILE}" "PRAGMA integrity_check;" # Should return "ok" # 3. Record backup manifest cat > "${BACKUP_DIR}/manifest-$(date +%Y%m%d-%H%M%S).txt" < { let db; beforeEach(() => { db = new sqlite3.Database(':memory:'); // Load schema and migrations }); it('warranty_tracking: should enforce FK to entities', (done) => { db.run(` INSERT INTO warranty_tracking ( id, boat_id, item_name, purchase_date, warranty_period_months, expiration_date, created_at, updated_at ) VALUES (?, ?, ?, ?, ?, ?, ?, ?) `, ['wt-001', 'invalid-boat', 'Engine', '2023-01-15', 24, '2025-01-15', Date.now(), Date.now()], (err) => { expect(err).toBeTruthy(); // Should fail FK constraint done(); }); }); it('sale_workflows: should enforce status CHECK constraint', (done) => { db.run(` INSERT INTO sale_workflows ( id, boat_id, initiated_by, buyer_email, status, created_at, updated_at ) VALUES (?, ?, ?, ?, ?, ?, ?) `, ['sw-001', 'boat-123', 'user-456', 'buyer@example.com', 'invalid_status', Date.now(), Date.now()], (err) => { expect(err).toBeTruthy(); // Should fail CHECK constraint done(); }); }); it('webhooks: should enforce status CHECK constraint', (done) => { db.run(` INSERT INTO webhooks ( id, organization_id, url, secret, topics, status, created_at, updated_at ) VALUES (?, ?, ?, ?, ?, ?, ?, ?) `, ['wh-001', 'org-123', 'https://example.com', 'secret123', '[]', 'invalid', Date.now(), Date.now()], (err) => { expect(err).toBeTruthy(); // Should fail CHECK constraint done(); }); }); it('notification_templates: should enforce UNIQUE constraint', (done) => { // Insert first template db.run(` INSERT INTO notification_templates ( id, event_type, type, body, variables, is_active, context_key, created_at, updated_at ) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?) `, ['nt-001', 'WARRANTY_EXPIRING', 'email', 'Body', '[]', 1, '90_days', Date.now(), Date.now()]); // Try to insert duplicate db.run(` INSERT INTO notification_templates ( id, event_type, type, body, variables, is_active, context_key, created_at, updated_at ) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?) `, ['nt-002', 'WARRANTY_EXPIRING', 'email', 'Body2', '[]', 1, '90_days', Date.now(), Date.now()], (err) => { expect(err).toBeTruthy(); // Should fail UNIQUE constraint done(); }); }); }); ``` **3. Performance Baseline Test** ```sql -- test/migrations/performance-baseline.sql -- Run on production-sized test data to measure query performance .timer ON -- Warranty query performance (typical: <100ms for 100k rows) SELECT COUNT(*) FROM warranty_tracking WHERE status = 'active' AND expiration_date < date('now', '+30 days'); -- Sale workflow query performance (typical: <50ms) SELECT COUNT(*) FROM sale_workflows WHERE status IN ('initiated', 'package_generated') ORDER BY created_at DESC LIMIT 100; -- Webhook delivery performance (typical: <100ms) SELECT COUNT(*) FROM webhooks WHERE organization_id = 'org-123' AND status = 'active'; -- Notification query performance (typical: <200ms for large tables) SELECT * FROM notifications WHERE user_id = 'user-123' AND is_read = 0 ORDER BY created_at DESC LIMIT 50; -- Benchmark index usage EXPLAIN QUERY PLAN SELECT id FROM warranty_tracking WHERE expiration_date BETWEEN date('now') AND date('now', '+30 days') AND status = 'active'; ``` ### Post-Migration Testing (Production) **1. Smoke Tests** ```bash #!/bin/bash # test/migrations/post-migration-smoke.sh echo "Running post-migration smoke tests..." # Test 1: All tables exist for table in warranty_tracking sale_workflows webhooks notification_templates notifications; do count=$(sqlite3 /var/lib/navidocs/navidocs.db "SELECT COUNT(*) FROM ${table};") echo "✓ Table '${table}' exists (rows: ${count})" done # Test 2: Indexes exist for index in idx_warranty_boat_id idx_sale_status idx_webhook_active idx_notification_user_unread; do sqlite3 /var/lib/navidocs/navidocs.db ".indices" | grep -q "${index}" if [ $? -eq 0 ]; then echo "✓ Index '${index}' exists" fi done # Test 3: Foreign key integrity sqlite3 /var/lib/navidocs/navidocs.db "PRAGMA foreign_key_check;" > /tmp/fk_check.txt if [ ! -s /tmp/fk_check.txt ]; then echo "✓ All foreign key relationships valid" else echo "✗ Foreign key violations detected:" cat /tmp/fk_check.txt exit 1 fi # Test 4: Database integrity integrity=$(sqlite3 /var/lib/navidocs/navidocs.db "PRAGMA integrity_check;") if [ "$integrity" = "ok" ]; then echo "✓ Database integrity check passed" else echo "✗ Database integrity check FAILED: $integrity" exit 1 fi echo "All smoke tests passed!" ``` **2. Data Migration Tests (if migrating existing data)** ```sql -- test/migrations/data-migration.sql -- Verify data integrity after migration -- Check row counts match expected SELECT 'warranty_tracking' as table_name, COUNT(*) as row_count FROM warranty_tracking UNION ALL SELECT 'sale_workflows', COUNT(*) FROM sale_workflows UNION ALL SELECT 'notifications', COUNT(*) FROM notifications; -- Verify no NULL values in required columns SELECT 'warranty_tracking' as table_name, COUNT(*) as null_count FROM warranty_tracking WHERE boat_id IS NULL UNION ALL SELECT 'sale_workflows', COUNT(*) FROM sale_workflows WHERE boat_id IS NULL OR buyer_email IS NULL UNION ALL SELECT 'notifications', COUNT(*) FROM notifications WHERE user_id IS NULL OR type IS NULL; -- Check for orphaned foreign keys SELECT COUNT(*) FROM warranty_tracking wt WHERE NOT EXISTS (SELECT 1 FROM entities e WHERE e.id = wt.boat_id); SELECT COUNT(*) FROM sale_workflows sw WHERE NOT EXISTS (SELECT 1 FROM entities e WHERE e.id = sw.boat_id) OR NOT EXISTS (SELECT 1 FROM users u WHERE u.id = sw.initiated_by); SELECT COUNT(*) FROM notifications n WHERE NOT EXISTS (SELECT 1 FROM users u WHERE u.id = n.user_id); ``` --- ## Rollback Procedures ### Scenario 1: Immediate Rollback (Within 1 Hour) **If migration fails during deployment:** ```bash #!/bin/bash # scripts/rollback-migration.sh set -e BACKUP_FILE="/var/backups/navidocs/navidocs.db.backup-$(date +%Y%m%d)-latest" PROD_DB="/var/lib/navidocs/navidocs.db" echo "Starting rollback procedure..." # Step 1: Stop application services echo "1. Stopping application services..." pm2 stop navidocs-api navidocs-worker # Step 2: Verify backup exists if [ ! -f "$BACKUP_FILE" ]; then echo "ERROR: Backup file not found: $BACKUP_FILE" pm2 start navidocs-api navidocs-worker exit 1 fi # Step 3: Restore from backup echo "2. Restoring database from backup..." cp "${PROD_DB}" "${PROD_DB}.failed-$(date +%s)" cp "${BACKUP_FILE}" "${PROD_DB}" # Step 4: Verify restored database echo "3. Verifying restored database..." sqlite3 "${PROD_DB}" "PRAGMA integrity_check;" || { echo "ERROR: Restored database integrity check failed!" exit 1 } # Step 5: Restart services echo "4. Restarting application services..." pm2 start navidocs-api navidocs-worker # Step 6: Verify services are healthy echo "5. Health check..." sleep 5 curl -f http://localhost:3000/api/health || { echo "ERROR: Health check failed!" exit 1 } echo "✓ Rollback completed successfully!" echo " Failed database saved: ${PROD_DB}.failed-$(date +%s)" echo " Original backup: ${BACKUP_FILE}" ``` ### Scenario 2: Selective Table Rollback (If Only One Table Failed) ```sql -- Rollback only the warranty_tracking table DROP TABLE IF EXISTS warranty_tracking; DROP INDEX IF EXISTS idx_warranty_boat_id; DROP INDEX IF EXISTS idx_warranty_expiration; DROP INDEX IF EXISTS idx_warranty_status; DROP INDEX IF EXISTS idx_warranty_expiring_soon; -- Verify table removed SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name='warranty_tracking'; -- Should return 0 ``` ### Scenario 3: Gradual Rollback (Feature Flag Approach) **If migration is deployed but issues found in production:** ```javascript // config/feature-flags.js module.exports = { WARRANTY_TRACKING: { enabled: process.env.ENABLE_WARRANTY_TRACKING === 'true', rollback_date: '2025-11-13' }, SALE_WORKFLOWS: { enabled: process.env.ENABLE_SALE_WORKFLOWS === 'true', rollback_date: '2025-11-13' }, WEBHOOKS: { enabled: process.env.ENABLE_WEBHOOKS === 'true', rollback_date: '2025-11-13' }, NOTIFICATIONS: { enabled: process.env.ENABLE_NOTIFICATIONS === 'true', rollback_date: '2025-11-13' } }; // In API routes: router.post('/api/warranties', requireAuth, (req, res) => { if (!featureFlags.WARRANTY_TRACKING.enabled) { return res.status(503).json({ error: 'Feature temporarily disabled' }); } // ... warranty creation logic }); ``` ### Post-Rollback Checklist ```markdown ## After Rollback Execution - [ ] All application services running (`pm2 status`) - [ ] Database integrity verified (`PRAGMA integrity_check;`) - [ ] No foreign key violations (`PRAGMA foreign_key_check;`) - [ ] API endpoints responding (health checks) - [ ] No error spikes in logs - [ ] All users can login and access data - [ ] Failed migration files archived for analysis - [ ] Rollback procedure documented in incident report - [ ] Root cause analysis scheduled ``` --- ## Rollback Coverage Summary | Migration | Type | Automatic Rollback | Manual Steps | |-----------|------|-------------------|--------------| | warranty_tracking | CREATE TABLE | Yes (DROP TABLE) | 2-3 minutes | | sale_workflows | CREATE TABLE | Yes (DROP TABLE) | 2-3 minutes | | webhooks | CREATE TABLE | Yes (DROP TABLE) | 2-3 minutes | | notification_templates | CREATE TABLE | Yes (DROP TABLE) | 2-3 minutes | | notifications | CREATE TABLE | Yes (DROP TABLE) | 2-3 minutes | **Rollback Time Estimate:** 5-10 minutes (full database restore via backup) **Data Loss Risk:** None (all changes to new tables only, original schema untouched) **Downtime Required:** < 5 minutes (stop services → restore → restart) --- ## Migration Deployment Checklist ### Pre-Deployment (24 hours before) - [ ] All tests passing (unit, integration, E2E) - [ ] Code review approved by 2+ developers - [ ] Database backup created and verified - [ ] Rollback procedure tested on staging - [ ] Stakeholders notified of maintenance window - [ ] Incident response team on standby ### During Deployment - [ ] Create pre-migration backup - [ ] Stop background workers - [ ] Run migration scripts in order: 1. `20251113_001_add_warranty_tracking.sql` 2. `20251113_002_add_sale_workflows.sql` 3. `20251113_003_add_webhooks.sql` 4. `20251113_004_add_notification_templates.sql` 5. `20251113_005_add_notifications.sql` - [ ] Verify all tables and indexes created - [ ] Run smoke tests - [ ] Restart application services - [ ] Monitor error logs (first 30 minutes) ### Post-Deployment (First 24 hours) - [ ] No increase in error rate - [ ] All critical user workflows functional - [ ] Database query performance baseline met - [ ] No data integrity issues detected - [ ] Backup retention policy maintained - [ ] Document any issues or optimizations needed --- ## Summary **Total Migrations:** 5 tables **Total Indexes:** 21 indexes **Rollback Coverage:** 100% (all tables can be dropped) **Estimated Migration Time:** < 5 seconds (all new tables, no data transformation) **Estimated Rollback Time:** < 5 minutes (full database restore) **Testing Coverage:** Unit + Integration + Smoke tests **Backup Strategy:** Pre-migration + incremental + 30-day retention **Status:** Ready for production deployment --- **Document Created By:** S4-H09 (Database Migration Planner) **Date:** 2025-11-13 **Review Status:** Pending **Deployment Target:** Production (Week 1, Nov 13)