-- Update search_sojorn function to include post body search -- This replaces the existing function with an enhanced version that searches: -- 1. Users by handle and display name -- 2. Tags from posts.tags array -- 3. Posts by body content and tags CREATE OR REPLACE FUNCTION search_sojorn(p_query TEXT, limit_count INTEGER DEFAULT 10) RETURNS JSON LANGUAGE plpgsql STABLE AS $$ DECLARE result JSON; BEGIN SELECT json_build_object( 'users', (SELECT json_agg(json_build_object('id', p.id, 'username', p.handle, 'display_name', p.display_name, 'avatar_url', p.avatar_url, 'harmony_tier', COALESCE(ts.tier, 'new'))) FROM profiles p LEFT JOIN trust_state ts ON p.id = ts.user_id WHERE p.handle ILIKE '%' || p_query || '%' OR p.display_name ILIKE '%' || p_query || '%' LIMIT limit_count), 'tags', (SELECT json_agg(json_build_object('tag', tag, 'count', cnt)) FROM ( SELECT LOWER(UNNEST(tags)) AS tag, COUNT(*) AS cnt FROM posts WHERE tags IS NOT NULL AND deleted_at IS NULL GROUP BY tag HAVING LOWER(tag) LIKE '%' || LOWER(p_query) || '%' ORDER BY cnt DESC LIMIT limit_count) t), 'posts', (SELECT json_agg(json_build_object('id', post.id, 'body', post.body, 'author_id', post.author_id, 'author_handle', post.handle, 'author_display_name', post.display_name, 'created_at', post.created_at)) FROM ( SELECT po.id, po.body, po.author_id, pr.handle, pr.display_name, po.created_at FROM posts po LEFT JOIN profiles pr ON po.author_id = pr.id WHERE po.deleted_at IS NULL AND po.status = 'active' AND ( po.body ILIKE '%' || p_query || '%' OR EXISTS (SELECT 1 FROM UNNEST(po.tags) AS tag WHERE LOWER(tag) = LOWER(p_query)) ) ORDER BY po.created_at DESC LIMIT limit_count ) post) ) INTO result; RETURN result; END; $$;