405 lines
10 KiB
Rust
405 lines
10 KiB
Rust
//! Realm management database queries.
|
|
//!
|
|
//! These queries are used by the owner interface and require the chattyness_owner role.
|
|
|
|
use sqlx::PgPool;
|
|
use uuid::Uuid;
|
|
|
|
use crate::models::{
|
|
OwnerCreateRealmRequest, RealmDetail, RealmListItem, RealmPrivacy, UpdateRealmRequest,
|
|
};
|
|
use chattyness_error::AppError;
|
|
|
|
use super::helpers::{generate_random_token, hash_password};
|
|
|
|
/// List all realms with owner info (for admin interface).
|
|
pub async fn list_realms_with_owner(
|
|
pool: &PgPool,
|
|
limit: i64,
|
|
offset: i64,
|
|
) -> Result<Vec<RealmListItem>, AppError> {
|
|
let realms = sqlx::query_as::<_, RealmListItem>(
|
|
r#"
|
|
SELECT
|
|
r.id,
|
|
r.name,
|
|
r.slug,
|
|
r.tagline,
|
|
r.privacy,
|
|
r.is_nsfw,
|
|
r.owner_id,
|
|
u.username as owner_username,
|
|
r.member_count,
|
|
COALESCE((
|
|
SELECT COUNT(*)::INTEGER
|
|
FROM scene.instance_members im
|
|
JOIN realm.scenes s ON im.instance_id = s.id
|
|
WHERE s.realm_id = r.id
|
|
), 0) AS current_user_count,
|
|
r.created_at
|
|
FROM realm.realms r
|
|
JOIN auth.users u ON r.owner_id = u.id
|
|
ORDER BY r.created_at DESC
|
|
LIMIT $1 OFFSET $2
|
|
"#,
|
|
)
|
|
.bind(limit)
|
|
.bind(offset)
|
|
.fetch_all(pool)
|
|
.await?;
|
|
|
|
Ok(realms)
|
|
}
|
|
|
|
/// Search realms by name or slug.
|
|
pub async fn search_realms(
|
|
pool: &PgPool,
|
|
query: &str,
|
|
limit: i64,
|
|
) -> Result<Vec<RealmListItem>, AppError> {
|
|
let pattern = format!("%{}%", query);
|
|
let realms = sqlx::query_as::<_, RealmListItem>(
|
|
r#"
|
|
SELECT
|
|
r.id,
|
|
r.name,
|
|
r.slug,
|
|
r.tagline,
|
|
r.privacy,
|
|
r.is_nsfw,
|
|
r.owner_id,
|
|
u.username as owner_username,
|
|
r.member_count,
|
|
COALESCE((
|
|
SELECT COUNT(*)::INTEGER
|
|
FROM scene.instance_members im
|
|
JOIN realm.scenes s ON im.instance_id = s.id
|
|
WHERE s.realm_id = r.id
|
|
), 0) AS current_user_count,
|
|
r.created_at
|
|
FROM realm.realms r
|
|
JOIN auth.users u ON r.owner_id = u.id
|
|
WHERE
|
|
r.name ILIKE $1
|
|
OR r.slug ILIKE $1
|
|
ORDER BY
|
|
CASE
|
|
WHEN r.slug ILIKE $1 THEN 1
|
|
WHEN r.name ILIKE $1 THEN 2
|
|
ELSE 3
|
|
END,
|
|
r.name
|
|
LIMIT $2
|
|
"#,
|
|
)
|
|
.bind(&pattern)
|
|
.bind(limit)
|
|
.fetch_all(pool)
|
|
.await?;
|
|
|
|
Ok(realms)
|
|
}
|
|
|
|
/// Create a new realm with an existing user as owner.
|
|
#[allow(clippy::too_many_arguments)]
|
|
pub async fn create_realm(
|
|
pool: &PgPool,
|
|
owner_id: Uuid,
|
|
name: &str,
|
|
slug: &str,
|
|
description: Option<&str>,
|
|
tagline: Option<&str>,
|
|
privacy: RealmPrivacy,
|
|
is_nsfw: bool,
|
|
max_users: i32,
|
|
allow_guest_access: bool,
|
|
theme_color: Option<&str>,
|
|
) -> Result<Uuid, AppError> {
|
|
// Start a transaction
|
|
let mut tx = pool.begin().await?;
|
|
|
|
// Create the realm
|
|
let realm_id = sqlx::query_scalar::<_, Uuid>(
|
|
r#"
|
|
INSERT INTO realm.realms (
|
|
name, slug, description, tagline, owner_id,
|
|
privacy, is_nsfw, max_users, allow_guest_access, theme_color
|
|
)
|
|
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
|
|
RETURNING id
|
|
"#,
|
|
)
|
|
.bind(name)
|
|
.bind(slug)
|
|
.bind(description)
|
|
.bind(tagline)
|
|
.bind(owner_id)
|
|
.bind(privacy)
|
|
.bind(is_nsfw)
|
|
.bind(max_users)
|
|
.bind(allow_guest_access)
|
|
.bind(theme_color)
|
|
.fetch_one(&mut *tx)
|
|
.await?;
|
|
|
|
// Add owner as realm member with owner role
|
|
sqlx::query(
|
|
r#"
|
|
INSERT INTO realm.memberships (realm_id, user_id, role)
|
|
VALUES ($1, $2, 'owner')
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.bind(owner_id)
|
|
.execute(&mut *tx)
|
|
.await?;
|
|
|
|
tx.commit().await?;
|
|
|
|
Ok(realm_id)
|
|
}
|
|
|
|
/// Create a realm with a new user as owner (atomically).
|
|
/// Returns (realm_id, user_id, plaintext_token) - the token should be shown to the server owner.
|
|
pub async fn create_realm_with_new_owner(
|
|
pool: &PgPool,
|
|
req: &OwnerCreateRealmRequest,
|
|
) -> Result<(Uuid, Uuid, String), AppError> {
|
|
let new_owner = req
|
|
.new_owner
|
|
.as_ref()
|
|
.ok_or_else(|| AppError::Validation("new_owner is required".to_string()))?;
|
|
|
|
// Generate a random token as the temporary password
|
|
let token = generate_random_token();
|
|
let password_hash = hash_password(&token)?;
|
|
|
|
// Start a transaction
|
|
let mut tx = pool.begin().await?;
|
|
|
|
// Create the user with force_pw_reset = true
|
|
let user_id = sqlx::query_scalar::<_, Uuid>(
|
|
r#"
|
|
INSERT INTO auth.users (username, email, display_name, password_hash, force_pw_reset)
|
|
VALUES ($1, $2, $3, $4, true)
|
|
RETURNING id
|
|
"#,
|
|
)
|
|
.bind(&new_owner.username)
|
|
.bind(&new_owner.email)
|
|
.bind(&new_owner.display_name)
|
|
.bind(&password_hash)
|
|
.fetch_one(&mut *tx)
|
|
.await?;
|
|
|
|
// Create the realm
|
|
let realm_id = sqlx::query_scalar::<_, Uuid>(
|
|
r#"
|
|
INSERT INTO realm.realms (
|
|
name, slug, description, tagline, owner_id,
|
|
privacy, is_nsfw, max_users, allow_guest_access, theme_color
|
|
)
|
|
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)
|
|
RETURNING id
|
|
"#,
|
|
)
|
|
.bind(&req.name)
|
|
.bind(&req.slug)
|
|
.bind(&req.description)
|
|
.bind(&req.tagline)
|
|
.bind(user_id)
|
|
.bind(req.privacy)
|
|
.bind(req.is_nsfw)
|
|
.bind(req.max_users)
|
|
.bind(req.allow_guest_access)
|
|
.bind(&req.theme_color)
|
|
.fetch_one(&mut *tx)
|
|
.await?;
|
|
|
|
// Add owner as realm member with owner role
|
|
sqlx::query(
|
|
r#"
|
|
INSERT INTO realm.memberships (realm_id, user_id, role)
|
|
VALUES ($1, $2, 'owner')
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.bind(user_id)
|
|
.execute(&mut *tx)
|
|
.await?;
|
|
|
|
tx.commit().await?;
|
|
|
|
Ok((realm_id, user_id, token))
|
|
}
|
|
|
|
/// Get a realm by slug with full details for editing.
|
|
pub async fn get_realm_by_slug(pool: &PgPool, slug: &str) -> Result<RealmDetail, AppError> {
|
|
let realm = sqlx::query_as::<_, RealmDetail>(
|
|
r#"
|
|
SELECT
|
|
r.id,
|
|
r.name,
|
|
r.slug,
|
|
r.description,
|
|
r.tagline,
|
|
r.owner_id,
|
|
u.username as owner_username,
|
|
u.display_name as owner_display_name,
|
|
r.privacy,
|
|
r.is_nsfw,
|
|
r.min_reputation_tier,
|
|
r.theme_color,
|
|
r.banner_image_path,
|
|
r.thumbnail_path,
|
|
r.max_users,
|
|
r.allow_guest_access,
|
|
r.member_count,
|
|
COALESCE((
|
|
SELECT COUNT(*)::INTEGER
|
|
FROM scene.instance_members im
|
|
JOIN realm.scenes s ON im.instance_id = s.id
|
|
WHERE s.realm_id = r.id
|
|
), 0) AS current_user_count,
|
|
r.created_at,
|
|
r.updated_at
|
|
FROM realm.realms r
|
|
JOIN auth.users u ON r.owner_id = u.id
|
|
WHERE r.slug = $1
|
|
"#,
|
|
)
|
|
.bind(slug)
|
|
.fetch_optional(pool)
|
|
.await?
|
|
.ok_or_else(|| AppError::NotFound(format!("Realm with slug '{}' not found", slug)))?;
|
|
|
|
Ok(realm)
|
|
}
|
|
|
|
/// Update a realm's settings.
|
|
pub async fn update_realm(
|
|
pool: &PgPool,
|
|
realm_id: Uuid,
|
|
req: &UpdateRealmRequest,
|
|
) -> Result<RealmDetail, AppError> {
|
|
// Update the realm
|
|
sqlx::query(
|
|
r#"
|
|
UPDATE realm.realms
|
|
SET
|
|
name = $1,
|
|
description = $2,
|
|
tagline = $3,
|
|
privacy = $4,
|
|
is_nsfw = $5,
|
|
max_users = $6,
|
|
allow_guest_access = $7,
|
|
theme_color = $8,
|
|
updated_at = now()
|
|
WHERE id = $9
|
|
"#,
|
|
)
|
|
.bind(&req.name)
|
|
.bind(&req.description)
|
|
.bind(&req.tagline)
|
|
.bind(req.privacy)
|
|
.bind(req.is_nsfw)
|
|
.bind(req.max_users)
|
|
.bind(req.allow_guest_access)
|
|
.bind(&req.theme_color)
|
|
.bind(realm_id)
|
|
.execute(pool)
|
|
.await?;
|
|
|
|
// Fetch and return the updated realm
|
|
let realm = sqlx::query_as::<_, RealmDetail>(
|
|
r#"
|
|
SELECT
|
|
r.id,
|
|
r.name,
|
|
r.slug,
|
|
r.description,
|
|
r.tagline,
|
|
r.owner_id,
|
|
u.username as owner_username,
|
|
u.display_name as owner_display_name,
|
|
r.privacy,
|
|
r.is_nsfw,
|
|
r.min_reputation_tier,
|
|
r.theme_color,
|
|
r.banner_image_path,
|
|
r.thumbnail_path,
|
|
r.max_users,
|
|
r.allow_guest_access,
|
|
r.member_count,
|
|
COALESCE((
|
|
SELECT COUNT(*)::INTEGER
|
|
FROM scene.instance_members im
|
|
JOIN realm.scenes s ON im.instance_id = s.id
|
|
WHERE s.realm_id = r.id
|
|
), 0) AS current_user_count,
|
|
r.created_at,
|
|
r.updated_at
|
|
FROM realm.realms r
|
|
JOIN auth.users u ON r.owner_id = u.id
|
|
WHERE r.id = $1
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.fetch_one(pool)
|
|
.await?;
|
|
|
|
Ok(realm)
|
|
}
|
|
|
|
/// Transfer realm ownership to a different user.
|
|
pub async fn transfer_realm_ownership(
|
|
pool: &PgPool,
|
|
realm_id: Uuid,
|
|
new_owner_id: Uuid,
|
|
) -> Result<(), AppError> {
|
|
let mut tx = pool.begin().await?;
|
|
|
|
// Get current owner_id
|
|
let current_owner_id =
|
|
sqlx::query_scalar::<_, Uuid>(r#"SELECT owner_id FROM realm.realms WHERE id = $1"#)
|
|
.bind(realm_id)
|
|
.fetch_one(&mut *tx)
|
|
.await?;
|
|
|
|
// Update realm owner
|
|
sqlx::query(r#"UPDATE realm.realms SET owner_id = $1, updated_at = now() WHERE id = $2"#)
|
|
.bind(new_owner_id)
|
|
.bind(realm_id)
|
|
.execute(&mut *tx)
|
|
.await?;
|
|
|
|
// Update old owner's membership role to member (or remove?)
|
|
sqlx::query(
|
|
r#"
|
|
UPDATE realm.memberships
|
|
SET role = 'moderator'
|
|
WHERE realm_id = $1 AND user_id = $2
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.bind(current_owner_id)
|
|
.execute(&mut *tx)
|
|
.await?;
|
|
|
|
// Ensure new owner has membership with owner role
|
|
sqlx::query(
|
|
r#"
|
|
INSERT INTO realm.memberships (realm_id, user_id, role)
|
|
VALUES ($1, $2, 'owner')
|
|
ON CONFLICT (realm_id, user_id) DO UPDATE SET role = 'owner'
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.bind(new_owner_id)
|
|
.execute(&mut *tx)
|
|
.await?;
|
|
|
|
tx.commit().await?;
|
|
Ok(())
|
|
}
|