From 3fcf24958b5aefa09d2e0aba99b8b47b21df84a6 Mon Sep 17 00:00:00 2001 From: Philipp Hofer Date: Thu, 8 Jan 2026 20:14:57 +0100 Subject: [PATCH] show all users on ranking board; be able to merge users --- src/model/stat.rs | 18 +- src/model/user/merge.rs | 490 +++++++++++++++++++++++++++ src/model/user/mod.rs | 1 + src/tera/admin/user.rs | 94 +++++ templates/admin/user/index.html.tera | 3 + templates/admin/user/merge.html.tera | 141 ++++++++ 6 files changed, 732 insertions(+), 15 deletions(-) create mode 100644 src/model/user/merge.rs create mode 100644 templates/admin/user/merge.html.tera diff --git a/src/model/stat.rs b/src/model/stat.rs index c49b36c..69a9380 100644 --- a/src/model/stat.rs +++ b/src/model/stat.rs @@ -133,19 +133,14 @@ WHERE l.distance_in_km IS NOT NULL {year_filter} AND not b.external; let guest_km: i32 = guests.get(0); let guest_amount_trips: i32 = guests.get(1); - // e.g. scheckbücher + // e.g. scheckbücher (users without any role) let guest_user = sqlx::query(&format!( " SELECT CAST(SUM(l.distance_in_km) AS INTEGER) AS rowed_km, COUNT(*) AS amount_trips FROM user u INNER JOIN rower r ON u.id = r.rower_id INNER JOIN logbook l ON r.logbook_id = l.id -WHERE u.id NOT IN ( - SELECT ur.user_id - FROM user_role ur - INNER JOIN role ro ON ur.role_id = ro.id - WHERE ro.name = 'Donau Linz' -) +WHERE u.id NOT IN (SELECT user_id FROM user_role) AND l.distance_in_km IS NOT NULL {year_filter} AND u.name != 'Externe Steuerperson'; @@ -195,14 +190,7 @@ AND u.name != 'Externe Steuerperson'; sqlx::query(&format!( " SELECT u.name, CAST(SUM(l.distance_in_km) AS INTEGER) AS rowed_km, COUNT(*) AS amount_trips -FROM ( - SELECT * FROM user - WHERE id IN ( - SELECT user_id FROM user_role - JOIN role ON user_role.role_id = role.id - WHERE role.name = 'Donau Linz' - ) -) u +FROM user u INNER JOIN rower r ON u.id = r.rower_id INNER JOIN logbook l ON r.logbook_id = l.id WHERE l.distance_in_km IS NOT NULL {year_filter} AND u.name != 'Externe Steuerperson' diff --git a/src/model/user/merge.rs b/src/model/user/merge.rs new file mode 100644 index 0000000..5efab0a --- /dev/null +++ b/src/model/user/merge.rs @@ -0,0 +1,490 @@ +use serde::Serialize; +use sqlx::{Row, Sqlite, SqlitePool, Transaction}; +use std::ops::DerefMut; + +use super::{ManageUserUser, User}; +use crate::model::{activity::ActivityBuilder, stat::Stat}; + +#[derive(Serialize, Debug, Clone)] +pub struct UserWithKm { + pub id: i64, + pub name: String, + pub total_km: i32, + pub trip_count: i32, + pub deleted: bool, +} + +impl UserWithKm { + /// Get all users with their total km stats, sorted by name + pub async fn all(db: &SqlitePool) -> Vec { + sqlx::query( + " + SELECT u.id, u.name, u.deleted, + COALESCE(CAST(SUM(l.distance_in_km) AS INTEGER), 0) AS total_km, + COUNT(r.logbook_id) AS trip_count + FROM user u + LEFT JOIN rower r ON u.id = r.rower_id + LEFT JOIN logbook l ON r.logbook_id = l.id AND l.distance_in_km IS NOT NULL + WHERE u.name != 'Externe Steuerperson' + GROUP BY u.id + ORDER BY u.name COLLATE NOCASE + ", + ) + .fetch_all(db) + .await + .unwrap() + .into_iter() + .map(|row| UserWithKm { + id: row.get("id"), + name: row.get("name"), + total_km: row.get("total_km"), + trip_count: row.get("trip_count"), + deleted: row.get("deleted"), + }) + .collect() + } +} + +#[derive(Serialize, Debug)] +pub struct MergePreview { + pub source_user: User, + pub target_user: User, + pub source_total_km: i32, + pub target_total_km: i32, + pub source_trip_count: i32, + pub target_trip_count: i32, + pub rower_entries_to_transfer: i64, + pub rower_conflicts: i64, + pub role_entries_to_transfer: i64, + pub role_conflicts: i64, + pub user_trip_entries_to_transfer: i64, + pub user_trip_conflicts: i64, + pub logbook_shipmaster_entries: i64, + pub logbook_steering_entries: i64, + pub trip_cox_entries: i64, + pub boat_owner_entries: i64, + pub boat_damage_entries: i64, + pub boat_reservation_entries: i64, + pub trailer_reservation_entries: i64, + pub notification_entries: i64, +} + +impl User { + /// Generate a preview of what would happen if source user is merged into target user. + /// Source user will be deleted, target user will receive all references. + pub async fn merge_preview(db: &SqlitePool, source: &User, target: &User) -> MergePreview { + let source_stats = Stat::total_km(db, source).await; + let target_stats = Stat::total_km(db, target).await; + + // Rower entries to transfer (no conflict - source is in logbooks target isn't) + let rower_entries_to_transfer = sqlx::query_scalar!( + "SELECT COUNT(*) FROM rower + WHERE rower_id = ? + AND logbook_id NOT IN (SELECT logbook_id FROM rower WHERE rower_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // Rower conflicts (both users in same logbook - will delete source's entry) + let rower_conflicts = sqlx::query_scalar!( + "SELECT COUNT(*) FROM rower + WHERE rower_id = ? + AND logbook_id IN (SELECT logbook_id FROM rower WHERE rower_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // Role entries to transfer (no conflict) + let role_entries_to_transfer = sqlx::query_scalar!( + "SELECT COUNT(*) FROM user_role + WHERE user_id = ? + AND role_id NOT IN (SELECT role_id FROM user_role WHERE user_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // Role conflicts (both have same role - will delete source's entry) + let role_conflicts = sqlx::query_scalar!( + "SELECT COUNT(*) FROM user_role + WHERE user_id = ? + AND role_id IN (SELECT role_id FROM user_role WHERE user_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // User trip entries to transfer (no conflict) + let user_trip_entries_to_transfer = sqlx::query_scalar!( + "SELECT COUNT(*) FROM user_trip + WHERE user_id = ? + AND trip_details_id NOT IN (SELECT trip_details_id FROM user_trip WHERE user_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // User trip conflicts + let user_trip_conflicts = sqlx::query_scalar!( + "SELECT COUNT(*) FROM user_trip + WHERE user_id = ? + AND trip_details_id IN (SELECT trip_details_id FROM user_trip WHERE user_id = ?)", + source.id, + target.id + ) + .fetch_one(db) + .await + .unwrap(); + + // Simple counts for other tables + let logbook_shipmaster_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM logbook WHERE shipmaster = ?", + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + let logbook_steering_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM logbook WHERE steering_person = ?", + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + let trip_cox_entries = + sqlx::query_scalar!("SELECT COUNT(*) FROM trip WHERE cox_id = ?", source.id) + .fetch_one(db) + .await + .unwrap(); + + let boat_owner_entries = + sqlx::query_scalar!("SELECT COUNT(*) FROM boat WHERE owner = ?", source.id) + .fetch_one(db) + .await + .unwrap(); + + let boat_damage_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM boat_damage + WHERE user_id_created = ? OR user_id_fixed = ? OR user_id_verified = ?", + source.id, + source.id, + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + let boat_reservation_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM boat_reservation + WHERE user_id_applicant = ? OR user_id_confirmation = ?", + source.id, + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + let trailer_reservation_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM trailer_reservation + WHERE user_id_applicant = ? OR user_id_confirmation = ?", + source.id, + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + let notification_entries = sqlx::query_scalar!( + "SELECT COUNT(*) FROM notification WHERE user_id = ?", + source.id + ) + .fetch_one(db) + .await + .unwrap(); + + MergePreview { + source_user: source.clone(), + target_user: target.clone(), + source_total_km: source_stats.rowed_km, + target_total_km: target_stats.rowed_km, + source_trip_count: source_stats.amount_trips, + target_trip_count: target_stats.amount_trips, + rower_entries_to_transfer, + rower_conflicts, + role_entries_to_transfer, + role_conflicts, + user_trip_entries_to_transfer, + user_trip_conflicts, + logbook_shipmaster_entries, + logbook_steering_entries, + trip_cox_entries, + boat_owner_entries, + boat_damage_entries, + boat_reservation_entries, + trailer_reservation_entries, + notification_entries, + } + } + + /// Merge source user into target user, then hard delete source. + /// All foreign key references are transferred from source to target. + /// Returns Ok(()) on success, Err with description on failure. + pub async fn merge_into( + db: &SqlitePool, + source: &User, + target: &User, + merged_by: &ManageUserUser, + ) -> Result<(), String> { + // Validation + if source.id == target.id { + return Err("Kann Benutzer nicht mit sich selbst zusammenführen".into()); + } + + if source.name == "Externe Steuerperson" { + return Err("'Externe Steuerperson' kann nicht zusammengeführt werden".into()); + } + + if source.on_water(db).await { + return Err(format!( + "{} ist gerade auf dem Wasser und kann nicht zusammengeführt werden", + source.name + )); + } + + let mut tx = db.begin().await.unwrap(); + + // Execute merge in transaction + Self::merge_into_tx(&mut tx, source, target).await?; + + // Log activity + ActivityBuilder::new(&format!( + "{} hat Benutzer '{}' ({} km, {} Ausfahrten) in '{}' zusammengeführt und gelöscht.", + merged_by.name, + source.name, + Stat::total_km(db, source).await.rowed_km, + Stat::total_km(db, source).await.amount_trips, + target.name + )) + .user(target) + .save_tx(&mut tx) + .await; + + tx.commit().await.unwrap(); + + Ok(()) + } + + async fn merge_into_tx( + tx: &mut Transaction<'_, Sqlite>, + source: &User, + target: &User, + ) -> Result<(), String> { + // Step 1: DELETE conflicts (where both users have same FK target) + + // Delete rower entries where both users rowed in same logbook + sqlx::query!( + "DELETE FROM rower + WHERE rower_id = ? + AND logbook_id IN (SELECT logbook_id FROM rower WHERE rower_id = ?)", + source.id, + target.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // Delete role entries where both users have same role + sqlx::query!( + "DELETE FROM user_role + WHERE user_id = ? + AND role_id IN (SELECT role_id FROM user_role WHERE user_id = ?)", + source.id, + target.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // Delete user_trip entries where both users in same trip + sqlx::query!( + "DELETE FROM user_trip + WHERE user_id = ? + AND trip_details_id IN (SELECT trip_details_id FROM user_trip WHERE user_id = ?)", + source.id, + target.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // Step 2: UPDATE remaining references + + // rower.rower_id + sqlx::query!( + "UPDATE rower SET rower_id = ? WHERE rower_id = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // user_role.user_id + sqlx::query!( + "UPDATE user_role SET user_id = ? WHERE user_id = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // user_trip.user_id + sqlx::query!( + "UPDATE user_trip SET user_id = ? WHERE user_id = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // logbook.shipmaster + sqlx::query!( + "UPDATE logbook SET shipmaster = ? WHERE shipmaster = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // logbook.steering_person + sqlx::query!( + "UPDATE logbook SET steering_person = ? WHERE steering_person = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // trip.cox_id + sqlx::query!( + "UPDATE trip SET cox_id = ? WHERE cox_id = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // boat.owner + sqlx::query!( + "UPDATE boat SET owner = ? WHERE owner = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // boat_damage (3 columns) + sqlx::query!( + "UPDATE boat_damage SET user_id_created = ? WHERE user_id_created = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + sqlx::query!( + "UPDATE boat_damage SET user_id_fixed = ? WHERE user_id_fixed = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + sqlx::query!( + "UPDATE boat_damage SET user_id_verified = ? WHERE user_id_verified = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // boat_reservation (2 columns) + sqlx::query!( + "UPDATE boat_reservation SET user_id_applicant = ? WHERE user_id_applicant = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + sqlx::query!( + "UPDATE boat_reservation SET user_id_confirmation = ? WHERE user_id_confirmation = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // trailer_reservation (2 columns) + sqlx::query!( + "UPDATE trailer_reservation SET user_id_applicant = ? WHERE user_id_applicant = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + sqlx::query!( + "UPDATE trailer_reservation SET user_id_confirmation = ? WHERE user_id_confirmation = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // notification.user_id + sqlx::query!( + "UPDATE notification SET user_id = ? WHERE user_id = ?", + target.id, + source.id + ) + .execute(tx.deref_mut()) + .await + .unwrap(); + + // Step 3: Hard delete the source user + sqlx::query!("DELETE FROM user WHERE id = ?", source.id) + .execute(tx.deref_mut()) + .await + .unwrap(); + + Ok(()) + } +} diff --git a/src/model/user/mod.rs b/src/model/user/mod.rs index 42a4f95..1034337 100644 --- a/src/model/user/mod.rs +++ b/src/model/user/mod.rs @@ -33,6 +33,7 @@ pub(crate) mod clubmember; mod fee; pub(crate) mod foerdernd; pub(crate) mod member; +pub mod merge; pub(crate) mod regular; pub(crate) mod scheckbuch; pub(crate) mod schnupperant; diff --git a/src/tera/admin/user.rs b/src/tera/admin/user.rs index 4cf5ebb..81e8ffb 100644 --- a/src/tera/admin/user.rs +++ b/src/tera/admin/user.rs @@ -306,6 +306,97 @@ async fn delete(db: &State, admin: ManageUserUser, user: i32) -> Fla } } +use crate::model::user::merge::UserWithKm; + +#[get("/user/merge?&")] +async fn merge_page( + db: &State, + admin: ManageUserUser, + flash: Option>, + source: Option, + target: Option, +) -> Template { + let users_with_km = UserWithKm::all(db).await; + + let admin_user: User = admin.into_inner(); + + let mut context = Context::new(); + if let Some(msg) = flash { + context.insert("flash", &msg.into_inner()); + } + context.insert("users", &users_with_km); + + // If both source and target are selected, show preview + if let (Some(source_id), Some(target_id)) = (source, target) { + if source_id != target_id { + if let (Some(source_user), Some(target_user)) = ( + User::find_by_id(db, source_id).await, + User::find_by_id(db, target_id).await, + ) { + let preview = User::merge_preview(db, &source_user, &target_user).await; + context.insert("source_user", &source_user); + context.insert("target_user", &target_user); + context.insert("preview", &preview); + } + } + } + + context.insert("selected_source", &source); + context.insert("selected_target", &target); + context.insert( + "loggedin_user", + &UserWithDetails::from_user(admin_user, db).await, + ); + + Template::render("admin/user/merge", context.into_json()) +} + +#[derive(FromForm, Debug)] +pub struct MergeForm { + source_id: i32, + target_id: i32, +} + +#[post("/user/merge", data = "")] +async fn merge_execute( + db: &State, + admin: ManageUserUser, + data: Form, +) -> Flash { + let Some(source_user) = User::find_by_id(db, data.source_id).await else { + return Flash::error( + Redirect::to("/admin/user/merge"), + format!("User mit ID {} existiert nicht", data.source_id), + ); + }; + + let Some(target_user) = User::find_by_id(db, data.target_id).await else { + return Flash::error( + Redirect::to("/admin/user/merge"), + format!("Ziel-User mit ID {} existiert nicht", data.target_id), + ); + }; + + let source_name = source_user.name.clone(); + + match User::merge_into(db, &source_user, &target_user, &admin).await { + Ok(()) => Flash::success( + Redirect::to(format!("/admin/user/{}", data.target_id)), + format!( + "Benutzer '{}' erfolgreich in '{}' zusammengeführt", + source_name, target_user.name + ), + ), + Err(e) => Flash::error( + Redirect::to(format!( + "/admin/user/merge?source={}&target={}", + data.source_id, data.target_id + )), + e, + ), + } +} + #[derive(FromForm, Debug)] pub struct MailUpdateForm { mail: String, @@ -1437,6 +1528,9 @@ pub fn routes() -> Vec { view, resetpw, delete, + // Merge + merge_page, + merge_execute, fees, fees_paid, scheckbuch, diff --git a/templates/admin/user/index.html.tera b/templates/admin/user/index.html.tera index 19219bd..8fe72cd 100644 --- a/templates/admin/user/index.html.tera +++ b/templates/admin/user/index.html.tera @@ -4,6 +4,9 @@

