From 08e2c2ff3f298d312bd01e3e14e7483d1a8747c8 Mon Sep 17 00:00:00 2001
From: Cory Dransfeldt <hi@coryd.dev>
Date: Sat, 12 Oct 2024 13:07:26 -0700
Subject: [PATCH] feat: initial view queries

---
 package-lock.json                         |  10 +-
 package.json                              |   2 +-
 src/assets/styles/base/index.css          |   5 +-
 views/content/links.psql                  |  36 ++++++
 views/content/posts.psql                  | 142 ++++++++++++++++++++++
 views/feeds/all-content.psql              |  89 ++++++++++++++
 views/feeds/search.psql                   |  94 ++++++++++++++
 views/feeds/sitemap.psql                  |  57 +++++++++
 views/feeds/syndication.psql              | 103 ++++++++++++++++
 views/globals/index.psql                  |  19 +++
 views/globals/pages.psql                  |  63 ++++++++++
 views/media/books.psql                    | 107 ++++++++++++++++
 views/media/movies.psql                   | 116 ++++++++++++++++++
 views/media/music/album-releases.psql     |  25 ++++
 views/media/music/artists.psql            | 117 ++++++++++++++++++
 views/media/music/concerts.psql           |  39 ++++++
 views/media/music/genres.psql             |  55 +++++++++
 views/media/music/listens.psql            |  24 ++++
 views/media/music/month-tracks.psql       |  21 ++++
 views/media/music/now-playing.psql        |  24 ++++
 views/media/music/recent-tracks.psql      |  21 ++++
 views/media/music/three-month-tracks.psql |  21 ++++
 views/media/shows.psql                    | 102 ++++++++++++++++
 23 files changed, 1282 insertions(+), 10 deletions(-)
 create mode 100644 views/content/links.psql
 create mode 100644 views/content/posts.psql
 create mode 100644 views/feeds/all-content.psql
 create mode 100644 views/feeds/search.psql
 create mode 100644 views/feeds/sitemap.psql
 create mode 100644 views/feeds/syndication.psql
 create mode 100644 views/globals/index.psql
 create mode 100644 views/globals/pages.psql
 create mode 100644 views/media/books.psql
 create mode 100644 views/media/movies.psql
 create mode 100644 views/media/music/album-releases.psql
 create mode 100644 views/media/music/artists.psql
 create mode 100644 views/media/music/concerts.psql
 create mode 100644 views/media/music/genres.psql
 create mode 100644 views/media/music/listens.psql
 create mode 100644 views/media/music/month-tracks.psql
 create mode 100644 views/media/music/now-playing.psql
 create mode 100644 views/media/music/recent-tracks.psql
 create mode 100644 views/media/music/three-month-tracks.psql
 create mode 100644 views/media/shows.psql

