398 lines
9.5 KiB
SQL
398 lines
9.5 KiB
SQL
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(globals.cdn_url, '/', df.filename_disk) AS image,
|
|
json_build_object(
|
|
'title',
|
|
ar.name_string,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df.filename_disk),
|
|
'url',
|
|
ar.slug,
|
|
'alt',
|
|
CASE
|
|
WHEN ar.total_plays > 0 THEN CONCAT(
|
|
to_char(ar.total_plays, 'FM999,999,999,999'),
|
|
' plays of ',
|
|
ar.name_string
|
|
)
|
|
ELSE CONCAT('Artwork of ', ar.name_string)
|
|
END,
|
|
'subtext',
|
|
CASE
|
|
WHEN ar.total_plays > 0 THEN CONCAT(
|
|
to_char(ar.total_plays, 'FM999,999,999,999'),
|
|
' plays'
|
|
)
|
|
ELSE NULL
|
|
END
|
|
) AS grid,
|
|
json_build_object(
|
|
'title',
|
|
ar.name_string,
|
|
'genre',
|
|
g.name,
|
|
'genre_url',
|
|
g.slug,
|
|
'emoji',
|
|
COALESCE(ar.emoji, g.emoji),
|
|
'plays',
|
|
to_char(ar.total_plays, 'FM999,999,999,999'),
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', 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,
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
a.name,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_album.filename_disk),
|
|
'alt',
|
|
CASE
|
|
WHEN a.total_plays > 0 THEN CONCAT(
|
|
to_char(a.total_plays, 'FM999,999,999,999'),
|
|
' plays of ',
|
|
a.name
|
|
)
|
|
ELSE CONCAT('Artwork for ', a.name)
|
|
END,
|
|
'subtext',
|
|
CASE
|
|
WHEN a.total_plays > 0 THEN CONCAT(
|
|
a.release_year,
|
|
' • ',
|
|
to_char(a.total_plays, 'FM999,999,999,999'),
|
|
' plays'
|
|
)
|
|
ELSE a.release_year::text
|
|
END
|
|
),
|
|
'type',
|
|
'albums'
|
|
)
|
|
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,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'alt',
|
|
CONCAT('Cover for ', b.title, ' by ', b.author),
|
|
'subtext',
|
|
CASE
|
|
WHEN b.star_rating IS NOT NULL THEN b.star_rating
|
|
ELSE NULL
|
|
END,
|
|
'url',
|
|
b.slug
|
|
),
|
|
'type',
|
|
'books'
|
|
)
|
|
ORDER BY
|
|
b.title ASC
|
|
)
|
|
FROM
|
|
books_artists ba
|
|
LEFT JOIN books b ON ba.books_id = b.id
|
|
LEFT JOIN directus_files df_book ON b.art = df_book.id
|
|
WHERE
|
|
ba.artists_id = ar.id
|
|
AND LOWER(b.read_status) = 'finished'
|
|
) AS books,
|
|
(
|
|
SELECT
|
|
json_agg(
|
|
json_build_object(
|
|
'title',
|
|
m.title,
|
|
'year',
|
|
m.year,
|
|
'url',
|
|
m.slug,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'alt',
|
|
CONCAT('Poster for ', m.title, ' (', m.year, ')'),
|
|
'subtext',
|
|
CASE
|
|
WHEN m.star_rating IS NOT NULL THEN m.star_rating::text
|
|
ELSE m.year::text
|
|
END,
|
|
'url',
|
|
m.slug
|
|
),
|
|
'type',
|
|
'movies'
|
|
)
|
|
ORDER BY
|
|
m.year ASC
|
|
)
|
|
FROM
|
|
movies_artists ma
|
|
LEFT JOIN movies m ON ma.movies_id = m.id
|
|
LEFT JOIN directus_files df_movie ON m.art = df_movie.id
|
|
WHERE
|
|
ma.artists_id = ar.id
|
|
AND m.last_watched IS NOT NULL
|
|
) AS movies,
|
|
(
|
|
SELECT
|
|
json_agg(
|
|
json_build_object(
|
|
'title',
|
|
s.title,
|
|
'year',
|
|
s.year,
|
|
'url',
|
|
s.slug,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_show.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_show.filename_disk),
|
|
'alt',
|
|
CONCAT('Artwork for ', 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,
|
|
'url',
|
|
s.slug
|
|
),
|
|
'type',
|
|
'tv'
|
|
)
|
|
ORDER BY
|
|
s.year ASC
|
|
)
|
|
FROM
|
|
shows_artists sa
|
|
LEFT JOIN shows s ON sa.shows_id = s.id
|
|
LEFT JOIN directus_files df_show ON s.art = df_show.id
|
|
WHERE
|
|
sa.artists_id = ar.id
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
episodes e
|
|
WHERE
|
|
e.show = s.id
|
|
AND e.last_watched_at IS NOT NULL
|
|
)
|
|
) AS shows,
|
|
(
|
|
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'),
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_related.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
related_ar.name_string,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_related.filename_disk),
|
|
'alt',
|
|
CASE
|
|
WHEN related_ar.total_plays > 0 THEN CONCAT(
|
|
to_char(related_ar.total_plays, 'FM999,999,999,999'),
|
|
' plays of ',
|
|
related_ar.name_string
|
|
)
|
|
ELSE CONCAT('Artwork of ', related_ar.name_string)
|
|
END,
|
|
'subtext',
|
|
CASE
|
|
WHEN related_ar.total_plays > 0 THEN CONCAT(
|
|
to_char(related_ar.total_plays, 'FM999,999,999,999'),
|
|
' plays'
|
|
)
|
|
ELSE NULL
|
|
END,
|
|
'url',
|
|
related_ar.slug
|
|
),
|
|
'type',
|
|
'music'
|
|
)
|
|
ORDER BY
|
|
related_ar.total_plays DESC
|
|
)
|
|
FROM
|
|
related_artists ra
|
|
LEFT JOIN artists related_ar ON ra.related_artists_id = related_ar.id
|
|
LEFT JOIN directus_files df_related ON related_ar.art = df_related.id
|
|
WHERE
|
|
ra.artists_id = ar.id
|
|
) AS related_artists,
|
|
json_build_object(
|
|
'title',
|
|
CONCAT(
|
|
'Artist • ',
|
|
ar.name_string,
|
|
' • ',
|
|
globals.site_name
|
|
),
|
|
'description',
|
|
LEFT(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
regexp_replace(ar.description, E'[*_`~#>-]', '', 'g'),
|
|
E'\\[(.*?)\\]\\((.*?)\\)',
|
|
E'\\1',
|
|
'g'
|
|
),
|
|
E'!\\[(.*?)\\]\\((.*?)\\)',
|
|
'',
|
|
'g'
|
|
),
|
|
250
|
|
),
|
|
'open_graph_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,
|
|
'url',
|
|
CONCAT(globals.url, ar.slug),
|
|
'type',
|
|
'artist'
|
|
) AS metadata
|
|
FROM
|
|
artists ar
|
|
LEFT JOIN directus_files df ON ar.art = df.id
|
|
LEFT JOIN genres g ON ar.genres = g.id
|
|
CROSS JOIN optimized_globals globals
|
|
GROUP BY
|
|
ar.id,
|
|
df.filename_disk,
|
|
g.name,
|
|
g.slug,
|
|
g.emoji,
|
|
globals.cdn_url,
|
|
globals.site_name,
|
|
globals.url;
|