 c8fb816775
			
		
	
	c8fb816775
	
	
	
		
			
			- Created complete Next.js 15 teaser website with CHORUS brand styling - Implemented mobile-responsive 3D logo (128px mobile, 512px desktop) - Added proper Exo font loading via Next.js Google Fonts for iOS/Chrome compatibility - Built comprehensive early access form with GDPR compliance and rate limiting - Integrated PostgreSQL database with complete schema for lead capture - Added scroll indicators that auto-hide when scrolling begins - Optimized mobile modal forms with proper scrolling and submit button access - Deployed via Docker Swarm with Traefik SSL termination at chorus.services - Includes database migrations, consent tracking, and email notifications 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
		
			
				
	
	
		
			239 lines
		
	
	
		
			7.7 KiB
		
	
	
	
		
			PL/PgSQL
		
	
	
	
	
	
			
		
		
	
	
			239 lines
		
	
	
		
			7.7 KiB
		
	
	
	
		
			PL/PgSQL
		
	
	
	
	
	
| -- Lead Capture System Database Schema
 | |
| -- Designed for international support, GDPR compliance, and security
 | |
| 
 | |
| -- Extension for UUID generation
 | |
| CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
 | |
| CREATE EXTENSION IF NOT EXISTS "pgcrypto";
 | |
| 
 | |
| -- Enum types for standardized values
 | |
| CREATE TYPE lead_source_type AS ENUM (
 | |
|     'schedule_strategic_demo',
 | |
|     'technical_deep_dive', 
 | |
|     'roi_calculator',
 | |
|     'compliance_brief',
 | |
|     'case_studies',
 | |
|     'contact_form',
 | |
|     'newsletter_signup'
 | |
| );
 | |
| 
 | |
| CREATE TYPE lead_status_type AS ENUM (
 | |
|     'new',
 | |
|     'contacted',
 | |
|     'qualified',
 | |
|     'converted',
 | |
|     'closed'
 | |
| );
 | |
| 
 | |
| CREATE TYPE consent_status_type AS ENUM (
 | |
|     'given',
 | |
|     'withdrawn',
 | |
|     'expired'
 | |
| );
 | |
| 
 | |
| CREATE TYPE company_size_type AS ENUM (
 | |
|     'startup',
 | |
|     'small_business',
 | |
|     'medium_business', 
 | |
|     'enterprise',
 | |
|     'government',
 | |
|     'nonprofit'
 | |
| );
 | |
| 
 | |
| -- Core leads table with international support
 | |
| CREATE TABLE leads (
 | |
|     -- Primary identification
 | |
|     id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
 | |
|     
 | |
|     -- Personal Information (encrypted for GDPR compliance)
 | |
|     first_name TEXT NOT NULL,
 | |
|     last_name TEXT NOT NULL,
 | |
|     email TEXT NOT NULL,
 | |
|     phone TEXT, -- International format +[country code][number]
 | |
|     
 | |
|     -- Address Information (flexible for international formats)
 | |
|     address_line1 TEXT,
 | |
|     address_line2 TEXT,
 | |
|     city TEXT,
 | |
|     state_province TEXT,
 | |
|     postal_code TEXT,
 | |
|     country_code CHAR(2), -- ISO 3166-1 alpha-2 country code
 | |
|     
 | |
|     -- Company Information
 | |
|     company_name TEXT,
 | |
|     company_role TEXT,
 | |
|     company_size company_size_type,
 | |
|     company_industry TEXT,
 | |
|     
 | |
|     -- Lead Classification
 | |
|     lead_source lead_source_type NOT NULL,
 | |
|     lead_status lead_status_type DEFAULT 'new',
 | |
|     inquiry_details TEXT, -- Specific interests or requirements
 | |
|     custom_message TEXT, -- Free text for additional context
 | |
|     
 | |
|     -- Technical tracking
 | |
|     ip_address INET,
 | |
|     user_agent TEXT,
 | |
|     referrer_url TEXT,
 | |
|     utm_source TEXT,
 | |
|     utm_medium TEXT,
 | |
|     utm_campaign TEXT,
 | |
|     
 | |
|     -- Timestamps
 | |
|     created_at TIMESTAMPTZ DEFAULT NOW(),
 | |
|     updated_at TIMESTAMPTZ DEFAULT NOW(),
 | |
|     last_contacted_at TIMESTAMPTZ,
 | |
|     
 | |
|     -- GDPR Compliance
 | |
|     gdpr_consent_given BOOLEAN DEFAULT false,
 | |
|     gdpr_consent_date TIMESTAMPTZ,
 | |
|     gdpr_lawful_basis TEXT DEFAULT 'consent',
 | |
|     marketing_consent BOOLEAN DEFAULT false,
 | |
|     data_retention_expires_at TIMESTAMPTZ,
 | |
|     
 | |
|     -- Security and validation
 | |
|     email_verified BOOLEAN DEFAULT false,
 | |
|     email_verification_token TEXT,
 | |
|     email_verification_sent_at TIMESTAMPTZ,
 | |
|     
 | |
|     -- Constraints
 | |
|     CONSTRAINT valid_email CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'),
 | |
|     CONSTRAINT valid_country_code CHECK (country_code IS NULL OR length(country_code) = 2),
 | |
|     CONSTRAINT gdpr_consent_check CHECK (
 | |
|         (gdpr_consent_given = true AND gdpr_consent_date IS NOT NULL) OR 
 | |
|         (gdpr_consent_given = false)
 | |
|     )
 | |
| );
 | |
