RBAC in place. Tailwind CSS working.
This commit is contained in:
102
supabase/migrations/20250717153538_setup_rbac.sql
Normal file
102
supabase/migrations/20250717153538_setup_rbac.sql
Normal file
@@ -0,0 +1,102 @@
|
||||
-- Create roles table
|
||||
CREATE TABLE IF NOT EXISTS public.roles (
|
||||
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
name VARCHAR(50) UNIQUE NOT NULL,
|
||||
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 REFERENCES auth.users(id) ON DELETE CASCADE PRIMARY KEY,
|
||||
first_name VARCHAR(100),
|
||||
last_name VARCHAR(100),
|
||||
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 DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
user_id UUID REFERENCES auth.users(id) ON DELETE CASCADE,
|
||||
role_id UUID REFERENCES public.roles(id) ON DELETE CASCADE,
|
||||
assigned_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
assigned_by UUID REFERENCES auth.users(id),
|
||||
UNIQUE(user_id, role_id)
|
||||
);
|
||||
|
||||
-- Insert default roles
|
||||
INSERT INTO public.roles (name, description) VALUES
|
||||
('admin', 'Administrator with full system access'),
|
||||
('user', 'Regular user with basic access'),
|
||||
('moderator', 'Moderator with limited administrative access')
|
||||
ON CONFLICT (name) DO NOTHING;
|
||||
|
||||
-- Enable RLS on all tables
|
||||
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;
|
||||
|
||||
-- Roles table policies
|
||||
CREATE POLICY "Anyone can view roles" ON public.roles FOR SELECT USING (true);
|
||||
|
||||
CREATE POLICY "Only admins can manage roles" ON public.roles FOR ALL USING (
|
||||
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 = 'admin'
|
||||
)
|
||||
);
|
||||
|
||||
-- User profiles policies
|
||||
CREATE POLICY "Users can view their own profile" ON public.user_profiles FOR SELECT USING (auth.uid() = id);
|
||||
|
||||
CREATE POLICY "Users can update their own profile" ON public.user_profiles FOR UPDATE USING (auth.uid() = id);
|
||||
|
||||
CREATE POLICY "Users can insert their own profile" ON public.user_profiles FOR INSERT WITH CHECK (auth.uid() = id);
|
||||
|
||||
CREATE POLICY "Admins can view all profiles" ON public.user_profiles FOR SELECT USING (
|
||||
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 = 'admin'
|
||||
)
|
||||
);
|
||||
|
||||
-- User roles policies
|
||||
CREATE POLICY "Users can view their own roles" ON public.user_roles FOR SELECT USING (auth.uid() = user_id);
|
||||
|
||||
CREATE POLICY "Admins can manage all user roles" ON public.user_roles FOR ALL USING (
|
||||
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 = 'admin'
|
||||
)
|
||||
);
|
||||
|
||||
-- Function to get user roles
|
||||
CREATE OR REPLACE FUNCTION get_user_roles(user_uuid UUID)
|
||||
RETURNS TABLE(role_name VARCHAR(50))
|
||||
LANGUAGE sql
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT r.name
|
||||
FROM public.user_roles ur
|
||||
JOIN public.roles r ON ur.role_id = r.id
|
||||
WHERE ur.user_id = user_uuid;
|
||||
$$;
|
||||
|
||||
-- Function to check if user has specific role
|
||||
CREATE OR REPLACE FUNCTION user_has_role(user_uuid UUID, role_name VARCHAR(50))
|
||||
RETURNS BOOLEAN
|
||||
LANGUAGE sql
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT EXISTS (
|
||||
SELECT 1
|
||||
FROM public.user_roles ur
|
||||
JOIN public.roles r ON ur.role_id = r.id
|
||||
WHERE ur.user_id = user_uuid AND r.name = role_name
|
||||
);
|
||||
$$;
|
||||
Reference in New Issue
Block a user