feat: initial view queries
This commit is contained in:
parent
8f44ce9bdd
commit
08e2c2ff3f
23 changed files with 1282 additions and 10 deletions
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;
|
Reference in a new issue