diff --git a/client/app/routes/MediaItems/Album.tsx b/client/app/routes/MediaItems/Album.tsx
index 955baec..a262ac3 100644
--- a/client/app/routes/MediaItems/Album.tsx
+++ b/client/app/routes/MediaItems/Album.tsx
@@ -43,7 +43,7 @@ export default function Album() {
}}
subContent={
diff --git a/client/app/routes/MediaItems/Artist.tsx b/client/app/routes/MediaItems/Artist.tsx
index 41a185a..b698a27 100644
--- a/client/app/routes/MediaItems/Artist.tsx
+++ b/client/app/routes/MediaItems/Artist.tsx
@@ -49,7 +49,7 @@ export default function Artist() {
}}
subContent={
{artist.listen_count &&
{artist.listen_count} play{ artist.listen_count > 1 ? 's' : ''}
}
- {
{timeListenedString(artist.time_listened)}
}
+ {
{timeListenedString(artist.time_listened)}
}
}
>
diff --git a/client/app/routes/MediaItems/MediaLayout.tsx b/client/app/routes/MediaItems/MediaLayout.tsx
index 309e347..f9762bb 100644
--- a/client/app/routes/MediaItems/MediaLayout.tsx
+++ b/client/app/routes/MediaItems/MediaLayout.tsx
@@ -61,7 +61,7 @@ export default function MediaLayout(props: Props) {
transition: '1000',
}}
>
-
+
{title}
appears on {album.title}
{track.listen_count &&
{track.listen_count} play{ track.listen_count > 1 ? 's' : ''}
}
- {
{timeListenedString(track.time_listened)}
}
+ {
{timeListenedString(track.time_listened)}
}
}
>
diff --git a/db/migrations/000004_fix_usernames.sql b/db/migrations/000004_fix_usernames.sql
new file mode 100644
index 0000000..58b13e6
--- /dev/null
+++ b/db/migrations/000004_fix_usernames.sql
@@ -0,0 +1,3 @@
+-- +goose Up
+UPDATE users
+SET username = LOWER(username);
\ No newline at end of file
diff --git a/db/migrations/migrations.go b/db/migrations/migrations.go
new file mode 100644
index 0000000..381665a
--- /dev/null
+++ b/db/migrations/migrations.go
@@ -0,0 +1,6 @@
+package migrations
+
+import "embed"
+
+//go:embed *.sql
+var Files embed.FS
diff --git a/db/queries/release.sql b/db/queries/release.sql
index eb66d71..767163f 100644
--- a/db/queries/release.sql
+++ b/db/queries/release.sql
@@ -4,7 +4,10 @@ VALUES ($1, $2, $3, $4)
RETURNING *;
-- name: GetRelease :one
-SELECT * FROM releases_with_title
+SELECT
+ *,
+ get_artists_for_release(id) AS artists
+FROM releases_with_title
WHERE id = $1 LIMIT 1;
-- name: GetReleaseByMbzID :one
diff --git a/db/queries/track.sql b/db/queries/track.sql
index 8d8e681..acaa1d3 100644
--- a/db/queries/track.sql
+++ b/db/queries/track.sql
@@ -11,6 +11,7 @@ ON CONFLICT DO NOTHING;
-- name: GetTrack :one
SELECT
t.*,
+ get_artists_for_track(t.id) AS artists,
r.image
FROM tracks_with_title t
JOIN releases r ON t.release_id = r.id
diff --git a/db/queries/year.sql b/db/queries/year.sql
new file mode 100644
index 0000000..d6e8017
--- /dev/null
+++ b/db/queries/year.sql
@@ -0,0 +1,374 @@
+-- name: GetMostReplayedTrackInYear :one
+WITH ordered_listens AS (
+ SELECT
+ user_id,
+ track_id,
+ listened_at,
+ ROW_NUMBER() OVER (PARTITION BY user_id ORDER BY listened_at) AS rn
+ FROM listens
+ WHERE EXTRACT(YEAR FROM listened_at) = @year::int
+),
+streaks AS (
+ SELECT
+ user_id,
+ track_id,
+ listened_at,
+ rn,
+ ROW_NUMBER() OVER (PARTITION BY user_id, track_id ORDER BY listened_at) AS track_rn
+ FROM ordered_listens
+),
+grouped_streaks AS (
+ SELECT
+ user_id,
+ track_id,
+ rn - track_rn AS group_id,
+ COUNT(*) AS streak_length
+ FROM streaks
+ GROUP BY user_id, track_id, rn - track_rn
+),
+ranked_streaks AS (
+ SELECT *,
+ RANK() OVER (PARTITION BY user_id ORDER BY streak_length DESC) AS r
+ FROM grouped_streaks
+)
+SELECT
+ t.*,
+ get_artists_for_track(t.id) as artists,
+ streak_length
+FROM ranked_streaks rs JOIN tracks_with_title t ON rs.track_id = t.id
+WHERE user_id = @user_id::int AND r = 1;
+
+-- name: TracksOnlyPlayedOnceInYear :many
+SELECT
+ t.id AS track_id,
+ t.title,
+ get_artists_for_track(t.id) as artists,
+ COUNT(l.*) AS listen_count
+FROM listens l
+JOIN tracks_with_title t ON t.id = l.track_id
+WHERE EXTRACT(YEAR FROM l.listened_at) = @year::int AND l.user_id = @user_id::int
+GROUP BY t.id, t.title
+HAVING COUNT(*) = 1
+LIMIT $1;
+
+-- name: ArtistsOnlyPlayedOnceInYear :many
+SELECT
+ a.id AS artist_id,
+ a.name,
+ COUNT(l.*) AS listen_count
+FROM listens l
+JOIN artist_tracks at ON at.track_id = l.track_id
+JOIN artists_with_name a ON a.id = at.artist_id
+WHERE EXTRACT(YEAR FROM l.listened_at) = @year::int AND l.user_id = @user_id::int
+GROUP BY a.id, a.name
+HAVING COUNT(*) = 1;
+
+-- GetNewTrackWithMostListensInYear :one
+WITH first_plays_in_year AS (
+ SELECT
+ l.user_id,
+ l.track_id,
+ MIN(l.listened_at) AS first_listen
+ FROM listens l
+ WHERE EXTRACT(YEAR FROM l.listened_at) = @year::int
+ AND NOT EXISTS (
+ SELECT 1
+ FROM listens l2
+ WHERE l2.user_id = l.user_id
+ AND l2.track_id = l.track_id
+ AND l2.listened_at < @first_day_of_year::date
+ )
+ GROUP BY l.user_id, l.track_id
+),
+seven_day_window AS (
+ SELECT
+ f.user_id,
+ f.track_id,
+ f.first_listen,
+ COUNT(l.*) AS plays_in_7_days
+ FROM first_plays_in_year f
+ JOIN listens l
+ ON l.user_id = f.user_id
+ AND l.track_id = f.track_id
+ AND l.listened_at >= f.first_listen
+ AND l.listened_at < f.first_listen + INTERVAL '7 days'
+ GROUP BY f.user_id, f.track_id, f.first_listen
+),
+ranked AS (
+ SELECT *,
+ RANK() OVER (PARTITION BY user_id ORDER BY plays_in_7_days DESC) AS r
+ FROM seven_day_window
+)
+SELECT
+ s.user_id,
+ s.track_id,
+ t.title,
+ get_artists_for_track(t.id) as artists,
+ s.first_listen,
+ s.plays_in_7_days
+FROM ranked s
+JOIN tracks_with_title t ON t.id = s.track_id
+WHERE r = 1;
+
+-- GetTopThreeNewArtistsInYear :many
+WITH first_artist_plays_in_year AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MIN(l.listened_at) AS first_listen
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE EXTRACT(YEAR FROM l.listened_at) = @year::int
+ AND NOT EXISTS (
+ SELECT 1
+ FROM listens l2
+ JOIN artist_tracks at2 ON at2.track_id = l2.track_id
+ WHERE l2.user_id = l.user_id
+ AND at2.artist_id = at.artist_id
+ AND l2.listened_at < @first_day_of_year::date
+ )
+ GROUP BY l.user_id, at.artist_id
+),
+artist_plays_in_year AS (
+ SELECT
+ f.user_id,
+ f.artist_id,
+ f.first_listen,
+ COUNT(l.*) AS total_plays_in_year
+ FROM first_artist_plays_in_year f
+ JOIN listens l ON l.user_id = f.user_id
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE at.artist_id = f.artist_id
+ AND EXTRACT(YEAR FROM l.listened_at) = @year::int
+ GROUP BY f.user_id, f.artist_id, f.first_listen
+),
+ranked AS (
+ SELECT *,
+ RANK() OVER (PARTITION BY user_id ORDER BY total_plays_in_year DESC) AS r
+ FROM artist_plays_in_year
+)
+SELECT
+ a.user_id,
+ a.artist_id,
+ awn.name AS artist_name,
+ a.first_listen,
+ a.total_plays_in_year
+FROM ranked a
+JOIN artists_with_name awn ON awn.id = a.artist_id
+WHERE r <= 3;
+
+-- name: GetArtistWithLongestGapInYear :one
+WITH first_listens AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MIN(l.listened_at::date) AS first_listen_of_year
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE EXTRACT(YEAR FROM l.listened_at) = @year::int
+ GROUP BY l.user_id, at.artist_id
+),
+last_listens AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MAX(l.listened_at::date) AS last_listen
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE l.listened_at < @first_day_of_year::date
+ GROUP BY l.user_id, at.artist_id
+),
+comebacks AS (
+ SELECT
+ f.user_id,
+ f.artist_id,
+ f.first_listen_of_year,
+ p.last_listen,
+ (f.first_listen_of_year - p.last_listen) AS gap_days
+ FROM first_listens f
+ JOIN last_listens p
+ ON f.user_id = p.user_id AND f.artist_id = p.artist_id
+),
+ranked AS (
+ SELECT *,
+ RANK() OVER (PARTITION BY user_id ORDER BY gap_days DESC) AS r
+ FROM comebacks
+)
+SELECT
+ c.user_id,
+ c.artist_id,
+ awn.name AS artist_name,
+ c.last_listen,
+ c.first_listen_of_year,
+ c.gap_days
+FROM ranked c
+JOIN artists_with_name awn ON awn.id = c.artist_id
+WHERE r = 1;
+
+-- name: GetFirstListenInYear :one
+SELECT
+ l.*,
+ t.*,
+ get_artists_for_track(t.id) as artists
+FROM listens l
+LEFT JOIN tracks_with_title t ON l.track_id = t.id
+WHERE EXTRACT(YEAR FROM l.listened_at) = 2025
+ORDER BY l.listened_at ASC
+LIMIT 1;
+
+-- name: GetTracksPlayedAtLeastOncePerMonthInYear :many
+WITH monthly_plays AS (
+ SELECT
+ l.track_id,
+ EXTRACT(MONTH FROM l.listened_at) AS month
+ FROM listens l
+ WHERE EXTRACT(YEAR FROM l.listened_at) = @user_id::int
+ GROUP BY l.track_id, EXTRACT(MONTH FROM l.listened_at)
+),
+monthly_counts AS (
+ SELECT
+ track_id,
+ COUNT(DISTINCT month) AS months_played
+ FROM monthly_plays
+ GROUP BY track_id
+)
+SELECT
+ t.id AS track_id,
+ t.title
+FROM monthly_counts mc
+JOIN tracks_with_title t ON t.id = mc.track_id
+WHERE mc.months_played = 12;
+
+-- name: GetWeekWithMostListensInYear :one
+SELECT
+ DATE_TRUNC('week', listened_at + INTERVAL '1 day') - INTERVAL '1 day' AS week_start,
+ COUNT(*) AS listen_count
+FROM listens
+WHERE EXTRACT(YEAR FROM listened_at) = @year::int
+ AND user_id = @user_id::int
+GROUP BY week_start
+ORDER BY listen_count DESC
+LIMIT 1;
+
+-- name: GetPercentageOfTotalListensFromTopTracksInYear :one
+WITH user_listens AS (
+ SELECT
+ l.track_id,
+ COUNT(*) AS listen_count
+ FROM listens l
+ WHERE l.user_id = @user_id::int
+ AND EXTRACT(YEAR FROM l.listened_at) = @year::int
+ GROUP BY l.track_id
+),
+top_tracks AS (
+ SELECT
+ track_id,
+ listen_count
+ FROM user_listens
+ ORDER BY listen_count DESC
+ LIMIT $1
+),
+totals AS (
+ SELECT
+ (SELECT SUM(listen_count) FROM top_tracks) AS top_tracks_total,
+ (SELECT SUM(listen_count) FROM user_listens) AS overall_total
+)
+SELECT
+ top_tracks_total,
+ overall_total,
+ ROUND((top_tracks_total::decimal / overall_total) * 100, 2) AS percent_of_total
+FROM totals;
+
+-- name: GetPercentageOfTotalListensFromTopArtistsInYear :one
+WITH user_artist_listens AS (
+ SELECT
+ at.artist_id,
+ COUNT(*) AS listen_count
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE l.user_id = @user_id::int
+ AND EXTRACT(YEAR FROM l.listened_at) = @year::int
+ GROUP BY at.artist_id
+),
+top_artists AS (
+ SELECT
+ artist_id,
+ listen_count
+ FROM user_artist_listens
+ ORDER BY listen_count DESC
+ LIMIT $1
+),
+totals AS (
+ SELECT
+ (SELECT SUM(listen_count) FROM top_artists) AS top_artist_total,
+ (SELECT SUM(listen_count) FROM user_artist_listens) AS overall_total
+)
+SELECT
+ top_artist_total,
+ overall_total,
+ ROUND((top_artist_total::decimal / overall_total) * 100, 2) AS percent_of_total
+FROM totals;
+
+-- name: GetArtistsWithOnlyOnePlayInYear :many
+WITH first_artist_plays_in_year AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MIN(l.listened_at) AS first_listen
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE EXTRACT(YEAR FROM l.listened_at) = 2024
+ AND NOT EXISTS (
+ SELECT 1
+ FROM listens l2
+ JOIN artist_tracks at2 ON at2.track_id = l2.track_id
+ WHERE l2.user_id = l.user_id
+ AND at2.artist_id = at.artist_id
+ AND l2.listened_at < DATE '2024-01-01'
+ )
+ GROUP BY l.user_id, at.artist_id
+)
+SELECT
+ f.user_id,
+ f.artist_id,
+ f.first_listen, a.name,
+ COUNT(l.*) AS total_plays_in_year
+FROM first_artist_plays_in_year f
+JOIN listens l ON l.user_id = f.user_id
+JOIN artist_tracks at ON at.track_id = l.track_id JOIN artists_with_name a ON at.artist_id = a.id
+WHERE at.artist_id = f.artist_id
+ AND EXTRACT(YEAR FROM l.listened_at) = 2024
+GROUP BY f.user_id, f.artist_id, f.first_listen, a.name HAVING COUNT(*) = 1;
+
+-- name: GetArtistCountInYear :one
+SELECT
+ COUNT(DISTINCT at.artist_id) AS artist_count
+FROM listens l
+JOIN artist_tracks at ON at.track_id = l.track_id
+WHERE l.user_id = @user_id::int
+ AND EXTRACT(YEAR FROM l.listened_at) = @year::int;
+
+-- name: GetListenPercentageInTimeWindowInYear :one
+WITH user_listens_in_year AS (
+ SELECT
+ listened_at
+ FROM listens
+ WHERE user_id = @user_id::int
+ AND EXTRACT(YEAR FROM listened_at) = @year::int
+),
+windowed AS (
+ SELECT
+ COUNT(*) AS in_window
+ FROM user_listens_in_year
+ WHERE EXTRACT(HOUR FROM listened_at) >= @hour_window_start::int
+ AND EXTRACT(HOUR FROM listened_at) < @hour_window_end::int
+),
+total AS (
+ SELECT COUNT(*) AS total_listens
+ FROM user_listens_in_year
+)
+SELECT
+ w.in_window,
+ t.total_listens,
+ ROUND((w.in_window::decimal / t.total_listens) * 100, 2) AS percent_of_total
+FROM windowed w, total t;
\ No newline at end of file
diff --git a/docs/src/content/docs/guides/editing.md b/docs/src/content/docs/guides/editing.md
index 298cf67..caf4150 100644
--- a/docs/src/content/docs/guides/editing.md
+++ b/docs/src/content/docs/guides/editing.md
@@ -60,6 +60,8 @@ Once merged, we can see that all of the listen activity for Tsumugu has been asi

