diff --git a/.gitignore b/.gitignore index 2f85b69..d3fed47 100644 --- a/.gitignore +++ b/.gitignore @@ -119,5 +119,5 @@ dist package-lock.json pnpm-lock.yaml +.env data/* -.env \ No newline at end of file diff --git a/api/api.js b/api/api.js new file mode 100644 index 0000000..17fc8f5 --- /dev/null +++ b/api/api.js @@ -0,0 +1,26 @@ +import { Router } from 'express' +import playerApi from './players.js' +import mapApi from './maps.js' +import finishesApi from './finishes.js' +import graphApi from './graph.js' + +const api = Router() + +api.get( + '/', + (req, res) => res.json({ + success: true, + response: "You connected to DDStats API! :D" + }) +) + +api.use('/players', playerApi) +api.use('/maps', mapApi) +api.use('/finishes', finishesApi) +api.use('/graph', graphApi) + +/** + * This module is the entrypoint for the API. + * @module api/api + */ +export default api \ No newline at end of file diff --git a/api/finishes.js b/api/finishes.js new file mode 100644 index 0000000..f339806 --- /dev/null +++ b/api/finishes.js @@ -0,0 +1,59 @@ +import { Router } from 'express' +import { sqlite } from '../libs/database/init.js' +import wrapper from '../libs/database/wrapper.js' + +const finishApi = Router() + +/* TODO: precalculate this */ +finishApi.get( + '/count', + (req, res) => { + const finishes = sqlite.prepare(`SELECT COUNT(*) as count FROM race`).get() + + return res.json({ + success: true, + response: finishes.count, + }) + } +) + +finishApi.get( + '/finishedMaps/:player', + (req, res) => { + /* Check if player exists */ + if(!wrapper.playerExists(req.params.player)) { + return res.json({ + success: false, + response: "No such player!" + }) + } + const finishes = wrapper.finishedMaps(req.params.player) + + return res.json({ + success: true, + response: finishes, + }) + } +) + +finishApi.get( + '/unfinishedMaps/:player', + (req, res) => { + /* Check if player exists */ + if(!wrapper.playerExists(req.params.player)) { + return res.json({ + success: false, + response: "No such player!" + }) + } + const finishes = wrapper.unfinishedMaps(req.params.player) + + return res.json({ + success: true, + response: finishes, + }) + } +) + + +export default finishApi \ No newline at end of file diff --git a/api/graph.js b/api/graph.js new file mode 100644 index 0000000..8e72a39 --- /dev/null +++ b/api/graph.js @@ -0,0 +1,66 @@ +import { Router } from 'express' +import { sqlite } from '../libs/database/init.js' + +const graphApi = Router() + +graphApi.get( + '/points', + (req, res) => { + /* Check if a query was provided */ + if (!req.query.q) { + return res.json({ + success: false, + response: "No query ('host/path?q=query') provided!" + }) + } + let player = req.query.q + + const finishes = sqlite.prepare( + ` + SELECT DISTINCT(a.map), a.date, b.points + FROM race AS a + INNER JOIN maps AS b + ON a.map = b.map + WHERE a.player = ? + GROUP BY a.map + ORDER BY a.date; + `) + let currentPoints = 0 + let array = [] + + for (const finish of finishes.iterate(player)) { + currentPoints += finish.points + array.push({ t: new Date(finish.date), y: currentPoints }) + } + + return res.json({ + success: true, + response: array, + }) + } +) + +graphApi.get( + '/map', + (req, res) => { + /* Check if a query was provided */ + if (!req.query.q) { + return res.json({ + success: false, + response: "No query ('host/path?q=query') provided!" + }) + } + const finishes = sqlite.prepare(`SELECT * FROM graphRecordCache WHERE map = ? ORDER BY date`) + + let array = [] + for (const record of finishes.iterate(req.query.q)) + array.push({ t: new Date(record.date), y: record.time, player: record.player}) + + return res.json({ + success: true, + response: array, + }) + } +) + +export default graphApi \ No newline at end of file diff --git a/api/maps.js b/api/maps.js new file mode 100644 index 0000000..d2ebceb --- /dev/null +++ b/api/maps.js @@ -0,0 +1,115 @@ +import { Router } from 'express' +import { sqlite } from '../libs/database/init.js' +import wrapper, { map } from '../libs/database/wrapper.js' + +const mapApi = Router() + +mapApi.get( + '/count', + (req, res) => { + const totalMaps = sqlite.prepare(`SELECT COUNT(*) as count FROM maps`).get() + + return res.json({ + success: true, + response: totalMaps.count, + }) + } +) + +mapApi.get( + '/get/:map', + (req, res) => { + /* Check if map exists */ + if(!wrapper.mapExists(req.params.map)) { + return res.json({ + success: false, + response: "No such map!" + }) + } + + return res.json({ + success: true, + response: map(req.params.map) + }) + } +) + +mapApi.get( + '/getAll', + (req, res) => { + return res.json({ + success: true, + response: wrapper.allMaps() + }) + } +) + +mapApi.get( + '/category/:category', + (req, res) => { + /* Check if category exists */ + if (!wrapper.categoryExists(req.params.category)) { + return res.json({ + success: false, + response: "Invalid category name!", + }) + } + + return res.json({ + success: true, + response: wrapper.mapCategory(req.params.category) + }) + } +) + +mapApi.get( + '/leaderboard/race/:map', + (req, res) => { + /* Check if map exists */ + if (!wrapper.mapExists(req.params.map)) { + return res.json({ + success: false, + response: "No such map!", + }) + } + + return res.json({ + success: true, + response: wrapper.leaderboardRace(req.params.map, 1, 20) + }) + } +) + +mapApi.get( + '/leaderboard/teamrace/:map', + (req, res) => { + /* Check if map exists */ + if (!wrapper.mapExists(req.params.map)) { + return res.json({ + success: false, + response: "No such map!", + }) + } + + return res.json({ + success: true, + response: wrapper.leaderboardTeamrace(req.params.map, 1, 20) + }) + } +) + +mapApi.get( + '/search', + async (req, res) => { + /* Check if a query was provided */ + if (!req.query.q) { + return res.json({ + success: false, + response: "No query ('host/path?q=query') provided!" + }) + } + /* TODO: Use the searcher function */ + } +) + +export default mapApi diff --git a/api/players.js b/api/players.js new file mode 100644 index 0000000..6bf13cf --- /dev/null +++ b/api/players.js @@ -0,0 +1,57 @@ +import { Router } from 'express' +import wrapper from '../libs/database/wrapper.js' + +const playerApi = Router() + +playerApi.get( + '/get/:player', + async (req, res) => { + /* Check if player exists */ + if(!wrapper.playerExists(req.params.player)) { + return res.json({ + success: false, + response: "No such player!" + }) + } + const data = wrapper.player(req.params.player) + + return res.json({ + success: true, + response: data + }) + } +) + +playerApi.get( + '/search', + async (req, res) => { + if (!req.query.q) { + return res.json({ + success: false, + response: "No query ('?q=query') provided!" + }) + } + + searcher( + 'points', + 'player', + `%${req.query.q}%`, + req.query.sort ?? undefined, + req.query.order === "asc", + "all", + req.query.page + ).then( + player => res.json({ + success: true, + response: player + }) + ).catch( + error => res.json({ + success: false, + response: error + }) + ) + } +) + +export default playerApi diff --git a/index.js b/index.js index 1754e61..8389b21 100644 --- a/index.js +++ b/index.js @@ -31,4 +31,4 @@ njk.configure( Server.use('/', routes) Server.use('/assets', express.static('static')) -Server.listen(process.env.PORT ?? 12345, () => log(`Server started and listening on port ${process.env.PORT}.`)) \ No newline at end of file +Server.listen(process.env.PORT ?? 12345, () => log(`Server started and listening on port ${process.env.PORT}.`)) diff --git a/libs/database/decodeMsgpack.js b/libs/database/decodeMsgpack.js new file mode 100644 index 0000000..47f1a8b --- /dev/null +++ b/libs/database/decodeMsgpack.js @@ -0,0 +1,21 @@ +import msgpack from '@msgpack/msgpack' +import fs from 'fs' + + +/** + * This module parses the msgpack provided by DDNet... + * @module db/decodeMsgpack + */ +export default function decodeMsgpack() { + const data = fs.readFileSync(process.env.MSGPACK_PATH ?? 'data/players.msgpack') + const decoded = msgpack.decodeMulti(data, { wrap: true }) + const order = ['categories', 'maps', 'totalPoints', 'pointsRanks', 'pointsThisWeek', 'pointsThisMonth', 'teamRankPoints', 'rankPoints', 'serverRanks'] + let final = {} + + let i = 0 + for (const part of decoded) { + final[order[i]] = part + ++i + } + return final +} diff --git a/libs/database/generate.js b/libs/database/generate.js new file mode 100644 index 0000000..0293681 --- /dev/null +++ b/libs/database/generate.js @@ -0,0 +1,184 @@ +import { sqlite, skinDB } from './init.js' +import tasks from './tasks.js' +import { execMany } from './helper.js' +import initLog from '../utils/log.js' + +const log = initLog("DB Generation") + +/** + * This constructs the DB with indexes and rankings... + * @module db/generateDB + */ +export function generateDB() { + if (process.env.GENERATE_DB !== "true") + return log("Won't generate the database since 'GENERATE_DB' is not set to \"true\" in '.env'!") + + const exists = sqlite.prepare(`SELECT count(*) as a FROM sqlite_master WHERE type='table' AND name='points'`).get() + if(!exists.a === 0) + return log("Database already generated!") + + /* Check if columns are already renamed */ + const renamed = sqlite.prepare(`SELECT COUNT(*) AS a FROM pragma_table_info('race') WHERE name='date'`).get() + + if(renamed.a === 0) { + log("Renaming columns...") + execMany([ + `ALTER TABLE race RENAME COLUMN Map TO map`, + `ALTER TABLE race RENAME COLUMN Name TO player`, + `ALTER TABLE race RENAME COLUMN Time TO time`, + `ALTER TABLE race RENAME COLUMN Timestamp TO date`, + `ALTER TABLE race RENAME COLUMN Server TO server`, + + `ALTER TABLE teamrace RENAME COLUMN Map TO map`, + `ALTER TABLE teamrace RENAME COLUMN Name TO player`, + `ALTER TABLE teamrace RENAME COLUMN Time TO time`, + `ALTER TABLE teamrace RENAME COLUMN ID TO id`, + `ALTER TABLE teamrace RENAME COLUMN Timestamp TO date`, + + `ALTER TABLE maps RENAME COLUMN Map TO map`, + `ALTER TABLE maps RENAME COLUMN Server TO category`, + `ALTER TABLE maps RENAME COLUMN Points TO points`, + `ALTER TABLE maps RENAME COLUMN Stars TO stars`, + `ALTER TABLE maps RENAME COLUMN Mapper TO mapper`, + `ALTER TABLE maps RENAME COLUMN Timestamp TO release` + ]) + } + + log("Generating race index...") + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_race_player" ON "race" ("player")`, + `CREATE INDEX IF NOT EXISTS "idx_race_name" ON "race" ("player", "date")`, + `CREATE INDEX IF NOT EXISTS "idx_race_server" ON "race" ("server")`, + `CREATE INDEX IF NOT EXISTS "idx_race_mapTimestamp" ON "race" ("map", "date")`, + `CREATE INDEX IF NOT EXISTS "idx_race_timestamp" ON "race" ("date")`, + `CREATE INDEX IF NOT EXISTS "idx_race_mapNameTime" ON "race" ("map", "player", "time")` + ]) + + log("Creating rankings table...") + sqlite.exec(` + CREATE TABLE IF NOT EXISTS "rankings" ( + "category" varchar(32) NOT NULL, + "points" integer NOT NULL DEFAULT 0, + "map" varchar(128) NOT NULL, + "player" varchar(16) NOT NULL, + "time" float NOT NULL DEFAULT 0, + "date" timestamp NOT NULL DEFAULT current_timestamp, + "server" char(4) NOT NULL DEFAULT '', + "rank" INTEGER NOT NULL, + "finishes" INTEGER NOT NULL DEFAULT 0 + ) + `) + + log("Calculating rankings for each map...") + tasks.processRankings() + + log("Generating rankings index...") + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_rankings_map" ON "rankings" ("map")`, + `CREATE INDEX IF NOT EXISTS "idx_rankings_rank" ON "rankings" ("rank")`, + `CREATE INDEX IF NOT EXISTS "idx_rankings_player" ON "rankings" ("player")`, + `CREATE INDEX IF NOT EXISTS "idx_rankings_finishes" ON "rankings" ("finishes")`, + `CREATE INDEX IF NOT EXISTS "idx_rankings_mapRank" ON "rankings" ("map", "rank")` + ]) + + log("Generating teamrace index...") + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_teamrace_map" ON "teamrace" ("map")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrace_id" ON "teamrace" ("id")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrace_mapID" ON "teamrace" ("map", "id")` + ]) + + log("Creating teamrankings table...") + sqlite.exec(` + CREATE TABLE IF NOT EXISTS "teamrankings" ( + "category" varchar(32) NOT NULL, + "points" integer NOT NULL DEFAULT 0, + "map" varchar(128) NOT NULL, + "id" varbinary(16) NOT NULL, + "player" varchar(16) NOT NULL, + "time" float NOT NULL DEFAULT 0, + "date" timestamp NOT NULL DEFAULT current_timestamp, + "server" char(4) NOT NULL DEFAULT '', + "teamrank" INTEGER NOT NULL + ) + `) + + log("Calculating teamrankings for each map...") + tasks.processTeamRankings() + + log("Generating teamrankings index...") + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_teamrankings_map" ON "teamrankings" ("map")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrankings_rank" ON "teamrankings" ("teamrank")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrankings_player" ON "teamrankings" ("player")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrankings_playerCategoryMap" ON "teamrankings" ("player", "category", "map")`, + `CREATE INDEX IF NOT EXISTS "idx_teamrankings_mapTeamrank" ON "teamrankings" ("map", "teamrank")` + ]) + + log("Generating graphRecordCache...") + sqlite.exec(` + CREATE TABLE IF NOT EXISTS "graphRecordCache" ( + "map" varchar(128) NOT NULL, + "player" varchar(16) NOT NULL, + "time" float NOT NULL DEFAULT 0, + "date" timestamp NOT NULL DEFAULT current_timestamp, + "server" char(4) NOT NULL DEFAULT '' + ) + `) + tasks.processTimeGraph() + + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_graphCache_player" ON "graphRecordCache" ("player")`, + `CREATE INDEX IF NOT EXISTS "idx_graphCache_map" ON "graphRecordCache" ("map")` + ]) + + log("Inserting points to DB...") + tasks.processAllPoints() + + log("Generating a new maps table...") + /* Rename the old one as we wanna use that name for the new one*/ + sqlite.exec(`ALTER TABLE maps RENAME TO oldmaps`) + + sqlite.exec(` + CREATE TABLE IF NOT EXISTS "maps" ( + "map" varchar(128) NOT NULL, + "category" varchar(32) NOT NULL, + "points" integer NOT NULL DEFAULT 0, + "stars" integer NOT NULL DEFAULT 0, + "mapper" char(128) NOT NULL, + "release" timestamp NOT NULL DEFAULT current_timestamp, + + "avgTime" FLOAT NOT NULL DEFAULT 0, + "medianTime" FLOAT NOT NULL DEFAULT 0, + "topTime" FLOAT NOT NULL DEFAULT 0, + "topTeamTime" FLOAT NOT NULL DEFAULT 0, + "finishesUnique" INTEGER NOT NULL DEFAULT 0, + "finishesTotal" INTEGER NOT NULL DEFAULT 0, + "finishesTeam" INTEGER NOT NULL DEFAULT 0 + ) + `) + tasks.processMaps() + + log("Generating map index...") + execMany([ + `CREATE INDEX IF NOT EXISTS "idx_maps_map" ON "maps" ("map")`, + `CREATE INDEX IF NOT EXISTS "idx_maps_category" ON "maps" ("category")` + `CREATE INDEX IF NOT EXISTS "idx_maps_categoryMap" ON "maps" ("category", "map")` + ]) + + + skinDB.exec(` + CREATE TABLE IF NOT EXISTS "skindata" ( + "timestamp" INTEGER NOT NULL, + "player" varchar(16) NOT NULL, + "clan" varchar(12) NOT NULL, + "flag" INTEGER NOT NULL, + "skin" varchar(16) NOT NULL, + "useColor" INTEGER NOT NULL, + "colorBodyRaw" INTEGER NOT NULL, + "colorBodyHex" varchar(8) NOT NULL, + "colorFeetRaw" INTEGER NOT NULL, + "colorFeetHex" varchar(8) NOT NULL + ) + `) +} diff --git a/libs/database/helper.js b/libs/database/helper.js new file mode 100644 index 0000000..1565b68 --- /dev/null +++ b/libs/database/helper.js @@ -0,0 +1,12 @@ +import { sqlite } from './init.js' + +/** + * This function takes an array of strings to be ran on the DB. + * + * @param {[string]} instructions Array of instructions to be ran. + * @author BurnyLlama + */ +export function execMany(instructions) { + for (const instruction of instructions) + sqlite.exec(instruction) +} \ No newline at end of file diff --git a/libs/database/init.js b/libs/database/init.js index c52cdf5..84f2098 100644 --- a/libs/database/init.js +++ b/libs/database/init.js @@ -1,35 +1,32 @@ +import Database from 'better-sqlite3' import initLog from '../utils/log.js' -import mongoose from 'mongoose' -import sqlite3 from 'sqlite3' -import { open } from 'sqlite' - -const log = initLog("database") +/* Export DB for use in other files */ export let sqlite = undefined +export let skinDB = undefined + +const log = initLog("Database") /** - * This initializes both the sqlite db and mongodb. - * @module libs/database/init + * This initalizes the ddnet.sqlite and skindata.sqlite DB... + * @module db/dbInit */ -async function init() { +export function dbInit() { log("Starting up databases...") - sqlite = await open({ - filename: 'ddnet.sqlite', - driver: sqlite3.cached.Database - }) + /* load in db using better-sqlite3 */ + sqlite = new Database(process.env.DDNET_SQLITE_PATH ?? 'data/ddnet.sqlite', { verbose: console.log }); + skinDB = new Database(process.env.DDNSS_SQLITE_PATH ?? 'data/skindata.sqlite', { }); + + /* WAL mode */ + sqlite.pragma('journal_mode = WAL'); + + /* Unsafe mode */ + sqlite.unsafeMode() + + /* Load external extensions */ + sqlite.loadExtension('./math-func.so') + log("Loaded in 'ddnet.sqlite'!") - - - await mongoose.connect( - process.env.MONGO_URI, - { - useNewUrlParser: true, - useUnifiedTopology: true - } - ) - - log("Connected to mongodb!") + log("Loaded in 'skindata.sqlite'!") } - -export default init \ No newline at end of file diff --git a/libs/database/searcher.js b/libs/database/searcher.js new file mode 100644 index 0000000..1102150 --- /dev/null +++ b/libs/database/searcher.js @@ -0,0 +1,65 @@ +import { sqlite } from './init.js' + +const entriesPerPage = process.env.ENTRIES_PER_PAGE ?? 50 + +function simpleSanitize(str) { + return String(str).replace(/\s/g, "") +} + +/** + * This is a 'general' search function for the sqlite database... + * + * @param {string} table The table to search in. + * @param {string} matchField If not 'undefined' or 'null' match 'matchQuery' in this field. + * @param {string} matchQuery The value to search for in 'matchField'. + * @param {string} orderBy The field of which to order by, if 'null' or 'undefined' it is whatever sqlite sees as default. + * @param {boolean} descending If true: sort in ascending order instead of ascending order. + * @param {string} method If set to "all" it will give all results instead of only one. + * @param {number} page The function paginates; this sets the page to look for. + * + * @returns {Promise} Returns a promise which wither resolves with the data or rejects with an error. + * + * @author BurnyLlama + */ +export default function searcher(table, matchField=undefined, matchQuery=undefined, orderBy=undefined, descending=false, method="get", page=1) { + return new Promise( + (resolve, reject) => { + const pageCount = + method === "get" ? 0 : + Math.ceil( + sqlite + .prepare(` + SELECT count(*) FROM ${simpleSanitize(table)} + ${matchField ? `WHERE ${simpleSanitize(matchField)} LIKE $matchQuery` : ""} + `) + .get({ + matchQuery + })['count(*)'] + / entriesPerPage + ) + + if (method === "all" && page > pageCount) + reject(`Page number too high! Page count: ${pageCount}`) + + const result = sqlite + .prepare(` + SELECT * FROM ${simpleSanitize(table)} + ${matchField ? `WHERE ${simpleSanitize(matchField)} LIKE $matchQuery` : ""} + ${orderBy ? `ORDER BY ${simpleSanitize(orderBy)} ${descending === true ? "DESC" : "ASC"}` : ""} + ${method === "all" ? `LIMIT ${entriesPerPage * (page - 1)}, ${entriesPerPage}` : ""} + `) + [method === "all" ? "all" : "get"]({ + matchQuery + }) + + // This check should work? + if ((typeof result === "object" && !result[0]) || (!result)) + reject("No search results found!") + + resolve({ + result, + pageCount + }) + } + ) +} \ No newline at end of file diff --git a/libs/database/tasks.js b/libs/database/tasks.js new file mode 100644 index 0000000..71e6e2f --- /dev/null +++ b/libs/database/tasks.js @@ -0,0 +1,209 @@ +import decodeMsgpack from './decodeMsgpack.js' +import { execMany } from './helper.js' +import { sqlite } from './init.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, + "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, rank, player, points + ) VALUES (?, ?, ?, ?) + `) + .run( + type, + rank, + entry[0], + entry[1] + ) + + ++rank + } + } + + /* 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")` + ]) +} + +export default { + processAllPoints, + processRankings, + processTeamRankings, + processMaps, + processTimeGraph +} \ No newline at end of file diff --git a/libs/database/wrapper.js b/libs/database/wrapper.js new file mode 100644 index 0000000..06c2cce --- /dev/null +++ b/libs/database/wrapper.js @@ -0,0 +1,335 @@ +import { sqlite } from './init.js' + +/** + * This function checks if a player exists + * + * @param {string} player The player to check + + * @returns {boolean} Returns a boolean + */ +export function playerExists(player) { + const exists = sqlite.prepare(`SELECT * FROM points WHERE player = ? LIMIT 1`).get(player) + + if(exists) + return true + else + return false +} + +/** + * This function checks if a map exists + * + * @param {string} player The map to check + + * @returns {boolean} Returns a boolean + */ +export function mapExists(map) { + const exists = sqlite.prepare(`SELECT * FROM maps WHERE map = ? LIMIT 1`).get(map) + + if(exists) + return true + else + return false +} + +/** + * This function checks if a map category exists + * + * @param {string} player The category to check + + * @returns {boolean} Returns a boolean + */ + export function categoryExists(category) { + const exists = sqlite.prepare(`SELECT category FROM maps WHERE category = ? LIMIT 1`).get(category) + + if(exists) + return true + else + return false +} + +/** + * This function returns all data pertaining a certain player + * + * @param {string} player The player to fetch + + * @returns {object} An object containing the players data + */ +export function player(player) { + /* Misc */ + const firstFinish = sqlite.prepare(`SELECT map, time, date, server FROM race WHERE player = ? ORDER BY date ASC LIMIT 1`).get(player) + + /* Points */ + let points = {} + let rank = {} + + const pointsData = sqlite.prepare(`SELECT * FROM points WHERE player = ?`) + + for (const pointsType of pointsData.iterate(player)) { + rank[pointsType.type] = pointsType.rank + } + for (const pointsType of pointsData.iterate(player)) { + points[pointsType.type] = pointsType.points + } + + return { + player, + firstFinish, + points, + rank, + } +} + +/** + * This function returns all data pertaining a certain map + * + * @param {string} map The map to fetch + + * @returns {object} An object containing map data + */ +export function map(map) { + const a = sqlite.prepare(` + SELECT * FROM maps WHERE map = ? + `).get(map) + + return prettyifyMap(a) +} + +export function mapCategory(category) { + let output = [] + const maps = sqlite.prepare(` + SELECT * FROM maps WHERE category = ?`).all(category) + + for(const map of maps) { + output.push(prettyifyMap(map)) + } + return output +} + +/** + * This function returns all data pertaining to all maps + + * @returns {array} An array contaning all map objects + */ +export function allMaps() { + let output = [] + const maps = sqlite.prepare(` + SELECT * FROM maps`).all() + + for(const map of maps) { + output.push(prettyifyMap(map)) + } + return output +} + +/** + * This function returns all data pertaining a certain map + * + * @param {string} map The map to fetch + + * @returns {object} An object containing map data + */ + export function prettyifyMap(a) { + let output + + output = { + map: a.map, + category: a.category, + points: a.points, + stars: a.stars, + release: a.release, + mappers: a.mapper.split(" & "), + + times: { + average: a.avgTime, + median: a.medianTime, + topTime: a.topTime, + topTimeTeam: (a.topTeamTime != -1) ? a.topTeamTime : undefined, + }, + finishes: { + total: a.finishesTotal, + team: a.finishesTeam, + unique: a.finishesUnique, + } + } + + return output +} + +/** + * This function returns the race leaderboard for a map + * + * @param {string} map The map to check + * @param {number} start At which rank the leaderboard should begin + * @param {number} end At which rank the leaderboard should end + + * @returns {array} An array containing the leaderboard + */ +export function leaderboardRace(map, start, end) { + const leaderboard = sqlite.prepare(` + SELECT rank, time, date, player, server FROM rankings WHERE map = ? AND rank >= ? AND rank <= ?`) + .all(map, start, end) + + return leaderboard +} + +/** + * This function returns the teamrace leaderboard for a map + * + * @param {string} map The map to check + * @param {number} start At which rank the leaderboard should begin + * @param {number} end At which rank the leaderboard should end + + * @returns {array} An array containing the leaderboard + */ + export function leaderboardTeamrace(map, start, end) { + // TODO: Optimize array creation of players + let leaderboard = [] + + const a = sqlite.prepare(` + SELECT teamrank, time, date, player, server FROM teamrankings WHERE map = ? AND teamrank >= ? AND teamrank <= ? GROUP BY teamrank`) + + for(const teamrank of a.iterate(map, start, end)) { + let players = [] + const b = sqlite.prepare(`SELECT player FROM teamrankings WHERE map = ? AND teamrank = ?`) + + for(const player of b.iterate(map, teamrank.teamrank)) { + players.push(player.player) + } + leaderboard.push({ + teamrank: teamrank.teamrank, + time: teamrank.time, + date: teamrank.date, + server: teamrank.server, + players: players, + }) + } + return leaderboard +} + +/** + * This function returns the points leaderboard for a specific type + * (points, pointsRank, pointsTeam, pointsThisWeek, pointsThisMonth) + * + * @param {string} type Which type of points to fetch + * @param {number} start At which rank the leaderboard should begin + * @param {number} end At which rank the leaderboard should end + + * @returns {array} An array containing the leaderboard + */ +export function leaderboardPoints(map, start, end) { + const leaderboard = sqlite.prepare(` + SELECT rank, player, points FROM points WHERE type = ? AND rank >= ? AND rank <= ? ORDER BY rank`) + .all(type, start, end) + + return leaderboard +} + +/** + * This function returns all finished maps by a specific player + * togheter with their respective rank, teamrank, amount of finishes. + * Finishes are grouped by map category (Novice, Brutal) + * + * @param {string} player The player to check + + * @returns {object} An object containing all finishes grouped by category + */ +export function finishedMaps(player) { + const finishesStmt = sqlite.prepare( + ` + SELECT a.map, + a.category, + a.points, + a.rank, + b.teamrank, + a.finishes + FROM rankings AS a + LEFT OUTER JOIN teamrankings AS b + ON a.player = b.player + AND a.category = b.category + AND a.map = b.map + WHERE a.player = ? + `) + + let finishes = { + Novice: [], + Moderate: [], + Brutal: [], + Insane: [], + Dummy: [], + DDmaX: [], + Oldschool: [], + Solo: [], + Race: [], + Fun: [] + } + for (const finish of finishesStmt.iterate(player)) { + finishes[finish.category].push(finish) + } + + return finishes +} + +/** + * This function returns all unfinished maps by a specific player + * togheter with category, points, finishTotal and medianTime. + * Maps are grouped by the map category (Novice, Brutal) + * + * @param {string} player The player to check + + * @returns {object} An object containing all unfinished maps + */ + export function unfinishedMaps(player) { + const maps = sqlite.prepare( + ` + SELECT a.map, + a.category, + a.points, + b.finishesTotal, + b.medianTime + FROM (SELECT category, + map, + points + FROM maps + WHERE map NOT IN (SELECT map + FROM rankings + WHERE player = ? )) AS a + JOIN maps AS b + ON a.category = b.category + AND a.map = b.map + ORDER BY b.category ASC; + `) + + let unfinished = { + Novice: [], + Moderate: [], + Brutal: [], + Insane: [], + Dummy: [], + DDmaX: [], + Oldschool: [], + Solo: [], + Race: [], + Fun: [] + } + for (const map of maps.iterate(player)) { + unfinished[map.category].push(map) + } + + return unfinished +} + +export default { + playerExists, + finishedMaps, + unfinishedMaps, + player, + + map, + mapCategory, + allMaps, + mapExists, + leaderboardRace, + leaderboardTeamrace, + categoryExists, +} \ No newline at end of file diff --git a/libs/ddnss/handler.js b/libs/ddnss/handler.js new file mode 100644 index 0000000..d105d32 --- /dev/null +++ b/libs/ddnss/handler.js @@ -0,0 +1,87 @@ +import { exec } from 'child_process' +import { skinDB } from '../database/init.js' +import initLog from '../utils/log.js' +import { download } from '../download/dowload.js' + +const log = initLog("DDNSS") + +export async function ddnssStart() { + const getServers = await download('https://ddnet.tw/status/index.json', "_RETURN_VALUE_") + const servers = await getServers.json() + + log(`Found ${servers.length} online servers!`) + + for (const server of servers) { + const connection = `${server.ip}:${server.port}` + + if (!(server.num_clients > 0 && server.num_clients < (server.max_clients - 2))) { + log(`Server (essentially) full! >> ${connection} -> ${server.num_clients}/${server.max_clients} clients`) + continue + } + if(server.password) { + log(`Server is locked >> ${connection}`) + continue + } + + log(`Connecting to server >> ${connection}`) + await scrapeServer(`${connection}`) + } + + // PLEASE!! + exec(`pkill -9 -f ddnss`) +} + +function scrapeServer(server) { + // TODO: Maybe fix the paths to be dynamic? Or have some sort of buildscript... + // -- BurnyLlama + const command = `./ddnss/build/DDNet "ui_server_address ${server}" -f ddnss/build/config.conf` + + return new Promise((resolve, reject) => { + exec(command, { encoding: 'utf8' }, (err, stdout, stderr) => { + try { + const skinData = JSON.parse(stdout) + + if (skinData === null) { + resolve() + return + } + + const currentTime = Date.now() + // TODO: Store statement once and reuse same statment. (whatever that means) + for (const entry of skinData) + skinDB.prepare(` + INSERT INTO "skindata" + ( + $timestamp, + $player, + $clan, + $flag, + $skin, + $useColor, + $colorBodyRaw, + $colorBodyHex, + $colorFeetRaw, + $ColorFeetHex + ) + `) + .run({ + timestamp: currentTime, + player: entry.player, + clan: entry.clan, + flag: entry.flag, + skin: entry.skindata.skin, + useColor: entry.skindata.useColor, + colorBodyRaw: entry.skindata.colorBody.raw, + colorBodyHex: entry.skindata.colorBody.hex, + colorFeetRaw: entry.skindata.colorFeet.raw, + colorFeetHex: entry.skindata.colorFeet.hex, + }) + + } catch (e) { + log(`Failed to handle ${server}!`) + } + + resolve() + }) + }) +} \ No newline at end of file diff --git a/libs/download/dowload.js b/libs/download/dowload.js new file mode 100644 index 0000000..5addf4a --- /dev/null +++ b/libs/download/dowload.js @@ -0,0 +1,84 @@ +import fs from 'fs' +import https from 'https' +import initLog from '../utils/log.js' +import { exec } from 'child_process' + +const log = initLog("Downloader") + + +/** + * This function can download and save data to files, or simply return the data. + * @param {string} url The URL of which to download from... + * @param {string} target This is the file path you want to save to. Alterntively use "_RETURN_VALUE_" to get value returned instead of saved to a file. + * + * @returns {Promise} + * + * @author BurnyLlama + */ +export function download(url, target) { + return new Promise( + (resolve, reject) => { + log(`Starting a download >> ${url}`) + + https.get( + url, + data => { + if (target === "_RETURN_VALUE_") { + let result + + data.on( + 'data', + chunk => result += chunk + ) + + data.on( + 'end', + () => resolve(result) + ) + } + + const file = fs.createWriteStream(target) + + data.pipe(file) + + data.on( + 'end', + () => { + log(`Done with a download >> ${url}`) + file.close() + resolve() + } + ) + } + ) + } + ) +} + +export function downloadEssentialData() { + return new Promise( + (resolve, reject) => { + log("Downloading 'ddnet.sqlite.zip' and 'players.msgpack'...") + Promise.all([ + download("https://ddnet.tw/stats/ddnet.sqlite.zip", process.env.DDNET_SQLITE_PATH ? `${process.env.DDNET_SQLITE_PATH}.zip` : 'data/ddnet.sqlite.zip'), + download("https://ddnet.tw/players.msgpack", process.env.MSGPACK_PATH ?? 'data/players.msgpack') + ]).then(() => { + log("All downloads done! Going to unzip 'ddnet.sqlite.zip'...") + + exec( + `unzip -o ${process.env.DDNET_SQLITE_PATH ? `${process.env.DDNET_SQLITE_PATH}.zip` : 'data/ddnet.sqlite.zip'} \ + -d ${process.env.DDNET_SQLITE_PATH ? process.env.DDNET_SQLITE_PATH.replace(/\/[\s\S]*\.sqlite/, "") : 'data'}`, + err => { + if (err) { + log("Error while unzipping!") + reject() + } + + log("Done unzipping!") + resolve() + } + ) + }) + } + ) +} \ No newline at end of file diff --git a/libs/utils/log.js b/libs/utils/log.js index 478d63e..88647a8 100644 --- a/libs/utils/log.js +++ b/libs/utils/log.js @@ -10,4 +10,4 @@ export default function initLog(prefix) { return string => console.log(`${prefix} >>> ${string}`) -} \ No newline at end of file +} diff --git a/math-func.so b/math-func.so new file mode 100755 index 0000000..3a3fc0b Binary files /dev/null and b/math-func.so differ diff --git a/template.env b/template.env new file mode 100644 index 0000000..dae7afe --- /dev/null +++ b/template.env @@ -0,0 +1,22 @@ +# +# You should copy this file to '.env' +# and set all settings there. +# + + +# Paths to SQLite databases... +DDNET_SQLITE_PATH = "data/ddnet.sqlite" +DDNSS_SQLITE_PATH = "data/skindata.sqlite" +MSGPACK_PATH = "data/players.msgpack" + +# Should the server try to generate the database? +GENERATE_DB = "true" + +# Should download files from DDNet servers? +DOWNLOAD_FILES = "true" + +# The port on which the server listens... +PORT = 12345 + +# The API paginates. How many entries per page? +ENTRIES_PER_PAGE = 50 \ No newline at end of file