diff --git a/api/v1_track_top_listeners.go b/api/v1_track_top_listeners.go index 8648a1d5..b5741cb4 100644 --- a/api/v1_track_top_listeners.go +++ b/api/v1_track_top_listeners.go @@ -28,21 +28,17 @@ func (app *ApiServer) v1TrackTopListeners(c *fiber.Ctx) error { } sql := ` - WITH deduped AS ( - SELECT DISTINCT play_item_id, user_id, date_trunc('hour', created_at) as created_at + SELECT c.user_id, c.play_count + FROM ( + SELECT user_id, + count(DISTINCT date_trunc('hour', created_at)) AS play_count FROM plays WHERE user_id IS NOT NULL AND play_item_id = @trackId - ), - counted as ( - SELECT user_id, count(*) as play_count - FROM deduped - GROUP BY 1 - ) - SELECT counted.user_id, counted.play_count - FROM counted - LEFT JOIN aggregate_user USING (user_id) - ORDER BY play_count DESC, follower_count DESC, counted.user_id ASC + GROUP BY user_id + ) c + LEFT JOIN aggregate_user au USING (user_id) + ORDER BY c.play_count DESC, au.follower_count DESC NULLS LAST, c.user_id ASC LIMIT @limit OFFSET @offset ` diff --git a/ddl/migrations/0190_add_plays_top_listeners_index.sql b/ddl/migrations/0190_add_plays_top_listeners_index.sql new file mode 100644 index 00000000..4dc0309a --- /dev/null +++ b/ddl/migrations/0190_add_plays_top_listeners_index.sql @@ -0,0 +1,10 @@ +BEGIN; + +-- Add index optimized for top_listeners query +-- This index allows efficient filtering by play_item_id and supports +-- the count(distinct date_trunc('hour', created_at)) operation +CREATE INDEX IF NOT EXISTS ix_plays_play_item_user_date +ON plays(play_item_id, user_id, created_at) +WHERE user_id IS NOT NULL; + +COMMIT;