core code for implementing H2 game stats database (see #1041 for more details).

master
lodici 2017-02-01 12:44:59 +00:00
parent fe302baf0c
commit 3d97985934
14 changed files with 1016 additions and 16 deletions

View File

@ -0,0 +1,223 @@
/*
* Stats schema script for a H2 database
* (http://www.h2database.com).
*
*/
/*
**
** TABLES
**
*/
create table GAMESTATS_SETTINGS (
SCHEMA_VERSION varchar(25)
);
create table PLAYER (
ID int identity,
AI_TYPE varchar(25),
AI_LEVEL int,
AI_XLIFE int,
PLAYER_PROFILE varchar(36) -- Human-only player profile guid.
);
create table DECK_TYPE (
ID int identity,
NAME varchar(15) not null
);
create table DECK (
ID int identity,
NAME varchar(100), -- assumes a deck name will be 100 chars or less.
FILE_CHECKSUM bigint,
DECK_TYPE_ID int,
DECK_SIZE int,
DECK_COLOR varchar(5)
);
create unique index IDX_PK_DECK
on DECK(NAME, FILE_CHECKSUM, DECK_TYPE_ID);
alter table DECK
add constraint DECK_TYPE_CONSTRAINT
foreign key (DECK_TYPE_ID)
references DECK_TYPE (ID);
create table GAME (
TIME_START bigint primary KEY, -- game start time as epoch
MAG_VERSION varchar(7), -- magarena version
CONCEDED boolean,
TURNS int,
START_HAND int,
START_LIFE int,
WINNING_PLAYER_NUMBER int
);
create table GAME_PLAYER (
GAME_TIME_START bigint NOT NULL,
PLAYER_NUMBER int NOT NULL, -- during a game, eg. player 1, player 2, etc.
PLAYER_ID int,
DECK_ID int
);
alter table GAME_PLAYER
add primary key (GAME_TIME_START, PLAYER_NUMBER);
alter table GAME_PLAYER
add constraint GAME_CONSTRAINT
foreign key (GAME_TIME_START)
references GAME (TIME_START);
alter table GAME_PLAYER
add constraint PLAYER_CONSTRAINT
foreign key (PLAYER_ID)
references PLAYER (ID);
alter table GAME_PLAYER
add constraint DECK_CONSTRAINT
foreign key (DECK_ID)
references DECK (ID);
/*
**
** VIEWS
**
*/
create or replace view ALL_GAME_STATS as
select
G.TIME_START,
G.MAG_VERSION,
G.WINNING_PLAYER_NUMBER as WINNER,
G.CONCEDED,
G.TURNS,
G.START_HAND,
G.START_LIFE,
PL1.PLAYER_PROFILE as P1_PROFILE,
PL1.AI_TYPE as P1_AI_TYPE,
PL1.AI_LEVEL as P1_AI_LEVEL,
PL1.AI_XLIFE as P1_AI_XLIFE,
D1.NAME as P1_DECK,
D1.FILE_CHECKSUM as P1_DECK_CRC,
DT1.NAME as P1_DECK_TYPE,
D1.DECK_SIZE as P1_DECK_SIZE,
D1.DECK_COLOR as P1_DECK_COLOR,
PL2.PLAYER_PROFILE as P2_PROFILE,
PL2.AI_TYPE as P2_AI_TYPE,
PL2.AI_LEVEL as P2_AI_LEVEL,
PL2.AI_XLIFE as P2_AI_XLIFE,
D2.NAME as P2_DECK,
D2.FILE_CHECKSUM as P2_DECK_CRC,
DT2.NAME as P2_DECK_TYPE,
D2.DECK_SIZE as P2_DECK_SIZE,
D2.DECK_COLOR as P2_DECK_COLOR
from
GAME as G
inner join GAME_PLAYER as GP1
on G.TIME_START = GP1.GAME_TIME_START
inner join GAME_PLAYER as GP2
on G.TIME_START = GP2.GAME_TIME_START
inner join DECK as D1
on GP1.DECK_ID = D1.ID
inner join DECK as D2
on GP2.DECK_ID = D2.ID
inner join DECK_TYPE as DT1
on D1.DECK_TYPE_ID = DT1.ID
inner join DECK_TYPE as DT2
on D2.DECK_TYPE_ID = DT2.ID
inner join PLAYER as PL1
on GP1.PLAYER_ID = PL1.ID
inner join PLAYER as PL2
on GP2.PLAYER_ID = PL2.ID
where
GP1.PLAYER_NUMBER = 1
and GP2.PLAYER_NUMBER = 2;
create or replace view GAME_RESULTS as
select
GP.GAME_TIME_START as GAME,
DK.NAME as DECK,
DK.FILE_CHECKSUM as DECK_CRC,
DT.NAME as DECK_TYPE,
GM.WINNING_PLAYER_NUMBER as WINNER
from
GAME_PLAYER as GP
left join GAME as GM
on GP.GAME_TIME_START = GM.TIME_START
and GP.PLAYER_NUMBER = GM.WINNING_PLAYER_NUMBER
join DECK as DK
on GP.DECK_ID = DK.ID
join DECK_TYPE as DT
on DK.DECK_TYPE_ID = DT.ID;
create or replace view DECK_GAME_PWL as
select
DECK,
DECK_CRC,
DECK_TYPE,
COUNT(GAME) as P,
COUNT(WINNER) as W,
SUM(NVL2(WINNER, 0, 1)) as L
from
GAME_RESULTS
group by
DECK, DECK_CRC, DECK_TYPE
order by
P desc, W desc, DECK;
create or replace view POPULAR_DECKS as
select
DECK,
DECK_CRC,
DECK_TYPE,
count(GAME) as P
from
GAME_RESULTS
where
DECK_CRC > 0 -- ignore Random decks which have no associated deck file.
group by
DECK, DECK_CRC, DECK_TYPE
order by
P desc, DECK;
create or replace view WINNING_DECKS as
select
DECK,
DECK_CRC,
DECK_TYPE,
count(WINNER) as W,
count(GAME) as P
from
GAME_RESULTS
where
DECK_CRC > 0 -- ignore Random decks which have no associated deck file.
group by
DECK, DECK_CRC, DECK_TYPE
having
W > 0
order by
W desc, P desc, DECK;
create or replace view RECENT_DECKS as
select distinct
DECK,
DECK_CRC,
DECK_TYPE,
max(GAME) as last_played
from
GAME_RESULTS
where
DECK_CRC > 0 -- ignore Random decks which have no associated deck file.
group by
DECK, DECK_CRC, DECK_TYPE
order by
last_played desc, DECK;

View File

@ -183,6 +183,9 @@ public class GeneralConfig {
private boolean isStatsVisible = true;
private static final String GAME_STATS = "gameStats";
private boolean logGameStats = false;
private GeneralConfig() { }
public Proxy getProxy() {
@ -581,6 +584,7 @@ public class GeneralConfig {
isCustomScrollBar = Boolean.parseBoolean(properties.getProperty(CUSTOM_SCROLLBAR, "" + isCustomScrollBar));
keywordsScreen = properties.getProperty(KEYWORDS_SCREEN, "");
cardDisplayMode = CardImageDisplayMode.valueOf(properties.getProperty(CARD_DISPLAY_MODE, cardDisplayMode.name()));
logGameStats = Boolean.parseBoolean(properties.getProperty(GAME_STATS, "" + logGameStats));
}
public void load() {
@ -635,6 +639,7 @@ public class GeneralConfig {
properties.setProperty(CUSTOM_SCROLLBAR, String.valueOf(isCustomScrollBar));
properties.setProperty(KEYWORDS_SCREEN, keywordsScreen);
properties.setProperty(CARD_DISPLAY_MODE, cardDisplayMode.name());
properties.setProperty(GAME_STATS, String.valueOf(logGameStats));
}
public void save() {
@ -748,4 +753,16 @@ public class GeneralConfig {
cardDisplayMode = newMode;
}
public void setGameStatsEnabled(boolean b) {
logGameStats = b;
}
public boolean isGameStatsEnabled() {
return logGameStats;
}
public static boolean isGameStatsOn() {
return getInstance().isGameStatsEnabled();
}
}

View File

@ -0,0 +1,7 @@
package magic.data.stats;
public class DeckStatsInfo {
public String deckName;
public long deckCheckSum;
public String deckType;
}

View File

@ -0,0 +1,80 @@
package magic.data.stats;
public class GameStatsInfo {
private static final String[] COL_NAMES = new String[]{
"Start", "Version",
"P1 Profile", "P1 AI", "Pl Level", "P1 +Life",
"P1 Deck", "P1 Deck CRC", "P1 Deck Type", "P1 Deck Size", "P1 Deck Color",
"P2 Profile", "P2 AI", "P2 Level", "P2 +Life",
"P2 Deck", "P2 Deck CRC", "P2 Deck Type", "P2 Deck Size", "P2 Deck Color",
"Winner Id", "Conceded", "Turns",
"Start Hand", "Start Life"
};
public static int fieldsCount() {
return COL_NAMES.length;
}
public static String getFieldName(int col) {
return COL_NAMES[col];
}
public static Object getValueAt(GameStatsInfo stats, int columnIndex) {
switch (columnIndex) {
case 0: return String.valueOf(stats.timeStart);
case 1: return String.valueOf(stats.magarenaVersion);
case 2: return stats.player1ProfileId;
case 3: return stats.player1AiType;
case 4: return String.valueOf(stats.player1AiLevel);
case 5: return String.valueOf(stats.player1AiXtraLife);
case 6: return stats.player1DeckName;
case 7: return String.valueOf(stats.player1DeckFileChecksum);
case 8: return stats.player1DeckType;
case 9: return String.valueOf(stats.player1DeckSize);
case 10: return stats.player1DeckColor;
case 11: return stats.player2ProfileId;
case 12: return stats.player2AiType;
case 13: return String.valueOf(stats.player2AiLevel);
case 14: return String.valueOf(stats.player2AiXtraLife);
case 15: return stats.player2DeckName;
case 16: return String.valueOf(stats.player2DeckFileChecksum);
case 17: return stats.player2DeckType;
case 18: return String.valueOf(stats.player2DeckSize);
case 19: return stats.player2DeckColor;
case 20: return stats.winningPlayerProfile;
case 21: return String.valueOf(stats.isConceded);
case 22: return String.valueOf(stats.turns);
case 23: return String.valueOf(stats.startHandSize);
case 24: return String.valueOf(stats.startLife);
default: return "???";
}
}
public long timeStart;
public String magarenaVersion;
public String player1ProfileId;
public String player1AiType;
public int player1AiLevel;
public int player1AiXtraLife;
public String player1DeckName;
public long player1DeckFileChecksum;
public String player1DeckType;
public int player1DeckSize;
public String player1DeckColor;
public String player2ProfileId;
public String player2AiType;
public int player2AiLevel;
public int player2AiXtraLife;
public String player2DeckName;
public long player2DeckFileChecksum;
public String player2DeckType;
public int player2DeckSize;
public String player2DeckColor;
public String winningPlayerProfile;
public boolean isConceded;
public int turns;
public int startHandSize;
public int startLife;
}

View File

@ -0,0 +1,193 @@
package magic.data.stats;
import java.sql.SQLException;
import java.util.ArrayList;
import java.util.List;
import magic.data.DeckType;
import magic.data.DuelConfig;
import magic.data.GeneralConfig;
import magic.data.stats.h2.H2Database;
import magic.model.MagicDeck;
import magic.model.MagicDuel;
import magic.model.MagicGame;
import magic.ui.ScreenController;
import magic.utility.DeckUtils;
import magic.utility.MagicSystem;
import org.h2.api.ErrorCode;
public final class MagicStats {
private MagicStats() {}
private static final GeneralConfig CONFIG = GeneralConfig.getInstance();
// do not access directly, use getDB().
private static H2Database db;
private static H2Database getDB() throws SQLException {
// primarily to prevent multiple threads trying
// to update the schema at the same time.
synchronized(MagicStats.class) {
if (db == null) {
db = new H2Database();
}
return db;
}
}
public static void init() {
try {
getDB();
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
private static boolean isDatabaseAlreadyOpenError(Exception ex) {
return ex instanceof SQLException
&& ((SQLException) ex).getErrorCode() == ErrorCode.DATABASE_ALREADY_OPEN_1;
}
private static void HandleErrorDisableStats(Exception ex) {
CONFIG.setGameStatsEnabled(false);
if (isDatabaseAlreadyOpenError(ex)) {
ScreenController.showWarningMessage(H2Database.getDatabaseFile() + "\n\nCannot connect to stats database as it is already open.\nStats have been switched off (see setting in preferences).");
} else {
CONFIG.save();
throw new RuntimeException(ex);
}
}
/**
* Currently only stats are only logged when at the end of game you click on
* the resume button to take you back to the duel decks screen. If after the
* game ends you open the menu and click back to the main menu no stats are logged.
*/
public static void logStats(MagicDuel duel, MagicGame game) {
// Don't log stats for AI simulated or test games.
if (game.isArtificial() || MagicSystem.isTestGame()) {
return;
}
saveGameData(game);
logFileBasedStats(duel, game);
}
/**
* Logs player stats using the old, file-based way and which are currently
* displayed on the new duel and player selection screens.
*
* TODO: phase out / replace with database system.
*/
private static void logFileBasedStats(MagicDuel duel, MagicGame game) {
if (!MagicSystem.isAiVersusAi()) {
// log player stats using the old way.
final DuelConfig duelConfig = duel.getConfiguration();
final boolean won = game.getLosingPlayer() != game.getPlayers()[0];
duelConfig.getPlayerProfile(0).getStats().update(won, game.getPlayer(0), game);
duelConfig.getPlayerProfile(1).getStats().update(!won, game.getPlayer(1), game);
}
}
/**
* Saves detailed game data to database.
*/
public static void saveGameData(MagicGame game) {
if (CONFIG.isGameStatsEnabled()) {
try {
getDB().logGameStats(game);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
}
public static String getPlayedWonLost(MagicDeck deck) {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getPlayedWonLost(deck);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return "";
}
public static int getTotalGamesPlayed() {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getTotalGamesPlayed();
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return 0;
}
public static int getTotalGamesPlayed(MagicDeck deck) {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getTotalGamesPlayed(deck);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return 0;
}
public static List<GameStatsInfo> getGameStats(int limit, int rowsToSkip) {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getGameStats(limit, rowsToSkip);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return new ArrayList<>();
}
public static List<GameStatsInfo> getGameStats(MagicDeck deck, int limit, int page) {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getGameStats(deck, limit, page);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return new ArrayList<>();
}
private static List<DeckStatsInfo> getMostPlayedDecks(int limit) {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getMostPlayedDecks(limit);
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return new ArrayList<>();
}
public static List<MagicDeck> getMostPlayedDecks() {
List<MagicDeck> decks = new ArrayList<>();
for (DeckStatsInfo info : getMostPlayedDecks(20)) {
MagicDeck deck = DeckUtils.loadDeckFromFile(
info.deckName, DeckType.valueOf(info.deckType)
);
if (DeckUtils.getDeckFileChecksum(deck) == info.deckCheckSum) {
decks.add(deck);
}
}
return decks;
}
public static String getSchemaVersion() {
if (CONFIG.isGameStatsEnabled()) {
try {
return getDB().getSchemaVersion();
} catch (Exception ex) {
HandleErrorDisableStats(ex);
}
}
return "";
}
}

View File

@ -0,0 +1,391 @@
package magic.data.stats.h2;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.util.ArrayList;
import java.util.List;
import java.util.logging.Level;
import java.util.logging.Logger;
import java.util.stream.Collectors;
import java.util.stream.IntStream;
import magic.data.stats.DeckStatsInfo;
import magic.data.stats.GameStatsInfo;
import magic.model.MagicDeck;
import magic.model.MagicGame;
import magic.model.MagicPlayer;
import magic.model.player.AiProfile;
import magic.model.player.PlayerProfile;
import magic.utility.DeckUtils;
import magic.utility.MagicSystem;
import org.h2.jdbcx.JdbcConnectionPool;
public class H2Database {
private static final Logger LOGGER = Logger.getLogger(H2Database.class.getName());
private final JdbcConnectionPool cpool;
static {
try {
Class.forName("org.h2.Driver");
} catch (ClassNotFoundException ex) {
LOGGER.log(Level.SEVERE, null, ex);
}
}
public H2Database() throws SQLException {
cpool = getConnectionPool();
applySchemaUpdates();
}
public static String getDatabaseFile() {
return MagicSystem.isDevMode() || MagicSystem.isTestGame()
? "./Magarena/stats/game-stats-dev"
: "./Magarena/stats/game-stats";
}
private JdbcConnectionPool getConnectionPool() {
// http://www.h2database.com/html/features.html#trace_options
String traceLevel = "TRACE_LEVEL_FILE=0"; // 0=OFF, 1=ERROR
return JdbcConnectionPool.create(
"jdbc:h2:file:" + getDatabaseFile() + ";" + traceLevel,
"sa", ""
);
}
private void applySchemaUpdates() throws SQLException {
try (Connection conn = getConnection()) {
H2Schema.applySchemaUpdates(conn);
}
}
public Connection getConnection() throws SQLException {
final Connection conn = cpool.getConnection();
conn.setAutoCommit(true);
return conn;
}
public Connection getReadOnlyConnection() throws SQLException {
final Connection conn = getConnection();
conn.setReadOnly(true);
return conn;
}
private String getRepeated(String s, int count, String delim) {
// http://stackoverflow.com/questions/1900477/can-one-initialise-a-java-string-with-a-single-repeated-character-to-a-specific
return IntStream.range(0, count)
.mapToObj(x -> s)
.collect(Collectors.joining(delim));
}
private int getDeckTypeId(Connection conn, MagicDeck deck) throws SQLException {
String SQL = "SELECT ID FROM DECK_TYPE WHERE NAME = ?";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setString(1, deck.getDeckType().name());
ResultSet rs = ps.executeQuery();
if (rs.next()) {
return rs.getInt(1);
}
}
SQL = "INSERT INTO DECK_TYPE (NAME) VALUES (?)";
try (PreparedStatement ps = conn.prepareStatement(SQL, new String[]{"ID"})) {
ps.setString(1, deck.getDeckType().name());
ps.executeUpdate();
ResultSet rs = ps.getGeneratedKeys();
if (rs.next()) {
return rs.getInt(1);
}
}
throw new SQLException("Unable to get DECK_TYPE ID value.");
}
private int getDeckId(Connection conn, MagicDeck deck) throws SQLException {
final int deckTypeId = getDeckTypeId(conn, deck);
String SQL = "SELECT ID FROM DECK "
+ "WHERE NAME = ? AND FILE_CHECKSUM = ? AND DECK_TYPE_ID = ?";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setString(1, deck.getName());
ps.setLong( 2, deck.getDeckFileChecksum());
ps.setInt( 3, deckTypeId);
ResultSet rs = ps.executeQuery();
if (rs.next()) {
return rs.getInt(1);
}
}
SQL = "INSERT INTO DECK (NAME, FILE_CHECKSUM, DECK_TYPE_ID, DECK_SIZE, DECK_COLOR) "
+ "VALUES (" + getRepeated("?", 5, ",") + ")";
try (PreparedStatement ps = conn.prepareStatement(SQL, new String[]{"ID"})) {
ps.setString( 1, deck.getName());
ps.setLong( 2, deck.getDeckFileChecksum());
ps.setInt( 3, deckTypeId);
ps.setInt( 4, deck.size());
ps.setString( 5, DeckUtils.getDeckColor(deck));
ps.executeUpdate();
ResultSet rs = ps.getGeneratedKeys();
if (rs.next()) {
return rs.getInt(1);
}
}
throw new SQLException("Unable to get DECK ID value.");
}
private int getAiPlayerId(Connection conn, AiProfile aiProfile) throws SQLException {
String SQL = "SELECT ID FROM PLAYER WHERE AI_TYPE = ? AND AI_LEVEL = ? AND AI_XLIFE = ?";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setString(1, aiProfile.getAiType().name());
ps.setInt(2, aiProfile.getAiLevel());
ps.setInt(3, aiProfile.getExtraLife());
ResultSet rs = ps.executeQuery();
if (rs.next()) {
return rs.getInt(1);
}
}
SQL = "INSERT INTO PLAYER (AI_TYPE, AI_LEVEL, AI_XLIFE) VALUES (?, ?, ?)";
try (PreparedStatement ps = conn.prepareStatement(SQL, new String[]{"ID"})) {
ps.setString(1, aiProfile.getAiType().name());
ps.setInt(2, aiProfile.getAiLevel());
ps.setInt(3, aiProfile.getExtraLife());
ps.executeUpdate();
ResultSet rs = ps.getGeneratedKeys();
if (rs.next()) {
return rs.getInt(1);
}
}
throw new SQLException("Unable to get PLAYER ID value.");
}
private int getHumanPlayerId(Connection conn, PlayerProfile profile) throws SQLException {
String SQL = "SELECT ID FROM PLAYER WHERE PLAYER_PROFILE = ?";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setString(1, profile.getId());
ResultSet rs = ps.executeQuery();
if (rs.next()) {
return rs.getInt(1);
}
}
SQL = "INSERT INTO PLAYER (PLAYER_PROFILE) VALUES (?)";
try (PreparedStatement ps = conn.prepareStatement(SQL, new String[]{"ID"})) {
ps.setString(1, profile.getId());
ps.executeUpdate();
ResultSet rs = ps.getGeneratedKeys();
if (rs.next()) {
return rs.getInt(1);
}
}
throw new SQLException("Unable to get PLAYER ID value.");
}
private int getPlayerId(Connection conn, MagicPlayer player) throws SQLException {
return player.isArtificial()
? getAiPlayerId(conn, player.getAiProfile())
: getHumanPlayerId(conn, player.getPlayerDefinition().getProfile());
}
public void logGameStats(MagicGame game) throws SQLException {
try (Connection conn = getConnection()) {
// updates should all succeed or none at all.
conn.setAutoCommit(false);
String SQL = "INSERT INTO GAME ("
+ "TIME_START, MAG_VERSION, WINNING_PLAYER_NUMBER, CONCEDED, TURNS, START_HAND, START_LIFE"
+ ") VALUES (" + getRepeated("?", 7, ",") + ")";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setLong( 1, game.getStartTimeMilli());
ps.setString( 2, MagicSystem.VERSION);
ps.setInt( 3, game.getWinner().equals(game.getPlayer(0)) ? 1 : 2);
ps.setBoolean( 4, game.isConceded());
ps.setInt( 5, game.getTurn());
ps.setInt( 6, game.getDuel().getConfiguration().getHandSize());
ps.setInt( 7, game.getDuel().getConfiguration().getStartLife());
ps.executeUpdate();
}
SQL = "INSERT INTO GAME_PLAYER ("
+ "GAME_TIME_START, PLAYER_NUMBER, PLAYER_ID, DECK_ID"
+ ") VALUES (" + getRepeated("?", 4, ",") + ")";
for (int i = 0; i < game.getPlayers().length; i++) {
MagicPlayer player = game.getPlayer(i);
MagicDeck deck = player.getPlayerDefinition().getDeck();
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setLong(1, game.getStartTimeMilli());
ps.setInt(2, i + 1);
ps.setInt(3, getPlayerId(conn, player));
ps.setInt(4, getDeckId(conn, deck));
ps.executeUpdate();
}
}
conn.commit();
}
}
public void close() {
cpool.dispose();
}
private int[] getPlayedWonLost(Connection conn, MagicDeck deck) throws SQLException {
String sql = "SELECT P, W, L "
+ "FROM DECK_GAME_PWL "
+ "WHERE DECK = ? AND DECK_CRC = ? AND DECK_TYPE = ?";
PreparedStatement ps = conn.prepareStatement(sql);
ps.setString(1, deck.getName());
ps.setLong(2, deck.getDeckFileChecksum());
ps.setString(3, deck.getDeckType().name());
int[] pwl = new int[3];
ResultSet rs = ps.executeQuery();
if (rs.next()) {
pwl[0] = rs.getInt(1);
pwl[1] = rs.getInt(2);
pwl[2] = rs.getInt(3);
}
return pwl;
}
public String getPlayedWonLost(MagicDeck deck) throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
int[] stats = getPlayedWonLost(conn, deck);
return stats[0] + " / " + stats[1] + " / " + stats[2];
}
}
public int getTotalGamesPlayed() throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
PreparedStatement ps = conn.prepareStatement(
"SELECT COUNT(1) FROM GAME",
ResultSet.TYPE_FORWARD_ONLY,
ResultSet.CONCUR_READ_ONLY
);
ResultSet rs = ps.executeQuery();
rs.next();
return rs.getInt(1);
}
}
public int getTotalGamesPlayed(MagicDeck deck) throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
return getPlayedWonLost(conn, deck)[0];
}
}
private GameStatsInfo getGameStatsDTO(ResultSet rs) throws SQLException {
final GameStatsInfo stats = new GameStatsInfo();
stats.timeStart = rs.getLong("TIME_START");
stats.magarenaVersion = rs.getString("MAG_VERSION");
stats.isConceded = rs.getBoolean("CONCEDED");
stats.player1AiLevel = rs.getInt("P1_AI_LEVEL");
stats.player1AiType = rs.getString("P1_AI_TYPE");
stats.player1AiXtraLife = rs.getInt("P1_AI_XLIFE");
stats.player1DeckColor = rs.getString("P1_DECK_COLOR");
stats.player1DeckFileChecksum = rs.getLong("P1_DECK_CRC");
stats.player1DeckName = rs.getString("P1_DECK");
stats.player1DeckSize = rs.getInt("P1_DECK_SIZE");
stats.player1DeckType = rs.getString("P1_DECK_TYPE");
stats.player1ProfileId = rs.getString("P1_PROFILE");
stats.player2AiLevel = rs.getInt("P2_AI_LEVEL");
stats.player2AiType = rs.getString("P2_AI_TYPE");
stats.player2AiXtraLife = rs.getInt("P2_AI_XLIFE");
stats.player2DeckColor = rs.getString("P2_DECK_COLOR");
stats.player2DeckFileChecksum = rs.getLong("P2_DECK_CRC");
stats.player2DeckName = rs.getString("P2_DECK");
stats.player2DeckSize = rs.getInt("P2_DECK_SIZE");
stats.player2DeckType = rs.getString("P2_DECK_TYPE");
stats.player2ProfileId = rs.getString("P2_PROFILE");
stats.startHandSize = rs.getInt("START_HAND");
stats.startLife = rs.getInt("START_LIFE");
stats.timeStart = rs.getLong("TIME_START");
stats.turns = rs.getInt("TURNS");
stats.winningPlayerProfile = rs.getString("WINNER");
return stats;
}
public List<GameStatsInfo> getGameStats(int limit, int rowsToSkip) throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
PreparedStatement ps1 = conn.prepareStatement(
"SELECT * FROM ALL_GAME_STATS "
+ "ORDER BY TIME_START DESC "
+ "LIMIT ? OFFSET ?",
ResultSet.TYPE_FORWARD_ONLY,
ResultSet.CONCUR_READ_ONLY
);
ps1.setInt(1, limit);
ps1.setInt(2, rowsToSkip);
ResultSet rs = ps1.executeQuery();
List<GameStatsInfo> games = new ArrayList<>();
while (rs.next()) {
games.add(getGameStatsDTO(rs));
}
return games;
}
}
public List<GameStatsInfo> getGameStats(MagicDeck deck, int limit, int page) throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
PreparedStatement ps1 = conn.prepareStatement(
"SELECT * "
+ "FROM ALL_GAME_STATS "
+ "WHERE (P1_DECK = ? AND P1_DECK_CRC = ?) "
+ "OR (P2_DECK = ? AND P2_DECK_CRC = ?) "
+ "ORDER BY TIME_START DESC "
+ "LIMIT ? OFFSET ?",
ResultSet.TYPE_FORWARD_ONLY,
ResultSet.CONCUR_READ_ONLY
);
ps1.setString(1, deck.getName());
ps1.setLong(2, deck.getDeckFileChecksum());
ps1.setString(3, deck.getName());
ps1.setLong(4, deck.getDeckFileChecksum());
ps1.setInt(5, limit);
ps1.setInt(6, page);
ResultSet rs = ps1.executeQuery();
List<GameStatsInfo> games = new ArrayList<>();
while (rs.next()) {
games.add(getGameStatsDTO(rs));
}
return games;
}
}
private DeckStatsInfo getNewDeckStatsInfo(ResultSet rs) throws SQLException {
final DeckStatsInfo info = new DeckStatsInfo();
info.deckName = rs.getString("DECK");
info.deckCheckSum = rs.getLong("DECK_CRC");
info.deckType = rs.getString("DECK_TYPE");
return info;
}
public List<DeckStatsInfo> getMostPlayedDecks(int limit) throws SQLException {
final List<DeckStatsInfo> decks = new ArrayList<>();
try (Connection conn = getReadOnlyConnection()) {
PreparedStatement ps1 = conn.prepareStatement(
"SELECT DECK, DECK_CRC, DECK_TYPE, P "
+ "FROM POPULAR_DECKS LIMIT ?",
ResultSet.TYPE_FORWARD_ONLY,
ResultSet.CONCUR_READ_ONLY
);
ps1.setInt(1, limit);
ResultSet rs = ps1.executeQuery();
while (rs.next()) {
decks.add(getNewDeckStatsInfo(rs));
}
}
return decks;
}
public String getSchemaVersion() throws SQLException {
try (Connection conn = getReadOnlyConnection()) {
String sql = "SELECT SCHEMA_VERSION FROM GAMESTATS_SETTINGS";
PreparedStatement ps = conn.prepareStatement(sql);
ResultSet rs = ps.executeQuery();
return rs.next() ? rs.getString(1) : "";
}
}
}

