Skip to content

Commit

Permalink
Added database server information to core engine + differentiated ran…
Browse files Browse the repository at this point in the history
…kings calculation query based on database engine. (#1253)

* Added database server information to core engine + differentiated rankings calculation query based on database engine.

* Some code clean-up + removed SQLite references.

* Small comment fix in database server info object
  • Loading branch information
TheMaximum committed Aug 24, 2023
1 parent 5e2f343 commit 2c7c432
Show file tree
Hide file tree
Showing 5 changed files with 170 additions and 43 deletions.
69 changes: 26 additions & 43 deletions pyplanet/apps/contrib/rankings/__init__.py
Original file line number Diff line number Diff line change
@@ -1,9 +1,11 @@
import logging
import math
from packaging import version
from peewee import RawQuery

from pyplanet.apps.contrib.rankings.models.ranked_map import RankedMap
from pyplanet.apps.contrib.rankings.models import Rank
from pyplanet.apps.contrib.rankings.queries import Queries
from pyplanet.apps.contrib.rankings.views import TopRanksView, MapListView
from pyplanet.apps.config import AppConfig
from pyplanet.apps.core.maniaplanet.models import Player
Expand All @@ -21,6 +23,9 @@ class Rankings(AppConfig):
# Rankings depend on the local records.
app_dependencies = ['core.maniaplanet', 'core.trackmania', 'local_records']

# Whether the system supports using the partition query.
supports_partition = False

def __init__(self, *args, **kwargs):
super().__init__(*args, **kwargs)

Expand All @@ -43,8 +48,7 @@ def __init__(self, *args, **kwargs):
)

async def on_start(self):
if self.instance.db.engine.__class__.__name__.lower().find('postgresql') != -1:
raise NotImplementedError("Rankings app only works on PyPlanet instances running on MySQL.")
await self.check_database_compatibility()

# Listen to signals.
self.context.signals.listen(mp_signals.map.map_end, self.map_end)
Expand All @@ -60,6 +64,21 @@ async def on_start(self):
# Register settings
await self.context.setting.register(self.setting_records_required, self.setting_chat_announce, self.setting_topranks_limit)

async def check_database_compatibility(self):
# The queries used for calculating the rankings are only compatible with MySQL and MariaDB.
# Provide an error when running PostgreSQL.
if self.instance.db.server_info.type == "postgresql":
raise NotImplementedError("Rankings app only works on PyPlanet instances running on MySQL.")

# Database engines starting from MySQL 8.0 / MariaDB 10.2 support the PARTITION BY query.
# The query without PARTITION BY is unsupported in newer versions.
if self.instance.db.server_info.type == "mysql" and \
version.parse(self.instance.db.server_info.version) >= version.parse("8.0"):
self.supports_partition = True
elif self.instance.db.server_info.type == "mariadb" and \
version.parse(self.instance.db.server_info.version) >= version.parse("10.2"):
self.supports_partition = True

async def map_end(self, map):
# Calculate server ranks.
await self.calculate_server_ranks()
Expand All @@ -81,47 +100,11 @@ async def calculate_server_ranks(self):

maximum_record_rank = await self.get_maximum_record_rank()

query = RawQuery(Rank, """
-- Reset the current ranks to insert new ones later one.
TRUNCATE TABLE rankings_rank;
-- Limit on maximum ranked records.
SET @ranked_record_limit = {};
-- Minimum amount of ranked records required to acquire a rank.
SET @minimum_ranked_records = {};
-- Total amount of maps active on the server.
SET @active_map_count = {};
-- Set the rank/current rank variables to ensure correct first calculation
SET @player_rank = 0;
SET @current_rank = 0;
INSERT INTO rankings_rank (player_id, average, calculated_at)
SELECT
player_id, average, calculated_at
FROM (
SELECT
player_id,
-- Calculation: the sum of the record ranks is combined with the ranked record limit times the amount of unranked maps.
-- Divide this summed ranking by the amount of active maps on the server, and an average calculated rank will be returned.
ROUND((SUM(player_rank) + (@active_map_count - COUNT(player_rank)) * @ranked_record_limit) / @active_map_count * 10000, 0) AS average,
NOW() AS calculated_at,
COUNT(player_rank) AS ranked_records_count
FROM
(
SELECT
id,
map_id,
player_id,
score,
@player_rank := IF(@current_rank = map_id, @player_rank + 1, 1) AS player_rank,
@current_rank := map_id
FROM localrecord
WHERE map_id IN ({})
ORDER BY map_id, score ASC
) AS ranked_records
WHERE player_rank <= @ranked_record_limit
GROUP BY player_id
) grouped_ranks
WHERE ranked_records_count >= @minimum_ranked_records
""".format(maximum_record_rank, minimum_records_required, str(len(maps_on_server)), ", ".join(str(map_id) for map_id in maps_on_server)))
query_text = Queries.CALCULATE_WITH_PARTITION if self.supports_partition else Queries.CALCULATE_WITHOUT_PARTITION

query = RawQuery(Rank, query_text.format(
maximum_record_rank, minimum_records_required, str(len(maps_on_server)), ", ".join(str(map_id) for map_id in maps_on_server))
)

await Rank.execute(query)