| 
 | |
| -- Indexes for performance
 | |
| CREATE INDEX idx_leads_email ON leads(email);
 | |
| CREATE INDEX idx_leads_created_at ON leads(created_at);
 | |
| CREATE INDEX idx_leads_lead_source ON leads(lead_source);
 | |
| CREATE INDEX idx_leads_lead_status ON leads(lead_status);
 | |
| CREATE INDEX idx_leads_company_name ON leads(company_name);
 | |
| CREATE INDEX idx_leads_country_code ON leads(country_code);
 | |
| CREATE INDEX idx_leads_gdpr_consent ON leads(gdpr_consent_given);
 | |
| CREATE INDEX idx_leads_data_retention ON leads(data_retention_expires_at);
 | |
| 
 | |
| -- Consent audit trail for GDPR compliance
 | |
| CREATE TABLE consent_audit (
 | |
|     id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
 | |
|     lead_id UUID NOT NULL REFERENCES leads(id) ON DELETE CASCADE,
 | |
|     consent_type TEXT NOT NULL, -- 'gdpr_consent', 'marketing_consent', etc.
 | |
|     consent_status consent_status_type NOT NULL,
 | |
|     consent_date TIMESTAMPTZ NOT NULL DEFAULT NOW(),
 | |
|     consent_method TEXT, -- 'web_form', 'email', 'phone', etc.
 | |
|     ip_address INET,
 | |
|     user_agent TEXT,
 | |
|     notes TEXT,
 | |
|     
 | |
|     -- Immutable audit trail
 | |
|     created_at TIMESTAMPTZ DEFAULT NOW()
 | |
| );
 | |
| 
 | |
| CREATE INDEX idx_consent_audit_lead_id ON consent_audit(lead_id);
 | |
| CREATE INDEX idx_consent_audit_date ON consent_audit(consent_date);
 | |
| 
 | |
| -- Lead interaction tracking
 | |
| CREATE TABLE lead_interactions (
 | |
|     id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
 | |
|     lead_id UUID NOT NULL REFERENCES leads(id) ON DELETE CASCADE,
 | |
|     interaction_type TEXT NOT NULL, -- 'email_sent', 'call_made', 'meeting_scheduled', etc.
 | |
|     interaction_date TIMESTAMPTZ NOT NULL DEFAULT NOW(),
 | |
|     subject TEXT,
 | |
|     notes TEXT,
 | |
|     outcome TEXT,
 | |
|     next_action TEXT,
 | |
|     next_action_date DATE,
 | |
|     
 | |
|     -- Staff information
 | |
|     staff_member TEXT, -- Could be user ID or email
 | |
|     
 | |
|     created_at TIMESTAMPTZ DEFAULT NOW(),
 | |
|     updated_at TIMESTAMPTZ DEFAULT NOW()
 | |
| );
 | |
| 
 | |
| CREATE INDEX idx_lead_interactions_lead_id ON lead_interactions(lead_id);
 | |
| CREATE INDEX idx_lead_interactions_date ON lead_interactions(interaction_date);
 | |
| CREATE INDEX idx_lead_interactions_type ON lead_interactions(interaction_type);
 | |
| 
 | |
| -- Rate limiting table for spam protection
 | |
