Skip to content

Commit 81af2f7

Browse files
Use send score filter birthdays
1 parent 16b34ed commit 81af2f7

File tree

2 files changed

+103
-20
lines changed

2 files changed

+103
-20
lines changed
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
set check_function_bodies = off;
2+
3+
CREATE OR REPLACE FUNCTION public.today_birthday_senders()
4+
RETURNS SETOF activity_feed_user
5+
LANGUAGE plpgsql
6+
SECURITY DEFINER
7+
AS $function$
8+
BEGIN
9+
RETURN QUERY
10+
11+
WITH birthday_profiles AS (
12+
SELECT p.*
13+
FROM profiles p
14+
WHERE p.is_public = TRUE -- only public profiles
15+
AND p.birthday IS NOT NULL -- Ensure birthday is set
16+
AND p.avatar_url IS NOT NULL -- Ensure avatar is set
17+
AND EXTRACT(MONTH FROM p.birthday) = EXTRACT(MONTH FROM CURRENT_DATE) -- Match current month
18+
AND EXTRACT(DAY FROM p.birthday) = EXTRACT(DAY FROM CURRENT_DATE) -- Match current day
19+
-- Ensure user has at least one tag associated via tag_receipts, 1 paid tag
20+
-- This where can be removed after
21+
AND EXISTS (
22+
SELECT 1
23+
FROM tags t
24+
JOIN tag_receipts tr ON tr.tag_name = t.name
25+
WHERE t.user_id = p.id
26+
)
27+
),
28+
-- Ensure user has historical send activity
29+
filtered_profiles AS (
30+
SELECT bp.*
31+
FROM birthday_profiles bp
32+
WHERE EXISTS (
33+
SELECT 1
34+
FROM (
35+
SELECT
36+
SUM(ss.unique_sends) as total_sends,
37+
SUM(ss.score) as total_score
38+
FROM send_scores ss
39+
WHERE ss.user_id = bp.id
40+
) totals
41+
WHERE totals.total_sends > 100
42+
AND totals.total_score > (SELECT hodler_min_balance FROM distributions WHERE id = (SELECT MAX(d.id) FROM distributions d))
43+
)
44+
)
45+
46+
SELECT (
47+
(
48+
NULL, -- Placeholder for the 'id' field in activity_feed_user, don't want to show users' IDs
49+
fp.name,
50+
fp.avatar_url,
51+
fp.send_id,
52+
sa.main_tag_id,
53+
main_tag.name,
54+
(
55+
-- Aggregate all confirmed tags for the user into an array
56+
SELECT ARRAY_AGG(t.name)
57+
FROM tags t
58+
WHERE t.user_id = fp.id
59+
AND t.status = 'confirmed'
60+
)
61+
)::activity_feed_user
62+
).*
63+
FROM filtered_profiles fp
64+
LEFT JOIN send_accounts sa ON sa.user_id = fp.id
65+
LEFT JOIN tags main_tag ON main_tag.id = sa.main_tag_id
66+
LEFT JOIN LATERAL (
67+
SELECT COALESCE(SUM(ss.score), 0) AS send_score
68+
FROM send_scores ss
69+
WHERE ss.user_id = fp.id
70+
) score ON TRUE
71+
ORDER BY score.send_score DESC;
72+
END;
73+
$function$
74+
;
75+
76+

supabase/schemas/activity.sql

Lines changed: 27 additions & 20 deletions
Original file line numberDiff line numberDiff line change
@@ -193,16 +193,16 @@ $function$
193193
ALTER FUNCTION "public"."recent_senders"() OWNER TO "postgres";
194194

195195
-- Functions (that depend on activity table directly)
196-
CREATE OR REPLACE FUNCTION today_birthday_senders()
197-
RETURNS SETOF activity_feed_user
198-
SECURITY DEFINER
199-
LANGUAGE plpgsql
200-
AS $$
196+
CREATE OR REPLACE FUNCTION public.today_birthday_senders()
197+
RETURNS SETOF activity_feed_user
198+
LANGUAGE plpgsql
199+
SECURITY DEFINER
200+
AS $function$
201201
BEGIN
202202
RETURN QUERY
203203

204-
WITH filtered_profiles AS (
205-
SELECT *
204+
WITH birthday_profiles AS (
205+
SELECT p.*
206206
FROM profiles p
207207
WHERE p.is_public = TRUE -- only public profiles
208208
AND p.birthday IS NOT NULL -- Ensure birthday is set
@@ -217,15 +217,22 @@ WITH filtered_profiles AS (
217217
JOIN tag_receipts tr ON tr.tag_name = t.name
218218
WHERE t.user_id = p.id
219219
)
220-
-- Ensure user is part of the most recent distribution, means user have sent SEND at least once in current month and has min balance
221-
AND EXISTS (
220+
),
221+
-- Ensure user has historical send activity
222+
filtered_profiles AS (
223+
SELECT bp.*
224+
FROM birthday_profiles bp
225+
WHERE EXISTS (
222226
SELECT 1
223-
FROM distribution_shares ds
224-
WHERE ds.user_id = p.id
225-
AND ds.distribution_id = (
226-
SELECT MAX(d.id)
227-
FROM distributions d
228-
)
227+
FROM (
228+
SELECT
229+
SUM(ss.unique_sends) as total_sends,
230+
SUM(ss.score) as total_score
231+
FROM send_scores ss
232+
WHERE ss.user_id = bp.id
233+
) totals
234+
WHERE totals.total_sends > 100
235+
AND totals.total_score > (SELECT hodler_min_balance FROM distributions WHERE id = (SELECT MAX(d.id) FROM distributions d))
229236
)
230237
)
231238

@@ -250,14 +257,14 @@ FROM filtered_profiles fp
250257
LEFT JOIN send_accounts sa ON sa.user_id = fp.id
251258
LEFT JOIN tags main_tag ON main_tag.id = sa.main_tag_id
252259
LEFT JOIN LATERAL (
253-
SELECT COALESCE(SUM(ds.amount), 0) AS send_score
254-
FROM distribution_shares ds
255-
WHERE ds.user_id = fp.id
256-
AND ds.distribution_id >= 6
260+
SELECT COALESCE(SUM(ss.score), 0) AS send_score
261+
FROM send_scores ss
262+
WHERE ss.user_id = fp.id
257263
) score ON TRUE
258264
ORDER BY score.send_score DESC;
259265
END;
260-
$$;
266+
$function$
267+
;
261268

262269
-- Function
263270

0 commit comments

Comments
 (0)