179 lines
5.5 KiB
SQL
179 lines
5.5 KiB
SQL
CREATE OR REPLACE VIEW optimized_shows AS
|
|
SELECT
|
|
s.id,
|
|
s.tmdb_id,
|
|
s.title,
|
|
s.year,
|
|
s.favorite,
|
|
s.tattoo,
|
|
s.description,
|
|
s.review,
|
|
s.ongoing,
|
|
s.slug AS url,
|
|
CONCAT(globals.cdn_url, '/', df_art.filename_disk) AS image,
|
|
CONCAT(globals.cdn_url, '/', df_backdrop.filename_disk) AS backdrop,
|
|
json_build_object(
|
|
'title', s.title,
|
|
'image', CONCAT(globals.cdn_url, '/', df_art.filename_disk),
|
|
'backdrop', CONCAT(globals.cdn_url, '/', df_backdrop.filename_disk),
|
|
'url', s.slug,
|
|
'alt', CONCAT('Poster from ', s.title),
|
|
'subtext', CASE
|
|
WHEN (
|
|
SELECT MAX(e1.last_watched_at)
|
|
FROM episodes e1
|
|
WHERE e1.show = s.id
|
|
) >= NOW() - INTERVAL '90 days' THEN
|
|
(SELECT CONCAT('S', e2.season_number, 'E', e2.episode_number)
|
|
FROM episodes e2
|
|
WHERE e2.show = s.id
|
|
ORDER BY e2.last_watched_at DESC, e2.season_number DESC, e2.episode_number DESC
|
|
LIMIT 1)
|
|
ELSE
|
|
s.year::text
|
|
END,
|
|
'type', 'tv'
|
|
) AS grid,
|
|
json_build_object(
|
|
'title', s.title,
|
|
'year', s.year,
|
|
'url', s.slug,
|
|
'image', CONCAT(globals.cdn_url, '/', df_art.filename_disk),
|
|
'backdrop', CONCAT(globals.cdn_url, '/', df_backdrop.filename_disk),
|
|
'formatted_episode', COALESCE((
|
|
SELECT CONCAT('S', e2.season_number, 'E', e2.episode_number)
|
|
FROM episodes e2
|
|
WHERE e2.show = s.id
|
|
ORDER BY e2.last_watched_at DESC, e2.season_number DESC, e2.episode_number DESC
|
|
LIMIT 1
|
|
), NULL),
|
|
'last_watched_at', (
|
|
SELECT MAX(e3.last_watched_at)
|
|
FROM episodes e3
|
|
WHERE e3.show = s.id
|
|
)
|
|
) AS episode,
|
|
(
|
|
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', m.title,
|
|
'image', CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'alt', CONCAT('Poster for ', m.title),
|
|
'subtext', m.year,
|
|
'url', m.slug
|
|
),
|
|
'type', 'movies'
|
|
)
|
|
ORDER BY m.year DESC
|
|
)
|
|
FROM shows_movies sm
|
|
LEFT JOIN movies m ON sm.movies_id = m.id
|
|
LEFT JOIN directus_files df_movie ON m.art = df_movie.id
|
|
WHERE sm.shows_id = s.id
|
|
) AS movies,
|
|
(
|
|
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', b.title,
|
|
'image', CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'alt', CONCAT('Cover for ', b.title, ' by ', b.author),
|
|
'subtext', b.author,
|
|
'url', b.slug
|
|
),
|
|
'type', 'books'
|
|
)
|
|
ORDER BY b.title
|
|
)
|
|
FROM shows_books sb
|
|
LEFT JOIN books b ON sb.books_id = b.id
|
|
LEFT JOIN directus_files df_book ON b.art = df_book.id
|
|
WHERE sb.shows_id = s.id
|
|
) AS books,
|
|
(
|
|
SELECT json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
|
ORDER BY p.date DESC)
|
|
FROM posts_shows ps
|
|
LEFT JOIN posts p ON ps.posts_id = p.id
|
|
WHERE ps.shows_id = s.id
|
|
) AS posts,
|
|
(
|
|
SELECT array_agg(t.name)
|
|
FROM shows_tags st
|
|
LEFT JOIN tags t ON st.tags_id = t.id
|
|
WHERE st.shows_id = s.id
|
|
) AS tags,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'title', rs.title,
|
|
'year', rs.year,
|
|
'url', rs.slug,
|
|
'image', CONCAT(globals.cdn_url, '/', df_related.filename_disk),
|
|
'grid', json_build_object(
|
|
'title', rs.title,
|
|
'image', CONCAT(globals.cdn_url, '/', df_related.filename_disk),
|
|
'alt', CONCAT('Artwork for ', rs.title),
|
|
'subtext', rs.year,
|
|
'url', rs.slug
|
|
),
|
|
'type', 'tv'
|
|
)
|
|
ORDER BY rs.year DESC
|
|
)
|
|
FROM related_shows sr
|
|
LEFT JOIN shows rs ON sr.related_shows_id = rs.id
|
|
LEFT JOIN directus_files df_related ON rs.art = df_related.id
|
|
WHERE sr.shows_id = s.id
|
|
) AS related_shows,
|
|
(
|
|
SELECT json_agg(
|
|
json_build_object(
|
|
'name', a.name_string,
|
|
'url', a.slug,
|
|
'country', a.country,
|
|
'total_plays', a.total_plays,
|
|
'image', CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'grid', json_build_object(
|
|
'title', a.name_string,
|
|
'image', CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'alt', CONCAT(to_char(a.total_plays, 'FM999,999,999,999'), ' plays of ', a.name_string),
|
|
'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.name_string
|
|
)
|
|
FROM shows_artists sa
|
|
LEFT JOIN artists a ON sa.artists_id = a.id
|
|
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
|
|
WHERE sa.shows_id = s.id
|
|
) AS artists,
|
|
MAX(e.last_watched_at) AS last_watched_at,
|
|
json_build_object(
|
|
'open_graph_image', CASE
|
|
WHEN df_backdrop.filename_disk IS NOT NULL AND df_backdrop.filename_disk != '' AND df_backdrop.filename_disk != '/' THEN
|
|
CONCAT('/', df_backdrop.filename_disk)
|
|
ELSE NULL
|
|
END
|
|
) AS metadata
|
|
FROM shows s
|
|
LEFT JOIN episodes e ON s.id = e.show
|
|
LEFT JOIN directus_files df_art ON s.art = df_art.id
|
|
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
|
|
CROSS JOIN optimized_globals globals
|
|
GROUP BY s.id, df_art.filename_disk, df_backdrop.filename_disk, globals.cdn_url
|
|
ORDER BY MAX(e.last_watched_at) DESC;
|