59 lines
1.1 KiB
SQL
59 lines
1.1 KiB
SQL
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,
|
|
RANK() OVER (
|
|
ORDER BY
|
|
COUNT(*) DESC,
|
|
MAX(ol.listened_at) DESC
|
|
) AS rank
|
|
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),
|
|
'rank',
|
|
rank
|
|
) AS chart
|
|
FROM
|
|
track_stats
|
|
ORDER BY
|
|
plays DESC,
|
|
last_listened DESC;
|