Users

{% if allowed_to_edit %} +
Neue Person hinzufügen diff --git a/templates/admin/user/merge.html.tera b/templates/admin/user/merge.html.tera new file mode 100644 index 0000000..c829c1e --- /dev/null +++ b/templates/admin/user/merge.html.tera @@ -0,0 +1,141 @@ +{% import "includes/macros" as macros %} +{% extends "base" %} +{% block content %} +
+ +

Benutzer zusammenführen

+

+ Wähle zwei Benutzer aus: Der erste (Quelle) wird gelöscht und alle Daten werden zum zweiten (Ziel) übertragen. +

+ +
+
+

Quelle (wird gelöscht)

+
+ {% if selected_target %} + + {% endif %} + +
+
+ +
+

Ziel (bleibt erhalten)

+
+ {% if selected_source %} + + {% endif %} + +
+
+
+ + {% if preview %} +
+

Vorschau der Änderungen

+ +
+
+

+ {{ source_user.name }} + (wird gelöscht) +

+
    +
  • {{ preview.source_total_km }} km
  • +
  • {{ preview.source_trip_count }} Ausfahrten
  • +
+
+ +
+ → +
+ +
+

+ {{ target_user.name }} + (bleibt) +

+
    +
  • {{ preview.target_total_km }} km
  • +
  • {{ preview.target_trip_count }} Ausfahrten
  • +
