CREATE OR REPLACE VIEW optimized_books AS SELECT b.date_finished, EXTRACT(YEAR FROM b.date_finished) AS year, b.author, b.description, b.title, b.progress, b.read_status AS status, b.star_rating AS rating, b.review, b.slug AS url, CONCAT(globals.cdn_url, '/', df.filename_disk) AS image, b.favorite, b.tattoo, ( SELECT array_agg(t.name) FROM books_tags bt LEFT JOIN tags t ON bt.tags_id = t.id WHERE bt.books_id = b.id ) AS tags, ( 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 books_artists ba LEFT JOIN artists a ON ba.artists_id = a.id LEFT JOIN directus_files df_artist ON a.art = df_artist.id WHERE ba.books_id = b.id ) AS artists, ( 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_books mb LEFT JOIN movies m ON mb.movies_id = m.id LEFT JOIN directus_files df_movie ON m.art = df_movie.id WHERE mb.books_id = b.id ) AS movies, ( SELECT json_agg( json_build_object('name', g.name, 'url', g.slug) ORDER BY g.name ASC ) FROM genres_books gb LEFT JOIN genres g ON gb.genres_id = g.id WHERE gb.books_id = b.id ) AS genres, ( 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_books sb LEFT JOIN shows s ON sb.shows_id = s.id LEFT JOIN directus_files df_show ON s.art = df_show.id WHERE sb.books_id = b.id ) AS shows, ( SELECT json_agg( json_build_object('title', p.title, 'date', p.date, 'url', p.slug) ORDER BY p.date DESC ) FROM posts_books pb LEFT JOIN posts p ON pb.posts_id = p.id WHERE pb.books_id = b.id ) AS posts, ( SELECT json_agg( json_build_object( 'title', rb.title, 'author', rb.author, 'url', rb.slug, 'image', CONCAT(globals.cdn_url, '/', df_rb.filename_disk), 'grid', json_build_object( 'title', NULL, 'image', CONCAT(globals.cdn_url, '/', df_rb.filename_disk), 'alt', CONCAT('Cover for ', rb.title, ' by ', rb.author), 'subtext', CASE WHEN rb.star_rating IS NOT NULL THEN rb.star_rating ELSE NULL END, 'url', rb.slug ), 'type', 'books' ) ORDER BY rb.title ASC ) FROM related_books rbk LEFT JOIN books rb ON rbk.related_books_id = rb.id LEFT JOIN directus_files df_rb ON rb.art = df_rb.id WHERE rbk.books_id = b.id ) AS related_books, json_build_object( 'title', NULL, 'image', CONCAT(globals.cdn_url, '/', df.filename_disk), 'url', b.slug, 'alt', CONCAT('Book cover from ', b.title, ' by ', b.author), 'subtext', CASE WHEN b.star_rating IS NOT NULL THEN b.star_rating::text ELSE NULL END, 'type', 'books' ) AS grid, CASE WHEN LOWER(b.read_status) = 'finished' AND b.star_rating IS NOT NULL THEN json_build_object( 'title', CONCAT(b.title, ' by ', b.author, ' (', b.star_rating, ')'), 'url', b.slug, 'date', b.date_finished, 'description', COALESCE(b.review, b.description), 'image', CONCAT(globals.cdn_url, '/', df.filename_disk), 'rating', b.star_rating ) ELSE NULL END AS feed, (SELECT TO_CHAR(days_read, 'FM999G999G999') FROM reading_streak LIMIT 1) AS days_read, json_build_object( 'open_graph_image', CASE WHEN df.filename_disk IS NOT NULL AND df.filename_disk != '' AND df.filename_disk != '/' THEN CONCAT('/', df.filename_disk) ELSE NULL END ) AS metadata FROM books b LEFT JOIN directus_files df ON b.art = df.id CROSS JOIN optimized_globals globals GROUP BY b.id, df.filename_disk, globals.cdn_url;