A decentralized music tracking and discovery platform built on AT Protocol 🎵
listenbrainz spotify atproto lastfm musicbrainz scrobbling

Add date filters and DuckDB-friendly bindings

Bind optional start_date/end_date as Option<&str> so None becomes SQL
NULL and use CAST(? AS TIMESTAMP) to filter ranges. Return
MAX(s.created_at) as created_at (last played) and fix
play_count/unique_listeners column indexes. Use i64 pagination values
and duckdb::params! for parameter binding; place LIMIT before OFFSET in
queries.

Changed files
+292 -192
crates
analytics
+110 -85
crates/analytics/src/handlers/albums.rs
··· 115 115 ) -> Result<HttpResponse, Error> { 116 116 let body = read_payload!(payload); 117 117 let params = serde_json::from_slice::<GetTopAlbumsParams>(&body)?; 118 - let pagination = params.pagination.unwrap_or_default(); 119 - let offset = pagination.skip.unwrap_or(0); 120 - let limit = pagination.take.unwrap_or(20); 121 - let did = params.user_did; 122 - tracing::info!(limit, offset, user_did = ?did, "Get top albums"); 118 + 119 + let pagination = params.pagination.clone().unwrap_or_default(); 120 + let offset: i64 = pagination.skip.unwrap_or(0) as i64; 121 + let limit: i64 = pagination.take.unwrap_or(20) as i64; 122 + 123 + let did = params.user_did.clone(); 124 + 125 + // Bind Option<&str> so None becomes SQL NULL (DuckDB-friendly) 126 + let start_date: Option<&str> = params.start_date.as_deref(); 127 + let end_date: Option<&str> = params.end_date.as_deref(); 128 + 129 + tracing::info!( 130 + limit, 131 + offset, 132 + user_did = ?did, 133 + start_date = ?params.start_date, 134 + end_date = ?params.end_date, 135 + "Get top albums" 136 + ); 123 137 124 138 let conn = conn.lock().unwrap(); 125 - let mut stmt = match did { 126 - Some(_) => conn.prepare( 127 - r#" 128 - SELECT 129 - s.album_id AS id, 130 - a.title AS title, 131 - ar.name AS artist, 132 - ar.uri AS artist_uri, 133 - a.album_art AS album_art, 134 - a.release_date, 135 - a.year, 136 - a.uri, 137 - a.sha256, 138 - COUNT(DISTINCT s.created_at) AS play_count, 139 - COUNT(DISTINCT s.user_id) AS unique_listeners 140 - FROM 141 - scrobbles s 142 - LEFT JOIN 143 - albums a ON s.album_id = a.id 144 - LEFT JOIN 145 - artists ar ON a.artist = ar.name 146 - LEFT JOIN 147 - users u ON s.user_id = u.id 148 - WHERE s.album_id IS NOT NULL AND (u.did = ? OR u.handle = ?) AND ar.name IS NOT NULL 149 - GROUP BY 150 - s.album_id, a.title, ar.name, a.release_date, a.year, a.uri, a.album_art, a.sha256, ar.uri 151 - ORDER BY 152 - play_count DESC 153 - OFFSET ? 154 - LIMIT ?; 155 - "#, 156 - )?, 157 - None => conn.prepare( 158 - r#" 159 - SELECT 160 - s.album_id AS id, 161 - a.title AS title, 162 - ar.name AS artist, 163 - ar.uri AS artist_uri, 164 - a.album_art AS album_art, 165 - a.release_date, 166 - a.year, 167 - a.uri, 168 - a.sha256, 169 - COUNT(*) AS play_count, 170 - COUNT(DISTINCT s.user_id) AS unique_listeners 171 - FROM 172 - scrobbles s 173 - LEFT JOIN 174 - albums a ON s.album_id = a.id 175 - LEFT JOIN 176 - artists ar ON a.artist = ar.name WHERE s.album_id IS NOT NULL 177 - GROUP BY 178 - s.album_id, a.title, ar.name, a.release_date, a.year, a.uri, a.album_art, a.sha256, ar.uri 179 - ORDER BY 180 - play_count DESC 181 - OFFSET ? 182 - LIMIT ?; 183 - "#, 184 - )?, 185 - }; 186 139 187 140 match did { 188 141 Some(did) => { 142 + let mut stmt = conn.prepare( 143 + r#" 144 + SELECT 145 + s.album_id AS id, 146 + a.title AS title, 147 + ar.name AS artist, 148 + ar.uri AS artist_uri, 149 + a.album_art AS album_art, 150 + a.release_date, 151 + a.year, 152 + a.uri, 153 + a.sha256, 154 + -- return "last played" (scrobble time), not album row time 155 + MAX(s.created_at) AS created_at, 156 + COUNT(DISTINCT s.created_at) AS play_count, 157 + COUNT(DISTINCT s.user_id) AS unique_listeners 158 + FROM scrobbles s 159 + LEFT JOIN albums a ON s.album_id = a.id 160 + LEFT JOIN artists ar ON a.artist = ar.name 161 + LEFT JOIN users u ON s.user_id = u.id 162 + WHERE 163 + s.album_id IS NOT NULL 164 + AND (u.did = ? OR u.handle = ?) 165 + AND ar.name IS NOT NULL 166 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 167 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 168 + GROUP BY 169 + s.album_id, a.title, ar.name, a.release_date, a.year, a.uri, a.album_art, a.sha256, ar.uri 170 + ORDER BY play_count DESC 171 + LIMIT ? 172 + OFFSET ?; 173 + "#, 174 + )?; 175 + 189 176 let albums = stmt.query_map( 190 - [&did, &did, &limit.to_string(), &offset.to_string()], 177 + duckdb::params![ 178 + did, did, start_date, start_date, end_date, end_date, limit, offset 179 + ], 191 180 |row| { 192 181 Ok(Album { 193 182 id: row.get(0)?, ··· 199 188 year: row.get(6)?, 200 189 uri: row.get(7)?, 201 190 sha256: row.get(8)?, 202 - play_count: Some(row.get(9)?), 203 - unique_listeners: Some(row.get(10)?), 191 + play_count: Some(row.get(10)?), 192 + unique_listeners: Some(row.get(11)?), 204 193 ..Default::default() 205 194 }) 206 195 }, 207 196 )?; 197 + 208 198 let albums: Result<Vec<_>, _> = albums.collect(); 209 199 Ok(HttpResponse::Ok().json(web::Json(albums?))) 210 200 } 201 + 211 202 None => { 212 - let albums = stmt.query_map([limit, offset], |row| { 213 - Ok(Album { 214 - id: row.get(0)?, 215 - title: row.get(1)?, 216 - artist: row.get(2)?, 217 - artist_uri: row.get(3)?, 218 - album_art: row.get(4)?, 219 - release_date: row.get(5)?, 220 - year: row.get(6)?, 221 - uri: row.get(7)?, 222 - sha256: row.get(8)?, 223 - play_count: Some(row.get(9)?), 224 - unique_listeners: Some(row.get(10)?), 225 - ..Default::default() 226 - }) 227 - })?; 203 + let mut stmt = conn.prepare( 204 + r#" 205 + SELECT 206 + s.album_id AS id, 207 + a.title AS title, 208 + ar.name AS artist, 209 + ar.uri AS artist_uri, 210 + a.album_art AS album_art, 211 + a.release_date, 212 + a.year, 213 + a.uri, 214 + a.sha256, 215 + MAX(s.created_at) AS created_at, 216 + COUNT(*) AS play_count, 217 + COUNT(DISTINCT s.user_id) AS unique_listeners 218 + FROM scrobbles s 219 + LEFT JOIN albums a ON s.album_id = a.id 220 + LEFT JOIN artists ar ON a.artist = ar.name 221 + WHERE 222 + s.album_id IS NOT NULL 223 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 224 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 225 + GROUP BY 226 + s.album_id, a.title, ar.name, a.release_date, a.year, a.uri, a.album_art, a.sha256, ar.uri 227 + ORDER BY play_count DESC 228 + LIMIT ? 229 + OFFSET ?; 230 + "#, 231 + )?; 232 + 233 + let albums = stmt.query_map( 234 + duckdb::params![start_date, start_date, end_date, end_date, limit, offset], 235 + |row| { 236 + Ok(Album { 237 + id: row.get(0)?, 238 + title: row.get(1)?, 239 + artist: row.get(2)?, 240 + artist_uri: row.get(3)?, 241 + album_art: row.get(4)?, 242 + release_date: row.get(5)?, 243 + year: row.get(6)?, 244 + uri: row.get(7)?, 245 + sha256: row.get(8)?, 246 + play_count: Some(row.get(10)?), 247 + unique_listeners: Some(row.get(11)?), 248 + ..Default::default() 249 + }) 250 + }, 251 + )?; 252 + 228 253 let albums: Result<Vec<_>, _> = albums.collect(); 229 254 Ok(HttpResponse::Ok().json(web::Json(albums?))) 230 255 }
+89 -65
crates/analytics/src/handlers/artists.rs
··· 165 165 ) -> Result<HttpResponse, Error> { 166 166 let body = read_payload!(payload); 167 167 let params = serde_json::from_slice::<GetTopArtistsParams>(&body)?; 168 - let pagination = params.pagination.unwrap_or_default(); 169 - let offset = pagination.skip.unwrap_or(0); 170 - let limit = pagination.take.unwrap_or(20); 171 - let did = params.user_did; 168 + 169 + let pagination = params.pagination.clone().unwrap_or_default(); 170 + let offset: i64 = pagination.skip.unwrap_or(0) as i64; 171 + let limit: i64 = pagination.take.unwrap_or(20) as i64; 172 + 173 + let did = params.user_did.clone(); 174 + 175 + // DuckDB-friendly optional bindings (None -> SQL NULL) 176 + let start_date: Option<&str> = params.start_date.as_deref(); 177 + let end_date: Option<&str> = params.end_date.as_deref(); 178 + 179 + tracing::info!( 180 + limit, 181 + offset, 182 + user_did = ?did, 183 + start_date = ?params.start_date, 184 + end_date = ?params.end_date, 185 + "Get top artists" 186 + ); 172 187 173 188 let conn = conn.lock().unwrap(); 174 - let mut stmt = match did { 175 - Some(_) => conn.prepare( 176 - r#" 189 + 190 + match did { 191 + Some(did) => { 192 + let mut stmt = conn.prepare( 193 + r#" 177 194 SELECT 178 195 s.artist_id AS id, 179 196 ar.name AS artist_name, ··· 181 198 ar.sha256 AS sha256, 182 199 ar.uri AS uri, 183 200 ar.genres AS genres, 201 + -- "created_at" reflects scrobble time (last played) 202 + MAX(s.created_at) AS created_at, 184 203 COUNT(DISTINCT s.created_at) AS play_count, 185 204 COUNT(DISTINCT s.user_id) AS unique_listeners 186 - FROM 187 - scrobbles s 188 - LEFT JOIN 189 - artists ar ON s.artist_id = ar.id 190 - LEFT JOIN 191 - users u ON s.user_id = u.id 205 + FROM scrobbles s 206 + LEFT JOIN artists ar ON s.artist_id = ar.id 207 + LEFT JOIN users u ON s.user_id = u.id 192 208 WHERE 193 - s.artist_id IS NOT NULL AND (u.did = ? OR u.handle = ?) AND ar.name != 'Various Artists' 209 + s.artist_id IS NOT NULL 210 + AND (u.did = ? OR u.handle = ?) 211 + AND ar.name != 'Various Artists' 212 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 213 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 194 214 GROUP BY 195 215 s.artist_id, ar.name, ar.uri, ar.picture, ar.sha256, ar.genres 196 - ORDER BY 197 - play_count DESC 198 - OFFSET ? 199 - LIMIT ?; 200 - "#, 201 - )?, 202 - None => conn.prepare( 203 - r#" 216 + ORDER BY play_count DESC 217 + LIMIT ? 218 + OFFSET ?; 219 + "#, 220 + )?; 221 + 222 + let artists = stmt.query_map( 223 + duckdb::params![ 224 + did, did, start_date, start_date, end_date, end_date, limit, offset 225 + ], 226 + |row| { 227 + let genres = extract_genres_from_value(row.get(5)?); 228 + Ok(Artist { 229 + id: row.get(0)?, 230 + name: row.get(1)?, 231 + biography: None, 232 + born: None, 233 + born_in: None, 234 + died: None, 235 + picture: row.get(2)?, 236 + sha256: row.get(3)?, 237 + spotify_link: None, 238 + tidal_link: None, 239 + youtube_link: None, 240 + apple_music_link: None, 241 + uri: row.get(4)?, 242 + genres, 243 + play_count: Some(row.get(7)?), 244 + unique_listeners: Some(row.get(8)?), 245 + }) 246 + }, 247 + )?; 248 + 249 + let artists: Result<Vec<_>, _> = artists.collect(); 250 + Ok(HttpResponse::Ok().json(artists?)) 251 + } 252 + 253 + None => { 254 + let mut stmt = conn.prepare( 255 + r#" 204 256 SELECT 205 257 s.artist_id AS id, 206 258 ar.name AS artist_name, ··· 208 260 ar.sha256 AS sha256, 209 261 ar.uri AS uri, 210 262 ar.genres AS genres, 263 + MAX(s.created_at) AS created_at, 211 264 COUNT(*) AS play_count, 212 265 COUNT(DISTINCT s.user_id) AS unique_listeners 213 - FROM 214 - scrobbles s 215 - LEFT JOIN 216 - artists ar ON s.artist_id = ar.id 266 + FROM scrobbles s 267 + LEFT JOIN artists ar ON s.artist_id = ar.id 217 268 WHERE 218 - s.artist_id IS NOT NULL AND ar.name != 'Various Artists' 269 + s.artist_id IS NOT NULL 270 + AND ar.name != 'Various Artists' 271 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 272 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 219 273 GROUP BY 220 274 s.artist_id, ar.name, ar.uri, ar.picture, ar.sha256, ar.genres 221 - ORDER BY 222 - play_count DESC 223 - OFFSET ? 224 - LIMIT ?; 225 - "#, 226 - )?, 227 - }; 275 + ORDER BY play_count DESC 276 + LIMIT ? 277 + OFFSET ?; 278 + "#, 279 + )?; 228 280 229 - match did { 230 - Some(did) => { 231 281 let artists = stmt.query_map( 232 - [&did, &did, &limit.to_string(), &offset.to_string()], 282 + duckdb::params![start_date, start_date, end_date, end_date, limit, offset], 233 283 |row| { 234 284 let genres = extract_genres_from_value(row.get(5)?); 235 285 Ok(Artist { ··· 247 297 apple_music_link: None, 248 298 uri: row.get(4)?, 249 299 genres, 250 - play_count: Some(row.get(6)?), 251 - unique_listeners: Some(row.get(7)?), 300 + play_count: Some(row.get(7)?), 301 + unique_listeners: Some(row.get(8)?), 252 302 }) 253 303 }, 254 304 )?; 255 - 256 - let artists: Result<Vec<_>, _> = artists.collect(); 257 - Ok(HttpResponse::Ok().json(artists?)) 258 - } 259 - None => { 260 - let artists = stmt.query_map([limit, offset], |row| { 261 - let genres = extract_genres_from_value(row.get(5)?); 262 - Ok(Artist { 263 - id: row.get(0)?, 264 - name: row.get(1)?, 265 - biography: None, 266 - born: None, 267 - born_in: None, 268 - died: None, 269 - picture: row.get(2)?, 270 - sha256: row.get(3)?, 271 - spotify_link: None, 272 - tidal_link: None, 273 - youtube_link: None, 274 - apple_music_link: None, 275 - uri: row.get(4)?, 276 - genres, 277 - play_count: Some(row.get(6)?), 278 - unique_listeners: Some(row.get(7)?), 279 - }) 280 - })?; 281 305 282 306 let artists: Result<Vec<_>, _> = artists.collect(); 283 307 Ok(HttpResponse::Ok().json(artists?))
+93 -42
crates/analytics/src/handlers/tracks.rs
··· 259 259 ) -> Result<HttpResponse, Error> { 260 260 let body = read_payload!(payload); 261 261 let params = serde_json::from_slice::<GetTopTracksParams>(&body)?; 262 - let pagination = params.pagination.unwrap_or_default(); 263 - let offset = pagination.skip.unwrap_or(0); 264 - let limit = pagination.take.unwrap_or(20); 265 - let did = params.user_did; 266 - tracing::info!(limit, offset, user_did = ?did, "Get top tracks"); 262 + 263 + let pagination = params.pagination.clone().unwrap_or_default(); 264 + let offset: i64 = pagination.skip.unwrap_or(0) as i64; 265 + let limit: i64 = pagination.take.unwrap_or(20) as i64; 266 + 267 + let did = params.user_did.clone(); 268 + 269 + let start_date: Option<&str> = params.start_date.as_deref(); 270 + let end_date: Option<&str> = params.end_date.as_deref(); 271 + 272 + tracing::info!( 273 + limit, 274 + offset, 275 + user_did = ?did, 276 + start_date = ?params.start_date, 277 + end_date = ?params.end_date, 278 + "Get top tracks" 279 + ); 267 280 268 281 let conn = conn.lock().unwrap(); 282 + 269 283 match did { 270 284 Some(did) => { 271 - let mut stmt = conn.prepare(r#" 285 + let mut stmt = conn.prepare( 286 + r#" 272 287 SELECT 273 288 t.id, 274 289 t.title, ··· 291 306 LEFT JOIN artists ar ON s.artist_id = ar.id 292 307 LEFT JOIN albums a ON s.album_id = a.id 293 308 LEFT JOIN users u ON s.user_id = u.id 294 - WHERE u.did = ? OR u.handle = ? 295 - GROUP BY t.id, s.track_id, t.title, ar.name, a.title, t.artist, t.uri, t.album_art, t.duration, t.disc_number, t.track_number, t.artist_uri, t.album_uri, t.created_at, t.sha256, t.album_artist, t.album 309 + WHERE 310 + (u.did = ? OR u.handle = ?) 311 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 312 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 313 + GROUP BY 314 + t.id, s.track_id, t.title, ar.name, a.title, t.artist, t.uri, 315 + t.album_art, t.duration, t.disc_number, t.track_number, 316 + t.artist_uri, t.album_uri, t.created_at, t.sha256, 317 + t.album_artist, t.album 296 318 ORDER BY play_count DESC 297 - OFFSET ? 298 - LIMIT ?; 299 - "#)?; 300 - let top_tracks = stmt.query_map( 301 - [&did, &did, &limit.to_string(), &offset.to_string()], 319 + LIMIT ? 320 + OFFSET ?; 321 + "#, 322 + )?; 323 + 324 + let rows = stmt.query_map( 325 + duckdb::params![ 326 + did, // u.did = ? 327 + did, // u.handle = ? 328 + start_date, // ? IS NULL 329 + start_date, // CAST(? AS TIMESTAMP) 330 + end_date, // ? IS NULL 331 + end_date, // CAST(? AS TIMESTAMP) 332 + limit, // LIMIT ? 333 + offset // OFFSET ? 334 + ], 302 335 |row| { 303 336 Ok(Track { 304 337 id: row.get(0)?, ··· 321 354 }) 322 355 }, 323 356 )?; 324 - let top_tracks: Result<Vec<_>, _> = top_tracks.collect(); 357 + 358 + let top_tracks: Result<Vec<_>, _> = rows.collect(); 325 359 Ok(HttpResponse::Ok().json(top_tracks?)) 326 360 } 361 + 327 362 None => { 328 - let mut stmt = conn.prepare(r#" 363 + let mut stmt = conn.prepare( 364 + r#" 329 365 SELECT 330 366 t.id, 331 367 t.title, ··· 347 383 LEFT JOIN tracks t ON s.track_id = t.id 348 384 LEFT JOIN artists ar ON s.artist_id = ar.id 349 385 LEFT JOIN albums a ON s.album_id = a.id 350 - WHERE s.track_id IS NOT NULL AND s.artist_id IS NOT NULL AND s.album_id IS NOT NULL 351 - GROUP BY t.id, s.track_id, t.title, ar.name, a.title, t.artist, t.uri, t.album_art, t.duration, t.disc_number, t.track_number, t.artist_uri, t.album_uri, t.created_at, t.sha256, t.album_artist, t.album 386 + WHERE 387 + s.track_id IS NOT NULL 388 + AND s.artist_id IS NOT NULL 389 + AND s.album_id IS NOT NULL 390 + AND (? IS NULL OR s.created_at >= CAST(? AS TIMESTAMP)) 391 + AND (? IS NULL OR s.created_at <= CAST(? AS TIMESTAMP)) 392 + GROUP BY 393 + t.id, s.track_id, t.title, ar.name, a.title, t.artist, t.uri, 394 + t.album_art, t.duration, t.disc_number, t.track_number, 395 + t.artist_uri, t.album_uri, t.created_at, t.sha256, 396 + t.album_artist, t.album 352 397 ORDER BY play_count DESC 353 - OFFSET ? 354 - LIMIT ?; 355 - "#)?; 356 - let top_tracks = stmt.query_map([limit, offset], |row| { 357 - Ok(Track { 358 - id: row.get(0)?, 359 - title: row.get(1)?, 360 - artist: row.get(2)?, 361 - album_artist: row.get(3)?, 362 - album: row.get(4)?, 363 - uri: row.get(5)?, 364 - album_art: row.get(6)?, 365 - duration: row.get(7)?, 366 - disc_number: row.get(8)?, 367 - track_number: row.get(9)?, 368 - artist_uri: row.get(10)?, 369 - album_uri: row.get(11)?, 370 - sha256: row.get(12)?, 371 - created_at: row.get(13)?, 372 - play_count: row.get(14)?, 373 - unique_listeners: row.get(15)?, 374 - ..Default::default() 375 - }) 376 - })?; 377 - let top_tracks: Result<Vec<_>, _> = top_tracks.collect(); 398 + LIMIT ? 399 + OFFSET ?; 400 + "#, 401 + )?; 402 + 403 + let rows = stmt.query_map( 404 + duckdb::params![start_date, start_date, end_date, end_date, limit, offset], 405 + |row| { 406 + Ok(Track { 407 + id: row.get(0)?, 408 + title: row.get(1)?, 409 + artist: row.get(2)?, 410 + album_artist: row.get(3)?, 411 + album: row.get(4)?, 412 + uri: row.get(5)?, 413 + album_art: row.get(6)?, 414 + duration: row.get(7)?, 415 + disc_number: row.get(8)?, 416 + track_number: row.get(9)?, 417 + artist_uri: row.get(10)?, 418 + album_uri: row.get(11)?, 419 + sha256: row.get(12)?, 420 + created_at: row.get(13)?, 421 + play_count: row.get(14)?, 422 + unique_listeners: row.get(15)?, 423 + ..Default::default() 424 + }) 425 + }, 426 + )?; 427 + 428 + let top_tracks: Result<Vec<_>, _> = rows.collect(); 378 429 Ok(HttpResponse::Ok().json(top_tracks?)) 379 430 } 380 431 }