import decodeMsgpack from './decodeMsgpack.js' import { execMany } from './helper.js' import { sqlite } from './init.js' import { mapToRegion, playerServer } from './wrapper.js' /** * This generates rankings for each map... * @module libs/database/processRankings */ export function processRankings() { const maps = sqlite.prepare(`SELECT * FROM maps`) for (const map of maps.iterate()) sqlite .prepare(` INSERT INTO rankings ( map, category, points, player, time, date, rank, server, finishes ) SELECT a.map, b.category, b.points, a.player, a.time, a.date, a.rank, a.server, a.finishes FROM ( SELECT rank() OVER w AS rank, map, date, player, min(time) AS time, server, COUNT(*) AS finishes FROM race as a WHERE map = ? GROUP BY player window w AS (ORDER BY time) ) AS a JOIN maps as b ON a.map = b.map ORDER BY rank `) .run(map.map) } /** * This generates teamrankings for each map... * @module libs/database/processTeamRankings */ export function processTeamRankings() { const maps = sqlite.prepare(`SELECT map FROM maps`) for (const map of maps.iterate()) sqlite .prepare(` INSERT INTO teamrankings ( player, map, id, time, date, server, teamrank, category, points ) SELECT DISTINCT(r.player), r.map, r.id, r.time, r.date, Substring(n.server, 1, 3), dense_rank() OVER w AS rank, a.category, a.points FROM (( SELECT DISTINCT id FROM teamrace WHERE map = ? ORDER BY time) AS l ) LEFT JOIN teamrace AS r ON l.id = r.id INNER JOIN race AS n ON r.map = n.map AND r.player = n.player AND r.time = n.time JOIN maps as a ON r.map = a.map window w AS (ORDER BY r.time) `) .run(map.map) } /** * This generates a cache for all the dates the top record has been improved for each map... * @module libs/database/processTimeGraph */ export function processTimeGraph() { const maps = sqlite.prepare(`SELECT map FROM maps`) const finishes = sqlite.prepare(`SELECT * FROM race WHERE map = ? ORDER BY date`) for (const map of maps.iterate()) { let currentFinish let currentBest = 0 for (const record of finishes.iterate(map.map)) { currentFinish = record.time if (currentFinish <= currentBest || currentBest == 0) { currentBest = currentFinish sqlite.prepare(` INSERT INTO "graphRecordCache" ( map, player, time, date, server ) VALUES (?, ?, ?, ?, ?) `).run( map.map, record.player, record.time, record.date, record.server ) } } } } /** * This generates a fancy map table containing more data such total finishes, median time. * @module libs/database/processMaps */ export function processMaps() { const maps = sqlite.prepare(`SELECT map FROM oldmaps`) const finishes = sqlite.prepare(`SELECT * FROM race WHERE map = ? ORDER BY date`) for (const map of maps.iterate()) { const info = sqlite.prepare(`SELECT * FROM oldmaps WHERE map = ?`).get(map.map) const avgTime = sqlite.prepare(`SELECT avg(time) AS avgTime FROM race WHERE map = ?`).get(map.map)?.avgTime ?? -1 const medianTime = sqlite.prepare(`SELECT median(time) as medianTime FROM race WHERE map = ?`).get(map.map)?.medianTime ?? -1 const teams = sqlite.prepare(`SELECT COUNT(distinct(id)) AS 'teams' FROM teamrace WHERE map = ?`).get(map.map)?.teams ?? -1 const topTeamTime = sqlite.prepare(`SELECT time as topTeamTime FROM teamrankings WHERE map = ? ORDER BY Time ASC LIMIT 1`).get(map.map)?.topTeamTime ?? -1 const topTime = sqlite.prepare(`SELECT time as topTime FROM rankings WHERE map = ? ORDER BY Time ASC LIMIT 1`).get(map.map)?.topTime ?? -1 const total = sqlite.prepare(`SELECT COUNT(*) AS 'total' FROM race WHERE map = ?`).get(map.map)?.total ?? -1 const unique = sqlite.prepare(`SELECT COUNT(distinct(player)) AS 'unique' FROM race WHERE map = ?`).get(map.map)?.unique ?? -1 sqlite.prepare(` INSERT INTO "maps" ( map, category, points, stars, mapper, release, avgTime, medianTime, topTime, topTeamTime, finishesUnique, finishesTotal, finishesTeam ) VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?) `).run( info.map, info.category, info.points, info.stars, info.mapper, info.release, avgTime, medianTime, topTime, topTeamTime, unique, total, teams, ) } } /** * This inserts all types of points into a table... * @module db/processAllPoints */ export function processAllPoints() { const msgpack = decodeMsgpack() const types = { points: msgpack.pointsRanks, pointsThisWeek: msgpack.pointsThisWeek, pointsThisMonth: msgpack.pointsThisMonth, pointsTeam: msgpack.teamRankPoints, pointsRank: msgpack.rankPoints, } /* Generate tables */ sqlite.exec(` CREATE TABLE IF NOT EXISTS "points" ( "type" varchar(16) NOT NULL, "region" varchar(24) NOT NULL, "rank" INTEGER NOT NULL, "player" varchar(16) NOT NULL, "points" INTEGER NOT NULL ) `) /* Insert data */ for (const type in types) { let rank = 1 for (const entry of types[type]) { sqlite .prepare(` INSERT INTO "points" ( type, region, rank, player, points ) VALUES (?, ?, ?, ?, ?) `) .run( type, mapToRegion(playerServer(entry[0])), rank, entry[0], entry[1] ) ++rank } console.log(`${type} Done...`) } /* Generate indexes */ execMany([ `CREATE INDEX IF NOT EXISTS "idx_points_type" ON "points" ("type")`, `CREATE INDEX IF NOT EXISTS "idx_points_rank" on "points" ("rank")`, `CREATE INDEX IF NOT EXISTS "idx_points_name" on "points" ("player")`, `CREATE INDEX IF NOT EXISTS "idx_points_regionPoints" on "points" ("region", "type")` ]) } export default { processAllPoints, processRankings, processTeamRankings, processMaps, processTimeGraph }