add winner endpoints
This commit is contained in:
parent
98568e38e2
commit
2d7e39d69c
17
migrations/20230416145528_winners.sql
Normal file
17
migrations/20230416145528_winners.sql
Normal file
@ -0,0 +1,17 @@
|
||||
CREATE TABLE prizes (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR NOT NULL,
|
||||
points_min INTEGER NOT NULL,
|
||||
description TEXT NOT NULL,
|
||||
directions_to_claim TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE winners (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
prize_id INTEGER NOT NULL,
|
||||
date TIMESTAMP NOT NULL,
|
||||
claimed BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
FOREIGN KEY (user_id) REFERENCES users(id),
|
||||
FOREIGN KEY (prize_id) REFERENCES prizes(id)
|
||||
);
|
||||
@ -135,7 +135,7 @@ pub async fn get_recent_events(
|
||||
e.created_by
|
||||
FROM events e
|
||||
INNER JOIN event_attendees ea
|
||||
ON ea.event_id = e.id AND ea.confirmed
|
||||
ON ea.event_id = e.id
|
||||
WHERE
|
||||
ea.user_id = $1
|
||||
;
|
||||
|
||||
@ -68,7 +68,7 @@ pub async fn list_points(
|
||||
LEFT JOIN events e
|
||||
ON ea.event_id = e.id
|
||||
GROUP BY u.id
|
||||
ORDER BY points
|
||||
ORDER BY points DESC
|
||||
;
|
||||
"#,
|
||||
)
|
||||
|
||||
@ -5,6 +5,7 @@ mod leaderboard;
|
||||
mod models;
|
||||
mod report;
|
||||
mod user;
|
||||
mod winner;
|
||||
|
||||
use axum::{
|
||||
routing::{delete, get, post, put},
|
||||
@ -54,6 +55,10 @@ async fn main() {
|
||||
.route("/attending/unmark", delete(attending::unmark_attending))
|
||||
.route("/leaderboard/my_points", get(leaderboard::get_points))
|
||||
.route("/leaderboard/list_points", get(leaderboard::list_points))
|
||||
.route("/winners/select", post(winner::select_winners))
|
||||
.route("/winners/recent", get(winner::get_recent_winners))
|
||||
.route("/winners/unclaimed", get(winner::get_unclaimed_winners))
|
||||
.route("/winners/mark", put(winner::mark_claimed))
|
||||
.with_state(AppState {
|
||||
db_pool,
|
||||
jwt_encode,
|
||||
|
||||
@ -1,6 +1,31 @@
|
||||
use serde::{Deserialize, Serialize};
|
||||
use sqlx::types::{chrono::NaiveDateTime, time::OffsetDateTime, BigDecimal};
|
||||
|
||||
/// The model for a winner of a prize.
|
||||
#[derive(
|
||||
sqlx::Type, Clone, Hash, Debug, PartialEq, Eq, PartialOrd, Ord, Serialize, Deserialize,
|
||||
)]
|
||||
pub struct WinnerEntry {
|
||||
pub user_id: i32,
|
||||
pub username: String,
|
||||
pub prize_id: i32,
|
||||
pub prize_name: String,
|
||||
pub prize_description: String,
|
||||
#[serde(with = "serde_datetime")]
|
||||
pub date: NaiveDateTime,
|
||||
pub claimed: bool,
|
||||
}
|
||||
|
||||
#[derive(Copy, Clone, Hash, Debug, PartialEq, Eq, PartialOrd, Ord, Serialize, Deserialize)]
|
||||
pub struct PrizeQuery {
|
||||
pub prize_id: Option<i32>,
|
||||
}
|
||||
|
||||
#[derive(Copy, Clone, Hash, Debug, PartialEq, Eq, PartialOrd, Ord, Serialize, Deserialize)]
|
||||
pub struct WinnerQuery {
|
||||
pub winner_id: i32,
|
||||
}
|
||||
|
||||
/// The possible event types.
|
||||
#[derive(
|
||||
sqlx::Type, Copy, Clone, Hash, Debug, PartialEq, Eq, PartialOrd, Ord, Serialize, Deserialize,
|
||||
|
||||
222
src/winner.rs
Normal file
222
src/winner.rs
Normal file
@ -0,0 +1,222 @@
|
||||
use axum::response::IntoResponse;
|
||||
use axum::{
|
||||
extract::{Query, State},
|
||||
http::StatusCode,
|
||||
response::Response,
|
||||
Json,
|
||||
};
|
||||
use axum_auth::AuthBearer;
|
||||
use serde_json::json;
|
||||
use sqlx::{query, query_as};
|
||||
|
||||
use crate::models::{WinnerEntry, WinnerQuery};
|
||||
use crate::{
|
||||
jwt::handle_token,
|
||||
models::{PrizeQuery, Role},
|
||||
AppState,
|
||||
};
|
||||
|
||||
pub async fn select_winners(
|
||||
AuthBearer(token): AuthBearer,
|
||||
State(app_state): State<AppState>,
|
||||
Query(prize_query): Query<PrizeQuery>,
|
||||
) -> Response {
|
||||
if let Err(err) = handle_token(token, &app_state, Role::Admin) {
|
||||
return err;
|
||||
};
|
||||
|
||||
let result = query!(
|
||||
r#"
|
||||
WITH weighted_users AS (
|
||||
SELECT
|
||||
u.id,
|
||||
u.username,
|
||||
COALESCE(SUM(e.points), 0) AS points,
|
||||
RANDOM() * COALESCE(SUM(e.points), 0) AS random_value
|
||||
FROM
|
||||
users u
|
||||
LEFT JOIN event_attendees ea
|
||||
ON u.id = ea.user_id AND ea.confirmed = true
|
||||
LEFT JOIN events e
|
||||
ON ea.event_id = e.id
|
||||
GROUP BY u.id
|
||||
ORDER BY random_value DESC
|
||||
),
|
||||
prize_winners AS (
|
||||
SELECT p.id AS prize_id, u.id AS user_id
|
||||
FROM prizes p
|
||||
CROSS JOIN LATERAL (
|
||||
SELECT
|
||||
id, points
|
||||
FROM weighted_users
|
||||
WHERE points > p.points_min
|
||||
LIMIT 1
|
||||
) u
|
||||
WHERE p.id = $1 OR $2
|
||||
)
|
||||
|
||||
INSERT INTO winners (user_id, prize_id, date)
|
||||
SELECT pw.user_id, pw.prize_id, now() as date
|
||||
FROM prize_winners pw
|
||||
"#,
|
||||
prize_query.prize_id.unwrap_or(0),
|
||||
prize_query.prize_id.is_none(),
|
||||
)
|
||||
.execute(&app_state.db_pool)
|
||||
.await;
|
||||
|
||||
match result {
|
||||
Ok(record) => (
|
||||
StatusCode::OK,
|
||||
Json(json!({"winners_generated": record.rows_affected()})),
|
||||
),
|
||||
Err(err) => (
|
||||
StatusCode::INTERNAL_SERVER_ERROR,
|
||||
Json(json!({
|
||||
"error": format!("Unknown error generating winners: {:?}", err)
|
||||
})),
|
||||
),
|
||||
}
|
||||
.into_response()
|
||||
}
|
||||
|
||||
pub async fn get_recent_winners(
|
||||
AuthBearer(token): AuthBearer,
|
||||
State(app_state): State<AppState>,
|
||||
Query(prize_query): Query<PrizeQuery>,
|
||||
) -> Response {
|
||||
if let Err(err) = handle_token(token, &app_state, Role::Student) {
|
||||
return err;
|
||||
};
|
||||
|
||||
let result = query_as!(
|
||||
WinnerEntry,
|
||||
r#"
|
||||
SELECT
|
||||
w.user_id,
|
||||
u.username,
|
||||
w.prize_id,
|
||||
p.name as prize_name,
|
||||
p.description as prize_description,
|
||||
w.date,
|
||||
w.claimed
|
||||
FROM winners w
|
||||
INNER JOIN users u
|
||||
ON u.id = w.user_id
|
||||
INNER JOIN prizes p
|
||||
ON p.id = w.prize_id
|
||||
WHERE
|
||||
date BETWEEN now() - interval '1 week' AND now() AND
|
||||
(
|
||||
p.id = $1 OR $2
|
||||
)
|
||||
ORDER BY date DESC
|
||||
|
||||
"#,
|
||||
prize_query.prize_id.unwrap_or(0),
|
||||
prize_query.prize_id.is_none(),
|
||||
)
|
||||
.fetch_all(&app_state.db_pool)
|
||||
.await;
|
||||
|
||||
match result {
|
||||
Ok(winners) => (StatusCode::OK, Json(json!(winners))),
|
||||
Err(err) => (
|
||||
StatusCode::INTERNAL_SERVER_ERROR,
|
||||
Json(json!({
|
||||
"error": format!("Unknown error getting winners: {:?}", err)
|
||||
})),
|
||||
),
|
||||
}
|
||||
.into_response()
|
||||
}
|
||||
|
||||
pub async fn get_unclaimed_winners(
|
||||
AuthBearer(token): AuthBearer,
|
||||
State(app_state): State<AppState>,
|
||||
) -> Response {
|
||||
if let Err(err) = handle_token(token, &app_state, Role::Student) {
|
||||
return err;
|
||||
};
|
||||
|
||||
let result = query_as!(
|
||||
WinnerEntry,
|
||||
r#"
|
||||
SELECT
|
||||
w.user_id,
|
||||
u.username,
|
||||
w.prize_id,
|
||||
p.name as prize_name,
|
||||
p.description as prize_description,
|
||||
w.date,
|
||||
w.claimed
|
||||
FROM winners w
|
||||
INNER JOIN users u
|
||||
ON u.id = w.user_id
|
||||
INNER JOIN prizes p
|
||||
ON p.id = w.prize_id
|
||||
WHERE
|
||||
w.claimed = false
|
||||
ORDER BY date DESC
|
||||
"#,
|
||||
)
|
||||
.fetch_all(&app_state.db_pool)
|
||||
.await;
|
||||
|
||||
match result {
|
||||
Ok(winners) => (StatusCode::OK, Json(json!(winners))),
|
||||
Err(err) => (
|
||||
StatusCode::INTERNAL_SERVER_ERROR,
|
||||
Json(json!({
|
||||
"error": format!("Unknown error getting winners: {:?}", err)
|
||||
})),
|
||||
),
|
||||
}
|
||||
.into_response()
|
||||
}
|
||||
|
||||
pub async fn mark_claimed(
|
||||
AuthBearer(token): AuthBearer,
|
||||
State(app_state): State<AppState>,
|
||||
Query(winner_query): Query<WinnerQuery>,
|
||||
) -> Response {
|
||||
if let Err(err) = handle_token(token, &app_state, Role::Student) {
|
||||
return err;
|
||||
};
|
||||
|
||||
let result = query!(
|
||||
r#"
|
||||
UPDATE winners
|
||||
SET
|
||||
claimed = true
|
||||
WHERE
|
||||
id = $1
|
||||
"#,
|
||||
winner_query.winner_id,
|
||||
)
|
||||
.execute(&app_state.db_pool)
|
||||
.await;
|
||||
|
||||
match result {
|
||||
Ok(record) => {
|
||||
if (record.rows_affected() == 0) {
|
||||
(
|
||||
StatusCode::BAD_REQUEST,
|
||||
Json(json!({ "error": format!("winner_id not found") })),
|
||||
)
|
||||
} else {
|
||||
(
|
||||
StatusCode::OK,
|
||||
Json(json!({"updated": record.rows_affected()})),
|
||||
)
|
||||
}
|
||||
}
|
||||
Err(err) => (
|
||||
StatusCode::INTERNAL_SERVER_ERROR,
|
||||
Json(json!({
|
||||
"error": format!("Unknown error getting winners: {:?}", err)
|
||||
})),
|
||||
),
|
||||
}
|
||||
.into_response()
|
||||
}
|
||||
Loading…
Reference in New Issue
Block a user