feat(01-02): create database migration with plans and profiles

- Create plans table with Free, Creator, Pro tiers
- Create profiles table with tenant_id for multi-tenant isolation
- Enable RLS on both tables (security critical)
- Add auto-profile trigger on auth.users insert
- Add helper functions: get_user_plan_features, get_user_plan_name
- Add performance indexes on tenant_id, plan_id, email

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
Michele
2026-01-31 03:25:48 +01:00
parent bfc5133683
commit f271d7fe7f

View File

@@ -0,0 +1,176 @@
-- Migration: 001_initial_auth_setup.sql
-- Purpose: Create plans, profiles tables with RLS for multi-tenant auth
-- Created: 2026-01-31
-- Phase: 01-foundation-auth, Plan: 02
-- ============================================
-- PLANS TABLE
-- ============================================
CREATE TABLE public.plans (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL UNIQUE CHECK (name IN ('free', 'creator', 'pro')),
display_name TEXT NOT NULL,
display_name_it TEXT NOT NULL, -- Italian display name
price_monthly INTEGER NOT NULL CHECK (price_monthly >= 0), -- cents
features JSONB NOT NULL DEFAULT '{}',
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Insert default plans
INSERT INTO public.plans (name, display_name, display_name_it, price_monthly, features) VALUES
('free', 'Free', 'Gratuito', 0, '{
"posts_per_month": 10,
"ai_models": ["gpt-4o-mini"],
"social_accounts": 1,
"image_generation": false,
"automation": false
}'),
('creator', 'Creator', 'Creator', 1900, '{
"posts_per_month": 50,
"ai_models": ["gpt-4o-mini", "gpt-4o", "claude-3-5-sonnet"],
"social_accounts": 3,
"image_generation": true,
"automation": "manual"
}'),
('pro', 'Pro', 'Pro', 4900, '{
"posts_per_month": 200,
"ai_models": ["gpt-4o-mini", "gpt-4o", "claude-3-5-sonnet", "claude-opus-4"],
"social_accounts": 10,
"image_generation": true,
"automation": "full"
}');
-- ============================================
-- PROFILES TABLE
-- ============================================
CREATE TABLE public.profiles (
id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
tenant_id UUID NOT NULL DEFAULT gen_random_uuid(),
plan_id UUID REFERENCES public.plans(id) NOT NULL DEFAULT (SELECT id FROM public.plans WHERE name = 'free'),
email TEXT NOT NULL,
full_name TEXT,
avatar_url TEXT,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Performance indexes
CREATE INDEX idx_profiles_tenant_id ON public.profiles(tenant_id);
CREATE INDEX idx_profiles_plan_id ON public.profiles(plan_id);
CREATE INDEX idx_profiles_email ON public.profiles(email);
-- ============================================
-- ROW LEVEL SECURITY
-- ============================================
-- Enable RLS on all tables (CRITICAL - never skip this)
ALTER TABLE public.plans ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.profiles ENABLE ROW LEVEL SECURITY;
-- Plans: Everyone can read (public info)
CREATE POLICY "Plans are viewable by everyone"
ON public.plans FOR SELECT
TO authenticated, anon
USING (true);
-- Profiles: Users can only read their own profile
-- IMPORTANT: Use (SELECT auth.uid()) for 99% performance improvement
CREATE POLICY "Users can read own profile"
ON public.profiles FOR SELECT
TO authenticated
USING ((SELECT auth.uid()) = id);
-- Profiles: Users can update their own profile
CREATE POLICY "Users can update own profile"
ON public.profiles FOR UPDATE
TO authenticated
USING ((SELECT auth.uid()) = id)
WITH CHECK ((SELECT auth.uid()) = id);
-- Profiles: System can insert (via trigger)
-- Note: INSERT policy needed because trigger runs as SECURITY DEFINER
CREATE POLICY "System can insert profiles"
ON public.profiles FOR INSERT
TO authenticated
WITH CHECK ((SELECT auth.uid()) = id);
-- ============================================
-- AUTO-CREATE PROFILE TRIGGER
-- ============================================
-- Function to create profile on user signup
CREATE OR REPLACE FUNCTION public.handle_new_user()
RETURNS TRIGGER AS $$
BEGIN
INSERT INTO public.profiles (id, email, tenant_id, full_name, avatar_url)
VALUES (
NEW.id,
NEW.email,
gen_random_uuid(), -- Each user gets unique tenant_id
COALESCE(NEW.raw_user_meta_data->>'full_name', NEW.raw_user_meta_data->>'name'),
NEW.raw_user_meta_data->>'avatar_url'
);
RETURN NEW;
END;
$$ LANGUAGE plpgsql SECURITY DEFINER;
-- Trigger on auth.users insert
CREATE TRIGGER on_auth_user_created
AFTER INSERT ON auth.users
FOR EACH ROW
EXECUTE FUNCTION public.handle_new_user();
-- ============================================
-- HELPER FUNCTIONS
-- ============================================
-- Function to get current user's plan features (for API limit checking)
CREATE OR REPLACE FUNCTION public.get_user_plan_features()
RETURNS JSONB
LANGUAGE SQL STABLE
SECURITY DEFINER
AS $$
SELECT p.features
FROM public.plans p
INNER JOIN public.profiles pr ON pr.plan_id = p.id
WHERE pr.id = (SELECT auth.uid());
$$;
-- Function to get current user's plan name
CREATE OR REPLACE FUNCTION public.get_user_plan_name()
RETURNS TEXT
LANGUAGE SQL STABLE
SECURITY DEFINER
AS $$
SELECT p.name
FROM public.plans p
INNER JOIN public.profiles pr ON pr.plan_id = p.id
WHERE pr.id = (SELECT auth.uid());
$$;
-- Function to update profile's updated_at timestamp
CREATE OR REPLACE FUNCTION public.update_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER profiles_updated_at
BEFORE UPDATE ON public.profiles
FOR EACH ROW
EXECUTE FUNCTION public.update_updated_at();
-- ============================================
-- GRANTS
-- ============================================
-- Grant usage to authenticated users
GRANT USAGE ON SCHEMA public TO authenticated;
GRANT SELECT ON public.plans TO authenticated;
GRANT SELECT, UPDATE ON public.profiles TO authenticated;
GRANT EXECUTE ON FUNCTION public.get_user_plan_features() TO authenticated;
GRANT EXECUTE ON FUNCTION public.get_user_plan_name() TO authenticated;