View File

@ -0,0 +1,62 @@
package magic.data.stats.h2;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import magic.utility.MagicResources;
import org.h2.tools.RunScript;
enum H2Schema {
/**
* Names of schema script files (minus the .sql extension).
*
* Schema scripts are stored in /resources/h2/stats/
*
* !! DO NOT CHANGE ORDER ONCE RELEASED !!
* Scripts are run in the order shown (ie. enum ordinal).
*
*/
schema_0 // initial schema.
;
private static H2Schema getCurrentSchema(Connection conn) throws SQLException {
String SQL = "SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'GAMESTATS_SETTINGS'";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ResultSet rs = ps.executeQuery();
if (rs.next() == false) {
return null;
}
}
SQL = "SELECT SCHEMA_VERSION FROM GAMESTATS_SETTINGS";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ResultSet rs = ps.executeQuery();
if (rs.next()) {
return H2Schema.valueOf(rs.getString(1));
} else {
return null;
}
}
}
static void applySchemaUpdates(Connection conn) throws SQLException {
conn.setAutoCommit(false);
H2Schema currentSchema = getCurrentSchema(conn);
int start = currentSchema == null ? 0 : currentSchema.ordinal() + 1;
for (int i = start; i < H2Schema.values().length; i++) {
H2Schema schema = H2Schema.values()[i];
RunScript.execute(conn, MagicResources.getH2ScriptFile(schema.name() + ".sql"));
String SQL = i == 0
? "INSERT INTO GAMESTATS_SETTINGS (SCHEMA_VERSION) VALUES (?)"
: "UPDATE GAMESTATS_SETTINGS SET SCHEMA_VERSION = ?";
try (PreparedStatement ps = conn.prepareStatement(SQL)) {
ps.setString(1, schema.name());
ps.executeUpdate();
}
conn.commit();
}
}
}

