Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
16 changes: 16 additions & 0 deletions migrations/20250524213558_materialized_ranking.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
-- Add down migration script here

CREATE OR REPLACE VIEW ranked_players AS
SELECT
ROW_NUMBER() OVER(ORDER BY players.score DESC, id) AS index,
RANK() OVER(ORDER BY players.score DESC) AS rank,
id, name, players.score, subdivision,
nationalities.iso_country_code,
nationalities.nation,
nationalities.continent
FROM players
LEFT OUTER JOIN nationalities
ON players.nationality = nationalities.iso_country_code
WHERE NOT players.banned AND players.score > 0.0;

DROP MATERIALIZED VIEW player_ranks;
25 changes: 25 additions & 0 deletions migrations/20250524213558_materialized_ranking.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- Add up migration script here

CREATE MATERIALIZED VIEW player_ranks AS
SELECT
RANK() OVER (ORDER BY score DESC) as rank,
id
FROM players
WHERE
score != 0 AND NOT banned;

CREATE UNIQUE INDEX player_ranks_id_idx ON player_ranks(id);


CREATE OR REPLACE VIEW ranked_players AS
SELECT
ROW_NUMBER() OVER(ORDER BY rank, id) AS index,
rank,
id, name, players.score, subdivision,
nationalities.iso_country_code,
nationalities.nation,
nationalities.continent
FROM players
LEFT OUTER JOIN nationalities
ON players.nationality = nationalities.iso_country_code
NATURAL JOIN player_ranks;
9 changes: 0 additions & 9 deletions pointercrate-demonlist-pages/static/js/modules/statsviewer.js
Original file line number Diff line number Diff line change
Expand Up @@ -149,15 +149,6 @@ export class StatsViewer extends FilteredPaginator {
main + " Main, " + extended + " Extended, " + legacy + " Legacy ";
}

onReceive(response) {
super.onReceive(response);

// Using currentlySelected is O.K. here, as selection via clicking li-elements is the only possibility (well, not for the nation based one, but oh well)!
this._rank.innerText = this.currentlySelected.dataset.rank;
this._score.innerHTML =
this.currentlySelected.getElementsByTagName("i")[0].innerHTML;
}

formatDemon(demon, link, dontStyle) {
var element;

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,9 @@ class IndividualStatsViewer extends StatsViewer {

var playerData = response.data.data;

this._rank.innerText = playerData.rank;
this._score.innerText = playerData.score.toFixed(2);

this.setName(playerData.name, playerData.nationality);

const selectedSort = this.demonSortingModeDropdown.selected;
Expand Down Expand Up @@ -231,7 +234,6 @@ function generateStatsViewerPlayer(player) {

li.className = "white hover";
li.dataset.id = player.id;
li.dataset.rank = player.rank;

b.appendChild(document.createTextNode("#" + player.rank + " "));
i.appendChild(document.createTextNode(player.score.toFixed(2)));
Expand Down
4 changes: 4 additions & 0 deletions pointercrate-demonlist-pages/static/js/statsviewer/nation.js
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,10 @@ class NationStatsViewer extends StatsViewer {
onReceive(response) {
super.onReceive(response);

this._rank.innerText = this.currentlySelected.dataset.rank;
this._score.innerHTML =
this.currentlySelected.getElementsByTagName("i")[0].innerHTML;

let nationData = response.data.data;

let selectedSort = this.demonSortingModeDropdown.selected;
Expand Down
9 changes: 5 additions & 4 deletions pointercrate-demonlist/sql/paginate_players_by_id.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,14 @@
SELECT id, players.name::TEXT, banned, nationalities.nation::TEXT, iso_country_code::TEXT, subdivision::TEXT AS iso_code, subdivisions.name AS subdivision_name, players.score
SELECT players.id, players.name::TEXT, banned, nationalities.nation::TEXT, iso_country_code::TEXT, subdivision::TEXT AS iso_code, subdivisions.name AS subdivision_name, players.score, player_ranks.rank
FROM players
LEFT OUTER JOIN nationalities ON nationality = iso_country_code
LEFT OUTER JOIN subdivisions ON iso_code = subdivision AND subdivisions.nation = nationality
WHERE (id < $1 OR $1 IS NULL)
AND (id > $2 OR $2 IS NULL)
LEFT OUTER JOIN player_ranks ON player_ranks.id = players.id
WHERE (players.id < $1 OR $1 IS NULL)
AND (players.id > $2 OR $2 IS NULL)
AND (players.name = $3::CITEXT OR $3 is NULL)
AND (STRPOS(players.name, $4::CITEXT) > 0 OR $4 is NULL)
AND (banned = $5 OR $5 IS NULL)
AND (nationality = $6 OR iso_country_code = $6 OR (nationality IS NULL AND $7) OR ($6 IS NULL AND NOT $7))
AND (subdivision = $8 OR $8 IS NULL)
ORDER BY id {}
ORDER BY players.id {}
LIMIT $9
5 changes: 3 additions & 2 deletions pointercrate-demonlist/src/player/get.rs
Original file line number Diff line number Diff line change
Expand Up @@ -26,8 +26,8 @@ impl Player {

pub async fn by_id(id: i32, connection: &mut PgConnection) -> Result<Player> {
let result = sqlx::query!(
r#"SELECT id, players.name, banned, players.score, nationalities.nation::text, iso_country_code::text, iso_code::text as subdivision_code, subdivisions.name::text as subdivision_name FROM players LEFT OUTER JOIN nationalities ON
players.nationality = nationalities.iso_country_code LEFT OUTER JOIN subdivisions ON players.subdivision = subdivisions.iso_code WHERE id = $1 AND (subdivisions.nation=nationalities.iso_country_code or players.subdivision is null)"#,
r#"SELECT players.id, players.name, banned, players.score, nationalities.nation::text, iso_country_code::text, iso_code::text as subdivision_code, subdivisions.name::text as subdivision_name, player_ranks.rank FROM players LEFT OUTER JOIN nationalities ON
players.nationality = nationalities.iso_country_code LEFT OUTER JOIN subdivisions ON players.subdivision = subdivisions.iso_code LEFT OUTER JOIN player_ranks ON player_ranks.id = players.id WHERE players.id = $1 AND (subdivisions.nation=nationalities.iso_country_code or players.subdivision is null)"#,
id
)
.fetch_one(connection)
Expand Down Expand Up @@ -58,6 +58,7 @@ impl Player {
banned: row.banned,
},
score: row.score,
rank: row.rank,
nationality,
})
},
Expand Down
5 changes: 4 additions & 1 deletion pointercrate-demonlist/src/player/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -59,6 +59,7 @@ pub struct Player {
/// * Player banned
/// * Player objects merged
pub score: f64,
pub rank: Option<i64>,
pub nationality: Option<Nationality>,
}

Expand Down Expand Up @@ -93,6 +94,7 @@ impl DatabasePlayer {

sqlx::query!("UPDATE nationalities SET score = coalesce(score_of_nation(nationalities.iso_country_code), 0) FROM players WHERE players.id = $1 AND players.nationality = nationalities.iso_country_code", self.id).execute(&mut *connection).await?;
sqlx::query!("UPDATE subdivisions SET score = coalesce(score_of_subdivision(subdivisions.nation, subdivisions.iso_code), 0) FROM players WHERE players.id = $1 AND players.nationality = subdivisions.nation AND players.subdivision = subdivisions.iso_code", self.id).execute(&mut *connection).await?;
sqlx::query!("REFRESH MATERIALIZED VIEW CONCURRENTLY player_ranks;").execute(&mut *connection).await?;

Ok(new_score.score)
}
Expand All @@ -101,6 +103,7 @@ impl DatabasePlayer {
pub async fn recompute_scores(connection: &mut PgConnection) -> Result<(), CoreError> {
sqlx::query!("SELECT recompute_player_scores();").execute(&mut *connection).await?;
sqlx::query!("SELECT recompute_nation_scores();").execute(&mut *connection).await?;
sqlx::query!("SELECT recompute_subdivision_scores();").execute(connection).await?;
sqlx::query!("SELECT recompute_subdivision_scores();").execute(&mut *connection).await?;
sqlx::query!("REFRESH MATERIALIZED VIEW CONCURRENTLY player_ranks;").execute(&mut *connection).await?;
Ok(())
}
4 changes: 2 additions & 2 deletions pointercrate-demonlist/src/player/paginate.rs
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,7 @@
banned: row.get("banned"),
},
score: row.get("score"),
rank: row.get("rank"),
nationality,
})
}
Expand Down Expand Up @@ -145,7 +146,6 @@

#[derive(Debug, Serialize)]
pub struct RankedPlayer {
rank: i64,
#[serde(skip)]
index: i64,
#[serde(flatten)]
Expand Down Expand Up @@ -198,11 +198,11 @@
banned: false,
},
score: row.get("score"),
rank: row.get("rank"),

Check warning on line 201 in pointercrate-demonlist/src/player/paginate.rs

View check run for this annotation

Codecov / codecov/patch

pointercrate-demonlist/src/player/paginate.rs#L201

Added line #L201 was not covered by tests
nationality,
};

