1+ alter type " public" ." tag_search_result" add attribute " verified_at" timestamptz ;
2+ alter type " public" ." profile_lookup_result" add attribute " verified_at" timestamptz ;
3+
4+ set check_function_bodies = off;
5+
6+ CREATE OR REPLACE FUNCTION public .send_token_balance(p_user_id uuid)
7+ RETURNS numeric
8+ LANGUAGE plpgsql
9+ SECURITY DEFINER
10+ SET search_path TO ' public'
11+ AS $function$
12+ DECLARE
13+ account_address bytea ;
14+ account_block_time numeric ;
15+ result_balance numeric ;
16+ BEGIN
17+ -- Get account address and convert created_at to block_time
18+ SELECT
19+ decode(replace(sa .address ::text , (' 0x' ::citext)::text , ' ' ::text ), ' hex' ),
20+ EXTRACT(EPOCH FROM sa .created_at )
21+ INTO account_address, account_block_time
22+ FROM public .send_accounts sa
23+ WHERE sa .user_id = p_user_id;
24+
25+ -- Return 0 if no account found
26+ IF account_address IS NULL THEN
27+ RETURN 0 ;
28+ END IF;
29+
30+ -- Sum transfers starting from account creation (with 1 hour buffer)
31+ SELECT COALESCE(SUM (
32+ CASE
33+ WHEN stt .t = account_address AND stt .f = account_address THEN 0 ::numeric -- Self-transfer = net 0
34+ WHEN stt .t = account_address THEN stt .v ::numeric
35+ WHEN stt .f = account_address THEN - stt .v ::numeric
36+ ELSE 0 ::numeric
37+ END
38+ ), 0 ::numeric )
39+ INTO result_balance
40+ FROM public .send_token_transfers stt
41+ WHERE stt .block_time >= (account_block_time - 3600 ) -- Subtract 1 hour buffer
42+ AND (stt .t = account_address OR stt .f = account_address);
43+
44+ RETURN result_balance;
45+ END;
46+ $function$
47+ ;
48+
49+ CREATE OR REPLACE FUNCTION public .verified_at(p profiles)
50+ RETURNS timestamp with time zone
51+ LANGUAGE plpgsql
52+ STABLE SECURITY DEFINER
53+ SET search_path TO ' public'
54+ AS $function$
55+ DECLARE
56+ v_has_tag boolean := false;
57+ v_has_hodler boolean := false;
58+ v_has_earn boolean := false;
59+ v_hodler_min numeric ;
60+ v_earn_min numeric ;
61+ BEGIN
62+ -- Active distribution thresholds
63+ SELECT hodler_min_balance::numeric , earn_min_balance::numeric
64+ INTO v_hodler_min, v_earn_min
65+ FROM distributions
66+ WHERE (now() AT TIME ZONE ' UTC' ) >= qualification_start
67+ AND (now() AT TIME ZONE ' UTC' ) < qualification_end
68+ ORDER BY qualification_start DESC
69+ LIMIT 1 ;
70+
71+ -- If there is no active distribution, not verified
72+ IF v_hodler_min IS NULL THEN
73+ RETURN NULL ;
74+ END IF;
75+
76+ -- 1) Quick check: must have at least one purchased tag receipt
77+ SELECT EXISTS (
78+ SELECT 1
79+ FROM public .sendtag_checkout_receipts scr
80+ JOIN public .send_accounts sa
81+ ON decode(replace(sa .address ::text , (' 0x' ::citext)::text , ' ' ::text ), ' hex' ) = scr .sender
82+ WHERE sa .user_id = p .id
83+ ) INTO v_has_tag;
84+ IF NOT v_has_tag THEN
85+ RETURN NULL ;
86+ END IF;
87+
88+ -- 2) Quick check: any earn balance meets threshold
89+ SELECT EXISTS (
90+ SELECT 1
91+ FROM public .send_earn_balances seb
92+ JOIN public .send_accounts sa
93+ ON seb .owner = decode(replace(sa .address ::text , (' 0x' ::citext)::text , ' ' ::text ), ' hex' )
94+ WHERE sa .user_id = p .id
95+ AND seb .assets >= v_earn_min
96+ ) INTO v_has_earn;
97+ IF NOT v_has_earn THEN
98+ RETURN NULL ;
99+ END IF;
100+
101+ -- 3) Hodler balance meets threshold
102+ v_has_hodler := public .send_token_balance (p .id ) >= v_hodler_min;
103+ IF NOT v_has_hodler THEN
104+ RETURN NULL ;
105+ END IF;
106+
107+ -- All checks passed
108+ RETURN (now() AT TIME ZONE ' UTC' );
109+ END;
110+ $function$
111+ ;
112+
113+ CREATE OR REPLACE FUNCTION public .tag_search(query text , limit_val integer , offset_val integer )
114+ RETURNS TABLE(send_id_matches tag_search_result[], tag_matches tag_search_result[], phone_matches tag_search_result[])
115+ LANGUAGE plpgsql
116+ IMMUTABLE SECURITY DEFINER
117+ AS $function$
118+ BEGIN
119+ IF limit_val IS NULL OR (limit_val <= 0 OR limit_val > 100 ) THEN
120+ RAISE EXCEPTION ' limit_val must be between 1 and 100' ;
121+ END IF;
122+ IF offset_val IS NULL OR offset_val < 0 THEN
123+ RAISE EXCEPTION ' offset_val must be greater than or equal to 0' ;
124+ END IF;
125+ RETURN query
126+ SELECT
127+ -- send_id matches
128+ (
129+ SELECT
130+ array_agg(ROW(sub .avatar_url , sub .tag_name , sub .send_id , sub .phone , sub .is_verified , sub .verified_at )::public .tag_search_result )
131+ FROM (
132+ WITH candidates AS (
133+ SELECT
134+ p .id AS user_id,
135+ p .avatar_url ,
136+ t .name AS tag_name,
137+ p .send_id ,
138+ p .verified_at (p) AS verified_at
139+ FROM
140+ profiles p
141+ LEFT JOIN send_accounts sa ON sa .user_id = p .id
142+ LEFT JOIN send_account_tags sat ON sat .send_account_id = sa .id
143+ LEFT JOIN tags t ON t .id = sat .tag_id
144+ AND t .status = ' confirmed'
145+ WHERE
146+ query SIMILAR TO ' \\ d+'
147+ AND p .send_id ::varchar LIKE ' %' || query || ' %'
148+ ORDER BY
149+ p .send_id
150+ LIMIT limit_val offset offset_val
151+ )
152+ SELECT
153+ c .avatar_url ,
154+ c .tag_name ,
155+ c .send_id ,
156+ NULL ::text AS phone,
157+ c .verified_at ,
158+ c .verified_at IS NOT NULL AS is_verified
159+ FROM candidates c
160+ ) sub) AS send_id_matches,
161+ -- tag matches
162+ (
163+ SELECT
164+ array_agg(ROW(sub .avatar_url , sub .tag_name , sub .send_id , sub .phone , sub .is_verified , sub .verified_at )::public .tag_search_result )
165+ FROM (
166+ SELECT
167+ ranked_matches .avatar_url ,
168+ ranked_matches .tag_name ,
169+ ranked_matches .send_id ,
170+ ranked_matches .phone ,
171+ ranked_matches .is_verified ,
172+ ranked_matches .verified_at
173+ FROM (
174+ WITH scores AS (
175+ -- Aggregate user send scores, summing all scores for cumulative activity
176+ SELECT
177+ user_id,
178+ SUM (score) AS total_score
179+ FROM private .send_scores_history
180+ GROUP BY user_id
181+ ),
182+ tag_matches AS (
183+ SELECT
184+ p .id AS user_id,
185+ p .avatar_url ,
186+ t .name AS tag_name,
187+ p .send_id ,
188+ p .verified_at (p) AS verified_at,
189+ NULL ::text AS phone,
190+ (t .name < - > query) AS distance, -- Trigram distance: 0=exact, higher=different
191+ COALESCE(scores .total_score , 0 ) AS send_score,
192+ -- Compute exact match flag in CTE
193+ LOWER (t .name ) = LOWER (query) AS is_exact,
194+ -- Primary ranking: exact matches (primary_rank=0) always outrank fuzzy matches (primary_rank=1)
195+ CASE WHEN LOWER (t .name ) = LOWER (query) THEN 0 ELSE 1 END AS primary_rank
196+ FROM profiles p
197+ JOIN send_accounts sa ON sa .user_id = p .id
198+ JOIN send_account_tags sat ON sat .send_account_id = sa .id
199+ JOIN tags t ON t .id = sat .tag_id
200+ AND t .status = ' confirmed'
201+ LEFT JOIN scores ON scores .user_id = p .id
202+ WHERE
203+ -- Use ILIKE '%' only when NOT exact to avoid excluding true exact matches like 'Ethen_'
204+ LOWER (t .name ) = LOWER (query)
205+ OR (NOT (LOWER (t .name ) = LOWER (query)) AND (t .name << - > query < 0 .7 OR t .name ILIKE ' %' || query || ' %' ))
206+ )
207+ SELECT
208+ tm .avatar_url ,
209+ tm .tag_name ,
210+ tm .send_id ,
211+ tm .phone ,
212+ tm .distance ,
213+ tm .send_score ,
214+ tm .is_exact ,
215+ tm .primary_rank ,
216+ tm .verified_at ,
217+ tm .verified_at IS NOT NULL AS is_verified,
218+ (
219+ -- Secondary ranking varies by match type:
220+ -- For exact matches (primary_rank=0): use negative send_score (higher score = better/lower secondary rank)
221+ -- For fuzzy matches (primary_rank=1): use old trigram + send_score formula
222+ CASE
223+ WHEN tm .is_exact THEN
224+ - tm .send_score -- Negative for DESC ordering within exact matches
225+ ELSE
226+ -- Old fuzzy ranking formula: distance - (send_score / 1M)
227+ CASE WHEN tm .distance IS NULL THEN 0 ELSE tm .distance END
228+ - (tm .send_score / 1000000 .0 )
229+ END
230+ ) AS secondary_rank,
231+ ROW_NUMBER() OVER (PARTITION BY tm .send_id ORDER BY (
232+ -- Deduplication uses same ranking logic as main ordering
233+ tm .primary_rank , -- Primary: exact vs fuzzy
234+ CASE
235+ WHEN tm .is_exact THEN
236+ - tm .send_score -- Secondary: send_score DESC for exact
237+ ELSE
238+ CASE WHEN tm .distance IS NULL THEN 0 ELSE tm .distance END
239+ - (tm .send_score / 1000000 .0 ) -- Secondary: old formula for fuzzy
240+ END
241+ )) AS rn
242+ FROM tag_matches tm
243+ ) ranked_matches
244+ WHERE ranked_matches .rn = 1
245+ ORDER BY ranked_matches .primary_rank ASC , ranked_matches .secondary_rank ASC
246+ LIMIT limit_val OFFSET offset_val
247+ ) sub
248+ ) AS tag_matches,
249+ -- phone matches, disabled for now
250+ (null ::public .tag_search_result []) AS phone_matches;
251+ END;
252+ $function$
253+ ;
254+
255+ CREATE OR REPLACE FUNCTION public .profile_lookup(lookup_type lookup_type_enum, identifier text )
256+ RETURNS SETOF profile_lookup_result
257+ LANGUAGE plpgsql
258+ IMMUTABLE SECURITY DEFINER
259+ AS $function$
260+ begin
261+ if identifier is null or identifier = ' ' then raise exception ' identifier cannot be null or empty' ; end if;
262+ if lookup_type is null then raise exception ' lookup_type cannot be null' ; end if;
263+
264+ RETURN QUERY
265+ SELECT
266+ b .id ,
267+ b .avatar_url ,
268+ b .name ,
269+ b .about ,
270+ b .refcode ,
271+ b .x_username ,
272+ b .birthday ,
273+ b .tag ,
274+ b .address ,
275+ b .chain_id ,
276+ b .is_public ,
277+ b .sendid ,
278+ b .all_tags ,
279+ b .main_tag_id ,
280+ b .main_tag_name ,
281+ b .links_in_bio ,
282+ b .banner_url ,
283+ (b .verified_at IS NOT NULL ) AS is_verified,
284+ b .verified_at
285+ FROM (
286+ SELECT
287+ CASE WHEN p .id = (SELECT auth .uid ()) THEN p .id END AS id,
288+ p .avatar_url ::text AS avatar_url,
289+ p .name ::text AS name,
290+ p .about ::text AS about,
291+ p .referral_code AS refcode,
292+ CASE WHEN p .is_public THEN p .x_username ELSE NULL END AS x_username,
293+ CASE WHEN p .is_public THEN p .birthday ELSE NULL END AS birthday,
294+ COALESCE(mt .name , t .name ) AS tag,
295+ sa .address AS address,
296+ sa .chain_id AS chain_id,
297+ CASE WHEN current_setting(' role' )::text = ' service_role' THEN p .is_public
298+ WHEN p .is_public THEN true ELSE false END AS is_public,
299+ p .send_id AS sendid,
300+ (
301+ SELECT array_agg(t2 .name ::text )
302+ FROM tags t2
303+ JOIN send_account_tags sat2 ON sat2 .tag_id = t2 .id
304+ JOIN send_accounts sa2 ON sa2 .id = sat2 .send_account_id
305+ WHERE sa2 .user_id = p .id AND t2 .status = ' confirmed' ::tag_status
306+ ) AS all_tags,
307+ CASE WHEN p .id = (SELECT auth .uid ()) THEN sa .main_tag_id END AS main_tag_id,
308+ mt .name ::text AS main_tag_name,
309+ CASE WHEN p .is_public THEN (
310+ SELECT array_agg(link_in_bio_row)
311+ FROM (
312+ SELECT ROW(
313+ CASE WHEN lib .user_id = (SELECT auth .uid ()) THEN lib .id ELSE NULL END,
314+ CASE WHEN lib .user_id = (SELECT auth .uid ()) THEN lib .user_id ELSE NULL END,
315+ lib .handle ,
316+ lib .domain_name ,
317+ lib .created_at ,
318+ lib .updated_at ,
319+ lib .domain
320+ )::link_in_bio AS link_in_bio_row
321+ FROM link_in_bio lib
322+ WHERE lib .user_id = p .id AND lib .handle IS NOT NULL
323+ ) sub
324+ ) ELSE NULL END AS links_in_bio,
325+ p .banner_url ::text AS banner_url,
326+ p .verified_at (p) AS verified_at
327+ FROM profiles p
328+ JOIN auth .users a ON a .id = p .id
329+ LEFT JOIN send_accounts sa ON sa .user_id = p .id
330+ LEFT JOIN tags mt ON mt .id = sa .main_tag_id
331+ LEFT JOIN send_account_tags sat ON sat .send_account_id = sa .id
332+ LEFT JOIN tags t ON t .id = sat .tag_id AND t .status = ' confirmed' ::tag_status
333+ WHERE ((lookup_type = ' sendid' AND p .send_id ::text = identifier) OR
334+ (lookup_type = ' tag' AND t .name = identifier::citext) OR
335+ (lookup_type = ' refcode' AND p .referral_code = identifier) OR
336+ (lookup_type = ' address' AND sa .address = identifier) OR
337+ (p .is_public AND lookup_type = ' phone' AND a .phone ::text = identifier))
338+ AND (p .is_public OR (SELECT auth .uid ()) IS NOT NULL OR current_setting(' role' )::text = ' service_role' )
339+ LIMIT 1
340+ ) AS b;
341+ end;
342+ $function$
343+ ;
344+
345+ create or replace view "public "." referrer" as WITH referrer AS (
346+ SELECT p .send_id
347+ FROM (referrals r
348+ JOIN profiles p ON ((r .referrer_id = p .id )))
349+ WHERE (r .referred_id = ( SELECT auth .uid () AS uid))
350+ ORDER BY r .created_at
351+ LIMIT 1
352+ ), profile_lookup AS (
353+ SELECT p .id ,
354+ p .avatar_url ,
355+ p .name ,
356+ p .about ,
357+ p .refcode ,
358+ p .x_username ,
359+ p .birthday ,
360+ p .tag ,
361+ p .address ,
362+ p .chain_id ,
363+ p .is_public ,
364+ p .sendid ,
365+ p .all_tags ,
366+ p .main_tag_id ,
367+ p .main_tag_name ,
368+ p .links_in_bio ,
369+ p .banner_url ,
370+ referrer .send_id ,
371+ p .is_verified ,
372+ p .verified_at
373+ FROM (profile_lookup(' sendid' ::lookup_type_enum, ( SELECT (referrer_1 .send_id )::text AS send_id
374+ FROM referrer referrer_1)) p(id, avatar_url, name, about, refcode, x_username, birthday, tag, address, chain_id, is_public, sendid, all_tags, main_tag_id, main_tag_name, links_in_bio, banner_url, is_verified, verified_at)
375+ JOIN referrer ON ((referrer .send_id IS NOT NULL )))
376+ )
377+ SELECT profile_lookup .id ,
378+ profile_lookup .avatar_url ,
379+ profile_lookup .name ,
380+ profile_lookup .about ,
381+ profile_lookup .refcode ,
382+ profile_lookup .x_username ,
383+ profile_lookup .birthday ,
384+ profile_lookup .tag ,
385+ profile_lookup .address ,
386+ profile_lookup .chain_id ,
387+ profile_lookup .is_public ,
388+ profile_lookup .sendid ,
389+ profile_lookup .all_tags ,
390+ profile_lookup .main_tag_id ,
391+ profile_lookup .main_tag_name ,
392+ profile_lookup .links_in_bio ,
393+ profile_lookup .send_id ,
394+ profile_lookup .banner_url ,
395+ profile_lookup .verified_at ,
396+ profile_lookup .is_verified
397+ FROM profile_lookup;
0 commit comments