diff --git a/api/finishes.js b/api/finishes.js index 1fd68f6..f339806 100644 --- a/api/finishes.js +++ b/api/finishes.js @@ -1,5 +1,6 @@ import { Router } from 'express' import { sqlite } from '../libs/database/init.js' +import wrapper from '../libs/database/wrapper.js' const finishApi = Router() @@ -16,4 +17,43 @@ finishApi.get( } ) +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/maps.js b/api/maps.js index 851ff06..d2ebceb 100644 --- a/api/maps.js +++ b/api/maps.js @@ -1,5 +1,6 @@ import { Router } from 'express' import { sqlite } from '../libs/database/init.js' +import wrapper, { map } from '../libs/database/wrapper.js' const mapApi = Router() @@ -18,37 +19,17 @@ mapApi.get( mapApi.get( '/get/:map', (req, res) => { - let map = req.params.map - /* Check if map exists */ - const check = sqlite.prepare(`SELECT map FROM maps WHERE map = ?`).get(map) - if (!check) { + if(!wrapper.mapExists(req.params.map)) { return res.json({ success: false, - response: "No map found!", + response: "No such map!" }) } - const info = sqlite.prepare(`SELECT * FROM maps WHERE map = ?`).get(map) - - /* TODO: Generate a table with this as a cache */ - const avgTime = sqlite.prepare(`SELECT avg(time) AS 'averageTime' FROM race WHERE map = ?`).get(map) - const total = sqlite.prepare(`SELECT COUNT(*) AS 'total' FROM race WHERE map = ?`).get(map) - const unique = sqlite.prepare(`SELECT COUNT(distinct(player)) AS 'unique' FROM race WHERE map = ?`).get(map) - const teams = sqlite.prepare(`SELECT COUNT(distinct(id)) AS 'teams' FROM teamrace WHERE map = ?`).get(map) return res.json({ success: true, - response: { - info, - - /* TODO Get median time*/ - averageTime: avgTime.averageTime, - finishes: { - unique: unique.unique, - total: total.total, - teams: teams.teams, - } - } + response: map(req.params.map) }) } ) @@ -56,11 +37,9 @@ mapApi.get( mapApi.get( '/getAll', (req, res) => { - const allMaps = sqlite.prepare(`SELECT * FROM maps`).all() - return res.json({ success: true, - response: allMaps, + response: wrapper.allMaps() }) } ) @@ -68,22 +47,53 @@ mapApi.get( mapApi.get( '/category/:category', (req, res) => { - let category = req.params.category - /* Check if category exists */ - const check = sqlite.prepare(`SELECT category FROM maps WHERE category = ? LIMIT 1`).get(category) - if (!check) { + if (!wrapper.categoryExists(req.params.category)) { return res.json({ success: false, response: "Invalid category name!", }) } - const allMaps = sqlite.prepare(`SELECT * FROM maps WHERE category = ?`).all(category) + 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: allMaps, + 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) }) } ) diff --git a/api/players.js b/api/players.js index d8d7f4d..6bf13cf 100644 --- a/api/players.js +++ b/api/players.js @@ -1,32 +1,24 @@ import { Router } from 'express' -import { sqlite } from '../libs/database/init.js' -import searcher from '../libs/database/searcher.js' +import wrapper from '../libs/database/wrapper.js' const playerApi = Router() - playerApi.get( '/get/:player', async (req, res) => { - searcher( - 'points', - 'player', - req.params.player, - undefined, - false, - "get", - 0 - ).then( - player => res.json({ - success: true, - response: player - }) - ).catch( - error => res.json({ + /* Check if player exists */ + if(!wrapper.playerExists(req.params.player)) { + return res.json({ success: false, - response: error + response: "No such player!" }) - ) + } + const data = wrapper.player(req.params.player) + + return res.json({ + success: true, + response: data + }) } ) diff --git a/index.js b/index.js index 3f6b3e2..4983417 100644 --- a/index.js +++ b/index.js @@ -4,7 +4,7 @@ import api from './api/api.js' import { generateDB } from './libs/database/generate.js' import { dbInit } from './libs/database/init.js' import { downloadEssentialData } from './libs/download/dowload.js' - +import tasks from './libs/database/tasks.js' loadEnv() diff --git a/libs/database/generate.js b/libs/database/generate.js index b9c5f69..0293681 100644 --- a/libs/database/generate.js +++ b/libs/database/generate.js @@ -43,11 +43,6 @@ export function generateDB() { `ALTER TABLE maps RENAME COLUMN Timestamp TO release` ]) } - 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")` - ]) log("Generating race index...") execMany([ @@ -62,12 +57,15 @@ export function generateDB() { 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 + "rank" INTEGER NOT NULL, + "finishes" INTEGER NOT NULL DEFAULT 0 ) `) @@ -78,7 +76,9 @@ export function generateDB() { 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_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...") @@ -91,6 +91,8 @@ export function generateDB() { 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, @@ -108,7 +110,9 @@ export function generateDB() { 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_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...") @@ -131,6 +135,38 @@ export function generateDB() { 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, diff --git a/libs/database/init.js b/libs/database/init.js index 281f7be..84f2098 100644 --- a/libs/database/init.js +++ b/libs/database/init.js @@ -24,6 +24,9 @@ export function dbInit() { /* Unsafe mode */ sqlite.unsafeMode() + /* Load external extensions */ + sqlite.loadExtension('./math-func.so') + log("Loaded in 'ddnet.sqlite'!") log("Loaded in 'skindata.sqlite'!") } diff --git a/libs/database/tasks.js b/libs/database/tasks.js index c91bc6a..71e6e2f 100644 --- a/libs/database/tasks.js +++ b/libs/database/tasks.js @@ -7,26 +7,28 @@ import { sqlite } from './init.js' * @module libs/database/processRankings */ export function processRankings() { - const maps = sqlite.prepare(`SELECT map FROM maps`) + const maps = sqlite.prepare(`SELECT * FROM maps`) for (const map of maps.iterate()) sqlite .prepare(` INSERT INTO rankings ( - map, player, time, date, rank, server + map, category, points, player, time, date, rank, server, finishes ) - SELECT map, player, time, date, rank, server + 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 - FROM race + 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) @@ -44,12 +46,13 @@ export function processTeamRankings() { .prepare(` INSERT INTO teamrankings ( - player, map, id, time, date, server, teamrank + 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 + dense_rank() OVER w AS rank, + a.category, a.points FROM (( SELECT DISTINCT id FROM teamrace @@ -61,7 +64,9 @@ export function processTeamRankings() { INNER JOIN race AS n ON r.map = n.map AND r.player = n.player - AND r.time = n.time window w AS (ORDER BY r.time) + AND r.time = n.time + JOIN maps as a + ON r.map = a.map window w AS (ORDER BY r.time) `) .run(map.map) } @@ -99,6 +104,45 @@ export function processTimeGraph() { } } +/** + * 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 @@ -160,5 +204,6 @@ 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/math-func.so b/math-func.so new file mode 100755 index 0000000..3a3fc0b Binary files /dev/null and b/math-func.so differ