Improve the frontend and repository layer
This commit is contained in:
464
services/inventory/app/repositories/dashboard_repository.py
Normal file
464
services/inventory/app/repositories/dashboard_repository.py
Normal file
@@ -0,0 +1,464 @@
|
||||
# services/inventory/app/repositories/dashboard_repository.py
|
||||
"""
|
||||
Dashboard Repository for complex dashboard queries
|
||||
"""
|
||||
|
||||
from typing import List, Optional, Dict, Any
|
||||
from uuid import UUID
|
||||
from datetime import datetime
|
||||
from decimal import Decimal
|
||||
from sqlalchemy import text
|
||||
from sqlalchemy.ext.asyncio import AsyncSession
|
||||
import structlog
|
||||
|
||||
logger = structlog.get_logger()
|
||||
|
||||
|
||||
class DashboardRepository:
|
||||
"""Repository for dashboard-specific database queries"""
|
||||
|
||||
def __init__(self, session: AsyncSession):
|
||||
self.session = session
|
||||
|
||||
async def get_business_model_metrics(self, tenant_id: UUID) -> Dict[str, Any]:
|
||||
"""Get ingredient metrics for business model detection"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
COUNT(*) as total_ingredients,
|
||||
COUNT(CASE WHEN product_type::text = 'finished_product' THEN 1 END) as finished_products,
|
||||
COUNT(CASE WHEN product_type::text = 'ingredient' THEN 1 END) as raw_ingredients,
|
||||
COUNT(DISTINCT st.supplier_id) as supplier_count,
|
||||
AVG(CASE WHEN s.available_quantity IS NOT NULL THEN s.available_quantity ELSE 0 END) as avg_stock_level
|
||||
FROM ingredients i
|
||||
LEFT JOIN (
|
||||
SELECT ingredient_id, SUM(available_quantity) as available_quantity
|
||||
FROM stock WHERE tenant_id = :tenant_id GROUP BY ingredient_id
|
||||
) s ON i.id = s.ingredient_id
|
||||
LEFT JOIN (
|
||||
SELECT ingredient_id, supplier_id
|
||||
FROM stock WHERE tenant_id = :tenant_id AND supplier_id IS NOT NULL
|
||||
GROUP BY ingredient_id, supplier_id
|
||||
) st ON i.id = st.ingredient_id
|
||||
WHERE i.tenant_id = :tenant_id AND i.is_active = true
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
row = result.fetchone()
|
||||
|
||||
if not row:
|
||||
return {
|
||||
"total_ingredients": 0,
|
||||
"finished_products": 0,
|
||||
"raw_ingredients": 0,
|
||||
"supplier_count": 0,
|
||||
"avg_stock_level": 0
|
||||
}
|
||||
|
||||
return {
|
||||
"total_ingredients": row.total_ingredients,
|
||||
"finished_products": row.finished_products,
|
||||
"raw_ingredients": row.raw_ingredients,
|
||||
"supplier_count": row.supplier_count,
|
||||
"avg_stock_level": float(row.avg_stock_level) if row.avg_stock_level else 0
|
||||
}
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get business model metrics", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_stock_by_category(self, tenant_id: UUID) -> Dict[str, Dict[str, Any]]:
|
||||
"""Get stock breakdown by category"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
COALESCE(i.ingredient_category::text, i.product_category::text, 'other') as category,
|
||||
COUNT(*) as count,
|
||||
COALESCE(SUM(s.available_quantity * s.unit_cost), 0) as total_value
|
||||
FROM ingredients i
|
||||
LEFT JOIN (
|
||||
SELECT ingredient_id, SUM(available_quantity) as available_quantity, AVG(unit_cost) as unit_cost
|
||||
FROM stock WHERE tenant_id = :tenant_id GROUP BY ingredient_id
|
||||
) s ON i.id = s.ingredient_id
|
||||
WHERE i.tenant_id = :tenant_id AND i.is_active = true
|
||||
GROUP BY category
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
categories = {}
|
||||
|
||||
for row in result.fetchall():
|
||||
categories[row.category] = {
|
||||
"count": row.count,
|
||||
"total_value": float(row.total_value)
|
||||
}
|
||||
|
||||
return categories
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get stock by category", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_alerts_by_severity(self, tenant_id: UUID) -> Dict[str, int]:
|
||||
"""Get active alerts breakdown by severity"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT severity, COUNT(*) as count
|
||||
FROM food_safety_alerts
|
||||
WHERE tenant_id = :tenant_id AND status = 'active'
|
||||
GROUP BY severity
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
alerts = {"critical": 0, "high": 0, "medium": 0, "low": 0}
|
||||
|
||||
for row in result.fetchall():
|
||||
alerts[row.severity] = row.count
|
||||
|
||||
return alerts
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get alerts by severity", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_movements_by_type(self, tenant_id: UUID, days: int = 7) -> Dict[str, int]:
|
||||
"""Get stock movements breakdown by type for recent period"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT sm.movement_type, COUNT(*) as count
|
||||
FROM stock_movements sm
|
||||
JOIN ingredients i ON sm.ingredient_id = i.id
|
||||
WHERE i.tenant_id = :tenant_id
|
||||
AND sm.movement_date > NOW() - INTERVAL '7 days'
|
||||
GROUP BY sm.movement_type
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
movements = {}
|
||||
|
||||
for row in result.fetchall():
|
||||
movements[row.movement_type] = row.count
|
||||
|
||||
return movements
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get movements by type", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_alert_trend(self, tenant_id: UUID, days: int = 30) -> List[Dict[str, Any]]:
|
||||
"""Get alert trend over time"""
|
||||
try:
|
||||
query = text(f"""
|
||||
SELECT
|
||||
DATE(created_at) as alert_date,
|
||||
COUNT(*) as alert_count,
|
||||
COUNT(CASE WHEN severity IN ('high', 'critical') THEN 1 END) as high_severity_count
|
||||
FROM food_safety_alerts
|
||||
WHERE tenant_id = :tenant_id
|
||||
AND created_at > NOW() - INTERVAL '{days} days'
|
||||
GROUP BY DATE(created_at)
|
||||
ORDER BY alert_date
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
|
||||
return [
|
||||
{
|
||||
"date": row.alert_date.isoformat(),
|
||||
"total_alerts": row.alert_count,
|
||||
"high_severity_alerts": row.high_severity_count
|
||||
}
|
||||
for row in result.fetchall()
|
||||
]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get alert trend", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_recent_stock_movements(
|
||||
self,
|
||||
tenant_id: UUID,
|
||||
limit: int = 20
|
||||
) -> List[Dict[str, Any]]:
|
||||
"""Get recent stock movements"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
'stock_movement' as activity_type,
|
||||
CASE
|
||||
WHEN movement_type = 'PURCHASE' THEN 'Stock added: ' || i.name || ' (' || sm.quantity || ' ' || i.unit_of_measure::text || ')'
|
||||
WHEN movement_type = 'PRODUCTION_USE' THEN 'Stock consumed: ' || i.name || ' (' || sm.quantity || ' ' || i.unit_of_measure::text || ')'
|
||||
WHEN movement_type = 'WASTE' THEN 'Stock wasted: ' || i.name || ' (' || sm.quantity || ' ' || i.unit_of_measure::text || ')'
|
||||
WHEN movement_type = 'ADJUSTMENT' THEN 'Stock adjusted: ' || i.name || ' (' || sm.quantity || ' ' || i.unit_of_measure::text || ')'
|
||||
ELSE 'Stock movement: ' || i.name
|
||||
END as description,
|
||||
sm.movement_date as timestamp,
|
||||
sm.created_by as user_id,
|
||||
CASE
|
||||
WHEN movement_type = 'WASTE' THEN 'high'
|
||||
WHEN movement_type = 'ADJUSTMENT' THEN 'medium'
|
||||
ELSE 'low'
|
||||
END as impact_level,
|
||||
sm.id as entity_id,
|
||||
'stock_movement' as entity_type
|
||||
FROM stock_movements sm
|
||||
JOIN ingredients i ON sm.ingredient_id = i.id
|
||||
WHERE i.tenant_id = :tenant_id
|
||||
ORDER BY sm.movement_date DESC
|
||||
LIMIT :limit
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id, "limit": limit})
|
||||
|
||||
return [
|
||||
{
|
||||
"activity_type": row.activity_type,
|
||||
"description": row.description,
|
||||
"timestamp": row.timestamp,
|
||||
"user_id": row.user_id,
|
||||
"impact_level": row.impact_level,
|
||||
"entity_id": row.entity_id,
|
||||
"entity_type": row.entity_type
|
||||
}
|
||||
for row in result.fetchall()
|
||||
]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get recent stock movements", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_recent_food_safety_alerts(
|
||||
self,
|
||||
tenant_id: UUID,
|
||||
limit: int = 20
|
||||
) -> List[Dict[str, Any]]:
|
||||
"""Get recent food safety alerts"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
'food_safety_alert' as activity_type,
|
||||
title as description,
|
||||
created_at as timestamp,
|
||||
created_by as user_id,
|
||||
CASE
|
||||
WHEN severity = 'critical' THEN 'high'
|
||||
WHEN severity = 'high' THEN 'medium'
|
||||
ELSE 'low'
|
||||
END as impact_level,
|
||||
id as entity_id,
|
||||
'food_safety_alert' as entity_type
|
||||
FROM food_safety_alerts
|
||||
WHERE tenant_id = :tenant_id
|
||||
ORDER BY created_at DESC
|
||||
LIMIT :limit
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id, "limit": limit})
|
||||
|
||||
return [
|
||||
{
|
||||
"activity_type": row.activity_type,
|
||||
"description": row.description,
|
||||
"timestamp": row.timestamp,
|
||||
"user_id": row.user_id,
|
||||
"impact_level": row.impact_level,
|
||||
"entity_id": row.entity_id,
|
||||
"entity_type": row.entity_type
|
||||
}
|
||||
for row in result.fetchall()
|
||||
]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get recent food safety alerts", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_live_metrics(self, tenant_id: UUID) -> Dict[str, Any]:
|
||||
"""Get real-time inventory metrics"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
COUNT(DISTINCT i.id) as total_ingredients,
|
||||
COUNT(CASE WHEN s.available_quantity > i.low_stock_threshold THEN 1 END) as in_stock,
|
||||
COUNT(CASE WHEN s.available_quantity <= i.low_stock_threshold THEN 1 END) as low_stock,
|
||||
COUNT(CASE WHEN s.available_quantity = 0 THEN 1 END) as out_of_stock,
|
||||
COALESCE(SUM(s.available_quantity * s.unit_cost), 0) as total_value,
|
||||
COUNT(CASE WHEN s.expiration_date < NOW() THEN 1 END) as expired_items,
|
||||
COUNT(CASE WHEN s.expiration_date BETWEEN NOW() AND NOW() + INTERVAL '7 days' THEN 1 END) as expiring_soon
|
||||
FROM ingredients i
|
||||
LEFT JOIN stock s ON i.id = s.ingredient_id AND s.is_available = true
|
||||
WHERE i.tenant_id = :tenant_id AND i.is_active = true
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
metrics = result.fetchone()
|
||||
|
||||
if not metrics:
|
||||
return {
|
||||
"total_ingredients": 0,
|
||||
"in_stock": 0,
|
||||
"low_stock": 0,
|
||||
"out_of_stock": 0,
|
||||
"total_value": 0.0,
|
||||
"expired_items": 0,
|
||||
"expiring_soon": 0,
|
||||
"last_updated": datetime.now().isoformat()
|
||||
}
|
||||
|
||||
return {
|
||||
"total_ingredients": metrics.total_ingredients,
|
||||
"in_stock": metrics.in_stock,
|
||||
"low_stock": metrics.low_stock,
|
||||
"out_of_stock": metrics.out_of_stock,
|
||||
"total_value": float(metrics.total_value),
|
||||
"expired_items": metrics.expired_items,
|
||||
"expiring_soon": metrics.expiring_soon,
|
||||
"last_updated": datetime.now().isoformat()
|
||||
}
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get live metrics", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_stock_status_by_category(
|
||||
self,
|
||||
tenant_id: UUID
|
||||
) -> List[Dict[str, Any]]:
|
||||
"""Get stock status breakdown by category"""
|
||||
try:
|
||||
query = text("""
|
||||
SELECT
|
||||
COALESCE(i.ingredient_category::text, i.product_category::text, 'other') as category,
|
||||
COUNT(DISTINCT i.id) as total_ingredients,
|
||||
COUNT(CASE WHEN s.available_quantity > i.low_stock_threshold THEN 1 END) as in_stock,
|
||||
COUNT(CASE WHEN s.available_quantity <= i.low_stock_threshold AND s.available_quantity > 0 THEN 1 END) as low_stock,
|
||||
COUNT(CASE WHEN COALESCE(s.available_quantity, 0) = 0 THEN 1 END) as out_of_stock,
|
||||
COALESCE(SUM(s.available_quantity * s.unit_cost), 0) as total_value
|
||||
FROM ingredients i
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
ingredient_id,
|
||||
SUM(available_quantity) as available_quantity,
|
||||
AVG(unit_cost) as unit_cost
|
||||
FROM stock
|
||||
WHERE tenant_id = :tenant_id AND is_available = true
|
||||
GROUP BY ingredient_id
|
||||
) s ON i.id = s.ingredient_id
|
||||
WHERE i.tenant_id = :tenant_id AND i.is_active = true
|
||||
GROUP BY category
|
||||
ORDER BY total_value DESC
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
|
||||
return [
|
||||
{
|
||||
"category": row.category,
|
||||
"total_ingredients": row.total_ingredients,
|
||||
"in_stock": row.in_stock,
|
||||
"low_stock": row.low_stock,
|
||||
"out_of_stock": row.out_of_stock,
|
||||
"total_value": float(row.total_value)
|
||||
}
|
||||
for row in result.fetchall()
|
||||
]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get stock status by category", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_alerts_summary(
|
||||
self,
|
||||
tenant_id: UUID,
|
||||
alert_types: Optional[List[str]] = None,
|
||||
severities: Optional[List[str]] = None,
|
||||
date_from: Optional[datetime] = None,
|
||||
date_to: Optional[datetime] = None
|
||||
) -> List[Dict[str, Any]]:
|
||||
"""Get alerts summary by type and severity with filters"""
|
||||
try:
|
||||
# Build query with filters
|
||||
where_conditions = ["tenant_id = :tenant_id", "status = 'active'"]
|
||||
params = {"tenant_id": tenant_id}
|
||||
|
||||
if alert_types:
|
||||
where_conditions.append("alert_type = ANY(:alert_types)")
|
||||
params["alert_types"] = alert_types
|
||||
|
||||
if severities:
|
||||
where_conditions.append("severity = ANY(:severities)")
|
||||
params["severities"] = severities
|
||||
|
||||
if date_from:
|
||||
where_conditions.append("created_at >= :date_from")
|
||||
params["date_from"] = date_from
|
||||
|
||||
if date_to:
|
||||
where_conditions.append("created_at <= :date_to")
|
||||
params["date_to"] = date_to
|
||||
|
||||
where_clause = " AND ".join(where_conditions)
|
||||
|
||||
query = text(f"""
|
||||
SELECT
|
||||
alert_type,
|
||||
severity,
|
||||
COUNT(*) as count,
|
||||
MIN(EXTRACT(EPOCH FROM (NOW() - created_at))/3600)::int as oldest_alert_age_hours,
|
||||
AVG(CASE WHEN resolved_at IS NOT NULL
|
||||
THEN EXTRACT(EPOCH FROM (resolved_at - created_at))/3600
|
||||
ELSE NULL END)::int as avg_resolution_hours
|
||||
FROM food_safety_alerts
|
||||
WHERE {where_clause}
|
||||
GROUP BY alert_type, severity
|
||||
ORDER BY severity DESC, count DESC
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, params)
|
||||
|
||||
return [
|
||||
{
|
||||
"alert_type": row.alert_type,
|
||||
"severity": row.severity,
|
||||
"count": row.count,
|
||||
"oldest_alert_age_hours": row.oldest_alert_age_hours,
|
||||
"average_resolution_time_hours": row.avg_resolution_hours
|
||||
}
|
||||
for row in result.fetchall()
|
||||
]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get alerts summary", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_ingredient_stock_levels(self, tenant_id: UUID) -> Dict[str, float]:
|
||||
"""
|
||||
Get current stock levels for all ingredients
|
||||
|
||||
Args:
|
||||
tenant_id: Tenant UUID
|
||||
|
||||
Returns:
|
||||
Dictionary mapping ingredient_id to current stock level
|
||||
"""
|
||||
try:
|
||||
stock_query = text("""
|
||||
SELECT
|
||||
i.id as ingredient_id,
|
||||
COALESCE(SUM(s.available_quantity), 0) as current_stock
|
||||
FROM ingredients i
|
||||
LEFT JOIN stock s ON i.id = s.ingredient_id AND s.is_available = true
|
||||
WHERE i.tenant_id = :tenant_id AND i.is_active = true
|
||||
GROUP BY i.id
|
||||
""")
|
||||
|
||||
result = await self.session.execute(stock_query, {"tenant_id": tenant_id})
|
||||
stock_levels = {}
|
||||
|
||||
for row in result.fetchall():
|
||||
stock_levels[str(row.ingredient_id)] = float(row.current_stock)
|
||||
|
||||
return stock_levels
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get ingredient stock levels", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
Reference in New Issue
Block a user