CREATE OR REPLACE VIEW optimized_search_index AS
WITH search_data AS (
  SELECT
      'post' AS type,
      CONCAT('📝 ', p.title) AS title,
      CONCAT('https://coryd.dev', p.url) AS url,
      p.description AS description,
      p.tags,
      NULL AS genre_name,
      NULL AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_posts p

  UNION ALL

  SELECT
      'link' AS type,
      CONCAT('🔗 ', l.title, ' via ', l.name) AS title,
      l.link AS url,
      l.description AS description,
      l.tags,
      NULL AS genre_name,
      NULL AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_links l

  UNION ALL

  SELECT
      'book' AS type,
      CASE
          WHEN b.rating IS NOT NULL THEN CONCAT('📖 ', b.title, ' (', b.rating, ')')
          ELSE CONCAT('📖 ', b.title)
      END AS title,
      CONCAT('https://coryd.dev', b.url) AS url,
      b.description AS description,
      b.tags,
      NULL AS genre_name,
      NULL AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_books b
  WHERE LOWER(b.status) = 'finished'

  UNION ALL

  SELECT
      'movie' AS type,
      CASE
          WHEN m.rating IS NOT NULL THEN CONCAT('🎥 ', m.title, ' (', m.rating, ')')
          ELSE CONCAT('🎥 ', m.title)
      END AS title,
      CONCAT('https://coryd.dev', m.url) AS url,
      m.description AS description,
      m.tags,
      NULL AS genre_name,
      NULL AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_movies m
  WHERE m.last_watched IS NOT NULL

  UNION ALL

  SELECT
      'artist' AS type,
      CONCAT(
          COALESCE(ar.emoji, ar.genre_emoji, '🎧'), ' ', ar.name
      ) AS title,
      CONCAT('https://coryd.dev', ar.url) AS url,
      ar.description AS description,
      ARRAY[ar.genre_name] AS tags,
      ar.genre_name,
      CONCAT('https://coryd.dev', ar.genre_slug) AS genre_url,
      ar.total_plays
  FROM optimized_artists ar

  UNION ALL

  SELECT
      'genre' AS type,
      CONCAT(COALESCE(g.emoji, '🎵'), ' ', g.name) AS title,
      CONCAT('https://coryd.dev', g.url) AS url,
      g.description AS description,
      NULL AS tags,
      g.name AS genre_name,
      CONCAT('https://coryd.dev', g.url) AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_genres g

  UNION ALL

  SELECT
      'show' AS type,
      CASE
          WHEN s.review IS NOT NULL THEN CONCAT('📺 ', s.title, ' (', s.year, ') - ', s.review)
          ELSE CONCAT('📺 ', s.title, ' (', s.year, ')')
      END AS title,
      CONCAT('https://coryd.dev', s.url) AS url,
      s.description AS description,
      s.tags,
      NULL AS genre_name,
      NULL AS genre_url,
      NULL::integer AS total_plays
  FROM optimized_shows s
  WHERE s.last_watched_at IS NOT NULL
),
search_data_with_id AS (
  SELECT
    ROW_NUMBER() OVER (ORDER BY url) AS id,
    search_data.*
  FROM search_data
)
SELECT
    json_agg(
      json_build_object(
        'id', search_data_with_id.id,
        'url', search_data_with_id.url,
        'title', search_data_with_id.title,
        'description', search_data_with_id.description,
        'tags', search_data_with_id.tags,
        'genre_name', search_data_with_id.genre_name,
        'genre_url', search_data_with_id.genre_url,
        'type', search_data_with_id.type,
        'total_plays', search_data_with_id.total_plays
      )
    ) AS search_index
FROM search_data_with_id;