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:
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;
|
||||
Reference in New Issue
Block a user