| CREATE TABLE rate_limits (
 | |
|     id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
 | |
|     identifier TEXT NOT NULL, -- IP address or email
 | |
|     identifier_type TEXT NOT NULL, -- 'ip' or 'email'
 | |
|     action_type TEXT NOT NULL, -- 'form_submission', 'email_verification', etc.
 | |
|     attempt_count INTEGER DEFAULT 1,
 | |
|     window_start TIMESTAMPTZ DEFAULT NOW(),
 | |
|     blocked_until TIMESTAMPTZ,
 | |
|     
 | |
|     created_at TIMESTAMPTZ DEFAULT NOW(),
 | |
|     updated_at TIMESTAMPTZ DEFAULT NOW()
 | |
| );
 | |
| 
 | |
| CREATE INDEX idx_rate_limits_identifier ON rate_limits(identifier, identifier_type);
 | |
| CREATE INDEX idx_rate_limits_blocked_until ON rate_limits(blocked_until);
 | |
| 
 | |
| -- Automated cleanup for expired data (GDPR Right to be Forgotten)
 | |
| CREATE TABLE data_retention_schedule (
 | |
|     id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
 | |
|     table_name TEXT NOT NULL,
 | |
|     record_id UUID NOT NULL,
 | |
|     scheduled_deletion_date DATE NOT NULL,
 | |
|     deletion_reason TEXT,
 | |
|     
 | |
|     created_at TIMESTAMPTZ DEFAULT NOW(),
 | |
|     processed_at TIMESTAMPTZ
 | |
| );
 | |
| 
 | |
| CREATE INDEX idx_data_retention_schedule_date ON data_retention_schedule(scheduled_deletion_date);
 | |
| CREATE INDEX idx_data_retention_schedule_processed ON data_retention_schedule(processed_at);
 | |
| 
 | |
| -- Update timestamp trigger
 | |
| CREATE OR REPLACE FUNCTION update_updated_at_column()
 | |
| RETURNS TRIGGER AS $$
 | |
| BEGIN
 | |
|     NEW.updated_at = NOW();
 | |
|     RETURN NEW;
 | |
| END;
 | |
| $$ language 'plpgsql';
 | |
| 
 | |
| -- Apply trigger to relevant tables
 | |
| CREATE TRIGGER update_leads_updated_at 
 | |
|     BEFORE UPDATE ON leads 
 | |
|     FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
 | |
| 
 | |
| CREATE TRIGGER update_lead_interactions_updated_at 
 | |
|     BEFORE UPDATE ON lead_interactions 
 | |
|     FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
 | |
| 
 | |
| CREATE TRIGGER update_rate_limits_updated_at 
 | |
|     BEFORE UPDATE ON rate_limits 
 | |
|     FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column();
 | |
| 
 | |
| -- Views for common queries
 | |
| CREATE VIEW active_leads AS
 | |
| SELECT * FROM leads 
 | |
| WHERE lead_status IN ('new', 'contacted', 'qualified')
 | |
| AND (data_retention_expires_at IS NULL OR data_retention_expires_at > NOW());
 | |
| 
 | |
| CREATE VIEW leads_by_source AS
 | |
| SELECT 
 | |
|     lead_source,
 | |
|     COUNT(*) as total_leads,
 | |
|     COUNT(*) FILTER (WHERE lead_status = 'converted') as converted_leads,
 | |
|     ROUND(
 | |
|         (COUNT(*) FILTER (WHERE lead_status = 'converted')::decimal / COUNT(*)) * 100, 2
 | |
|     ) as conversion_rate
 | |
| FROM leads
 | |
| GROUP BY lead_source;
 | |
| 
 | |
| -- Security: Row Level Security (RLS) - Enable if needed
 | |
| -- ALTER TABLE leads ENABLE ROW LEVEL SECURITY;
 | |
| -- ALTER TABLE consent_audit ENABLE ROW LEVEL SECURITY;
 | |
| -- ALTER TABLE lead_interactions ENABLE ROW LEVEL SECURITY;
 | |
| 
 | |
| -- Grant permissions (adjust based on application user)
 | |
| -- GRANT SELECT, INSERT, UPDATE ON leads TO app_user;
 | |
| -- GRANT SELECT, INSERT ON consent_audit TO app_user;
 | |
| -- GRANT SELECT, INSERT, UPDATE ON lead_interactions TO app_user;
 | |
| -- GRANT SELECT, INSERT, UPDATE, DELETE ON rate_limits TO app_user; |