diff --git a/client/app/components/SearchResults.tsx b/client/app/components/SearchResults.tsx index b2a4566..0e68c3d 100644 --- a/client/app/components/SearchResults.tsx +++ b/client/app/components/SearchResults.tsx @@ -23,12 +23,12 @@ export default function SearchResults({ data, onSelect, selectorMode }: Props) { } } - if (data === undefined) { + if (!data) { return <> } return (
- { data.artists.length > 0 && + { data.artists && data.artists.length > 0 && <>

Artists

@@ -52,7 +52,7 @@ export default function SearchResults({ data, onSelect, selectorMode }: Props) {
} - { data.albums.length > 0 && + { data.albums && data.albums.length > 0 && <>

Albums

@@ -77,7 +77,7 @@ export default function SearchResults({ data, onSelect, selectorMode }: Props) {
} - { data.tracks.length > 0 && + { data.tracks && data.tracks.length > 0 && <>

Tracks

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/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/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/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/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 +}