feat: initial commit

This commit is contained in:
Cory Dransfeldt 2025-03-27 16:46:02 -07:00
commit e214116e40
No known key found for this signature in database
253 changed files with 17406 additions and 0 deletions

View file

@ -0,0 +1,107 @@
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('/', 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)
ORDER BY a.name_string ASC)
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)
ORDER BY m.year DESC)
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)
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)
ORDER BY s.year DESC)
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 ASC)
FROM
related_books rbk
LEFT JOIN books rb ON rbk.related_books_id = rb.id
WHERE
rbk.books_id = b.id) AS related_books,
json_build_object(
'title', NULL,
'image', CONCAT('/', 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
) 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('/', 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
FROM
books b
LEFT JOIN directus_files df ON b.art = df.id
GROUP BY
b.id,
df.filename_disk;

View file

@ -0,0 +1,119 @@
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('/', df.filename_disk) AS image,
CONCAT('/', df2.filename_disk) AS backdrop,
json_build_object(
'title', NULL,
'url', m.slug,
'image', CONCAT('/', df.filename_disk),
'backdrop', CONCAT('/', 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
) 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)
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', CONCAT(m.title, CASE
WHEN m.star_rating IS NOT NULL THEN CONCAT(' (', m.star_rating, ')')
ELSE ''
END),
'url', m.slug,
'date', m.last_watched,
'description', COALESCE(m.review, 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;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW optimized_album_releases AS
SELECT
a.name AS title,
a.release_date,
COALESCE(a.release_link, ar.slug) AS url,
a.total_plays,
CONCAT('/', df.filename_disk) AS image,
json_build_object('name', ar.name_string, 'url', ar.slug, 'description', ar.description) AS artist,
EXTRACT(EPOCH FROM a.release_date) AS release_timestamp,
json_build_object(
'title', a.name,
'image', CONCAT('/', df.filename_disk),
'url', COALESCE(a.release_link, ar.slug),
'alt', CONCAT(a.name, ' by ', ar.name_string),
'subtext', CONCAT(ar.name_string, ' / ', TO_CHAR(a.release_date, 'Mon FMDD, YYYY'))
) AS grid
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;

View file

@ -0,0 +1,29 @@
CREATE OR REPLACE VIEW optimized_albums AS
SELECT
al.name AS name,
al.release_year,
to_char(al.total_plays, 'FM999,999,999,999') AS total_plays,
al.total_plays AS total_plays_raw,
ar.name_string AS artist_name,
ar.slug AS artist_url,
CONCAT('/', df_album.filename_disk) AS image,
json_build_object(
'title', al.name,
'image', CONCAT('/', df_album.filename_disk),
'url', ar.slug,
'alt', CONCAT('Cover for ', al.name, ' by ', ar.name_string),
'subtext', CONCAT(to_char(al.total_plays, 'FM999,999,999,999'), ' plays')
) AS grid,
json_build_object(
'title', al.name,
'artist', ar.name_string,
'plays', to_char(al.total_plays, 'FM999,999,999,999'),
'image', CONCAT('/', df_album.filename_disk),
'url', ar.slug,
'year', al.release_year,
'alt', CONCAT('Cover for ', al.name, ' by ', ar.name_string)
) AS table
FROM albums al
LEFT JOIN artists ar ON al.artist = ar.id
LEFT JOIN directus_files df_album ON al.art = df_album.id
GROUP BY al.id, ar.name_string, ar.slug, df_album.filename_disk;

View file

@ -0,0 +1,109 @@
CREATE OR REPLACE VIEW optimized_artists AS
SELECT
ar.name_string AS name,
ar.slug AS url,
ar.tentative,
to_char(ar.total_plays, 'FM999,999,999,999') AS total_plays,
ar.total_plays AS total_plays_raw,
ar.country,
ar.description,
ar.favorite,
g.name AS genre_name,
g.slug AS genre_slug,
g.emoji AS genre_emoji,
json_build_object('name', g.name, 'url', g.slug, 'emoji', g.emoji) AS genre,
ar.emoji,
ar.tattoo,
CONCAT('/', df.filename_disk) AS image,
json_build_object(
'title', ar.name_string,
'image',
CONCAT('/', df.filename_disk),
'url', ar.slug,
'alt', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays of ', ar.name_string),
'subtext', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays')
) AS grid,
json_build_object(
'title', ar.name_string,
'genre', g.name,
'genre_url', g.slug,
'emoji', CASE WHEN ar.emoji IS NOT NULL THEN ar.emoji ELSE g.emoji END,
'plays', to_char(ar.total_plays, 'FM999,999,999,999'),
'image', CONCAT('/', df.filename_disk),
'url', ar.slug,
'alt', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays of ', ar.name_string)
) AS table,
(
SELECT
json_agg(json_build_object('name', a.name, 'release_year', a.release_year, 'total_plays', to_char(a.total_plays, 'FM999,999,999,999'),
'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_name_short', trim(split_part(v.name, ',', 1)), '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.title ASC)
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)
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', to_char(related_ar.total_plays, 'FM999,999,999,999'))
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,
g.emoji;

View file

@ -0,0 +1,19 @@
CREATE OR REPLACE VIEW optimized_concerts AS
SELECT
c.id,
c.date,
c.notes,
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, 'name_short', trim(split_part(v.name, ',', 1)), '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;

View file

@ -0,0 +1,50 @@
CREATE OR REPLACE VIEW optimized_genres AS
SELECT
g.id,
g.name,
g.description,
g.emoji,
to_char(g.total_plays, 'FM999,999,999,999') AS total_plays,
g.wiki_link,
g.slug AS url,
(
SELECT
json_agg(json_build_object('name', a.name_string, 'url', a.slug, 'image', CONCAT('/', df_artist.filename_disk), 'total_plays', to_char(a.total_plays, 'FM999,999,999,999'))
ORDER BY a.total_plays DESC)
FROM
artists a
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
WHERE
a.genres = g.id) AS artists,
(
SELECT
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
ORDER BY b.title ASC)
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;

View file

@ -0,0 +1,19 @@
CREATE OR REPLACE VIEW optimized_latest_listen AS
SELECT
l.track_name::TEXT AS track_name,
l.artist_name::TEXT AS artist_name,
a.emoji::TEXT AS artist_emoji,
g.emoji::TEXT AS genre_emoji,
a.slug::TEXT AS url,
NULL::FLOAT AS total_duration,
NULL::FLOAT AS progress_ticks
FROM
listens l
JOIN
artists a
ON l.artist_name = a.name_string
LEFT JOIN
genres g
ON a.genres = g.id
ORDER BY l.listened_at DESC
LIMIT 1;

View file

@ -0,0 +1,28 @@
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;

View file

@ -0,0 +1,20 @@
CREATE OR REPLACE VIEW month_albums AS
SELECT
ol.album_name,
ol.artist_name,
COUNT(*) AS plays,
ol.album_art,
ol.artist_url,
json_build_object('title', ol.album_name, 'image', ol.album_art, 'url', ol.artist_url, 'alt', CONCAT(ol.album_name, ' by ', ol.artist_name), 'subtext', ol.artist_name) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.album_name,
ol.artist_name,
ol.album_art,
ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,19 @@
CREATE OR REPLACE VIEW month_artists AS
SELECT
ol.artist_name,
COUNT(*) AS plays,
ol.artist_art,
ol.artist_url,
ARRAY_AGG(DISTINCT ol.genre_name) AS genres,
json_build_object('title', ol.artist_name, 'image', ol.artist_art, 'url', ol.artist_url, 'alt', CONCAT(COUNT(*), ' plays of ', ol.artist_name), 'subtext', CONCAT(COUNT(*), ' plays')) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.artist_name,
ol.artist_art,
ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,16 @@
CREATE OR REPLACE VIEW month_genres AS
SELECT
ol.genre_name,
ol.genre_url,
COUNT(*) AS plays,
json_build_object('alt', ol.genre_name, 'subtext', CONCAT(COUNT(*), ' plays')) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.genre_name,
ol.genre_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,37 @@
CREATE OR REPLACE VIEW month_tracks AS
WITH track_stats AS (
SELECT
ol.track_name,
ol.artist_name,
ol.album_name,
COUNT(*) AS plays,
MAX(ol.listened_at) AS last_listened,
ol.album_art,
ol.artist_url,
MAX(COUNT(*)) OVER () AS most_played
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.track_name,
ol.artist_name,
ol.album_name,
ol.album_art,
ol.artist_url
)
SELECT
track_name,
artist_name,
album_name,
plays,
last_listened,
album_art,
artist_url,
json_build_object('title', track_name, 'artist', artist_name, 'url', artist_url, 'plays', plays, 'alt', CONCAT(track_name, ' by ', artist_name), 'subtext', CONCAT(album_name, ' (', plays, ' plays)'), 'percentage', ROUND((plays::decimal / most_played) * 100, 2)) AS chart
FROM
track_stats
ORDER BY
plays DESC,
last_listened DESC;

View file

@ -0,0 +1,23 @@
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,
json_build_object('title', ol.track_name, 'subtext', ol.artist_name, 'alt', CONCAT(ol.track_name, ' by ', ol.artist_name), 'url', ol.artist_url, 'image', ol.album_art, 'played_at', ol.listened_at) AS chart
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
ORDER BY
TO_TIMESTAMP(ol.listened_at) DESC;

View file

@ -0,0 +1,20 @@
CREATE OR REPLACE VIEW week_albums AS
SELECT
ol.album_name,
ol.artist_name,
COUNT(*) AS plays,
ol.album_art,
ol.artist_url,
json_build_object('title', ol.album_name, 'image', ol.album_art, 'url', ol.artist_url, 'alt', CONCAT(ol.album_name, ' by ', ol.artist_name), 'subtext', ol.artist_name) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.album_name,
ol.artist_name,
ol.album_art,
ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,18 @@
CREATE OR REPLACE VIEW week_artists AS
SELECT
ol.artist_name,
COUNT(*) AS plays,
ol.artist_art,
ol.artist_url,
ARRAY_AGG(DISTINCT ol.genre_name) AS genres,
json_build_object('title', ol.artist_name, 'image', ol.artist_art, 'url', ol.artist_url, 'alt', CONCAT(COUNT(*), ' plays of ', ol.artist_name), 'subtext', CONCAT(COUNT(*), ' plays')) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.artist_name,
ol.artist_art,
ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,16 @@
CREATE OR REPLACE VIEW week_genres AS
SELECT
ol.genre_name,
ol.genre_url,
COUNT(*) AS plays,
json_build_object('alt', ol.genre_name, 'subtext', CONCAT(COUNT(*), ' plays')) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.genre_name,
ol.genre_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,46 @@
CREATE OR REPLACE VIEW week_tracks AS
WITH track_stats AS (
SELECT
ol.track_name,
ol.artist_name,
ol.album_name,
COUNT(*) AS plays,
MAX(ol.listened_at) AS last_listened,
ol.album_art,
ol.artist_url,
MAX(COUNT(*)) OVER () AS most_played,
RANK() OVER (ORDER BY COUNT(*) DESC, MAX(ol.listened_at) DESC) AS rank
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.track_name,
ol.artist_name,
ol.album_name,
ol.album_art,
ol.artist_url
)
SELECT
track_name,
artist_name,
album_name,
plays,
last_listened,
album_art,
artist_url,
json_build_object(
'title', track_name,
'artist', artist_name,
'url', artist_url,
'plays', plays,
'alt', CONCAT(track_name, ' by ', artist_name),
'subtext', CONCAT(album_name, ' (', plays, ' plays)'),
'percentage', ROUND((plays::decimal / most_played) * 100, 2),
'rank', rank
) AS chart
FROM
track_stats
ORDER BY
plays DESC,
last_listened DESC;

View file

@ -0,0 +1,248 @@
CREATE OR REPLACE VIEW optimized_recent_media AS
WITH ordered_artists AS (
SELECT
wa.artist_name,
wa.artist_art,
wa.artist_url,
wa.plays,
json_build_object(
'title', wa.artist_name,
'image', wa.artist_art,
'url', wa.artist_url,
'alt', CONCAT(wa.plays, ' plays of ', wa.artist_name),
'subtext', CONCAT(wa.plays, ' plays')
) AS grid
FROM week_artists wa
ORDER BY wa.plays DESC, wa.artist_name ASC
),
ordered_albums AS (
SELECT
wa.album_name,
wa.album_art,
wa.artist_name,
wa.artist_url,
wa.plays,
json_build_object(
'title', wa.album_name,
'image', wa.album_art,
'url', wa.artist_url,
'alt', CONCAT(wa.album_name, ' by ', wa.artist_name, ' (', wa.plays, ' plays)'),
'subtext', wa.artist_name
) AS grid
FROM week_albums wa
ORDER BY wa.plays DESC, wa.album_name ASC
),
recent_music AS (
SELECT * FROM (
(
SELECT
artist_name AS title,
artist_art AS image,
artist_url AS url,
'music' AS type,
1 AS rank,
grid
FROM ordered_artists
LIMIT 1
)
UNION ALL
(
SELECT
album_name AS title,
album_art AS image,
artist_url AS url,
'music' AS type,
2 AS rank,
grid
FROM ordered_albums
LIMIT 1
)
UNION ALL
(
SELECT
artist_name AS title,
artist_art AS image,
artist_url AS url,
'music' AS type,
3 AS rank,
grid
FROM ordered_artists
OFFSET 1 LIMIT 1
)
UNION ALL
(
SELECT
album_name AS title,
album_art AS image,
artist_url AS url,
'music' AS type,
4 AS rank,
grid
FROM ordered_albums
OFFSET 1 LIMIT 1
)
) AS recent_music_subquery
),
recent_watched_read AS (
SELECT * FROM (
(
SELECT
om.title,
om.image,
om.url,
'tv' AS type,
1 AS rank,
json_build_object(
'title', null,
'url', om.url,
'image', om.image,
'backdrop', om.backdrop,
'alt', CONCAT('Poster from ', om.title, ' (', om.year, ')'),
'subtext', CASE WHEN om.rating IS NOT NULL THEN
om.rating::text
ELSE
om.year::text
END
) AS grid
FROM optimized_movies om
WHERE om.last_watched IS NOT NULL
ORDER BY om.last_watched DESC, om.title ASC
LIMIT 1
)
UNION ALL
(
SELECT
os.title,
os.image,
os.url,
'tv' AS type,
2 AS rank,
json_build_object(
'title', null,
'image', os.image,
'url', os.url,
'alt', CONCAT('Poster from ', os.title),
'subtext', (
SELECT CONCAT('S', e.season_number, 'E', e.episode_number)
FROM episodes e
WHERE e.show = os.id
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
LIMIT 1
)
) AS grid
FROM optimized_shows os
WHERE os.last_watched_at IS NOT NULL
ORDER BY os.last_watched_at DESC, os.title ASC
LIMIT 1
)
UNION ALL
(
SELECT
ob.title,
ob.image,
ob.url,
'books' AS type,
3 AS rank,
json_build_object(
'title', null,
'image', ob.image,
'url', ob.url,
'alt', CONCAT('Book cover from ', ob.title, ' by ', ob.author),
'subtext', CASE WHEN ob.rating IS NOT NULL THEN
ob.rating
ELSE
NULL
END
) AS grid
FROM optimized_books ob
WHERE ob.status = 'finished'
ORDER BY ob.date_finished DESC, ob.title ASC
LIMIT 1
)
UNION ALL
(
SELECT
om.title,
om.image,
om.url,
'tv' AS type,
4 AS rank,
json_build_object(
'title', null,
'url', om.url,
'image', om.image,
'backdrop', om.backdrop,
'alt', CONCAT('Poster from ', om.title, ' (', om.year, ')'),
'subtext', CASE WHEN om.rating IS NOT NULL THEN
om.rating::text
ELSE
om.year::text
END
) AS grid
FROM optimized_movies om
WHERE om.last_watched IS NOT NULL
ORDER BY om.last_watched DESC, om.title ASC
OFFSET 1 LIMIT 1
)
UNION ALL
(
SELECT
os.title,
os.image,
os.url,
'tv' AS type,
5 AS rank,
json_build_object(
'title', null,
'image', os.image,
'url', os.url,
'alt', CONCAT('Poster from ', os.title),
'subtext', (
SELECT CONCAT('S', e.season_number, 'E', e.episode_number)
FROM episodes e
WHERE e.show = os.id
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
LIMIT 1
)
) AS grid
FROM optimized_shows os
WHERE os.last_watched_at IS NOT NULL
ORDER BY os.last_watched_at DESC, os.title ASC
OFFSET 1 LIMIT 1
)
UNION ALL
(
SELECT
ob.title,
ob.image,
ob.url,
'books' AS type,
6 AS rank,
json_build_object(
'title', null,
'image', ob.image,
'url', ob.url,
'alt', CONCAT('Book cover from ', ob.title, ' by ', ob.author),
'subtext', CASE WHEN ob.rating IS NOT NULL THEN
ob.rating
ELSE
NULL
END
) AS grid
FROM optimized_books ob
WHERE ob.status = 'finished'
ORDER BY ob.date_finished DESC, ob.title ASC
OFFSET 1 LIMIT 1
)
) AS recent_watched_read_subquery
)
SELECT json_build_object(
'recentMusic', (
SELECT json_agg(m.* ORDER BY m.rank)
FROM recent_music m
),
'recentWatchedRead', (
SELECT json_agg(w.* ORDER BY w.rank)
FROM recent_watched_read w
)
) AS recent_activity;

View file

@ -0,0 +1,10 @@
CREATE OR REPLACE VIEW optimized_last_watched_episodes AS
SELECT DISTINCT ON (e.show)
e.show AS show_id,
e.season_number,
e.episode_number,
e.last_watched_at,
CONCAT('S', e.season_number, 'E', e.episode_number) AS last_watched_episode
FROM episodes e
WHERE e.last_watched_at IS NOT NULL
ORDER BY e.show, e.last_watched_at DESC;

View file

@ -0,0 +1,26 @@
CREATE OR REPLACE VIEW optimized_scheduled_episodes AS
SELECT
se.show_id,
se.season_number,
se.episode_number,
se.status,
se.air_date,
(
SELECT CONCAT('S', se2.season_number, 'E', se2.episode_number)
FROM scheduled_episodes se2
WHERE se2.show_id = se.show_id
AND se2.status IN ('upcoming', 'aired')
ORDER BY se2.air_date ASC
LIMIT 1
) AS next_scheduled_episode,
(
SELECT se2.air_date
FROM scheduled_episodes se2
WHERE se2.show_id = se.show_id
AND se2.status IN ('upcoming', 'aired')
ORDER BY se2.air_date ASC
LIMIT 1
) AS next_air_date
FROM scheduled_episodes se
WHERE se.status IN ('upcoming', 'aired')
GROUP BY se.show_id, se.season_number, se.episode_number, se.status, se.air_date;

View file

@ -0,0 +1,145 @@
CREATE OR REPLACE VIEW optimized_scheduled_shows AS
SELECT json_build_object(
'watching', (
SELECT json_agg(watching) FROM (
SELECT
s.id,
s.tmdb_id,
s.title,
s.year,
s.ongoing,
s.slug AS url,
CONCAT('/', df_art.filename_disk) AS image,
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
json_build_object(
'title', s.title,
'image', CONCAT('/', df_art.filename_disk),
'backdrop', CONCAT('/', df_backdrop.filename_disk),
'url', s.slug,
'alt', CONCAT('Poster from ', s.title),
'subtext', COALESCE(
(SELECT CONCAT(
'S', se.season_number, 'E', se.episode_number, ' • ',
CASE
WHEN EXTRACT(YEAR FROM se.air_date) < EXTRACT(YEAR FROM CURRENT_DATE)
THEN TO_CHAR(se.air_date, 'FMMM/FMDD/YY')
ELSE TO_CHAR(se.air_date, 'FMMM/FMDD')
END
)
FROM scheduled_episodes se
WHERE se.show_id = s.id
AND se.status IN ('upcoming', 'aired')
AND NOT EXISTS (
SELECT 1 FROM episodes e
WHERE e.show = s.id
AND e.season_number = se.season_number
AND e.episode_number = se.episode_number
)
ORDER BY se.season_number ASC, se.episode_number ASC
LIMIT 1),
(SELECT CONCAT(
'S', e.season_number, 'E', e.episode_number, ' • ',
CASE
WHEN EXTRACT(YEAR FROM e.last_watched_at) < EXTRACT(YEAR FROM CURRENT_DATE)
THEN TO_CHAR(e.last_watched_at, 'FMMM/FMDD/YY')
ELSE TO_CHAR(e.last_watched_at, 'FMMM/FMDD')
END
)
FROM episodes e
WHERE e.show = s.id
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
LIMIT 1),
s.year::text
)
) AS grid,
CASE
WHEN (
SELECT se.air_date
FROM scheduled_episodes se
WHERE se.show_id = s.id
AND se.status IN ('upcoming', 'aired')
AND NOT EXISTS (
SELECT 1 FROM episodes e
WHERE e.show = s.id
AND e.season_number = se.season_number
AND e.episode_number = se.episode_number
)
ORDER BY se.season_number ASC, se.episode_number ASC
LIMIT 1
) >= NOW()
THEN (
SELECT se.air_date::timestamp
FROM scheduled_episodes se
WHERE se.show_id = s.id
AND se.status IN ('upcoming', 'aired')
AND NOT EXISTS (
SELECT 1 FROM episodes e
WHERE e.show = s.id
AND e.season_number = se.season_number
AND e.episode_number = se.episode_number
)
ORDER BY se.season_number ASC, se.episode_number ASC
LIMIT 1
)
ELSE (
SELECT MIN(e.last_watched_at)::timestamp
FROM episodes e
WHERE e.show = s.id
)
END AS sort_date
FROM shows s
LEFT JOIN directus_files df_art ON s.art = df_art.id
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
WHERE s.ongoing = true
AND EXISTS (
SELECT 1
FROM scheduled_episodes se
WHERE se.show_id = s.id
AND se.status IN ('upcoming', 'aired')
)
AND EXISTS (
SELECT 1
FROM episodes e
WHERE e.show = s.id
)
ORDER BY sort_date ASC NULLS LAST, s.title ASC NULLS LAST
) watching
),
'unstarted', (
SELECT json_agg(unstarted) FROM (
SELECT
s.id,
s.tmdb_id,
s.title,
s.year,
s.ongoing,
s.slug AS url,
CONCAT('/', df_art.filename_disk) AS image,
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
json_build_object(
'title', s.title,
'image', CONCAT('/', df_art.filename_disk),
'backdrop', CONCAT('/', df_backdrop.filename_disk),
'url', s.slug,
'alt', CONCAT('Poster from ', s.title),
'subtext', s.year::text
) AS grid
FROM shows s
LEFT JOIN directus_files df_art ON s.art = df_art.id
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
WHERE s.ongoing = true
AND EXISTS (
SELECT 1
FROM scheduled_episodes se
WHERE se.show_id = s.id
AND se.status IN ('upcoming', 'aired')
)
AND NOT EXISTS (
SELECT 1
FROM episodes e
WHERE e.show = s.id
)
ORDER BY s.title ASC
) unstarted
)
) AS scheduled_shows

View file

@ -0,0 +1,125 @@
CREATE OR REPLACE VIEW optimized_shows AS
SELECT
s.id,
s.tmdb_id,
s.title,
s.year,
s.favorite,
s.tattoo,
s.description,
s.review,
s.ongoing,
s.slug AS url,
CONCAT('/', df_art.filename_disk) AS image,
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
json_build_object(
'title', NULL,
'image', CONCAT('/', df_art.filename_disk),
'backdrop', CONCAT('/', df_backdrop.filename_disk),
'url', s.slug,
'alt', CONCAT('Poster from ', 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
) AS grid,
json_build_object(
'title', s.title,
'year', s.year,
'url', s.slug,
'image', CONCAT('/', df_art.filename_disk),
'backdrop', CONCAT('/', df_backdrop.filename_disk),
'formatted_episode', COALESCE((
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
), NULL),
'last_watched_at', (
SELECT MAX(e3.last_watched_at)
FROM episodes e3
WHERE e3.show = s.id
)
) 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 ASC)
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 ASC)
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;