+You can also search for items when merging by their ID using the format `id:1234`.
+
#### Deleting Items
To delete at item, just click the trash icon, which is the fourth and final icon in the editing options. Doing so will open a confirmation dialogue. Once confirmed, the item you delete, as well as all of its children
diff --git a/docs/src/content/docs/index.mdx b/docs/src/content/docs/index.mdx
index 63f0403..a4d1858 100644
--- a/docs/src/content/docs/index.mdx
+++ b/docs/src/content/docs/index.mdx
@@ -34,6 +34,6 @@ import { Card, CardGrid } from '@astrojs/starlight/components';
Koito automatically fetches data from MusicBrainz and images from Deezer and Cover Art Archive to compliment what is provided by your music server.
- Koito ships with twelve different themes, with custom theme options to be added soon™.
+ Koito ships with twelve different themes, now with support for custom themes!
diff --git a/engine/handlers/search.go b/engine/handlers/search.go
index 9f29c75..ee90936 100644
--- a/engine/handlers/search.go
+++ b/engine/handlers/search.go
@@ -2,6 +2,8 @@ package handlers
import (
"net/http"
+ "strconv"
+ "strings"
"github.com/gabehf/koito/internal/db"
"github.com/gabehf/koito/internal/logger"
@@ -20,27 +22,62 @@ func SearchHandler(store db.DB) http.HandlerFunc {
ctx := r.Context()
l := logger.FromContext(ctx)
q := r.URL.Query().Get("q")
- artists, err := store.SearchArtists(ctx, q)
l.Debug().Msgf("SearchHandler: Received search with query: %s", r.URL.Query().Encode())
- if err != nil {
- l.Err(err).Msg("Failed to search for artists")
- utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
- return
- }
- albums, err := store.SearchAlbums(ctx, q)
- if err != nil {
- l.Err(err).Msg("Failed to search for albums")
- utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
- return
- }
- tracks, err := store.SearchTracks(ctx, q)
- if err != nil {
- l.Err(err).Msg("Failed to search for tracks")
- utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
- return
+ var artists []*models.Artist
+ var albums []*models.Album
+ var tracks []*models.Track
+
+ if strings.HasPrefix(q, "id:") {
+ idStr := strings.TrimPrefix(q, "id:")
+ id, _ := strconv.Atoi(idStr)
+
+ artist, err := store.GetArtist(ctx, db.GetArtistOpts{ID: int32(id)})
+ if err != nil {
+ l.Debug().Msg("No artists found with id")
+ }
+ if artist != nil {
+ artists = append(artists, artist)
+ }
+
+ album, err := store.GetAlbum(ctx, db.GetAlbumOpts{ID: int32(id)})
+ if err != nil {
+ l.Debug().Msg("No albums found with id")
+ }
+ if album != nil {
+ albums = append(albums, album)
+ }
+
+ track, err := store.GetTrack(ctx, db.GetTrackOpts{ID: int32(id)})
+ if err != nil {
+ l.Debug().Msg("No tracks found with id")
+ }
+ if track != nil {
+ tracks = append(tracks, track)
+ }
+ } else {
+ var err error
+ artists, err = store.SearchArtists(ctx, q)
+ if err != nil {
+ l.Err(err).Msg("Failed to search for artists")
+ utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
+ return
+ }
+ albums, err = store.SearchAlbums(ctx, q)
+ if err != nil {
+ l.Err(err).Msg("Failed to search for albums")
+ utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
+ return
+ }
+ tracks, err = store.SearchTracks(ctx, q)
+ if err != nil {
+ l.Err(err).Msg("Failed to search for tracks")
+ utils.WriteError(w, "failed to search in database", http.StatusInternalServerError)
+ return
+ }
}
+
utils.WriteJSON(w, http.StatusOK, SearchResults{
Artists: artists,
Albums: albums,
diff --git a/engine/handlers/stats.go b/engine/handlers/stats.go
index 3e01816..7dbfc29 100644
--- a/engine/handlers/stats.go
+++ b/engine/handlers/stats.go
@@ -10,11 +10,11 @@ import (
)
type StatsResponse struct {
- ListenCount int64 `json:"listen_count"`
- TrackCount int64 `json:"track_count"`
- AlbumCount int64 `json:"album_count"`
- ArtistCount int64 `json:"artist_count"`
- HoursListened int64 `json:"hours_listened"`
+ ListenCount int64 `json:"listen_count"`
+ TrackCount int64 `json:"track_count"`
+ AlbumCount int64 `json:"album_count"`
+ ArtistCount int64 `json:"artist_count"`
+ MinutesListened int64 `json:"minutes_listened"`
}
func StatsHandler(store db.DB) http.HandlerFunc {
@@ -79,11 +79,11 @@ func StatsHandler(store db.DB) http.HandlerFunc {
l.Debug().Msg("StatsHandler: Successfully fetched statistics")
utils.WriteJSON(w, http.StatusOK, StatsResponse{
- ListenCount: listens,
- TrackCount: tracks,
- AlbumCount: albums,
- ArtistCount: artists,
- HoursListened: timeListenedS / 60 / 60,
+ ListenCount: listens,
+ TrackCount: tracks,
+ AlbumCount: albums,
+ ArtistCount: artists,
+ MinutesListened: timeListenedS / 60,
})
}
}
diff --git a/engine/long_test.go b/engine/long_test.go
index 20dcc01..a947a79 100644
--- a/engine/long_test.go
+++ b/engine/long_test.go
@@ -447,7 +447,7 @@ func TestStats(t *testing.T) {
assert.EqualValues(t, 3, actual.TrackCount)
assert.EqualValues(t, 3, actual.AlbumCount)
assert.EqualValues(t, 3, actual.ArtistCount)
- assert.EqualValues(t, 0, actual.HoursListened)
+ assert.EqualValues(t, 11, actual.MinutesListened)
}
func TestListenActivity(t *testing.T) {
diff --git a/internal/catalog/catalog.go b/internal/catalog/catalog.go
index 4fe5754..21949fa 100644
--- a/internal/catalog/catalog.go
+++ b/internal/catalog/catalog.go
@@ -134,15 +134,35 @@ func SubmitListen(ctx context.Context, store db.DB, opts SubmitListenOpts) error
}
l.Debug().Any("track", track).Msg("Matched listen to track")
- if track.Duration == 0 && opts.Duration != 0 {
- err := store.UpdateTrack(ctx, db.UpdateTrackOpts{
- ID: track.ID,
- Duration: opts.Duration,
- })
- if err != nil {
- l.Err(err).Msgf("Failed to update duration for track %s", track.Title)
+ if track.Duration == 0 {
+ if opts.Duration != 0 {
+ l.Debug().Msg("Updating duration using request information")
+ err := store.UpdateTrack(ctx, db.UpdateTrackOpts{
+ ID: track.ID,
+ Duration: opts.Duration,
+ })
+ if err != nil {
+ l.Err(err).Msgf("Failed to update duration for track %s", track.Title)
+ } else {
+ l.Info().Msgf("Duration updated to %d for track '%s'", opts.Duration, track.Title)
+ }
+ } else if track.MbzID != nil && *track.MbzID != uuid.Nil {
+ l.Debug().Msg("Attempting to update duration using MusicBrainz ID")
+ mbztrack, err := opts.MbzCaller.GetTrack(ctx, *track.MbzID)
+ if err != nil {
+ l.Err(err).Msg("Failed to make request to MusicBrainz")
+ } else {
+ err = store.UpdateTrack(ctx, db.UpdateTrackOpts{
+ ID: track.ID,
+ Duration: int32(mbztrack.LengthMs / 1000),
+ })
+ if err != nil {
+ l.Err(err).Msgf("Failed to update duration for track %s", track.Title)
+ } else {
+ l.Info().Msgf("Duration updated to %d for track '%s'", mbztrack.LengthMs/1000, track.Title)
+ }
+ }
}
- l.Info().Msgf("Duration updated to %d for track '%s'", opts.Duration, track.Title)
}
if opts.SkipSaveListen {
diff --git a/internal/catalog/catalog_test.go b/internal/catalog/catalog_test.go
index 039fe1c..e50435c 100644
--- a/internal/catalog/catalog_test.go
+++ b/internal/catalog/catalog_test.go
@@ -134,7 +134,8 @@ var (
}
mbzTrackData = map[uuid.UUID]*mbz.MusicBrainzTrack{
uuid.MustParse("00000000-0000-0000-0000-000000001001"): {
- Title: "Tokyo Calling",
+ Title: "Tokyo Calling",
+ LengthMs: 191000,
},
}
)
diff --git a/internal/catalog/submit_listen_test.go b/internal/catalog/submit_listen_test.go
index c82f48a..69eb0a6 100644
--- a/internal/catalog/submit_listen_test.go
+++ b/internal/catalog/submit_listen_test.go
@@ -554,6 +554,43 @@ func TestSubmitListen_UpdateTrackDuration(t *testing.T) {
assert.Equal(t, 1, count, "expected duration to be updated")
}
+func TestSubmitListen_UpdateTrackDurationWithMbz(t *testing.T) {
+ setupTestDataSansMbzIDs(t)
+
+ ctx := context.Background()
+ mbzc := &mbz.MbzMockCaller{
+ Tracks: mbzTrackData,
+ }
+ opts := catalog.SubmitListenOpts{
+ MbzCaller: mbzc,
+ ArtistNames: []string{"ATARASHII GAKKO!"},
+ Artist: "ATARASHII GAKKO!",
+ TrackTitle: "Tokyo Calling",
+ RecordingMbzID: uuid.MustParse("00000000-0000-0000-0000-000000001001"),
+ ReleaseTitle: "AG! Calling",
+ Time: time.Now(),
+ UserID: 1,
+ }
+
+ err := catalog.SubmitListen(ctx, store, opts)
+ require.NoError(t, err)
+
+ // Verify that the listen was saved
+ exists, err := store.RowExists(ctx, `
+ SELECT EXISTS (
+ SELECT 1 FROM listens
+ WHERE track_id = $1
+ )`, 1)
+ require.NoError(t, err)
+ assert.True(t, exists, "expected listen row to exist")
+
+ count, err := store.Count(ctx, `
+ SELECT COUNT(*) FROM tracks_with_title WHERE title = $1 AND duration = 191
+ `, "Tokyo Calling")
+ require.NoError(t, err)
+ assert.Equal(t, 1, count, "expected duration to be updated")
+}
+
func TestSubmitListen_MatchFromTrackTitleNoMbzIDs(t *testing.T) {
setupTestDataSansMbzIDs(t)
diff --git a/internal/db/psql/album.go b/internal/db/psql/album.go
index e58514f..0b6ade9 100644
--- a/internal/db/psql/album.go
+++ b/internal/db/psql/album.go
@@ -2,6 +2,7 @@ package psql
import (
"context"
+ "encoding/json"
"errors"
"fmt"
"strings"
@@ -19,40 +20,71 @@ import (
func (d *Psql) GetAlbum(ctx context.Context, opts db.GetAlbumOpts) (*models.Album, error) {
l := logger.FromContext(ctx)
-
- var row repository.ReleasesWithTitle
var err error
+ var ret = new(models.Album)
if opts.ID != 0 {
l.Debug().Msgf("Fetching album from DB with id %d", opts.ID)
- row, err = d.q.GetRelease(ctx, opts.ID)
+ row, err := d.q.GetRelease(ctx, opts.ID)
+ if err != nil {
+ return nil, fmt.Errorf("GetAlbum: %w", err)
+ }
+ ret.ID = row.ID
+ ret.MbzID = row.MusicBrainzID
+ ret.Title = row.Title
+ ret.Image = row.Image
+ ret.VariousArtists = row.VariousArtists
+ err = json.Unmarshal(row.Artists, &ret.Artists)
+ if err != nil {
+ return nil, fmt.Errorf("GetAlbum: json.Unmarshal: %w", err)
+ }
} else if opts.MusicBrainzID != uuid.Nil {
l.Debug().Msgf("Fetching album from DB with MusicBrainz Release ID %s", opts.MusicBrainzID)
- row, err = d.q.GetReleaseByMbzID(ctx, &opts.MusicBrainzID)
+ row, err := d.q.GetReleaseByMbzID(ctx, &opts.MusicBrainzID)
+ if err != nil {
+ return nil, fmt.Errorf("GetAlbum: %w", err)
+ }
+ ret.ID = row.ID
+ ret.MbzID = row.MusicBrainzID
+ ret.Title = row.Title
+ ret.Image = row.Image
+ ret.VariousArtists = row.VariousArtists
} else if opts.ArtistID != 0 && opts.Title != "" {
l.Debug().Msgf("Fetching album from DB with artist_id %d and title %s", opts.ArtistID, opts.Title)
- row, err = d.q.GetReleaseByArtistAndTitle(ctx, repository.GetReleaseByArtistAndTitleParams{
+ row, err := d.q.GetReleaseByArtistAndTitle(ctx, repository.GetReleaseByArtistAndTitleParams{
ArtistID: opts.ArtistID,
Title: opts.Title,
})
+ if err != nil {
+ return nil, fmt.Errorf("GetAlbum: %w", err)
+ }
+ ret.ID = row.ID
+ ret.MbzID = row.MusicBrainzID
+ ret.Title = row.Title
+ ret.Image = row.Image
+ ret.VariousArtists = row.VariousArtists
} else if opts.ArtistID != 0 && len(opts.Titles) > 0 {
l.Debug().Msgf("Fetching release group from DB with artist_id %d and titles %v", opts.ArtistID, opts.Titles)
- row, err = d.q.GetReleaseByArtistAndTitles(ctx, repository.GetReleaseByArtistAndTitlesParams{
+ row, err := d.q.GetReleaseByArtistAndTitles(ctx, repository.GetReleaseByArtistAndTitlesParams{
ArtistID: opts.ArtistID,
Column1: opts.Titles,
})
+ if err != nil {
+ return nil, fmt.Errorf("GetAlbum: %w", err)
+ }
+ ret.ID = row.ID
+ ret.MbzID = row.MusicBrainzID
+ ret.Title = row.Title
+ ret.Image = row.Image
+ ret.VariousArtists = row.VariousArtists
} else {
return nil, errors.New("GetAlbum: insufficient information to get album")
}
- if err != nil {
- return nil, fmt.Errorf("GetAlbum: %w", err)
- }
-
count, err := d.q.CountListensFromRelease(ctx, repository.CountListensFromReleaseParams{
ListenedAt: time.Unix(0, 0),
ListenedAt_2: time.Now(),
- ReleaseID: row.ID,
+ ReleaseID: ret.ID,
})
if err != nil {
return nil, fmt.Errorf("GetAlbum: CountListensFromRelease: %w", err)
@@ -60,21 +92,16 @@ func (d *Psql) GetAlbum(ctx context.Context, opts db.GetAlbumOpts) (*models.Albu
seconds, err := d.CountTimeListenedToItem(ctx, db.TimeListenedOpts{
Period: db.PeriodAllTime,
- AlbumID: row.ID,
+ AlbumID: ret.ID,
})
if err != nil {
return nil, fmt.Errorf("GetAlbum: CountTimeListenedToItem: %w", err)
}
- return &models.Album{
- ID: row.ID,
- MbzID: row.MusicBrainzID,
- Title: row.Title,
- Image: row.Image,
- VariousArtists: row.VariousArtists,
- ListenCount: count,
- TimeListened: seconds,
- }, nil
+ ret.ListenCount = count
+ ret.TimeListened = seconds
+
+ return ret, nil
}
func (d *Psql) SaveAlbum(ctx context.Context, opts db.SaveAlbumOpts) (*models.Album, error) {
diff --git a/internal/db/psql/psql.go b/internal/db/psql/psql.go
index 0a917b5..3d288c0 100644
--- a/internal/db/psql/psql.go
+++ b/internal/db/psql/psql.go
@@ -5,10 +5,9 @@ import (
"context"
"database/sql"
"fmt"
- "path/filepath"
- "runtime"
"time"
+ "github.com/gabehf/koito/db/migrations"
"github.com/gabehf/koito/internal/cfg"
"github.com/gabehf/koito/internal/db"
"github.com/gabehf/koito/internal/repository"
@@ -54,13 +53,9 @@ func New() (*Psql, error) {
return nil, fmt.Errorf("psql.New: failed to open db for migrations: %w", err)
}
- _, filename, _, ok := runtime.Caller(0)
- if !ok {
- return nil, fmt.Errorf("psql.New: unable to get caller info")
- }
- migrationsPath := filepath.Join(filepath.Dir(filename), "..", "..", "..", "db", "migrations")
+ goose.SetBaseFS(migrations.Files)
- if err := goose.Up(sqlDB, migrationsPath); err != nil {
+ if err := goose.Up(sqlDB, "."); err != nil {
return nil, fmt.Errorf("psql.New: goose failed: %w", err)
}
_ = sqlDB.Close()
diff --git a/internal/db/psql/track.go b/internal/db/psql/track.go
index ed7959a..572047c 100644
--- a/internal/db/psql/track.go
+++ b/internal/db/psql/track.go
@@ -2,6 +2,7 @@ package psql
import (
"context"
+ "encoding/json"
"errors"
"fmt"
"strings"
@@ -34,6 +35,10 @@ func (d *Psql) GetTrack(ctx context.Context, opts db.GetTrackOpts) (*models.Trac
Image: t.Image,
Duration: t.Duration,
}
+ err = json.Unmarshal(t.Artists, &track.Artists)
+ if err != nil {
+ return nil, fmt.Errorf("GetTrack: json.Unmarshal: %w", err)
+ }
} else if opts.MusicBrainzID != uuid.Nil {
l.Debug().Msgf("Fetching track from DB with MusicBrainz ID %s", opts.MusicBrainzID)
t, err := d.q.GetTrackByMbzID(ctx, &opts.MusicBrainzID)
diff --git a/internal/db/psql/user.go b/internal/db/psql/user.go
index 33a8cf9..b80ddad 100644
--- a/internal/db/psql/user.go
+++ b/internal/db/psql/user.go
@@ -120,7 +120,7 @@ func (d *Psql) UpdateUser(ctx context.Context, opts db.UpdateUserOpts) error {
}
err = qtx.UpdateUserUsername(ctx, repository.UpdateUserUsernameParams{
ID: opts.ID,
- Username: opts.Username,
+ Username: strings.ToLower(opts.Username),
})
if err != nil {
return fmt.Errorf("UpdateUser: UpdateUserUsername: %w", err)
diff --git a/internal/mbz/track.go b/internal/mbz/track.go
index a7d8a12..f2e3885 100644
--- a/internal/mbz/track.go
+++ b/internal/mbz/track.go
@@ -8,7 +8,8 @@ import (
)
type MusicBrainzTrack struct {
- Title string `json:"title"`
+ Title string `json:"title"`
+ LengthMs int `json:"length"`
}
const recordingFmtStr = "%s/ws/2/recording/%s"
diff --git a/internal/repository/release.sql.go b/internal/repository/release.sql.go
index a7a5382..ec6c467 100644
--- a/internal/repository/release.sql.go
+++ b/internal/repository/release.sql.go
@@ -85,13 +85,26 @@ func (q *Queries) DeleteReleasesFromArtist(ctx context.Context, artistID int32)
}
const getRelease = `-- name: GetRelease :one
-SELECT id, musicbrainz_id, image, various_artists, image_source, title FROM releases_with_title
+SELECT
+ id, musicbrainz_id, image, various_artists, image_source, title,
+ get_artists_for_release(id) AS artists
+FROM releases_with_title
WHERE id = $1 LIMIT 1
`
-func (q *Queries) GetRelease(ctx context.Context, id int32) (ReleasesWithTitle, error) {
+type GetReleaseRow struct {
+ ID int32
+ MusicBrainzID *uuid.UUID
+ Image *uuid.UUID
+ VariousArtists bool
+ ImageSource pgtype.Text
+ Title string
+ Artists []byte
+}
+
+func (q *Queries) GetRelease(ctx context.Context, id int32) (GetReleaseRow, error) {
row := q.db.QueryRow(ctx, getRelease, id)
- var i ReleasesWithTitle
+ var i GetReleaseRow
err := row.Scan(
&i.ID,
&i.MusicBrainzID,
@@ -99,6 +112,7 @@ func (q *Queries) GetRelease(ctx context.Context, id int32) (ReleasesWithTitle,
&i.VariousArtists,
&i.ImageSource,
&i.Title,
+ &i.Artists,
)
return i, err
}
diff --git a/internal/repository/track.sql.go b/internal/repository/track.sql.go
index 88af17f..f87b180 100644
--- a/internal/repository/track.sql.go
+++ b/internal/repository/track.sql.go
@@ -344,6 +344,7 @@ func (q *Queries) GetTopTracksPaginated(ctx context.Context, arg GetTopTracksPag
const getTrack = `-- name: GetTrack :one
SELECT
t.id, t.musicbrainz_id, t.duration, t.release_id, t.title,
+ get_artists_for_track(t.id) AS artists,
r.image
FROM tracks_with_title t
JOIN releases r ON t.release_id = r.id
@@ -356,6 +357,7 @@ type GetTrackRow struct {
Duration int32
ReleaseID int32
Title string
+ Artists []byte
Image *uuid.UUID
}
@@ -368,6 +370,7 @@ func (q *Queries) GetTrack(ctx context.Context, id int32) (GetTrackRow, error) {
&i.Duration,
&i.ReleaseID,
&i.Title,
+ &i.Artists,
&i.Image,
)
return i, err
diff --git a/internal/repository/year.sql.go b/internal/repository/year.sql.go
new file mode 100644
index 0000000..457052d
--- /dev/null
+++ b/internal/repository/year.sql.go
@@ -0,0 +1,616 @@
+// Code generated by sqlc. DO NOT EDIT.
+// versions:
+// sqlc v1.29.0
+// source: year.sql
+
+package repository
+
+import (
+ "context"
+ "time"
+
+ "github.com/google/uuid"
+ "github.com/jackc/pgx/v5/pgtype"
+)
+
+const artistsOnlyPlayedOnceInYear = `-- name: ArtistsOnlyPlayedOnceInYear :many
+SELECT
+ a.id AS artist_id,
+ a.name,
+ COUNT(l.*) AS listen_count
+FROM listens l
+JOIN artist_tracks at ON at.track_id = l.track_id
+JOIN artists_with_name a ON a.id = at.artist_id
+WHERE EXTRACT(YEAR FROM l.listened_at) = $1::int AND l.user_id = $2::int
+GROUP BY a.id, a.name
+HAVING COUNT(*) = 1
+`
+
+type ArtistsOnlyPlayedOnceInYearParams struct {
+ Year int32
+ UserID int32
+}
+
+type ArtistsOnlyPlayedOnceInYearRow struct {
+ ArtistID int32
+ Name string
+ ListenCount int64
+}
+
+func (q *Queries) ArtistsOnlyPlayedOnceInYear(ctx context.Context, arg ArtistsOnlyPlayedOnceInYearParams) ([]ArtistsOnlyPlayedOnceInYearRow, error) {
+ rows, err := q.db.Query(ctx, artistsOnlyPlayedOnceInYear, arg.Year, arg.UserID)
+ if err != nil {
+ return nil, err
+ }
+ defer rows.Close()
+ var items []ArtistsOnlyPlayedOnceInYearRow
+ for rows.Next() {
+ var i ArtistsOnlyPlayedOnceInYearRow
+ if err := rows.Scan(&i.ArtistID, &i.Name, &i.ListenCount); err != nil {
+ return nil, err
+ }
+ items = append(items, i)
+ }
+ if err := rows.Err(); err != nil {
+ return nil, err
+ }
+ return items, nil
+}
+
+const getArtistCountInYear = `-- name: GetArtistCountInYear :one
+SELECT
+ COUNT(DISTINCT at.artist_id) AS artist_count
+FROM listens l
+JOIN artist_tracks at ON at.track_id = l.track_id
+WHERE l.user_id = $1::int
+ AND EXTRACT(YEAR FROM l.listened_at) = $2::int
+`
+
+type GetArtistCountInYearParams struct {
+ UserID int32
+ Year int32
+}
+
+func (q *Queries) GetArtistCountInYear(ctx context.Context, arg GetArtistCountInYearParams) (int64, error) {
+ row := q.db.QueryRow(ctx, getArtistCountInYear, arg.UserID, arg.Year)
+ var artist_count int64
+ err := row.Scan(&artist_count)
+ return artist_count, err
+}
+
+const getArtistWithLongestGapInYear = `-- name: GetArtistWithLongestGapInYear :one
+WITH first_listens AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MIN(l.listened_at::date) AS first_listen_of_year
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE EXTRACT(YEAR FROM l.listened_at) = $1::int
+ GROUP BY l.user_id, at.artist_id
+),
+last_listens AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MAX(l.listened_at::date) AS last_listen
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE l.listened_at < $2::date
+ GROUP BY l.user_id, at.artist_id
+),
+comebacks AS (
+ SELECT
+ f.user_id,
+ f.artist_id,
+ f.first_listen_of_year,
+ p.last_listen,
+ (f.first_listen_of_year - p.last_listen) AS gap_days
+ FROM first_listens f
+ JOIN last_listens p
+ ON f.user_id = p.user_id AND f.artist_id = p.artist_id
+),
+ranked AS (
+ SELECT user_id, artist_id, first_listen_of_year, last_listen, gap_days,
+ RANK() OVER (PARTITION BY user_id ORDER BY gap_days DESC) AS r
+ FROM comebacks
+)
+SELECT
+ c.user_id,
+ c.artist_id,
+ awn.name AS artist_name,
+ c.last_listen,
+ c.first_listen_of_year,
+ c.gap_days
+FROM ranked c
+JOIN artists_with_name awn ON awn.id = c.artist_id
+WHERE r = 1
+`
+
+type GetArtistWithLongestGapInYearParams struct {
+ Year int32
+ FirstDayOfYear pgtype.Date
+}
+
+type GetArtistWithLongestGapInYearRow struct {
+ UserID int32
+ ArtistID int32
+ ArtistName string
+ LastListen interface{}
+ FirstListenOfYear interface{}
+ GapDays int32
+}
+
+func (q *Queries) GetArtistWithLongestGapInYear(ctx context.Context, arg GetArtistWithLongestGapInYearParams) (GetArtistWithLongestGapInYearRow, error) {
+ row := q.db.QueryRow(ctx, getArtistWithLongestGapInYear, arg.Year, arg.FirstDayOfYear)
+ var i GetArtistWithLongestGapInYearRow
+ err := row.Scan(
+ &i.UserID,
+ &i.ArtistID,
+ &i.ArtistName,
+ &i.LastListen,
+ &i.FirstListenOfYear,
+ &i.GapDays,
+ )
+ return i, err
+}
+
+const getArtistsWithOnlyOnePlayInYear = `-- name: GetArtistsWithOnlyOnePlayInYear :many
+WITH first_artist_plays_in_year AS (
+ SELECT
+ l.user_id,
+ at.artist_id,
+ MIN(l.listened_at) AS first_listen
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE EXTRACT(YEAR FROM l.listened_at) = 2024
+ AND NOT EXISTS (
+ SELECT 1
+ FROM listens l2
+ JOIN artist_tracks at2 ON at2.track_id = l2.track_id
+ WHERE l2.user_id = l.user_id
+ AND at2.artist_id = at.artist_id
+ AND l2.listened_at < DATE '2024-01-01'
+ )
+ GROUP BY l.user_id, at.artist_id
+)
+SELECT
+ f.user_id,
+ f.artist_id,
+ f.first_listen, a.name,
+ COUNT(l.*) AS total_plays_in_year
+FROM first_artist_plays_in_year f
+JOIN listens l ON l.user_id = f.user_id
+JOIN artist_tracks at ON at.track_id = l.track_id JOIN artists_with_name a ON at.artist_id = a.id
+WHERE at.artist_id = f.artist_id
+ AND EXTRACT(YEAR FROM l.listened_at) = 2024
+GROUP BY f.user_id, f.artist_id, f.first_listen, a.name HAVING COUNT(*) = 1
+`
+
+type GetArtistsWithOnlyOnePlayInYearRow struct {
+ UserID int32
+ ArtistID int32
+ FirstListen interface{}
+ Name string
+ TotalPlaysInYear int64
+}
+
+func (q *Queries) GetArtistsWithOnlyOnePlayInYear(ctx context.Context) ([]GetArtistsWithOnlyOnePlayInYearRow, error) {
+ rows, err := q.db.Query(ctx, getArtistsWithOnlyOnePlayInYear)
+ if err != nil {
+ return nil, err
+ }
+ defer rows.Close()
+ var items []GetArtistsWithOnlyOnePlayInYearRow
+ for rows.Next() {
+ var i GetArtistsWithOnlyOnePlayInYearRow
+ if err := rows.Scan(
+ &i.UserID,
+ &i.ArtistID,
+ &i.FirstListen,
+ &i.Name,
+ &i.TotalPlaysInYear,
+ ); err != nil {
+ return nil, err
+ }
+ items = append(items, i)
+ }
+ if err := rows.Err(); err != nil {
+ return nil, err
+ }
+ return items, nil
+}
+
+const getFirstListenInYear = `-- name: GetFirstListenInYear :one
+SELECT
+ l.track_id, l.listened_at, l.client, l.user_id,
+ t.id, t.musicbrainz_id, t.duration, t.release_id, t.title,
+ get_artists_for_track(t.id) as artists
+FROM listens l
+LEFT JOIN tracks_with_title t ON l.track_id = t.id
+WHERE EXTRACT(YEAR FROM l.listened_at) = 2025
+ORDER BY l.listened_at ASC
+LIMIT 1
+`
+
+type GetFirstListenInYearRow struct {
+ TrackID int32
+ ListenedAt time.Time
+ Client *string
+ UserID int32
+ ID pgtype.Int4
+ MusicBrainzID *uuid.UUID
+ Duration pgtype.Int4
+ ReleaseID pgtype.Int4
+ Title pgtype.Text
+ Artists []byte
+}
+
+func (q *Queries) GetFirstListenInYear(ctx context.Context) (GetFirstListenInYearRow, error) {
+ row := q.db.QueryRow(ctx, getFirstListenInYear)
+ var i GetFirstListenInYearRow
+ err := row.Scan(
+ &i.TrackID,
+ &i.ListenedAt,
+ &i.Client,
+ &i.UserID,
+ &i.ID,
+ &i.MusicBrainzID,
+ &i.Duration,
+ &i.ReleaseID,
+ &i.Title,
+ &i.Artists,
+ )
+ return i, err
+}
+
+const getListenPercentageInTimeWindowInYear = `-- name: GetListenPercentageInTimeWindowInYear :one
+WITH user_listens_in_year AS (
+ SELECT
+ listened_at
+ FROM listens
+ WHERE user_id = $1::int
+ AND EXTRACT(YEAR FROM listened_at) = $2::int
+),
+windowed AS (
+ SELECT
+ COUNT(*) AS in_window
+ FROM user_listens_in_year
+ WHERE EXTRACT(HOUR FROM listened_at) >= $3::int
+ AND EXTRACT(HOUR FROM listened_at) < $4::int
+),
+total AS (
+ SELECT COUNT(*) AS total_listens
+ FROM user_listens_in_year
+)
+SELECT
+ w.in_window,
+ t.total_listens,
+ ROUND((w.in_window::decimal / t.total_listens) * 100, 2) AS percent_of_total
+FROM windowed w, total t
+`
+
+type GetListenPercentageInTimeWindowInYearParams struct {
+ UserID int32
+ Year int32
+ HourWindowStart int32
+ HourWindowEnd int32
+}
+
+type GetListenPercentageInTimeWindowInYearRow struct {
+ InWindow int64
+ TotalListens int64
+ PercentOfTotal pgtype.Numeric
+}
+
+func (q *Queries) GetListenPercentageInTimeWindowInYear(ctx context.Context, arg GetListenPercentageInTimeWindowInYearParams) (GetListenPercentageInTimeWindowInYearRow, error) {
+ row := q.db.QueryRow(ctx, getListenPercentageInTimeWindowInYear,
+ arg.UserID,
+ arg.Year,
+ arg.HourWindowStart,
+ arg.HourWindowEnd,
+ )
+ var i GetListenPercentageInTimeWindowInYearRow
+ err := row.Scan(&i.InWindow, &i.TotalListens, &i.PercentOfTotal)
+ return i, err
+}
+
+const getMostReplayedTrackInYear = `-- name: GetMostReplayedTrackInYear :one
+WITH ordered_listens AS (
+ SELECT
+ user_id,
+ track_id,
+ listened_at,
+ ROW_NUMBER() OVER (PARTITION BY user_id ORDER BY listened_at) AS rn
+ FROM listens
+ WHERE EXTRACT(YEAR FROM listened_at) = $2::int
+),
+streaks AS (
+ SELECT
+ user_id,
+ track_id,
+ listened_at,
+ rn,
+ ROW_NUMBER() OVER (PARTITION BY user_id, track_id ORDER BY listened_at) AS track_rn
+ FROM ordered_listens
+),
+grouped_streaks AS (
+ SELECT
+ user_id,
+ track_id,
+ rn - track_rn AS group_id,
+ COUNT(*) AS streak_length
+ FROM streaks
+ GROUP BY user_id, track_id, rn - track_rn
+),
+ranked_streaks AS (
+ SELECT user_id, track_id, group_id, streak_length,
+ RANK() OVER (PARTITION BY user_id ORDER BY streak_length DESC) AS r
+ FROM grouped_streaks
+)
+SELECT
+ t.id, t.musicbrainz_id, t.duration, t.release_id, t.title,
+ get_artists_for_track(t.id) as artists,
+ streak_length
+FROM ranked_streaks rs JOIN tracks_with_title t ON rs.track_id = t.id
+WHERE user_id = $1::int AND r = 1
+`
+
+type GetMostReplayedTrackInYearParams struct {
+ UserID int32
+ Year int32
+}
+
+type GetMostReplayedTrackInYearRow struct {
+ ID int32
+ MusicBrainzID *uuid.UUID
+ Duration int32
+ ReleaseID int32
+ Title string
+ Artists []byte
+ StreakLength int64
+}
+
+func (q *Queries) GetMostReplayedTrackInYear(ctx context.Context, arg GetMostReplayedTrackInYearParams) (GetMostReplayedTrackInYearRow, error) {
+ row := q.db.QueryRow(ctx, getMostReplayedTrackInYear, arg.UserID, arg.Year)
+ var i GetMostReplayedTrackInYearRow
+ err := row.Scan(
+ &i.ID,
+ &i.MusicBrainzID,
+ &i.Duration,
+ &i.ReleaseID,
+ &i.Title,
+ &i.Artists,
+ &i.StreakLength,
+ )
+ return i, err
+}
+
+const getPercentageOfTotalListensFromTopArtistsInYear = `-- name: GetPercentageOfTotalListensFromTopArtistsInYear :one
+WITH user_artist_listens AS (
+ SELECT
+ at.artist_id,
+ COUNT(*) AS listen_count
+ FROM listens l
+ JOIN artist_tracks at ON at.track_id = l.track_id
+ WHERE l.user_id = $2::int
+ AND EXTRACT(YEAR FROM l.listened_at) = $3::int
+ GROUP BY at.artist_id
+),
+top_artists AS (
+ SELECT
+ artist_id,
+ listen_count
+ FROM user_artist_listens
+ ORDER BY listen_count DESC
+ LIMIT $1
+),
+totals AS (
+ SELECT
+ (SELECT SUM(listen_count) FROM top_artists) AS top_artist_total,
+ (SELECT SUM(listen_count) FROM user_artist_listens) AS overall_total
+)
+SELECT
+ top_artist_total,
+ overall_total,
+ ROUND((top_artist_total::decimal / overall_total) * 100, 2) AS percent_of_total
+FROM totals
+`
+
+type GetPercentageOfTotalListensFromTopArtistsInYearParams struct {
+ Limit int32
+ UserID int32
+ Year int32
+}
+
+type GetPercentageOfTotalListensFromTopArtistsInYearRow struct {
+ TopArtistTotal int64
+ OverallTotal int64
+ PercentOfTotal pgtype.Numeric
+}
+
+func (q *Queries) GetPercentageOfTotalListensFromTopArtistsInYear(ctx context.Context, arg GetPercentageOfTotalListensFromTopArtistsInYearParams) (GetPercentageOfTotalListensFromTopArtistsInYearRow, error) {
+ row := q.db.QueryRow(ctx, getPercentageOfTotalListensFromTopArtistsInYear, arg.Limit, arg.UserID, arg.Year)
+ var i GetPercentageOfTotalListensFromTopArtistsInYearRow
+ err := row.Scan(&i.TopArtistTotal, &i.OverallTotal, &i.PercentOfTotal)
+ return i, err
+}
+
+const getPercentageOfTotalListensFromTopTracksInYear = `-- name: GetPercentageOfTotalListensFromTopTracksInYear :one
+WITH user_listens AS (
+ SELECT
+ l.track_id,
+ COUNT(*) AS listen_count
+ FROM listens l
+ WHERE l.user_id = $2::int
+ AND EXTRACT(YEAR FROM l.listened_at) = $3::int
+ GROUP BY l.track_id
+),
+top_tracks AS (
+ SELECT
+ track_id,
+ listen_count
+ FROM user_listens
+ ORDER BY listen_count DESC
+ LIMIT $1
+),
+totals AS (
+ SELECT
+ (SELECT SUM(listen_count) FROM top_tracks) AS top_tracks_total,
+ (SELECT SUM(listen_count) FROM user_listens) AS overall_total
+)
+SELECT
+ top_tracks_total,
+ overall_total,
+ ROUND((top_tracks_total::decimal / overall_total) * 100, 2) AS percent_of_total
+FROM totals
+`
+
+type GetPercentageOfTotalListensFromTopTracksInYearParams struct {
+ Limit int32
+ UserID int32
+ Year int32
+}
+
+type GetPercentageOfTotalListensFromTopTracksInYearRow struct {
+ TopTracksTotal int64
+ OverallTotal int64
+ PercentOfTotal pgtype.Numeric
+}
+
+func (q *Queries) GetPercentageOfTotalListensFromTopTracksInYear(ctx context.Context, arg GetPercentageOfTotalListensFromTopTracksInYearParams) (GetPercentageOfTotalListensFromTopTracksInYearRow, error) {
+ row := q.db.QueryRow(ctx, getPercentageOfTotalListensFromTopTracksInYear, arg.Limit, arg.UserID, arg.Year)
+ var i GetPercentageOfTotalListensFromTopTracksInYearRow
+ err := row.Scan(&i.TopTracksTotal, &i.OverallTotal, &i.PercentOfTotal)
+ return i, err
+}
+
+const getTracksPlayedAtLeastOncePerMonthInYear = `-- name: GetTracksPlayedAtLeastOncePerMonthInYear :many
+WITH monthly_plays AS (
+ SELECT
+ l.track_id,
+ EXTRACT(MONTH FROM l.listened_at) AS month
+ FROM listens l
+ WHERE EXTRACT(YEAR FROM l.listened_at) = $1::int
+ GROUP BY l.track_id, EXTRACT(MONTH FROM l.listened_at)
+),
+monthly_counts AS (
+ SELECT
+ track_id,
+ COUNT(DISTINCT month) AS months_played
+ FROM monthly_plays
+ GROUP BY track_id
+)
+SELECT
+ t.id AS track_id,
+ t.title
+FROM monthly_counts mc
+JOIN tracks_with_title t ON t.id = mc.track_id
+WHERE mc.months_played = 12
+`
+
+type GetTracksPlayedAtLeastOncePerMonthInYearRow struct {
+ TrackID int32
+ Title string
+}
+
+func (q *Queries) GetTracksPlayedAtLeastOncePerMonthInYear(ctx context.Context, userID int32) ([]GetTracksPlayedAtLeastOncePerMonthInYearRow, error) {
+ rows, err := q.db.Query(ctx, getTracksPlayedAtLeastOncePerMonthInYear, userID)
+ if err != nil {
+ return nil, err
+ }
+ defer rows.Close()
+ var items []GetTracksPlayedAtLeastOncePerMonthInYearRow
+ for rows.Next() {
+ var i GetTracksPlayedAtLeastOncePerMonthInYearRow
+ if err := rows.Scan(&i.TrackID, &i.Title); err != nil {
+ return nil, err
+ }
+ items = append(items, i)
+ }
+ if err := rows.Err(); err != nil {
+ return nil, err
+ }
+ return items, nil
+}
+
+const getWeekWithMostListensInYear = `-- name: GetWeekWithMostListensInYear :one
+SELECT
+ DATE_TRUNC('week', listened_at + INTERVAL '1 day') - INTERVAL '1 day' AS week_start,
+ COUNT(*) AS listen_count
+FROM listens
+WHERE EXTRACT(YEAR FROM listened_at) = $1::int
+ AND user_id = $2::int
+GROUP BY week_start
+ORDER BY listen_count DESC
+LIMIT 1
+`
+
+type GetWeekWithMostListensInYearParams struct {
+ Year int32
+ UserID int32
+}
+
+type GetWeekWithMostListensInYearRow struct {
+ WeekStart int32
+ ListenCount int64
+}
+
+func (q *Queries) GetWeekWithMostListensInYear(ctx context.Context, arg GetWeekWithMostListensInYearParams) (GetWeekWithMostListensInYearRow, error) {
+ row := q.db.QueryRow(ctx, getWeekWithMostListensInYear, arg.Year, arg.UserID)
+ var i GetWeekWithMostListensInYearRow
+ err := row.Scan(&i.WeekStart, &i.ListenCount)
+ return i, err
+}
+
+const tracksOnlyPlayedOnceInYear = `-- name: TracksOnlyPlayedOnceInYear :many
+SELECT
+ t.id AS track_id,
+ t.title,
+ get_artists_for_track(t.id) as artists,
+ COUNT(l.*) AS listen_count
+FROM listens l
+JOIN tracks_with_title t ON t.id = l.track_id
+WHERE EXTRACT(YEAR FROM l.listened_at) = $2::int AND l.user_id = $3::int
+GROUP BY t.id, t.title
+HAVING COUNT(*) = 1
+LIMIT $1
+`
+
+type TracksOnlyPlayedOnceInYearParams struct {
+ Limit int32
+ Year int32
+ UserID int32
+}
+
+type TracksOnlyPlayedOnceInYearRow struct {
+ TrackID int32
+ Title string
+ Artists []byte
+ ListenCount int64
+}
+
+func (q *Queries) TracksOnlyPlayedOnceInYear(ctx context.Context, arg TracksOnlyPlayedOnceInYearParams) ([]TracksOnlyPlayedOnceInYearRow, error) {
+ rows, err := q.db.Query(ctx, tracksOnlyPlayedOnceInYear, arg.Limit, arg.Year, arg.UserID)
+ if err != nil {
+ return nil, err
+ }
+ defer rows.Close()
+ var items []TracksOnlyPlayedOnceInYearRow
+ for rows.Next() {
+ var i TracksOnlyPlayedOnceInYearRow
+ if err := rows.Scan(
+ &i.TrackID,
+ &i.Title,
+ &i.Artists,
+ &i.ListenCount,
+ ); err != nil {
+ return nil, err
+ }
+ items = append(items, i)
+ }
+ if err := rows.Err(); err != nil {
+ return nil, err
+ }
+ return items, nil
+}