initial commit
This commit is contained in:
commit
c70fc72952
143 changed files with 13594 additions and 0 deletions
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;
|
||||
|
Reference in a new issue