Files
next-template/scripts/supabase/db/schema.sql
2025-07-09 15:33:45 -05:00

136 lines
4.0 KiB
PL/PgSQL

create table statuses (
id uuid default gen_random_uuid() primary key,
user_id uuid references auth.users on delete cascade not null,
updated_by_id uuid references auth.users on delete set null,
created_at timestamp with time zone default now() not null,
status text not null,
constraint status_length check (char_length(status) >= 3 and char_length(status) <= 80)
);
create table profiles (
id uuid references auth.users on delete cascade not null primary key,
updated_at timestamp with time zone,
email text unique,
full_name text,
avatar_url text,
provider text,
current_status_id uuid references statuses(id) on delete set null,
constraint full_name_length check (char_length(full_name) >= 3 and char_length(full_name) <= 50)
);
alter table profiles
enable row level security;
create policy "Public profiles are viewable by everyone." on profiles
for select using (true);
create policy "Users can insert their own profile." on profiles
for insert with check ((select auth.uid()) = id);
create policy "Users can update own profile." on profiles
for update using ((select auth.uid()) = id);
-- set up row level security (rls) for statuses
alter table statuses
enable row level security;
-- policies for statuses
create policy "Public statuses are viewable by everyone." on statuses
for select using (true);
create policy "Authenticated users can insert statuses for any user."
on public.statuses
for insert
with check (
(select auth.role()) = 'authenticated'
);
create policy "Authenticated users can update statuses for any user."
on public.statuses
for update
using (
(select auth.role()) = 'authenticated'
)
with check (
(select auth.role()) = 'authenticated'
);
-- function to handle new user creation
create function public.handle_new_user()
returns trigger
set search_path = ''
as $$
declare
new_status_id uuid;
begin
-- first create the profile
insert into public.profiles (id, email, full_name, avatar_url, provider, updated_at)
values (
new.id,
new.email,
new.raw_user_meta_data->>'full_name',
new.raw_user_meta_data->>'avatar_url',
new.raw_user_meta_data->>'provider',
now()
);
-- then create the first status
insert into public.statuses (user_id, updated_by_id, status)
values (
new.id,
new.id,
'Just joined!'
) returning id into new_status_id;
-- update the profile with the current status
update public.profiles
set current_status_id = new_status_id
where id = new.id;
return new;
end;
$$ language plpgsql security definer;
-- function to update profile when status changes
create function public.update_profile_current_status()
returns trigger
set search_path = ''
as $$
begin
-- update the profile's current_status_id to the most recent status
update public.profiles
set current_status_id = (
select id
from public.statuses
where user_id = new.user_id
order by created_at desc
limit 1
)
where id = new.user_id;
return new;
end;
$$ language plpgsql security definer;
-- triggers
create trigger on_auth_user_created
after insert on auth.users
for each row execute procedure public.handle_new_user();
create trigger on_status_insert_or_update
after insert or update on public.statuses
for each row execute procedure public.update_profile_current_status();
-- set up storage with public access!
insert into storage.buckets (id, name, public)
values ('avatars', 'avatars', true);
-- set up access controls for storage (adjusted for public access)
create policy "Avatar images are publicly accessible." on storage.objects
for select using (bucket_id = 'avatars');
create policy "Anyone can upload an avatar." on storage.objects
for insert with check (bucket_id = 'avatars');
create policy "Anyone can update an avatar." on storage.objects
for update using (bucket_id = 'avatars');
create policy "Anyone can delete an avatar." on storage.objects
for delete using (bucket_id = 'avatars');
-- enable realtime
alter publication supabase_realtime add table profiles;
alter publication supabase_realtime add table statuses;