-- Users and Roles -- This migration creates user-related tables with clean separation -- ============================================= -- 1. 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() ); -- ============================================= -- 2. 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() ); -- ============================================= -- 3. 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) ); -- ============================================= -- 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(); -- Create trigger for updated_at on roles CREATE TRIGGER set_updated_at_roles BEFORE UPDATE ON public.roles 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'); -- ============================================= -- 9. USER MANAGEMENT FUNCTIONS -- ============================================= -- Function to create a new user with roles CREATE OR REPLACE FUNCTION public.create_user_with_roles( user_email TEXT, role_names TEXT[], temp_password TEXT ) RETURNS JSON AS $$ DECLARE new_user_id UUID; encrypted_pwd TEXT; role_name TEXT; role_id_val UUID; assigned_by_id UUID; result JSON; user_roles_array TEXT[]; BEGIN -- Generate new user ID new_user_id := uuid_generate_v4(); -- Encrypt the password encrypted_pwd := crypt(temp_password, gen_salt('bf')); -- Get the current user ID for assigned_by, but only if they have a profile -- Otherwise, use the new user ID (which we'll create next) SELECT id INTO assigned_by_id FROM public.user_profiles WHERE id = auth.uid(); -- If no valid assigned_by user found, use the new user ID (self-assigned) IF assigned_by_id IS NULL THEN assigned_by_id := new_user_id; END IF; -- Create user in auth.users INSERT INTO auth.users ( instance_id, id, aud, role, email, encrypted_password, email_confirmed_at, created_at, updated_at, confirmation_token, email_change, email_change_token_new, recovery_token ) VALUES ( '00000000-0000-0000-0000-000000000000', new_user_id, 'authenticated', 'authenticated', user_email, encrypted_pwd, NOW(), NOW(), NOW(), '', '', '', '' ); -- Create user profile INSERT INTO public.user_profiles (id, email, status) VALUES (new_user_id, user_email, 'active'); -- Assign roles user_roles_array := ARRAY[]::TEXT[]; FOREACH role_name IN ARRAY role_names LOOP -- Get role ID SELECT id INTO role_id_val FROM public.roles WHERE name = role_name; -- If role exists, assign it IF role_id_val IS NOT NULL THEN INSERT INTO public.user_roles (user_id, role_id, assigned_by) VALUES (new_user_id, role_id_val, assigned_by_id) ON CONFLICT (user_id, role_id) DO NOTHING; -- Add to roles array for return value user_roles_array := array_append(user_roles_array, role_name); END IF; END LOOP; -- Return the result as JSON result := json_build_object( 'user_id', new_user_id::TEXT, 'email', user_email, 'temp_password', temp_password, 'roles', user_roles_array, 'status', 'active' ); RETURN result; EXCEPTION WHEN unique_violation THEN RAISE EXCEPTION 'User with email % already exists', user_email; WHEN OTHERS THEN RAISE EXCEPTION 'Error creating user: %', SQLERRM; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Grant execute permission on the function GRANT EXECUTE ON FUNCTION public.create_user_with_roles(TEXT, TEXT[], TEXT) TO authenticated; -- Comment for documentation COMMENT ON FUNCTION public.create_user_with_roles(TEXT, TEXT[], TEXT) IS 'Creates a new user in auth.users, creates a profile in user_profiles, and assigns the specified roles. Returns user information including user_id, email, temp_password, roles, and status.';