-- User Management and Authentication -- This migration creates user-related tables, roles, and authentication structures -- ============================================= -- 1. EXTENSIONS -- ============================================= -- Enable UUID generation CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Enable password hashing CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- ============================================= -- 2. USER MANAGEMENT -- ============================================= -- Create roles table CREATE TABLE IF NOT EXISTS public.roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name TEXT NOT NULL UNIQUE, description TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create user profiles table CREATE TABLE IF NOT EXISTS public.user_profiles ( id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, email TEXT NOT NULL UNIQUE, first_name TEXT, last_name TEXT, status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create user roles junction table CREATE TABLE IF NOT EXISTS public.user_roles ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES public.user_profiles(id) ON DELETE CASCADE, role_id UUID NOT NULL REFERENCES public.roles(id) ON DELETE CASCADE, assigned_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), assigned_by UUID REFERENCES public.user_profiles(id), UNIQUE(user_id, role_id) ); -- ============================================= -- 3. UTILITY FUNCTIONS -- ============================================= -- Function to handle updated_at timestamp CREATE OR REPLACE FUNCTION public.handle_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Helper function to get current user's roles CREATE OR REPLACE FUNCTION public.get_user_roles() RETURNS TEXT[] AS $$ BEGIN RETURN ARRAY( SELECT r.name FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to get current user's first role (for backward compatibility) CREATE OR REPLACE FUNCTION public.get_user_role() RETURNS TEXT AS $$ BEGIN -- Return the first role found (for backward compatibility) RETURN ( SELECT r.name FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() LIMIT 1 ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user is admin CREATE OR REPLACE FUNCTION public.is_admin() RETURNS BOOLEAN AS $$ BEGIN RETURN 'admin' = ANY(public.get_user_roles()); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user has specific role CREATE OR REPLACE FUNCTION public.has_role(role_name TEXT) RETURNS BOOLEAN AS $$ BEGIN RETURN role_name = ANY(public.get_user_roles()); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Helper function to check if user can manage experiments CREATE OR REPLACE FUNCTION public.can_manage_experiments() RETURNS BOOLEAN AS $$ BEGIN RETURN EXISTS ( SELECT 1 FROM public.user_roles ur JOIN public.roles r ON ur.role_id = r.id WHERE ur.user_id = auth.uid() AND r.name IN ('admin', 'conductor') ); END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- ============================================= -- 4. INDEXES FOR PERFORMANCE -- ============================================= CREATE INDEX IF NOT EXISTS idx_user_profiles_email ON public.user_profiles(email); CREATE INDEX IF NOT EXISTS idx_user_roles_user_id ON public.user_roles(user_id); CREATE INDEX IF NOT EXISTS idx_user_roles_role_id ON public.user_roles(role_id); -- ============================================= -- 5. TRIGGERS -- ============================================= -- Create trigger for updated_at on user_profiles CREATE TRIGGER set_updated_at_user_profiles BEFORE UPDATE ON public.user_profiles FOR EACH ROW EXECUTE FUNCTION public.handle_updated_at(); -- ============================================= -- 6. GRANT PERMISSIONS -- ============================================= GRANT ALL ON public.roles TO authenticated; GRANT ALL ON public.user_profiles TO authenticated; GRANT ALL ON public.user_roles TO authenticated; -- ============================================= -- 7. ENABLE ROW LEVEL SECURITY -- ============================================= ALTER TABLE public.roles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_profiles ENABLE ROW LEVEL SECURITY; ALTER TABLE public.user_roles ENABLE ROW LEVEL SECURITY; -- ============================================= -- 8. CREATE RLS POLICIES -- ============================================= -- Create RLS policies for roles (read-only for all authenticated users) CREATE POLICY "Roles are viewable by authenticated users" ON public.roles FOR SELECT USING (auth.role() = 'authenticated'); -- Create RLS policies for user_profiles CREATE POLICY "User profiles are viewable by authenticated users" ON public.user_profiles FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "User profiles are insertable by authenticated users" ON public.user_profiles FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "User profiles are updatable by authenticated users" ON public.user_profiles FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "User profiles are deletable by authenticated users" ON public.user_profiles FOR DELETE USING (auth.role() = 'authenticated'); -- Create RLS policies for user_roles CREATE POLICY "User roles are viewable by authenticated users" ON public.user_roles FOR SELECT USING (auth.role() = 'authenticated'); CREATE POLICY "User roles are insertable by authenticated users" ON public.user_roles FOR INSERT WITH CHECK (auth.role() = 'authenticated'); CREATE POLICY "User roles are updatable by authenticated users" ON public.user_roles FOR UPDATE USING (auth.role() = 'authenticated'); CREATE POLICY "User roles are deletable by authenticated users" ON public.user_roles FOR DELETE USING (auth.role() = 'authenticated');