Skip to content

Commit

Permalink
Further remove selects from elo_updates; Remove dbreinit on every are…
Browse files Browse the repository at this point in the history
…na start
  • Loading branch information
StanislavNikolov committed Aug 19, 2023
1 parent 03422fe commit c0be661
Show file tree
Hide file tree
Showing 5 changed files with 148 additions and 139 deletions.
11 changes: 5 additions & 6 deletions TODO.txt
Original file line number Diff line number Diff line change
@@ -1,15 +1,14 @@

High:
- Login system - send a special link to the email
- Cmndr: Finish the "your bots" page - add button to decommision bot
- Optimize the query in backend/arena.ts: pickBotByNumberOfGamesPlayed.
It counts the number of games played by each bot, and then picks a bot.
Takes 200ms, should be more like 2ms.

Mid:
- Add "fen" string view on the game page
- Add timer to live games.
- Add token count to each bot in the db
- Add animation when live games "die"
- Optimzie the renderer in the live games page

Low:
[4] - Some kind of captcha for uploading new bots
- Make the timer update if you leave the page open overnight.
- Add "fork me on github" ribbon
- Maybe optimize with websockets?
59 changes: 34 additions & 25 deletions backend/arena.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,15 @@ import { Subprocess } from "bun";
import { mkdir } from "node:fs/promises";
import { ok as assert } from "node:assert";
import { dirname } from "node:path";
import sql from "./db";
import { makeTmpDir, getElo } from "./utils";
import { sql } from "./db";
import { makeTmpDir } from "./utils";
import rawfenstxt from "../fens.txt";

export async function getElo(botId: number): Promise<number> {
const res = await sql`SELECT elo FROM bot_elos WHERE bot_id = ${botId}`;
return res[0].elo;
}

const startingPositions = rawfenstxt.split('\n');

const colors = {
Expand Down Expand Up @@ -250,42 +255,45 @@ export class Arena {
}
}

