sojorn/_legacy/supabase/migrations/20260117_private_follow_model.sql
2026-02-15 00:33:24 -06:00

175 lines
3.8 KiB
PL/PgSQL

-- Private-by-default follow model + mutuals enforcement
-- 1) Profiles: add privacy/official flags
alter table if exists profiles
add column if not exists is_private boolean not null default true,
add column if not exists is_official boolean not null default false;
-- 2) Follows: add status and constraint
alter table if exists follows
add column if not exists status text not null default 'accepted';
do $$
begin
if not exists (
select 1
from pg_constraint
where conname = 'follows_status_check'
) then
alter table follows
add constraint follows_status_check
check (status in ('pending', 'accepted'));
end if;
end $$;
-- 3) Request follow function (privacy-aware)
create or replace function request_follow(target_id uuid)
returns text
language plpgsql
security definer
as $$
declare
existing_status text;
target_private boolean;
target_official boolean;
new_status text;
begin
if auth.uid() is null then
raise exception 'Not authenticated';
end if;
select status into existing_status
from follows
where follower_id = auth.uid()
and following_id = target_id;
if existing_status is not null then
return existing_status;
end if;
select is_private, is_official
into target_private, target_official
from profiles
where id = target_id;
if target_private is null then
raise exception 'Target profile not found';
end if;
if target_official or target_private = false then
new_status := 'accepted';
else
new_status := 'pending';
end if;
insert into follows (follower_id, following_id, status)
values (auth.uid(), target_id, new_status);
return new_status;
end;
$$;
-- 4) Mutual follow must be accepted on both sides
create or replace function is_mutual_follow(user_a uuid, user_b uuid)
returns boolean
language plpgsql
security definer
as $$
begin
return exists (
select 1
from follows f1
where f1.follower_id = user_a
and f1.following_id = user_b
and f1.status = 'accepted'
) and exists (
select 1
from follows f2
where f2.follower_id = user_b
and f2.following_id = user_a
and f2.status = 'accepted'
);
end;
$$;
-- 5) Follow request management helpers
create or replace function accept_follow_request(requester_id uuid)
returns void
language plpgsql
security definer
as $$
begin
if auth.uid() is null then
raise exception 'Not authenticated';
end if;
update follows
set status = 'accepted'
where follower_id = requester_id
and following_id = auth.uid();
end;
$$;
create or replace function reject_follow_request(requester_id uuid)
returns void
language plpgsql
security definer
as $$
begin
if auth.uid() is null then
raise exception 'Not authenticated';
end if;
delete from follows
where follower_id = requester_id
and following_id = auth.uid();
end;
$$;
create or replace function get_follow_requests()
returns table (
follower_id uuid,
handle text,
display_name text,
avatar_url text,
requested_at timestamptz
)
language sql
security definer
as $$
select
f.follower_id,
p.handle,
p.display_name,
p.avatar_url,
f.created_at as requested_at
from follows f
join profiles p on p.id = f.follower_id
where f.following_id = auth.uid()
and f.status = 'pending'
order by f.created_at desc;
$$;
-- 6) Posts RLS: allow self, public, or accepted follow
alter table if exists posts enable row level security;
drop policy if exists posts_select_private_model on posts;
create policy posts_select_private_model on posts
for select
using (
auth.uid() = author_id
or exists (
select 1
from profiles p
where p.id = author_id
and p.is_private = false
)
or exists (
select 1
from follows f
where f.follower_id = auth.uid()
and f.following_id = author_id
and f.status = 'accepted'
)
);