Expand Down
80 changes: 80 additions & 0 deletions pyplanet/apps/contrib/rankings/queries.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
class Queries:
CALCULATE_WITH_PARTITION = """
-- Reset the current ranks to insert new ones later one.
TRUNCATE TABLE rankings_rank;
-- Limit on maximum ranked records.
SET @ranked_record_limit = {};
-- Minimum amount of ranked records required to acquire a rank.
SET @minimum_ranked_records = {};
-- Total amount of maps active on the server.
SET @active_map_count = {};
-- Set the rank/current rank variables to ensure correct first calculation
INSERT INTO rankings_rank (player_id, average, calculated_at)
SELECT
player_id, average, calculated_at
FROM (
SELECT
player_id,
-- Calculation: the sum of the record ranks is combined with the ranked record limit times the amount of unranked maps.
-- Divide this summed ranking by the amount of active maps on the server, and an average calculated rank will be returned.
ROUND((SUM(player_rank) + (@active_map_count - COUNT(player_rank)) * @ranked_record_limit) / @active_map_count * 10000, 0) AS average,
NOW() AS calculated_at,
COUNT(player_rank) AS ranked_records_count
FROM
(
SELECT
id,
map_id,
player_id,
score,
RANK() OVER (PARTITION BY map_id ORDER BY score ASC) AS player_rank
FROM localrecord
WHERE map_id IN ({})
) AS ranked_records
WHERE player_rank <= @ranked_record_limit
GROUP BY player_id
) grouped_ranks
WHERE ranked_records_count >= @minimum_ranked_records
"""

CALCULATE_WITHOUT_PARTITION = """
-- Reset the current ranks to insert new ones later one.
TRUNCATE TABLE rankings_rank;
-- Limit on maximum ranked records.
SET @ranked_record_limit = {};
-- Minimum amount of ranked records required to acquire a rank.
SET @minimum_ranked_records = {};
-- Total amount of maps active on the server.
SET @active_map_count = {};
-- Set the rank/current rank variables to ensure correct first calculation
SET @player_rank = 0;
SET @current_rank = 0;
INSERT INTO rankings_rank (player_id, average, calculated_at)
SELECT
player_id, average, calculated_at
FROM (
SELECT
player_id,
-- Calculation: the sum of the record ranks is combined with the ranked record limit times the amount of unranked maps.
-- Divide this summed ranking by the amount of active maps on the server, and an average calculated rank will be returned.
ROUND((SUM(player_rank) + (@active_map_count - COUNT(player_rank)) * @ranked_record_limit) / @active_map_count * 10000, 0) AS average,
NOW() AS calculated_at,
COUNT(player_rank) AS ranked_records_count
FROM
(
SELECT
id,
map_id,
player_id,
score,
@player_rank := IF(@current_rank = map_id, @player_rank + 1, 1) AS player_rank,
@current_rank := map_id
FROM localrecord
WHERE map_id IN ({})
ORDER BY map_id, score ASC
) AS ranked_records
WHERE player_rank <= @ranked_record_limit
GROUP BY player_id
) grouped_ranks
WHERE ranked_records_count >= @minimum_ranked_records
"""
6 changes: 6 additions & 0 deletions pyplanet/core/db/database.py
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@
from pyplanet.core.exceptions import ImproperlyConfigured
from .registry import Registry
from .migrator import Migrator
from .server_info import ServerInfo

Proxy = peewee.Proxy()

Expand All @@ -31,6 +32,7 @@ def __init__(self, engine_cls, instance, *args, **kwargs):
self.migrator = Migrator(self.instance, self)
self.registry = Registry(self.instance, self)
self.objects = peewee_async.Manager(self.engine, loop=self.instance.loop)
self.server_info = ServerInfo(self.engine, self)

# Don't allow any sync code.
if hasattr(self.engine, 'allow_sync'):
Expand Down Expand Up @@ -80,6 +82,10 @@ def allow_sync(self, *args, **kwargs):

async def connect(self):
self.engine.connect()

with self.allow_sync():
await self.server_info.determine()

logging.info('Database connection established!')

async def initiate(self):
Expand Down
57 changes: 57 additions & 0 deletions pyplanet/core/db/server_info.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,57 @@
"""
The server information object contains version information about the database server.
"""
import logging
import peewee

logger = logging.getLogger(__name__)


class ServerInfo:
def __init__(self, engine, db):
"""
Initiate database server information object.
:param engine: Database engine instance.
:param db: Database instance.
"""
self.engine = engine
self.db = db
self.type = None
self.version = None
self.version_text = None

async def determine(self):
if isinstance(self.db.engine, peewee.MySQLDatabase):
self.type = "mysql"
query = "SELECT @@version AS version, @@innodb_version AS innodb_version"
elif isinstance(self.db.engine, peewee.PostgresqlDatabase):
self.type = "postgresql"
query = "SHOW SERVER_VERSION"
else:
logger.warning("Unable to determine database server version (unknown engine type: {})".format(type(self.db.engine)))
return

try:
cursor = self.engine.execute_sql(query)
result = cursor.fetchone()

if result is None or len(result) == 0:
return

if self.type == "mysql":
# Use the innodb_version (1) for a clean engine version, use the version (0) as version text.
self.version = result[1]
self.version_text = result[0]

if "mariadb" in self.version_text.lower():
self.type = "mariadb"
elif self.type == "postgresql":
self.version_text = result[0]
self.version = self.version_text.split(' ')[0]

logger.info("Determined database server type: {}, version: {}".format(self.type, self.version))
except:
# No database version could be established
logger.warning("Unable to determine database server version (type: {})".format(self.type))

1 change: 1 addition & 0 deletions requirements.txt
Original file line number Diff line number Diff line change
Expand Up @@ -30,5 +30,6 @@ bcrypt==3.2.0
raven==6.10.0
xmltodict==0.12.0
PyYAML==5.4.1
packaging<=23.1

cryptography==36.0.1

0 comments on commit 2c7c432

Please sign in to comment.