-- Database schema for mailing list and email campaign management -- Mailing Lists CREATE TABLE IF NOT EXISTS mailing_lists ( id UUID PRIMARY KEY, name VARCHAR(255) NOT NULL, description TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Subscribers CREATE TABLE IF NOT EXISTS subscribers ( id UUID PRIMARY KEY, email VARCHAR(255) NOT NULL UNIQUE, first_name VARCHAR(255), last_name VARCHAR(255), status VARCHAR(50) DEFAULT 'active', -- active, unsubscribed, bounced, complained created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, last_activity_at TIMESTAMP ); -- Mailing List Subscribers (many-to-many) CREATE TABLE IF NOT EXISTS mailing_list_subscribers ( list_id UUID REFERENCES mailing_lists(id) ON DELETE CASCADE, subscriber_id UUID REFERENCES subscribers(id) ON DELETE CASCADE, subscribed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (list_id, subscriber_id) ); -- Email Campaigns CREATE TABLE IF NOT EXISTS email_campaigns ( id UUID PRIMARY KEY, name VARCHAR(255) NOT NULL, subject VARCHAR(255) NOT NULL, preheader VARCHAR(255), from_name VARCHAR(255), from_email VARCHAR(255) NOT NULL, content TEXT, design TEXT, -- JSON storage for the email editor design list_ids UUID[] NOT NULL, -- Array of list IDs to send to status VARCHAR(50) DEFAULT 'draft', -- draft, scheduled, sending, sent, archived created_by UUID REFERENCES users(id), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, scheduled_for TIMESTAMP, sent_at TIMESTAMP ); -- Campaign Recipients CREATE TABLE IF NOT EXISTS campaign_recipients ( campaign_id UUID REFERENCES email_campaigns(id) ON DELETE CASCADE, subscriber_id UUID REFERENCES subscribers(id) ON DELETE CASCADE, added_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (campaign_id, subscriber_id) ); -- Campaign Links (for click tracking) CREATE TABLE IF NOT EXISTS campaign_links ( id UUID PRIMARY KEY, campaign_id UUID REFERENCES email_campaigns(id) ON DELETE CASCADE, url TEXT NOT NULL, text VARCHAR(255), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Subscriber Activity CREATE TABLE IF NOT EXISTS subscriber_activity ( id SERIAL PRIMARY KEY, subscriber_id UUID REFERENCES subscribers(id) ON DELETE CASCADE, campaign_id UUID REFERENCES email_campaigns(id) ON DELETE SET NULL, link_id UUID REFERENCES campaign_links(id) ON DELETE SET NULL, type VARCHAR(50) NOT NULL, -- open, click, bounce, complaint, unsubscribe timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP, url TEXT, -- For click events details TEXT, -- Additional information bounce_type VARCHAR(50), -- hard, soft CONSTRAINT valid_activity_type CHECK ( type IN ('open', 'click', 'bounce', 'complaint', 'unsubscribe', 'sent', 'error') ) ); -- Subscription Confirmations (double opt-in) CREATE TABLE IF NOT EXISTS subscription_confirmations ( id SERIAL PRIMARY KEY, subscriber_id UUID REFERENCES subscribers(id) ON DELETE CASCADE, token VARCHAR(255) UNIQUE NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, confirmed_at TIMESTAMP, expires_at TIMESTAMP NOT NULL ); -- Unsubscribe Tokens CREATE TABLE IF NOT EXISTS unsubscribe_tokens ( id SERIAL PRIMARY KEY, subscriber_id UUID REFERENCES subscribers(id) ON DELETE CASCADE, campaign_id UUID REFERENCES email_campaigns(id) ON DELETE SET NULL, token VARCHAR(255) UNIQUE NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, used_at TIMESTAMP, expires_at TIMESTAMP NOT NULL ); -- Email Logs ALTER TABLE email_logs ADD COLUMN IF NOT EXISTS message_id VARCHAR(255), ADD COLUMN IF NOT EXISTS campaign_id UUID REFERENCES email_campaigns(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS subscriber_id UUID REFERENCES subscribers(id) ON DELETE SET NULL, ADD COLUMN IF NOT EXISTS error_message TEXT; -- Create indexes for performance CREATE INDEX idx_subscribers_email ON subscribers(email); CREATE INDEX idx_subscribers_status ON subscribers(status); CREATE INDEX idx_mailing_list_subscribers_list_id ON mailing_list_subscribers(list_id); CREATE INDEX idx_mailing_list_subscribers_subscriber_id ON mailing_list_subscribers(subscriber_id); CREATE INDEX idx_email_campaigns_status ON email_campaigns(status); CREATE INDEX idx_email_campaigns_scheduled_for ON email_campaigns(scheduled_for); CREATE INDEX idx_campaign_recipients_campaign_id ON campaign_recipients(campaign_id); CREATE INDEX idx_campaign_recipients_subscriber_id ON campaign_recipients(subscriber_id); CREATE INDEX idx_campaign_links_campaign_id ON campaign_links(campaign_id); CREATE INDEX idx_subscriber_activity_subscriber_id ON subscriber_activity(subscriber_id); CREATE INDEX idx_subscriber_activity_campaign_id ON subscriber_activity(campaign_id); CREATE INDEX idx_subscriber_activity_type ON subscriber_activity(type); CREATE INDEX idx_subscriber_activity_timestamp ON subscriber_activity(timestamp); CREATE INDEX idx_subscription_confirmations_token ON subscription_confirmations(token); CREATE INDEX idx_unsubscribe_tokens_token ON unsubscribe_tokens(token); CREATE INDEX idx_email_logs_recipient ON email_logs(recipient); CREATE INDEX idx_email_logs_campaign_id ON email_logs(campaign_id); CREATE INDEX idx_email_logs_status ON email_logs(status); INSERT INTO mailing_lists (id, name, description) VALUES ('1db91b9b-b1f9-4892-80b5-51437d8b6045', 'Default Mailing List', 'This is the default mailing list that new users who accept are attached to, do not delete, feel free to rename');