CREATE OR REPLACE VIEW optimized_movies AS SELECT m.id, m.tmdb_id, m.last_watched, m.title, m.year, m.plays, m.favorite, m.tattoo, m.star_rating AS rating, m.description, m.review, m.slug AS url, CONCAT(globals.cdn_url, '/', df.filename_disk) AS image, CONCAT(globals.cdn_url, '/', df2.filename_disk) AS backdrop, json_build_object( 'title', m.title, 'url', m.slug, 'image', CONCAT(globals.cdn_url, '/', df.filename_disk), 'backdrop', CONCAT(globals.cdn_url, '/', df2.filename_disk), 'alt', CONCAT('Poster from ', m.title), 'subtext', CASE WHEN m.last_watched >= NOW() - INTERVAL '90 days' THEN m.star_rating::text ELSE m.year::text END, 'type', 'movies' ) AS grid, ( SELECT array_agg(t.name) FROM movies_tags mt LEFT JOIN tags t ON mt.tags_id = t.id WHERE mt.movies_id = m.id ) AS tags, ( SELECT json_agg( json_build_object('name', g.name, 'url', g.slug) ORDER BY g.name ASC ) FROM genres_movies gm LEFT JOIN genres g ON gm.genres_id = g.id WHERE gm.movies_id = m.id ) AS genres, ( 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', 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 movies_artists ma LEFT JOIN artists a ON ma.artists_id = a.id LEFT JOIN directus_files df_artist ON a.art = df_artist.id WHERE ma.movies_id = m.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', 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 movies_books mb LEFT JOIN books b ON mb.books_id = b.id LEFT JOIN directus_files df_book ON b.art = df_book.id WHERE mb.movies_id = m.id AND LOWER(b.read_status) = 'finished' ) AS books, ( SELECT json_agg( json_build_object( 'title', s.title, 'year', s.year, 'url', s.slug, 'image', CONCAT(globals.cdn_url, '/', df_show.filename_disk), 'grid', json_build_object( 'title', NULL, 'image', CONCAT(globals.cdn_url, '/', df_show.filename_disk), 'alt', CONCAT('Artwork for ', 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, 'url', s.slug ), 'type', 'tv' ) ORDER BY s.year ASC ) FROM shows_movies sm LEFT JOIN shows s ON sm.shows_id = s.id LEFT JOIN directus_files df_show ON s.art = df_show.id WHERE sm.movies_id = m.id AND EXISTS ( SELECT 1 FROM episodes e WHERE e.show = s.id AND e.last_watched_at IS NOT NULL ) ) AS shows, ( SELECT json_agg( json_build_object('title', p.title, 'date', p.date, 'url', p.slug) ORDER BY p.date DESC ) FROM posts_movies pm LEFT JOIN posts p ON pm.posts_id = p.id WHERE pm.movies_id = m.id ) AS posts, ( SELECT json_agg( json_build_object( 'title', rm.title, 'year', rm.year, 'url', rm.slug, 'image', CONCAT(globals.cdn_url, '/', df_related.filename_disk), 'grid', json_build_object( 'title', rm.title, 'image', CONCAT(globals.cdn_url, '/', df_related.filename_disk), 'alt', CONCAT('Poster for ', rm.title), 'subtext', CASE WHEN rm.last_watched IS NOT NULL THEN rm.star_rating::text ELSE rm.year::text END, 'url', rm.slug ), 'type', 'movies' ) ORDER BY rm.year ASC ) FROM related_movies r LEFT JOIN movies rm ON r.related_movies_id = rm.id LEFT JOIN directus_files df_related ON rm.art = df_related.id WHERE r.movies_id = m.id AND rm.last_watched IS NOT NULL ) AS related_movies, CASE WHEN m.star_rating IS NOT NULL AND m.last_watched IS NOT NULL THEN json_build_object( 'title', CONCAT(m.title, ' (', m.star_rating, ')'), 'url', m.slug, 'date', m.last_watched, 'description', COALESCE(m.review, m.description), 'image', CONCAT(globals.cdn_url, '/', df.filename_disk), 'rating', m.star_rating ) ELSE NULL END AS feed, json_build_object( 'title', CONCAT('Movie • ', m.title, ' • ', globals.site_name), 'description', LEFT( regexp_replace( regexp_replace( regexp_replace(m.description, E'[*_`~#>-]', '', 'g'), E'\\[(.*?)\\]\\((.*?)\\)', E'\\1', 'g' ), E'!\\[(.*?)\\]\\((.*?)\\)', '', 'g' ), 250 ), 'open_graph_image', CASE WHEN df2.filename_disk IS NOT NULL AND df2.filename_disk != '' AND df2.filename_disk != '/' THEN CONCAT('/', df2.filename_disk) ELSE NULL END, 'url', CONCAT(globals.url, m.slug), 'type', 'movie' ) AS metadata FROM movies m LEFT JOIN directus_files df ON m.art = df.id LEFT JOIN directus_files df2 ON m.backdrop = df2.id CROSS JOIN optimized_globals globals GROUP BY m.id, df.filename_disk, df2.filename_disk, globals.cdn_url, globals.site_name, globals.url ORDER BY m.last_watched DESC;