Skip to content

Commit 70de9b9

Browse files
committed
feat: add bookmark support and track seen users
1 parent 5a0a2b9 commit 70de9b9

38 files changed

+1985
-195
lines changed
Lines changed: 71 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,71 @@
1+
-- Table: public.message_bookmarks
2+
-- Description: Stores user bookmarks for messages. Allows users to save messages for later reference and organize them.
3+
create table public.message_bookmarks (
4+
id bigint generated always as identity primary key,
5+
user_id uuid not null references public.users(id) on delete cascade,
6+
message_id uuid not null references public.messages(id) on delete cascade,
7+
created_at timestamp with time zone default timezone('utc', now()) not null,
8+
updated_at timestamp with time zone default timezone('utc', now()) not null,
9+
archived_at timestamp with time zone, -- When the bookmark was archived by the user
10+
marked_at timestamp with time zone, -- When the bookmark was marked as read by the user
11+
metadata jsonb default '{}'::jsonb, -- For future features like folders, tags, priority levels, etc.
12+
unique(user_id, message_id) -- Prevent users from bookmarking the same message multiple times
13+
);
14+
15+
comment on table public.message_bookmarks is 'Stores user bookmarks for messages, allowing users to save and organize messages for later reference with archive and read status tracking.';
16+
17+
-- Column comments for better documentation
18+
comment on column public.message_bookmarks.id is 'Unique identifier for the bookmark';
19+
comment on column public.message_bookmarks.user_id is 'Reference to the user who created this bookmark';
20+
comment on column public.message_bookmarks.message_id is 'Reference to the bookmarked message';
21+
comment on column public.message_bookmarks.created_at is 'Timestamp when the message was bookmarked';
22+
comment on column public.message_bookmarks.updated_at is 'Timestamp when the bookmark was last updated';
23+
comment on column public.message_bookmarks.archived_at is 'Timestamp when the bookmark was archived, null if active';
24+
comment on column public.message_bookmarks.marked_at is 'Timestamp when the bookmark was marked as read, null if unread';
25+
comment on column public.message_bookmarks.metadata is 'Additional configurable properties for organizing bookmarks (folders, tags, etc.)';
26+
27+
-- Indexes for performance
28+
create index message_bookmarks_user_id_idx on public.message_bookmarks (user_id);
29+
create index message_bookmarks_message_id_idx on public.message_bookmarks (message_id);
30+
create index message_bookmarks_created_at_idx on public.message_bookmarks (created_at desc);
31+
create index message_bookmarks_archived_at_idx on public.message_bookmarks (archived_at) where archived_at is not null;
32+
create index message_bookmarks_marked_at_idx on public.message_bookmarks (marked_at) where marked_at is not null;
33+
34+
-- Trigger to automatically update updated_at timestamp
35+
create or replace function update_message_bookmarks_updated_at()
36+
returns trigger as $$
37+
begin
38+
new.updated_at = timezone('utc', now());
39+
return new;
40+
end;
41+
$$ language plpgsql;
42+
43+
create trigger update_message_bookmarks_updated_at
44+
before update on public.message_bookmarks
45+
for each row
46+
execute function update_message_bookmarks_updated_at();
47+
48+
-- Enable Row Level Security
49+
alter table public.message_bookmarks enable row level security;
50+
51+
-- RLS Policies
52+
create policy "Users can view their own bookmarks"
53+
on public.message_bookmarks
54+
for select
55+
using (auth.uid() = user_id);
56+
57+
create policy "Users can create their own bookmarks"
58+
on public.message_bookmarks
59+
for insert
60+
with check (auth.uid() = user_id);
61+
62+
create policy "Users can update their own bookmarks"
63+
on public.message_bookmarks
64+
for update
65+
using (auth.uid() = user_id)
66+
with check (auth.uid() = user_id);
67+
68+
create policy "Users can delete their own bookmarks"
69+
on public.message_bookmarks
70+
for delete
71+
using (auth.uid() = user_id);
Lines changed: 309 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,309 @@
1+
-- Function: toggle_message_bookmark
2+
-- Description: Toggles a bookmark for a message. If bookmark exists, removes it. If not, creates it.
3+
create or replace function public.toggle_message_bookmark(
4+
p_message_id uuid
5+
)
6+
returns jsonb
7+
language plpgsql
8+
security definer
9+
set search_path = public
10+
as $$
11+
declare
12+
v_user_id uuid;
13+
v_bookmark_id bigint;
14+
v_action text;
15+
begin
16+
-- Get the current user ID
17+
v_user_id := auth.uid();
18+
19+
if v_user_id is null then
20+
raise exception 'User not authenticated';
21+
end if;
22+
23+
-- Check if bookmark already exists
24+
select id into v_bookmark_id
25+
from message_bookmarks
26+
where user_id = v_user_id and message_id = p_message_id;
27+
28+
if v_bookmark_id is not null then
29+
-- Bookmark exists, remove it
30+
delete from message_bookmarks
31+
where id = v_bookmark_id;
32+
v_action := 'removed';
33+
else
34+
-- Bookmark doesn't exist, create it
35+
insert into message_bookmarks (user_id, message_id)
36+
values (v_user_id, p_message_id)
37+
returning id into v_bookmark_id;
38+
v_action := 'added';
39+
end if;
40+
41+
return jsonb_build_object(
42+
'action', v_action,
43+
'bookmark_id', v_bookmark_id,
44+
'message_id', p_message_id
45+
);
46+
end;
47+
$$;
48+
49+
comment on function public.toggle_message_bookmark is 'Toggles a bookmark for a message. Returns the action taken (added/removed) and relevant IDs.';
50+
51+
-- Function: get_user_bookmarks
52+
-- Description: Gets all bookmarked messages for the current user with message details
53+
create or replace function public.get_user_bookmarks(
54+
p_workspace_id varchar(36) default null,
55+
p_archived boolean default false,
56+
p_limit int default 50,
57+
p_offset int default 0
58+
)
59+
returns table (
60+
bookmark_id bigint,
61+
bookmark_created_at timestamptz,
62+
bookmark_updated_at timestamptz,
63+
bookmark_archived_at timestamptz,
64+
bookmark_marked_at timestamptz,
65+
bookmark_metadata jsonb,
66+
message_id uuid,
67+
message_content text,
68+
message_html text,
69+
message_created_at timestamptz,
70+
message_user_id uuid,
71+
message_channel_id varchar,
72+
message_type message_type,
73+
user_details jsonb,
74+
channel_name text,
75+
channel_slug text,
76+
workspace_id varchar,
77+
workspace_name text,
78+
workspace_slug text
79+
)
80+
language plpgsql
81+
security definer
82+
set search_path = public
83+
as $$
84+
declare
85+
v_user_id uuid;
86+
begin
87+
-- Get the current user ID
88+
v_user_id := auth.uid();
89+
90+
if v_user_id is null then
91+
raise exception 'User not authenticated';
92+
end if;
93+
94+
return query
95+
select
96+
mb.id as bookmark_id,
97+
mb.created_at as bookmark_created_at,
98+
mb.updated_at as bookmark_updated_at,
99+
mb.archived_at as bookmark_archived_at,
100+
mb.marked_at as bookmark_marked_at,
101+
mb.metadata as bookmark_metadata,
102+
m.id as message_id,
103+
m.content as message_content,
104+
m.html as message_html,
105+
m.created_at as message_created_at,
106+
m.user_id as message_user_id,
107+
m.channel_id as message_channel_id,
108+
m.type as message_type,
109+
user_details_json(u) as user_details,
110+
c.name as channel_name,
111+
c.slug as channel_slug,
112+
w.id as workspace_id,
113+
w.name as workspace_name,
114+
w.slug as workspace_slug
115+
from message_bookmarks mb
116+
join messages m on mb.message_id = m.id
117+
join users u on m.user_id = u.id
118+
join channels c on m.channel_id = c.id
119+
join workspaces w on c.workspace_id = w.id
120+
where mb.user_id = v_user_id
121+
and m.deleted_at is null
122+
and c.deleted_at is null
123+
and w.deleted_at is null
124+
and (p_workspace_id is null or w.id = p_workspace_id)
125+
and (
126+
(p_archived = true and mb.archived_at is not null)
127+
or (p_archived = false and mb.archived_at is null)
128+
)
129+
order by mb.created_at desc
130+
limit p_limit
131+
offset p_offset;
132+
end;
133+
$$;
134+
135+
comment on function public.get_user_bookmarks is 'Retrieves bookmarked messages for the current user with full message and channel context. Can filter by workspace and archived status.';
136+
137+
-- Function: archive_bookmark
138+
-- Description: Archives or unarchives a bookmark
139+
create or replace function public.archive_bookmark(
140+
p_bookmark_id bigint,
141+
p_archive boolean default true
142+
)
143+
returns boolean
144+
language plpgsql
145+
security definer
146+
set search_path = public
147+
as $$
148+
declare
149+
v_user_id uuid;
150+
v_updated_count int;
151+
begin
152+
-- Get the current user ID
153+
v_user_id := auth.uid();
154+
155+
if v_user_id is null then
156+
raise exception 'User not authenticated';
157+
end if;
158+
159+
-- Update the bookmark archive status
160+
update message_bookmarks
161+
set archived_at = case
162+
when p_archive then timezone('utc', now())
163+
else null
164+
end
165+
where id = p_bookmark_id
166+
and user_id = v_user_id;
167+
168+
get diagnostics v_updated_count = row_count;
169+
170+
return v_updated_count > 0;
171+
end;
172+
$$;
173+
174+
comment on function public.archive_bookmark is 'Archives or unarchives a bookmark. Returns true if successful, false if bookmark not found or not owned by user.';
175+
176+
-- Function: mark_bookmark_as_read
177+
-- Description: Marks or unmarks a bookmark as read
178+
create or replace function public.mark_bookmark_as_read(
179+
p_bookmark_id bigint,
180+
p_mark_as_read boolean default true
181+
)
182+
returns boolean
183+
language plpgsql
184+
security definer
185+
set search_path = public
186+
as $$
187+
declare
188+
v_user_id uuid;
189+
v_updated_count int;
190+
begin
191+
-- Get the current user ID
192+
v_user_id := auth.uid();
193+
194+
if v_user_id is null then
195+
raise exception 'User not authenticated';
196+
end if;
197+
198+
-- Update the bookmark read status
199+
update message_bookmarks
200+
set marked_at = case
201+
when p_mark_as_read then timezone('utc', now())
202+
else null
203+
end
204+
where id = p_bookmark_id
205+
and user_id = v_user_id;
206+
207+
get diagnostics v_updated_count = row_count;
208+
209+
return v_updated_count > 0;
210+
end;
211+
$$;
212+
213+
comment on function public.mark_bookmark_as_read is 'Marks or unmarks a bookmark as read. Returns true if successful, false if bookmark not found or not owned by user.';
214+
215+
-- Function: get_bookmark_count
216+
-- Description: Gets the total count of bookmarks for the current user
217+
create or replace function public.get_bookmark_count(
218+
p_workspace_id varchar(36) default null,
219+
p_archived boolean default false
220+
)
221+
returns int
222+
language plpgsql
223+
security definer
224+
set search_path = public
225+
as $$
226+
declare
227+
v_user_id uuid;
228+
v_count int;
229+
begin
230+
-- Get the current user ID
231+
v_user_id := auth.uid();
232+
233+
if v_user_id is null then
234+
raise exception 'User not authenticated';
235+
end if;
236+
237+
select count(*)::int into v_count
238+
from message_bookmarks mb
239+
join messages m on mb.message_id = m.id
240+
join channels c on m.channel_id = c.id
241+
join workspaces w on c.workspace_id = w.id
242+
where mb.user_id = v_user_id
243+
and m.deleted_at is null
244+
and c.deleted_at is null
245+
and w.deleted_at is null
246+
and (p_workspace_id is null or w.id = p_workspace_id)
247+
and (
248+
(p_archived = true and mb.archived_at is not null)
249+
or (p_archived = false and mb.archived_at is null)
250+
);
251+
252+
return v_count;
253+
end;
254+
$$;
255+
256+
comment on function public.get_bookmark_count is 'Returns the total number of bookmarks for the current user. Can filter by workspace and archived status.';
257+
258+
-- Function: get_bookmark_stats
259+
-- Description: Gets bookmark statistics for the current user
260+
create or replace function public.get_bookmark_stats(
261+
p_workspace_id varchar(36) default null
262+
)
263+
returns jsonb
264+
language plpgsql
265+
security definer
266+
set search_path = public
267+
as $$
268+
declare
269+
v_user_id uuid;
270+
v_total int := 0;
271+
v_archived int := 0;
272+
v_unread int := 0;
273+
v_read int := 0;
274+
begin
275+
-- Get the current user ID
276+
v_user_id := auth.uid();
277+
278+
if v_user_id is null then
279+
raise exception 'User not authenticated';
280+
end if;
281+
282+
-- Get counts
283+
select
284+
count(*)::int,
285+
count(case when mb.archived_at is not null then 1 end)::int,
286+
count(case when mb.marked_at is null then 1 end)::int,
287+
count(case when mb.marked_at is not null then 1 end)::int
288+
into v_total, v_archived, v_unread, v_read
289+
from message_bookmarks mb
290+
join messages m on mb.message_id = m.id
291+
join channels c on m.channel_id = c.id
292+
join workspaces w on c.workspace_id = w.id
293+
where mb.user_id = v_user_id
294+
and m.deleted_at is null
295+
and c.deleted_at is null
296+
and w.deleted_at is null
297+
and (p_workspace_id is null or w.id = p_workspace_id);
298+
299+
return jsonb_build_object(
300+
'total', v_total,
301+
'archived', v_archived,
302+
'active', v_total - v_archived,
303+
'unread', v_unread,
304+
'read', v_read
305+
);
306+
end;
307+
$$;
308+
309+
comment on function public.get_bookmark_stats is 'Returns bookmark statistics for the current user including total, archived, active, read, and unread counts.';

0 commit comments

Comments
 (0)