-- ==================== FRESH DATABASE MIGRATION ==================== -- LinkedIn Workflow - Complete Schema for new Supabase Database -- Run this in the Supabase SQL Editor -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- ==================== CORE TABLES ==================== -- Customers/Clients Table CREATE TABLE IF NOT EXISTS customers ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Basic Info name TEXT NOT NULL, email TEXT, company_name TEXT, -- LinkedIn Profile linkedin_url TEXT NOT NULL, -- Metadata metadata JSONB DEFAULT '{}'::JSONB, -- Email workflow fields creator_email TEXT, customer_email TEXT, -- Relations user_id UUID, -- FK added after auth setup company_id UUID, -- FK added after companies table writing_style_notes TEXT, is_active BOOLEAN DEFAULT TRUE, profile_picture TEXT ); -- Post Types Table (for categorizing posts by type) CREATE TABLE IF NOT EXISTS post_types ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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 analysis JSONB, analysis_generated_at TIMESTAMP WITH TIME ZONE, analyzed_post_count INTEGER DEFAULT 0, -- Status is_active BOOLEAN DEFAULT TRUE, UNIQUE(customer_id, name) ); -- LinkedIn Profiles Table (scraped data) CREATE TABLE IF NOT EXISTS linkedin_profiles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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(customer_id) ); -- LinkedIn Posts Table (scraped posts) CREATE TABLE IF NOT EXISTS linkedin_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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, -- Post type classification post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL, classification_method TEXT, classification_confidence FLOAT, UNIQUE(customer_id, post_url) ); -- Topics Table (extracted from posts) CREATE TABLE IF NOT EXISTS topics ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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(), customer_id UUID NOT NULL REFERENCES customers(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(customer_id) ); -- Research Results Table CREATE TABLE IF NOT EXISTS research_results ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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(), customer_id UUID NOT NULL REFERENCES customers(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: draft -> approved -> ready -> scheduled -> published -- draft: AI generated, waiting for review -- approved: User edited, email sent to customer -- ready: Customer approved via email, can be scheduled -- scheduled: Scheduled in calendar -- published: Actually published to LinkedIn -- rejected: Customer rejected, back to draft status TEXT DEFAULT 'draft' CHECK (status IN ('draft', 'approved', 'ready', '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 -- FK added after auth setup ); -- ==================== COMPANIES & PROFILES (Supabase Auth) ==================== -- Companies Table 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 company_strategy JSONB DEFAULT '{}'::JSONB, owner_user_id UUID NOT NULL, -- FK to auth.users onboarding_completed BOOLEAN DEFAULT FALSE ); -- Profiles Table (extends auth.users) CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY, -- Same as auth.users.id 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', -- Display name display_name TEXT, -- Onboarding onboarding_status TEXT DEFAULT 'pending', onboarding_data JSONB DEFAULT '{}'::JSONB, -- Links customer_id UUID REFERENCES customers(id) ON DELETE SET NULL, company_id UUID REFERENCES companies(id) ON DELETE SET NULL ); -- Invitations Table 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, -- FK to auth.users status TEXT DEFAULT 'pending', accepted_at TIMESTAMP WITH TIME ZONE, accepted_by_user_id UUID -- FK to auth.users ); -- Example Posts Table CREATE TABLE IF NOT EXISTS example_posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(id) ON DELETE CASCADE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), post_text TEXT NOT NULL, source TEXT DEFAULT 'manual', source_linkedin_url TEXT, post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL ); -- Reference Profiles Table CREATE TABLE IF NOT EXISTS reference_profiles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), customer_id UUID NOT NULL REFERENCES customers(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(customer_id, linkedin_url) ); -- ==================== ADD FOREIGN KEYS (after all tables exist) ==================== -- Add FK from profiles to auth.users ALTER TABLE profiles ADD CONSTRAINT fk_profiles_auth_users FOREIGN KEY (id) REFERENCES auth.users(id) ON DELETE CASCADE; -- Add FK from companies to auth.users ALTER TABLE companies ADD CONSTRAINT fk_companies_owner FOREIGN KEY (owner_user_id) REFERENCES auth.users(id) ON DELETE CASCADE; -- Add FK from customers to auth.users and companies ALTER TABLE customers ADD CONSTRAINT fk_customers_user FOREIGN KEY (user_id) REFERENCES auth.users(id) ON DELETE SET NULL; ALTER TABLE customers ADD CONSTRAINT fk_customers_company FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE SET NULL; -- Add FK from generated_posts to auth.users ALTER TABLE generated_posts ADD CONSTRAINT fk_generated_posts_scheduled_by FOREIGN KEY (scheduled_by_user_id) REFERENCES auth.users(id) ON DELETE SET NULL; -- Add FK from invitations to auth.users ALTER TABLE invitations ADD CONSTRAINT fk_invitations_invited_by FOREIGN KEY (invited_by_user_id) REFERENCES auth.users(id) ON DELETE CASCADE; ALTER TABLE invitations ADD CONSTRAINT fk_invitations_accepted_by FOREIGN KEY (accepted_by_user_id) REFERENCES auth.users(id) ON DELETE SET NULL; -- ==================== INDEXES ==================== -- Customers CREATE INDEX idx_customers_linkedin_url ON customers(linkedin_url); CREATE INDEX idx_customers_user_id ON customers(user_id); CREATE INDEX idx_customers_company_id ON customers(company_id); -- LinkedIn data CREATE INDEX idx_linkedin_profiles_customer_id ON linkedin_profiles(customer_id); CREATE INDEX idx_linkedin_posts_customer_id ON linkedin_posts(customer_id); CREATE INDEX idx_linkedin_posts_post_type_id ON linkedin_posts(post_type_id); -- Topics CREATE INDEX idx_topics_customer_id ON topics(customer_id); CREATE INDEX idx_topics_is_used ON topics(is_used); CREATE INDEX idx_topics_target_post_type_id ON topics(target_post_type_id); -- Profile analyses & research CREATE INDEX idx_profile_analyses_customer_id ON profile_analyses(customer_id); CREATE INDEX idx_research_results_customer_id ON research_results(customer_id); CREATE INDEX idx_research_results_target_post_type_id ON research_results(target_post_type_id); -- Generated posts CREATE INDEX idx_generated_posts_customer_id ON generated_posts(customer_id); CREATE INDEX idx_generated_posts_status ON generated_posts(status); CREATE INDEX idx_generated_posts_post_type_id ON generated_posts(post_type_id); CREATE INDEX idx_generated_posts_scheduled_at ON generated_posts(scheduled_at) WHERE scheduled_at IS NOT NULL AND status = 'scheduled'; -- Post types CREATE INDEX idx_post_types_customer_id ON post_types(customer_id); CREATE INDEX idx_post_types_is_active ON post_types(is_active); -- Profiles CREATE INDEX idx_profiles_account_type ON profiles(account_type); CREATE INDEX idx_profiles_onboarding_status ON profiles(onboarding_status); CREATE INDEX idx_profiles_customer_id ON profiles(customer_id); CREATE INDEX idx_profiles_company_id ON profiles(company_id); -- Companies CREATE INDEX idx_companies_owner_user_id ON companies(owner_user_id); -- Invitations CREATE INDEX idx_invitations_token ON invitations(token); CREATE INDEX idx_invitations_company_id ON invitations(company_id); CREATE INDEX idx_invitations_email ON invitations(email); CREATE INDEX idx_invitations_status ON invitations(status); -- Example posts & reference profiles CREATE INDEX idx_example_posts_customer_id ON example_posts(customer_id); CREATE INDEX idx_reference_profiles_customer_id ON reference_profiles(customer_id); -- ==================== TRIGGERS ==================== -- Updated_at trigger function CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Add triggers CREATE TRIGGER update_customers_updated_at BEFORE UPDATE ON customers FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_post_types_updated_at BEFORE UPDATE ON post_types FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_profiles_updated_at BEFORE UPDATE ON profiles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_companies_updated_at BEFORE UPDATE ON companies FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ==================== AUTO-CREATE PROFILE ON 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; 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(); -- ==================== ROW LEVEL SECURITY ==================== -- Enable RLS ALTER TABLE profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE companies ENABLE ROW LEVEL SECURITY; ALTER TABLE customers ENABLE ROW LEVEL SECURITY; ALTER TABLE generated_posts ENABLE ROW LEVEL SECURITY; ALTER TABLE invitations ENABLE ROW LEVEL SECURITY; -- Profiles policies 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 FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- Companies policies CREATE POLICY "Company owners can manage their company" ON companies FOR ALL 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 FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- Customers policies CREATE POLICY "Users can manage own customers" ON customers FOR ALL USING (auth.uid() = user_id); CREATE POLICY "Company members can view company customers" ON customers FOR SELECT USING ( EXISTS ( SELECT 1 FROM profiles WHERE profiles.id = auth.uid() AND profiles.company_id = customers.company_id ) ); CREATE POLICY "Service role has full access to customers" ON customers FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- Generated posts policies CREATE POLICY "Users can manage posts of their customers" ON generated_posts FOR ALL USING ( EXISTS ( SELECT 1 FROM customers WHERE customers.id = generated_posts.customer_id AND customers.user_id = auth.uid() ) ); CREATE POLICY "Company members can view company posts" ON generated_posts FOR SELECT USING ( EXISTS ( SELECT 1 FROM customers JOIN profiles ON profiles.company_id = customers.company_id WHERE customers.id = generated_posts.customer_id AND profiles.id = auth.uid() ) ); CREATE POLICY "Service role has full access to generated_posts" ON generated_posts FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- Invitations policies CREATE POLICY "Company owners can manage invitations" ON invitations FOR ALL USING ( EXISTS ( SELECT 1 FROM companies WHERE companies.id = invitations.company_id AND companies.owner_user_id = auth.uid() ) ); CREATE POLICY "Anyone can view invitation by token" ON invitations FOR SELECT USING (true); CREATE POLICY "Service role has full access to invitations" ON invitations FOR ALL USING (auth.jwt() ->> 'role' = 'service_role'); -- ==================== DONE ==================== -- Run this script in the Supabase SQL Editor -- Make sure to configure your .env with the new Supabase URL and keys