feat: Basic migration system + initial migration

This commit is contained in:
overflowerror 2024-07-27 18:53:36 +02:00
parent 0b72962ce5
commit 1199023daf
5 changed files with 240 additions and 4 deletions

View file

@ -1 +1,5 @@
<?php
require_once __DIR__ . '/lib/migrate.php';
migrate();

View file

@ -4,4 +4,4 @@ require_once __DIR__ . "/../credentials.php";
$dsn = "pgsql:host=" . POSTGRES_HOST . ";dbname=" . POSTGRES_DBNAME . ";port=" . POSTGRES_PORT;
$pdo = new PDO($dsn, POSTGRES_USER, POSTGRES_PASSWORD);
$pdo = new PDO($dsn, POSTGRES_USER, POSTGRES_PASSWORD);

117
lib/migrate.php Normal file
View file

@ -0,0 +1,117 @@
<?php
require_once __DIR__ . "/database.php";
// variable because heredoc doesn't support consts
$MIGRATION_TABLE = "mm_migrations";
function ensureMigrationsTable(): void {
global $pdo;
global $MIGRATION_TABLE;
if ($pdo->query(<<<EOF
SELECT tablename FROM pg_tables
WHERE schemaname = 'public' AND tablename = '${MIGRATION_TABLE}'
EOF
)->rowCount() != 0) {
return;
}
$pdo->exec(<<<EOF
CREATE TABLE IF NOT EXISTS $MIGRATION_TABLE (
id INT NOT NULL,
file VARCHAR(255) NOT NULL,
applied TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
);
EOF
) !== false or die("unable to initialize migrations: " . $pdo->errorCode());
}
function getAllMigrations(): array {
$files = scandir(__DIR__ . "/../migrations/");
$files = array_values(array_filter($files, fn($f) => $f[0] != "."));
sort($files);
$migrations = [];
foreach ($files as $file) {
$delimiterPos = strpos($file, "_");
$migrations[intval(substr($file, 0, $delimiterPos))] = $file;
}
return $migrations;
}
function getAppliedMigrations(): array {
global $pdo;
global $MIGRATION_TABLE;
$result = $pdo->query(<<<EOF
SELECT * FROM ${MIGRATION_TABLE}
EOF);
$migrations = [];
foreach ($result->fetchAll() as $row) {
$migrations[$row["id"]] = $row["file"];
}
return $migrations;
}
function getMigrationsToApply(): array {
global $pdo;
$all = getAllMigrations();
$applied = getAppliedMigrations();
foreach ($applied as $id => $file) {
unset($all[$id]);
}
return $all;
}
function executeSqlScript(string $sql, string $file) {
global $pdo;
if ($pdo->exec($sql) === false) {
die("failed to apply migration " . $file . ": " . $pdo->errorCode());
}
}
function applyMigration(int $id, string $file) {
global $pdo;
global $MIGRATION_TABLE;
$pdo->beginTransaction();
$sql = file_get_contents(__DIR__ . "/../migrations/" . $file);
if (!$sql) {
die("Unable to read migration file: " . $file);
}
executeSqlScript($sql, $file);
$statement = $pdo->prepare(<<<EOF
INSERT INTO ${MIGRATION_TABLE}
(id, file) VALUES
(?, ?)
EOF);
$statement->execute([$id, $file]);
try {
$pdo->commit();
} catch (PDOException $e) {
// this might happen if the migration script contains a DDL statement
// -> ignore
}
}
function migrate() {
ensureMigrationsTable();
$migrations = getMigrationsToApply();
foreach ($migrations as $id => $file) {
applyMigration($id, $file);
}
}

View file