diff --git a/package-lock.json b/package-lock.json
index a5293dcd..4c4c2381 100644
--- a/package-lock.json
+++ b/package-lock.json
@@ -1,12 +1,12 @@
 {
   "name": "coryd.dev",
-  "version": "1.0.2",
+  "version": "1.0.3",
   "lockfileVersion": 3,
   "requires": true,
   "packages": {
     "": {
       "name": "coryd.dev",
-      "version": "1.0.2",
+      "version": "1.0.3",
       "license": "MIT",
       "dependencies": {
         "@cdransf/api-text": "^1.5.0",
@@ -1092,9 +1092,9 @@
       }
     },
     "node_modules/caniuse-lite": {
-      "version": "1.0.30001667",
-      "resolved": "https://registry.npmjs.org/caniuse-lite/-/caniuse-lite-1.0.30001667.tgz",
-      "integrity": "sha512-7LTwJjcRkzKFmtqGsibMeuXmvFDfZq/nzIjnmgCGzKKRVzjD72selLDK1oPF/Oxzmt4fNcPvTDvGqSDG4tCALw==",
+      "version": "1.0.30001668",
+      "resolved": "https://registry.npmjs.org/caniuse-lite/-/caniuse-lite-1.0.30001668.tgz",
+      "integrity": "sha512-nWLrdxqCdblixUO+27JtGJJE/txpJlyUy5YN1u53wLZkP0emYCo5zgS6QYft7VUYR42LGgi/S5hdLZTrnyIddw==",
       "dev": true,
       "funding": [
         {
diff --git a/package.json b/package.json
index a3cce6ca..f0bfd908 100644
--- a/package.json
+++ b/package.json
@@ -1,6 +1,6 @@
 {
   "name": "coryd.dev",
-  "version": "1.0.2",
+  "version": "1.0.3",
   "description": "The source for my personal site. Built using 11ty (and other tools).",
   "type": "module",
   "scripts": {
diff --git a/src/assets/styles/base/index.css b/src/assets/styles/base/index.css
index c3af590f..de12efd3 100644
--- a/src/assets/styles/base/index.css
+++ b/src/assets/styles/base/index.css
@@ -419,10 +419,7 @@ article {
     border-bottom: none;
   }
 
-  & h3:not(+ :not(p)) {
-    margin: 0;
-  }
-
+  h3,
   &:not(:has(h3)) p {
     margin-top: 0;
   }
diff --git a/views/content/links.psql b/views/content/links.psql
new file mode 100644
index 00000000..c50d22e6
--- /dev/null
+++ b/views/content/links.psql
@@ -0,0 +1,36 @@
+CREATE OR REPLACE VIEW optimized_links AS
+SELECT
+    l.id,
+    l.title,
+    l.date,
+    l.description,
+    l.link,
+    a.mastodon,
+    a.name,
+    json_build_object(
+        'name', a.name,
+        'url', a.url,
+        'mastodon', a.mastodon
+    ) AS author,
+    'link' AS type,
+
+    (
+        SELECT array_agg(t.name)
+        FROM links_tags lt
+        LEFT JOIN tags t ON lt.tags_id = t.id
+        WHERE lt.links_id = l.id
+    ) AS tags,
+
+    json_build_object(
+        'title', CONCAT(l.title, ' via ', a.name),
+        'url', l.link,
+        'description', l.description,
+        'date', l.date
+    ) AS feed
+
+FROM
+    links l
+JOIN
+    authors a ON l.author = a.id
+ORDER BY
+    l.date DESC;
\ No newline at end of file
diff --git a/views/content/posts.psql b/views/content/posts.psql
new file mode 100644
index 00000000..684738c8
--- /dev/null
+++ b/views/content/posts.psql
@@ -0,0 +1,142 @@
+CREATE OR REPLACE VIEW optimized_posts AS
+SELECT
+  p.id,
+  p.date,
+  p.title,
+  p.description,
+  p.content,
+  p.featured,
+  p.slug AS url,
+  p.mastodon_url,
+  CONCAT('/', df.filename_disk) AS image,
+  p.image_alt,
+
+  (
+    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_text', 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
+    )
+    FROM posts_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.posts_id = p.id
+  ) AS blocks,
+
+  (
+    SELECT array_agg(t.name)
+    FROM posts_tags pt
+    LEFT JOIN tags t ON pt.tags_id = t.id
+    WHERE pt.posts_id = p.id
+  ) AS tags,
+
+  (
+    SELECT json_agg(json_build_object(
+        'name', g.name,
+        'url', g.slug
+    ))
+    FROM posts_genres gp
+    LEFT JOIN genres g ON gp.genres_id = g.id
+    WHERE gp.posts_id = p.id
+  ) AS genres,
+
+  (
+    SELECT json_agg(json_build_object(
+        'name', a.name_string,
+        'url', a.slug,
+        'country', a.country,
+        'total_plays', a.total_plays
+    ))
+    FROM posts_artists pa
+    LEFT JOIN artists a ON pa.artists_id = a.id
+    WHERE pa.posts_id = p.id
+  ) AS artists,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', b.title,
+        'author', b.author,
+        'url', b.slug
+    ) ORDER BY b.title)
+    FROM posts_books pbk
+    LEFT JOIN books b ON pbk.books_id = b.id
+    WHERE pbk.posts_id = p.id
+  ) AS books,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', m.title,
+        'year', m.year,
+        'url', m.slug
+    ) ORDER BY m.year DESC)
+    FROM posts_movies pm
+    LEFT JOIN movies m ON pm.movies_id = m.id
+    WHERE pm.posts_id = p.id
+  ) AS movies,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', s.title,
+        'year', s.year,
+        'url', s.slug
+    ))
+    FROM posts_shows ps
+    LEFT JOIN shows s ON ps.shows_id = s.id
+    WHERE ps.posts_id = p.id
+  ) AS shows,
+
+  json_build_object(
+    'title', p.title,
+    'url', CONCAT('https://coryd.dev', p.slug),
+    'description', p.content,
+    'date', p.date,
+    '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 feed
+
+FROM
+  posts p
+LEFT JOIN
+  directus_files df ON p.image = df.id
+GROUP BY
+  p.id, df.filename_disk;
\ No newline at end of file
diff --git a/views/feeds/all-content.psql b/views/feeds/all-content.psql
new file mode 100644
index 00000000..d5fa13eb
--- /dev/null
+++ b/views/feeds/all-content.psql
@@ -0,0 +1,89 @@
+CREATE OR REPLACE VIEW optimized_all_activity AS
+WITH feed_data AS (
+  SELECT
+      p.date AS content_date,
+      'post' AS content_type,
+      p.title,
+      p.description,
+      CONCAT('https://coryd.dev', p.url) AS url,
+      NULL AS image,
+      NULL AS rating,
+      p.tags,
+      json_build_object(
+          'title', p.title,
+          'url', CONCAT('https://coryd.dev', p.url),
+          'description', p.description,
+          'date', p.date
+      ) AS feed
+  FROM optimized_posts p
+
+  UNION ALL
+
+  SELECT
+      l.date AS content_date,
+      'link' AS content_type,
+      CONCAT(l.title, ' via ', l.name) AS title,
+      l.description,
+      l.link AS url,
+      NULL AS image,
+      NULL AS rating,
+      l.tags,
+      json_build_object(
+          'title', CONCAT(l.title, ' via ', l.name),
+          'url', l.link,
+          'description', l.description,
+          'date', l.date
+      ) AS feed
+  FROM optimized_links l
+
+  UNION ALL
+
+  SELECT
+      b.date_finished AS content_date,
+      'book' AS content_type,
+      b.title,
+      b.description,
+      CONCAT('https://coryd.dev', b.url) AS url,
+      b.image,
+      b.rating,
+      b.tags,
+      CASE
+          WHEN LOWER(b.status) = 'finished' THEN json_build_object(
+              'title', b.title,
+              'url', CONCAT('https://coryd.dev', b.url),
+              'description', b.description,
+              'image', b.image,
+              'rating', b.rating,
+              'date', b.date_finished
+          )
+          ELSE NULL
+      END AS feed
+  FROM optimized_books b
+
+  UNION ALL
+
+  SELECT
+      m.last_watched AS content_date,
+      'movie' AS content_type,
+      m.title,
+      m.description,
+      CONCAT('https://coryd.dev', m.url) AS url,
+      m.image,
+      m.rating,
+      m.tags,
+      CASE
+          WHEN m.last_watched IS NOT NULL THEN json_build_object(
+              'title', m.title,
+              'url', CONCAT('https://coryd.dev', m.url),
+              'description', m.description,
+              'image', m.image,
+              'rating', m.rating,
+              'date', m.last_watched
+          )
+          ELSE NULL
+      END AS feed
+  FROM optimized_movies m
+)
+
+SELECT json_agg(feed_data.* ORDER BY feed_data.content_date DESC) AS feed
+FROM feed_data;
\ No newline at end of file
diff --git a/views/feeds/search.psql b/views/feeds/search.psql
new file mode 100644
index 00000000..05c3ef28
--- /dev/null
+++ b/views/feeds/search.psql
@@ -0,0 +1,94 @@
+CREATE OR REPLACE VIEW optimized_search_index AS
+WITH search_data AS (
+  SELECT
+      'post' AS content_type,
+      CONCAT('📝 ', p.title) AS title,
+      CONCAT('https://coryd.dev', p.url) AS url,
+      p.tags,
+      NULL AS genre_name,
+      NULL AS genre_url
+  FROM optimized_posts p
+
+  UNION ALL
+
+  SELECT
+      'link' AS content_type,
+      CONCAT('🔗 ', l.title, ' via ', l.name) AS title,
+      l.link AS url,
+      l.tags,
+      NULL AS genre_name,
+      NULL AS genre_url
+  FROM optimized_links l
+
+  UNION ALL
+
+  SELECT
+      'book' AS content_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.tags,
+      NULL AS genre_name,
+      NULL AS genre_url
+  FROM optimized_books b
+  WHERE LOWER(b.status) = 'finished'
+
+  UNION ALL
+
+  SELECT
+      'movie' AS content_type,
+      CASE
+          WHEN m.rating IS NOT NULL THEN CONCAT('🎥 ', m.title, ' (', m.rating, ')')  -- Add emoji and rating for movies
+          ELSE CONCAT('🎥 ', m.title)
+      END AS title,
+      CONCAT('https://coryd.dev', m.url) AS url,
+      m.tags,
+      NULL AS genre_name,
+      NULL AS genre_url
+  FROM optimized_movies m
+  WHERE m.last_watched IS NOT NULL
+
+  UNION ALL
+
+  SELECT
+      'artist' AS content_type,
+      CONCAT('🎧 ', ar.name, ' - ', ar.genre_name) AS title,
+      CONCAT('https://coryd.dev', ar.url) AS url,
+      ARRAY[ar.genre_name] AS tags,
+      ar.genre_name,
+      CONCAT('https://coryd.dev', ar.genre_slug) AS genre_url
+  FROM optimized_artists ar
+
+  UNION ALL
+
+  SELECT
+      'genre' AS content_type,
+      CONCAT('🎵 ', g.name) AS title,
+      CONCAT('https://coryd.dev', g.url) AS url,
+      NULL AS tags,
+      g.name AS genre_name,
+      CONCAT('https://coryd.dev', g.url) AS genre_url
+  FROM optimized_genres g
+),
+
+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,
+        'tags', search_data_with_id.tags,
+        'genre_name', search_data_with_id.genre_name,
+        'genre_url', search_data_with_id.genre_url
+      )
+    ) AS search_index
+FROM search_data_with_id;
\ No newline at end of file
diff --git a/views/feeds/sitemap.psql b/views/feeds/sitemap.psql
new file mode 100644
index 00000000..83e9d877
--- /dev/null
+++ b/views/feeds/sitemap.psql
@@ -0,0 +1,57 @@
+CREATE OR REPLACE VIEW optimized_sitemap AS
+WITH sitemap_data AS (
+  SELECT
+      p.date AS content_date,
+      'post' AS content_type,
+      p.title,
+      CONCAT('https://coryd.dev', p.url) AS url
+  FROM optimized_posts p
+
+  UNION ALL
+
+  SELECT
+      b.date_finished AS content_date,
+      'book' AS content_type,
+      b.title,
+      CONCAT('https://coryd.dev', b.url) AS url
+  FROM optimized_books b
+  WHERE LOWER(b.status) = 'finished'
+
+  UNION ALL
+
+  SELECT
+      m.last_watched AS content_date,
+      'movie' AS content_type,
+      m.title,
+      CONCAT('https://coryd.dev', m.url) AS url
+  FROM optimized_movies m
+  WHERE m.last_watched IS NOT NULL
+
+  UNION ALL
+
+  SELECT
+      NULL AS content_date,
+      'artist' AS content_type,
+      ar.name AS title,
+      CONCAT('https://coryd.dev', ar.url) AS url
+  FROM optimized_artists ar
+
+  UNION ALL
+
+  SELECT
+      NULL AS content_date,
+      'genre' AS content_type,
+      g.name AS title,
+      CONCAT('https://coryd.dev', g.url) AS url
+  FROM optimized_genres g
+)
+
+SELECT
+    json_agg(
+        json_build_object(
+            'url', sd.url,
+            'title', sd.title,
+            'date', sd.content_date
+        )
+    ) AS sitemap
+FROM sitemap_data sd;
\ No newline at end of file
diff --git a/views/feeds/syndication.psql b/views/feeds/syndication.psql
new file mode 100644
index 00000000..17933f95
--- /dev/null
+++ b/views/feeds/syndication.psql
@@ -0,0 +1,103 @@
+CREATE OR REPLACE VIEW optimized_syndication AS
+WITH syndication_data AS (
+  SELECT
+      p.date AS content_date,
+      'post' AS content_type,
+      p.title,
+      p.description,
+      CONCAT('https://coryd.dev', p.url) AS url,
+      p.tags,
+      json_build_object(
+          'title', CONCAT('📝 ', p.title, ' ', (
+              SELECT array_to_string(
+                  array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
+              )
+              FROM unnest(p.tags) AS t(name)
+          )),
+          'description', p.description,
+          'url', CONCAT('https://coryd.dev', p.url),
+          'date', p.date
+      ) AS syndication
+  FROM optimized_posts p
+
+  UNION ALL
+
+  SELECT
+      l.date AS content_date,
+      'link' AS content_type,
+      l.title,
+      l.description,
+      l.link AS url,
+      l.tags,
+      json_build_object(
+          'title', CONCAT('🔗 ', l.title,
+              CASE
+                  WHEN l.mastodon IS NOT NULL THEN
+                      ' via @' || split_part(l.mastodon, '@', 2) || '@' || split_part(split_part(l.mastodon, 'https://', 2), '/', 1)
+                  ELSE ''
+              END, ' ', (
+                  SELECT array_to_string(
+                      array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
+                  )
+                  FROM unnest(l.tags) AS t(name)
+              )
+          ),
+          'description', l.description,
+          'url', l.link,
+          'date', l.date
+      ) AS syndication
+  FROM optimized_links l
+
+  UNION ALL
+
+  SELECT
+      b.date_finished AS content_date,
+      'book' AS content_type,
+      b.title,
+      b.description,
+      CONCAT('https://coryd.dev', b.url) AS url,
+      b.tags,
+      CASE
+          WHEN LOWER(b.status) = 'finished' THEN json_build_object(
+              'title', CONCAT('📖 ', b.title, ' ', (
+                  SELECT array_to_string(
+                      array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
+                  )
+                  FROM unnest(b.tags) AS t(name)
+              )),
+              'description', b.description,
+              'url', CONCAT('https://coryd.dev', b.url),
+              'date', b.date_finished
+          )
+          ELSE NULL
+      END AS syndication
+  FROM optimized_books b
+
+  UNION ALL
+
+  SELECT
+      m.last_watched AS content_date,
+      'movie' AS content_type,
+      m.title,
+      m.description,
+      CONCAT('https://coryd.dev', m.url) AS url,
+      m.tags,
+      CASE
+          WHEN m.last_watched IS NOT NULL THEN json_build_object(
+              'title', CONCAT('🎥 ', m.title, ' ', (
+                  SELECT array_to_string(
+                      array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
+                  )
+                  FROM unnest(m.tags) AS t(name)
+              )),
+              'description', m.description,
+              'url', CONCAT('https://coryd.dev', m.url),
+              'date', m.last_watched
+          )
+          ELSE NULL
+      END AS syndication
+  FROM optimized_movies m
+)
+
+SELECT json_agg(syndication_data.* ORDER BY syndication_data.content_date DESC) AS syndication
+FROM syndication_data;
\ No newline at end of file
diff --git a/views/globals/index.psql b/views/globals/index.psql
new file mode 100644
index 00000000..ab724e65
--- /dev/null
+++ b/views/globals/index.psql
@@ -0,0 +1,19 @@
+CREATE OR REPLACE VIEW optimized_globals AS
+SELECT
+    g.id,
+    g.site_name,
+    g.site_description,
+    g.author,
+    g.email,
+    g.mastodon,
+    g.url,
+    g.theme_color,
+    g.site_type,
+    g.locale,
+    g.lang,
+    CONCAT('/', df.filename_disk) AS avatar,
+    CONCAT('/', df2.filename_disk) AS avatar_transparent
+FROM
+    globals g
+    LEFT JOIN directus_files df ON g.avatar = df.id
+    LEFT JOIN directus_files df2 ON g.avatar_transparent = df2.id
\ No newline at end of file
diff --git a/views/globals/pages.psql b/views/globals/pages.psql
new file mode 100644
index 00000000..63ddcc40
--- /dev/null
+++ b/views/globals/pages.psql
@@ -0,0 +1,63 @@
+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;
\ No newline at end of file
diff --git a/views/media/books.psql b/views/media/books.psql
new file mode 100644
index 00000000..a7c6ba36
--- /dev/null
+++ b/views/media/books.psql
@@ -0,0 +1,107 @@
+CREATE OR REPLACE VIEW optimized_books AS
+SELECT
+    b.date_finished,
+    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('/', df.filename_disk) AS image,
+    b.favorite,
+    b.tattoo,
+    'book' AS type,
+
+    (
+      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
+      ))
+      FROM books_artists ba
+      LEFT JOIN artists a ON ba.artists_id = a.id
+      WHERE ba.books_id = b.id
+    ) AS artists,
+
+    (
+      SELECT json_agg(json_build_object(
+          'title', m.title,
+          'year', m.year,
+          'url', m.slug
+      ))
+      FROM movies_books mb
+      LEFT JOIN movies m ON mb.movies_id = m.id
+      WHERE mb.books_id = b.id
+    ) AS movies,
+
+    (
+      SELECT json_agg(json_build_object(
+          'name', g.name,
+          'url', g.slug
+      ))
+      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
+      ))
+      FROM shows_books sb
+      LEFT JOIN shows s ON sb.shows_id = s.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
+      ) ORDER BY rb.title)
+      FROM related_books rbk
+      LEFT JOIN books rb ON rbk.related_books_id = rb.id
+      WHERE rbk.books_id = b.id
+    ) AS related_books,
+
+    CASE
+        WHEN LOWER(b.read_status) = 'finished' AND b.star_rating IS NOT NULL THEN json_build_object(
+            'title', b.title,
+            'url', CONCAT('https://coryd.dev', b.slug),
+            'date', b.date_finished,
+            'description', b.description,
+            'image', CONCAT('/', df.filename_disk),
+            'rating', b.star_rating
+        )
+        ELSE NULL
+    END AS feed
+
+FROM
+    books b
+LEFT JOIN
+    directus_files df ON b.art = df.id
+GROUP BY
+    b.id, df.filename_disk;
\ No newline at end of file
diff --git a/views/media/movies.psql b/views/media/movies.psql
new file mode 100644
index 00000000..c15b57dc
--- /dev/null
+++ b/views/media/movies.psql
@@ -0,0 +1,116 @@
+CREATE OR REPLACE VIEW optimized_movies AS
+SELECT
+  m.id,
+  m.last_watched,
+  m.title,
+  m.year,
+  m.collected,
+  m.plays,
+  m.favorite,
+  m.tattoo,
+  m.star_rating AS rating,
+  m.description,
+  m.review,
+  'movie' AS type,
+
+  m.slug AS url,
+
+  CONCAT('/', df.filename_disk) AS image,
+  CONCAT('/', df2.filename_disk) AS backdrop,
+
+  (
+    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
+    ) ORDER BY a.name_string ASC)
+    FROM movies_artists ma
+    LEFT JOIN artists a ON ma.artists_id = a.id
+    WHERE ma.movies_id = m.id
+  ) AS artists,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', b.title,
+        'author', b.author,
+        'url', b.slug
+    ) ORDER BY b.title ASC)
+    FROM movies_books mb
+    LEFT JOIN books b ON mb.books_id = b.id
+    WHERE mb.movies_id = m.id
+  ) AS books,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', s.title,
+        'year', s.year,
+        'url', s.slug
+    ) ORDER BY s.year DESC)
+    FROM shows_movies sm
+    LEFT JOIN shows s ON sm.shows_id = s.id
+    WHERE sm.movies_id = m.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_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
+    ) ORDER BY rm.year DESC)
+    FROM related_movies r
+    LEFT JOIN movies rm ON r.related_movies_id = rm.id
+    WHERE r.movies_id = m.id
+  ) AS related_movies,
+
+  CASE
+    WHEN m.star_rating IS NOT NULL AND m.last_watched IS NOT NULL THEN 
+      json_build_object(
+        'title', m.title,
+        'url', CONCAT('https://coryd.dev', m.slug),
+        'date', m.last_watched,
+        'description', m.description,
+        'image', CONCAT('/', df.filename_disk),
+        'rating', m.star_rating
+      )
+    ELSE NULL
+  END AS feed
+
+FROM
+  movies m
+LEFT JOIN
+  directus_files df ON m.art = df.id
+LEFT JOIN
+  directus_files df2 ON m.backdrop = df2.id
+GROUP BY
+  m.id, df.filename_disk, df2.filename_disk
+ORDER BY
+  m.last_watched DESC, m.favorite DESC, m.title ASC;
\ No newline at end of file
diff --git a/views/media/music/album-releases.psql b/views/media/music/album-releases.psql
new file mode 100644
index 00000000..7c015fa5
--- /dev/null
+++ b/views/media/music/album-releases.psql
@@ -0,0 +1,25 @@
+CREATE OR REPLACE VIEW optimized_album_releases AS
+SELECT
+  a.name AS title,
+  a.release_date,
+  a.release_link AS url,
+  a.total_plays,
+  CONCAT('/', df.filename_disk) AS image,
+  'album-release' AS type,
+
+  json_build_object(
+    'name', ar.name_string,
+    'url', ar.slug,
+    'description', ar.description
+  ) AS artist,
+
+  EXTRACT(EPOCH FROM a.release_date) AS release_timestamp
+
+FROM
+  albums a
+LEFT JOIN
+  directus_files df ON a.art = df.id
+LEFT JOIN
+  artists ar ON a.artist = ar.id
+WHERE
+  a.release_date IS NOT NULL;
\ No newline at end of file
diff --git a/views/media/music/artists.psql b/views/media/music/artists.psql
new file mode 100644
index 00000000..348f2b62
--- /dev/null
+++ b/views/media/music/artists.psql
@@ -0,0 +1,117 @@
+CREATE OR REPLACE VIEW optimized_artists AS
+SELECT
+    ar.name_string AS name,
+    ar.slug AS url,
+    ar.tentative,
+    ar.total_plays AS totalPlays,
+    ar.country,
+    ar.description,
+    ar.favorite,
+    g.name AS genre_name,
+    g.slug AS genre_slug,
+
+    json_build_object(
+        'name', g.name,
+        'url', g.slug
+    ) AS genre,
+
+    ar.emoji,
+    ar.tattoo,
+    CONCAT('/', df.filename_disk) AS image,
+
+    json_build_object(
+        'alt', CONCAT(ar.total_plays, ' plays of ', ar.name_string),
+        'subtext', CONCAT(ar.total_plays, ' plays')
+    ) AS grid,
+
+    (
+        SELECT json_agg(json_build_object(
+            'name', a.name,
+            'releaseYear', a.release_year,
+            'totalPlays', a.total_plays,
+            'art', df_album.filename_disk
+        ) ORDER BY a.release_year)
+        FROM albums a
+        LEFT JOIN directus_files df_album ON a.art = df_album.id
+        WHERE a.artist = ar.id
+    ) AS albums,
+
+    (
+        SELECT json_agg(json_build_object(
+            'id', c.id,
+            'date', c.date,
+            'venue_name', v.name,
+            'venue_latitude', v.latitude,
+            'venue_longitude', v.longitude,
+            'notes', c.notes
+        ) ORDER BY c.date DESC)
+        FROM concerts c
+        LEFT JOIN venues v ON c.venue = v.id
+        WHERE c.artist = ar.id
+    ) AS concerts,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', b.title,
+            'author', b.author,
+            'url', b.slug
+        ) ORDER BY b.date_finished DESC)
+        FROM books_artists ba
+        LEFT JOIN books b ON ba.books_id = b.id
+        WHERE ba.artists_id = ar.id
+    ) AS books,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', m.title,
+            'year', m.year,
+            'url', m.slug,
+            'rating', m.rating,
+            'favorite', m.favorite
+        ) ORDER BY m.year DESC)
+        FROM movies_artists ma
+        LEFT JOIN movies m ON ma.movies_id = m.id
+        WHERE ma.artists_id = ar.id
+    ) AS movies,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', s.title,
+            'year', s.year,
+            'url', s.slug
+        ) ORDER BY s.year DESC)
+        FROM shows_artists sa
+        LEFT JOIN shows s ON sa.shows_id = s.id
+        WHERE sa.artists_id = ar.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_artists pa
+        LEFT JOIN posts p ON pa.posts_id = p.id
+        WHERE pa.artists_id = ar.id
+    ) AS posts,
+
+    (
+        SELECT json_agg(json_build_object(
+            'name', related_ar.name_string,
+            'url', related_ar.slug,
+            'country', related_ar.country,
+            'total_plays', related_ar.total_plays
+        ) ORDER BY related_ar.name_string)
+        FROM related_artists ra
+        LEFT JOIN artists related_ar ON ra.related_artists_id = related_ar.id
+        WHERE ra.artists_id = ar.id
+    ) AS related_artists
+FROM
+    artists ar
+LEFT JOIN
+    directus_files df ON ar.art = df.id
+LEFT JOIN
+    genres g ON ar.genres = g.id
+GROUP BY
+    ar.id, df.filename_disk, g.name, g.slug;
\ No newline at end of file
diff --git a/views/media/music/concerts.psql b/views/media/music/concerts.psql
new file mode 100644
index 00000000..7d9ed314
--- /dev/null
+++ b/views/media/music/concerts.psql
@@ -0,0 +1,39 @@
+CREATE OR REPLACE VIEW optimized_concerts AS
+SELECT
+    c.id,
+    c.date,
+    c.notes,
+    'I went to (yet another) concert!' AS description,
+    'concert' AS type,
+
+    CONCAT('/music/concerts?id=', c.id) AS url,
+
+    CASE
+        WHEN c.artist IS NOT NULL THEN
+            json_build_object(
+                'name', a.name_string,
+                'url', a.slug
+            )
+        ELSE
+            json_build_object(
+                'name', c.artist_name_string,
+                'url', NULL
+            )
+    END AS artist,
+
+    json_build_object(
+        'name', v.name,
+        'latitude', v.latitude,
+        'longitude', v.longitude,
+        'notes', v.notes
+    ) AS venue,
+
+    c.notes AS concert_notes
+
+FROM
+    concerts c
+    LEFT JOIN artists a ON c.artist = a.id
+    LEFT JOIN venues v ON c.venue = v.id
+
+ORDER BY
+    c.date DESC;
\ No newline at end of file
diff --git a/views/media/music/genres.psql b/views/media/music/genres.psql
new file mode 100644
index 00000000..cc2885f0
--- /dev/null
+++ b/views/media/music/genres.psql
@@ -0,0 +1,55 @@
+CREATE OR REPLACE VIEW optimized_genres AS
+SELECT
+    g.id,
+    g.name,
+    g.description,
+    g.total_plays,
+    g.wiki_link,
+    g.slug AS url,
+
+    (
+        SELECT json_agg(json_build_object(
+            'name', a.name_string,
+            'url', a.slug,
+            'total_plays', a.total_plays
+        ))
+        FROM artists a
+        WHERE a.genres = g.id
+    ) AS artists,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', b.title,
+            'author', b.author,
+            'url', b.slug
+        ))
+        FROM books b
+        JOIN genres_books gb ON gb.books_id = b.id
+        WHERE gb.genres_id = g.id
+    ) AS books,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', m.title,
+            'year', m.year,
+            'url', m.slug
+        ) ORDER BY m.year DESC)
+        FROM movies m
+        JOIN genres_movies gm ON gm.movies_id = m.id
+        WHERE gm.genres_id = g.id
+    ) AS movies,
+
+    (
+        SELECT json_agg(json_build_object(
+            'title', p.title,
+            'date', p.date,
+            'url', p.slug
+        ) ORDER BY p.date DESC)
+        FROM posts_genres pg
+        LEFT JOIN posts p ON pg.posts_id = p.id
+        WHERE pg.genres_id = g.id
+    ) AS posts
+FROM
+    genres g
+ORDER BY
+    g.id ASC;
\ No newline at end of file
diff --git a/views/media/music/listens.psql b/views/media/music/listens.psql
new file mode 100644
index 00000000..753944b6
--- /dev/null
+++ b/views/media/music/listens.psql
@@ -0,0 +1,24 @@
+CREATE OR REPLACE VIEW optimized_listens AS
+SELECT DISTINCT ON (l.id, l.listened_at, l.track_name, l.artist_name, l.album_name)
+    l.id,
+    l.listened_at,
+    l.track_name,
+    l.artist_name,
+    l.album_name,
+    l.album_key,
+    CONCAT('/', df_art.filename_disk) AS artist_art,
+    a.genres AS artist_genres,
+    g.name AS genre_name,
+    g.slug AS genre_url,
+    a.country AS artist_country,
+    a.slug AS artist_url,
+    CONCAT('/', df_album.filename_disk) AS album_art
+FROM
+    listens l
+LEFT JOIN artists a ON (l.artist_name = a.name_string)
+LEFT JOIN albums al ON (l.album_key = al.key)
+LEFT JOIN directus_files df_art ON (a.art = df_art.id)
+LEFT JOIN directus_files df_album ON (al.art = df_album.id)
+LEFT JOIN genres g ON (a.genres = g.id)
+ORDER BY
+    l.id, l.listened_at, l.track_name, l.artist_name, l.album_name;
\ No newline at end of file
diff --git a/views/media/music/month-tracks.psql b/views/media/music/month-tracks.psql
new file mode 100644
index 00000000..1533886e
--- /dev/null
+++ b/views/media/music/month-tracks.psql
@@ -0,0 +1,21 @@
+CREATE OR REPLACE VIEW month_tracks AS
+SELECT
+    ol.id,
+    ol.listened_at,
+    ol.track_name,
+    ol.artist_name,
+    ol.album_name,
+    ol.album_key,
+    ol.artist_art,
+    ol.artist_genres,
+    ol.genre_name,
+    ol.artist_country,
+    ol.album_art,
+    ol.artist_url,
+    ol.genre_url
+FROM
+    optimized_listens ol
+WHERE
+    TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
+ORDER BY
+    TO_TIMESTAMP(ol.listened_at) DESC;
\ No newline at end of file
diff --git a/views/media/music/now-playing.psql b/views/media/music/now-playing.psql
new file mode 100644
index 00000000..eede35b9
--- /dev/null
+++ b/views/media/music/now-playing.psql
@@ -0,0 +1,24 @@
+CREATE VIEW optimized_latest_listen AS
+WITH latest_listen AS (
+    SELECT
+        l.track_name,
+        l.artist_name,
+        a.emoji AS artist_emoji,
+        g.emoji AS genre_emoji,
+        a.slug AS url,
+        ROW_NUMBER() OVER (ORDER BY l.listened_at DESC) AS row_num
+    FROM
+        listens l
+    JOIN artists a ON l.artist_name = a.name_string
+    LEFT JOIN genres g ON a.genres = g.id
+)
+SELECT
+    track_name,
+    artist_name,
+    artist_emoji,
+    genre_emoji,
+    url
+FROM
+    latest_listen
+WHERE
+    row_num = 1;
\ No newline at end of file
diff --git a/views/media/music/recent-tracks.psql b/views/media/music/recent-tracks.psql
new file mode 100644
index 00000000..2715cf29
--- /dev/null
+++ b/views/media/music/recent-tracks.psql
@@ -0,0 +1,21 @@
+CREATE OR REPLACE VIEW recent_tracks AS
+SELECT
+    ol.id,
+    ol.listened_at,
+    ol.track_name,
+    ol.artist_name,
+    ol.album_name,
+    ol.album_key,
+    ol.artist_art,
+    ol.artist_genres,
+    ol.genre_name,
+    ol.artist_country,
+    ol.album_art,
+    ol.artist_url,
+    ol.genre_url
+FROM
+    optimized_listens ol
+WHERE
+    TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
+ORDER BY
+    TO_TIMESTAMP(ol.listened_at) DESC;
\ No newline at end of file
diff --git a/views/media/music/three-month-tracks.psql b/views/media/music/three-month-tracks.psql
new file mode 100644
index 00000000..f94b9142
--- /dev/null
+++ b/views/media/music/three-month-tracks.psql
@@ -0,0 +1,21 @@
+CREATE OR REPLACE VIEW three_month_tracks AS
+SELECT
+    ol.id,
+    ol.listened_at,
+    ol.track_name,
+    ol.artist_name,
+    ol.album_name,
+    ol.album_key,
+    ol.artist_art,
+    ol.artist_genres,
+    ol.genre_name,
+    ol.artist_country,
+    ol.album_art,
+    ol.artist_url,
+    ol.genre_url
+FROM
+    optimized_listens ol
+WHERE
+    TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
+ORDER BY
+    TO_TIMESTAMP(ol.listened_at) DESC;
\ No newline at end of file
diff --git a/views/media/shows.psql b/views/media/shows.psql
new file mode 100644
index 00000000..819f1f9b
--- /dev/null
+++ b/views/media/shows.psql
@@ -0,0 +1,102 @@
+CREATE OR REPLACE VIEW optimized_shows AS
+SELECT
+  s.id,
+  s.title,
+  s.year,
+  s.collected,
+  s.favorite,
+  s.tattoo,
+  s.description,
+  s.review,
+  s.slug AS url,
+  CONCAT('/', df_art.filename_disk) AS image,
+  CONCAT('/', df_backdrop.filename_disk) AS backdrop,
+
+  json_build_object(
+    'type', 'tv',
+    'title', s.title,
+    'year', s.year,
+    'url', s.slug,
+    'image', CONCAT('/', df_art.filename_disk),
+    'backdrop', CONCAT('/', df_backdrop.filename_disk),
+    'formatted_episode', CONCAT('S', MAX(e.season_number), 'E', MAX(e.episode_number)),
+    'last_watched_at', MAX(e.last_watched_at)
+  ) AS episode,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', m.title,
+        'year', m.year,
+        'url', m.slug
+    ) ORDER BY m.year DESC)
+    FROM shows_movies sm
+    LEFT JOIN movies m ON sm.movies_id = m.id
+    WHERE sm.shows_id = s.id
+  ) AS movies,
+
+  (
+    SELECT json_agg(json_build_object(
+        'title', b.title,
+        'author', b.author,
+        'url', b.slug
+    ) ORDER BY b.title)
+    FROM shows_books sb
+    LEFT JOIN books b ON sb.books_id = b.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
+    ) ORDER BY rs.year DESC)
+    FROM related_shows sr
+    LEFT JOIN shows rs ON sr.related_shows_id = rs.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
+    ) ORDER BY a.name_string)
+    FROM shows_artists sa
+    LEFT JOIN artists a ON sa.artists_id = a.id
+    WHERE sa.shows_id = s.id
+  ) AS artists,
+
+  MAX(e.last_watched_at) AS last_watched_at
+
+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
+GROUP BY
+  s.id, df_art.filename_disk, df_backdrop.filename_disk
+ORDER BY
+  MAX(e.last_watched_at) DESC;
\ No newline at end of file