295 lines
7.9 KiB
PL/PgSQL
295 lines
7.9 KiB
PL/PgSQL
-- ============================================================================
|
|
-- NOTIFICATION TRIGGERS
|
|
-- Automatically create notifications for appreciates, comments, mentions, chains
|
|
-- ============================================================================
|
|
|
|
-- ===========================================
|
|
-- 1. APPRECIATE (LIKE) NOTIFICATIONS
|
|
-- ===========================================
|
|
create or replace function handle_appreciate_notification()
|
|
returns trigger
|
|
language plpgsql
|
|
security definer
|
|
as $$
|
|
declare
|
|
post_author_id uuid;
|
|
begin
|
|
-- Get the post author
|
|
select author_id into post_author_id
|
|
from posts
|
|
where id = new.post_id;
|
|
|
|
-- Don't notify if user likes their own post
|
|
if post_author_id is null or post_author_id = new.user_id then
|
|
return new;
|
|
end if;
|
|
|
|
-- Insert notification
|
|
insert into notifications (user_id, type, actor_id, post_id, metadata)
|
|
values (
|
|
post_author_id,
|
|
'appreciate',
|
|
new.user_id,
|
|
new.post_id,
|
|
jsonb_build_object(
|
|
'post_id', new.post_id,
|
|
'liker_id', new.user_id
|
|
)
|
|
);
|
|
|
|
return new;
|
|
end;
|
|
$$;
|
|
|
|
drop trigger if exists appreciate_notification_trigger on post_likes;
|
|
create trigger appreciate_notification_trigger
|
|
after insert on post_likes
|
|
for each row execute function handle_appreciate_notification();
|
|
|
|
|
|
-- ===========================================
|
|
-- 2. COMMENT NOTIFICATIONS
|
|
-- ===========================================
|
|
create or replace function handle_comment_notification()
|
|
returns trigger
|
|
language plpgsql
|
|
security definer
|
|
as $$
|
|
declare
|
|
post_author_id uuid;
|
|
begin
|
|
-- Get the post author
|
|
select author_id into post_author_id
|
|
from posts
|
|
where id = new.post_id;
|
|
|
|
-- Don't notify if user comments on their own post
|
|
if post_author_id is null or post_author_id = new.author_id then
|
|
return new;
|
|
end if;
|
|
|
|
-- Insert notification
|
|
insert into notifications (user_id, type, actor_id, post_id, comment_id, metadata)
|
|
values (
|
|
post_author_id,
|
|
'comment',
|
|
new.author_id,
|
|
new.post_id,
|
|
new.id,
|
|
jsonb_build_object(
|
|
'post_id', new.post_id,
|
|
'comment_id', new.id,
|
|
'comment_preview', left(new.body, 100)
|
|
)
|
|
);
|
|
|
|
return new;
|
|
end;
|
|
$$;
|
|
|
|
drop trigger if exists comment_notification_trigger on comments;
|
|
create trigger comment_notification_trigger
|
|
after insert on comments
|
|
for each row execute function handle_comment_notification();
|
|
|
|
|
|
-- ===========================================
|
|
-- 3. MENTION NOTIFICATIONS
|
|
-- ===========================================
|
|
create or replace function handle_mention_notification()
|
|
returns trigger
|
|
language plpgsql
|
|
security definer
|
|
as $$
|
|
declare
|
|
mentioned_handle text;
|
|
mentioned_user_id uuid;
|
|
mention_matches text[];
|
|
begin
|
|
-- Extract @mentions from the body using regex
|
|
-- Matches @handle patterns (lowercase letters, numbers, underscores, 3-20 chars)
|
|
for mentioned_handle in
|
|
select (regexp_matches(new.body, '@([a-z0-9_]{3,20})', 'gi'))[1]
|
|
loop
|
|
-- Look up the mentioned user
|
|
select id into mentioned_user_id
|
|
from profiles
|
|
where lower(handle) = lower(mentioned_handle);
|
|
|
|
-- Skip if user not found or mentioning self
|
|
if mentioned_user_id is null or mentioned_user_id = new.author_id then
|
|
continue;
|
|
end if;
|
|
|
|
-- Insert mention notification (for comments)
|
|
insert into notifications (user_id, type, actor_id, post_id, comment_id, metadata)
|
|
values (
|
|
mentioned_user_id,
|
|
'mention',
|
|
new.author_id,
|
|
new.post_id,
|
|
new.id,
|
|
jsonb_build_object(
|
|
'post_id', new.post_id,
|
|
'comment_id', new.id,
|
|
'mentioned_in', 'comment',
|
|
'preview', left(new.body, 100)
|
|
)
|
|
)
|
|
on conflict do nothing; -- Avoid duplicate notifications
|
|
end loop;
|
|
|
|
return new;
|
|
end;
|
|
$$;
|
|
|
|
drop trigger if exists mention_notification_trigger on comments;
|
|
create trigger mention_notification_trigger
|
|
after insert on comments
|
|
for each row execute function handle_mention_notification();
|
|
|
|
|
|
-- Also handle mentions in posts
|
|
create or replace function handle_post_mention_notification()
|
|
returns trigger
|
|
language plpgsql
|
|
security definer
|
|
as $$
|
|
declare
|
|
mentioned_handle text;
|
|
mentioned_user_id uuid;
|
|
begin
|
|
-- Extract @mentions from the post body
|
|
for mentioned_handle in
|
|
select (regexp_matches(new.body, '@([a-z0-9_]{3,20})', 'gi'))[1]
|
|
loop
|
|
-- Look up the mentioned user
|
|
select id into mentioned_user_id
|
|
from profiles
|
|
where lower(handle) = lower(mentioned_handle);
|
|
|
|
-- Skip if user not found or mentioning self
|
|
if mentioned_user_id is null or mentioned_user_id = new.author_id then
|
|
continue;
|
|
end if;
|
|
|
|
-- Insert mention notification (for posts)
|
|
insert into notifications (user_id, type, actor_id, post_id, metadata)
|
|
values (
|
|
mentioned_user_id,
|
|
'mention',
|
|
new.author_id,
|
|
new.id,
|
|
jsonb_build_object(
|
|
'post_id', new.id,
|
|
'mentioned_in', 'post',
|
|
'preview', left(new.body, 100)
|
|
)
|
|
)
|
|
on conflict do nothing;
|
|
end loop;
|
|
|
|
return new;
|
|
end;
|
|
$$;
|
|
|
|
drop trigger if exists post_mention_notification_trigger on posts;
|
|
create trigger post_mention_notification_trigger
|
|
after insert on posts
|
|
for each row execute function handle_post_mention_notification();
|
|
|
|
|
|
-- ===========================================
|
|
-- 4. CHAIN (REPOST) NOTIFICATIONS
|
|
-- ===========================================
|
|
create or replace function handle_chain_notification()
|
|
returns trigger
|
|
language plpgsql
|
|
security definer
|
|
as $$
|
|
declare
|
|
parent_author_id uuid;
|
|
begin
|
|
-- Only trigger if this is a chain (has parent)
|
|
if new.chain_parent_id is null then
|
|
return new;
|
|
end if;
|
|
|
|
-- Get the parent post author
|
|
select author_id into parent_author_id
|
|
from posts
|
|
where id = new.chain_parent_id;
|
|
|
|
-- Don't notify if user chains their own post
|
|
if parent_author_id is null or parent_author_id = new.author_id then
|
|
return new;
|
|
end if;
|
|
|
|
-- Insert notification
|
|
insert into notifications (user_id, type, actor_id, post_id, metadata)
|
|
values (
|
|
parent_author_id,
|
|
'chain',
|
|
new.author_id,
|
|
new.chain_parent_id, -- Reference the original post
|
|
jsonb_build_object(
|
|
'original_post_id', new.chain_parent_id,
|
|
'chain_post_id', new.id,
|
|
'chain_preview', left(new.body, 100)
|
|
)
|
|
);
|
|
|
|
return new;
|
|
end;
|
|
$$;
|
|
|
|
drop trigger if exists chain_notification_trigger on posts;
|
|
create trigger chain_notification_trigger
|
|
after insert on posts
|
|
for each row execute function handle_chain_notification();
|
|
|
|
|
|
-- ===========================================
|
|
-- 5. ADD UNIQUE CONSTRAINT TO PREVENT DUPLICATES
|
|
-- ===========================================
|
|
-- Prevent duplicate notifications for the same action
|
|
-- (e.g., user can't appreciate same post twice anyway, but this adds safety)
|
|
create unique index if not exists idx_notifications_unique_appreciate
|
|
on notifications (user_id, type, actor_id, post_id)
|
|
where type = 'appreciate' and comment_id is null;
|
|
|
|
create unique index if not exists idx_notifications_unique_comment
|
|
on notifications (user_id, type, actor_id, comment_id)
|
|
where type = 'comment' and comment_id is not null;
|
|
|
|
create unique index if not exists idx_notifications_unique_chain
|
|
on notifications (user_id, type, actor_id, (metadata->>'chain_post_id'))
|
|
where type = 'chain';
|
|
|
|
|
|
-- ===========================================
|
|
-- 6. ADD INDEX FOR FASTER NOTIFICATION QUERIES
|
|
-- ===========================================
|
|
create index if not exists idx_notifications_user_unread
|
|
on notifications (user_id, is_read, created_at desc)
|
|
where is_read = false;
|
|
|
|
create index if not exists idx_notifications_user_created
|
|
on notifications (user_id, created_at desc);
|
|
|
|
|
|
-- ===========================================
|
|
-- 7. ENABLE REALTIME FOR NOTIFICATIONS
|
|
-- ===========================================
|
|
-- This allows clients to subscribe to notification changes
|
|
do $$
|
|
begin
|
|
if not exists (
|
|
select 1 from pg_publication_tables
|
|
where pubname = 'supabase_realtime'
|
|
and tablename = 'notifications'
|
|
) then
|
|
alter publication supabase_realtime add table notifications;
|
|
end if;
|
|
end $$;
|