Add LiveStatistics table
parent
797714618f
commit
6cf621f156
|
@ -7,7 +7,8 @@ import kotlinx.coroutines.*
|
||||||
import kotlinx.serialization.*
|
import kotlinx.serialization.*
|
||||||
import kotlinx.serialization.json.Json
|
import kotlinx.serialization.json.Json
|
||||||
import org.jetbrains.exposed.sql.*
|
import org.jetbrains.exposed.sql.*
|
||||||
import org.jetbrains.exposed.sql.transactions.transaction
|
import org.jetbrains.exposed.sql.transactions.*
|
||||||
|
import xyz.etztech.stonks.dsl.LiveStatistics
|
||||||
import xyz.etztech.stonks.dsl.Statistics
|
import xyz.etztech.stonks.dsl.Statistics
|
||||||
|
|
||||||
private var statisticsCache = ""
|
private var statisticsCache = ""
|
||||||
|
@ -22,26 +23,6 @@ fun initApiServer(apiServerPort: Int, database: Database) {
|
||||||
val app = Javalin.create().start(apiServerPort)
|
val app = Javalin.create().start(apiServerPort)
|
||||||
println("Javalin web server started")
|
println("Javalin web server started")
|
||||||
|
|
||||||
app.get("/") { ctx ->
|
|
||||||
run {
|
|
||||||
transaction(database) {
|
|
||||||
addLogger(StdOutSqlLogger)
|
|
||||||
val dataPoints =
|
|
||||||
Statistics.slice(Statistics.playerId.count()).selectAll().limit(1).map {
|
|
||||||
it[Statistics.playerId.count()]
|
|
||||||
}[0]
|
|
||||||
|
|
||||||
val playerCount =
|
|
||||||
Statistics.slice(Statistics.playerId.countDistinct())
|
|
||||||
.selectAll()
|
|
||||||
.limit(1)
|
|
||||||
.map { it[Statistics.playerId.countDistinct()] }[0]
|
|
||||||
|
|
||||||
ctx.result("$dataPoints data points from $playerCount players!")
|
|
||||||
}
|
|
||||||
}
|
|
||||||
}
|
|
||||||
|
|
||||||
app.get("/statistics") { ctx ->
|
app.get("/statistics") { ctx ->
|
||||||
run {
|
run {
|
||||||
if (statisticsCache.isEmpty() or
|
if (statisticsCache.isEmpty() or
|
||||||
|
@ -51,10 +32,12 @@ fun initApiServer(apiServerPort: Int, database: Database) {
|
||||||
addLogger(StdOutSqlLogger)
|
addLogger(StdOutSqlLogger)
|
||||||
|
|
||||||
val statistics =
|
val statistics =
|
||||||
Statistics.slice(Statistics.type, Statistics.name)
|
LiveStatistics.slice(LiveStatistics.type, LiveStatistics.name)
|
||||||
.selectAll()
|
.selectAll()
|
||||||
.groupBy(Statistics.type, Statistics.name)
|
.groupBy(LiveStatistics.type, LiveStatistics.name)
|
||||||
.map { Statistic(it[Statistics.type], it[Statistics.name]) }
|
.map {
|
||||||
|
Statistic(it[LiveStatistics.type], it[LiveStatistics.name])
|
||||||
|
}
|
||||||
|
|
||||||
statisticsCache = Json.encodeToString(statistics)
|
statisticsCache = Json.encodeToString(statistics)
|
||||||
}
|
}
|
||||||
|
@ -68,26 +51,25 @@ fun initApiServer(apiServerPort: Int, database: Database) {
|
||||||
run {
|
run {
|
||||||
transaction(database) {
|
transaction(database) {
|
||||||
addLogger(StdOutSqlLogger)
|
addLogger(StdOutSqlLogger)
|
||||||
val maxExpr = Statistics.value.max()
|
|
||||||
|
|
||||||
val statistics =
|
val statistics =
|
||||||
Statistics.slice(
|
LiveStatistics.slice(
|
||||||
Statistics.type,
|
LiveStatistics.type,
|
||||||
Statistics.name,
|
LiveStatistics.name,
|
||||||
Statistics.playerId,
|
LiveStatistics.playerId,
|
||||||
maxExpr)
|
LiveStatistics.value,
|
||||||
|
LiveStatistics.rank)
|
||||||
.select {
|
.select {
|
||||||
Statistics.type.eq(ctx.pathParam("type")) and
|
LiveStatistics.type.eq(ctx.pathParam("type")) and
|
||||||
Statistics.name.eq(ctx.pathParam("name"))
|
LiveStatistics.name.eq(ctx.pathParam("name"))
|
||||||
}
|
}
|
||||||
.groupBy(Statistics.playerId)
|
.orderBy(LiveStatistics.rank, SortOrder.ASC)
|
||||||
.orderBy(maxExpr, SortOrder.DESC)
|
|
||||||
.map {
|
.map {
|
||||||
StatisticValue(
|
StatisticValue(
|
||||||
it[Statistics.playerId],
|
it[LiveStatistics.playerId],
|
||||||
it[Statistics.type],
|
it[LiveStatistics.type],
|
||||||
it[Statistics.name],
|
it[LiveStatistics.name],
|
||||||
it[maxExpr]!!)
|
it[LiveStatistics.value],
|
||||||
|
it[LiveStatistics.rank])
|
||||||
}
|
}
|
||||||
|
|
||||||
ctx.result(Json { prettyPrint = true }.encodeToString(statistics))
|
ctx.result(Json { prettyPrint = true }.encodeToString(statistics))
|
||||||
|
@ -104,10 +86,10 @@ fun initApiServer(apiServerPort: Int, database: Database) {
|
||||||
addLogger(StdOutSqlLogger)
|
addLogger(StdOutSqlLogger)
|
||||||
|
|
||||||
val players =
|
val players =
|
||||||
Statistics.slice(Statistics.playerId)
|
LiveStatistics.slice(LiveStatistics.playerId)
|
||||||
.selectAll()
|
.selectAll()
|
||||||
.groupBy(Statistics.playerId)
|
.groupBy(LiveStatistics.playerId)
|
||||||
.map { it[Statistics.playerId] }
|
.map { it[LiveStatistics.playerId] }
|
||||||
playersCache = Json.encodeToString(players)
|
playersCache = Json.encodeToString(players)
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
@ -120,22 +102,22 @@ fun initApiServer(apiServerPort: Int, database: Database) {
|
||||||
run {
|
run {
|
||||||
transaction(database) {
|
transaction(database) {
|
||||||
addLogger(StdOutSqlLogger)
|
addLogger(StdOutSqlLogger)
|
||||||
val maxExpr = Statistics.value.max()
|
|
||||||
|
|
||||||
val statistics =
|
val statistics =
|
||||||
Statistics.slice(
|
LiveStatistics.slice(
|
||||||
Statistics.type,
|
LiveStatistics.type,
|
||||||
Statistics.name,
|
LiveStatistics.name,
|
||||||
Statistics.playerId,
|
LiveStatistics.playerId,
|
||||||
maxExpr)
|
LiveStatistics.value,
|
||||||
.select { Statistics.playerId.eq(ctx.pathParam("playerId")) }
|
LiveStatistics.rank)
|
||||||
.groupBy(Statistics.type, Statistics.name)
|
.select { LiveStatistics.playerId.eq(ctx.pathParam("playerId")) }
|
||||||
.map {
|
.map {
|
||||||
StatisticValue(
|
StatisticValue(
|
||||||
it[Statistics.playerId],
|
it[LiveStatistics.playerId],
|
||||||
it[Statistics.type],
|
it[LiveStatistics.type],
|
||||||
it[Statistics.name],
|
it[LiveStatistics.name],
|
||||||
it[maxExpr]!!)
|
it[LiveStatistics.value],
|
||||||
|
it[LiveStatistics.rank])
|
||||||
}
|
}
|
||||||
|
|
||||||
ctx.result(Json { prettyPrint = true }.encodeToString(statistics))
|
ctx.result(Json { prettyPrint = true }.encodeToString(statistics))
|
||||||
|
@ -182,7 +164,8 @@ data class StatisticValue(
|
||||||
val playerId: String,
|
val playerId: String,
|
||||||
val type: String,
|
val type: String,
|
||||||
val name: String,
|
val name: String,
|
||||||
val value: Long
|
val value: Long,
|
||||||
|
val rank: Int
|
||||||
)
|
)
|
||||||
|
|
||||||
@Serializable
|
@Serializable
|
||||||
|
|
|
@ -10,6 +10,7 @@ import org.jetbrains.exposed.sql.*
|
||||||
import org.jetbrains.exposed.sql.transactions.TransactionManager
|
import org.jetbrains.exposed.sql.transactions.TransactionManager
|
||||||
import org.jetbrains.exposed.sql.transactions.transaction
|
import org.jetbrains.exposed.sql.transactions.transaction
|
||||||
import xyz.etztech.stonks.api.initApiServer
|
import xyz.etztech.stonks.api.initApiServer
|
||||||
|
import xyz.etztech.stonks.dsl.LiveStatistics
|
||||||
import xyz.etztech.stonks.dsl.Statistics
|
import xyz.etztech.stonks.dsl.Statistics
|
||||||
import xyz.etztech.stonks.statisticsimporter.StatisticsImporter
|
import xyz.etztech.stonks.statisticsimporter.StatisticsImporter
|
||||||
|
|
||||||
|
@ -76,6 +77,7 @@ fun initH2Server(
|
||||||
transaction {
|
transaction {
|
||||||
addLogger(StdOutSqlLogger)
|
addLogger(StdOutSqlLogger)
|
||||||
SchemaUtils.create(Statistics)
|
SchemaUtils.create(Statistics)
|
||||||
|
SchemaUtils.create(LiveStatistics)
|
||||||
|
|
||||||
// Create indexes with explicit SQL because I can't figure out how to do it with exposed
|
// Create indexes with explicit SQL because I can't figure out how to do it with exposed
|
||||||
// Wrap it in a try block because it throws an exception if index already exists
|
// Wrap it in a try block because it throws an exception if index already exists
|
||||||
|
@ -88,6 +90,16 @@ fun initH2Server(
|
||||||
TransactionManager.current()
|
TransactionManager.current()
|
||||||
.exec("CREATE INDEX idx_type_name ON Statistics (\"Type\", \"Name\")")
|
.exec("CREATE INDEX idx_type_name ON Statistics (\"Type\", \"Name\")")
|
||||||
} catch (e: ExposedSQLException) {}
|
} catch (e: ExposedSQLException) {}
|
||||||
|
|
||||||
|
try {
|
||||||
|
TransactionManager.current()
|
||||||
|
.exec("CREATE INDEX idx_playerid ON LiveStatistics (\"PlayerId\")")
|
||||||
|
} catch (e: ExposedSQLException) {}
|
||||||
|
|
||||||
|
try {
|
||||||
|
TransactionManager.current()
|
||||||
|
.exec("CREATE INDEX idx_type_name ON LiveStatistics (\"Type\", \"Name\")")
|
||||||
|
} catch (e: ExposedSQLException) {}
|
||||||
}
|
}
|
||||||
|
|
||||||
return database
|
return database
|
||||||
|
|
|
@ -4,6 +4,16 @@ import java.time.Instant
|
||||||
import org.jetbrains.exposed.sql.*
|
import org.jetbrains.exposed.sql.*
|
||||||
import org.jetbrains.exposed.sql.`java-time`.timestamp
|
import org.jetbrains.exposed.sql.`java-time`.timestamp
|
||||||
|
|
||||||
|
object LiveStatistics : Table() {
|
||||||
|
val playerId: Column<String> = varchar("PlayerId", 150)
|
||||||
|
val type: Column<String> = varchar("Type", 150)
|
||||||
|
val name: Column<String> = varchar("Name", 150)
|
||||||
|
val value: Column<Long> = long("Value")
|
||||||
|
val rank: Column<Int> = integer("Rank")
|
||||||
|
|
||||||
|
override val primaryKey = PrimaryKey(playerId, type, name, name = "PK_playerId_type_name")
|
||||||
|
}
|
||||||
|
|
||||||
object Statistics : Table() {
|
object Statistics : Table() {
|
||||||
val playerId: Column<String> = varchar("PlayerId", 150)
|
val playerId: Column<String> = varchar("PlayerId", 150)
|
||||||
val type: Column<String> = varchar("Type", 150)
|
val type: Column<String> = varchar("Type", 150)
|
||||||
|
|
|
@ -6,6 +6,7 @@ import java.io.File
|
||||||
import java.time.Instant
|
import java.time.Instant
|
||||||
import org.jetbrains.exposed.sql.*
|
import org.jetbrains.exposed.sql.*
|
||||||
import org.jetbrains.exposed.sql.`java-time`.timestamp
|
import org.jetbrains.exposed.sql.`java-time`.timestamp
|
||||||
|
import org.jetbrains.exposed.sql.transactions.TransactionManager
|
||||||
import org.jetbrains.exposed.sql.transactions.transaction
|
import org.jetbrains.exposed.sql.transactions.transaction
|
||||||
import xyz.etztech.stonks.dsl.Statistics
|
import xyz.etztech.stonks.dsl.Statistics
|
||||||
|
|
||||||
|
@ -15,7 +16,10 @@ object StatisticsImporter {
|
||||||
private val klaxon = Klaxon()
|
private val klaxon = Klaxon()
|
||||||
|
|
||||||
fun importStatistics(folder: String, database: Database) {
|
fun importStatistics(folder: String, database: Database) {
|
||||||
|
println("Importing new statistics...")
|
||||||
File(folder).listFiles().forEach { readFile(it, database) }
|
File(folder).listFiles().forEach { readFile(it, database) }
|
||||||
|
println("Updating live statistics table...")
|
||||||
|
updateLiveStatistics(database)
|
||||||
}
|
}
|
||||||
|
|
||||||
fun readFile(file: File, database: Database) {
|
fun readFile(file: File, database: Database) {
|
||||||
|
@ -58,6 +62,48 @@ object StatisticsImporter {
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
fun updateLiveStatistics(database: Database) {
|
||||||
|
transaction(database) {
|
||||||
|
TransactionManager.current()
|
||||||
|
.exec(
|
||||||
|
"""
|
||||||
|
MERGE INTO LIVESTATISTICS AS T USING (
|
||||||
|
SELECT
|
||||||
|
STATISTICS."Type",
|
||||||
|
STATISTICS."Name",
|
||||||
|
STATISTICS."PlayerId",
|
||||||
|
STATISTICS."Value",
|
||||||
|
(RANK () OVER (PARTITION BY STATISTICS."Type", STATISTICS."Name" ORDER BY STATISTICS."Value" DESC)) AS "Rank"
|
||||||
|
FROM
|
||||||
|
STATISTICS
|
||||||
|
JOIN (
|
||||||
|
SELECT
|
||||||
|
"Type",
|
||||||
|
"Name",
|
||||||
|
"PlayerId",
|
||||||
|
MAX("Timestamp") AS "MaxTimestamp",
|
||||||
|
FROM STATISTICS
|
||||||
|
GROUP BY
|
||||||
|
"Type",
|
||||||
|
"Name",
|
||||||
|
"PlayerId"
|
||||||
|
) MAX_TIMESTAMPS
|
||||||
|
ON
|
||||||
|
STATISTICS."Type" = MAX_TIMESTAMPS."Type"
|
||||||
|
AND STATISTICS."Name" = MAX_TIMESTAMPS."Name"
|
||||||
|
AND STATISTICS."PlayerId" = MAX_TIMESTAMPS."PlayerId"
|
||||||
|
AND STATISTICS."Timestamp" = MAX_TIMESTAMPS."MaxTimestamp"
|
||||||
|
) AS S
|
||||||
|
ON (T."Type" = S."Type" AND T."Name" = S."Name" AND T."PlayerId" = S."PlayerId")
|
||||||
|
|
||||||
|
WHEN MATCHED AND (S."Value" <> T."Value" OR S."Rank" <> T."Rank")THEN
|
||||||
|
UPDATE SET T."Value" = S."Value", T."Rank" = S."Rank"
|
||||||
|
WHEN NOT MATCHED THEN
|
||||||
|
INSERT VALUES (S."PlayerId", S."Type", S."Name", S."Value", S."Rank")
|
||||||
|
""".trimIndent())
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
data class StatsFile(val stats: Map<String, Map<String, Long>>) {
|
data class StatsFile(val stats: Map<String, Map<String, Long>>) {
|
||||||
companion object {
|
companion object {
|
||||||
public fun fromJson(json: String) = klaxon.parse<StatsFile>(json)
|
public fun fromJson(json: String) = klaxon.parse<StatsFile>(json)
|
||||||
|
|
Loading…
Reference in New Issue