# CHORUS Website Database Integration - Brand Updated This document describes the updated CHORUS website database integration aligned with current brand guidelines and technical specifications, including lead capture system optimization for ultra-minimalist design and accessibility compliance. ## Integration Overview The website module now uses the centralized PostgreSQL database service instead of maintaining its own separate database. This provides: - **Unified Infrastructure**: Single PostgreSQL instance for all CHORUS services - **Simplified Management**: One database to backup, monitor, and maintain - **Better Resource Utilization**: Shared database resources across services - **Consistent Configuration**: Same database credentials and network across all services ## Database Architecture ### Main Database Service - **Host**: `postgres` (Docker service name) - **Port**: `5432` (internal), `5433` (external) - **User**: `chorus` - **Password**: `choruspass` ### Website Database (Brand-Optimized) - **Database Name**: `chorus_website` - **Connection String**: `postgresql://chorus:choruspass@postgres:5432/chorus_website` - **Performance Optimization**: Optimized for ultra-minimalist UI with fast query response times - **Accessibility Integration**: Stores user accessibility theme preferences and interaction data ### Updated Database Structure (Brand-Aligned) ``` chorus_postgres (PostgreSQL 15 container) ├── chorus_whoosh (WHOOSH orchestration data) ├── chorus_slurp (SLURP context curation data) ├── chorus_rl_tuner (RL feedback system data) ├── chorus_monitoring (Monitoring and metrics data) └── chorus_website (Website lead capture & brand data) ├── leads (Main lead capture table) ├── consent_audit (GDPR consent tracking) ├── lead_interactions (CRM interaction history) ├── accessibility_preferences (User accessibility themes) ├── website_analytics (Minimalist analytics data) ├── brand_engagement (Three.js logo interaction data) ├── rate_limits (Spam protection) ├── data_retention_schedule (GDPR data cleanup) └── schema_migrations (Migration tracking) ``` ## Migration System ### Migration Files - **Location**: `/modules/website/database/migrations/` - **Naming**: `001_initial_lead_capture.sql`, `002_next_feature.sql`, etc. - **Tracking**: `schema_migrations` table tracks applied migrations ### Running Migrations ```bash # Automated migration runner cd /modules/website/database/ ./run-migrations.sh # Manual migration (if needed) psql postgresql://chorus:choruspass@postgres:5432/chorus_website -f migrations/001_initial_lead_capture.sql ``` ## Integration Setup ### 1. Database Initialization The main `init-db.sql` now includes: ```sql CREATE DATABASE chorus_website; GRANT ALL PRIVILEGES ON DATABASE chorus_website TO chorus; \c chorus_website; CREATE TABLE schema_migrations ( version VARCHAR(255) PRIMARY KEY, applied_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); ``` ### 2. Website Configuration Updates - **API Route**: Updated to use `chorus_website` database - **Docker Compose**: Connected to external `chorus_network` - **Environment**: Database URL points to main postgres service ### 3. Network Integration ```yaml # Website connects to main CHORUS network networks: - chorus-dev # Local development - chorus-services_chorus_network # Main CHORUS network ``` ## Development Workflow ### Starting the Integrated System 1. **Start Main CHORUS Infrastructure**: ```bash cd /chorus.services/ docker-compose up -d postgres redis ``` 2. **Run Website Integration Setup**: ```bash cd /chorus.services/modules/website/ ./integrate-with-chorus.sh ``` 3. **Start Website Development**: ```bash # Option 1: Standalone development docker-compose up website-dev # Option 2: With database profile docker-compose --profile database up website-dev ``` ### Production Deployment 1. **Full CHORUS Stack with Website**: ```bash cd /chorus.services/ docker-compose --profile website up -d ``` 2. **Website Only** (assumes main stack is running): ```bash docker-compose up -d chorus-website ``` ## Database Schema Features (Brand-Enhanced) ### Lead Capture Tables #### leads (Enhanced for Brand Compliance) ```sql CREATE TABLE leads ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), first_name VARCHAR(100) NOT NULL, last_name VARCHAR(100) NOT NULL, email VARCHAR(255) UNIQUE NOT NULL, company_name VARCHAR(200), inquiry_details TEXT, lead_source VARCHAR(50) DEFAULT 'contact_form', accessibility_theme VARCHAR(20) DEFAULT 'default', -- Brand accessibility preference preferred_communication VARCHAR(20) DEFAULT 'email', gdpr_consent BOOLEAN NOT NULL DEFAULT FALSE, marketing_consent BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), -- Brand engagement tracking logo_interactions INTEGER DEFAULT 0, time_on_site INTEGER, -- milliseconds for performance analysis pages_viewed JSONB DEFAULT '[]'::jsonb, -- Performance and analytics load_time_lcp INTEGER, -- Largest Contentful Paint load_time_fid INTEGER, -- First Input Delay device_type VARCHAR(20), -- mobile, tablet, desktop browser_info JSONB ); -- Indexes for performance CREATE INDEX idx_leads_created_at ON leads(created_at); CREATE INDEX idx_leads_accessibility_theme ON leads(accessibility_theme); CREATE INDEX idx_leads_lead_source ON leads(lead_source); ``` #### accessibility_preferences (New Brand Table) ```sql CREATE TABLE accessibility_preferences ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), session_id VARCHAR(100), accessibility_theme VARCHAR(20) NOT NULL, -- default, protanopia, deuteranopia, tritanopia, achromatopsia dark_mode_preference BOOLEAN DEFAULT TRUE, -- Dark mode default per brand reduced_motion BOOLEAN DEFAULT FALSE, font_size_preference VARCHAR(10) DEFAULT 'medium', high_contrast BOOLEAN DEFAULT FALSE, -- Brand interaction data logo_interaction_count INTEGER DEFAULT 0, theme_switch_count INTEGER DEFAULT 0, session_duration INTEGER, -- milliseconds created_at TIMESTAMPTZ DEFAULT NOW(), last_updated TIMESTAMPTZ DEFAULT NOW() ); -- Performance indexes CREATE INDEX idx_accessibility_session ON accessibility_preferences(session_id); CREATE INDEX idx_accessibility_theme ON accessibility_preferences(accessibility_theme); ``` #### consent_audit (Enhanced) - **Brand Compliance**: Tracks accessibility theme consent changes - **Three.js Interaction**: Logs consent for logo interaction data collection - **Performance Analytics**: Consent for collecting Core Web Vitals data #### brand_engagement (New Table) ```sql CREATE TABLE brand_engagement ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), session_id VARCHAR(100), lead_id UUID REFERENCES leads(id), -- Three.js logo interactions logo_interactions JSONB DEFAULT '[]'::jsonb, logo_accessibility_theme_changes INTEGER DEFAULT 0, -- Ultra-minimalist design engagement scroll_depth_percentage INTEGER, time_spent_per_section JSONB DEFAULT '{}'::jsonb, cta_clicks JSONB DEFAULT '[]'::jsonb, -- Performance metrics core_web_vitals JSONB DEFAULT '{}'::jsonb, page_load_performance JSONB DEFAULT '{}'::jsonb, -- Accessibility usage accessibility_features_used JSONB DEFAULT '[]'::jsonb, keyboard_navigation_used BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX idx_brand_engagement_session ON brand_engagement(session_id); CREATE INDEX idx_brand_engagement_lead ON brand_engagement(lead_id); ``` #### lead_interactions (Enhanced) - **Brand-Aware CRM**: Tracks accessibility preferences in interactions - **Performance Context**: Records page performance during interactions - **Design Feedback**: Captures ultra-minimalist design effectiveness #### rate_limits - **Spam Protection**: IP and email-based rate limiting - **Configurable Limits**: Different limits per action type - **Automatic Cleanup**: Expired limits are cleared ### Security Features - **Input Validation**: Zod schema validation - **SQL Injection Protection**: Parameterized queries - **Rate Limiting**: Multiple rate limiters (IP, email) - **GDPR Compliance**: Consent tracking, data retention - **Phone Validation**: International phone number formatting ## API Endpoints (Brand-Enhanced) ### POST /api/leads (Updated) Lead capture endpoint with brand compliance and accessibility support. **Enhanced Request Example**: ```bash curl -X POST http://localhost:3000/api/leads \ -H 'Content-Type: application/json' \ -d '{ "firstName": "John", "lastName": "Doe", "email": "john.doe@example.com", "leadSource": "contact_form", "gdprConsent": true, "companyName": "Acme Corp", "inquiryDetails": "Interested in technical deep dive", // Brand-specific fields "accessibilityTheme": "protanopia", "deviceType": "desktop", "coreWebVitals": { "lcp": 2300, "fid": 85, "cls": 0.08 }, "logoInteractions": 3, "timeOnSite": 145000, "pagesViewed": ["/", "/ecosystem", "/contact"] }' ``` ### POST /api/accessibility-preferences ```typescript // New endpoint for storing user accessibility preferences interface AccessibilityPreferencesRequest { sessionId: string; accessibilityTheme: 'default' | 'protanopia' | 'deuteranopia' | 'tritanopia' | 'achromatopsia'; darkModePreference: boolean; reducedMotion: boolean; logoInteractionCount: number; sessionDuration: number; } // Usage curl -X POST http://localhost:3000/api/accessibility-preferences \ -H 'Content-Type: application/json' \ -d '{ "sessionId": "sess_abc123", "accessibilityTheme": "deuteranopia", "darkModePreference": true, "reducedMotion": false, "logoInteractionCount": 5, "sessionDuration": 180000 }' ``` ### POST /api/brand-engagement ```typescript // Track Three.js logo and brand element interactions interface BrandEngagementRequest { sessionId: string; logoInteractions: Array<{timestamp: number, theme: string, duration: number}>; scrollDepthPercentage: number; timeSpentPerSection: Record; coreWebVitals: {lcp: number, fid: number, cls: number}; accessibilityFeaturesUsed: string[]; } ``` ### GET /api/leads (Enhanced) Protected endpoint with brand analytics (requires API key). ## Monitoring and Maintenance (Brand-Enhanced) ### Database Monitoring ```sql -- Performance monitoring queries for brand compliance -- Track accessibility theme usage SELECT accessibility_theme, COUNT(*) as usage_count, AVG(session_duration) as avg_session_duration FROM accessibility_preferences WHERE created_at >= NOW() - INTERVAL '30 days' GROUP BY accessibility_theme; -- Monitor Three.js logo performance impact SELECT AVG(core_web_vitals->>'lcp')::numeric as avg_lcp, AVG(core_web_vitals->>'fid')::numeric as avg_fid, AVG(core_web_vitals->>'cls')::numeric as avg_cls FROM brand_engagement WHERE created_at >= NOW() - INTERVAL '7 days'; -- Track ultra-minimalist design effectiveness SELECT AVG(scroll_depth_percentage) as avg_scroll_depth, AVG(JSON_ARRAY_LENGTH(cta_clicks)) as avg_cta_interactions FROM brand_engagement WHERE created_at >= NOW() - INTERVAL '30 days'; ``` ### GDPR Compliance (Brand-Enhanced) ```sql -- Enhanced GDPR compliance with brand data -- Data retention with accessibility preferences CREATE OR REPLACE FUNCTION cleanup_expired_brand_data() RETURNS void AS $$ BEGIN -- Clean up old accessibility preferences (90 days) DELETE FROM accessibility_preferences WHERE created_at < NOW() - INTERVAL '90 days' AND session_id NOT IN (SELECT DISTINCT session_id FROM leads); -- Clean up brand engagement data (2 years) DELETE FROM brand_engagement WHERE created_at < NOW() - INTERVAL '2 years' AND lead_id IS NULL; -- Standard GDPR cleanup for leads (7 years) DELETE FROM leads WHERE created_at < NOW() - INTERVAL '7 years' AND gdpr_consent = false; END; $$ LANGUAGE plpgsql; -- Schedule cleanup SELECT cron.schedule('brand-data-cleanup', '0 2 * * 0', 'SELECT cleanup_expired_brand_data();'); ``` ### Backup Strategy The website data is automatically included in the main CHORUS database backup strategy: - **Full Backups**: Daily backups of entire PostgreSQL instance - **Point-in-time Recovery**: Transaction log shipping - **Cross-site Replication**: For disaster recovery ## Troubleshooting ### Common Issues 1. **Connection Refused** ```bash # Ensure main CHORUS postgres is running docker-compose up -d postgres # Check network connectivity docker network ls | grep chorus ``` 2. **Database Not Found** ```bash # Recreate postgres container to run init-db.sql docker-compose down postgres docker-compose up -d postgres ``` 3. **Migration Failures** ```bash # Check migration status psql postgresql://chorus:choruspass@localhost:5433/chorus_website \ -c "SELECT * FROM schema_migrations;" # Run migrations manually cd database/ ./run-migrations.sh ``` ### Brand-Aware Health Checks ```bash # Test database connectivity with brand tables psql postgresql://chorus:choruspass@localhost:5433/chorus_website -c " SELECT 'leads' as table_name, COUNT(*) as row_count FROM leads UNION ALL SELECT 'accessibility_preferences', COUNT(*) FROM accessibility_preferences UNION ALL SELECT 'brand_engagement', COUNT(*) FROM brand_engagement;" # Test brand-enhanced API endpoints curl -f http://localhost:3000/api/leads/health curl -f http://localhost:3000/api/accessibility-preferences/health curl -f http://localhost:3000/api/brand-engagement/health # Check Three.js logo performance impact curl -f http://localhost:3000/api/brand-analytics/performance # Verify accessibility theme data collection curl -f http://localhost:3000/api/brand-analytics/accessibility-usage ``` ## Security Considerations - **Network Isolation**: Website container only has access to necessary services - **Credential Management**: Database credentials managed via environment variables - **Input Validation**: Multi-layer validation (client, API, database) - **Rate Limiting**: Protection against abuse and spam - **GDPR Compliance**: Full consent management and data retention policies ## Future Enhancements (Brand-Focused) ### Performance Optimization 1. **Three.js Logo Optimization**: Database caching for logo material preferences 2. **Real-time Analytics**: WebSocket integration for live brand engagement metrics 3. **Accessibility Analytics**: ML-based analysis of accessibility theme effectiveness ### Brand Intelligence ```sql -- Planned brand intelligence features -- A/B testing for ultra-minimalist design elements CREATE TABLE brand_ab_tests ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), test_name VARCHAR(100) NOT NULL, variant_a_design JSONB, variant_b_design JSONB, conversion_metrics JSONB, accessibility_impact JSONB, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Logo interaction heatmaps CREATE TABLE logo_interaction_heatmaps ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), session_id VARCHAR(100), interaction_coordinates JSONB, -- x,y coordinates of interactions accessibility_theme VARCHAR(20), interaction_duration INTEGER, timestamp TIMESTAMPTZ DEFAULT NOW() ); -- Performance benchmarking CREATE TABLE performance_benchmarks ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), page_path VARCHAR(200), device_type VARCHAR(20), accessibility_theme VARCHAR(20), core_web_vitals JSONB, lighthouse_scores JSONB, three_js_render_time INTEGER, created_at TIMESTAMPTZ DEFAULT NOW() ); ``` ### Advanced Features 1. **Connection Pooling**: pgBouncer with brand-optimized connection management 2. **Read Replicas**: Dedicated replicas for accessibility and brand analytics 3. **Real-time Monitoring**: Prometheus metrics for Three.js logo performance 4. **Brand Audit Logging**: Complete audit trail for all brand-related data changes 5. **Encryption**: Field-level encryption for accessibility preferences and engagement data