You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
Koito/internal/repository/year.sql.go

617 lines
16 KiB

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