players.push(RankedPlayer {
rank: row.get("rank"),
index: row.get("index"),
player,
})
Expand Down
36 changes: 36 additions & 0 deletions pointercrate-test/tests/demonlist/player/mod.rs
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,9 @@ use pointercrate_demonlist::{
LIST_HELPER, LIST_MODERATOR,
};
use rocket::http::Status;
use serde_json::json;
use sqlx::{PgConnection, Pool, Postgres};
use pointercrate_demonlist::record::RecordStatus;

mod score;

Expand Down Expand Up @@ -325,3 +327,37 @@ async fn test_players_pagination(pool: Pool<Postgres>) {
})
);
}


#[sqlx::test(migrations = "../migrations")]
async fn test_player_merge(pool: Pool<Postgres>) {
let (client, mut connection) = pointercrate_test::demonlist::setup_rocket(pool).await;
let moderator = pointercrate_test::user::system_user_with_perms(LIST_MODERATOR, &mut connection).await;

/*
* We're creating two players with approved records on the same demon (but different progress) and then rename them to have the same name
* This should merge the two records (keeping the higher progress) and delete one of the player objects.
*/

let player1 = DatabasePlayer::by_name_or_create("stardust1971", &mut connection).await.unwrap();
let player2 = DatabasePlayer::by_name_or_create("stardust1972", &mut connection).await.unwrap();

let demon1 = pointercrate_test::demonlist::add_demon("Bloodbath", 1, 87, player1.id, player1.id, &mut connection).await;

pointercrate_test::demonlist::add_simple_record(90, player1.id, demon1, RecordStatus::Approved, &mut connection).await;
pointercrate_test::demonlist::add_simple_record(95, player2.id, demon1, RecordStatus::Approved, &mut connection).await;

let patched: FullPlayer = client.patch_player(player2.id, &moderator, json!{{"name": "stardust1971"}})
.await
.get_success_result()
.await;

assert_eq!(patched.records.len(), 1);
assert_eq!(patched.records[0].progress, 95);
assert_eq!(patched.player.base.id, player2.id);

client.get(&format!("/api/v1/players/{}/", player1.id))
.expect_status(Status::NotFound)
.execute()
.await;
}
Loading