Major updates: LinkedIn auto-posting, timezone fixes, and Docker improvements
Features: - Add LinkedIn OAuth integration and auto-posting functionality - Add scheduler service for automated post publishing - Add metadata field to generated_posts for LinkedIn URLs - Add privacy policy page for LinkedIn API compliance - Add company management features and employee accounts - Add license key system for company registrations Fixes: - Fix timezone issues (use UTC consistently across app) - Fix datetime serialization errors in database operations - Fix scheduling timezone conversion (local time to UTC) - Fix import errors (get_database -> db) Infrastructure: - Update Docker setup to use port 8001 (avoid conflicts) - Add SSL support with nginx-proxy and Let's Encrypt - Add LinkedIn setup documentation - Add migration scripts for schema updates Services: - Add linkedin_service.py for LinkedIn API integration - Add scheduler_service.py for background job processing - Add storage_service.py for Supabase Storage - Add email_service.py improvements - Add encryption utilities for token storage Co-Authored-By: Claude Sonnet 4.5 <noreply@anthropic.com>
This commit is contained in:
536
config/fresh_migration.sql
Normal file
536
config/fresh_migration.sql
Normal file
@@ -0,0 +1,536 @@
|
||||
-- ==================== 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
|
||||
94
config/migrate_add_license_system.sql
Normal file
94
config/migrate_add_license_system.sql
Normal file
@@ -0,0 +1,94 @@
|
||||
-- Migration: Add License Key System with Company Limits
|
||||
-- This migration adds:
|
||||
-- 1. license_keys table for managing license keys
|
||||
-- 2. company_daily_quotas table for tracking daily usage
|
||||
-- 3. license_key_id reference in companies table
|
||||
|
||||
-- ==================== 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');
|
||||
|
||||
-- ==================== EXTEND COMPANIES TABLE ====================
|
||||
|
||||
-- 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 ====================
|
||||
|
||||
-- Track daily usage per company
|
||||
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 ====================
|
||||
|
||||
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();
|
||||
68
config/migrate_add_linkedin_accounts.sql
Normal file
68
config/migrate_add_linkedin_accounts.sql
Normal file
@@ -0,0 +1,68 @@
|
||||
-- Migration: Add LinkedIn accounts for auto-posting
|
||||
-- Description: Allows employees to link their LinkedIn accounts for automatic post publishing
|
||||
|
||||
CREATE TABLE IF NOT EXISTS linkedin_accounts (
|
||||
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(),
|
||||
|
||||
-- LinkedIn Identity
|
||||
linkedin_user_id TEXT NOT NULL,
|
||||
linkedin_vanity_name TEXT,
|
||||
linkedin_name TEXT,
|
||||
linkedin_picture TEXT,
|
||||
|
||||
-- OAuth Tokens (encrypted)
|
||||
access_token TEXT NOT NULL,
|
||||
refresh_token TEXT,
|
||||
token_expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
granted_scopes TEXT[] DEFAULT '{}',
|
||||
|
||||
-- Status
|
||||
is_active BOOLEAN DEFAULT TRUE,
|
||||
last_used_at TIMESTAMP WITH TIME ZONE,
|
||||
last_error TEXT,
|
||||
last_error_at TIMESTAMP WITH TIME ZONE,
|
||||
|
||||
UNIQUE(user_id) -- Only one account per user
|
||||
);
|
||||
|
||||
CREATE INDEX idx_linkedin_accounts_user_id ON linkedin_accounts(user_id);
|
||||
|
||||
-- Enable RLS
|
||||
ALTER TABLE linkedin_accounts ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Policy: Users can only see their own LinkedIn account
|
||||
CREATE POLICY "Users can view own linkedin account"
|
||||
ON linkedin_accounts FOR SELECT
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- Policy: Users can insert their own LinkedIn account
|
||||
CREATE POLICY "Users can insert own linkedin account"
|
||||
ON linkedin_accounts FOR INSERT
|
||||
WITH CHECK (auth.uid() = user_id);
|
||||
|
||||
-- Policy: Users can update their own LinkedIn account
|
||||
CREATE POLICY "Users can update own linkedin account"
|
||||
ON linkedin_accounts FOR UPDATE
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- Policy: Users can delete their own LinkedIn account
|
||||
CREATE POLICY "Users can delete own linkedin account"
|
||||
ON linkedin_accounts FOR DELETE
|
||||
USING (auth.uid() = user_id);
|
||||
|
||||
-- Function to update updated_at timestamp
|
||||
CREATE OR REPLACE FUNCTION update_linkedin_accounts_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER update_linkedin_accounts_updated_at
|
||||
BEFORE UPDATE ON linkedin_accounts
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_linkedin_accounts_updated_at();
|
||||
8
config/migrate_add_metadata_to_posts.sql
Normal file
8
config/migrate_add_metadata_to_posts.sql
Normal file
@@ -0,0 +1,8 @@
|
||||
-- Add metadata field to generated_posts table
|
||||
-- This field stores additional information like LinkedIn post URLs, auto-posting status, etc.
|
||||
|
||||
ALTER TABLE generated_posts
|
||||
ADD COLUMN IF NOT EXISTS metadata JSONB DEFAULT '{}'::JSONB;
|
||||
|
||||
-- Add comment
|
||||
COMMENT ON COLUMN generated_posts.metadata IS 'Additional metadata (LinkedIn post URL, auto-posting status, etc.)';
|
||||
314
config/migrate_remove_customers.sql
Normal file
314
config/migrate_remove_customers.sql
Normal file
@@ -0,0 +1,314 @@
|
||||
-- Migration: Remove customers table, move everything to user_id on profiles
|
||||
-- BACKUP YOUR DATABASE BEFORE RUNNING THIS!
|
||||
-- Run with: psql -d your_db -f config/migrate_remove_customers.sql
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- ============================================================
|
||||
-- 1. Add new columns to profiles (from customers)
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE profiles
|
||||
ADD COLUMN IF NOT EXISTS linkedin_url TEXT,
|
||||
ADD COLUMN IF NOT EXISTS writing_style_notes TEXT,
|
||||
ADD COLUMN IF NOT EXISTS metadata JSONB DEFAULT '{}'::JSONB,
|
||||
ADD COLUMN IF NOT EXISTS profile_picture TEXT,
|
||||
ADD COLUMN IF NOT EXISTS creator_email TEXT,
|
||||
ADD COLUMN IF NOT EXISTS customer_email TEXT,
|
||||
ADD COLUMN IF NOT EXISTS is_active BOOLEAN DEFAULT TRUE;
|
||||
|
||||
-- ============================================================
|
||||
-- 2. Migrate data from customers to profiles
|
||||
-- ============================================================
|
||||
|
||||
UPDATE profiles
|
||||
SET
|
||||
linkedin_url = c.linkedin_url,
|
||||
writing_style_notes = c.writing_style_notes,
|
||||
metadata = c.metadata,
|
||||
profile_picture = c.profile_picture,
|
||||
creator_email = c.creator_email,
|
||||
customer_email = c.customer_email,
|
||||
is_active = c.is_active
|
||||
FROM customers c
|
||||
WHERE profiles.customer_id = c.id;
|
||||
|
||||
-- Also populate display_name from customer.name where profiles.display_name is null
|
||||
UPDATE profiles
|
||||
SET display_name = c.name
|
||||
FROM customers c
|
||||
WHERE profiles.customer_id = c.id
|
||||
AND profiles.display_name IS NULL;
|
||||
|
||||
-- ============================================================
|
||||
-- 3. Add user_id column to all content tables
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE linkedin_profiles
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE linkedin_posts
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE topics
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE post_types
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE profile_analyses
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE research_results
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE generated_posts
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE example_posts
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE reference_profiles
|
||||
ADD COLUMN IF NOT EXISTS user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
-- ============================================================
|
||||
-- 4. Populate user_id via profiles.customer_id mapping
|
||||
-- ============================================================
|
||||
|
||||
UPDATE linkedin_profiles lp
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE lp.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE linkedin_posts lp
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE lp.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE topics t
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE t.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE post_types pt
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE pt.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE profile_analyses pa
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE pa.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE research_results rr
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE rr.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE generated_posts gp
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE gp.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE example_posts ep
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE ep.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
UPDATE reference_profiles rp
|
||||
SET user_id = p.id
|
||||
FROM profiles p
|
||||
WHERE rp.customer_id = p.customer_id
|
||||
AND p.customer_id IS NOT NULL;
|
||||
|
||||
-- ============================================================
|
||||
-- 5. Drop old unique constraints (customer_id based)
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE linkedin_profiles DROP CONSTRAINT IF EXISTS linkedin_profiles_customer_id_key;
|
||||
ALTER TABLE profile_analyses DROP CONSTRAINT IF EXISTS profile_analyses_customer_id_key;
|
||||
ALTER TABLE post_types DROP CONSTRAINT IF EXISTS post_types_customer_id_name_key;
|
||||
ALTER TABLE linkedin_posts DROP CONSTRAINT IF EXISTS linkedin_posts_customer_id_post_url_key;
|
||||
ALTER TABLE reference_profiles DROP CONSTRAINT IF EXISTS reference_profiles_customer_id_linkedin_url_key;
|
||||
|
||||
-- ============================================================
|
||||
-- 6. Set user_id NOT NULL (after data migration)
|
||||
-- ============================================================
|
||||
|
||||
-- Delete orphan rows that have no user_id (data without a profile link)
|
||||
DELETE FROM linkedin_profiles WHERE user_id IS NULL;
|
||||
DELETE FROM linkedin_posts WHERE user_id IS NULL;
|
||||
DELETE FROM topics WHERE user_id IS NULL;
|
||||
DELETE FROM post_types WHERE user_id IS NULL;
|
||||
DELETE FROM profile_analyses WHERE user_id IS NULL;
|
||||
DELETE FROM research_results WHERE user_id IS NULL;
|
||||
DELETE FROM generated_posts WHERE user_id IS NULL;
|
||||
DELETE FROM example_posts WHERE user_id IS NULL;
|
||||
DELETE FROM reference_profiles WHERE user_id IS NULL;
|
||||
|
||||
ALTER TABLE linkedin_profiles ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE linkedin_posts ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE topics ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE post_types ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE profile_analyses ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE research_results ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE generated_posts ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE example_posts ALTER COLUMN user_id SET NOT NULL;
|
||||
ALTER TABLE reference_profiles ALTER COLUMN user_id SET NOT NULL;
|
||||
|
||||
-- ============================================================
|
||||
-- 7. Add new unique constraints (user_id based)
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE linkedin_profiles ADD CONSTRAINT linkedin_profiles_user_id_key UNIQUE (user_id);
|
||||
ALTER TABLE profile_analyses ADD CONSTRAINT profile_analyses_user_id_key UNIQUE (user_id);
|
||||
ALTER TABLE post_types ADD CONSTRAINT post_types_user_id_name_key UNIQUE (user_id, name);
|
||||
ALTER TABLE linkedin_posts ADD CONSTRAINT linkedin_posts_user_id_post_url_key UNIQUE (user_id, post_url);
|
||||
ALTER TABLE reference_profiles ADD CONSTRAINT reference_profiles_user_id_linkedin_url_key UNIQUE (user_id, linkedin_url);
|
||||
|
||||
-- ============================================================
|
||||
-- 8. Drop RLS policies that reference customer_id
|
||||
-- ============================================================
|
||||
|
||||
-- Drop ALL policies on generated_posts (we'll recreate them with user_id)
|
||||
DROP POLICY IF EXISTS "Users can manage posts of their customers" ON generated_posts;
|
||||
DROP POLICY IF EXISTS "Company members can view company posts" ON generated_posts;
|
||||
DROP POLICY IF EXISTS "Service role has full access to generated_posts" ON generated_posts;
|
||||
|
||||
-- Drop policies on customers table (will be dropped anyway)
|
||||
DROP POLICY IF EXISTS "Users can manage own customers" ON customers;
|
||||
DROP POLICY IF EXISTS "Company members can view company customers" ON customers;
|
||||
DROP POLICY IF EXISTS "Service role has full access to customers" ON customers;
|
||||
|
||||
-- ============================================================
|
||||
-- 8b. Drop users view (depends on profiles.customer_id)
|
||||
-- ============================================================
|
||||
|
||||
DROP VIEW IF EXISTS users;
|
||||
|
||||
-- ============================================================
|
||||
-- 9. Drop old customer_id columns from content tables
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE linkedin_profiles DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE linkedin_posts DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE topics DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE post_types DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE profile_analyses DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE research_results DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE generated_posts DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE example_posts DROP COLUMN IF EXISTS customer_id;
|
||||
ALTER TABLE reference_profiles DROP COLUMN IF EXISTS customer_id;
|
||||
|
||||
-- Drop customer_id from profiles
|
||||
ALTER TABLE profiles DROP COLUMN IF EXISTS customer_id;
|
||||
|
||||
-- Drop customer_id from api_usage_logs
|
||||
ALTER TABLE api_usage_logs DROP COLUMN IF EXISTS customer_id;
|
||||
|
||||
-- ============================================================
|
||||
-- 10. Create new RLS policies using user_id
|
||||
-- ============================================================
|
||||
|
||||
-- Generated posts policies (using user_id instead of customer_id)
|
||||
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');
|
||||
|
||||
-- ============================================================
|
||||
-- 11. Drop old indexes and create new ones
|
||||
-- ============================================================
|
||||
|
||||
DROP INDEX IF EXISTS idx_linkedin_profiles_customer_id;
|
||||
DROP INDEX IF EXISTS idx_linkedin_posts_customer_id;
|
||||
DROP INDEX IF EXISTS idx_topics_customer_id;
|
||||
DROP INDEX IF EXISTS idx_post_types_customer_id;
|
||||
DROP INDEX IF EXISTS idx_profile_analyses_customer_id;
|
||||
DROP INDEX IF EXISTS idx_research_results_customer_id;
|
||||
DROP INDEX IF EXISTS idx_generated_posts_customer_id;
|
||||
DROP INDEX IF EXISTS idx_example_posts_customer_id;
|
||||
DROP INDEX IF EXISTS idx_reference_profiles_customer_id;
|
||||
DROP INDEX IF EXISTS idx_profiles_customer_id;
|
||||
DROP INDEX IF EXISTS idx_customers_linkedin_url;
|
||||
DROP INDEX IF EXISTS idx_customers_user_id;
|
||||
DROP INDEX IF EXISTS idx_customers_company_id;
|
||||
DROP INDEX IF EXISTS idx_api_usage_logs_customer_id;
|
||||
|
||||
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_post_types_user_id ON post_types(user_id);
|
||||
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_generated_posts_user_id ON generated_posts(user_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);
|
||||
|
||||
-- ============================================================
|
||||
-- 12. Drop customers table
|
||||
-- ============================================================
|
||||
|
||||
-- Remove trigger first
|
||||
DROP TRIGGER IF EXISTS update_customers_updated_at ON customers;
|
||||
|
||||
DROP TABLE IF EXISTS customers CASCADE;
|
||||
|
||||
-- ============================================================
|
||||
-- 13. Recreate users view (without customer_id)
|
||||
-- ============================================================
|
||||
|
||||
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;
|
||||
|
||||
COMMIT;
|
||||
7
config/migrate_remove_linkedin_unique.sql
Normal file
7
config/migrate_remove_linkedin_unique.sql
Normal file
@@ -0,0 +1,7 @@
|
||||
-- Migration: Remove UNIQUE constraint from customers.linkedin_url
|
||||
-- This allows multiple customers (different ghostwriters/companies) to share the same LinkedIn URL.
|
||||
-- Each user context gets its own independent Customer record.
|
||||
|
||||
ALTER TABLE customers DROP CONSTRAINT IF EXISTS customers_linkedin_url_key;
|
||||
|
||||
-- The existing index idx_customers_linkedin_url remains for fast lookups (non-unique).
|
||||
210
config/migrate_to_supabase_auth.sql
Normal file
210
config/migrate_to_supabase_auth.sql
Normal file
@@ -0,0 +1,210 @@
|
||||
-- Migration Script: From custom users table to Supabase Auth
|
||||
-- ============================================================
|
||||
-- IMPORTANT: Run these steps IN ORDER, one at a time!
|
||||
-- ============================================================
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 1: Backup the old users table (run this first!)
|
||||
-- ============================================================
|
||||
|
||||
-- Create backup of existing users table
|
||||
CREATE TABLE IF NOT EXISTS users_backup AS SELECT * FROM users;
|
||||
|
||||
-- Verify backup was created
|
||||
SELECT COUNT(*) as backup_count FROM users_backup;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 2: Create profiles table
|
||||
-- ============================================================
|
||||
|
||||
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 TEXT NOT NULL DEFAULT 'ghostwriter',
|
||||
display_name TEXT,
|
||||
onboarding_status TEXT DEFAULT 'pending',
|
||||
onboarding_data JSONB DEFAULT '{}'::JSONB,
|
||||
customer_id UUID,
|
||||
company_id UUID
|
||||
);
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 3: Drop constraints that reference the old users table
|
||||
-- ============================================================
|
||||
|
||||
-- Drop FK constraints from companies table
|
||||
ALTER TABLE companies DROP CONSTRAINT IF EXISTS companies_owner_user_id_fkey;
|
||||
|
||||
-- Drop FK constraints from invitations table
|
||||
ALTER TABLE invitations DROP CONSTRAINT IF EXISTS invitations_invited_by_user_id_fkey;
|
||||
ALTER TABLE invitations DROP CONSTRAINT IF EXISTS invitations_accepted_by_user_id_fkey;
|
||||
|
||||
-- Drop FK constraints from customers table
|
||||
ALTER TABLE customers DROP CONSTRAINT IF EXISTS customers_user_id_fkey;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 4: Rename old users table
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE IF EXISTS users RENAME TO users_old;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 5: Create the users VIEW
|
||||
-- ============================================================
|
||||
|
||||
CREATE OR REPLACE VIEW users AS
|
||||
SELECT
|
||||
p.id,
|
||||
p.created_at,
|
||||
p.updated_at,
|
||||
au.email,
|
||||
NULL::TEXT as password_hash,
|
||||
CASE
|
||||
WHEN au.raw_app_meta_data->>'provider' = 'linkedin_oidc' THEN 'linkedin_oauth'
|
||||
ELSE 'email_password'
|
||||
END as auth_method,
|
||||
au.raw_user_meta_data->>'sub' as linkedin_sub,
|
||||
au.raw_user_meta_data->>'vanityName' as linkedin_vanity_name,
|
||||
COALESCE(au.raw_user_meta_data->>'name', au.raw_user_meta_data->>'full_name') as linkedin_name,
|
||||
au.raw_user_meta_data->>'picture' as linkedin_picture,
|
||||
p.account_type,
|
||||
p.display_name,
|
||||
p.onboarding_status,
|
||||
p.onboarding_data,
|
||||
p.customer_id,
|
||||
p.company_id,
|
||||
au.email_confirmed_at IS NOT NULL as email_verified,
|
||||
NULL::TEXT as email_verification_token,
|
||||
NULL::TIMESTAMP WITH TIME ZONE as email_verification_expires_at
|
||||
FROM profiles p
|
||||
JOIN auth.users au ON p.id = au.id;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 6: Create the trigger for new users
|
||||
-- ============================================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.handle_new_user()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
INSERT INTO public.profiles (id, account_type, onboarding_status, display_name)
|
||||
VALUES (
|
||||
NEW.id,
|
||||
COALESCE(NEW.raw_user_meta_data->>'account_type', 'ghostwriter'),
|
||||
'pending',
|
||||
NEW.raw_user_meta_data->>'display_name'
|
||||
)
|
||||
ON CONFLICT (id) DO NOTHING;
|
||||
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();
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 7: Re-add FK constraints pointing to auth.users
|
||||
-- ============================================================
|
||||
|
||||
-- Add FK to companies
|
||||
ALTER TABLE companies
|
||||
ADD CONSTRAINT companies_owner_user_id_fkey
|
||||
FOREIGN KEY (owner_user_id) REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
-- Add FK to invitations
|
||||
ALTER TABLE invitations
|
||||
ADD CONSTRAINT invitations_invited_by_user_id_fkey
|
||||
FOREIGN KEY (invited_by_user_id) REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE invitations
|
||||
ADD CONSTRAINT invitations_accepted_by_user_id_fkey
|
||||
FOREIGN KEY (accepted_by_user_id) REFERENCES auth.users(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK to customers
|
||||
ALTER TABLE customers
|
||||
ADD CONSTRAINT customers_user_id_fkey
|
||||
FOREIGN KEY (user_id) REFERENCES auth.users(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK from profiles to companies
|
||||
ALTER TABLE profiles
|
||||
ADD CONSTRAINT fk_profiles_company
|
||||
FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK from profiles to customers
|
||||
ALTER TABLE profiles
|
||||
ADD CONSTRAINT fk_profiles_customer
|
||||
FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE SET NULL;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 8: Create indexes on 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_customer_id ON profiles(customer_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_profiles_company_id ON profiles(company_id);
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 9: Create updated_at trigger for profiles
|
||||
-- ============================================================
|
||||
|
||||
-- Make sure the function exists
|
||||
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();
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 10: Enable RLS on profiles
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
-- Drop existing policies if they exist
|
||||
DROP POLICY IF EXISTS "Users can view own profile" ON profiles;
|
||||
DROP POLICY IF EXISTS "Users can update own profile" ON profiles;
|
||||
DROP POLICY IF EXISTS "Service role has full access to profiles" ON profiles;
|
||||
|
||||
-- Profiles: Users can read/update their own profile
|
||||
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);
|
||||
|
||||
-- Service role can do everything (for admin operations)
|
||||
CREATE POLICY "Service role has full access to profiles"
|
||||
ON profiles FOR ALL
|
||||
USING (true);
|
||||
|
||||
-- ============================================================
|
||||
-- DONE!
|
||||
--
|
||||
-- The old users table has been renamed to 'users_old'.
|
||||
-- A backup was created as 'users_backup'.
|
||||
--
|
||||
-- New users will be created via Supabase Auth and will
|
||||
-- automatically get a profile via the trigger.
|
||||
--
|
||||
-- To clean up later (after verifying everything works):
|
||||
-- DROP TABLE IF EXISTS users_old;
|
||||
-- DROP TABLE IF EXISTS users_backup;
|
||||
-- ============================================================
|
||||
|
||||
-- Verify the migration
|
||||
SELECT 'Migration complete!' as status;
|
||||
SELECT COUNT(*) as profiles_count FROM profiles;
|
||||
SELECT COUNT(*) as auth_users_count FROM auth.users;
|
||||
257
config/migrate_to_supabase_auth_v2.sql
Normal file
257
config/migrate_to_supabase_auth_v2.sql
Normal file
@@ -0,0 +1,257 @@
|
||||
-- Migration Script v2: From custom users table to Supabase Auth
|
||||
-- ============================================================
|
||||
-- This version handles orphaned references properly
|
||||
-- ============================================================
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 1: Backup tables
|
||||
-- ============================================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS users_backup AS SELECT * FROM users;
|
||||
CREATE TABLE IF NOT EXISTS customers_backup AS SELECT * FROM customers;
|
||||
CREATE TABLE IF NOT EXISTS companies_backup AS SELECT * FROM companies;
|
||||
CREATE TABLE IF NOT EXISTS invitations_backup AS SELECT * FROM invitations;
|
||||
|
||||
SELECT 'Backups created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 2: Create profiles table
|
||||
-- ============================================================
|
||||
|
||||
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 TEXT NOT NULL DEFAULT 'ghostwriter',
|
||||
display_name TEXT,
|
||||
onboarding_status TEXT DEFAULT 'pending',
|
||||
onboarding_data JSONB DEFAULT '{}'::JSONB,
|
||||
customer_id UUID,
|
||||
company_id UUID
|
||||
);
|
||||
|
||||
SELECT 'Profiles table created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 3: Drop ALL constraints that reference the old users table
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE companies DROP CONSTRAINT IF EXISTS companies_owner_user_id_fkey;
|
||||
ALTER TABLE invitations DROP CONSTRAINT IF EXISTS invitations_invited_by_user_id_fkey;
|
||||
ALTER TABLE invitations DROP CONSTRAINT IF EXISTS invitations_accepted_by_user_id_fkey;
|
||||
ALTER TABLE customers DROP CONSTRAINT IF EXISTS customers_user_id_fkey;
|
||||
|
||||
-- Also drop the FK from users to companies if it exists
|
||||
ALTER TABLE users DROP CONSTRAINT IF EXISTS fk_users_company;
|
||||
ALTER TABLE users DROP CONSTRAINT IF EXISTS users_company_id_fkey;
|
||||
|
||||
SELECT 'Old constraints dropped' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 4: Clear orphaned references BEFORE adding new constraints
|
||||
-- Set user_id to NULL where user doesn't exist in auth.users
|
||||
-- ============================================================
|
||||
|
||||
-- Clear customers.user_id where user doesn't exist in auth.users
|
||||
UPDATE customers
|
||||
SET user_id = NULL
|
||||
WHERE user_id IS NOT NULL
|
||||
AND user_id NOT IN (SELECT id FROM auth.users);
|
||||
|
||||
-- Clear companies.owner_user_id - but we can't set to NULL (NOT NULL constraint)
|
||||
-- So we need to delete companies with orphaned owners, or skip FK for now
|
||||
-- Let's check if there are any orphaned companies first
|
||||
SELECT 'Orphaned companies:' as info, COUNT(*) as count
|
||||
FROM companies
|
||||
WHERE owner_user_id NOT IN (SELECT id FROM auth.users);
|
||||
|
||||
-- Delete companies with orphaned owner_user_id (they can't be used anyway)
|
||||
DELETE FROM companies
|
||||
WHERE owner_user_id NOT IN (SELECT id FROM auth.users);
|
||||
|
||||
-- Clear invitations with orphaned user references
|
||||
UPDATE invitations
|
||||
SET accepted_by_user_id = NULL
|
||||
WHERE accepted_by_user_id IS NOT NULL
|
||||
AND accepted_by_user_id NOT IN (SELECT id FROM auth.users);
|
||||
|
||||
DELETE FROM invitations
|
||||
WHERE invited_by_user_id NOT IN (SELECT id FROM auth.users);
|
||||
|
||||
SELECT 'Orphaned references cleaned' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 5: Rename old users table
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE IF EXISTS users RENAME TO users_old;
|
||||
|
||||
SELECT 'Old users table renamed to users_old' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 6: Create the users VIEW
|
||||
-- ============================================================
|
||||
|
||||
CREATE OR REPLACE VIEW users AS
|
||||
SELECT
|
||||
p.id,
|
||||
p.created_at,
|
||||
p.updated_at,
|
||||
au.email,
|
||||
NULL::TEXT as password_hash,
|
||||
CASE
|
||||
WHEN au.raw_app_meta_data->>'provider' = 'linkedin_oidc' THEN 'linkedin_oauth'
|
||||
ELSE 'email_password'
|
||||
END as auth_method,
|
||||
au.raw_user_meta_data->>'sub' as linkedin_sub,
|
||||
au.raw_user_meta_data->>'vanityName' as linkedin_vanity_name,
|
||||
COALESCE(au.raw_user_meta_data->>'name', au.raw_user_meta_data->>'full_name') as linkedin_name,
|
||||
au.raw_user_meta_data->>'picture' as linkedin_picture,
|
||||
p.account_type,
|
||||
p.display_name,
|
||||
p.onboarding_status,
|
||||
p.onboarding_data,
|
||||
p.customer_id,
|
||||
p.company_id,
|
||||
au.email_confirmed_at IS NOT NULL as email_verified,
|
||||
NULL::TEXT as email_verification_token,
|
||||
NULL::TIMESTAMP WITH TIME ZONE as email_verification_expires_at
|
||||
FROM profiles p
|
||||
JOIN auth.users au ON p.id = au.id;
|
||||
|
||||
SELECT 'Users VIEW created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 7: Create the trigger for new users
|
||||
-- ============================================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.handle_new_user()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
INSERT INTO public.profiles (id, account_type, onboarding_status, display_name)
|
||||
VALUES (
|
||||
NEW.id,
|
||||
COALESCE(NEW.raw_user_meta_data->>'account_type', 'ghostwriter'),
|
||||
'pending',
|
||||
NEW.raw_user_meta_data->>'display_name'
|
||||
)
|
||||
ON CONFLICT (id) DO NOTHING;
|
||||
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();
|
||||
|
||||
SELECT 'Trigger created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 8: Add NEW FK constraints pointing to auth.users
|
||||
-- ============================================================
|
||||
|
||||
-- Add FK to customers (user_id can be NULL)
|
||||
ALTER TABLE customers
|
||||
ADD CONSTRAINT customers_user_id_fkey
|
||||
FOREIGN KEY (user_id) REFERENCES auth.users(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK to companies (only if there are no orphaned references)
|
||||
ALTER TABLE companies
|
||||
ADD CONSTRAINT companies_owner_user_id_fkey
|
||||
FOREIGN KEY (owner_user_id) REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
-- Add FK to invitations
|
||||
ALTER TABLE invitations
|
||||
ADD CONSTRAINT invitations_invited_by_user_id_fkey
|
||||
FOREIGN KEY (invited_by_user_id) REFERENCES auth.users(id) ON DELETE CASCADE;
|
||||
|
||||
ALTER TABLE invitations
|
||||
ADD CONSTRAINT invitations_accepted_by_user_id_fkey
|
||||
FOREIGN KEY (accepted_by_user_id) REFERENCES auth.users(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK from profiles to companies
|
||||
ALTER TABLE profiles
|
||||
ADD CONSTRAINT fk_profiles_company
|
||||
FOREIGN KEY (company_id) REFERENCES companies(id) ON DELETE SET NULL;
|
||||
|
||||
-- Add FK from profiles to customers
|
||||
ALTER TABLE profiles
|
||||
ADD CONSTRAINT fk_profiles_customer
|
||||
FOREIGN KEY (customer_id) REFERENCES customers(id) ON DELETE SET NULL;
|
||||
|
||||
SELECT 'New FK constraints added' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 9: Create indexes on 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_customer_id ON profiles(customer_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_profiles_company_id ON profiles(company_id);
|
||||
|
||||
SELECT 'Indexes created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 10: Create updated_at trigger for profiles
|
||||
-- ============================================================
|
||||
|
||||
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();
|
||||
|
||||
SELECT 'Updated_at trigger created' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- STEP 11: Enable RLS on profiles
|
||||
-- ============================================================
|
||||
|
||||
ALTER TABLE profiles ENABLE ROW LEVEL SECURITY;
|
||||
|
||||
DROP POLICY IF EXISTS "Users can view own profile" ON profiles;
|
||||
DROP POLICY IF EXISTS "Users can update own profile" ON profiles;
|
||||
DROP POLICY IF EXISTS "Service role has full access to profiles" ON profiles;
|
||||
|
||||
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 (true);
|
||||
|
||||
SELECT 'RLS enabled' as status;
|
||||
|
||||
-- ============================================================
|
||||
-- VERIFICATION
|
||||
-- ============================================================
|
||||
|
||||
SELECT 'Migration complete!' as status;
|
||||
SELECT 'Profiles count:' as info, COUNT(*) as count FROM profiles;
|
||||
SELECT 'Auth users count:' as info, COUNT(*) as count FROM auth.users;
|
||||
SELECT 'Customers with user_id:' as info, COUNT(*) as count FROM customers WHERE user_id IS NOT NULL;
|
||||
SELECT 'Companies count:' as info, COUNT(*) as count FROM companies;
|
||||
|
||||
-- ============================================================
|
||||
-- CLEANUP (run later after verifying everything works)
|
||||
-- ============================================================
|
||||
DROP TABLE IF EXISTS users_old;
|
||||
DROP TABLE IF EXISTS users_backup;
|
||||
DROP TABLE IF EXISTS customers_backup;
|
||||
DROP TABLE IF EXISTS companies_backup;
|
||||
DROP TABLE IF EXISTS invitations_backup;
|
||||
@@ -1,30 +1,92 @@
|
||||
-- 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";
|
||||
|
||||
-- Customers/Clients Table
|
||||
CREATE TABLE IF NOT EXISTS customers (
|
||||
id UUID PRIMARY wKEY DEFAULT uuid_generate_v4(),
|
||||
-- ==================== 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(),
|
||||
|
||||
-- Basic Info
|
||||
name TEXT NOT NULL,
|
||||
email TEXT,
|
||||
company_name TEXT,
|
||||
-- Account Type
|
||||
account_type TEXT NOT NULL DEFAULT 'ghostwriter', -- 'ghostwriter' | 'company' | 'employee'
|
||||
|
||||
-- LinkedIn Profile
|
||||
linkedin_url TEXT NOT NULL UNIQUE,
|
||||
-- Display name
|
||||
display_name TEXT,
|
||||
|
||||
-- Metadata
|
||||
metadata JSONB DEFAULT '{}'::JSONB
|
||||
-- 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(),
|
||||
customer_id UUID NOT NULL REFERENCES customers(id) ON DELETE CASCADE,
|
||||
user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE,
|
||||
scraped_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
|
||||
-- Profile Data
|
||||
@@ -37,123 +99,13 @@ CREATE TABLE IF NOT EXISTS linkedin_profiles (
|
||||
location TEXT,
|
||||
industry TEXT,
|
||||
|
||||
UNIQUE(customer_id)
|
||||
UNIQUE(user_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,
|
||||
|
||||
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
|
||||
);
|
||||
|
||||
-- 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'
|
||||
);
|
||||
|
||||
-- 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
|
||||
status TEXT DEFAULT 'draft' CHECK (status IN ('draft', 'approved', 'published', 'rejected')),
|
||||
approved_at TIMESTAMP WITH TIME ZONE,
|
||||
published_at TIMESTAMP WITH TIME ZONE
|
||||
);
|
||||
|
||||
-- Create Indexes
|
||||
CREATE INDEX idx_customers_linkedin_url ON customers(linkedin_url);
|
||||
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_topics_customer_id ON topics(customer_id);
|
||||
CREATE INDEX idx_topics_is_used ON topics(is_used);
|
||||
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_generated_posts_customer_id ON generated_posts(customer_id);
|
||||
CREATE INDEX idx_generated_posts_status ON generated_posts(status);
|
||||
|
||||
-- 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,
|
||||
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(),
|
||||
|
||||
@@ -172,36 +124,228 @@ CREATE TABLE IF NOT EXISTS post_types (
|
||||
-- Status
|
||||
is_active BOOLEAN DEFAULT TRUE,
|
||||
|
||||
UNIQUE(customer_id, name)
|
||||
UNIQUE(user_id, name)
|
||||
);
|
||||
|
||||
-- Add post_type_id to linkedin_posts
|
||||
ALTER TABLE linkedin_posts
|
||||
ADD COLUMN IF NOT EXISTS post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL,
|
||||
ADD COLUMN IF NOT EXISTS classification_method TEXT,
|
||||
ADD COLUMN IF NOT EXISTS classification_confidence FLOAT;
|
||||
-- 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(),
|
||||
|
||||
-- Add target_post_type_id to topics
|
||||
ALTER TABLE topics
|
||||
ADD COLUMN IF NOT EXISTS target_post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL;
|
||||
-- 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,
|
||||
|
||||
-- Add target_post_type_id to research_results
|
||||
ALTER TABLE research_results
|
||||
ADD COLUMN IF NOT EXISTS target_post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL;
|
||||
-- Raw Data
|
||||
raw_data JSONB,
|
||||
|
||||
-- Add post_type_id to generated_posts
|
||||
ALTER TABLE generated_posts
|
||||
ADD COLUMN IF NOT EXISTS post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL;
|
||||
-- Classification
|
||||
post_type_id UUID REFERENCES post_types(id) ON DELETE SET NULL,
|
||||
classification_method TEXT,
|
||||
classification_confidence FLOAT,
|
||||
|
||||
-- Create indexes for post_types
|
||||
CREATE INDEX IF NOT EXISTS idx_post_types_customer_id ON post_types(customer_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_post_types_is_active ON post_types(is_active);
|
||||
CREATE INDEX IF NOT EXISTS idx_linkedin_posts_post_type_id ON linkedin_posts(post_type_id);
|
||||
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 updated_at trigger function
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
@@ -210,15 +354,196 @@ BEGIN
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Add trigger to customers table
|
||||
CREATE TRIGGER update_customers_updated_at
|
||||
BEFORE UPDATE ON customers
|
||||
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();
|
||||
|
||||
-- Add trigger to post_types table
|
||||
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();
|
||||
|
||||
Reference in New Issue
Block a user