+
+
+ +
+

Nach Zusammenführung:

+

+ {{ target_user.name }} wird haben: + {{ preview.source_total_km + preview.target_total_km }} km, + {{ preview.source_trip_count + preview.target_trip_count - preview.rower_conflicts }} Ausfahrten +

+
+ + {% set total_to_transfer = preview.rower_entries_to_transfer + preview.role_entries_to_transfer + preview.user_trip_entries_to_transfer + preview.logbook_shipmaster_entries + preview.logbook_steering_entries %} + {% if total_to_transfer > 0 %} +
+

Daten die übertragen werden:

+
    + {% if preview.rower_entries_to_transfer > 0 %} +
  • {{ preview.rower_entries_to_transfer }} Ausfahrten
  • + {% endif %} + {% if preview.role_entries_to_transfer > 0 %} +
  • {{ preview.role_entries_to_transfer }} Rollen
  • + {% endif %} + {% if preview.logbook_shipmaster_entries > 0 %} +
  • {{ preview.logbook_shipmaster_entries }} Logbuch-Einträge (als Schiffsführer)
  • + {% endif %} + {% if preview.logbook_steering_entries > 0 %} +
  • {{ preview.logbook_steering_entries }} Logbuch-Einträge (als Steuerperson)
  • + {% endif %} +
+
+ {% endif %} + + {% set total_conflicts = preview.rower_conflicts + preview.role_conflicts + preview.user_trip_conflicts %} + {% if total_conflicts > 0 %} +
+

+ {{ total_conflicts }} doppelte Einträge werden entfernt +

+
    + {% if preview.rower_conflicts > 0 %} +
  • {{ preview.rower_conflicts }} Ausfahrten (beide waren im selben Boot)
  • + {% endif %} + {% if preview.role_conflicts > 0 %} +
  • {{ preview.role_conflicts }} Rollen (beide haben dieselbe Rolle)
  • + {% endif %} +
+
+ {% endif %} + +
+ + + Abbrechen + +
+
+ {% endif %} +
+{% endblock content %}