CREATE OR REPLACE VIEW optimized_pages AS
SELECT 
  p.id,
  p.title,
  p.permalink,
  p.description,
  CONCAT('/', df.filename_disk) AS open_graph_image,
  p.updated,

  (
    SELECT json_agg(
      CASE
        WHEN pb.collection = 'youtube_player' THEN json_build_object(
          'type', pb.collection,
          'url', yp.url
        )
        WHEN pb.collection = 'github_banner' THEN json_build_object(
          'type', pb.collection,
          'url', gb.url
        )
        WHEN pb.collection = 'npm_banner' THEN json_build_object(
          'type', pb.collection,
          'url', nb.url,
          'command', nb.command
        )
        WHEN pb.collection = 'rss_banner' THEN json_build_object(
          'type', pb.collection,
          'url', rb.url,
          'text', rb.text
        )
        WHEN pb.collection = 'hero' THEN json_build_object(
          'type', pb.collection,
          'image', CONCAT('/', df_hero.filename_disk),
          'alt', h.alt_text
        )
        WHEN pb.collection = 'markdown' THEN json_build_object(
          'type', pb.collection,
          'text', md.text
        )
        WHEN pb.collection = 'divider' THEN json_build_object(
          'type', pb.collection,
          'markup', d.markup
        )
        ELSE json_build_object('type', pb.collection)
      END
    ORDER BY pb.sort)
    FROM pages_blocks pb
    LEFT JOIN youtube_player yp ON pb.collection = 'youtube_player' AND yp.id = pb.item::INTEGER
    LEFT JOIN github_banner gb ON pb.collection = 'github_banner' AND gb.id = pb.item::INTEGER
    LEFT JOIN npm_banner nb ON pb.collection = 'npm_banner' AND nb.id = pb.item::INTEGER
    LEFT JOIN rss_banner rb ON pb.collection = 'rss_banner' AND rb.id = pb.item::INTEGER
    LEFT JOIN hero h ON pb.collection = 'hero' AND h.id = pb.item::INTEGER
    LEFT JOIN directus_files df_hero ON h.image = df_hero.id
    LEFT JOIN markdown md ON pb.collection = 'markdown' AND md.id = pb.item::INTEGER
    LEFT JOIN divider d ON pb.collection = 'divider' AND d.id = pb.item::INTEGER
    WHERE pb.pages_id = p.id
  ) AS blocks
FROM
  pages p
LEFT JOIN
  directus_files df ON p.open_graph_image = df.id
GROUP BY
  p.id, df.filename_disk;