|
| 1 | +drop function if exists "public"."get_projects"(search_query text, category_id bigint, sort_by text, limit_val integer, offset_val integer, current_username text); |
| 2 | + |
| 3 | +drop function if exists "public"."get_research"(search_query text, category_id bigint, research_status research_status, sort_by text, limit_val integer, offset_val integer); |
| 4 | + |
| 5 | +set check_function_bodies = off; |
| 6 | + |
| 7 | +CREATE OR REPLACE FUNCTION public.get_projects(search_query text DEFAULT NULL::text, category_id bigint DEFAULT NULL::bigint, sort_by text DEFAULT 'Newest'::text, limit_val integer DEFAULT 12, offset_val integer DEFAULT 0, current_username text DEFAULT NULL::text, days_back integer DEFAULT 7) |
| 8 | + RETURNS TABLE(id bigint, created_at timestamp with time zone, created_by bigint, modified_at timestamp with time zone, description text, slug text, cover_image json, category json, tags text[], title text, moderation text, total_views bigint, author json, comment_count integer, useful_votes_last_week integer) |
| 9 | + LANGUAGE plpgsql |
| 10 | + SET search_path TO 'public', 'pg_temp' |
| 11 | +AS $function$DECLARE |
| 12 | + ts_query tsquery; |
| 13 | +BEGIN |
| 14 | + -- Parse search query once if provided |
| 15 | + IF search_query IS NOT NULL THEN |
| 16 | + ts_query := to_tsquery('english', search_query); |
| 17 | + END IF; |
| 18 | + |
| 19 | + RETURN QUERY |
| 20 | + SELECT |
| 21 | + p.id, |
| 22 | + p.created_at, |
| 23 | + p.created_by, |
| 24 | + p.modified_at, |
| 25 | + p.description, |
| 26 | + p.slug, |
| 27 | + p.cover_image, |
| 28 | + (SELECT json_build_object('id', c.id, 'name', c.name) |
| 29 | + FROM categories c |
| 30 | + WHERE c.id = p.category) AS category, |
| 31 | + p.tags, |
| 32 | + p.title, |
| 33 | + p.moderation, |
| 34 | + p.total_views, |
| 35 | + (SELECT json_build_object( |
| 36 | + 'id', prof.id, |
| 37 | + 'display_name', prof.display_name, |
| 38 | + 'username', prof.username, |
| 39 | + 'country', prof.country, |
| 40 | + 'badges', COALESCE( |
| 41 | + (SELECT json_agg( |
| 42 | + json_build_object( |
| 43 | + 'id', pb.id, |
| 44 | + 'name', pb.name, |
| 45 | + 'display_name', pb.display_name, |
| 46 | + 'image_url', pb.image_url, |
| 47 | + 'action_url', pb.action_url |
| 48 | + ) |
| 49 | + ) |
| 50 | + FROM profile_badges_relations pbr |
| 51 | + JOIN profile_badges pb ON pb.id = pbr.profile_badge_id |
| 52 | + WHERE pbr.profile_id = prof.id), |
| 53 | + '[]'::json |
| 54 | + ) |
| 55 | + ) FROM profiles prof WHERE prof.id = p.created_by) AS author, |
| 56 | + p.comment_count, |
| 57 | + (SELECT COALESCE(COUNT(uv.id), 0)::integer |
| 58 | + FROM useful_votes uv |
| 59 | + WHERE uv.content_id = p.id |
| 60 | + AND uv.content_type = 'projects' |
| 61 | + AND uv.created_at >= NOW() - INTERVAL '1 day' * days_back) AS useful_votes_last_week |
| 62 | + FROM projects p |
| 63 | + JOIN profiles prof ON prof.id = p.created_by -- Add explicit JOIN |
| 64 | + WHERE |
| 65 | + (search_query IS NULL OR |
| 66 | + p.fts @@ ts_query OR |
| 67 | + prof.username ILIKE '%' || search_query || '%' |
| 68 | + ) AND |
| 69 | + (category_id IS NULL OR p.category = category_id) AND |
| 70 | + (p.is_draft IS NULL OR p.is_draft = FALSE) AND |
| 71 | + (p.deleted IS NULL OR p.deleted = FALSE) AND |
| 72 | + (p.moderation = 'accepted' OR prof.username = current_username) |
| 73 | + ORDER BY |
| 74 | + -- Add relevance ranking when search query is provided |
| 75 | + CASE WHEN search_query IS NOT NULL THEN ts_rank_cd(p.fts, ts_query) END DESC NULLS LAST, |
| 76 | + CASE |
| 77 | + WHEN sort_by = 'Newest' THEN extract(epoch from p.created_at) |
| 78 | + WHEN sort_by = 'LatestUpdated' THEN extract(epoch from p.modified_at) |
| 79 | + WHEN sort_by = 'MostComments' THEN p.comment_count |
| 80 | + WHEN sort_by = 'MostDownloads' THEN p.file_download_count |
| 81 | + WHEN sort_by = 'MostUseful' THEN |
| 82 | + (SELECT COALESCE(COUNT(uv.id), 0) |
| 83 | + FROM useful_votes uv |
| 84 | + WHERE uv.content_id = p.id AND uv.content_type = 'projects') |
| 85 | + WHEN sort_by = 'MostUsefulLastWeek' THEN |
| 86 | + (SELECT COALESCE(COUNT(uv.id), 0) |
| 87 | + FROM useful_votes uv |
| 88 | + WHERE uv.content_id = p.id |
| 89 | + AND uv.content_type = 'projects' |
| 90 | + AND uv.created_at >= NOW() - INTERVAL '1 day' * days_back) |
| 91 | + WHEN sort_by = 'MostViews' THEN p.total_views |
| 92 | + ELSE 0 |
| 93 | + END DESC NULLS LAST, |
| 94 | + CASE |
| 95 | + WHEN sort_by = 'LeastComments' THEN p.comment_count |
| 96 | + END ASC NULLS LAST, |
| 97 | + p.created_at DESC |
| 98 | + LIMIT limit_val OFFSET offset_val; |
| 99 | +END;$function$ |
| 100 | +; |
| 101 | + |
| 102 | +CREATE OR REPLACE FUNCTION public.get_research(search_query text DEFAULT NULL::text, category_id bigint DEFAULT NULL::bigint, research_status research_status DEFAULT NULL::research_status, sort_by text DEFAULT 'Newest'::text, limit_val integer DEFAULT 10, offset_val integer DEFAULT 0, days_back integer DEFAULT 7) |
| 103 | + RETURNS TABLE(id bigint, created_at timestamp with time zone, created_by bigint, modified_at timestamp with time zone, description text, slug text, image json, status research_status, category json, tags text[], title text, total_views integer, author json, update_count bigint, comment_count bigint, useful_votes_last_week integer) |
| 104 | + LANGUAGE plpgsql |
| 105 | + SET search_path TO 'public', 'pg_temp' |
| 106 | +AS $function$ |
| 107 | +DECLARE |
| 108 | + ts_query tsquery; |
| 109 | +BEGIN |
| 110 | + -- Parse the search query once if provided |
| 111 | + IF search_query IS NOT NULL THEN |
| 112 | + ts_query := to_tsquery('english', search_query); |
| 113 | + END IF; |
| 114 | + |
| 115 | + RETURN QUERY |
| 116 | + SELECT |
| 117 | + r.id, |
| 118 | + r.created_at, |
| 119 | + r.created_by, |
| 120 | + GREATEST( |
| 121 | + r.modified_at, |
| 122 | + COALESCE( |
| 123 | + (SELECT MAX(ru.modified_at) FROM research_updates ru |
| 124 | + WHERE ru.research_id = r.id |
| 125 | + AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 126 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)), |
| 127 | + r.modified_at |
| 128 | + ) |
| 129 | + ) AS modified_at, |
| 130 | + r.description, |
| 131 | + r.slug, |
| 132 | + r.image, |
| 133 | + r.status, |
| 134 | + (SELECT json_build_object('id', c.id, 'name', c.name) FROM categories c WHERE c.id = r.category) AS category, |
| 135 | + r.tags, |
| 136 | + r.title, |
| 137 | + r.total_views, |
| 138 | + (SELECT json_build_object( |
| 139 | + 'id', p.id, |
| 140 | + 'display_name', p.display_name, |
| 141 | + 'username', p.username, |
| 142 | + 'country', p.country, |
| 143 | + 'badges', COALESCE( |
| 144 | + (SELECT json_agg( |
| 145 | + json_build_object( |
| 146 | + 'id', pb.id, |
| 147 | + 'name', pb.name, |
| 148 | + 'display_name', pb.display_name, |
| 149 | + 'image_url', pb.image_url, |
| 150 | + 'action_url', pb.action_url |
| 151 | + ) |
| 152 | + ) |
| 153 | + FROM profile_badges_relations pbr |
| 154 | + JOIN profile_badges pb ON pb.id = pbr.profile_badge_id |
| 155 | + WHERE pbr.profile_id = p.id), |
| 156 | + '[]'::json |
| 157 | + ) |
| 158 | + ) FROM profiles p WHERE p.id = r.created_by) AS author, |
| 159 | + (SELECT COUNT(*) FROM research_updates ru WHERE ru.research_id = r.id AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 160 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)) AS update_count, |
| 161 | + (SELECT COALESCE(SUM(ru.comment_count), 0) FROM research_updates ru WHERE ru.research_id = r.id AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 162 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)) AS comment_count, |
| 163 | + (SELECT COALESCE(COUNT(uv.id), 0)::integer |
| 164 | + FROM useful_votes uv |
| 165 | + WHERE uv.content_id = r.id |
| 166 | + AND uv.content_type = 'research' |
| 167 | + AND uv.created_at >= NOW() - INTERVAL '1 day' * days_back) AS useful_votes_last_week |
| 168 | + FROM research r |
| 169 | + JOIN profiles prof ON prof.id = r.created_by |
| 170 | + WHERE |
| 171 | + (search_query IS NULL OR |
| 172 | + r.fts @@ ts_query OR |
| 173 | + prof.username ILIKE '%' || search_query || '%' |
| 174 | + ) AND |
| 175 | + (category_id IS NULL OR r.category = category_id) AND |
| 176 | + (research_status IS NULL OR r.status = research_status) AND |
| 177 | + (r.is_draft IS NULL OR r.is_draft = FALSE) AND |
| 178 | + (r.deleted IS NULL OR r.deleted = FALSE) |
| 179 | + ORDER BY |
| 180 | + -- Add relevance ranking when search query is provided |
| 181 | + CASE WHEN search_query IS NOT NULL THEN ts_rank_cd(r.fts, ts_query) END DESC NULLS LAST, |
| 182 | + CASE |
| 183 | + WHEN sort_by = 'Newest' THEN extract(epoch from r.created_at) |
| 184 | + WHEN sort_by = 'LatestUpdated' THEN extract(epoch from |
| 185 | + GREATEST( |
| 186 | + r.modified_at, |
| 187 | + COALESCE( |
| 188 | + (SELECT MAX(ru.modified_at) FROM research_updates ru |
| 189 | + WHERE ru.research_id = r.id |
| 190 | + AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 191 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)), |
| 192 | + r.modified_at |
| 193 | + ) |
| 194 | + ) |
| 195 | + ) |
| 196 | + WHEN sort_by = 'MostComments' THEN |
| 197 | + (SELECT COALESCE(SUM(ru.comment_count), 0) FROM research_updates ru WHERE ru.research_id = r.id AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 198 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)) |
| 199 | + WHEN sort_by = 'MostUseful' THEN |
| 200 | + (SELECT COALESCE(COUNT(uv.id), 0) FROM useful_votes uv WHERE uv.content_id = r.id AND uv.content_type = 'research') |
| 201 | + WHEN sort_by = 'MostUsefulLastWeek' THEN |
| 202 | + (SELECT COALESCE(COUNT(uv.id), 0) FROM useful_votes uv |
| 203 | + WHERE uv.content_id = r.id |
| 204 | + AND uv.content_type = 'research' |
| 205 | + AND uv.created_at >= NOW() - INTERVAL '1 day' * days_back) |
| 206 | + WHEN sort_by = 'MostUpdates' THEN |
| 207 | + (SELECT COUNT(*) FROM research_updates ru WHERE ru.research_id = r.id AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 208 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)) |
| 209 | + ELSE 0 |
| 210 | + END DESC NULLS LAST, |
| 211 | + CASE |
| 212 | + WHEN sort_by = 'LeastComments' THEN |
| 213 | + (SELECT COALESCE(SUM(ru.comment_count), 0) FROM research_updates ru WHERE ru.research_id = r.id AND (ru.is_draft IS NULL OR ru.is_draft = FALSE) |
| 214 | + AND (ru.deleted IS NULL OR ru.deleted = FALSE)) |
| 215 | + END ASC NULLS LAST, |
| 216 | + r.created_at DESC |
| 217 | + LIMIT limit_val OFFSET offset_val; |
| 218 | +END; |
| 219 | +$function$ |
| 220 | +; |
| 221 | + |
| 222 | + |
0 commit comments