From 87ffc6f5811e6c2f71b65c65e88b9264b999c9d3 Mon Sep 17 00:00:00 2001 From: MingxuanGame Date: Sat, 3 Jan 2026 15:36:18 +0800 Subject: [PATCH] perf(user): use keyset to boost user scores API & user beatmap API --- app/database/beatmap_playcounts.py | 10 +- app/database/favourite_beatmapset.py | 3 +- app/database/score.py | 85 ++++++------ app/database/total_score_best_scores.py | 5 + app/router/v2/user.py | 127 ++++++++++++++---- ..._c5472f592d13_add_union_index_for_score.py | 51 +++++++ 6 files changed, 203 insertions(+), 78 deletions(-) create mode 100644 migrations/versions/2026-01-03_c5472f592d13_add_union_index_for_score.py diff --git a/app/database/beatmap_playcounts.py b/app/database/beatmap_playcounts.py index cf2fb6c..c4b4234 100644 --- a/app/database/beatmap_playcounts.py +++ b/app/database/beatmap_playcounts.py @@ -12,6 +12,7 @@ from sqlmodel import ( Column, Field, ForeignKey, + Index, Relationship, select, ) @@ -32,11 +33,7 @@ class BeatmapPlaycountsDict(TypedDict): class BeatmapPlaycountsModel(AsyncAttrs, DatabaseModel[BeatmapPlaycountsDict]): - __tablename__: str = "beatmap_playcounts" - - id: int | None = Field( - default=None, sa_column=Column(BigInteger, primary_key=True, autoincrement=True), exclude=True - ) + id: int = Field(default=None, sa_column=Column(BigInteger, primary_key=True, autoincrement=True), exclude=True) user_id: int = Field(sa_column=Column(BigInteger, ForeignKey("lazer_users.id"), index=True)) beatmap_id: int = Field(foreign_key="beatmaps.id", index=True) playcount: int = Field(default=0, exclude=True) @@ -68,6 +65,9 @@ class BeatmapPlaycountsModel(AsyncAttrs, DatabaseModel[BeatmapPlaycountsDict]): class BeatmapPlaycounts(BeatmapPlaycountsModel, table=True): + __tablename__: str = "beatmap_playcounts" + __table_args__ = (Index("idx_beatmap_playcounts_playcount_id", "playcount", "id"),) + user: "User" = Relationship() beatmap: "Beatmap" = Relationship() diff --git a/app/database/favourite_beatmapset.py b/app/database/favourite_beatmapset.py index 2925207..a9b626a 100644 --- a/app/database/favourite_beatmapset.py +++ b/app/database/favourite_beatmapset.py @@ -17,7 +17,8 @@ from sqlmodel import ( class FavouriteBeatmapset(AsyncAttrs, SQLModel, table=True): __tablename__: str = "favourite_beatmapset" - id: int | None = Field( + + id: int = Field( default=None, sa_column=Column(BigInteger, autoincrement=True, primary_key=True), exclude=True, diff --git a/app/database/score.py b/app/database/score.py index 940582c..eb184b3 100644 --- a/app/database/score.py +++ b/app/database/score.py @@ -56,9 +56,9 @@ from .user import User, UserDict, UserModel from pydantic import BaseModel, field_serializer, field_validator from redis.asyncio import Redis -from sqlalchemy import Boolean, Column, DateTime, TextClause +from sqlalchemy import Boolean, Column, DateTime, Index, TextClause, exists from sqlalchemy.ext.asyncio import AsyncAttrs -from sqlalchemy.orm import Mapped, joinedload +from sqlalchemy.orm import Mapped, aliased, joinedload from sqlalchemy.sql.elements import ColumnElement from sqlmodel import ( JSON, @@ -414,6 +414,11 @@ class ScoreModel(AsyncAttrs, DatabaseModel[ScoreDict]): class Score(ScoreModel, table=True): __tablename__: str = "scores" + __table_args__ = ( + Index("idx_score_user_mode_pinned", "user_id", "gamemode", "pinned_order", "id"), + Index("idx_score_user_mode_pp", "user_id", "gamemode", "pp", "id"), + Index("idx_score_user_mode_date", "user_id", "gamemode", "ended_at", "id"), + ) # ScoreStatistics n300: int = Field(exclude=True) @@ -828,64 +833,54 @@ async def get_user_best_score_with_mod_in_beatmap( async def get_user_first_scores( - session: AsyncSession, user_id: int, mode: GameMode, limit: int = 5, offset: int = 0 + session: AsyncSession, + user_id: int, + mode: GameMode, + limit: int = 5, + offset: int = 0, + cursor_id: int | None = None, ) -> list[TotalScoreBestScore]: - rownum = ( - func.row_number() - .over( - partition_by=(col(TotalScoreBestScore.beatmap_id), col(TotalScoreBestScore.gamemode)), - order_by=col(TotalScoreBestScore.total_score).desc(), - ) - .label("rn") + # Alias for the subquery table + s2 = aliased(TotalScoreBestScore) + + query = select(TotalScoreBestScore).where( + TotalScoreBestScore.user_id == user_id, + TotalScoreBestScore.gamemode == mode, ) - # Step 1: Fetch top score_ids in Python - subq = ( - select( - col(TotalScoreBestScore.score_id).label("score_id"), - col(TotalScoreBestScore.user_id).label("user_id"), - rownum, - ) - .where(col(TotalScoreBestScore.gamemode) == mode) - .subquery() + # Subquery for NOT EXISTS + # Check if there is a score with same beatmap, same mode, but higher total_score + subq = select(1).where( + s2.beatmap_id == TotalScoreBestScore.beatmap_id, + s2.gamemode == TotalScoreBestScore.gamemode, + s2.total_score > TotalScoreBestScore.total_score, ) - top_ids_stmt = select(subq.c.score_id).where(subq.c.rn == 1, subq.c.user_id == user_id).limit(limit).offset(offset) + query = query.where(~exists(subq)) - top_ids = await session.exec(top_ids_stmt) - top_ids = list(top_ids) + if cursor_id: + query = query.where(TotalScoreBestScore.score_id < cursor_id) - stmt = ( - select(TotalScoreBestScore) - .where(col(TotalScoreBestScore.score_id).in_(top_ids)) - .order_by(col(TotalScoreBestScore.total_score).desc()) - ) + query = query.order_by(col(TotalScoreBestScore.score_id).desc()).limit(limit).offset(offset) - result = await session.exec(stmt) + result = await session.exec(query) return list(result.all()) async def get_user_first_score_count(session: AsyncSession, user_id: int, mode: GameMode) -> int: - rownum = ( - func.row_number() - .over( - partition_by=(col(TotalScoreBestScore.beatmap_id), col(TotalScoreBestScore.gamemode)), - order_by=col(TotalScoreBestScore.total_score).desc(), - ) - .label("rn") + s2 = aliased(TotalScoreBestScore) + query = select(func.count()).where( + TotalScoreBestScore.user_id == user_id, + TotalScoreBestScore.gamemode == mode, ) - subq = ( - select( - col(TotalScoreBestScore.score_id).label("score_id"), - col(TotalScoreBestScore.user_id).label("user_id"), - rownum, - ) - .where(col(TotalScoreBestScore.gamemode) == mode) - .subquery() + subq = select(1).where( + s2.beatmap_id == TotalScoreBestScore.beatmap_id, + s2.gamemode == TotalScoreBestScore.gamemode, + s2.total_score > TotalScoreBestScore.total_score, ) - count_stmt = select(func.count()).where(subq.c.rn == 1, subq.c.user_id == user_id) + query = query.where(~exists(subq)) - result = await session.exec(count_stmt) + result = await session.exec(query) return result.one() diff --git a/app/database/total_score_best_scores.py b/app/database/total_score_best_scores.py index f2a8f2d..7b7950c 100644 --- a/app/database/total_score_best_scores.py +++ b/app/database/total_score_best_scores.py @@ -6,6 +6,7 @@ from app.models.score import GameMode, Rank from .statistics import UserStatistics from .user import User +from sqlalchemy import Index from sqlmodel import ( JSON, BigInteger, @@ -27,6 +28,10 @@ if TYPE_CHECKING: class TotalScoreBestScore(SQLModel, table=True): __tablename__: str = "total_score_best_scores" + __table_args__ = ( + Index("ix_total_score_best_scores_user_mode_score", "user_id", "gamemode", "score_id"), + Index("ix_total_score_best_scores_beatmap_mode_score", "beatmap_id", "gamemode", "total_score"), + ) user_id: int = Field(sa_column=Column(BigInteger, ForeignKey("lazer_users.id"), index=True)) score_id: int = Field(sa_column=Column(BigInteger, ForeignKey("scores.id"), primary_key=True)) beatmap_id: int = Field(foreign_key="beatmaps.id", index=True) diff --git a/app/router/v2/user.py b/app/router/v2/user.py index 31403f9..71b70ef 100644 --- a/app/router/v2/user.py +++ b/app/router/v2/user.py @@ -8,6 +8,7 @@ from app.database import ( BeatmapModel, BeatmapPlaycounts, BeatmapsetModel, + FavouriteBeatmapset, User, ) from app.database.beatmap_playcounts import BeatmapPlaycountsModel @@ -30,7 +31,7 @@ from app.utils import api_doc, utcnow from .router import router from fastapi import BackgroundTasks, HTTPException, Path, Query, Request, Security -from sqlmodel import exists, false, select +from sqlmodel import exists, select, tuple_ from sqlmodel.sql.expression import col @@ -418,7 +419,7 @@ async def get_user_beatmapsets( return cached_result user = await session.get(User, user_id) - if not user or user.id == BANCHOBOT_ID: + if not user or user.id == BANCHOBOT_ID or not await visible_to_current_user(user, current_user, session): raise HTTPException(404, detail="User not found") if type in { @@ -433,10 +434,21 @@ async def get_user_beatmapsets( resp = [] elif type == BeatmapsetType.FAVOURITE: - user = await session.get(User, user_id) - if user is None or not await visible_to_current_user(user, current_user, session): - raise HTTPException(404, detail="User not found") - favourites = await user.awaitable_attrs.favourite_beatmapsets + cursor = ( + await session.exec( + select(FavouriteBeatmapset.id).where(FavouriteBeatmapset.user_id == user_id).limit(1).offset(offset) + ) + ).first() + if cursor is None: + return [] + favourites = ( + await session.exec( + select(FavouriteBeatmapset) + .where(FavouriteBeatmapset.user_id == user_id, FavouriteBeatmapset.id > cursor) + .order_by(col(FavouriteBeatmapset.date).desc()) + .limit(limit) + ) + ).all() resp = [ await BeatmapsetModel.transform( favourite.beatmapset, session=session, user=user, includes=beatmapset_includes @@ -445,16 +457,26 @@ async def get_user_beatmapsets( ] elif type == BeatmapsetType.MOST_PLAYED: - user = await session.get(User, user_id) - if user is None or not await visible_to_current_user(user, current_user, session): - raise HTTPException(404, detail="User not found") - + cursor = ( + await session.exec( + select(BeatmapPlaycounts.playcount, BeatmapPlaycounts.id) + .where(BeatmapPlaycounts.user_id == user_id) + .order_by(col(BeatmapPlaycounts.playcount).desc(), col(BeatmapPlaycounts.id).desc()) + .limit(1) + .offset(offset) + ) + ).first() + if cursor is None: + return [] + cursor_pc, cursor_id = cursor most_played = await session.exec( select(BeatmapPlaycounts) - .where(BeatmapPlaycounts.user_id == user_id) - .order_by(col(BeatmapPlaycounts.playcount).desc()) + .where( + BeatmapPlaycounts.user_id == user_id, + tuple_(BeatmapPlaycounts.playcount, BeatmapPlaycounts.id) < tuple_(cursor_pc, cursor_id), + ) + .order_by(col(BeatmapPlaycounts.playcount).desc(), col(BeatmapPlaycounts.id).desc()) .limit(limit) - .offset(offset) ) resp = [ await BeatmapPlaycountsModel.transform(most_played_beatmap, user=user, includes=beatmapset_includes) @@ -520,32 +542,83 @@ async def get_user_scores( raise HTTPException(404, detail="User not found") gamemode = mode or db_user.playmode - order_by = None where_clause = (col(Score.user_id) == db_user.id) & (col(Score.gamemode) == gamemode) includes = Score.USER_PROFILE_INCLUDES.copy() if not include_fails: where_clause &= col(Score.passed).is_(True) + + scores = [] if type == "pinned": where_clause &= Score.pinned_order > 0 - order_by = col(Score.pinned_order).asc() + cursor = ( + await session.exec( + select(Score.pinned_order, Score.id) + .where(where_clause) + .order_by(col(Score.pinned_order).asc(), col(Score.id).desc()) + .limit(1) + .offset(offset) + ) + ).first() + if cursor: + cursor_pinned, cursor_id = cursor + where_clause &= (col(Score.pinned_order) > cursor_pinned) | ( + (col(Score.pinned_order) == cursor_pinned) & (col(Score.id) < cursor_id) + ) + scores = ( + await session.exec( + select(Score) + .where(where_clause) + .order_by(col(Score.pinned_order).asc(), col(Score.id).desc()) + .limit(limit) + ) + ).all() + elif type == "best": where_clause &= exists().where(col(BestScore.score_id) == Score.id) - order_by = col(Score.pp).desc() includes.append("weight") + cursor = ( + await session.exec( + select(Score.pp, Score.id) + .where(where_clause) + .order_by(col(Score.pp).desc(), col(Score.id).desc()) + .limit(1) + .offset(offset) + ) + ).first() + if cursor: + cursor_pp, cursor_id = cursor + where_clause &= tuple_(col(Score.pp), col(Score.id)) < tuple_(cursor_pp, cursor_id) + scores = ( + await session.exec( + select(Score).where(where_clause).order_by(col(Score.pp).desc(), col(Score.id).desc()).limit(limit) + ) + ).all() + elif type == "recent": where_clause &= Score.ended_at > utcnow() - timedelta(hours=24) - order_by = col(Score.ended_at).desc() - elif type == "firsts": - where_clause &= false() + cursor = ( + await session.exec( + select(Score.ended_at, Score.id) + .where(where_clause) + .order_by(col(Score.ended_at).desc(), col(Score.id).desc()) + .limit(1) + .offset(offset) + ) + ).first() + if cursor: + cursor_date, cursor_id = cursor + where_clause &= tuple_(col(Score.ended_at), col(Score.id)) < tuple_(cursor_date, cursor_id) + scores = ( + await session.exec( + select(Score) + .where(where_clause) + .order_by(col(Score.ended_at).desc(), col(Score.id).desc()) + .limit(limit) + ) + ).all() - if type != "firsts": - scores = ( - await session.exec(select(Score).where(where_clause).order_by(order_by).limit(limit).offset(offset)) - ).all() - if not scores: - return [] - else: - best_scores = await get_user_first_scores(session, db_user.id, gamemode, limit) + elif type == "firsts": + best_scores = await get_user_first_scores(session, db_user.id, gamemode, limit, offset) scores = [best_score.score for best_score in best_scores] score_responses = [ diff --git a/migrations/versions/2026-01-03_c5472f592d13_add_union_index_for_score.py b/migrations/versions/2026-01-03_c5472f592d13_add_union_index_for_score.py new file mode 100644 index 0000000..65d93c8 --- /dev/null +++ b/migrations/versions/2026-01-03_c5472f592d13_add_union_index_for_score.py @@ -0,0 +1,51 @@ +"""add union index for score + +Revision ID: c5472f592d13 +Revises: 96c4f4b3f0ab +Create Date: 2026-01-03 07:10:11.050661 + +""" + +from collections.abc import Sequence + +from alembic import op + +# revision identifiers, used by Alembic. +revision: str = "c5472f592d13" +down_revision: str | Sequence[str] | None = "96c4f4b3f0ab" +branch_labels: str | Sequence[str] | None = None +depends_on: str | Sequence[str] | None = None + + +def upgrade() -> None: + """Upgrade schema.""" + # ### commands auto generated by Alembic - please adjust! ### + op.create_index("idx_score_user_mode_date", "scores", ["user_id", "gamemode", "ended_at", "id"], unique=False) + op.create_index("idx_score_user_mode_pinned", "scores", ["user_id", "gamemode", "pinned_order", "id"], unique=False) + op.create_index("idx_score_user_mode_pp", "scores", ["user_id", "gamemode", "pp", "id"], unique=False) + op.create_index("idx_beatmap_playcounts_playcount_id", "beatmap_playcounts", ["playcount", "id"], unique=False) + op.create_index( + "ix_total_score_best_scores_user_mode_score", + "total_score_best_scores", + ["user_id", "gamemode", "score_id"], + unique=False, + ) + op.create_index( + "ix_total_score_best_scores_beatmap_mode_score", + "total_score_best_scores", + ["beatmap_id", "gamemode", "total_score"], + unique=False, + ) + # ### end Alembic commands ### + + +def downgrade() -> None: + """Downgrade schema.""" + # ### commands auto generated by Alembic - please adjust! ### + op.drop_index("idx_score_user_mode_pp", table_name="scores") + op.drop_index("idx_score_user_mode_pinned", table_name="scores") + op.drop_index("idx_score_user_mode_date", table_name="scores") + op.drop_index("idx_beatmap_playcounts_playcount_id", table_name="beatmap_playcounts") + op.drop_index("ix_total_score_best_scores_beatmap_mode_score", table_name="total_score_best_scores") + op.drop_index("ix_total_score_best_scores_user_mode_score", table_name="total_score_best_scores") + # ### end Alembic commands ###