View File

@ -103,7 +103,7 @@ public class MagicDeck extends ArrayList<MagicCardDefinition> {
this.deckType = deckType;
}
long getDeckFileChecksum() {
public long getDeckFileChecksum() {
return deckFileChecksum;
}

View File

@ -6,14 +6,14 @@ import java.nio.file.Path;
import java.nio.file.Paths;
import java.util.Properties;
import magic.data.DeckGenerators;
import magic.utility.DeckUtils;
import magic.data.DuelConfig;
import magic.data.stats.MagicStats;
import magic.model.phase.MagicDefaultGameplay;
import magic.model.player.PlayerProfile;
import magic.utility.DeckUtils;
import magic.utility.FileIO;
import magic.utility.MagicFileSystem.DataPath;
import magic.utility.MagicFileSystem;
import magic.utility.MagicSystem;
import magic.utility.MagicFileSystem.DataPath;
import magic.utility.SortedProperties;
public class MagicDuel {
@ -97,10 +97,7 @@ public class MagicDuel {
startPlayer = playerIndex;
}
if (game.isReal() && !MagicSystem.isTestGame() && !MagicSystem.isAiVersusAi()) {
duelConfig.getPlayerProfile(0).getStats().update(won, game.getPlayer(0), game);
duelConfig.getPlayerProfile(1).getStats().update(!won, game.getPlayer(1), game);
}
MagicStats.logStats(this, game);
}
public MagicGame nextGame() {

View File

@ -1,5 +1,6 @@
package magic.model;
import java.time.Instant;
import java.util.ArrayList;
import java.util.Arrays;
import java.util.Collection;
@ -115,6 +116,8 @@ public class MagicGame {
private boolean hintPriority = true;
private boolean hintTarget = true;
private final long startTimeMilli = Instant.now().toEpochMilli();
public static MagicGame getInstance() {
return INSTANCE;
}
@ -915,6 +918,10 @@ public class MagicGame {
return losingPlayer;
}
public MagicPlayer getWinner() {
return players[0] == losingPlayer ? players[1] : players[0];
}
public MagicSource getActiveSource() {
return activeSource;
}
@ -1407,4 +1414,8 @@ public class MagicGame {
aSound.play();
}
}
public long getStartTimeMilli() {
return startTimeMilli;
}
}

View File

@ -33,6 +33,7 @@ class GeneralPanel extends JPanel {
private final PreferredSizePanel preferredSizePanel;
private final DirectoryChooser imagesFolderChooser;
private final MCheckBox imagesOnDemandCheckbox;
private final MCheckBox gameStatsCheckbox;
GeneralPanel(MouseListener aListener) {
@ -63,6 +64,11 @@ class GeneralPanel extends JPanel {
previewCardOnSelectCheckBox.setFocusable(false);
previewCardOnSelectCheckBox.addMouseListener(aListener);
gameStatsCheckbox = new MCheckBox(MText.get("Game statistics."), config.isGameStatsEnabled());
gameStatsCheckbox.setToolTipText(MText.get("Keeps detailed statistics of each game played which is used to generate P/W/L totals for each deck, adds a games history tab to the deck editor and new dynamically generated deck groups such as \"most played\", \"top winning\", etc. to the deck selection screen."));
gameStatsCheckbox.setFocusable(false);
gameStatsCheckbox.addMouseListener(aListener);
setLayout(new MigLayout("flowy, gapy 4, insets 16"));
// lang
@ -77,6 +83,8 @@ class GeneralPanel extends JPanel {
add(getCaptionLabel(MText.get(_S64)), "gaptop 10");
add(splitViewDeckEditorCheckBox.component());
add(previewCardOnSelectCheckBox.component());
//
add(gameStatsCheckbox.component(), "w 100%, gaptop 20");
}
void saveSettings() {
@ -86,6 +94,7 @@ class GeneralPanel extends JPanel {
config.setIsSplitViewDeckEditor(splitViewDeckEditorCheckBox.isSelected());
config.setPreviewCardOnSelect(previewCardOnSelectCheckBox.isSelected());
config.setImagesOnDemand(imagesOnDemandCheckbox.isSelected());
config.setGameStatsEnabled(gameStatsCheckbox.isSelected());
}
private JLabel getCaptionLabel(String text) {

View File

@ -294,6 +294,11 @@ public class DeckUtils {
return deck;
}
public static MagicDeck loadDeckFromFile(String name, DeckType deckType) {
Path deckPath = DeckType.getDeckFolder(deckType);
return loadDeckFromFile(deckPath.resolve(name + ".dec"));
}
public static void loadAndSetPlayerDeck(final String filename, final DuelPlayerConfig player) {
final MagicDeck deck = loadDeckFromFile(Paths.get(filename));
@ -329,7 +334,7 @@ public class DeckUtils {
/**
* Find up to 3 of the most common colors in the deck.
*/
private static String getDeckColor(final MagicDeck deck) {
public static String getDeckColor(final MagicDeck deck) {
final int[] colorCount = getDeckColorCount(deck);
final StringBuilder colorText = new StringBuilder();
while (colorText.length() < 3) {

View File

@ -2,6 +2,7 @@ package magic.utility;
import java.io.IOException;
import java.io.InputStream;
import java.io.InputStreamReader;
import java.net.URL;
import magic.data.GeneralConfig;
import magic.data.MagicIcon;
@ -61,4 +62,9 @@ public final class MagicResources {
return instance.getClass().getResource("/soundfx/" + filename);
}
public static InputStreamReader getH2ScriptFile(String filename) {
return new InputStreamReader(
getJarResourceStream("/h2/stats/" + filename)
);
}
}

View File

@ -19,6 +19,7 @@ import magic.data.DeckGenerators;
import magic.data.GeneralConfig;
import magic.data.MagicCustomFormat;
import magic.data.UnimplementedParser;
import magic.data.stats.MagicStats;
import magic.model.MagicGameLog;
import magic.utility.MagicFileSystem.DataPath;
@ -202,15 +203,13 @@ final public class MagicSystem {
reporter.setMessage("Initializing log...");
MagicGameLog.initialize();
// start a separate thread to load cards
// Queue up tasks to run synchronously on a single background thread.
final ExecutorService background = Executors.newSingleThreadExecutor();
if (GeneralConfig.getInstance().isGameStatsEnabled()) {
background.execute(() -> { MagicStats.init(); });
}
background.execute(loadCards);
background.execute(new Runnable() {
@Override
public void run() {
CardDefinitions.postCardDefinitions();
}
});
background.execute(() -> { CardDefinitions.postCardDefinitions(); });
background.execute(loadMissing);
background.shutdown();