mirror of
https://github.com/283375/arcaea-offline.git
synced 2025-04-19 22:20:17 +00:00
refactor: db model using sqlalchemy
This commit is contained in:
parent
73f388f05e
commit
bee8268dd2
137
src/arcaea_offline/models_scores.py
Normal file
137
src/arcaea_offline/models_scores.py
Normal file
@ -0,0 +1,137 @@
|
|||||||
|
from typing import Optional
|
||||||
|
|
||||||
|
from sqlalchemy import TEXT, case, func, inspect, select
|
||||||
|
from sqlalchemy.orm import DeclarativeBase, Mapped, mapped_column
|
||||||
|
from sqlalchemy_utils import create_view
|
||||||
|
|
||||||
|
from .models_songs import Chart, ChartInfo
|
||||||
|
|
||||||
|
|
||||||
|
class ScoresBase(DeclarativeBase):
|
||||||
|
pass
|
||||||
|
|
||||||
|
|
||||||
|
class Score(ScoresBase):
|
||||||
|
__tablename__ = "score"
|
||||||
|
|
||||||
|
id: Mapped[int] = mapped_column(autoincrement=True, primary_key=True)
|
||||||
|
song_id: Mapped[str] = mapped_column(TEXT())
|
||||||
|
rating_class: Mapped[int]
|
||||||
|
score: Mapped[int]
|
||||||
|
pure: Mapped[Optional[int]]
|
||||||
|
far: Mapped[Optional[int]]
|
||||||
|
lost: Mapped[Optional[int]]
|
||||||
|
date: Mapped[Optional[int]]
|
||||||
|
max_recall: Mapped[Optional[int]]
|
||||||
|
r10_clear_type: Mapped[Optional[int]] = mapped_column(
|
||||||
|
comment="0: LOST, 1: COMPLETE, 2: HARD_LOST"
|
||||||
|
)
|
||||||
|
|
||||||
|
|
||||||
|
# How to create an SQL View with SQLAlchemy?
|
||||||
|
# https://stackoverflow.com/a/53253105/16484891
|
||||||
|
# CC BY-SA 4.0
|
||||||
|
|
||||||
|
|
||||||
|
class Calculated(ScoresBase):
|
||||||
|
score_id: Mapped[str]
|
||||||
|
song_id: Mapped[str]
|
||||||
|
rating_class: Mapped[int]
|
||||||
|
score: Mapped[int]
|
||||||
|
pure: Mapped[int]
|
||||||
|
far: Mapped[int]
|
||||||
|
lost: Mapped[int]
|
||||||
|
date: Mapped[int]
|
||||||
|
max_recall: Mapped[int]
|
||||||
|
r10_clear_type: Mapped[int]
|
||||||
|
shiny_pure: Mapped[int]
|
||||||
|
potential: Mapped[float]
|
||||||
|
|
||||||
|
__table__ = create_view(
|
||||||
|
name="calculated",
|
||||||
|
selectable=select(
|
||||||
|
Score.id.label("score_id"),
|
||||||
|
Chart.song_id,
|
||||||
|
Chart.rating_class,
|
||||||
|
Score.score,
|
||||||
|
Score.pure,
|
||||||
|
Score.far,
|
||||||
|
Score.lost,
|
||||||
|
Score.date,
|
||||||
|
Score.max_recall,
|
||||||
|
Score.r10_clear_type,
|
||||||
|
(
|
||||||
|
Score.score
|
||||||
|
- func.floor(
|
||||||
|
(Score.pure * 10000000.0 / ChartInfo.note)
|
||||||
|
+ (Score.far * 0.5 * 10000000.0 / ChartInfo.note)
|
||||||
|
)
|
||||||
|
).label("shiny_pure"),
|
||||||
|
case(
|
||||||
|
(Score.score >= 10000000, ChartInfo.constant / 10.0 + 2),
|
||||||
|
(
|
||||||
|
Score.score >= 9800000,
|
||||||
|
ChartInfo.constant / 10.0 + 1 + (Score.score - 9800000) / 200000.0,
|
||||||
|
),
|
||||||
|
else_=func.max(
|
||||||
|
(ChartInfo.constant / 10.0) + (Score.score - 9500000) / 300000.0,
|
||||||
|
0,
|
||||||
|
),
|
||||||
|
).label("potential"),
|
||||||
|
)
|
||||||
|
.select_from(Chart)
|
||||||
|
.join(
|
||||||
|
ChartInfo,
|
||||||
|
(Chart.song_id == ChartInfo.song_id)
|
||||||
|
& (Chart.rating_class == ChartInfo.rating_class),
|
||||||
|
)
|
||||||
|
.join(
|
||||||
|
Score,
|
||||||
|
(Chart.song_id == Score.song_id)
|
||||||
|
& (Chart.rating_class == Score.rating_class),
|
||||||
|
),
|
||||||
|
metadata=ScoresBase.metadata,
|
||||||
|
)
|
||||||
|
|
||||||
|
|
||||||
|
class Best(ScoresBase):
|
||||||
|
score_id: Mapped[str]
|
||||||
|
song_id: Mapped[str]
|
||||||
|
rating_class: Mapped[int]
|
||||||
|
score: Mapped[int]
|
||||||
|
pure: Mapped[int]
|
||||||
|
far: Mapped[int]
|
||||||
|
lost: Mapped[int]
|
||||||
|
date: Mapped[int]
|
||||||
|
max_recall: Mapped[int]
|
||||||
|
r10_clear_type: Mapped[int]
|
||||||
|
shiny_pure: Mapped[int]
|
||||||
|
potential: Mapped[float]
|
||||||
|
|
||||||
|
__table__ = create_view(
|
||||||
|
name="best",
|
||||||
|
selectable=select(
|
||||||
|
*[col for col in inspect(Calculated).columns if col.name != "potential"],
|
||||||
|
func.max(Calculated.potential).label("potential"),
|
||||||
|
)
|
||||||
|
.select_from(Calculated)
|
||||||
|
.group_by(Calculated.song_id, Calculated.rating_class)
|
||||||
|
.order_by(Calculated.potential.desc()),
|
||||||
|
metadata=ScoresBase.metadata,
|
||||||
|
)
|
||||||
|
|
||||||
|
|
||||||
|
class CalculatedPotential(ScoresBase):
|
||||||
|
b30: Mapped[float]
|
||||||
|
|
||||||
|
_select_bests_subquery = (
|
||||||
|
select(Best.potential.label("b30_sum"))
|
||||||
|
.order_by(Best.potential.desc())
|
||||||
|
.limit(30)
|
||||||
|
.subquery()
|
||||||
|
)
|
||||||
|
__table__ = create_view(
|
||||||
|
name="calculated_potential",
|
||||||
|
selectable=select(func.avg(_select_bests_subquery.c.b30_sum).label("b30")),
|
||||||
|
metadata=ScoresBase.metadata,
|
||||||
|
)
|
134
src/arcaea_offline/models_songs.py
Normal file
134
src/arcaea_offline/models_songs.py
Normal file
@ -0,0 +1,134 @@
|
|||||||
|
from typing import Optional
|
||||||
|
|
||||||
|
from sqlalchemy import TEXT, ForeignKey
|
||||||
|
from sqlalchemy.orm import DeclarativeBase, Mapped, mapped_column
|
||||||
|
|
||||||
|
|
||||||
|
class SongsBase(DeclarativeBase):
|
||||||
|
pass
|
||||||
|
|
||||||
|
|
||||||
|
class Property(SongsBase):
|
||||||
|
__tablename__ = "property"
|
||||||
|
|
||||||
|
id: Mapped[str] = mapped_column(TEXT(), primary_key=True)
|
||||||
|
value: Mapped[str] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class Pack(SongsBase):
|
||||||
|
__tablename__ = "pack"
|
||||||
|
|
||||||
|
id: Mapped[str] = mapped_column(TEXT(), primary_key=True)
|
||||||
|
name: Mapped[str] = mapped_column(TEXT())
|
||||||
|
description: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class PackLocalized(SongsBase):
|
||||||
|
__tablename__ = "pack_localized"
|
||||||
|
|
||||||
|
id: Mapped[str] = mapped_column(ForeignKey("pack.id"), primary_key=True)
|
||||||
|
name_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
name_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
name_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
name_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
description_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
description_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
description_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
description_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class Song(SongsBase):
|
||||||
|
__tablename__ = "song"
|
||||||
|
|
||||||
|
idx: Mapped[int]
|
||||||
|
id: Mapped[str] = mapped_column(TEXT(), primary_key=True)
|
||||||
|
title: Mapped[str] = mapped_column(TEXT())
|
||||||
|
artist: Mapped[str] = mapped_column(TEXT())
|
||||||
|
set: Mapped[str] = mapped_column(TEXT())
|
||||||
|
bpm: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bpm_base: Mapped[Optional[float]]
|
||||||
|
audio_preview: Mapped[Optional[int]]
|
||||||
|
audio_preview_end: Mapped[Optional[int]]
|
||||||
|
side: Mapped[Optional[int]]
|
||||||
|
version: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
date: Mapped[Optional[int]]
|
||||||
|
bg: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bg_inverse: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bg_day: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bg_night: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
source: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
source_copyright: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class SongLocalized(SongsBase):
|
||||||
|
__tablename__ = "song_localized"
|
||||||
|
|
||||||
|
id: Mapped[str] = mapped_column(ForeignKey("song.id"), primary_key=True)
|
||||||
|
title_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
search_title_ja: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_title_ko: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_title_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_title_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_artist_ja: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_artist_ko: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_artist_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
search_artist_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT(), comment="json")
|
||||||
|
source_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
source_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
source_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
source_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class Chart(SongsBase):
|
||||||
|
__tablename__ = "chart"
|
||||||
|
|
||||||
|
song_id: Mapped[str] = mapped_column(TEXT(), primary_key=True)
|
||||||
|
rating_class: Mapped[int] = mapped_column(primary_key=True)
|
||||||
|
rating: Mapped[int]
|
||||||
|
rating_plus: Mapped[bool]
|
||||||
|
chart_designer: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
jacket_desginer: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
audio_override: Mapped[bool]
|
||||||
|
jacket_override: Mapped[bool]
|
||||||
|
jacket_night: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
artist: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bg: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bg_inverse: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bpm: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
bpm_base: Mapped[Optional[float]]
|
||||||
|
version: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
date: Mapped[Optional[int]]
|
||||||
|
|
||||||
|
|
||||||
|
class ChartLocalized(SongsBase):
|
||||||
|
__tablename__ = "chart_localized"
|
||||||
|
|
||||||
|
song_id: Mapped[str] = mapped_column(ForeignKey("chart.song_id"), primary_key=True)
|
||||||
|
rating_class: Mapped[str] = mapped_column(
|
||||||
|
ForeignKey("chart.rating_class"), primary_key=True
|
||||||
|
)
|
||||||
|
title_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
title_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
artist_ja: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
artist_ko: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
artist_zh_hans: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
artist_zh_hant: Mapped[Optional[str]] = mapped_column(TEXT())
|
||||||
|
|
||||||
|
|
||||||
|
class ChartInfo(SongsBase):
|
||||||
|
__tablename__ = "chart_info"
|
||||||
|
|
||||||
|
song_id: Mapped[str] = mapped_column(ForeignKey("chart.song_id"), primary_key=True)
|
||||||
|
rating_class: Mapped[str] = mapped_column(
|
||||||
|
ForeignKey("chart.rating_class"), primary_key=True
|
||||||
|
)
|
||||||
|
constant: Mapped[int] = mapped_column(
|
||||||
|
comment="real_constant * 10. For example, Crimson Throne [FTR] is 10.4, then store 104 here."
|
||||||
|
)
|
||||||
|
note: Mapped[Optional[int]]
|
Loading…
x
Reference in New Issue
Block a user