initial commit
This commit is contained in:
commit
c70fc72952
143 changed files with 13594 additions and 0 deletions
17
queries/views/media/music/album-releases.psql
Normal file
17
queries/views/media/music/album-releases.psql
Normal file
|
@ -0,0 +1,17 @@
|
|||
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,
|
||||
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', a.release_link, '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;
|
||||
|
94
queries/views/media/music/artists.psql
Normal file
94
queries/views/media/music/artists.psql
Normal file
|
@ -0,0 +1,94 @@
|
|||
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, -- Format total_plays with commas
|
||||
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('alt', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays of ', ar.name_string), -- Format total_plays in alt text
|
||||
'subtext', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays') -- Format total_plays in subtext
|
||||
) AS grid,
|
||||
(
|
||||
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'), -- Format total_plays here as well
|
||||
'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.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)
|
||||
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;
|
||||
|
19
queries/views/media/music/concerts.psql
Normal file
19
queries/views/media/music/concerts.psql
Normal 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;
|
||||
|
49
queries/views/media/music/genres.psql
Normal file
49
queries/views/media/music/genres.psql
Normal file
|
@ -0,0 +1,49 @@
|
|||
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))
|
||||
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;
|
||||
|
28
queries/views/media/music/listens.psql
Normal file
28
queries/views/media/music/listens.psql
Normal 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;
|
||||
|
20
queries/views/media/music/month/albums.psql
Normal file
20
queries/views/media/music/month/albums.psql
Normal 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;
|
||||
|
19
queries/views/media/music/month/artists.psql
Normal file
19
queries/views/media/music/month/artists.psql
Normal 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;
|
||||
|
16
queries/views/media/music/month/genres.psql
Normal file
16
queries/views/media/music/month/genres.psql
Normal 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;
|
||||
|
37
queries/views/media/music/month/tracks.psql
Normal file
37
queries/views/media/music/month/tracks.psql
Normal 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;
|
||||
|
25
queries/views/media/music/now-playing.psql
Normal file
25
queries/views/media/music/now-playing.psql
Normal file
|
@ -0,0 +1,25 @@
|
|||
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;
|
||||
|
23
queries/views/media/music/recent-tracks.psql
Normal file
23
queries/views/media/music/recent-tracks.psql
Normal 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;
|
||||
|
20
queries/views/media/music/week/albums.psql
Normal file
20
queries/views/media/music/week/albums.psql
Normal 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;
|
||||
|
19
queries/views/media/music/week/artists.psql
Normal file
19
queries/views/media/music/week/artists.psql
Normal file
|
@ -0,0 +1,19 @@
|
|||
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;
|
||||
|
16
queries/views/media/music/week/genres.psql
Normal file
16
queries/views/media/music/week/genres.psql
Normal 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;
|
||||
|
37
queries/views/media/music/week/tracks.psql
Normal file
37
queries/views/media/music/week/tracks.psql
Normal file
|
@ -0,0 +1,37 @@
|
|||
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
|
||||
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)) AS chart
|
||||
FROM
|
||||
track_stats
|
||||
ORDER BY
|
||||
plays DESC,
|
||||
last_listened DESC;
|
||||
|
Reference in a new issue