feat(search): design consistency with other feed/content aggregation lists

This commit is contained in:
Cory Dransfeldt 2025-06-10 10:31:50 -07:00
parent f2bca309f5
commit 0caf857a7e
No known key found for this signature in database
9 changed files with 162 additions and 144 deletions

View file

@ -1,12 +1,15 @@
CREATE OR REPLACE FUNCTION search_optimized_index(search_query text, page_size integer, page_offset integer, types text[])
DROP FUNCTION IF EXISTS search_optimized_index(text, integer, integer, text[]);
CREATE FUNCTION search_optimized_index(search_query text, page_size integer, page_offset integer, sections text[])
RETURNS TABLE(
result_id integer,
url text,
title text,
description text,
tags text,
tags text[],
genre_name text,
genre_url text,
section text,
type text,
total_plays text,
rank real,
@ -20,20 +23,21 @@ BEGIN
s.url,
s.title,
s.description,
array_to_string(s.tags, ', ') AS tags,
s.tags,
s.genre_name,
s.genre_url,
s.section,
s.type,
s.total_plays,
ts_rank_cd(to_tsvector('english', s.title || ' ' || s.description || array_to_string(s.tags, ' ')), plainto_tsquery('english', search_query)) AS rank,
COUNT(*) OVER() AS total_count
FROM
optimized_search_index s
WHERE(types IS NULL
OR s.type = ANY(types))
WHERE(sections IS NULL
OR s.section = ANY(sections))
AND plainto_tsquery('english', search_query) @@ to_tsvector('english', s.title || ' ' || s.description || array_to_string(s.tags, ' '))
ORDER BY
s.type = 'post' DESC,
s.section = 'post' DESC,
s.content_date DESC NULLS LAST,
rank DESC
LIMIT page_size OFFSET page_offset;

View file

@ -1,37 +1,38 @@
CREATE OR REPLACE VIEW optimized_search_index AS
WITH search_data AS (
SELECT
'post' AS type,
CONCAT('📝 ', p.title) AS title,
p.title,
p.url::TEXT AS url,
p.description AS description,
p.tags,
NULL AS genre_name,
NULL AS genre_url,
NULL::TEXT AS total_plays,
p.date AS content_date
p.date AS content_date,
'article' AS type,
'post' AS section
FROM
optimized_posts p
UNION ALL
SELECT
'link' AS type,
CONCAT('🔗 ', l.title, ' via ', l.name) AS title,
CONCAT(l.title, ' via ', l.name) AS title,
l.link::TEXT AS url,
l.description AS description,
l.tags,
NULL AS genre_name,
NULL AS genre_url,
NULL::TEXT AS total_plays,
l.date AS content_date
l.date AS content_date,
'link' AS type,
'link' AS section
FROM
optimized_links l
UNION ALL
SELECT
'book' AS type,
CASE WHEN b.rating IS NOT NULL THEN
CONCAT('📖 ', b.title, ' (', b.rating, ')')
CONCAT(b.title, ' (', b.rating, ')')
ELSE
CONCAT('📖 ', b.title)
b.title
END AS title,
b.url::TEXT AS url,
b.description AS description,
@ -39,58 +40,62 @@ WITH search_data AS (
NULL AS genre_name,
NULL AS genre_url,
NULL::TEXT AS total_plays,
b.date_finished AS content_date
b.date_finished AS content_date,
'books' AS type,
'book' AS section
FROM
optimized_books b
WHERE
LOWER(b.status) = 'finished'
UNION ALL
SELECT
'artist' AS type,
CONCAT(COALESCE(ar.emoji, ar.genre_emoji, '🎧'), ' ', ar.name) AS title,
ar.name AS title,
ar.url::TEXT AS url,
ar.description AS description,
ARRAY[ar.genre_name] AS tags,
ar.genre_name,
CONCAT(COALESCE(ar.emoji, ar.genre_emoji, '🎧'), ' ', ar.genre_name) AS genre_name,
ar.genre_slug AS genre_url,
TO_CHAR(ar.total_plays::NUMERIC, 'FM999,999,999,999') AS total_plays,
NULL AS content_date
NULL AS content_date,
'music' AS type,
'artist' AS section
FROM
optimized_artists ar
UNION ALL
SELECT
'genre' AS type,
CONCAT(COALESCE(g.emoji, '🎵'), ' ', g.name) AS title,
g.name AS title,
g.url::TEXT AS url,
g.description AS description,
NULL AS tags,
g.name AS genre_name,
g.url AS genre_url,
NULL::TEXT AS total_plays,
NULL AS content_date
g.total_plays AS total_plays,
NULL AS content_date,
'music' AS type,
'genre' AS section
FROM
optimized_genres g
UNION ALL
SELECT
'show' AS type,
CONCAT('📺 ', s.title, ' (', s.year, ')') AS title,
CONCAT(s.title, ' (', s.year, ')') AS title,
s.url::TEXT AS url,
s.description AS description,
s.tags,
NULL AS genre_name,
NULL AS genre_url,
NULL::TEXT AS total_plays,
s.last_watched_at AS content_date
s.last_watched_at AS content_date,
'tv' AS type,
'show' AS section
FROM
optimized_shows s
WHERE
s.last_watched_at IS NOT NULL
UNION ALL
SELECT
'movie' AS type,
CASE
WHEN m.rating IS NOT NULL THEN CONCAT('🎬 ', m.title, ' (', m.rating, ')')
ELSE CONCAT('🎬 ', m.title, ' (', m.year, ')')
WHEN m.rating IS NOT NULL THEN CONCAT(m.title, ' (', m.rating, ')')
ELSE CONCAT(m.title, ' (', m.year, ')')
END AS title,
m.url::TEXT AS url,
m.description AS description,
@ -98,7 +103,9 @@ WITH search_data AS (
NULL AS genre_name,
NULL AS genre_url,
NULL::TEXT AS total_plays,
m.last_watched AS content_date
m.last_watched AS content_date,
'movies' AS type,
'movie' AS section
FROM
optimized_movies m
WHERE