supabase: add initial migration

This commit is contained in:
2025-09-26 16:27:10 +02:00
parent 3957c346ed
commit f5ec337cf4

View File

@@ -0,0 +1,128 @@
create table profiles (
user_id uuid primary key references auth.users(id) on delete cascade,
user_type text not null check (user_type in ('brand', 'creator', 'admin'))
);
alter table profiles enable row level security;
create table brands (
profile_id uuid primary key references profiles(user_id) on delete cascade,
company_name text not null,
website text not null
);
alter table brands enable row level security;
create table creators (
profile_id uuid primary key references profiles(user_id) on delete cascade,
nickname text not null,
bio text,
social_links jsonb
);
alter table creators enable row level security;
create table admins (
profile_id uuid primary key references profiles(user_id) on delete cascade
);
alter table admins enable row level security;
-- based on raw_user_meta_data, create a profile and subprofile for new users
create function public.handle_new_user()
returns trigger
language plpgsql
security definer set search_path = ''
as $$
declare
user_type text;
begin
user_type := new.raw_user_meta_data ->> 'user_type';
if user_type is null or trim(user_type) = '' then
raise exception 'Missing required user_type in raw_user_meta_data';
end if;
insert into profiles (user_id, user_type) values (new.id, new.raw_user_meta_data ->> 'user_type');
if user_type = 'brand' then
insert into brands (profile_id, company_name, website)
values (new.id,
new.raw_user_meta_data ->> 'company_name',
new.raw_user_meta_data ->> 'website');
elsif user_type = 'creator' then
insert into creators (profile_id, nickname, bio, social_links)
values (new.id,
new.raw_user_meta_data ->> 'nickname',
new.raw_user_meta_data ->> 'bio',
new.raw_user_meta_data ->> 'social_links');
elsif user_type = 'admin' then
insert into admins (profile_id) values (new.id);
end if;
return new;
end;
$$;
create trigger on_auth_user_created
after insert on auth.users
for each row execute procedure public.handle_new_user();
-- keep validation on subprofiles
create or replace function public.enforce_profile_type(profile_id uuid, expected_type text)
returns void
language plpgsql
security definer set search_path = ''
as $$
declare
actual_type text;
begin
select user_type into actual_type
from profiles where user_id = profile_id;
if actual_type is null then
raise exception 'profile not found for id: %', profile_id;
end if;
if actual_type <> expected_type then
raise exception 'user_type mismatch: expected %, got %', expected_type, actual_type;
end if;
end;
$$;
create or replace function public.check_brand_user_type()
returns trigger
language plpgsql
security definer set search_path = ''
as $$ begin
perform public.enforce_profile_type(new.profile_id, 'brand');
return new;
end; $$;
create or replace function public.check_creator_user_type()
returns trigger
language plpgsql
security definer set search_path = ''
as $$ begin
perform public.enforce_profile_type(new.profile_id, 'creator');
return new;
end; $$;
create or replace function public.check_admin_user_type()
returns trigger
language plpgsql
security definer set search_path = ''
as $$ begin
perform public.enforce_profile_type(new.profile_id, 'admin');
return new;
end; $$;
create trigger check_brands_user_type
before insert or update
on brands
for each row
execute function public.check_brand_user_type();
create trigger check_creators_user_type
before insert or update
on creators
for each row
execute function public.check_creator_user_type();
create trigger check_admins_user_type
before insert or update
on admins
for each row
execute function public.check_admin_user_type();