546 lines
17 KiB
Rust
546 lines
17 KiB
Rust
//! Inventory-related database queries.
|
|
|
|
use sqlx::PgExecutor;
|
|
use uuid::Uuid;
|
|
|
|
use crate::models::{InventoryItem, PropAcquisitionInfo};
|
|
use chattyness_error::AppError;
|
|
|
|
/// List all inventory items for a user.
|
|
pub async fn list_user_inventory<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
user_id: Uuid,
|
|
) -> Result<Vec<InventoryItem>, AppError> {
|
|
let items = sqlx::query_as::<_, InventoryItem>(
|
|
r#"
|
|
SELECT
|
|
id,
|
|
prop_name,
|
|
prop_asset_path,
|
|
layer,
|
|
is_transferable,
|
|
is_portable,
|
|
is_droppable,
|
|
origin,
|
|
acquired_at
|
|
FROM auth.inventory
|
|
WHERE user_id = $1
|
|
ORDER BY acquired_at DESC
|
|
"#,
|
|
)
|
|
.bind(user_id)
|
|
.fetch_all(executor)
|
|
.await?;
|
|
|
|
Ok(items)
|
|
}
|
|
|
|
/// Drop a prop (remove from inventory).
|
|
/// Returns an error if the prop is non-droppable (essential prop).
|
|
pub async fn drop_inventory_item<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
user_id: Uuid,
|
|
item_id: Uuid,
|
|
) -> Result<(), AppError> {
|
|
// Use a CTE to check existence/droppability and delete in a single query
|
|
// Returns: (existed, was_droppable, was_deleted)
|
|
let result: Option<(bool, bool, bool)> = sqlx::query_as(
|
|
r#"
|
|
WITH item_info AS (
|
|
SELECT id, is_droppable
|
|
FROM auth.inventory
|
|
WHERE id = $1 AND user_id = $2
|
|
),
|
|
deleted AS (
|
|
DELETE FROM auth.inventory
|
|
WHERE id = $1 AND user_id = $2 AND is_droppable = true
|
|
RETURNING id
|
|
)
|
|
SELECT
|
|
EXISTS(SELECT 1 FROM item_info) AS existed,
|
|
COALESCE((SELECT is_droppable FROM item_info), false) AS was_droppable,
|
|
EXISTS(SELECT 1 FROM deleted) AS was_deleted
|
|
"#,
|
|
)
|
|
.bind(item_id)
|
|
.bind(user_id)
|
|
.fetch_optional(executor)
|
|
.await?;
|
|
|
|
match result {
|
|
Some((false, _, _)) | None => {
|
|
return Err(AppError::NotFound(
|
|
"Inventory item not found or not owned by user".to_string(),
|
|
));
|
|
}
|
|
Some((true, false, _)) => {
|
|
return Err(AppError::Forbidden(
|
|
"This prop cannot be dropped - it is an essential prop".to_string(),
|
|
));
|
|
}
|
|
Some((true, true, true)) => {
|
|
// Successfully deleted
|
|
}
|
|
Some((true, true, false)) => {
|
|
// Should not happen - item existed, was droppable, but wasn't deleted
|
|
return Err(AppError::Internal(
|
|
"Unexpected error dropping inventory item".to_string(),
|
|
));
|
|
}
|
|
}
|
|
|
|
Ok(())
|
|
}
|
|
|
|
/// List public server props with optional acquisition status.
|
|
///
|
|
/// Returns props that are active and public, with flags indicating:
|
|
/// - `user_owns`: Whether the user already has this prop (false if no user_id)
|
|
/// - `is_claimed`: Whether a unique prop has been claimed by anyone
|
|
/// - `is_available`: Whether the prop is within its availability window
|
|
///
|
|
/// When `user_id` is None, returns default values for user-specific fields.
|
|
pub async fn list_server_props<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
user_id: Option<Uuid>,
|
|
) -> Result<Vec<PropAcquisitionInfo>, AppError> {
|
|
let props = sqlx::query_as::<_, PropAcquisitionInfo>(
|
|
r#"
|
|
SELECT
|
|
p.id,
|
|
p.name,
|
|
p.asset_path,
|
|
p.description,
|
|
p.is_unique,
|
|
CASE
|
|
WHEN $1::uuid IS NOT NULL THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $1 AND i.server_prop_id = p.id
|
|
)
|
|
ELSE false
|
|
END AS user_owns,
|
|
CASE
|
|
WHEN p.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.server_prop_id = p.id
|
|
)
|
|
ELSE false
|
|
END AS is_claimed,
|
|
(p.available_from IS NULL OR p.available_from <= now())
|
|
AND (p.available_until IS NULL OR p.available_until > now()) AS is_available
|
|
FROM server.props p
|
|
WHERE p.is_active = true
|
|
AND p.is_public = true
|
|
ORDER BY p.name ASC
|
|
"#,
|
|
)
|
|
.bind(user_id)
|
|
.fetch_all(executor)
|
|
.await?;
|
|
|
|
Ok(props)
|
|
}
|
|
|
|
/// List public realm props with optional acquisition status.
|
|
///
|
|
/// Returns props that are active and public in the specified realm, with flags indicating:
|
|
/// - `user_owns`: Whether the user already has this prop (false if no user_id)
|
|
/// - `is_claimed`: Whether a unique prop has been claimed by anyone
|
|
/// - `is_available`: Whether the prop is within its availability window
|
|
///
|
|
/// When `user_id` is None, returns default values for user-specific fields.
|
|
pub async fn list_realm_props<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
realm_id: Uuid,
|
|
user_id: Option<Uuid>,
|
|
) -> Result<Vec<PropAcquisitionInfo>, AppError> {
|
|
let props = sqlx::query_as::<_, PropAcquisitionInfo>(
|
|
r#"
|
|
SELECT
|
|
p.id,
|
|
p.name,
|
|
p.asset_path,
|
|
p.description,
|
|
p.is_unique,
|
|
CASE
|
|
WHEN $2::uuid IS NOT NULL THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $2 AND i.realm_prop_id = p.id
|
|
)
|
|
ELSE false
|
|
END AS user_owns,
|
|
CASE
|
|
WHEN p.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.realm_prop_id = p.id
|
|
)
|
|
ELSE false
|
|
END AS is_claimed,
|
|
(p.available_from IS NULL OR p.available_from <= now())
|
|
AND (p.available_until IS NULL OR p.available_until > now()) AS is_available
|
|
FROM realm.props p
|
|
WHERE p.realm_id = $1
|
|
AND p.is_active = true
|
|
AND p.is_public = true
|
|
ORDER BY p.name ASC
|
|
"#,
|
|
)
|
|
.bind(realm_id)
|
|
.bind(user_id)
|
|
.fetch_all(executor)
|
|
.await?;
|
|
|
|
Ok(props)
|
|
}
|
|
|
|
/// Acquire a server prop into user's inventory.
|
|
///
|
|
/// Atomically validates and acquires the prop:
|
|
/// - Validates prop is active, public, within availability window
|
|
/// - For unique props: checks no one owns it yet
|
|
/// - For non-unique props: checks user doesn't already own it
|
|
/// - Inserts into `auth.inventory` with `origin = server_library`
|
|
///
|
|
/// Returns the created inventory item or an appropriate error.
|
|
pub async fn acquire_server_prop<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
prop_id: Uuid,
|
|
user_id: Uuid,
|
|
) -> Result<InventoryItem, AppError> {
|
|
// Use a CTE to atomically check conditions and insert
|
|
let result: Option<InventoryItem> = sqlx::query_as(
|
|
r#"
|
|
WITH prop_check AS (
|
|
SELECT
|
|
p.id,
|
|
p.name,
|
|
p.asset_path,
|
|
p.default_layer,
|
|
p.is_unique,
|
|
p.is_transferable,
|
|
p.is_portable,
|
|
p.is_droppable,
|
|
p.is_active,
|
|
p.is_public,
|
|
(p.available_from IS NULL OR p.available_from <= now()) AS available_from_ok,
|
|
(p.available_until IS NULL OR p.available_until > now()) AS available_until_ok
|
|
FROM server.props p
|
|
WHERE p.id = $1
|
|
),
|
|
ownership_check AS (
|
|
SELECT
|
|
pc.*,
|
|
EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $2 AND i.server_prop_id = $1
|
|
) AS user_owns,
|
|
CASE
|
|
WHEN pc.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.server_prop_id = $1
|
|
)
|
|
ELSE false
|
|
END AS is_claimed
|
|
FROM prop_check pc
|
|
),
|
|
inserted AS (
|
|
INSERT INTO auth.inventory (
|
|
user_id,
|
|
server_prop_id,
|
|
prop_name,
|
|
prop_asset_path,
|
|
layer,
|
|
origin,
|
|
is_transferable,
|
|
is_portable,
|
|
is_droppable
|
|
)
|
|
SELECT
|
|
$2,
|
|
oc.id,
|
|
oc.name,
|
|
oc.asset_path,
|
|
oc.default_layer,
|
|
'server_library'::server.prop_origin,
|
|
oc.is_transferable,
|
|
oc.is_portable,
|
|
oc.is_droppable
|
|
FROM ownership_check oc
|
|
WHERE oc.is_active = true
|
|
AND oc.is_public = true
|
|
AND oc.available_from_ok = true
|
|
AND oc.available_until_ok = true
|
|
AND oc.user_owns = false
|
|
AND oc.is_claimed = false
|
|
RETURNING
|
|
id,
|
|
prop_name,
|
|
prop_asset_path,
|
|
layer,
|
|
is_transferable,
|
|
is_portable,
|
|
is_droppable,
|
|
origin,
|
|
acquired_at
|
|
)
|
|
SELECT * FROM inserted
|
|
"#,
|
|
)
|
|
.bind(prop_id)
|
|
.bind(user_id)
|
|
.fetch_optional(executor)
|
|
.await?;
|
|
|
|
match result {
|
|
Some(item) => Ok(item),
|
|
None => {
|
|
// Need to determine the specific error case
|
|
// We'll do a separate query to understand why it failed
|
|
Err(AppError::Conflict(
|
|
"Unable to acquire prop - it may not exist, not be available, or already owned"
|
|
.to_string(),
|
|
))
|
|
}
|
|
}
|
|
}
|
|
|
|
/// Get detailed acquisition error for a server prop.
|
|
///
|
|
/// This is called when acquire_server_prop fails to determine the specific error.
|
|
pub async fn get_server_prop_acquisition_error<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
prop_id: Uuid,
|
|
user_id: Uuid,
|
|
) -> Result<AppError, AppError> {
|
|
#[derive(sqlx::FromRow)]
|
|
#[allow(dead_code)]
|
|
struct PropStatus {
|
|
exists: bool,
|
|
is_active: bool,
|
|
is_public: bool,
|
|
is_available: bool,
|
|
is_unique: bool,
|
|
user_owns: bool,
|
|
is_claimed: bool,
|
|
}
|
|
|
|
let status: Option<PropStatus> = sqlx::query_as(
|
|
r#"
|
|
SELECT
|
|
true AS exists,
|
|
p.is_active,
|
|
p.is_public,
|
|
(p.available_from IS NULL OR p.available_from <= now())
|
|
AND (p.available_until IS NULL OR p.available_until > now()) AS is_available,
|
|
p.is_unique,
|
|
EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $2 AND i.server_prop_id = $1
|
|
) AS user_owns,
|
|
CASE
|
|
WHEN p.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.server_prop_id = $1
|
|
)
|
|
ELSE false
|
|
END AS is_claimed
|
|
FROM server.props p
|
|
WHERE p.id = $1
|
|
"#,
|
|
)
|
|
.bind(prop_id)
|
|
.bind(user_id)
|
|
.fetch_optional(executor)
|
|
.await?;
|
|
|
|
match status {
|
|
None => Ok(AppError::NotFound("Server prop not found".to_string())),
|
|
Some(s) if !s.is_active || !s.is_public => {
|
|
Ok(AppError::Forbidden("This prop is not available".to_string()))
|
|
}
|
|
Some(s) if !s.is_available => Ok(AppError::Forbidden(
|
|
"This prop is not currently available".to_string(),
|
|
)),
|
|
Some(s) if s.user_owns => Ok(AppError::Conflict("You already own this prop".to_string())),
|
|
Some(s) if s.is_claimed => Ok(AppError::Conflict(
|
|
"This unique prop has already been claimed by another user".to_string(),
|
|
)),
|
|
Some(_) => Ok(AppError::Internal(
|
|
"Unknown error acquiring prop".to_string(),
|
|
)),
|
|
}
|
|
}
|
|
|
|
/// Acquire a realm prop into user's inventory.
|
|
///
|
|
/// Atomically validates and acquires the prop:
|
|
/// - Validates prop belongs to realm, is active, public, within availability window
|
|
/// - For unique props: checks no one owns it yet
|
|
/// - For non-unique props: checks user doesn't already own it
|
|
/// - Inserts into `auth.inventory` with `origin = realm_library`
|
|
///
|
|
/// Returns the created inventory item or an appropriate error.
|
|
pub async fn acquire_realm_prop<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
prop_id: Uuid,
|
|
realm_id: Uuid,
|
|
user_id: Uuid,
|
|
) -> Result<InventoryItem, AppError> {
|
|
// Use a CTE to atomically check conditions and insert
|
|
let result: Option<InventoryItem> = sqlx::query_as(
|
|
r#"
|
|
WITH prop_check AS (
|
|
SELECT
|
|
p.id,
|
|
p.name,
|
|
p.asset_path,
|
|
p.default_layer,
|
|
p.is_unique,
|
|
p.is_transferable,
|
|
p.is_droppable,
|
|
p.is_active,
|
|
p.is_public,
|
|
(p.available_from IS NULL OR p.available_from <= now()) AS available_from_ok,
|
|
(p.available_until IS NULL OR p.available_until > now()) AS available_until_ok
|
|
FROM realm.props p
|
|
WHERE p.id = $1 AND p.realm_id = $2
|
|
),
|
|
ownership_check AS (
|
|
SELECT
|
|
pc.*,
|
|
EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $3 AND i.realm_prop_id = $1
|
|
) AS user_owns,
|
|
CASE
|
|
WHEN pc.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.realm_prop_id = $1
|
|
)
|
|
ELSE false
|
|
END AS is_claimed
|
|
FROM prop_check pc
|
|
),
|
|
inserted AS (
|
|
INSERT INTO auth.inventory (
|
|
user_id,
|
|
realm_prop_id,
|
|
prop_name,
|
|
prop_asset_path,
|
|
layer,
|
|
origin,
|
|
is_transferable,
|
|
is_portable,
|
|
is_droppable
|
|
)
|
|
SELECT
|
|
$3,
|
|
oc.id,
|
|
oc.name,
|
|
oc.asset_path,
|
|
oc.default_layer,
|
|
'realm_library'::server.prop_origin,
|
|
oc.is_transferable,
|
|
true, -- realm props are portable by default
|
|
oc.is_droppable
|
|
FROM ownership_check oc
|
|
WHERE oc.is_active = true
|
|
AND oc.is_public = true
|
|
AND oc.available_from_ok = true
|
|
AND oc.available_until_ok = true
|
|
AND oc.user_owns = false
|
|
AND oc.is_claimed = false
|
|
RETURNING
|
|
id,
|
|
prop_name,
|
|
prop_asset_path,
|
|
layer,
|
|
is_transferable,
|
|
is_portable,
|
|
is_droppable,
|
|
origin,
|
|
acquired_at
|
|
)
|
|
SELECT * FROM inserted
|
|
"#,
|
|
)
|
|
.bind(prop_id)
|
|
.bind(realm_id)
|
|
.bind(user_id)
|
|
.fetch_optional(executor)
|
|
.await?;
|
|
|
|
match result {
|
|
Some(item) => Ok(item),
|
|
None => {
|
|
// Need to determine the specific error case
|
|
Err(AppError::Conflict(
|
|
"Unable to acquire prop - it may not exist, not be available, or already owned"
|
|
.to_string(),
|
|
))
|
|
}
|
|
}
|
|
}
|
|
|
|
/// Get detailed acquisition error for a realm prop.
|
|
///
|
|
/// This is called when acquire_realm_prop fails to determine the specific error.
|
|
pub async fn get_realm_prop_acquisition_error<'e>(
|
|
executor: impl PgExecutor<'e>,
|
|
prop_id: Uuid,
|
|
realm_id: Uuid,
|
|
user_id: Uuid,
|
|
) -> Result<AppError, AppError> {
|
|
#[derive(sqlx::FromRow)]
|
|
#[allow(dead_code)]
|
|
struct PropStatus {
|
|
exists: bool,
|
|
is_active: bool,
|
|
is_public: bool,
|
|
is_available: bool,
|
|
is_unique: bool,
|
|
user_owns: bool,
|
|
is_claimed: bool,
|
|
}
|
|
|
|
let status: Option<PropStatus> = sqlx::query_as(
|
|
r#"
|
|
SELECT
|
|
true AS exists,
|
|
p.is_active,
|
|
p.is_public,
|
|
(p.available_from IS NULL OR p.available_from <= now())
|
|
AND (p.available_until IS NULL OR p.available_until > now()) AS is_available,
|
|
p.is_unique,
|
|
EXISTS(
|
|
SELECT 1 FROM auth.inventory i
|
|
WHERE i.user_id = $3 AND i.realm_prop_id = $1
|
|
) AS user_owns,
|
|
CASE
|
|
WHEN p.is_unique THEN EXISTS(
|
|
SELECT 1 FROM auth.inventory i WHERE i.realm_prop_id = $1
|
|
)
|
|
ELSE false
|
|
END AS is_claimed
|
|
FROM realm.props p
|
|
WHERE p.id = $1 AND p.realm_id = $2
|
|
"#,
|
|
)
|
|
.bind(prop_id)
|
|
.bind(realm_id)
|
|
.bind(user_id)
|
|
.fetch_optional(executor)
|
|
.await?;
|
|
|
|
match status {
|
|
None => Ok(AppError::NotFound("Realm prop not found".to_string())),
|
|
Some(s) if !s.is_active || !s.is_public => {
|
|
Ok(AppError::Forbidden("This prop is not available".to_string()))
|
|
}
|
|
Some(s) if !s.is_available => Ok(AppError::Forbidden(
|
|
"This prop is not currently available".to_string(),
|
|
)),
|
|
Some(s) if s.user_owns => Ok(AppError::Conflict("You already own this prop".to_string())),
|
|
Some(s) if s.is_claimed => Ok(AppError::Conflict(
|
|
"This unique prop has already been claimed by another user".to_string(),
|
|
)),
|
|
Some(_) => Ok(AppError::Internal(
|
|
"Unknown error acquiring prop".to_string(),
|
|
)),
|
|
}
|
|
}
|