Skip to content

Commit

Permalink
Merge pull request #306 from alyssaruth/team-reporting
Browse files Browse the repository at this point in the history
Team reporting
  • Loading branch information
alyssaruth authored Mar 5, 2024
2 parents e33d351 + 48df42f commit a1b0d43
Show file tree
Hide file tree
Showing 10 changed files with 240 additions and 40 deletions.
5 changes: 2 additions & 3 deletions src/main/kotlin/dartzee/achievements/AchievementSqlUtil.kt
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ import dartzee.game.GameType
import dartzee.`object`.SegmentType
import dartzee.utils.Database
import dartzee.utils.getQuotedIdStr
import dartzee.utils.isNullStatement
import java.sql.ResultSet

const val X01_ROUNDS_TABLE = "X01Rounds"
Expand Down Expand Up @@ -119,9 +120,7 @@ fun buildQualifyingDartzeeGamesTable(database: Database): String? {

val sb = StringBuilder()
sb.append(" INSERT INTO $dartzeeGames")
sb.append(
" SELECT g.RowId, COUNT(1) + 1, CASE WHEN dt.Name IS NULL THEN '' ELSE dt.Name END AS TemplateName"
)
sb.append(" SELECT g.RowId, COUNT(1) + 1, ${isNullStatement("dt.Name", "''", "TemplateName")}")
sb.append(" FROM ${EntityName.DartzeeRule} dr, ${EntityName.Game} g")
sb.append(" LEFT OUTER JOIN ${EntityName.DartzeeTemplate} dt ON (g.GameParams = dt.RowId)")
sb.append(" WHERE dr.EntityId = g.RowId")
Expand Down
3 changes: 2 additions & 1 deletion src/main/kotlin/dartzee/db/AchievementEntity.kt
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@ import dartzee.core.util.getSqlDateNow
import dartzee.screen.ScreenCache
import dartzee.utils.Database
import dartzee.utils.InjectedThings.mainDatabase
import dartzee.utils.isNullStatement
import java.sql.Timestamp

/**
Expand Down Expand Up @@ -50,7 +51,7 @@ class AchievementEntity(database: Database = mainDatabase) :

val sb = StringBuilder()
sb.append("SELECT ${dao.getColumnsForSelectStatement("a")}, ")
sb.append(" CASE WHEN g.LocalId IS NULL THEN -1 ELSE g.LocalId END AS LocalGameId")
sb.append(isNullStatement("g.LocalId", "-1", "LocalGameId"))
sb.append(" FROM Achievement a")
sb.append(" LEFT OUTER JOIN Game g ON (a.GameIdEarned = g.RowId)")
sb.append(" WHERE PlayerId = '$playerId'")
Expand Down
12 changes: 9 additions & 3 deletions src/main/kotlin/dartzee/reporting/ParticipantWrapper.kt
Original file line number Diff line number Diff line change
@@ -1,8 +1,14 @@
package dartzee.reporting

/** Lightweight wrapper object to represent a participant Used in reporting */
class ParticipantWrapper(private val playerName: String, val finishingPosition: Int) {
/** Lightweight wrapper object to represent a participant used in reporting */
class ParticipantWrapper(
var playerName: String,
val finishingPosition: Int,
private val resigned: Boolean,
val teamId: String?
) {
override fun toString() = "$playerName (${getPositionDesc()})"

private fun getPositionDesc() = if (finishingPosition == -1) "-" else "$finishingPosition"
private fun getPositionDesc() =
if (resigned) "R" else if (finishingPosition == -1) "-" else "$finishingPosition"
}
8 changes: 4 additions & 4 deletions src/main/kotlin/dartzee/reporting/ReportParameters.kt
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ import dartzee.utils.InjectedThings.mainDatabase

data class ReportParameters(val game: ReportParametersGame, val players: ReportParametersPlayers) {

fun getExtraWhereSql(): String {
fun getExtraWhereSql(participantTempTable: String): String {
val sb = StringBuilder()

if (game.gameType != null) {
Expand Down Expand Up @@ -72,7 +72,7 @@ data class ReportParameters(val game: ReportParametersGame, val players: ReportP
val parms = entry.value

sb.append(" AND EXISTS (")
sb.append(" SELECT 1 FROM Participant z")
sb.append(" SELECT 1 FROM $participantTempTable z")
sb.append(" WHERE z.PlayerId = '${player.rowId}'")
sb.append(" AND z.GameId = g.RowId")

Expand All @@ -84,14 +84,14 @@ data class ReportParameters(val game: ReportParametersGame, val players: ReportP

for (player in players.excludedPlayers) {
sb.append(" AND NOT EXISTS (")
sb.append(" SELECT 1 FROM Participant z")
sb.append(" SELECT 1 FROM $participantTempTable z")
sb.append(" WHERE z.PlayerId = '${player.rowId}'")
sb.append(" AND z.GameId = g.RowId)")
}

if (players.excludeOnlyAi) {
sb.append(" AND EXISTS (")
sb.append(" SELECT 1 FROM Participant z, Player p")
sb.append(" SELECT 1 FROM $participantTempTable z, Player p")
sb.append(" WHERE z.PlayerId = p.RowId")
sb.append(" AND z.GameId = g.RowId")
sb.append(" AND p.Strategy = '')")
Expand Down
98 changes: 77 additions & 21 deletions src/main/kotlin/dartzee/reporting/ReportingUtil.kt
Original file line number Diff line number Diff line change
@@ -1,7 +1,9 @@
package dartzee.reporting

import dartzee.db.EntityName
import dartzee.game.GameType
import dartzee.utils.InjectedThings.mainDatabase
import dartzee.utils.isNullStatement
import java.sql.ResultSet
import java.sql.Timestamp
import javax.swing.JCheckBox
Expand All @@ -12,8 +14,11 @@ fun <T> grabIfSelected(checkbox: JCheckBox, getter: () -> T) =
fun runReport(rp: ReportParameters?): List<ReportResultWrapper> {
rp ?: return emptyList()

var sql = buildBasicSqlStatement()
sql += rp.getExtraWhereSql()
val ptTemp = makeParticipantTempTable() ?: return emptyList()

var sql = buildBasicSqlStatement(ptTemp)
sql += rp.getExtraWhereSql(ptTemp)
sql += "\n ORDER BY LocalId, TeamOrdinal, Ordinal"

val hm = mutableMapOf<Long, ReportResultWrapper>()
mainDatabase.executeQuery(sql).use { rs ->
Expand All @@ -28,23 +33,69 @@ fun runReport(rp: ReportParameters?): List<ReportResultWrapper> {
return hm.values.toList()
}

fun buildBasicSqlStatement(): String {
val sb = StringBuilder()
sb.append(
"SELECT g.RowId, g.LocalId, g.GameType, g.GameParams, g.DtCreation, g.DtFinish, p.Name, pt.FinishingPosition, g.DartsMatchId, g.MatchOrdinal, dt.Name AS TemplateName,"
)
sb.append(" CASE WHEN m.LocalId IS NULL THEN -1 ELSE m.LocalId END AS LocalMatchId")
sb.append(" FROM Participant pt, Player p, Game g")
sb.append(" LEFT OUTER JOIN DartsMatch m ON (g.DartsMatchId = m.RowId)")
sb.append(
" LEFT OUTER JOIN DartzeeTemplate dt ON (g.GameType = '${GameType.DARTZEE}' AND g.GameParams = dt.RowId)"
private fun makeParticipantTempTable(): String? {
val tempTable =
mainDatabase.createTempTable(
"reportParticipants",
"GameId VARCHAR(36), PlayerId VARCHAR(36), FinishingPosition INT, FinalScore INT, " +
"TeamId VARCHAR(36), Resigned BOOLEAN, TeamOrdinal INT, Ordinal INT"
) ?: return null

mainDatabase.executeUpdate(
"""
INSERT INTO
$tempTable
SELECT
pt.GameId,
pt.PlayerId,
${isNullStatement("t.FinishingPosition", "pt.FinishingPosition", "FinishingPosition")},
${isNullStatement("t.FinalScore", "pt.FinalScore", "FinalScore")},
pt.TeamId,
${isNullStatement("t.Resigned", "pt.Resigned", "Resigned")},
${isNullStatement("t.Ordinal", "99", "TeamOrdinal")},
pt.Ordinal
FROM
${EntityName.Participant} pt LEFT OUTER JOIN ${EntityName.Team} t ON (pt.TeamId = t.RowId)
"""
.trimIndent()
)
sb.append(" WHERE pt.GameId = g.RowId")
sb.append(" AND pt.PlayerId = p.RowId")

return sb.toString()
mainDatabase.executeUpdate("CREATE INDEX ${tempTable}_GameId ON $tempTable(GameId)")

return tempTable
}

private fun buildBasicSqlStatement(ptTempTable: String) =
"""
SELECT
g.RowId,
g.LocalId,
g.GameType,
g.GameParams,
g.DtCreation,
g.DtFinish,
p.Name,
pt.FinishingPosition,
pt.Resigned,
pt.TeamId,
g.DartsMatchId,
g.MatchOrdinal,
dt.Name AS TemplateName,
${isNullStatement("m.LocalId", "-1", "LocalMatchId")}
FROM
$ptTempTable pt,
${EntityName.Player} p,
${EntityName.Game} g
LEFT OUTER JOIN
${EntityName.DartsMatch} m ON (g.DartsMatchId = m.RowId)
LEFT OUTER JOIN
${EntityName.DartzeeTemplate} dt ON (g.GameType = '${GameType.DARTZEE}' AND g.GameParams = dt.RowId)
WHERE
pt.GameId = g.RowId
AND pt.PlayerId = p.RowId
"""
.trimIndent()

data class ReportResultWrapper(
val localId: Long,
val gameType: GameType,
Expand All @@ -70,15 +121,20 @@ data class ReportResultWrapper(
return arrayOf(localId, gameTypeDesc, playerDesc, dtStart, dtFinish, matchDesc)
}

private fun getPlayerDesc(): String {
participants.sortBy { it.finishingPosition }
return participants.joinToString()
}
private fun getPlayerDesc() = participants.joinToString()

fun addParticipant(rs: ResultSet) {
val playerName = rs.getString("Name")
val finishPos = rs.getInt("FinishingPosition")
participants.add(ParticipantWrapper(playerName, finishPos))
val resigned = rs.getBoolean("Resigned")
val teamId = rs.getString("TeamId")

val existing = if (teamId.isNotEmpty()) participants.find { it.teamId == teamId } else null
if (existing != null) {
existing.playerName = "${existing.playerName} & $playerName"
} else {
participants.add(ParticipantWrapper(playerName, finishPos, resigned, teamId))
}
}

companion object {
Expand All @@ -99,7 +155,7 @@ data class ReportResultWrapper(
dtFinish,
localMatchId,
matchOrdinal,
templateName
templateName,
)
}

Expand Down
3 changes: 3 additions & 0 deletions src/main/kotlin/dartzee/utils/SqlUtil.kt
Original file line number Diff line number Diff line change
Expand Up @@ -4,3 +4,6 @@ fun List<String>.getQuotedIdStr() = getQuotedIdStr { it }

fun <T : Any> List<T>.getQuotedIdStr(fieldSelector: (obj: T) -> String) =
"(${joinToString { "'${fieldSelector(it)}'" } })"

fun isNullStatement(thingToCheck: String, fallback: String, columnName: String) =
"CASE WHEN $thingToCheck IS NULL THEN $fallback ELSE $thingToCheck END AS $columnName"
39 changes: 39 additions & 0 deletions src/test/kotlin/dartzee/helper/InMemoryDatabaseHelper.kt
Original file line number Diff line number Diff line change
Expand Up @@ -203,6 +203,45 @@ fun insertParticipant(
return pe
}

fun insertTeamAndParticipants(
gameId: String = randomGuid(),
ordinal: Int = 1,
finishingPosition: Int = -1,
finalScore: Int = -1,
dtFinished: Timestamp = DateStatics.END_OF_TIME,
playerOne: PlayerEntity = insertPlayer(),
playerTwo: PlayerEntity = insertPlayer(),
database: Database = mainDatabase
): TeamEntity {
val t =
insertTeam(
gameId = gameId,
ordinal = ordinal,
finishingPosition = finishingPosition,
finalScore = finalScore,
dtFinished = dtFinished,
database = database
)

insertParticipant(
gameId = gameId,
playerId = playerOne.rowId,
teamId = t.rowId,
ordinal = 0,
database = database
)

insertParticipant(
gameId = gameId,
playerId = playerTwo.rowId,
teamId = t.rowId,
ordinal = 1,
database = database
)

return t
}

fun insertTeam(
uuid: String = randomGuid(),
gameId: String = randomGuid(),
Expand Down
7 changes: 4 additions & 3 deletions src/test/kotlin/dartzee/reporting/TestParticipantWrapper.kt
Original file line number Diff line number Diff line change
Expand Up @@ -7,8 +7,9 @@ import org.junit.jupiter.api.Test
class TestParticipantWrapper : AbstractTest() {
@Test
fun `Should describe the player and their position correctly`() {
ParticipantWrapper("Alice", 3).toString() shouldBe "Alice (3)"
ParticipantWrapper("Bob", 6).toString() shouldBe "Bob (6)"
ParticipantWrapper("Clive", -1).toString() shouldBe "Clive (-)"
ParticipantWrapper("Alice", 3, false, "").toString() shouldBe "Alice (3)"
ParticipantWrapper("Bob", 6, false, "").toString() shouldBe "Bob (6)"
ParticipantWrapper("Clive", -1, false, "").toString() shouldBe "Clive (-)"
ParticipantWrapper("Daisy", 5, true, "").toString() shouldBe "Daisy (R)"
}
}
49 changes: 49 additions & 0 deletions src/test/kotlin/dartzee/reporting/TestReportParameters.kt
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ import dartzee.helper.insertGame
import dartzee.helper.insertGameForReport
import dartzee.helper.insertParticipant
import dartzee.helper.insertPlayerForGame
import dartzee.helper.insertTeamAndParticipants
import dartzee.helper.makeIncludedPlayerParameters
import dartzee.helper.makeReportParametersGame
import dartzee.helper.makeReportParametersPlayers
Expand Down Expand Up @@ -250,6 +251,54 @@ class TestReportParameters : AbstractTest() {
resultsAliceAndBob.shouldContainExactly(gAllPlayers.localId, gAliceAndBob.localId)
}

@Test
fun `Should account for teams when restricting to specific players`() {
val gAllPlayers = insertGame()
val alice = insertPlayerForGame("Alice", gAllPlayers.rowId)
val bob = insertPlayerForGame("Bob", gAllPlayers.rowId)
val clive = insertPlayerForGame("Clive", gAllPlayers.rowId)
val daisy = insertPlayerForGame("Daisy", gAllPlayers.rowId)

val gAliceAndBob = insertGame()
insertTeamAndParticipants(gameId = gAliceAndBob.rowId, playerOne = alice, playerTwo = bob)

val gAliceCliveDaisy = insertGame()
insertTeamAndParticipants(
gameId = gAliceCliveDaisy.rowId,
playerOne = alice,
playerTwo = clive
)
insertParticipant(playerId = daisy.rowId, gameId = gAliceCliveDaisy.rowId)

val gBobAndDaisy = insertGame()
insertTeamAndParticipants(gameId = gBobAndDaisy.rowId, playerOne = bob, playerTwo = daisy)

val gCliveDaisy = insertGame()
insertTeamAndParticipants(gameId = gCliveDaisy.rowId, playerOne = clive, playerTwo = daisy)

val rpIncludeAlice =
makeReportParametersPlayers(
includedPlayers = mapOf(alice to makeIncludedPlayerParameters())
)
val resultsAlice = runReportForTest(player = rpIncludeAlice)
resultsAlice.shouldContainExactlyInAnyOrder(
gAllPlayers.localId,
gAliceAndBob.localId,
gAliceCliveDaisy.localId
)

val rpIncludeAliceAndBob =
makeReportParametersPlayers(
includedPlayers =
mapOf(
alice to makeIncludedPlayerParameters(),
bob to makeIncludedPlayerParameters()
)
)
val resultsAliceAndBob = runReportForTest(player = rpIncludeAliceAndBob)
resultsAliceAndBob.shouldContainExactly(gAllPlayers.localId, gAliceAndBob.localId)
}

@Test
fun `Should only include games with at least one human player if specified`() {
val gAllPlayers = insertGame()
Expand Down
Loading

0 comments on commit a1b0d43

Please sign in to comment.