@ -98,14 +98,14 @@ function downloadImage(string $url, string $mobname): string {
function addOrUpdateMob(string $name, string $filename) {
global $pdo;
$query = $pdo->prepare("SELECT name from mobs where name = ?");
$query = $pdo->prepare("SELECT name from mm_mobs where name = ?");
$query->execute([$name]) or die("unable to check if mob exists");
if ($query->rowCount() == 0) {
$query = $pdo->prepare("INSERT INTO mobs (name, image) VALUES (?, ?)");
$query = $pdo->prepare("INSERT INTO mm_mobs (name, image) VALUES (?, ?)");
$query->execute([$name, $filename]) or die("unable to add new mob");
echo " added\n";
} else {
$query = $pdo->prepare("UPDATE mobs SET image = ? WHERE name = ?");
$query = $pdo->prepare("UPDATE mm_mobs SET image = ? WHERE name = ?");
$query->execute([$filename, $name]) or die("unable to update mob");
echo " updated\n";
}

View file

@ -0,0 +1,115 @@
create table mm_mobs
(
id serial
constraint mobs_pk
primary key,
name varchar(255) not null,
image varchar(255) not null,
created timestamp default CURRENT_TIMESTAMP not null,
enabled boolean default true not null
);
create table mm_matches
(
id bigserial,
mob1fk integer not null
constraint matches_mob1_fk
references mm_mobs,
mob2fk integer not null
constraint matches_mob2_fk
references mm_mobs,
created timestamp default CURRENT_TIMESTAMP not null,
winner integer not null,
session varchar(255)
);
CREATE VIEW mm_matches_of_mob(id, mob, opponent, won, created) AS
SELECT mm_matches.id,
mm_matches.mob1fk AS mob,
mm_matches.mob2fk AS opponent,
mm_matches.winner = 1 AS won,
mm_matches.created
FROM mm_matches
UNION
SELECT mm_matches.id,
mm_matches.mob2fk AS mob,
mm_matches.mob1fk AS opponent,
mm_matches.winner = 2 AS won,
mm_matches.created
FROM mm_matches;
CREATE VIEW mm_rating(mob, rating, last_update) AS
WITH RECURSIVE rating(mob, rating, last_update) AS (
SELECT mm_mobs.id AS mob,
1500.0 AS rating,
0::bigint AS last_update
FROM mm_mobs
UNION
SELECT expectation.mob,
expectation.own_rating + 32::numeric * (
CASE
WHEN expectation.won THEN 1
ELSE 0
END::numeric - expectation.expectation) AS rating,
expectation.id AS last_update
FROM (
WITH newest_rating(mob, rating, last_update) AS (
SELECT
rating_with_row_number.mob,
rating_with_row_number.rating,
rating_with_row_number.last_update,
rating_with_row_number.row_number
FROM (
SELECT rating_for_row_number.mob,
rating_for_row_number.rating,
rating_for_row_number.last_update,
row_number()
OVER (
PARTITION BY rating_for_row_number.mob
ORDER BY rating_for_row_number.last_update DESC
) AS row_number
FROM rating rating_for_row_number
) rating_with_row_number
WHERE rating_with_row_number.row_number = 1)
SELECT
next_match.id,
mm_matches_of_mob.mob,
mm_matches_of_mob.won,
own_rating.rating AS own_rating,
opponent_rating.rating AS opponent_rating,
(1::numeric /
(
1::numeric +
power(
10::numeric,
(
opponent_rating.rating - own_rating.rating
) / 400::numeric
)
)
) AS expectation
FROM (
SELECT
min(matches_for_next_match.id) AS id,
matches_for_next_match.mob
FROM mm_matches_of_mob matches_for_next_match
JOIN newest_rating own_rating_1
ON matches_for_next_match.mob = own_rating_1.mob
WHERE matches_for_next_match.id > own_rating_1.last_update
GROUP BY matches_for_next_match.mob
) next_match
JOIN mm_matches_of_mob
ON next_match.id = mm_matches_of_mob.id AND
next_match.mob = mm_matches_of_mob.mob
JOIN newest_rating own_rating
ON mm_matches_of_mob.mob = own_rating.mob
JOIN newest_rating opponent_rating
ON mm_matches_of_mob.opponent = opponent_rating.mob
) expectation
)
SELECT mob,
rating,
last_update
FROM rating;