mirror of
https://github.com/283375/arcaea-offline.git
synced 2025-04-17 21:30:18 +00:00
chore(db): split init sql statements
This commit is contained in:
parent
5e13685cf4
commit
08b1013820
@ -6,6 +6,7 @@ from typing import List, NamedTuple, Optional, TypeVar, Union
|
||||
from thefuzz import fuzz
|
||||
from thefuzz import process as fuzz_process
|
||||
|
||||
from .init_sqls import INIT_SQLS
|
||||
from .models import DbAliasRow, DbCalculatedRow, DbChartRow, DbPackageRow, DbScoreRow
|
||||
from .utils.singleton import Singleton
|
||||
from .utils.types import TDataclass
|
||||
@ -72,155 +73,7 @@ class Database(metaclass=Singleton):
|
||||
conn.commit()
|
||||
|
||||
def init(self):
|
||||
create_sqls = [
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS charts (
|
||||
song_id TEXT NOT NULL,
|
||||
rating_class INTEGER NOT NULL,
|
||||
name_en TEXT NOT NULL,
|
||||
name_jp TEXT,
|
||||
artist TEXT NOT NULL,
|
||||
bpm TEXT NOT NULL,
|
||||
bpm_base REAL NOT NULL,
|
||||
package_id TEXT NOT NULL,
|
||||
time INTEGER,
|
||||
side INTEGER NOT NULL,
|
||||
world_unlock BOOLEAN NOT NULL,
|
||||
remote_download BOOLEAN,
|
||||
bg TEXT NOT NULL,
|
||||
date INTEGER NOT NULL,
|
||||
version TEXT NOT NULL,
|
||||
difficulty INTEGER NOT NULL,
|
||||
rating INTEGER NOT NULL,
|
||||
note INTEGER NOT NULL,
|
||||
chart_designer TEXT,
|
||||
jacket_designer TEXT,
|
||||
jacket_override BOOLEAN NOT NULL,
|
||||
audio_override BOOLEAN NOT NULL,
|
||||
|
||||
PRIMARY KEY (song_id, rating_class)
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS aliases (
|
||||
song_id TEXT NOT NULL,
|
||||
alias TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS packages (
|
||||
package_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS scores (
|
||||
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
||||
song_id TEXT NOT NULL,
|
||||
rating_class INTEGER NOT NULL,
|
||||
score INTEGER NOT NULL,
|
||||
pure INTEGER NOT NULL,
|
||||
far INTEGER NOT NULL,
|
||||
lost INTEGER NOT NULL,
|
||||
time INTEGER NOT NULL,
|
||||
max_recall INTEGER,
|
||||
|
||||
FOREIGN KEY (song_id, rating_class) REFERENCES charts(song_id, rating_class) ON UPDATE CASCADE ON DELETE NO ACTION
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS properties (
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
value TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS calculated AS
|
||||
SELECT
|
||||
scores.song_id,
|
||||
scores.rating_class,
|
||||
scores.score,
|
||||
scores.pure,
|
||||
scores.far,
|
||||
scores.lost,
|
||||
scores.time,
|
||||
charts.rating,
|
||||
charts.note,
|
||||
score - FLOOR(( pure * 10000000.0 / note ) + ( far * 0.5 * 10000000.0 / note )) AS pure_small,
|
||||
CASE
|
||||
WHEN score >= 10000000 THEN
|
||||
rating / 10.0 + 2
|
||||
WHEN score >= 9800000 THEN
|
||||
rating / 10.0 + 1 + ( score - 9800000 ) / 200000.0 ELSE MAX( rating / 10.0, 0 ) + ( score - 9500000 ) / 300000.0
|
||||
END AS potential
|
||||
FROM
|
||||
scores
|
||||
LEFT JOIN charts ON scores.rating_class = charts.rating_class
|
||||
AND scores.song_id = charts.song_id
|
||||
GROUP BY
|
||||
scores.song_id,
|
||||
scores.rating_class
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS recent_10 AS
|
||||
SELECT
|
||||
c.song_id,
|
||||
c.rating_class,
|
||||
MAX(c.potential) AS potential
|
||||
FROM
|
||||
calculated c
|
||||
WHERE
|
||||
c.time IN (
|
||||
SELECT DISTINCT time
|
||||
FROM calculated
|
||||
ORDER BY time DESC
|
||||
LIMIT 10
|
||||
)
|
||||
GROUP BY
|
||||
c.song_id,
|
||||
c.rating_class
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS best_30 AS
|
||||
SELECT
|
||||
c.song_id,
|
||||
c.rating_class,
|
||||
MAX(c.potential) AS potential
|
||||
FROM
|
||||
calculated c
|
||||
GROUP BY
|
||||
c.song_id,
|
||||
c.rating_class
|
||||
ORDER BY
|
||||
potential DESC
|
||||
LIMIT 30
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS calculated_potential AS
|
||||
SELECT
|
||||
r10_avg AS r10,
|
||||
b30_avg AS b30,
|
||||
(r10_sum + b30_sum) / (r10_count + b30_count) AS potential
|
||||
FROM
|
||||
(SELECT SUM(potential) AS r10_sum, AVG(potential) AS r10_avg, COUNT(*) AS r10_count FROM recent_10) r10,
|
||||
(SELECT SUM(potential) AS b30_sum, AVG(potential) AS b30_avg, COUNT(*) AS b30_count FROM best_30) b30
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS song_id_names AS
|
||||
SELECT song_id, name
|
||||
FROM (
|
||||
SELECT song_id, alias AS name FROM aliases
|
||||
UNION ALL
|
||||
SELECT song_id, song_id AS name FROM charts
|
||||
UNION ALL
|
||||
SELECT song_id, name_en AS name FROM charts
|
||||
UNION ALL
|
||||
SELECT song_id, name_jp AS name FROM charts
|
||||
) AS subquery
|
||||
WHERE name IS NOT NULL AND name <> ''
|
||||
GROUP BY song_id, name
|
||||
""",
|
||||
]
|
||||
create_sqls = INIT_SQLS[1]["init"]
|
||||
|
||||
with self.conn as conn:
|
||||
cursor = conn.cursor()
|
||||
|
162
src/arcaea_offline/init_sqls.py
Normal file
162
src/arcaea_offline/init_sqls.py
Normal file
@ -0,0 +1,162 @@
|
||||
from typing import Dict, List, TypedDict
|
||||
|
||||
|
||||
class VersionSqls(TypedDict):
|
||||
init: List[str]
|
||||
update: List[str]
|
||||
|
||||
|
||||
INIT_SQLS: Dict[int, VersionSqls] = {
|
||||
1: {
|
||||
"init": [
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS charts (
|
||||
song_id TEXT NOT NULL,
|
||||
rating_class INTEGER NOT NULL,
|
||||
name_en TEXT NOT NULL,
|
||||
name_jp TEXT,
|
||||
artist TEXT NOT NULL,
|
||||
bpm TEXT NOT NULL,
|
||||
bpm_base REAL NOT NULL,
|
||||
package_id TEXT NOT NULL,
|
||||
time INTEGER,
|
||||
side INTEGER NOT NULL,
|
||||
world_unlock BOOLEAN NOT NULL,
|
||||
remote_download BOOLEAN,
|
||||
bg TEXT NOT NULL,
|
||||
date INTEGER NOT NULL,
|
||||
version TEXT NOT NULL,
|
||||
difficulty INTEGER NOT NULL,
|
||||
rating INTEGER NOT NULL,
|
||||
note INTEGER NOT NULL,
|
||||
chart_designer TEXT,
|
||||
jacket_designer TEXT,
|
||||
jacket_override BOOLEAN NOT NULL,
|
||||
audio_override BOOLEAN NOT NULL,
|
||||
|
||||
PRIMARY KEY (song_id, rating_class)
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS aliases (
|
||||
song_id TEXT NOT NULL,
|
||||
alias TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS packages (
|
||||
package_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS scores (
|
||||
id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
||||
song_id TEXT NOT NULL,
|
||||
rating_class INTEGER NOT NULL,
|
||||
score INTEGER NOT NULL,
|
||||
pure INTEGER NOT NULL,
|
||||
far INTEGER NOT NULL,
|
||||
lost INTEGER NOT NULL,
|
||||
time INTEGER NOT NULL,
|
||||
max_recall INTEGER,
|
||||
|
||||
FOREIGN KEY (song_id, rating_class) REFERENCES charts(song_id, rating_class) ON UPDATE CASCADE ON DELETE NO ACTION
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE TABLE IF NOT EXISTS properties (
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
value TEXT NOT NULL
|
||||
)
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS calculated AS
|
||||
SELECT
|
||||
scores.song_id,
|
||||
scores.rating_class,
|
||||
scores.score,
|
||||
scores.pure,
|
||||
scores.far,
|
||||
scores.lost,
|
||||
scores.time,
|
||||
charts.rating,
|
||||
charts.note,
|
||||
score - FLOOR(( pure * 10000000.0 / note ) + ( far * 0.5 * 10000000.0 / note )) AS pure_small,
|
||||
CASE
|
||||
WHEN score >= 10000000 THEN
|
||||
rating / 10.0 + 2
|
||||
WHEN score >= 9800000 THEN
|
||||
rating / 10.0 + 1 + ( score - 9800000 ) / 200000.0 ELSE MAX( rating / 10.0, 0 ) + ( score - 9500000 ) / 300000.0
|
||||
END AS potential
|
||||
FROM
|
||||
scores
|
||||
LEFT JOIN charts ON scores.rating_class = charts.rating_class
|
||||
AND scores.song_id = charts.song_id
|
||||
GROUP BY
|
||||
scores.song_id,
|
||||
scores.rating_class
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS recent_10 AS
|
||||
SELECT
|
||||
c.song_id,
|
||||
c.rating_class,
|
||||
MAX(c.potential) AS potential
|
||||
FROM
|
||||
calculated c
|
||||
WHERE
|
||||
c.time IN (
|
||||
SELECT DISTINCT time
|
||||
FROM calculated
|
||||
ORDER BY time DESC
|
||||
LIMIT 10
|
||||
)
|
||||
GROUP BY
|
||||
c.song_id,
|
||||
c.rating_class
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS best_30 AS
|
||||
SELECT
|
||||
c.song_id,
|
||||
c.rating_class,
|
||||
MAX(c.potential) AS potential
|
||||
FROM
|
||||
calculated c
|
||||
GROUP BY
|
||||
c.song_id,
|
||||
c.rating_class
|
||||
ORDER BY
|
||||
potential DESC
|
||||
LIMIT 30
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS calculated_potential AS
|
||||
SELECT
|
||||
r10_avg AS r10,
|
||||
b30_avg AS b30,
|
||||
(r10_sum + b30_sum) / (r10_count + b30_count) AS potential
|
||||
FROM
|
||||
(SELECT SUM(potential) AS r10_sum, AVG(potential) AS r10_avg, COUNT(*) AS r10_count FROM recent_10) r10,
|
||||
(SELECT SUM(potential) AS b30_sum, AVG(potential) AS b30_avg, COUNT(*) AS b30_count FROM best_30) b30
|
||||
""",
|
||||
"""
|
||||
CREATE VIEW IF NOT EXISTS song_id_names AS
|
||||
SELECT song_id, name
|
||||
FROM (
|
||||
SELECT song_id, alias AS name FROM aliases
|
||||
UNION ALL
|
||||
SELECT song_id, song_id AS name FROM charts
|
||||
UNION ALL
|
||||
SELECT song_id, name_en AS name FROM charts
|
||||
UNION ALL
|
||||
SELECT song_id, name_jp AS name FROM charts
|
||||
) AS subquery
|
||||
WHERE name IS NOT NULL AND name <> ''
|
||||
GROUP BY song_id, name
|
||||
""",
|
||||
],
|
||||
"update": [],
|
||||
}
|
||||
}
|
Loading…
x
Reference in New Issue
Block a user