|
| 1 | +CREATE OR REPLACE FUNCTION public.search_jargons( |
| 2 | + search_query text DEFAULT NULL::text, |
| 3 | + sort_option text DEFAULT 'recent'::text, |
| 4 | + limit_count integer DEFAULT 20, |
| 5 | + offset_count integer DEFAULT 0, |
| 6 | + category_acronyms text[] DEFAULT NULL::text[] |
| 7 | +) RETURNS TABLE( |
| 8 | + id uuid, |
| 9 | + name text, |
| 10 | + slug text, |
| 11 | + updated_at timestamptz, |
| 12 | + translations json, |
| 13 | + categories json, |
| 14 | + comments json |
| 15 | +) |
| 16 | +LANGUAGE plpgsql |
| 17 | +AS $$ |
| 18 | +BEGIN |
| 19 | + RETURN QUERY |
| 20 | + ------------------------------------------------------------------ |
| 21 | + -- Precompute allowed jargons by category filter |
| 22 | + ------------------------------------------------------------------ |
| 23 | + WITH allowed_jargon AS ( |
| 24 | + SELECT j.id |
| 25 | + FROM jargon j |
| 26 | + WHERE CASE |
| 27 | + WHEN category_acronyms IS NULL THEN TRUE |
| 28 | + WHEN COALESCE(array_length(category_acronyms, 1), 0) = 0 THEN NOT EXISTS ( |
| 29 | + SELECT 1 FROM jargon_category jc WHERE jc.jargon_id = j.id |
| 30 | + ) |
| 31 | + ELSE EXISTS ( |
| 32 | + SELECT 1 |
| 33 | + FROM jargon_category jc |
| 34 | + JOIN category c ON c.id = jc.category_id |
| 35 | + WHERE jc.jargon_id = j.id |
| 36 | + AND c.acronym = ANY (category_acronyms) |
| 37 | + ) |
| 38 | + END |
| 39 | + ), |
| 40 | + |
| 41 | + ------------------------------------------------------------------ |
| 42 | + -- 1. jargons matched on their own name |
| 43 | + ------------------------------------------------------------------ |
| 44 | + jargon_matches AS ( |
| 45 | + SELECT |
| 46 | + j.id, |
| 47 | + j.name, |
| 48 | + j.slug, |
| 49 | + j.updated_at, |
| 50 | + ( |
| 51 | + SELECT json_agg( |
| 52 | + json_build_object('name', t.name) |
| 53 | + ORDER BY (t.llm_rank IS NULL), t.llm_rank, t.name |
| 54 | + ) |
| 55 | + FROM translation t |
| 56 | + WHERE t.jargon_id = j.id |
| 57 | + ) AS translations, |
| 58 | + ( |
| 59 | + SELECT json_agg(json_build_object('acronym', c.acronym)) |
| 60 | + FROM jargon_category jc |
| 61 | + JOIN category c ON c.id = jc.category_id |
| 62 | + WHERE jc.jargon_id = j.id |
| 63 | + ) AS categories, |
| 64 | + ( |
| 65 | + SELECT json_build_array(json_build_object('count', COUNT(*))) |
| 66 | + FROM comment c |
| 67 | + WHERE c.jargon_id = j.id |
| 68 | + ) AS comments |
| 69 | + FROM jargon j |
| 70 | + JOIN allowed_jargon aj ON aj.id = j.id |
| 71 | + WHERE COALESCE(search_query, '') = '' |
| 72 | + OR j.name ILIKE '%' || search_query || '%' |
| 73 | + ), |
| 74 | + |
| 75 | + ------------------------------------------------------------------ |
| 76 | + -- 2. jargons reached through a translation hit |
| 77 | + ------------------------------------------------------------------ |
| 78 | + translation_hits AS ( |
| 79 | + SELECT DISTINCT j.id |
| 80 | + FROM translation t |
| 81 | + JOIN jargon j ON j.id = t.jargon_id |
| 82 | + JOIN allowed_jargon aj ON aj.id = j.id |
| 83 | + WHERE COALESCE(search_query, '') <> '' |
| 84 | + AND t.name ILIKE '%' || search_query || '%' |
| 85 | + ), |
| 86 | + translation_matches AS ( |
| 87 | + SELECT |
| 88 | + j.id, |
| 89 | + j.name, |
| 90 | + j.slug, |
| 91 | + j.updated_at, |
| 92 | + ( |
| 93 | + SELECT json_agg( |
| 94 | + json_build_object('name', t2.name) |
| 95 | + ORDER BY (t2.llm_rank IS NULL), t2.llm_rank, t2.name |
| 96 | + ) |
| 97 | + FROM translation t2 |
| 98 | + WHERE t2.jargon_id = j.id |
| 99 | + ) AS translations, |
| 100 | + ( |
| 101 | + SELECT json_agg(json_build_object('acronym', c.acronym)) |
| 102 | + FROM jargon_category jc |
| 103 | + JOIN category c ON c.id = jc.category_id |
| 104 | + WHERE jc.jargon_id = j.id |
| 105 | + ) AS categories, |
| 106 | + ( |
| 107 | + SELECT json_build_array(json_build_object('count', COUNT(*))) |
| 108 | + FROM comment c |
| 109 | + WHERE c.jargon_id = j.id |
| 110 | + ) AS comments |
| 111 | + FROM translation_hits th |
| 112 | + JOIN jargon j ON j.id = th.id |
| 113 | + ), |
| 114 | + |
| 115 | + ------------------------------------------------------------------ |
| 116 | + -- 3. union + final de-duplication |
| 117 | + ------------------------------------------------------------------ |
| 118 | + combined AS ( |
| 119 | + SELECT * FROM jargon_matches |
| 120 | + UNION ALL |
| 121 | + SELECT * FROM translation_matches |
| 122 | + ), |
| 123 | + final AS ( |
| 124 | + SELECT DISTINCT ON (combined.id) |
| 125 | + combined.id, |
| 126 | + combined.name, |
| 127 | + combined.slug, |
| 128 | + combined.updated_at, |
| 129 | + combined.translations, |
| 130 | + combined.categories, |
| 131 | + combined.comments |
| 132 | + FROM combined |
| 133 | + ORDER BY combined.id, combined.updated_at DESC |
| 134 | + ) |
| 135 | + |
| 136 | + ------------------------------------------------------------------ |
| 137 | + -- 4. paging with dynamic sorting |
| 138 | + ------------------------------------------------------------------ |
| 139 | + SELECT |
| 140 | + f.id, |
| 141 | + f.name, |
| 142 | + f.slug, |
| 143 | + f.updated_at, |
| 144 | + COALESCE(f.translations, '[]'::json) AS translations, |
| 145 | + COALESCE(f.categories, '[]'::json) AS categories, |
| 146 | + COALESCE(f.comments, '[{"count":0}]'::json) AS comments |
| 147 | + FROM final AS f |
| 148 | + ORDER BY |
| 149 | + CASE WHEN sort_option = 'recent' THEN f.updated_at END DESC, |
| 150 | + CASE WHEN sort_option = 'popular' THEN (f.comments->0->>'count')::integer END DESC, |
| 151 | + CASE WHEN sort_option = 'abc' THEN f.name END ASC, |
| 152 | + CASE WHEN sort_option = 'zyx' THEN f.name END DESC, |
| 153 | + f.updated_at DESC, |
| 154 | + f.id ASC |
| 155 | + LIMIT limit_count |
| 156 | + OFFSET offset_count; |
| 157 | +END; |
| 158 | +$$; |
| 159 | + |
| 160 | +NOTIFY pgrst, 'reload schema'; |
0 commit comments