# Search Function Debugging Journey ## Problem Summary The search function was returning a 401 "Invalid JWT" error, then after deployment continued to return empty results despite the function being deployed. ## Timeline of Issues and Fixes ### Issue 1: Function Not Deployed **Problem:** The search function existed in code but was never deployed to Supabase. **Error:** ``` FunctionException(status: 401, details: {code: 401, message: Invalid JWT}) ``` **Root Cause:** The function was missing from the deployment list in `deploy_all_functions.ps1`. **Fix:** 1. Added `"search"` to the `$functions` array in `deploy_all_functions.ps1` 2. Deployed with: `supabase functions deploy search --no-verify-jwt` --- ### Issue 2: Critical Code Bugs After deployment, the function was returning 400 errors. Analysis revealed three critical bugs: #### Bug 1: Performance - "Download the Internet" Bug **Problem:** The tag search query had no limit and downloaded ALL posts into memory. **Bad Code:** ```typescript const { data: tagData } = await serviceClient .from("posts") .select("tags") .not("tags", "is", null) .is("deleted_at", null); // NO LIMIT! ``` **Impact:** Would timeout or crash with 1000+ posts in database. **Fix:** Use a database view to aggregate tags at the database level: ```typescript const { data: tagsResult } = await serviceClient .from("view_searchable_tags") .select("tag, count") .ilike("tag", `%${safeQuery}%`) .order("count", { ascending: false }) .limit(5); ``` **View SQL:** ```sql CREATE OR REPLACE VIEW view_searchable_tags AS SELECT unnest(tags) as tag, COUNT(*) as count FROM posts WHERE deleted_at IS NULL AND tags IS NOT NULL AND array_length(tags, 1) > 0 GROUP BY unnest(tags) ORDER BY count DESC; ``` #### Bug 2: Syntax Error - Array Filter **Problem:** PostgREST expects an array for `in` filters, not a formatted string. **Bad Code:** ```typescript .not("id", "in", `(${excludeIds.join(",")})`) // Wrong: passing string ``` **Error:** `PGRST100` - PostgREST syntax error **Fix:** Pass array with proper PostgREST string format: ```typescript if (excludeIds.length > 0) { dbQuery = dbQuery.not("id", "in", `(${excludeIds.join(",")})`); } ``` Note: Must use the string format `(val1,val2)` for PostgREST, and check for empty array first. #### Bug 3: Security - SQL Injection Risk **Problem:** User input wasn't sanitized, allowing special characters to break PostgREST query syntax. **Bad Code:** ```typescript const trimmedQuery = query.trim().toLowerCase(); // User searches "hello,world" -> breaks OR syntax ``` **Impact:** Commas and parentheses in user input caused 500 errors. **Fix:** Sanitize query string: ```typescript const safeQuery = query.trim().toLowerCase().replace(/[,()]/g, ""); ``` --- ### Issue 3: Wrong Column Name in blocks Table **Problem:** Code referenced `user_id` column that doesn't exist. **Error:** ``` ERROR: column blocks.user_id does not exist SQL state code: 42703 ``` **Bad Code:** ```typescript const { data: blockedUsers } = await serviceClient .from("blocks") .select("blocked_id") .eq("user_id", user.id); // Wrong column name! ``` **Actual Schema:** ```sql CREATE TABLE blocks ( blocker_id UUID NOT NULL, blocked_id UUID NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), PRIMARY KEY (blocker_id, blocked_id) ); ``` **Fix:** ```typescript const { data: blockedUsers } = await serviceClient .from("blocks") .select("blocked_id") .eq("blocker_id", user.id); // Correct column name ``` --- ### Issue 4: Ambiguous Foreign Key Relationship **Problem:** PostgREST couldn't determine which foreign key to use for the profiles join. **Error:** `PGRST201` - "Multiple objects found for foreign key" **Bad Code:** ```typescript .select("id, body, created_at, author_id, author:profiles!inner(handle, display_name)") ``` **Root Cause:** The `posts` table has multiple foreign key relationships to `profiles` table, making the join ambiguous. **Fix:** Explicitly specify the foreign key constraint name: ```typescript .select("id, body, created_at, author_id, profiles!posts_author_id_fkey(handle, display_name)") ``` **Updated Processing Code:** ```typescript const searchPosts: SearchPost[] = (postsResult.data || []).map((p: any) => ({ id: p.id, body: p.body, author_id: p.author_id, author_handle: p.profiles?.handle || "unknown", author_display_name: p.profiles?.display_name || "Unknown User", created_at: p.created_at })); ``` --- ## Additional Improvements ### Parallel Query Execution Used `Promise.all()` to run all three searches (users, tags, posts) simultaneously for better performance: ```typescript const [usersResult, tagsResult, postsResult] = await Promise.all([ // User search (async () => { /* ... */ })(), // Tag search (async () => { /* ... */ })(), // Post search (async () => { /* ... */ })() ]); ``` This reduces total search time from sequential to parallel execution. --- ## Final Working Code Structure ```typescript import { serve } from "https://deno.land/std@0.177.0/http/server.ts"; import { createSupabaseClient, createServiceClient } from "../_shared/supabase-client.ts"; serve(async (req: Request) => { // 1. CORS handling if (req.method === "OPTIONS") { /* ... */ } try { // 2. Auth & Input Parsing const authHeader = req.headers.get("Authorization"); if (!authHeader) throw new Error("Missing authorization header"); let query = /* parse from POST body or query param */; if (!query || query.trim().length === 0) { return new Response(JSON.stringify({ users: [], tags: [], posts: [] }), { status: 200, headers: { "Content-Type": "application/json" } }); } // Sanitize query const safeQuery = query.trim().toLowerCase().replace(/[,()]/g, ""); // Verify auth const supabase = createSupabaseClient(authHeader); const { data: { user }, error: authError } = await supabase.auth.getUser(); if (authError || !user) throw new Error("Unauthorized"); // 3. Get blocked users list const { data: blockedUsers } = await serviceClient .from("blocks") .select("blocked_id") .eq("blocker_id", user.id); const excludeIds = (blockedUsers?.map(b => b.blocked_id) || []); excludeIds.push(user.id); // 4. Parallel search execution const [usersResult, tagsResult, postsResult] = await Promise.all([ // Search users with proper exclusion // Search tags using view // Search posts with explicit FK reference ]); // 5-7. Process results // 8. Return JSON response } catch (error: any) { return new Response( JSON.stringify({ error: error.message || "Internal server error" }), { status: 500, headers: { "Content-Type": "application/json" } } ); } }); ``` --- ## Setup Requirements ### 1. Create Database View The search function requires the `view_searchable_tags` view for efficient tag searching. **Location:** `supabase/migrations/create_searchable_tags_view.sql` **Apply via Supabase Dashboard:** 1. Go to: https://supabase.com/dashboard/project/[YOUR_PROJECT_ID]/sql 2. Run the SQL from the migration file **Verify:** ```sql SELECT * FROM view_searchable_tags LIMIT 10; ``` ### 2. Deploy Function ```powershell supabase functions deploy search --no-verify-jwt ``` Or deploy all functions: ```powershell .\deploy_all_functions.ps1 ``` --- ## Key Learnings ### 1. PostgREST Syntax is Strict - Array filters must use format: `.not("id", "in", "(val1,val2)")` - Empty arrays can cause errors - always check length first - Foreign key relationships must be explicit when ambiguous ### 2. Performance Matters - Never query unlimited rows from large tables - Use database views for aggregations - Use parallel queries (`Promise.all()`) when queries are independent ### 3. Security First - Always sanitize user input before using in queries - Remove special characters that can break query syntax - Characters to watch: `,` `(` `)` `'` `"` ### 4. Schema Knowledge is Critical - Always verify actual column names in schema - Don't assume standard naming conventions - Use `\d table_name` in psql or check migration files ### 5. Explicit is Better Than Implicit - Specify foreign key constraint names when joining tables - Use service client for bypassing RLS - Check for edge cases (empty arrays, null values) --- ## Debugging Checklist When search returns no results: 1. **Check function deployment status** ```bash supabase functions list | grep search ``` 2. **Verify database has data** - Test with broad search terms ("a", "the") - Check posts table has non-deleted records 3. **Review query logs** - Check Supabase Dashboard > Logs - Look for 400/500 errors - Check PostgREST error codes 4. **Verify schema matches code** - Column names correct? - Foreign key names correct? - Required views exist? 5. **Test queries directly in SQL** - Run queries in Supabase SQL editor - Verify they return expected results - Check for RLS policy issues --- ## Files Modified 1. `supabase/functions/search/index.ts` - Complete rewrite 2. `deploy_all_functions.ps1` - Added search to deployment list 3. `supabase/migrations/create_searchable_tags_view.sql` - New view 4. `supabase/CREATE_SEARCH_VIEW.md` - Setup instructions --- ## References - [PostgREST API Documentation](https://postgrest.org/en/stable/api.html) - [Supabase Edge Functions Guide](https://supabase.com/docs/guides/functions) - [docs/troubleshooting/READ_FIRST.md](./READ_FIRST.md) - Authentication patterns