-- LinkedIn Workflow Database Schema for Supabase -- Post-migration schema: No customers table, all content uses user_id -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- ==================== GHOSTWRITER & COMPANY ACCOUNTS ==================== -- Uses Supabase Auth (auth.users) for authentication -- The profiles table stores application-specific user data -- Profiles Table (extends auth.users with app-specific data) CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Account Type account_type TEXT NOT NULL DEFAULT 'ghostwriter', -- 'ghostwriter' | 'company' | 'employee' -- Display name display_name TEXT, -- Onboarding onboarding_status TEXT DEFAULT 'pending', -- 'pending' | 'profile_setup' | 'posts_scraped' | 'categorizing' | 'completed' onboarding_data JSONB DEFAULT '{}'::JSONB, -- Company link company_id UUID, -- FK added after companies table -- Fields migrated from customers linkedin_url TEXT, writing_style_notes TEXT, metadata JSONB DEFAULT '{}'::JSONB, profile_picture TEXT, creator_email TEXT, customer_email TEXT, is_active BOOLEAN DEFAULT TRUE ); -- Function to automatically create profile on user signup CREATE OR REPLACE FUNCTION public.handle_new_user() RETURNS TRIGGER AS $$ BEGIN INSERT INTO public.profiles (id, account_type, onboarding_status) VALUES ( NEW.id, COALESCE(NEW.raw_user_meta_data->>'account_type', 'ghostwriter'), 'pending' ); RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Trigger to create profile on auth.users insert DROP TRIGGER IF EXISTS on_auth_user_created ON auth.users; CREATE TRIGGER on_auth_user_created AFTER INSERT ON auth.users FOR EACH ROW EXECUTE FUNCTION public.handle_new_user(); -- Companies Table (company accounts) CREATE TABLE IF NOT EXISTS companies ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Company Data name TEXT NOT NULL, description TEXT, website TEXT, industry TEXT, -- Strategy (used during post creation) company_strategy JSONB DEFAULT '{}'::JSONB, owner_user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, onboarding_completed BOOLEAN DEFAULT FALSE ); -- Add FK from profiles to companies (after companies table exists) ALTER TABLE profiles ADD CONSTRAINT fk_profiles_company FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE SET NULL; -- ==================== CONTENT TABLES (all use user_id) ==================== -- LinkedIn Profiles Table (scraped data) CREATE TABLE IF NOT EXISTS linkedin_profiles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, scraped_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Profile Data profile_data JSONB NOT NULL, -- Extracted Information name TEXT, headline TEXT, summary TEXT, location TEXT, industry TEXT, UNIQUE(user_id) ); -- Post Types Table (for categorizing posts by type) CREATE TABLE IF NOT EXISTS post_types ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Type Definition name TEXT NOT NULL, description TEXT, identifying_hashtags TEXT[] DEFAULT '{}', identifying_keywords TEXT[] DEFAULT '{}', semantic_properties JSONB DEFAULT '{}'::JSONB, -- Analysis Results (generated after classification) analysis JSONB, analysis_generated_at TIMESTAMP WITH TIME ZONE, analyzed_post_count INTEGER DEFAULT 0, -- Status is_active BOOLEAN DEFAULT TRUE, UNIQUE(user_id, name) ); -- LinkedIn Posts Table (scraped posts) CREATE TABLE IF NOT EXISTS linkedin_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, scraped_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Post Data post_url TEXT, post_text TEXT NOT NULL, post_date TIMESTAMP WITH TIME ZONE, likes INTEGER DEFAULT 0, comments INTEGER DEFAULT 0, shares INTEGER DEFAULT 0, -- Raw Data raw_data JSONB, -- Classification post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL, classification_method TEXT, classification_confidence FLOAT, UNIQUE(user_id, post_url) ); -- Topics Table (extracted from posts) CREATE TABLE IF NOT EXISTS topics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Topic Info title TEXT NOT NULL, description TEXT, category TEXT, -- AI Extraction extracted_from_post_id UUID REFERENCES linkedin_posts(id), extraction_confidence FLOAT, -- Status is_used BOOLEAN DEFAULT FALSE, used_at TIMESTAMP WITH TIME ZONE, -- Target post type target_post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL ); -- Profile Analysis Table (AI-generated insights) CREATE TABLE IF NOT EXISTS profile_analyses ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Analysis Results writing_style JSONB NOT NULL, tone_analysis JSONB NOT NULL, topic_patterns JSONB NOT NULL, audience_insights JSONB NOT NULL, -- Full Analysis full_analysis JSONB NOT NULL, UNIQUE(user_id) ); -- Research Results Table CREATE TABLE IF NOT EXISTS research_results ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Research Data query TEXT NOT NULL, results JSONB NOT NULL, -- Topic Suggestions suggested_topics JSONB NOT NULL, -- Metadata source TEXT DEFAULT 'perplexity', -- Target post type target_post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL ); -- Generated Posts Table CREATE TABLE IF NOT EXISTS generated_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Topic topic_id UUID REFERENCES topics(id), topic_title TEXT NOT NULL, -- Post Content post_content TEXT NOT NULL, -- Generation Metadata iterations INTEGER DEFAULT 0, writer_versions JSONB DEFAULT '[]'::JSONB, critic_feedback JSONB DEFAULT '[]'::JSONB, -- Status status TEXT DEFAULT 'draft' CHECK (status IN ('draft', 'approved', 'scheduled', 'published', 'rejected')), approved_at TIMESTAMP WITH TIME ZONE, published_at TIMESTAMP WITH TIME ZONE, -- Post type post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL, -- Scheduling scheduled_at TIMESTAMP WITH TIME ZONE, scheduled_by_user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL, -- Image image_url TEXT ); -- Invitations Table (employee invitations) CREATE TABLE IF NOT EXISTS invitations ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), email TEXT NOT NULL, token TEXT NOT NULL UNIQUE, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, company_id UUID NOT NULL REFERENCES companies(id) ON DELETE CASCADE, invited_by_user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, status TEXT DEFAULT 'pending', -- 'pending' | 'accepted' | 'expired' | 'cancelled' accepted_at TIMESTAMP WITH TIME ZONE, accepted_by_user_id UUID REFERENCES auth.users(id) ); -- Example Posts Table (manual example posts when <10 scraped) CREATE TABLE IF NOT EXISTS example_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), post_text TEXT NOT NULL, source TEXT DEFAULT 'manual', -- 'manual' | 'reference_profile' source_linkedin_url TEXT, post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL ); -- Reference Profiles Table (alternative LinkedIn profiles for scraping) CREATE TABLE IF NOT EXISTS reference_profiles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), linkedin_url TEXT NOT NULL, name TEXT, posts_scraped INTEGER DEFAULT 0, UNIQUE(user_id, linkedin_url) ); -- ==================== API USAGE LOGS ==================== CREATE TABLE IF NOT EXISTS api_usage_logs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES auth.users(id) ON DELETE SET NULL, company_id UUID REFERENCES companies(id) ON DELETE SET NULL, provider TEXT NOT NULL, model TEXT NOT NULL, operation TEXT NOT NULL, prompt_tokens INT NOT NULL DEFAULT 0, completion_tokens INT NOT NULL DEFAULT 0, total_tokens INT NOT NULL DEFAULT 0, estimated_cost_usd DECIMAL(10,6) NOT NULL DEFAULT 0, created_at TIMESTAMPTZ DEFAULT now() ); -- ==================== INDEXES ==================== -- Profiles CREATE INDEX IF NOT EXISTS idx_profiles_account_type ON profiles(account_type); CREATE INDEX IF NOT EXISTS idx_profiles_onboarding_status ON profiles(onboarding_status); CREATE INDEX IF NOT EXISTS idx_profiles_company_id ON profiles(company_id); -- Content tables CREATE INDEX IF NOT EXISTS idx_linkedin_profiles_user_id ON linkedin_profiles(user_id); CREATE INDEX IF NOT EXISTS idx_linkedin_posts_user_id ON linkedin_posts(user_id); CREATE INDEX IF NOT EXISTS idx_topics_user_id ON topics(user_id); CREATE INDEX IF NOT EXISTS idx_topics_is_used ON topics(is_used); CREATE INDEX IF NOT EXISTS idx_topics_target_post_type_id ON topics(target_post_type_id); CREATE INDEX IF NOT EXISTS idx_post_types_user_id ON post_types(user_id); CREATE INDEX IF NOT EXISTS idx_post_types_is_active ON post_types(is_active); CREATE INDEX IF NOT EXISTS idx_profile_analyses_user_id ON profile_analyses(user_id); CREATE INDEX IF NOT EXISTS idx_research_results_user_id ON research_results(user_id); CREATE INDEX IF NOT EXISTS idx_research_results_target_post_type_id ON research_results(target_post_type_id); CREATE INDEX IF NOT EXISTS idx_generated_posts_user_id ON generated_posts(user_id); CREATE INDEX IF NOT EXISTS idx_generated_posts_status ON generated_posts(status); CREATE INDEX IF NOT EXISTS idx_generated_posts_post_type_id ON generated_posts(post_type_id); CREATE INDEX IF NOT EXISTS idx_generated_posts_scheduled_at ON generated_posts(scheduled_at) WHERE scheduled_at IS NOT NULL AND status = 'scheduled'; CREATE INDEX IF NOT EXISTS idx_linkedin_posts_post_type_id ON linkedin_posts(post_type_id); CREATE INDEX IF NOT EXISTS idx_example_posts_user_id ON example_posts(user_id); CREATE INDEX IF NOT EXISTS idx_reference_profiles_user_id ON reference_profiles(user_id); -- Companies & Invitations CREATE INDEX IF NOT EXISTS idx_companies_owner_user_id ON companies(owner_user_id); CREATE INDEX IF NOT EXISTS idx_invitations_token ON invitations(token); CREATE INDEX IF NOT EXISTS idx_invitations_company_id ON invitations(company_id); CREATE INDEX IF NOT EXISTS idx_invitations_email ON invitations(email); CREATE INDEX IF NOT EXISTS idx_invitations_status ON invitations(status); -- API usage CREATE INDEX IF NOT EXISTS idx_api_usage_logs_user_id ON api_usage_logs(user_id); CREATE INDEX IF NOT EXISTS idx_api_usage_logs_company_id ON api_usage_logs(company_id); CREATE INDEX IF NOT EXISTS idx_api_usage_logs_created_at ON api_usage_logs(created_at); -- ==================== TRIGGERS ==================== CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; DROP TRIGGER IF EXISTS update_profiles_updated_at ON profiles; CREATE TRIGGER update_profiles_updated_at BEFORE UPDATE ON profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS update_post_types_updated_at ON post_types; CREATE TRIGGER update_post_types_updated_at BEFORE UPDATE ON post_types FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS update_companies_updated_at ON companies; CREATE TRIGGER update_companies_updated_at BEFORE UPDATE ON companies FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ==================== ROW LEVEL SECURITY ==================== ALTER TABLE profiles ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can view own profile" ON profiles FOR SELECT USING (auth.uid() = id); CREATE POLICY "Users can update own profile" ON profiles FOR UPDATE USING (auth.uid() = id); CREATE POLICY "Service role has full access to profiles" ON profiles USING (auth.jwt() ->> 'role' = 'service_role'); ALTER TABLE companies ENABLE ROW LEVEL SECURITY; CREATE POLICY "Company owners can manage their company" ON companies USING (auth.uid() = owner_user_id); CREATE POLICY "Employees can view their company" ON companies FOR SELECT USING ( EXISTS ( SELECT 1 FROM profiles WHERE profiles.id = auth.uid() AND profiles.company_id = companies.id ) ); CREATE POLICY "Service role has full access to companies" ON companies USING (auth.jwt() ->> 'role' = 'service_role'); -- Generated posts RLS ALTER TABLE generated_posts ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can manage own posts" ON generated_posts FOR ALL USING (user_id = auth.uid()); CREATE POLICY "Company members can view company posts" ON generated_posts FOR SELECT USING ( EXISTS ( SELECT 1 FROM profiles p1 JOIN profiles p2 ON p1.company_id = p2.company_id WHERE p1.id = auth.uid() AND p2.id = generated_posts.user_id AND p1.company_id IS NOT NULL ) ); CREATE POLICY "Service role has full access to generated_posts" ON generated_posts FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- ==================== USERS VIEW ==================== CREATE OR REPLACE VIEW users AS SELECT au.id, au.created_at, au.updated_at, au.email, au.raw_user_meta_data->>'sub' AS linkedin_sub, au.raw_user_meta_data->>'vanityName' AS linkedin_vanity_name, au.raw_user_meta_data->>'name' AS linkedin_name, au.raw_user_meta_data->>'picture' AS linkedin_picture, CASE WHEN au.raw_user_meta_data->>'iss' LIKE '%linkedin%' THEN 'linkedin_oauth' ELSE 'email_password' END AS auth_method, COALESCE(p.account_type, 'ghostwriter') AS account_type, p.display_name, COALESCE(p.onboarding_status, 'pending') AS onboarding_status, COALESCE(p.onboarding_data, '{}'::jsonb) AS onboarding_data, p.company_id, p.linkedin_url, p.writing_style_notes, p.metadata, p.profile_picture, p.creator_email, p.customer_email, p.is_active, au.email_confirmed_at IS NOT NULL AS email_verified FROM auth.users au LEFT JOIN profiles p ON au.id = p.id; -- ==================== LICENSE KEY SYSTEM ==================== -- License Keys Table CREATE TABLE IF NOT EXISTS license_keys ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), key TEXT UNIQUE NOT NULL, description TEXT, -- Limits (stored here, NOT in companies table) max_employees INT NOT NULL DEFAULT 5, max_posts_per_day INT NOT NULL DEFAULT 10, max_researches_per_day INT NOT NULL DEFAULT 5, -- Usage tracking used BOOLEAN DEFAULT FALSE, company_id UUID REFERENCES companies(id) ON DELETE SET NULL, used_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Index for fast lookups CREATE INDEX IF NOT EXISTS idx_license_keys_key ON license_keys(key); CREATE INDEX IF NOT EXISTS idx_license_keys_used ON license_keys(used); CREATE INDEX IF NOT EXISTS idx_license_keys_company_id ON license_keys(company_id); -- RLS Policies (Admin only) ALTER TABLE license_keys ENABLE ROW LEVEL SECURITY; CREATE POLICY "Service role has full access to license_keys" ON license_keys FOR ALL USING (auth.jwt()->>'role' = 'service_role'); -- Add license key reference to companies table -- (limits are stored in license_keys table, not duplicated here) ALTER TABLE companies ADD COLUMN IF NOT EXISTS license_key_id UUID REFERENCES license_keys(id); -- Index CREATE INDEX IF NOT EXISTS idx_companies_license_key_id ON companies(license_key_id); -- Company Daily Quotas Table CREATE TABLE IF NOT EXISTS company_daily_quotas ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), company_id UUID NOT NULL REFERENCES companies(id) ON DELETE CASCADE, date DATE NOT NULL, posts_created INT DEFAULT 0, researches_created INT DEFAULT 0, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), UNIQUE(company_id, date) ); -- Index for fast daily lookups CREATE INDEX IF NOT EXISTS idx_company_daily_quotas_company_date ON company_daily_quotas(company_id, date); -- RLS Policies ALTER TABLE company_daily_quotas ENABLE ROW LEVEL SECURITY; CREATE POLICY "Users can view own company quotas" ON company_daily_quotas FOR SELECT USING ( company_id IN ( SELECT company_id FROM profiles WHERE id = auth.uid() ) ); CREATE POLICY "Service role has full access to company_daily_quotas" ON company_daily_quotas FOR ALL USING (auth.jwt()->>'role' = 'service_role'); -- Triggers for updated_at DROP TRIGGER IF EXISTS update_license_keys_updated_at ON license_keys; CREATE TRIGGER update_license_keys_updated_at BEFORE UPDATE ON license_keys FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); DROP TRIGGER IF EXISTS update_company_daily_quotas_updated_at ON company_daily_quotas; CREATE TRIGGER update_company_daily_quotas_updated_at BEFORE UPDATE ON company_daily_quotas FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();