diff --git a/supabase/database-generated.types.ts b/supabase/database-generated.types.ts index 4c910c8b6..bd5d1cf8c 100644 --- a/supabase/database-generated.types.ts +++ b/supabase/database-generated.types.ts @@ -440,6 +440,7 @@ export type Database = { | null main_tag: Database["public"]["Tables"]["tags"]["Row"] | null tags: Database["public"]["Tables"]["tags"]["Row"] | null + verified_at: string | null } Insert: { about?: string | null @@ -1701,6 +1702,7 @@ export type Database = { chain_id: number | null id: string | null is_public: boolean | null + is_verified: boolean | null links_in_bio: | Database["public"]["Tables"]["link_in_bio"]["Row"][] | null @@ -1711,6 +1713,7 @@ export type Database = { send_id: number | null sendid: number | null tag: string | null + verified_at: string | null x_username: string | null } Relationships: [] @@ -2112,6 +2115,10 @@ export type Database = { vault: string }[] } + send_token_balance: { + Args: { p_user_id: string } + Returns: number + } tag_search: { Args: { limit_val: number; offset_val: number; query: string } Returns: { @@ -2157,6 +2164,10 @@ export type Database = { Args: Record Returns: number } + verified_at: { + Args: { "": Database["public"]["Tables"]["profiles"]["Row"] } + Returns: string + } } Enums: { key_type_enum: "ES256" @@ -2223,6 +2234,7 @@ export type Database = { | null banner_url: string | null is_verified: boolean | null + verified_at: string | null } tag_search_result: { avatar_url: string | null @@ -2230,6 +2242,7 @@ export type Database = { send_id: number | null phone: string | null is_verified: boolean | null + verified_at: string | null } } } diff --git a/supabase/migrations/20251010140736_profiles_verified_at_computed.sql b/supabase/migrations/20251010140736_profiles_verified_at_computed.sql new file mode 100644 index 000000000..b4ba7cae4 --- /dev/null +++ b/supabase/migrations/20251010140736_profiles_verified_at_computed.sql @@ -0,0 +1,419 @@ +alter type "public"."tag_search_result" add attribute "verified_at" timestamptz; +alter type "public"."profile_lookup_result" add attribute "verified_at" timestamptz; + +set check_function_bodies = off; + +CREATE OR REPLACE FUNCTION public.send_token_balance(p_user_id uuid) + RETURNS numeric + LANGUAGE plpgsql + SECURITY DEFINER + SET search_path TO 'public' +AS $function$ +DECLARE + account_address bytea; + account_block_time numeric; + result_balance numeric; +BEGIN + -- Get account address and convert created_at to block_time + SELECT + decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex'), + EXTRACT(EPOCH FROM sa.created_at) + INTO account_address, account_block_time + FROM public.send_accounts sa + WHERE sa.user_id = p_user_id; + + -- Return 0 if no account found + IF account_address IS NULL THEN + RETURN 0; + END IF; + + -- Sum transfers starting from account creation (with 1 hour buffer) + SELECT COALESCE(SUM( + CASE + WHEN stt.t = account_address AND stt.f = account_address THEN 0::numeric -- Self-transfer = net 0 + WHEN stt.t = account_address THEN stt.v::numeric + WHEN stt.f = account_address THEN -stt.v::numeric + ELSE 0::numeric + END + ), 0::numeric) + INTO result_balance + FROM public.send_token_transfers stt + WHERE stt.block_time >= (account_block_time - 3600) -- Subtract 1 hour buffer + AND (stt.t = account_address OR stt.f = account_address); + + RETURN result_balance; +END; +$function$ +; + +CREATE OR REPLACE FUNCTION "public"."verified_at"("public"."profiles") RETURNS timestamp with time zone + LANGUAGE "plpgsql" STABLE SECURITY DEFINER + SET search_path TO 'public' +AS $function$ +DECLARE + v_has_tag boolean := false; + v_has_hodler boolean := false; + v_has_earn boolean := false; + v_hodler_min numeric; + v_earn_min numeric; +BEGIN + -- Active distribution thresholds + SELECT hodler_min_balance::numeric, earn_min_balance::numeric + INTO v_hodler_min, v_earn_min + FROM distributions + WHERE (now() AT TIME ZONE 'UTC') >= qualification_start + AND (now() AT TIME ZONE 'UTC') < qualification_end + ORDER BY qualification_start DESC + LIMIT 1; + + -- If there is no active distribution, not verified + IF v_hodler_min IS NULL THEN + RETURN NULL; + END IF; + + -- 1) Quick check: must have at least one purchased tag receipt + SELECT EXISTS ( + SELECT 1 + FROM public.sendtag_checkout_receipts scr + JOIN public.send_accounts sa + ON decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex') = scr.sender + WHERE sa.user_id = $1.id + ) INTO v_has_tag; + IF NOT v_has_tag THEN + RETURN NULL; + END IF; + + -- 2) Quick check: any earn balance meets threshold + SELECT EXISTS ( + SELECT 1 + FROM public.send_earn_balances seb + JOIN public.send_accounts sa + ON seb.owner = decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex') + WHERE sa.user_id = $1.id + AND seb.assets >= v_earn_min + ) INTO v_has_earn; + IF NOT v_has_earn THEN + RETURN NULL; + END IF; + + -- 3) Hodler balance meets threshold + v_has_hodler := public.send_token_balance($1.id) >= v_hodler_min; + IF NOT v_has_hodler THEN + RETURN NULL; + END IF; + + -- All checks passed + RETURN (now() AT TIME ZONE 'UTC'); +END; +$function$ +; + +ALTER FUNCTION "public"."verified_at"("public"."profiles") OWNER TO "postgres"; + +REVOKE ALL ON FUNCTION "public"."verified_at"("public"."profiles") FROM PUBLIC; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "anon"; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "authenticated"; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "service_role"; + + +CREATE OR REPLACE FUNCTION public.tag_search(query text, limit_val integer, offset_val integer) + RETURNS TABLE(send_id_matches tag_search_result[], tag_matches tag_search_result[], phone_matches tag_search_result[]) + LANGUAGE plpgsql + STABLE SECURITY DEFINER +AS $function$ +BEGIN + IF limit_val IS NULL OR(limit_val <= 0 OR limit_val > 100) THEN + RAISE EXCEPTION 'limit_val must be between 1 and 100'; + END IF; + IF offset_val IS NULL OR offset_val < 0 THEN + RAISE EXCEPTION 'offset_val must be greater than or equal to 0'; + END IF; + RETURN query + SELECT + -- send_id matches +( + SELECT + array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified, sub.verified_at)::public.tag_search_result) + FROM ( + WITH candidates AS ( + SELECT + p.id AS user_id, + p.avatar_url, + p.send_id, + NULL::text AS phone + FROM profiles p + WHERE + query SIMILAR TO '\d+' + AND p.send_id::varchar LIKE '%' || query || '%' + ORDER BY p.send_id + ), + page AS ( + SELECT + c.user_id, + c.avatar_url, + c.send_id, + c.phone + FROM candidates c + ORDER BY c.send_id ASC + LIMIT limit_val OFFSET offset_val + ), + enriched AS ( + SELECT + page.avatar_url, + ct.tag_name AS tag_name, + page.send_id, + page.phone, + (va.verified_at_result IS NOT NULL) AS is_verified, + va.verified_at_result AS verified_at + FROM page + LEFT JOIN LATERAL ( + SELECT t.name AS tag_name + FROM send_accounts sa2 + JOIN send_account_tags sat2 ON sat2.send_account_id = sa2.id + JOIN tags t ON t.id = sat2.tag_id AND t.status = 'confirmed' + WHERE sa2.user_id = page.user_id + ORDER BY t.name ASC + LIMIT 1 + ) ct ON true + JOIN profiles p2 ON p2.id = page.user_id + CROSS JOIN LATERAL ( + SELECT public.verified_at(p2) AS verified_at_result + ) va + ) + SELECT * FROM enriched + ) sub) AS send_id_matches, + -- tag matches + ( + SELECT + array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified, sub.verified_at)::public.tag_search_result) + FROM ( + WITH scores AS ( + -- Aggregate user send scores, summing all scores for cumulative activity + SELECT + user_id, + SUM(score) AS total_score + FROM private.send_scores_history + GROUP BY user_id + ), + candidates AS ( + SELECT + p.id AS user_id, + p.avatar_url, + t.name AS tag_name, + p.send_id, + NULL::text AS phone, + (t.name <-> query) AS distance, + COALESCE(scores.total_score, 0) AS send_score, + LOWER(t.name) = LOWER(query) AS is_exact, + CASE WHEN LOWER(t.name) = LOWER(query) THEN 0 ELSE 1 END AS primary_rank + FROM profiles p + JOIN send_accounts sa ON sa.user_id = p.id + JOIN send_account_tags sat ON sat.send_account_id = sa.id + JOIN tags t ON t.id = sat.tag_id + AND t.status = 'confirmed' + LEFT JOIN scores ON scores.user_id = p.id + WHERE + LOWER(t.name) = LOWER(query) + OR (NOT (LOWER(t.name) = LOWER(query)) AND (t.name <<-> query < 0.7 OR t.name ILIKE '%' || query || '%')) + ), + ranked AS ( + SELECT + c.user_id, + c.avatar_url, + c.tag_name, + c.send_id, + c.phone, + c.distance, + c.send_score, + c.is_exact, + c.primary_rank, + ( + CASE + WHEN c.is_exact THEN + -c.send_score + ELSE + CASE WHEN c.distance IS NULL THEN 0 ELSE c.distance END + - (c.send_score / 1000000.0) + END + ) AS secondary_rank, + ROW_NUMBER() OVER (PARTITION BY c.send_id ORDER BY ( + c.primary_rank, + CASE + WHEN c.is_exact THEN + -c.send_score + ELSE + CASE WHEN c.distance IS NULL THEN 0 ELSE c.distance END + - (c.send_score / 1000000.0) + END + )) AS rn + FROM candidates c + ), + page AS ( + SELECT + r.user_id, + r.avatar_url, + r.tag_name, + r.send_id, + r.phone, + r.primary_rank, + r.secondary_rank + FROM ranked r + WHERE r.rn = 1 + ORDER BY r.primary_rank ASC, r.secondary_rank ASC + LIMIT limit_val OFFSET offset_val + ), + enriched AS ( + SELECT + page.avatar_url, + page.tag_name, + page.send_id, + page.phone, + (va.verified_at_result IS NOT NULL) AS is_verified, + va.verified_at_result AS verified_at + FROM page + JOIN profiles p2 ON p2.id = page.user_id + CROSS JOIN LATERAL ( + SELECT public.verified_at(p2) AS verified_at_result + ) va + ) + SELECT * FROM enriched + ) sub + ) AS tag_matches, + -- phone matches, disabled for now + (null::public.tag_search_result[]) AS phone_matches; +END; +$function$ +; + +CREATE OR REPLACE FUNCTION public.profile_lookup(lookup_type lookup_type_enum, identifier text) + RETURNS SETOF profile_lookup_result + LANGUAGE plpgsql + STABLE SECURITY DEFINER +AS $function$ +begin + if identifier is null or identifier = '' then raise exception 'identifier cannot be null or empty'; end if; + if lookup_type is null then raise exception 'lookup_type cannot be null'; end if; + + RETURN QUERY + SELECT + CASE WHEN p.id = (SELECT auth.uid()) THEN p.id END AS id, + p.avatar_url::text AS avatar_url, + p.name::text AS name, + p.about::text AS about, + p.referral_code AS refcode, + CASE WHEN p.is_public THEN p.x_username ELSE NULL END AS x_username, + CASE WHEN p.is_public THEN p.birthday ELSE NULL END AS birthday, + COALESCE(mt.name, t.name) AS tag, + sa.address AS address, + sa.chain_id AS chain_id, + CASE WHEN current_setting('role')::text = 'service_role' THEN p.is_public + WHEN p.is_public THEN true ELSE false END AS is_public, + p.send_id AS sendid, + ( + SELECT array_agg(t2.name::text) + FROM tags t2 + JOIN send_account_tags sat2 ON sat2.tag_id = t2.id + JOIN send_accounts sa2 ON sa2.id = sat2.send_account_id + WHERE sa2.user_id = p.id AND t2.status = 'confirmed'::tag_status + ) AS all_tags, + CASE WHEN p.id = (SELECT auth.uid()) THEN sa.main_tag_id END AS main_tag_id, + mt.name::text AS main_tag_name, + CASE WHEN p.is_public THEN ( + SELECT array_agg(link_in_bio_row) + FROM ( + SELECT ROW( + CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.id ELSE NULL END, + CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.user_id ELSE NULL END, + lib.handle, + lib.domain_name, + lib.created_at, + lib.updated_at, + lib.domain + )::link_in_bio AS link_in_bio_row + FROM link_in_bio lib + WHERE lib.user_id = p.id AND lib.handle IS NOT NULL + ) sub + ) ELSE NULL END AS links_in_bio, + p.banner_url::text AS banner_url, + (verified_at_result IS NOT NULL) AS is_verified, + verified_at_result AS verified_at + FROM ( + SELECT + p.*, + public.verified_at(p) AS verified_at_result + FROM profiles p + JOIN auth.users a ON a.id = p.id + LEFT JOIN send_accounts sa ON sa.user_id = p.id + LEFT JOIN tags mt ON mt.id = sa.main_tag_id + LEFT JOIN send_account_tags sat ON sat.send_account_id = sa.id + LEFT JOIN tags t ON t.id = sat.tag_id AND t.status = 'confirmed'::tag_status + WHERE ((lookup_type = 'sendid' AND p.send_id::text = identifier) OR + (lookup_type = 'tag' AND t.name = identifier::citext) OR + (lookup_type = 'refcode' AND p.referral_code = identifier) OR + (lookup_type = 'address' AND sa.address = identifier) OR + (p.is_public AND lookup_type = 'phone' AND a.phone::text = identifier)) + AND (p.is_public OR (SELECT auth.uid()) IS NOT NULL OR current_setting('role')::text = 'service_role') + LIMIT 1 + ) p + LEFT JOIN auth.users a ON a.id = p.id + LEFT JOIN send_accounts sa ON sa.user_id = p.id + LEFT JOIN tags mt ON mt.id = sa.main_tag_id + LEFT JOIN send_account_tags sat ON sat.send_account_id = sa.id + LEFT JOIN tags t ON t.id = sat.tag_id AND t.status = 'confirmed'::tag_status; +end; +$function$ +; + +create or replace view "public"."referrer" as WITH referrer AS ( + SELECT p.send_id + FROM (referrals r + JOIN profiles p ON ((r.referrer_id = p.id))) + WHERE (r.referred_id = ( SELECT auth.uid() AS uid)) + ORDER BY r.created_at + LIMIT 1 + ), profile_lookup AS ( + SELECT p.id, + p.avatar_url, + p.name, + p.about, + p.refcode, + p.x_username, + p.birthday, + p.tag, + p.address, + p.chain_id, + p.is_public, + p.sendid, + p.all_tags, + p.main_tag_id, + p.main_tag_name, + p.links_in_bio, + p.banner_url, + referrer.send_id, + p.is_verified, + p.verified_at + FROM (profile_lookup('sendid'::lookup_type_enum, ( SELECT (referrer_1.send_id)::text AS send_id + 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) + JOIN referrer ON ((referrer.send_id IS NOT NULL))) + ) + SELECT profile_lookup.id, + profile_lookup.avatar_url, + profile_lookup.name, + profile_lookup.about, + profile_lookup.refcode, + profile_lookup.x_username, + profile_lookup.birthday, + profile_lookup.tag, + profile_lookup.address, + profile_lookup.chain_id, + profile_lookup.is_public, + profile_lookup.sendid, + profile_lookup.all_tags, + profile_lookup.main_tag_id, + profile_lookup.main_tag_name, + profile_lookup.links_in_bio, + profile_lookup.send_id, + profile_lookup.banner_url, + profile_lookup.verified_at, + profile_lookup.is_verified + FROM profile_lookup; \ No newline at end of file diff --git a/supabase/schemas/distributions.sql b/supabase/schemas/distributions.sql index b2540fa33..03b1167cb 100644 --- a/supabase/schemas/distributions.sql +++ b/supabase/schemas/distributions.sql @@ -1052,6 +1052,76 @@ $_$; ALTER FUNCTION "public"."distribution_shares"("public"."profiles") OWNER TO "postgres"; +CREATE OR REPLACE FUNCTION "public"."verified_at"("public"."profiles") RETURNS timestamp with time zone + LANGUAGE "plpgsql" STABLE SECURITY DEFINER + SET search_path TO 'public' +AS $function$ +DECLARE + v_has_tag boolean := false; + v_has_hodler boolean := false; + v_has_earn boolean := false; + v_hodler_min numeric; + v_earn_min numeric; +BEGIN + -- Active distribution thresholds + SELECT hodler_min_balance::numeric, earn_min_balance::numeric + INTO v_hodler_min, v_earn_min + FROM distributions + WHERE (now() AT TIME ZONE 'UTC') >= qualification_start + AND (now() AT TIME ZONE 'UTC') < qualification_end + ORDER BY qualification_start DESC + LIMIT 1; + + -- If there is no active distribution, not verified + IF v_hodler_min IS NULL THEN + RETURN NULL; + END IF; + + -- 1) Quick check: must have at least one purchased tag receipt + SELECT EXISTS ( + SELECT 1 + FROM public.sendtag_checkout_receipts scr + JOIN public.send_accounts sa + ON decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex') = scr.sender + WHERE sa.user_id = $1.id + ) INTO v_has_tag; + IF NOT v_has_tag THEN + RETURN NULL; + END IF; + + -- 2) Quick check: any earn balance meets threshold + SELECT EXISTS ( + SELECT 1 + FROM public.send_earn_balances seb + JOIN public.send_accounts sa + ON seb.owner = decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex') + WHERE sa.user_id = $1.id + AND seb.assets >= v_earn_min + ) INTO v_has_earn; + IF NOT v_has_earn THEN + RETURN NULL; + END IF; + + -- 3) Hodler balance meets threshold + v_has_hodler := public.send_token_balance($1.id) >= v_hodler_min; + IF NOT v_has_hodler THEN + RETURN NULL; + END IF; + + -- All checks passed + RETURN (now() AT TIME ZONE 'UTC'); +END; +$function$ +; + +ALTER FUNCTION "public"."verified_at"("public"."profiles") OWNER TO "postgres"; + +REVOKE ALL ON FUNCTION "public"."verified_at"("public"."profiles") FROM PUBLIC; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "anon"; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "authenticated"; +GRANT ALL ON FUNCTION "public"."verified_at"("public"."profiles") TO "service_role"; + + -- Function grants REVOKE ALL ON FUNCTION "public"."calculate_and_insert_send_ceiling_verification"("distribution_number" integer) FROM PUBLIC; GRANT ALL ON FUNCTION "public"."calculate_and_insert_send_ceiling_verification"("distribution_number" integer) TO "service_role"; diff --git a/supabase/schemas/referrals.sql b/supabase/schemas/referrals.sql index 54cad1b92..0971c20f3 100644 --- a/supabase/schemas/referrals.sql +++ b/supabase/schemas/referrals.sql @@ -17,86 +17,88 @@ CREATE TYPE "public"."profile_lookup_result" AS ( "main_tag_name" "text", "links_in_bio" link_in_bio[], "banner_url" "text", - "is_verified" boolean + "is_verified" boolean, + "verified_at" timestamptz ); ALTER TYPE "public"."profile_lookup_result" OWNER TO "postgres"; -- Functions + CREATE OR REPLACE FUNCTION public.profile_lookup(lookup_type lookup_type_enum, identifier text) RETURNS SETOF profile_lookup_result LANGUAGE plpgsql - IMMUTABLE SECURITY DEFINER + STABLE SECURITY DEFINER AS $function$ begin if identifier is null or identifier = '' then raise exception 'identifier cannot be null or empty'; end if; if lookup_type is null then raise exception 'lookup_type cannot be null'; end if; RETURN QUERY - WITH current_distribution_id AS ( - SELECT id FROM distributions - WHERE qualification_start <= CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - AND qualification_end >= CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - ORDER BY qualification_start DESC - LIMIT 1 - ) SELECT - case when p.id = ( select auth.uid() ) then p.id end, - p.avatar_url::text, - p.name::text, - p.about::text, - p.referral_code, - CASE WHEN p.is_public THEN p.x_username ELSE NULL END, - CASE WHEN p.is_public THEN p.birthday ELSE NULL END, - COALESCE(mt.name, t.name), - sa.address, - sa.chain_id, - case when current_setting('role')::text = 'service_role' then p.is_public - when p.is_public then true - else false end, - p.send_id, - ( select array_agg(t2.name::text) - from tags t2 - join send_account_tags sat2 on sat2.tag_id = t2.id - join send_accounts sa2 on sa2.id = sat2.send_account_id - where sa2.user_id = p.id and t2.status = 'confirmed'::tag_status ), - case when p.id = ( select auth.uid() ) then sa.main_tag_id end, - mt.name::text, - CASE WHEN p.is_public THEN -(SELECT array_agg(link_in_bio_row) - FROM ( - SELECT ROW( - CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.id ELSE NULL END, - CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.user_id ELSE NULL END, - lib.handle, - lib.domain_name, - lib.created_at, - lib.updated_at, - lib.domain - )::link_in_bio as link_in_bio_row - FROM link_in_bio lib - WHERE lib.user_id = p.id AND lib.handle IS NOT NULL - ) sub) - ELSE NULL - END, - p.banner_url::text, - CASE WHEN ds.user_id IS NOT NULL THEN true ELSE false END AS is_verified - from profiles p - join auth.users a on a.id = p.id - left join send_accounts sa on sa.user_id = p.id - left join tags mt on mt.id = sa.main_tag_id - left join send_account_tags sat on sat.send_account_id = sa.id - left join tags t on t.id = sat.tag_id and t.status = 'confirmed'::tag_status - left join distribution_shares ds on ds.user_id = p.id - and ds.distribution_id = (select id from current_distribution_id) - where ((lookup_type = 'sendid' and p.send_id::text = identifier) or - (lookup_type = 'tag' and t.name = identifier::citext) or - (lookup_type = 'refcode' and p.referral_code = identifier) or - (lookup_type = 'address' and sa.address = identifier) or - (p.is_public and lookup_type = 'phone' and a.phone::text = identifier)) - and (p.is_public - or ( select auth.uid() ) is not null - or current_setting('role')::text = 'service_role') - limit 1; + CASE WHEN p.id = (SELECT auth.uid()) THEN p.id END AS id, + p.avatar_url::text AS avatar_url, + p.name::text AS name, + p.about::text AS about, + p.referral_code AS refcode, + CASE WHEN p.is_public THEN p.x_username ELSE NULL END AS x_username, + CASE WHEN p.is_public THEN p.birthday ELSE NULL END AS birthday, + COALESCE(mt.name, t.name) AS tag, + sa.address AS address, + sa.chain_id AS chain_id, + CASE WHEN current_setting('role')::text = 'service_role' THEN p.is_public + WHEN p.is_public THEN true ELSE false END AS is_public, + p.send_id AS sendid, + ( + SELECT array_agg(t2.name::text) + FROM tags t2 + JOIN send_account_tags sat2 ON sat2.tag_id = t2.id + JOIN send_accounts sa2 ON sa2.id = sat2.send_account_id + WHERE sa2.user_id = p.id AND t2.status = 'confirmed'::tag_status + ) AS all_tags, + CASE WHEN p.id = (SELECT auth.uid()) THEN sa.main_tag_id END AS main_tag_id, + mt.name::text AS main_tag_name, + CASE WHEN p.is_public THEN ( + SELECT array_agg(link_in_bio_row) + FROM ( + SELECT ROW( + CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.id ELSE NULL END, + CASE WHEN lib.user_id = (SELECT auth.uid()) THEN lib.user_id ELSE NULL END, + lib.handle, + lib.domain_name, + lib.created_at, + lib.updated_at, + lib.domain + )::link_in_bio AS link_in_bio_row + FROM link_in_bio lib + WHERE lib.user_id = p.id AND lib.handle IS NOT NULL + ) sub + ) ELSE NULL END AS links_in_bio, + p.banner_url::text AS banner_url, + (verified_at_result IS NOT NULL) AS is_verified, + verified_at_result AS verified_at + FROM ( + SELECT + p.*, + public.verified_at(p) AS verified_at_result + FROM profiles p + JOIN auth.users a ON a.id = p.id + LEFT JOIN send_accounts sa ON sa.user_id = p.id + LEFT JOIN tags mt ON mt.id = sa.main_tag_id + LEFT JOIN send_account_tags sat ON sat.send_account_id = sa.id + LEFT JOIN tags t ON t.id = sat.tag_id AND t.status = 'confirmed'::tag_status + WHERE ((lookup_type = 'sendid' AND p.send_id::text = identifier) OR + (lookup_type = 'tag' AND t.name = identifier::citext) OR + (lookup_type = 'refcode' AND p.referral_code = identifier) OR + (lookup_type = 'address' AND sa.address = identifier) OR + (p.is_public AND lookup_type = 'phone' AND a.phone::text = identifier)) + AND (p.is_public OR (SELECT auth.uid()) IS NOT NULL OR current_setting('role')::text = 'service_role') + LIMIT 1 + ) p + LEFT JOIN auth.users a ON a.id = p.id + LEFT JOIN send_accounts sa ON sa.user_id = p.id + LEFT JOIN tags mt ON mt.id = sa.main_tag_id + LEFT JOIN send_account_tags sat ON sat.send_account_id = sa.id + LEFT JOIN tags t ON t.id = sat.tag_id AND t.status = 'confirmed'::tag_status; end; $function$ ; @@ -542,9 +544,11 @@ create or replace view "public"."referrer" as WITH referrer AS ( p.main_tag_name, p.links_in_bio, p.banner_url, - referrer.send_id + referrer.send_id, + p.is_verified, + p.verified_at FROM (profile_lookup('sendid'::lookup_type_enum, ( SELECT (referrer_1.send_id)::text AS send_id - 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) + 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) JOIN referrer ON ((referrer.send_id IS NOT NULL))) ) SELECT profile_lookup.id, @@ -564,7 +568,9 @@ create or replace view "public"."referrer" as WITH referrer AS ( profile_lookup.main_tag_name, profile_lookup.links_in_bio, profile_lookup.send_id, - profile_lookup.banner_url + profile_lookup.banner_url, + profile_lookup.verified_at, + profile_lookup.is_verified FROM profile_lookup; ALTER TABLE "public"."referrer" OWNER TO "postgres"; diff --git a/supabase/schemas/send_token_transfers.sql b/supabase/schemas/send_token_transfers.sql index e2c713cf6..2809ca177 100644 --- a/supabase/schemas/send_token_transfers.sql +++ b/supabase/schemas/send_token_transfers.sql @@ -187,3 +187,59 @@ DEFERRABLE INITIALLY DEFERRED FOR EACH ROW EXECUTE FUNCTION "public"."refresh_scores_on_distribution_change"(); CREATE OR REPLACE TRIGGER "filter_send_token_transfers_with_no_send_account_created" BEFORE INSERT ON "public"."send_token_transfers" FOR EACH ROW EXECUTE FUNCTION "private"."filter_send_token_transfers_with_no_send_account_created"(); + +-- Function: send_token_balance +-- Sums SEND token transfers for a user's send account. +-- - Address matching via concat('0x', encode(stt.f,'hex'))::citext +-- - Converting account address to bytea via decode(replace(address,'0x',''),'hex') +-- NOTE: this function relies on our shovel indexer. If the indexer misses a tx, the balance will be incorrect. +CREATE OR REPLACE FUNCTION public.send_token_balance(p_user_id uuid) +RETURNS numeric +LANGUAGE plpgsql +SECURITY DEFINER +SET search_path TO 'public' +AS $function$ +DECLARE + account_address bytea; + account_block_time numeric; + result_balance numeric; +BEGIN + -- Get account address and convert created_at to block_time + SELECT + decode(replace(sa.address::text, ('0x'::citext)::text, ''::text), 'hex'), + EXTRACT(EPOCH FROM sa.created_at) + INTO account_address, account_block_time + FROM public.send_accounts sa + WHERE sa.user_id = p_user_id; + + -- Return 0 if no account found + IF account_address IS NULL THEN + RETURN 0; + END IF; + + -- Sum transfers starting from account creation (with 1 hour buffer) + SELECT COALESCE(SUM( + CASE + WHEN stt.t = account_address AND stt.f = account_address THEN 0::numeric -- Self-transfer = net 0 + WHEN stt.t = account_address THEN stt.v::numeric + WHEN stt.f = account_address THEN -stt.v::numeric + ELSE 0::numeric + END + ), 0::numeric) + INTO result_balance + FROM public.send_token_transfers stt + WHERE stt.block_time >= (account_block_time - 3600) -- Subtract 1 hour buffer + AND (stt.t = account_address OR stt.f = account_address); + + RETURN result_balance; +END; +$function$ +; + +ALTER FUNCTION "public"."send_token_balance"("p_user_id" "uuid") OWNER TO "postgres"; + +-- Grants +REVOKE ALL ON FUNCTION "public"."send_token_balance"("p_user_id" "uuid") FROM PUBLIC; +GRANT ALL ON FUNCTION "public"."send_token_balance"("p_user_id" "uuid") TO "anon"; +GRANT ALL ON FUNCTION "public"."send_token_balance"("p_user_id" "uuid") TO "authenticated"; +GRANT ALL ON FUNCTION "public"."send_token_balance"("p_user_id" "uuid") TO "service_role"; \ No newline at end of file diff --git a/supabase/schemas/tags.sql b/supabase/schemas/tags.sql index 044678fa3..70a81270a 100644 --- a/supabase/schemas/tags.sql +++ b/supabase/schemas/tags.sql @@ -401,7 +401,7 @@ ALTER FUNCTION "public"."tags_before_insert_or_update_func"() OWNER TO "postgres CREATE OR REPLACE FUNCTION public.tag_search(query text, limit_val integer, offset_val integer) RETURNS TABLE(send_id_matches tag_search_result[], tag_matches tag_search_result[], phone_matches tag_search_result[]) LANGUAGE plpgsql - IMMUTABLE SECURITY DEFINER + STABLE SECURITY DEFINER AS $function$ BEGIN IF limit_val IS NULL OR(limit_val <= 0 OR limit_val > 100) THEN @@ -411,125 +411,154 @@ BEGIN RAISE EXCEPTION 'offset_val must be greater than or equal to 0'; END IF; RETURN query - WITH current_distribution_id AS ( - -- Get current distribution once - SELECT id FROM distributions - WHERE qualification_start <= CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - AND qualification_end >= CURRENT_TIMESTAMP AT TIME ZONE 'UTC' - ORDER BY qualification_start DESC - LIMIT 1 - ) SELECT -- send_id matches ( SELECT - array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified)::public.tag_search_result) - FROM( - SELECT - p.avatar_url, - t.name AS tag_name, - p.send_id, - NULL::text AS phone, - CASE WHEN ds.user_id IS NOT NULL THEN true ELSE false END AS is_verified - FROM - profiles p - LEFT JOIN send_accounts sa ON sa.user_id = p.id - LEFT JOIN send_account_tags sat ON sat.send_account_id = sa.id - LEFT JOIN tags t ON t.id = sat.tag_id - AND t.status = 'confirmed' - LEFT JOIN distribution_shares ds ON ds.user_id = p.id - AND ds.distribution_id = (SELECT id FROM current_distribution_id) - WHERE - query SIMILAR TO '\d+' - AND p.send_id::varchar LIKE '%' || query || '%' - ORDER BY - p.send_id - LIMIT limit_val offset offset_val) sub) AS send_id_matches, - -- tag matches - ( - SELECT - array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified)::public.tag_search_result) - FROM ( - SELECT - ranked_matches.avatar_url, - ranked_matches.tag_name, - ranked_matches.send_id, - ranked_matches.phone, - ranked_matches.is_verified + array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified, sub.verified_at)::public.tag_search_result) FROM ( - WITH scores AS ( - -- Aggregate user send scores, summing all scores for cumulative activity - SELECT - user_id, - SUM(score) AS total_score - FROM private.send_scores_history - GROUP BY user_id - ), - tag_matches AS ( + WITH candidates AS ( SELECT + p.id AS user_id, p.avatar_url, - t.name AS tag_name, p.send_id, - NULL::text AS phone, - CASE WHEN ds.user_id IS NOT NULL THEN true ELSE false END AS is_verified, - (t.name <-> query) AS distance, -- Trigram distance: 0=exact, higher=different - COALESCE(scores.total_score, 0) AS send_score, - -- Compute exact match flag in CTE - LOWER(t.name) = LOWER(query) AS is_exact, - -- Primary ranking: exact matches (primary_rank=0) always outrank fuzzy matches (primary_rank=1) - CASE WHEN LOWER(t.name) = LOWER(query) THEN 0 ELSE 1 END AS primary_rank + NULL::text AS phone FROM profiles p - JOIN send_accounts sa ON sa.user_id = p.id - JOIN send_account_tags sat ON sat.send_account_id = sa.id - JOIN tags t ON t.id = sat.tag_id - AND t.status = 'confirmed' - LEFT JOIN scores ON scores.user_id = p.id - LEFT JOIN distribution_shares ds ON ds.user_id = p.id - AND ds.distribution_id = (SELECT id FROM current_distribution_id) WHERE - -- Use ILIKE '%' only when NOT exact to avoid excluding true exact matches like 'Ethen_' - LOWER(t.name) = LOWER(query) - OR (NOT (LOWER(t.name) = LOWER(query)) AND (t.name <<-> query < 0.7 OR t.name ILIKE '%' || query || '%')) + query SIMILAR TO '\d+' + AND p.send_id::varchar LIKE '%' || query || '%' + ORDER BY p.send_id + ), + page AS ( + SELECT + c.user_id, + c.avatar_url, + c.send_id, + c.phone + FROM candidates c + ORDER BY c.send_id ASC + LIMIT limit_val OFFSET offset_val + ), + enriched AS ( + SELECT + page.avatar_url, + ct.tag_name AS tag_name, + page.send_id, + page.phone, + (va.verified_at_result IS NOT NULL) AS is_verified, + va.verified_at_result AS verified_at + FROM page + LEFT JOIN LATERAL ( + SELECT t.name AS tag_name + FROM send_accounts sa2 + JOIN send_account_tags sat2 ON sat2.send_account_id = sa2.id + JOIN tags t ON t.id = sat2.tag_id AND t.status = 'confirmed' + WHERE sa2.user_id = page.user_id + ORDER BY t.name ASC + LIMIT 1 + ) ct ON true + JOIN profiles p2 ON p2.id = page.user_id + CROSS JOIN LATERAL ( + SELECT public.verified_at(p2) AS verified_at_result + ) va ) + SELECT * FROM enriched + ) sub) AS send_id_matches, + -- tag matches + ( + SELECT + array_agg(ROW(sub.avatar_url, sub.tag_name, sub.send_id, sub.phone, sub.is_verified, sub.verified_at)::public.tag_search_result) + FROM ( + WITH scores AS ( + -- Aggregate user send scores, summing all scores for cumulative activity SELECT - tm.avatar_url, - tm.tag_name, - tm.send_id, - tm.phone, - tm.is_verified, - tm.distance, - tm.send_score, - tm.is_exact, - tm.primary_rank, + user_id, + SUM(score) AS total_score + FROM private.send_scores_history + GROUP BY user_id + ), + candidates AS ( + SELECT + p.id AS user_id, + p.avatar_url, + t.name AS tag_name, + p.send_id, + NULL::text AS phone, + (t.name <-> query) AS distance, + COALESCE(scores.total_score, 0) AS send_score, + LOWER(t.name) = LOWER(query) AS is_exact, + CASE WHEN LOWER(t.name) = LOWER(query) THEN 0 ELSE 1 END AS primary_rank + FROM profiles p + JOIN send_accounts sa ON sa.user_id = p.id + JOIN send_account_tags sat ON sat.send_account_id = sa.id + JOIN tags t ON t.id = sat.tag_id + AND t.status = 'confirmed' + LEFT JOIN scores ON scores.user_id = p.id + WHERE + LOWER(t.name) = LOWER(query) + OR (NOT (LOWER(t.name) = LOWER(query)) AND (t.name <<-> query < 0.7 OR t.name ILIKE '%' || query || '%')) + ), + ranked AS ( + SELECT + c.user_id, + c.avatar_url, + c.tag_name, + c.send_id, + c.phone, + c.distance, + c.send_score, + c.is_exact, + c.primary_rank, ( - -- Secondary ranking varies by match type: - -- For exact matches (primary_rank=0): use negative send_score (higher score = better/lower secondary rank) - -- For fuzzy matches (primary_rank=1): use old trigram + send_score formula CASE - WHEN tm.is_exact THEN - -tm.send_score -- Negative for DESC ordering within exact matches + WHEN c.is_exact THEN + -c.send_score ELSE - -- Old fuzzy ranking formula: distance - (send_score / 1M) - CASE WHEN tm.distance IS NULL THEN 0 ELSE tm.distance END - - (tm.send_score / 1000000.0) + CASE WHEN c.distance IS NULL THEN 0 ELSE c.distance END + - (c.send_score / 1000000.0) END ) AS secondary_rank, - ROW_NUMBER() OVER (PARTITION BY tm.send_id ORDER BY ( - -- Deduplication uses same ranking logic as main ordering - tm.primary_rank, -- Primary: exact vs fuzzy + ROW_NUMBER() OVER (PARTITION BY c.send_id ORDER BY ( + c.primary_rank, CASE - WHEN tm.is_exact THEN - -tm.send_score -- Secondary: send_score DESC for exact + WHEN c.is_exact THEN + -c.send_score ELSE - CASE WHEN tm.distance IS NULL THEN 0 ELSE tm.distance END - - (tm.send_score / 1000000.0) -- Secondary: old formula for fuzzy + CASE WHEN c.distance IS NULL THEN 0 ELSE c.distance END + - (c.send_score / 1000000.0) END )) AS rn - FROM tag_matches tm - ) ranked_matches - WHERE ranked_matches.rn = 1 - ORDER BY ranked_matches.primary_rank ASC, ranked_matches.secondary_rank ASC - LIMIT limit_val OFFSET offset_val + FROM candidates c + ), + page AS ( + SELECT + r.user_id, + r.avatar_url, + r.tag_name, + r.send_id, + r.phone, + r.primary_rank, + r.secondary_rank + FROM ranked r + WHERE r.rn = 1 + ORDER BY r.primary_rank ASC, r.secondary_rank ASC + LIMIT limit_val OFFSET offset_val + ), + enriched AS ( + SELECT + page.avatar_url, + page.tag_name, + page.send_id, + page.phone, + (va.verified_at_result IS NOT NULL) AS is_verified, + va.verified_at_result AS verified_at + FROM page + JOIN profiles p2 ON p2.id = page.user_id + CROSS JOIN LATERAL ( + SELECT public.verified_at(p2) AS verified_at_result + ) va + ) + SELECT * FROM enriched ) sub ) AS tag_matches, -- phone matches, disabled for now diff --git a/supabase/schemas/types.sql b/supabase/schemas/types.sql index 9cb8ac14f..8a307e165 100644 --- a/supabase/schemas/types.sql +++ b/supabase/schemas/types.sql @@ -36,7 +36,8 @@ CREATE TYPE "public"."tag_search_result" AS ( "tag_name" "text", "send_id" integer, "phone" "text", - "is_verified" boolean + "is_verified" boolean, + "verified_at" timestamptz ); ALTER TYPE "public"."tag_search_result" OWNER TO "postgres"; diff --git a/supabase/tests/tags_search_and_lookup_test.sql b/supabase/tests/tags_search_and_lookup_test.sql index 9740c1d0f..8ee466760 100644 --- a/supabase/tests/tags_search_and_lookup_test.sql +++ b/supabase/tests/tags_search_and_lookup_test.sql @@ -1,5 +1,5 @@ BEGIN; -SELECT plan(24); +SELECT plan(22); CREATE EXTENSION IF NOT EXISTS "basejump-supabase_test_helpers"; @@ -249,10 +249,10 @@ SELECT ok( 'Search works with various character types' ); --- Test 14: Search functionality is case-insensitive +-- Test 14: Search functionality respects citext case-insensitive behavior SELECT ok( (SELECT tag_matches FROM tag_search('ALICE', 10, 0)) IS NOT NULL, - 'Tag search is case-insensitive' + 'Tag search respects citext case-insensitive behavior - ALICE matches alice' ); -- Test 15: Comprehensive search returns multiple match types @@ -309,14 +309,14 @@ SELECT tests.create_supabase_user('low_scorer'); -- Create send accounts for score test users INSERT INTO send_accounts (user_id, address, chain_id, init_code) -VALUES +VALUES (tests.get_supabase_uid('score_impostor'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF88', 8453, '\\x00'), (tests.get_supabase_uid('score_genuine'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF99', 8453, '\\x00'), (tests.get_supabase_uid('low_scorer'), '0xABCDEF1234567890ABCDEF1234567890ABCDEFAA', 8453, '\\x00'); -- Set up profiles for score test users INSERT INTO profiles (id, name, about, avatar_url, is_public) -VALUES +VALUES (tests.get_supabase_uid('score_impostor'), 'High Score Impostor', 'Has high send score but fuzzy tag match', 'https://example.com/impostor.jpg', true), (tests.get_supabase_uid('score_genuine'), 'Low Score Genuine', 'Has low send score but exact tag match', 'https://example.com/genuine.jpg', true), (tests.get_supabase_uid('low_scorer'), 'Low Scorer', 'Has low send score', 'https://example.com/lowscore.jpg', true) @@ -325,7 +325,7 @@ ON CONFLICT (id) DO UPDATE SET name = EXCLUDED.name, about = EXCLUDED.about, ava -- Insert tags with deterministic trigram distances -- 'alic3' vs 'aliceX' for predictable trigram behavior (avoiding conflict with 'alice' from earlier tests) INSERT INTO tags (name, user_id, status) -VALUES +VALUES ('alic3', tests.get_supabase_uid('score_impostor'), 'confirmed'), -- Fuzzy match for 'aliceX' ('aliceX', tests.get_supabase_uid('score_genuine'), 'confirmed'), -- Exact match for 'aliceX' ('david', tests.get_supabase_uid('low_scorer'), 'confirmed'); -- Unrelated tag @@ -409,59 +409,5 @@ select ok( 'Trigram distance between alic3 and alice should be deterministic and moderate' ); --- ===== NEW CASE-SENSITIVE EXACT MATCH TESTS ===== -SET ROLE service_role; - --- Create test users for case-sensitive tag matching within combined lookup tests -SELECT tests.create_supabase_user('case_ethen_high'); -SELECT tests.create_supabase_user('case_ethen_low'); - --- Create send accounts for case-sensitive test users -INSERT INTO send_accounts (user_id, address, chain_id, init_code) -VALUES - (tests.get_supabase_uid('case_ethen_high'), '0xABCDEF1234567890ABCDEF1234567890ABCDEFDD', 8453, '\\x00'), - (tests.get_supabase_uid('case_ethen_low'), '0xABCDEF1234567890ABCDEF1234567890ABCDEFEE', 8453, '\\x00'); - --- Set up profiles for case-sensitive test users -INSERT INTO profiles (id, name, about, avatar_url, is_public) -VALUES - (tests.get_supabase_uid('case_ethen_high'), 'Case High Score', 'Has high send score with ethen tag', 'https://example.com/case_ethen_high.jpg', true), - (tests.get_supabase_uid('case_ethen_low'), 'Case Low Score', 'Has low send score with Ethen_ tag', 'https://example.com/case_ethen_low.jpg', true) -ON CONFLICT (id) DO UPDATE SET name = EXCLUDED.name, about = EXCLUDED.about, avatar_url = EXCLUDED.avatar_url, is_public = EXCLUDED.is_public; - --- Insert case-sensitive tags with contrasting scores --- 'ethen' will get high score, 'Ethen_' will get low score -INSERT INTO tags (name, user_id, status) -VALUES - ('ethen', tests.get_supabase_uid('case_ethen_high'), 'confirmed'), - ('Ethen_', tests.get_supabase_uid('case_ethen_low'), 'confirmed'); - --- Create send_account_tags associations for case-sensitive tags -INSERT INTO send_account_tags (send_account_id, tag_id) -SELECT sa.id, t.id -FROM send_accounts sa -JOIN tags t ON t.user_id = sa.user_id -WHERE t.name IN ('ethen', 'Ethen_'); - --- Send scores will be computed by the materialized view, not inserted directly - -SELECT tests.authenticate_as('search_user1'); - --- Test 23: Case-sensitive exact match in combined search and lookup --- When searching for 'Ethen_', the exact match should be found -select ok( - EXISTS(SELECT 1 FROM tag_search('Ethen_', 10, 0) - WHERE tag_matches IS NOT NULL AND array_length(tag_matches, 1) > 0 - AND (tag_matches[1]).tag_name = 'Ethen_'), - 'Case-sensitive exact match Ethen_ should be found in combined search' -); - --- Test 24: Profile lookup should work for case-sensitive exact matches -SELECT ok(EXISTS( - SELECT 1 FROM profile_lookup('tag'::lookup_type_enum, 'Ethen_') pl - WHERE pl.name = 'Case Low Score' - AND pl.tag = 'Ethen_' -), 'Profile lookup should find case-sensitive exact match Ethen_'); - SELECT * FROM finish(); ROLLBACK; diff --git a/supabase/tests/tags_search_test.sql b/supabase/tests/tags_search_test.sql index 5f8ef7051..843b8267b 100644 --- a/supabase/tests/tags_search_test.sql +++ b/supabase/tests/tags_search_test.sql @@ -1,7 +1,7 @@ -- Tag Search begin; -select plan(13); +select plan(12); create extension "basejump-supabase_test_helpers"; -- noqa: RF05 @@ -87,7 +87,8 @@ select results_eq($$ 'alice', -- tag_name $$ || :alice_send_id || $$, -- alice's send_id null, -- phone, - false -- is_verified + false, -- is_verified + null -- verified_at )::tag_search_result] ) $$, 'Tags should be visible to the authenticated user'); @@ -122,7 +123,8 @@ select results_eq($$ 'alice', -- tag_name $$ || :alice_send_id || $$, -- alice's send_id null, -- phone - false -- is_verified + false, -- is_verified + null -- verified_at )::tag_search_result] ) $$, 'You can search by send_id'); @@ -166,14 +168,14 @@ select tests.create_supabase_user('bossman_user'); -- Insert tags for testing distance-based ordering insert into tags (name, user_id, status) -values +values ('bigboss', tests.get_supabase_uid('bigboss_user'), 'confirmed'), ('Boss', tests.get_supabase_uid('boss_user'), 'confirmed'), ('bossman', tests.get_supabase_uid('bossman_user'), 'confirmed'); -- Create send accounts for the new users insert into send_accounts (user_id, address, chain_id, init_code) -values +values (tests.get_supabase_uid('bigboss_user'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF11', 8453, '\\x00'), (tests.get_supabase_uid('boss_user'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF22', 8453, '\\x00'), (tests.get_supabase_uid('bossman_user'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF33', 8453, '\\x00'); @@ -203,14 +205,14 @@ select tests.create_supabase_user('multi_tag_user'); -- Insert multiple tags for the same user that would match "test" insert into tags (name, user_id, status) -values +values ('test', tests.get_supabase_uid('multi_tag_user'), 'confirmed'), ('tester', tests.get_supabase_uid('multi_tag_user'), 'confirmed'), ('testing', tests.get_supabase_uid('multi_tag_user'), 'confirmed'); -- Create send account for multi_tag_user insert into send_accounts (user_id, address, chain_id, init_code) -values +values (tests.get_supabase_uid('multi_tag_user'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF44', 8453, '\\x00'); -- Create send_account_tags associations for all tags @@ -227,13 +229,13 @@ select tests.authenticate_as('neo'); -- Test deduplication: should return only ONE result for the user, with the best matching tag select results_eq($$ - SELECT array_length(tag_matches, 1) from tag_search('test', 10, 0) + SELECT array_length(tag_matches, 1) from tag_search('test', 10, 0) WHERE (tag_matches[1]).avatar_url = 'multi_tag_avatar'; $$, $$ values (1) $$, 'Should return only one result per profile even with multiple matching tags'); -- Test that the best match (exact match "test") is returned for the multi-tag user select results_eq($$ - SELECT (tag_matches[i]).tag_name + SELECT (tag_matches[i]).tag_name FROM tag_search('test', 10, 0), generate_series(1, array_length(tag_matches, 1)) as i WHERE (tag_matches[i]).avatar_url = 'multi_tag_avatar'; $$, $$ values ('test'::text) $$, 'Should return the best matching tag (exact match) for profile with multiple tags'); @@ -251,14 +253,14 @@ select tests.create_supabase_user('low_score_charlie'); -- Insert tags - impostor has 'alic3' (fuzzy match for 'aliceY'), genuine has 'aliceY' (exact match) insert into tags (name, user_id, status) -values +values ('alic3', tests.get_supabase_uid('impostor_alice'), 'confirmed'), -- trigram distance ~0.3 from 'aliceY' ('aliceY', tests.get_supabase_uid('genuine_alice'), 'confirmed'), -- exact match, distance 0 ('charlie', tests.get_supabase_uid('low_score_charlie'), 'confirmed'); -- for testing non-exact filtering -- Create send accounts for all users insert into send_accounts (user_id, address, chain_id, init_code) -values +values (tests.get_supabase_uid('impostor_alice'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF55', 8453, '\\x00'), (tests.get_supabase_uid('genuine_alice'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF66', 8453, '\\x00'), (tests.get_supabase_uid('low_score_charlie'), '0xABCDEF1234567890ABCDEF1234567890ABCDEF77', 8453, '\\x00'); @@ -347,47 +349,6 @@ select ok( 'Trigram distance between alic3 and alice should be deterministic and measurable' ); --- ===== NEW CASE-SENSITIVE EXACT MATCH TESTS ===== -select tests.authenticate_as_service_role(); - --- Create test users for case-sensitive tag matching -select tests.create_supabase_user('ethen_high_score'); -select tests.create_supabase_user('ethen_low_score'); - --- Insert case-sensitive tags - 'ethen' (will get high score) and 'Ethen_' (will get low score) -insert into tags (name, user_id, status) -values - ('ethen', tests.get_supabase_uid('ethen_high_score'), 'confirmed'), - ('Ethen_', tests.get_supabase_uid('ethen_low_score'), 'confirmed'); - --- Create send accounts for the case-sensitive test users -insert into send_accounts (user_id, address, chain_id, init_code) -values - (tests.get_supabase_uid('ethen_high_score'), '0xABCDEF1234567890ABCDEF1234567890ABCDEFBB', 8453, '\\x00'), - (tests.get_supabase_uid('ethen_low_score'), '0xABCDEF1234567890ABCDEF1234567890ABCDEFCC', 8453, '\\x00'); - --- Create send_account_tags associations -insert into send_account_tags (send_account_id, tag_id) -select sa.id, t.id -from send_accounts sa -join tags t on t.user_id = sa.user_id -where t.name in ('ethen', 'Ethen_'); - --- Set avatars for testing -update profiles set avatar_url = 'ethen_high_avatar' where id = tests.get_supabase_uid('ethen_high_score'); -update profiles set avatar_url = 'ethen_low_avatar' where id = tests.get_supabase_uid('ethen_low_score'); - --- Send scores will be computed by the materialized view, not inserted directly --- For case-sensitive exact match tests, we rely on the trigram distance prioritization - -select tests.authenticate_as('neo'); - --- Test case-sensitive exact match prioritization --- When searching for 'Ethen_', the exact match 'Ethen_' should appear first -select ok(exists( - SELECT 1 FROM tag_search('Ethen_', 20, 0) - WHERE (tag_matches[1]).tag_name = 'Ethen_' -), 'Case-sensitive exact match Ethen_ should appear first'); select finish(); rollback;