225 lines
7.6 KiB
PL/PgSQL
225 lines
7.6 KiB
PL/PgSQL
--
|
|
-- For use with https://github.com/supabase/supabase/tree/master/examples/slack-clone/nextjs-slack-clone
|
|
--
|
|
|
|
-- Custom types
|
|
create type public.app_permission as enum ('channels.delete', 'messages.delete');
|
|
create type public.app_role as enum ('admin', 'moderator');
|
|
create type public.user_status as enum ('ONLINE', 'OFFLINE');
|
|
|
|
-- USERS
|
|
create table public.users (
|
|
id uuid references auth.users not null primary key, -- UUID from auth.users
|
|
username text,
|
|
status user_status default 'OFFLINE'::public.user_status
|
|
);
|
|
comment on table public.users is 'Profile data for each user.';
|
|
comment on column public.users.id is 'References the internal Supabase Auth user.';
|
|
|
|
-- CHANNELS
|
|
create table public.channels (
|
|
id bigint generated by default as identity primary key,
|
|
inserted_at timestamp with time zone default timezone('utc'::text, now()) not null,
|
|
slug text not null unique,
|
|
created_by uuid references public.users not null
|
|
);
|
|
comment on table public.channels is 'Topics and groups.';
|
|
|
|
-- MESSAGES
|
|
create table public.messages (
|
|
id bigint generated by default as identity primary key,
|
|
inserted_at timestamp with time zone default timezone('utc'::text, now()) not null,
|
|
message text,
|
|
user_id uuid references public.users not null,
|
|
channel_id bigint references public.channels on delete cascade not null
|
|
);
|
|
comment on table public.messages is 'Individual messages sent by each user.';
|
|
|
|
-- USER ROLES
|
|
create table public.user_roles (
|
|
id bigint generated by default as identity primary key,
|
|
user_id uuid references public.users on delete cascade not null,
|
|
role app_role not null,
|
|
unique (user_id, role)
|
|
);
|
|
comment on table public.user_roles is 'Application roles for each user.';
|
|
|
|
-- ROLE PERMISSIONS
|
|
create table public.role_permissions (
|
|
id bigint generated by default as identity primary key,
|
|
role app_role not null,
|
|
permission app_permission not null,
|
|
unique (role, permission)
|
|
);
|
|
comment on table public.role_permissions is 'Application permissions for each role.';
|
|
|
|
-- authorize with role-based access control (RBAC)
|
|
create function public.authorize(
|
|
requested_permission app_permission
|
|
)
|
|
returns boolean as $$
|
|
declare
|
|
bind_permissions int;
|
|
begin
|
|
select count(*)
|
|
from public.role_permissions
|
|
where role_permissions.permission = authorize.requested_permission
|
|
and role_permissions.role = (auth.jwt() ->> 'user_role')::public.app_role
|
|
into bind_permissions;
|
|
|
|
return bind_permissions > 0;
|
|
end;
|
|
$$ language plpgsql security definer set search_path = public;
|
|
|
|
-- Secure the tables
|
|
alter table public.users enable row level security;
|
|
alter table public.channels enable row level security;
|
|
alter table public.messages enable row level security;
|
|
alter table public.user_roles enable row level security;
|
|
alter table public.role_permissions enable row level security;
|
|
create policy "Allow logged-in read access" on public.users for select using ( auth.role() = 'authenticated' );
|
|
create policy "Allow individual insert access" on public.users for insert with check ( auth.uid() = id );
|
|
create policy "Allow individual update access" on public.users for update using ( auth.uid() = id );
|
|
create policy "Allow logged-in read access" on public.channels for select using ( auth.role() = 'authenticated' );
|
|
create policy "Allow individual insert access" on public.channels for insert with check ( auth.uid() = created_by );
|
|
create policy "Allow individual delete access" on public.channels for delete using ( auth.uid() = created_by );
|
|
create policy "Allow authorized delete access" on public.channels for delete using ( authorize('channels.delete') );
|
|
create policy "Allow logged-in read access" on public.messages for select using ( auth.role() = 'authenticated' );
|
|
create policy "Allow individual insert access" on public.messages for insert with check ( auth.uid() = user_id );
|
|
create policy "Allow individual update access" on public.messages for update using ( auth.uid() = user_id );
|
|
create policy "Allow individual delete access" on public.messages for delete using ( auth.uid() = user_id );
|
|
create policy "Allow authorized delete access" on public.messages for delete using ( authorize('messages.delete') );
|
|
create policy "Allow individual read access" on public.user_roles for select using ( auth.uid() = user_id );
|
|
|
|
-- Send "previous data" on change
|
|
alter table public.users replica identity full;
|
|
alter table public.channels replica identity full;
|
|
alter table public.messages replica identity full;
|
|
|
|
-- inserts a row into public.users and assigns roles
|
|
create function public.handle_new_user()
|
|
returns trigger as $$
|
|
declare is_admin boolean;
|
|
begin
|
|
insert into public.users (id, username)
|
|
values (new.id, new.email);
|
|
|
|
select count(*) = 1 from auth.users into is_admin;
|
|
|
|
if position('+supaadmin@' in new.email) > 0 then
|
|
insert into public.user_roles (user_id, role) values (new.id, 'admin');
|
|
elsif position('+supamod@' in new.email) > 0 then
|
|
insert into public.user_roles (user_id, role) values (new.id, 'moderator');
|
|
end if;
|
|
|
|
return new;
|
|
end;
|
|
$$ language plpgsql security definer set search_path = auth, public;
|
|
|
|
-- trigger the function every time a user is created
|
|
create trigger on_auth_user_created
|
|
after insert on auth.users
|
|
for each row execute procedure public.handle_new_user();
|
|
|
|
/**
|
|
* REALTIME SUBSCRIPTIONS
|
|
* Only allow realtime listening on public tables.
|
|
*/
|
|
|
|
begin;
|
|
-- remove the realtime publication
|
|
drop publication if exists supabase_realtime;
|
|
|
|
-- re-create the publication but don't enable it for any tables
|
|
create publication supabase_realtime;
|
|
commit;
|
|
|
|
-- add tables to the publication
|
|
alter publication supabase_realtime add table public.channels;
|
|
alter publication supabase_realtime add table public.messages;
|
|
alter publication supabase_realtime add table public.users;
|
|
|
|
/**
|
|
* AUTH HOOKS
|
|
* Create an auth hook to add a custom claim to the access token jwt.
|
|
*/
|
|
|
|
-- Create the auth hook function
|
|
-- https://supabase.com/docs/guides/auth/auth-hooks#hook-custom-access-token
|
|
create or replace function public.custom_access_token_hook(event jsonb)
|
|
returns jsonb
|
|
language plpgsql
|
|
stable
|
|
as $$
|
|
declare
|
|
claims jsonb;
|
|
user_role public.app_role;
|
|
begin
|
|
-- Check if the user is marked as admin in the profiles table
|
|
select role into user_role from public.user_roles where user_id = (event->>'user_id')::uuid;
|
|
|
|
claims := event->'claims';
|
|
|
|
if user_role is not null then
|
|
-- Set the claim
|
|
claims := jsonb_set(claims, '{user_role}', to_jsonb(user_role));
|
|
else
|
|
claims := jsonb_set(claims, '{user_role}', 'null');
|
|
end if;
|
|
|
|
-- Update the 'claims' object in the original event
|
|
event := jsonb_set(event, '{claims}', claims);
|
|
|
|
-- Return the modified or original event
|
|
return event;
|
|
end;
|
|
$$;
|
|
|
|
grant usage on schema public to supabase_auth_admin;
|
|
|
|
grant execute
|
|
on function public.custom_access_token_hook
|
|
to supabase_auth_admin;
|
|
|
|
revoke execute
|
|
on function public.custom_access_token_hook
|
|
from authenticated, anon, public;
|
|
|
|
grant all
|
|
on table public.user_roles
|
|
to supabase_auth_admin;
|
|
|
|
revoke all
|
|
on table public.user_roles
|
|
from authenticated, anon, public;
|
|
|
|
create policy "Allow auth admin to read user roles" ON public.user_roles
|
|
as permissive for select
|
|
to supabase_auth_admin
|
|
using (true)
|
|
|
|
|
|
/**
|
|
* HELPER FUNCTIONS
|
|
* Create test user helper method.
|
|
*/
|
|
create or replace function public.create_user(
|
|
email text
|
|
) returns uuid
|
|
security definer
|
|
set search_path = auth
|
|
as $$
|
|
declare
|
|
user_id uuid;
|
|
begin
|
|
user_id := extensions.uuid_generate_v4();
|
|
|
|
insert into auth.users (id, email)
|
|
values (user_id, email)
|
|
returning id into user_id;
|
|
|
|
return user_id;
|
|
end;
|
|
$$ language plpgsql;
|
|
|