138 lines
4.2 KiB
SQL
138 lines
4.2 KiB
SQL
CREATE OR REPLACE VIEW optimized_genres AS
|
|
SELECT
|
|
g.id,
|
|
g.name,
|
|
g.description,
|
|
g.emoji,
|
|
to_char(g.total_plays, 'FM999,999,999,999') AS total_plays,
|
|
g.wiki_link,
|
|
g.slug AS url,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'name', a.name_string,
|
|
'url', a.slug,
|
|
'image', CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'total_plays', to_char(a.total_plays, 'FM999,999,999,999'),
|
|
'grid', json_build_object(
|
|
'title', a.name_string,
|
|
'image', CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'alt', CASE
|
|
WHEN a.total_plays > 0 THEN CONCAT(to_char(a.total_plays, 'FM999,999,999,999'), ' plays of ', a.name_string)
|
|
ELSE CONCAT('Artwork of ', a.name_string)
|
|
END,
|
|
'subtext', CASE
|
|
WHEN a.total_plays > 0 THEN CONCAT(to_char(a.total_plays, 'FM999,999,999,999'), ' plays')
|
|
ELSE NULL
|
|
END,
|
|
'url', a.slug
|
|
),
|
|
'type', 'music'
|
|
)
|
|
ORDER BY a.total_plays DESC
|
|
)
|
|
FROM artists a
|
|
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
|
|
WHERE a.genres = g.id
|
|
) AS artists,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'title', b.title,
|
|
'author', b.author,
|
|
'url', b.slug,
|
|
'image', CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'grid', json_build_object(
|
|
'title', NULL,
|
|
'image', CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'alt', CONCAT('Cover for ', b.title, ' by ', b.author),
|
|
'subtext', CASE WHEN b.star_rating IS NOT NULL THEN b.star_rating ELSE NULL END,
|
|
'url', b.slug
|
|
),
|
|
'type', 'books'
|
|
)
|
|
ORDER BY b.title ASC
|
|
)
|
|
FROM books b
|
|
JOIN genres_books gb ON gb.books_id = b.id
|
|
LEFT JOIN directus_files df_book ON b.art = df_book.id
|
|
WHERE gb.genres_id = g.id
|
|
AND LOWER(b.read_status) = 'finished'
|
|
) AS books,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'title', m.title,
|
|
'year', m.year,
|
|
'url', m.slug,
|
|
'image', CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'grid', json_build_object(
|
|
'title', NULL,
|
|
'image', CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'alt', CONCAT('Poster for ', m.title, ' (', m.year, ')'),
|
|
'subtext', CASE WHEN m.star_rating IS NOT NULL THEN m.star_rating::text ELSE m.year::text END,
|
|
'url', m.slug
|
|
),
|
|
'type', 'movies'
|
|
)
|
|
ORDER BY m.year ASC
|
|
)
|
|
FROM movies m
|
|
JOIN genres_movies gm ON gm.movies_id = m.id
|
|
LEFT JOIN directus_files df_movie ON m.art = df_movie.id
|
|
WHERE gm.genres_id = g.id
|
|
AND m.last_watched IS NOT NULL
|
|
) AS movies,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'title', p.title,
|
|
'date', p.date,
|
|
'url', p.slug,
|
|
'grid', json_build_object(
|
|
'title', p.title,
|
|
'image', CONCAT(globals.cdn_url, '/', df_post.filename_disk),
|
|
'alt', p.title,
|
|
'subtext', TO_CHAR(p.date, 'FMMonth DD, YYYY'),
|
|
'url', p.slug
|
|
),
|
|
'type', 'posts'
|
|
)
|
|
ORDER BY p.date DESC
|
|
)
|
|
FROM posts_genres pg
|
|
LEFT JOIN posts p ON pg.posts_id = p.id
|
|
LEFT JOIN directus_files df_post ON p.image = df_post.id
|
|
WHERE pg.genres_id = g.id
|
|
) AS posts,
|
|
json_build_object(
|
|
'title', CONCAT('Genre • ', g.name, ' • ', globals.site_name),
|
|
'description', LEFT(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
g.description,
|
|
E'[*_`~#>-]', '', 'g'
|
|
),
|
|
E'\\[(.*?)\\]\\((.*?)\\)', E'\\1', 'g'
|
|
),
|
|
E'!\\[(.*?)\\]\\((.*?)\\)', '', 'g'
|
|
),
|
|
250
|
|
),
|
|
'open_graph_image', (
|
|
SELECT CONCAT('/', df_artist.filename_disk)
|
|
FROM artists a
|
|
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
|
|
WHERE a.genres = g.id
|
|
AND df_artist.filename_disk IS NOT NULL
|
|
AND df_artist.filename_disk != ''
|
|
ORDER BY a.total_plays DESC
|
|
LIMIT 1
|
|
),
|
|
'url', CONCAT(globals.url, g.slug),
|
|
'type', 'genre'
|
|
) AS metadata
|
|
FROM genres g
|
|
CROSS JOIN optimized_globals globals
|
|
ORDER BY g.id ASC;
|