feat: initial view queries
This commit is contained in:
parent
8f44ce9bdd
commit
08e2c2ff3f
23 changed files with 1282 additions and 10 deletions
107
views/media/books.psql
Normal file
107
views/media/books.psql
Normal file
|
@ -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;
|
116
views/media/movies.psql
Normal file
116
views/media/movies.psql
Normal file
|
@ -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;
|
25
views/media/music/album-releases.psql
Normal file
25
views/media/music/album-releases.psql
Normal file
|
@ -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;
|
117
views/media/music/artists.psql
Normal file
117
views/media/music/artists.psql
Normal file
|
@ -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;
|
39
views/media/music/concerts.psql
Normal file
39
views/media/music/concerts.psql
Normal file
|
@ -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;
|
55
views/media/music/genres.psql
Normal file
55
views/media/music/genres.psql
Normal file
|
@ -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;
|
24
views/media/music/listens.psql
Normal file
24
views/media/music/listens.psql
Normal file
|
@ -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;
|
21
views/media/music/month-tracks.psql
Normal file
21
views/media/music/month-tracks.psql
Normal file
|
@ -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;
|
24
views/media/music/now-playing.psql
Normal file
24
views/media/music/now-playing.psql
Normal file
|
@ -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;
|
21
views/media/music/recent-tracks.psql
Normal file
21
views/media/music/recent-tracks.psql
Normal file
|
@ -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;
|
21
views/media/music/three-month-tracks.psql
Normal file
21
views/media/music/three-month-tracks.psql
Normal file
|
@ -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;
|
102
views/media/shows.psql
Normal file
102
views/media/shows.psql
Normal file
|
@ -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;
|
Reference in a new issue