async function pickBotByNumberOfGamesPlayed(): Promise<number> {
async function pickBotByNumberOfGamesPlayed(): Promise<{ id: number, elo: number }> {
// Bots that have played FEWER games have a HIGHER chance to be picked.
// Playing more than 100 games does not change your weight.

const stats = await sql`
SELECT bots.id, LEAST(COUNT(*), 100)::int AS cnt FROM bots
LEFT JOIN games ON games.wid = bots.id OR games.bid = bots.id
WHERE paused = FALSE
GROUP BY bots.id
WITH bot_games AS (
SELECT bots.id, LEAST(COUNT(*), 100)::int AS cnt FROM bots
LEFT JOIN games ON games.wid = bots.id OR games.bid = bots.id
LEFT JOIN bot_elos ON bot_elos.bot_id = bots.id
WHERE paused = FALSE
GROUP BY bots.id
)
SELECT bot_elos.bot_id AS id, bot_games.cnt, bot_elos.elo
FROM bot_elos
JOIN bot_games ON bot_games.id = bot_elos.bot_id
ORDER BY cnt
` as { id: number, cnt: number }[];
` as { id: number, cnt: number, elo: number }[];

const weightSum = stats.reduce((tot, curr) => tot + 1 / curr.cnt, 0);
let prefSum = 0;
const random = Math.random() * weightSum;
for (const { id, cnt } of stats) {
prefSum += 1 / cnt;
if (prefSum >= random) return id;
for (const st of stats) {
prefSum += 1 / st.cnt;
if (prefSum >= random) return { id: st.id, elo: st.elo };
}
}

async function pickBotThatHasCloseElo(otherBotId: number): Promise<number> {
async function pickBotThatHasCloseElo(otherBot: { id: number, elo: number }): Promise<number> {
// Bots that have elo that is CLOSE to otherBotId have MORE chance to be picked up.

const otherElo = await getElo(otherBotId);
const stats = await sql`
SELECT bot_id, coalesce(SUM(change), 0)::int AS elo
FROM elo_updates
SELECT bot_id, elo FROM bot_elos
JOIN bots ON bots.id = bot_id
WHERE bot_id != ${otherBotId} AND paused = FALSE
GROUP BY bot_id
WHERE bot_id != ${otherBot.id} AND paused = FALSE
` as { bot_id: number, elo: number }[];

const W = 50;
const P = 2;
const calcWeight = (elo: number) => 1 / Math.pow(Math.abs(elo - otherElo) + W, P);
const calcWeight = (elo: number) => 1 / Math.pow(Math.abs(elo - otherBot.elo) + W, P);

const weightSum = stats.reduce((tot, curr) => tot + calcWeight(curr.elo), 0);

Expand All @@ -295,21 +303,22 @@ async function pickBotThatHasCloseElo(otherBotId: number): Promise<number> {
prefSum += calcWeight(elo);
if (prefSum >= random) return bot_id;
}
console.log("HERE")
}

async function match() {
let id1 = await pickBotByNumberOfGamesPlayed();
if (id1 == null) return;
let bot1 = await pickBotByNumberOfGamesPlayed();
if (bot1 == null) return;

let id2 = await pickBotThatHasCloseElo(id1);
let id2 = await pickBotThatHasCloseElo(bot1);
if (id2 == null) return;

if (id1 == id2) return;
if (bot1.id == id2) return;

if (Math.random() > 0.5) [id1, id2] = [id2, id1];
if (Math.random() > 0.5) var arena = new Arena(bot1.id, id2);
else var arena = new Arena(id2, bot1.id);

console.log(`${colors.green}Starting game between ${id1} and ${id2}${colors.reset}`);
const arena = new Arena(id1, id2);
console.log(`${colors.green}Starting game between ${arena.bots.w.id} and ${arena.bots.b.id}${colors.reset}`);
await arena.start();
}

Expand Down
199 changes: 101 additions & 98 deletions backend/db.ts
Original file line number Diff line number Diff line change
Expand Up @@ -2,114 +2,117 @@ import postgres from "postgres";

const sql = postgres({ onnotice: () => { } });

await sql`
CREATE TABLE IF NOT EXISTS devs (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL,
email TEXT NOT NULL UNIQUE
export async function setupDatabase() {
await sql`
CREATE TABLE IF NOT EXISTS devs (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL,
email TEXT NOT NULL UNIQUE
);
`;
`;

await sql`
CREATE TABLE IF NOT EXISTS bots (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL,
code TEXT NOT NULL,
uploaded TIMESTAMPTZ NOT NULL,
hash TEXT,
dev_id INTEGER NOT NULL,
FOREIGN KEY(dev_id) REFERENCES devs(id) ON DELETE CASCADE
);
`;
await sql`
CREATE TABLE IF NOT EXISTS bots (
id SERIAL PRIMARY KEY,
name TEXT NOT NULL,
code TEXT NOT NULL,
uploaded TIMESTAMPTZ NOT NULL,
hash TEXT,
dev_id INTEGER NOT NULL,
FOREIGN KEY(dev_id) REFERENCES devs(id) ON DELETE CASCADE
);
`;

await sql`
ALTER TABLE bots ADD COLUMN IF NOT EXISTS paused BOOLEAN DEFAULT FALSE;
`;
await sql`
ALTER TABLE bots ADD COLUMN IF NOT EXISTS paused BOOLEAN DEFAULT FALSE;
`;

await sql`
CREATE TABLE IF NOT EXISTS games (
id SERIAL PRIMARY KEY,
bid INTEGER NOT NULL,
wid INTEGER NOT NULL,
started TIMESTAMPTZ,
ended TIMESTAMPTZ,
winner VARCHAR(1),
initial_time_ms INTEGER NOT NULL,
initial_position TEXT,
current_position TEXT, -- used for quickly showing live games
reason TEXT,
FOREIGN KEY(wid) REFERENCES bots(id) ON DELETE CASCADE,
FOREIGN KEY(bid) REFERENCES bots(id) ON DELETE CASCADE
);
`;
await sql`
CREATE TABLE IF NOT EXISTS games (
id SERIAL PRIMARY KEY,
bid INTEGER NOT NULL,
wid INTEGER NOT NULL,
started TIMESTAMPTZ,
ended TIMESTAMPTZ,
winner VARCHAR(1),
initial_time_ms INTEGER NOT NULL,
initial_position TEXT,
current_position TEXT, -- used for quickly showing live games
reason TEXT,
FOREIGN KEY(wid) REFERENCES bots(id) ON DELETE CASCADE,
FOREIGN KEY(bid) REFERENCES bots(id) ON DELETE CASCADE
);
`;

await sql`
CREATE TABLE IF NOT EXISTS moves (
id SERIAL PRIMARY KEY,
game_id INTEGER NOT NULL,
move TEXT NOT NULL,
color TEXT NOT NULL,
time_ms INTEGER NOT NULL,
FOREIGN KEY(game_id) REFERENCES games(id) ON DELETE CASCADE
);
`;
await sql`
CREATE TABLE IF NOT EXISTS moves (
id SERIAL PRIMARY KEY,
game_id INTEGER NOT NULL,
move TEXT NOT NULL,
color TEXT NOT NULL,
time_ms INTEGER NOT NULL,
FOREIGN KEY(game_id) REFERENCES games(id) ON DELETE CASCADE
);
`;

await sql`
CREATE TABLE IF NOT EXISTS elo_updates (
id SERIAL PRIMARY KEY,
game_id INTEGER,
bot_id INTEGER NOT NULL,
change FLOAT NOT NULL,
FOREIGN KEY(game_id) REFERENCES games(id) ON DELETE CASCADE,
FOREIGN KEY(bot_id) REFERENCES bots(id) ON DELETE CASCADE
);
`;
await sql`
CREATE TABLE IF NOT EXISTS elo_updates (
id SERIAL PRIMARY KEY,
game_id INTEGER,
bot_id INTEGER NOT NULL,
change FLOAT NOT NULL,
FOREIGN KEY(game_id) REFERENCES games(id) ON DELETE CASCADE,
FOREIGN KEY(bot_id) REFERENCES bots(id) ON DELETE CASCADE
);
`;

await sql`
CREATE TABLE IF NOT EXISTS dev_tokens (
id SERIAL PRIMARY KEY,
dev_id INTEGER,
token TEXT NOT NULL,
FOREIGN KEY(dev_id) REFERENCES devs(id) ON DELETE CASCADE
);
`;

await sql`
CREATE TABLE IF NOT EXISTS dev_tokens (
id SERIAL PRIMARY KEY,
dev_id INTEGER,
token TEXT NOT NULL,
FOREIGN KEY(dev_id) REFERENCES devs(id) ON DELETE CASCADE
);
`;

// This is a materialized view that is used to quickly get the elo of each bot.
// Since this query is executed often I cache the result.
await sql`
CREATE MATERIALIZED VIEW IF NOT EXISTS bot_elos AS
SELECT bots.id as bot_id, SUM(change)::float AS elo FROM bots
LEFT JOIN elo_updates ON elo_updates.bot_id = bots.id
GROUP BY bots.id;
`;

// This is a materialized view that is used to quickly get the elo of each bot.
// Since this query is executed often I cache the result.
await sql`
CREATE MATERIALIZED VIEW IF NOT EXISTS bot_elos AS
SELECT bots.id as bot_id, SUM(change)::float AS elo FROM bots
LEFT JOIN elo_updates ON elo_updates.bot_id = bots.id
GROUP BY bots.id;
`;
// I want to refresh the view whenever a new elo update is added. Sadly triggers
// cannot call refresh directly, so I make this function that the trigger can call.
await sql`
CREATE OR REPLACE FUNCTION refresh_bot_elos()
RETURNS TRIGGER LANGUAGE PLPGSQL
AS
$$
BEGIN
REFRESH MATERIALIZED VIEW bot_elos;
RETURN NULL;
END
$$;
`;

// I want to refresh the view whenever a new elo update is added. Sadly triggers
// cannot call refresh directly, so I make this function that the trigger can call.
await sql`
CREATE OR REPLACE FUNCTION refresh_bot_elos()
RETURNS TRIGGER LANGUAGE PLPGSQL
AS
$$
BEGIN
REFRESH MATERIALIZED VIEW bot_elos;
RETURN NULL;
END
$$;
`;
await sql`
CREATE OR REPLACE TRIGGER refresh_bot_elos_on_elo_updates_change
AFTER INSERT OR UPDATE OR DELETE
ON elo_updates
FOR EACH STATEMENT
EXECUTE PROCEDURE refresh_bot_elos();
`;

await sql`
CREATE OR REPLACE TRIGGER refresh_bot_elos_on_elo_updates_change
AFTER INSERT OR UPDATE OR DELETE
ON elo_updates
FOR EACH STATEMENT
EXECUTE PROCEDURE refresh_bot_elos();
`;
// This speeds up finding live and old games.
await sql`CREATE INDEX IF NOT EXISTS games_ended ON games (ended);`;
await sql`CREATE INDEX IF NOT EXISTS moves_game_id ON moves (game_id);`;
await sql`CREATE INDEX IF NOT EXISTS elo_game_id ON elo_updates (game_id);`;
await sql`CREATE INDEX IF NOT EXISTS elo_bot_id ON elo_updates (bot_id);`;

// This speeds up finding live and old games.
await sql`CREATE INDEX IF NOT EXISTS games_ended ON games (ended);`;
await sql`CREATE INDEX IF NOT EXISTS moves_game_id ON moves (game_id);`;
await sql`CREATE INDEX IF NOT EXISTS elo_game_id ON elo_updates (game_id);`;
await sql`CREATE INDEX IF NOT EXISTS elo_bot_id ON elo_updates (bot_id);`;
}

export default sql;
export { sql };
12 changes: 8 additions & 4 deletions backend/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -3,8 +3,7 @@ import { getCookie, setCookie } from "hono/cookie";
import { serveStatic } from "hono/bun";

import { compile } from "./compile";
import sql from "./db";
import { getElo } from "./utils";
import { sql, setupDatabase } from "./db";
import { sendEmail } from "./email";
import { randomBytes } from "crypto";

Expand Down Expand Up @@ -178,11 +177,14 @@ app.get("/api/game/:gameId/", async c => {
app.get("/api/bot/:botId/", async c => {
const botId = Number(c.req.param("botId"));

const res = (await sql`SELECT name, uploaded FROM bots WHERE bots.id = ${botId}`);
const res = await sql`
SELECT name, uploaded, elo
FROM bots
JOIN bot_elos ON bot_elos.bot_id = bots.id
WHERE bots.id = ${botId}`;
if (res.length === 0) return c.text('', 404);

const bot = res[0];
bot.elo = await getElo(botId);

bot.games = await sql`
SELECT games.id AS id, started, bid, wid, wbot.name AS wname, bbot.name AS bname, winner, reason, change as elo_change
Expand Down Expand Up @@ -266,6 +268,8 @@ for (const file of ["index.ts", "game.ts", "bot.ts"]) {
});
}

await setupDatabase();

const port = parseInt(process.env.PORT) || 3000;
console.log(`Running at http://localhost:${port}`);
export default {
Expand Down
6 changes: 0 additions & 6 deletions backend/utils.ts
Original file line number Diff line number Diff line change
@@ -1,13 +1,7 @@
import { tmpdir } from "node:os";
import { randomBytes } from "node:crypto";
import sql from "./db";

export function makeTmpDir() {
const rnd = randomBytes(16).toString('base64url');
return `${tmpdir()}/chess-${rnd}`;
}

export async function getElo(botId: number): Promise<number> {
const res = await sql`SELECT SUM(change)::float FROM elo_updates WHERE bot_id = ${botId}`;
return res[0].sum;
}

0 comments on commit c0be661

Please sign in to comment.