demo seed change
This commit is contained in:
@@ -745,4 +745,176 @@ class StockRepository(BaseRepository[Stock, StockCreate, StockUpdate], BatchCoun
|
||||
error=str(e),
|
||||
stock_id=str(stock_id),
|
||||
tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_expiring_products(self, tenant_id: UUID, days_threshold: int = 7) -> List[Dict[str, Any]]:
|
||||
"""
|
||||
Get products expiring soon or already expired
|
||||
"""
|
||||
try:
|
||||
from sqlalchemy import text
|
||||
query = text("""
|
||||
SELECT
|
||||
i.id as ingredient_id,
|
||||
i.name as ingredient_name,
|
||||
s.id as stock_id,
|
||||
s.batch_number,
|
||||
s.expiration_date,
|
||||
s.current_quantity,
|
||||
i.unit_of_measure,
|
||||
s.unit_cost,
|
||||
(s.current_quantity * s.unit_cost) as total_value,
|
||||
CASE
|
||||
WHEN s.expiration_date < CURRENT_DATE THEN 'expired'
|
||||
WHEN s.expiration_date <= CURRENT_DATE + INTERVAL '1 day' THEN 'expires_today'
|
||||
WHEN s.expiration_date <= CURRENT_DATE + INTERVAL '3 days' THEN 'expires_soon'
|
||||
ELSE 'warning'
|
||||
END as urgency,
|
||||
EXTRACT(DAY FROM (s.expiration_date - CURRENT_DATE)) as days_until_expiry
|
||||
FROM stock s
|
||||
JOIN ingredients i ON s.ingredient_id = i.id
|
||||
WHERE i.tenant_id = :tenant_id
|
||||
AND s.is_available = true
|
||||
AND s.expiration_date <= CURRENT_DATE + (INTERVAL '1 day' * :days_threshold)
|
||||
ORDER BY s.expiration_date ASC, total_value DESC
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {
|
||||
"tenant_id": tenant_id,
|
||||
"days_threshold": days_threshold
|
||||
})
|
||||
return [dict(row._mapping) for row in result.fetchall()]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get expiring products", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_temperature_breaches(self, tenant_id: UUID, hours_back: int = 24) -> List[Dict[str, Any]]:
|
||||
"""
|
||||
Get temperature monitoring breaches
|
||||
"""
|
||||
try:
|
||||
from sqlalchemy import text
|
||||
query = text("""
|
||||
SELECT
|
||||
tl.id,
|
||||
tl.equipment_id,
|
||||
tl.equipment_name,
|
||||
tl.storage_type,
|
||||
tl.temperature_celsius,
|
||||
tl.min_threshold,
|
||||
tl.max_threshold,
|
||||
tl.is_within_range,
|
||||
tl.recorded_at,
|
||||
tl.alert_triggered,
|
||||
EXTRACT(EPOCH FROM (NOW() - tl.recorded_at))/3600 as hours_ago,
|
||||
CASE
|
||||
WHEN tl.temperature_celsius < tl.min_threshold
|
||||
THEN tl.min_threshold - tl.temperature_celsius
|
||||
WHEN tl.temperature_celsius > tl.max_threshold
|
||||
THEN tl.temperature_celsius - tl.max_threshold
|
||||
ELSE 0
|
||||
END as deviation
|
||||
FROM temperature_logs tl
|
||||
WHERE tl.tenant_id = :tenant_id
|
||||
AND tl.is_within_range = false
|
||||
AND tl.recorded_at > NOW() - (INTERVAL '1 hour' * :hours_back)
|
||||
AND tl.alert_triggered = false
|
||||
ORDER BY deviation DESC, tl.recorded_at DESC
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {
|
||||
"tenant_id": tenant_id,
|
||||
"hours_back": hours_back
|
||||
})
|
||||
return [dict(row._mapping) for row in result.fetchall()]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get temperature breaches", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_waste_opportunities(self, tenant_id: UUID) -> List[Dict[str, Any]]:
|
||||
"""
|
||||
Identify waste reduction opportunities
|
||||
"""
|
||||
try:
|
||||
from sqlalchemy import text
|
||||
query = text("""
|
||||
WITH waste_analysis AS (
|
||||
SELECT
|
||||
i.id as ingredient_id,
|
||||
i.name as ingredient_name,
|
||||
i.ingredient_category,
|
||||
COUNT(sm.id) as waste_incidents,
|
||||
SUM(sm.quantity) as total_waste_quantity,
|
||||
SUM(sm.total_cost) as total_waste_cost,
|
||||
AVG(sm.quantity) as avg_waste_per_incident,
|
||||
MAX(sm.movement_date) as last_waste_date
|
||||
FROM stock_movements sm
|
||||
JOIN ingredients i ON sm.ingredient_id = i.id
|
||||
WHERE i.tenant_id = :tenant_id
|
||||
AND sm.movement_type = 'WASTE'
|
||||
AND sm.movement_date > NOW() - INTERVAL '30 days'
|
||||
GROUP BY i.id, i.name, i.ingredient_category
|
||||
HAVING COUNT(sm.id) >= 3 OR SUM(sm.total_cost) > 50
|
||||
)
|
||||
SELECT * FROM waste_analysis
|
||||
ORDER BY total_waste_cost DESC, waste_incidents DESC
|
||||
LIMIT 20
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
return [dict(row._mapping) for row in result.fetchall()]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get waste opportunities", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
|
||||
async def get_reorder_recommendations(self, tenant_id: UUID) -> List[Dict[str, Any]]:
|
||||
"""
|
||||
Get ingredients that need reordering based on stock levels and usage
|
||||
"""
|
||||
try:
|
||||
from sqlalchemy import text
|
||||
query = text("""
|
||||
WITH usage_analysis AS (
|
||||
SELECT
|
||||
i.id,
|
||||
i.name,
|
||||
COALESCE(SUM(s.current_quantity), 0) as current_stock,
|
||||
i.reorder_point,
|
||||
i.low_stock_threshold,
|
||||
COALESCE(SUM(sm.quantity) FILTER (WHERE sm.movement_date > NOW() - INTERVAL '7 days'), 0) / 7 as daily_usage,
|
||||
i.preferred_supplier_id,
|
||||
i.standard_order_quantity
|
||||
FROM ingredients i
|
||||
LEFT JOIN stock s ON s.ingredient_id = i.id AND s.is_available = true
|
||||
LEFT JOIN stock_movements sm ON sm.ingredient_id = i.id
|
||||
AND sm.movement_type = 'PRODUCTION_USE'
|
||||
AND sm.movement_date > NOW() - INTERVAL '7 days'
|
||||
WHERE i.tenant_id = :tenant_id
|
||||
AND i.is_active = true
|
||||
GROUP BY i.id, i.name, i.reorder_point, i.low_stock_threshold,
|
||||
i.preferred_supplier_id, i.standard_order_quantity
|
||||
)
|
||||
SELECT *,
|
||||
CASE
|
||||
WHEN daily_usage > 0 THEN FLOOR(current_stock / NULLIF(daily_usage, 0))
|
||||
ELSE 999
|
||||
END as days_of_stock,
|
||||
GREATEST(
|
||||
standard_order_quantity,
|
||||
CEIL(daily_usage * 14)
|
||||
) as recommended_order_quantity
|
||||
FROM usage_analysis
|
||||
WHERE current_stock <= reorder_point
|
||||
ORDER BY days_of_stock ASC, current_stock ASC
|
||||
LIMIT 50
|
||||
""")
|
||||
|
||||
result = await self.session.execute(query, {"tenant_id": tenant_id})
|
||||
return [dict(row._mapping) for row in result.fetchall()]
|
||||
|
||||
except Exception as e:
|
||||
logger.error("Failed to get reorder recommendations", error=str(e), tenant_id=str(tenant_id))
|
||||
raise
|
||||
Reference in New Issue
Block a user