Optimize leaderboard queries to remove stray filesort due to inner join and remove web calls to temporary in-memory leaderboard system

This commit is contained in:
AlexTheCoder 2018-09-09 16:47:40 -05:00
parent fc4a12bec3
commit af595585ea
1 changed files with 7 additions and 43 deletions

View File

@ -1,25 +1,16 @@
package mineplex.core.leaderboard;
import java.io.IOException;
import java.io.InputStream;
import java.net.HttpURLConnection;
import java.net.URL;
import java.net.URLConnection;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.Collection;
import java.util.HashMap;
import java.util.LinkedHashMap;
import java.util.Map;
import java.util.function.Consumer;
import com.google.common.collect.ImmutableMap;
import mineplex.core.common.util.UtilServer;
import mineplex.core.thread.ThreadPool;
import mineplex.serverdata.database.DBPool;
import mineplex.serverdata.database.RepositoryBase;
@ -36,14 +27,14 @@ public class LeaderboardRepository extends RepositoryBase
private static final String INSERT_STAT = "INSERT INTO accountStatsAllTime (accountId, statId, value) VALUES (?, ?, ?);";
private static final String UPDATE_STAT = "UPDATE accountStatsAllTime SET value=value + ? WHERE accountId=? AND statId=?;";
private static final String FETCH_STAT_ALL = "SELECT a.name, sl.value FROM accountStatsAllTime AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE sl.statId=%STAT% ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_YEARLY = "SELECT a.name, sl.value FROM accountStatsYearly AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE YEAR(sl.date) = YEAR(CURDATE()) AND sl.statId=%STAT% ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_MONTHLY = "SELECT a.name, sl.value FROM accountStatsMonthly AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE MONTH(sl.date) = MONTH(CURDATE()) AND YEAR(sl.date) = YEAR(CURDATE()) AND sl.statId=%STAT% ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_WEEKLY = "SELECT a.name, sl.value FROM accountStatsWeekly AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE YEARWEEK(sl.date, 1) = YEARWEEK(CURDATE(), 1) AND sl.statId=%STAT% ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_DAILY = "SELECT a.name, sl.value FROM accountStatsDaily AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE sl.date = CURDATE() AND sl.statId=%STAT% ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_ALL = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsAllTime WHERE statId=(SELECT id FROM stats WHERE name='%STAT%') ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
private static final String FETCH_STAT_ALL_SEASON = "SELECT a.name, sl.value FROM accountStatsSeasonal AS sl INNER JOIN accounts AS a ON a.id=sl.accountId WHERE sl.statId=%STAT% AND seasonId=(SELECT id FROM statSeasons WHERE now() BETWEEN startDate AND endDate LIMIT 1) ORDER BY sl.value DESC LIMIT %START%,%LIMIT%;";
private static final String FETCH_STAT_YEARLY = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsYearly WHERE (date BETWEEN MAKEDATE(YEAR(CURDATE()),1) AND CURDATE()) AND statId=(SELECT id FROM stats WHERE name='%STAT%') ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
private static final String FETCH_STAT_MONTHLY = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsMonthly WHERE (date BETWEEN DATE_FORMAT(CURDATE(),'%Y-%m-01') AND CURDATE()) AND statId=(SELECT id FROM stats WHERE name='%STAT%') ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
private static final String FETCH_STAT_WEEKLY = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsWeekly WHERE (date BETWEEN SUBDATE(CURDATE(), dayofweek(CURDATE())-1) AND CURDATE()) AND statId=(SELECT id FROM stats WHERE name='%STAT%') ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
private static final String FETCH_STAT_DAILY = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsDaily WHERE date = CURDATE() AND statId=(SELECT id FROM stats WHERE name='%STAT%') ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
private static final String FETCH_STAT_ALL_SEASON = "SELECT a.name, a.uuid, sl.value FROM (SELECT accountId, value FROM accountStatsSeasonal WHERE statId=(SELECT id FROM stats WHERE name='%STAT%') AND seasonId=(SELECT id FROM statSeasons WHERE now() BETWEEN startDate AND endDate LIMIT 1) ORDER BY value DESC LIMIT %START%,%LIMIT%) AS sl INNER JOIN accounts AS a ON a.id=sl.accountId;";
public LeaderboardRepository()
{
@ -52,33 +43,6 @@ public class LeaderboardRepository extends RepositoryBase
public void insertStats(Map<Integer, Map<Integer, Long>> stats)
{
Map<Integer, Map<Integer, Long>> copy = new HashMap<>(stats.size());
stats.forEach((statId, map) -> copy.put(statId, ImmutableMap.copyOf(map)));
ThreadPool.ASYNC.execute(() ->
{
for (Integer accountId : stats.keySet())
{
for (Integer statId : stats.get(accountId).keySet())
{
try
{
URL url = new URL("http://184.154.154.86:30030/update/" + statId + "/" + accountId + "/" + stats.get(accountId).get(statId) + "?apiKey=3e265961-f554-4aa7-8d6e-51f2af536537");
URLConnection con = url.openConnection();
HttpURLConnection http = (HttpURLConnection)con;
http.setRequestMethod("POST"); // PUT is another valid option
http.connect();
try (InputStream is = http.getInputStream())
{
is.close();
}
}
catch (IOException ex)
{
ex.printStackTrace();
}
}
}
});
UtilServer.runAsync(() ->
{
try (