diff --git a/src/maximo/service.py b/src/maximo/service.py index ec90ca9..0292963 100644 --- a/src/maximo/service.py +++ b/src/maximo/service.py @@ -1,5 +1,5 @@ from datetime import datetime -from sqlalchemy import select, func, cast, Numeric +from sqlalchemy import select, func, cast, Numeric, text from sqlalchemy.orm import Session from sqlalchemy import and_ from sqlalchemy.sql import not_ @@ -8,72 +8,144 @@ from src.database.core import CollectorDbSession async def get_cm_cost_summary(collector_db: CollectorDbSession, last_oh_date:datetime, upcoming_oh_date:datetime): - query = select( - WorkOrderData.location, - (func.sum(WorkOrderData.total_cost_max).cast(Numeric) / func.count(WorkOrderData.wonum)).label('avg_cost') - ).where( - and_( - # WorkOrderData.wo_start >= last_oh_date, - # WorkOrderData.wo_start <= upcoming_oh_date, - WorkOrderData.worktype.in_(['CM', 'EM', 'PROACTIVE']), - WorkOrderData.system_tag.in_(['HPB', 'AH', 'APC', 'SCR', 'CL', 'DM', 'CRH', 'ASH', 'BAD', 'DS', 'WTP', - 'MT', 'SUP', 'DCS', 'FF', 'EG', 'AI', 'SPS', 'EVM', 'SCW', 'KLH', 'CH', - 'TUR', 'LOT', 'HRH', 'ESP', 'CAE', 'GMC', 'BFT', 'LSH', 'CHB', 'BSS', - 'LOS', 'LPB', 'SAC', 'CP', 'EHS', 'RO', 'GG', 'MS', 'CW', 'SO', 'ATT', - 'AFG', 'EHB', 'RP', 'FO', 'PC', 'APE', 'AF', 'DMW', 'BRS', 'GEN', 'ABS', - 'CHA', 'TR', 'H2', 'BDW', 'LOM', 'ACR', 'AL', 'FW', 'COND', 'CCCW', 'IA', - 'GSS', 'BOL', 'SSB', 'CO', 'OA', 'CTH-UPD', 'AS', 'DP']), - WorkOrderData.reportdate.is_not(None), - WorkOrderData.actstart.is_not(None), - WorkOrderData.actfinish.is_not(None), - WorkOrderData.unit.in_([3, 0]), - WorkOrderData.reportdate >= datetime.strptime('2015-01-01', '%Y-%m-%d'), - not_(WorkOrderData.wonum.like('T%')) + query = text("""WITH part_costs AS ( + SELECT + mu.wonum, + SUM(COALESCE(inv.avgcost, po.unit_cost, 0)) AS parts_total_cost + FROM maximo_material_use_transactions mu + LEFT JOIN maximo_inventory inv + ON mu.itemnum = inv.itemnum + LEFT JOIN ( + SELECT item_num, AVG(unit_cost) AS unit_cost + FROM maximo_sparepart_pr_po_line + GROUP BY item_num + ) po + ON mu.itemnum = po.item_num + GROUP BY mu.wonum +), +wo_costs AS ( + SELECT + w.wonum, + w.asset_location, + (COALESCE(w.mat_cost_max, 0) + COALESCE(pc.parts_total_cost, 0)) AS total_wo_cost + FROM wo_staging_maximo_2 w + LEFT JOIN part_costs pc + ON w.wonum = pc.wonum + WHERE + w.worktype IN ('CM', 'EM', 'PROACTIVE') + AND w.asset_system IN ( + 'HPB','AH','APC','SCR','CL','DM','CRH','ASH','BAD','DS','WTP', + 'MT','SUP','DCS','FF','EG','AI','SPS','EVM','SCW','KLH','CH', + 'TUR','LOT','HRH','ESP','CAE','GMC','BFT','LSH','CHB','BSS', + 'LOS','LPB','SAC','CP','EHS','RO','GG','MS','CW','SO','ATT', + 'AFG','EHB','RP','FO','PC','APE','AF','DMW','BRS','GEN','ABS', + 'CHA','TR','H2','BDW','LOM','ACR','AL','FW','COND','CCCW','IA', + 'GSS','BOL','SSB','CO','OA','CTH-UPD','AS','DP' ) - ).group_by( - WorkOrderData.location - ).order_by( - func.count(WorkOrderData.wonum).desc() - ) - result = await collector_db.execute(query) - data = result.all() + AND w.reportdate IS NOT NULL + AND w.actstart IS NOT NULL + AND w.actfinish IS NOT NULL + AND w.asset_unit IN ('3','00') + AND w.reportdate >= '2015-01-01' + AND w.wonum NOT LIKE 'T%' +), +-- find max cost per location +location_max AS ( + SELECT asset_location, MAX(total_wo_cost) AS max_cost + FROM wo_costs + WHERE total_wo_cost > 0 + GROUP BY asset_location +), +-- filter WO costs to only reasonable range (e.g. >0 and >=10% of max) +filtered_wo AS ( + SELECT w.* + FROM wo_costs w + JOIN location_max lm ON w.asset_location = lm.asset_location + WHERE w.total_wo_cost > 0 + AND w.total_wo_cost >= lm.max_cost * 0.2 -- keep within 10% of max +) +SELECT + asset_location, + SUM(total_wo_cost)::numeric / COUNT(wonum) AS avg_cost +FROM filtered_wo +GROUP BY asset_location +ORDER BY avg_cost DESC; + """) + results = await collector_db.execute(query) + data = [] + + for row in results: + data.append({ + "location_tag": row.asset_location, + "avg_cost": row.avg_cost + }) + return { - data.location: data.avg_cost for data in data + item["location_tag"]: item["avg_cost"] for item in data } async def get_oh_cost_summary(collector_db: CollectorDbSession, last_oh_date:datetime, upcoming_oh_date:datetime): - query = select( - WorkOrderData.location, - (func.sum(WorkOrderData.total_cost_max).cast(Numeric) / func.count(WorkOrderData.wonum)).label('avg_cost') - ).where( - and_( - # WorkOrderData.wo_start >= last_oh_date, - # WorkOrderData.wo_start <= upcoming_oh_date, - WorkOrderData.worktype.in_(['OH']), - WorkOrderData.system_tag.in_(['HPB', 'AH', 'APC', 'SCR', 'CL', 'DM', 'CRH', 'ASH', 'BAD', 'DS', 'WTP', - 'MT', 'SUP', 'DCS', 'FF', 'EG', 'AI', 'SPS', 'EVM', 'SCW', 'KLH', 'CH', - 'TUR', 'LOT', 'HRH', 'ESP', 'CAE', 'GMC', 'BFT', 'LSH', 'CHB', 'BSS', - 'LOS', 'LPB', 'SAC', 'CP', 'EHS', 'RO', 'GG', 'MS', 'CW', 'SO', 'ATT', - 'AFG', 'EHB', 'RP', 'FO', 'PC', 'APE', 'AF', 'DMW', 'BRS', 'GEN', 'ABS', - 'CHA', 'TR', 'H2', 'BDW', 'LOM', 'ACR', 'AL', 'FW', 'COND', 'CCCW', 'IA', - 'GSS', 'BOL', 'SSB', 'CO', 'OA', 'CTH-UPD', 'AS', 'DP']), - WorkOrderData.reportdate.is_not(None), - WorkOrderData.actstart.is_not(None), - WorkOrderData.actfinish.is_not(None), - WorkOrderData.unit.in_([3, 0]), - WorkOrderData.reportdate >= datetime.strptime('2015-01-01', '%Y-%m-%d'), - not_(WorkOrderData.wonum.like('T%')) + query = text(""" + WITH part_costs AS ( + SELECT + mu.wonum, + SUM(COALESCE(inv.avgcost, po.unit_cost, 0)) AS parts_total_cost + FROM maximo_material_use_transactions mu + LEFT JOIN maximo_inventory inv + ON mu.itemnum = inv.itemnum + LEFT JOIN ( + SELECT item_num, AVG(unit_cost) AS unit_cost + FROM maximo_sparepart_pr_po_line + GROUP BY item_num + ) po + ON mu.itemnum = po.item_num + GROUP BY mu.wonum +) +, wo_costs AS ( + SELECT + w.wonum, + w.asset_location, + (COALESCE(w.mat_cost_max, 0) + COALESCE(pc.parts_total_cost, 0)) AS total_wo_cost + FROM wo_staging_maximo_2 w + LEFT JOIN part_costs pc + ON w.wonum = pc.wonum + WHERE + w.worktype = 'OH' + AND w.asset_system IN ( + 'HPB', 'AH', 'APC', 'SCR', 'CL', 'DM', 'CRH', 'ASH', 'BAD', 'DS', 'WTP', + 'MT', 'SUP', 'DCS', 'FF', 'EG', 'AI', 'SPS', 'EVM', 'SCW', 'KLH', 'CH', + 'TUR', 'LOT', 'HRH', 'ESP', 'CAE', 'GMC', 'BFT', 'LSH', 'CHB', 'BSS', + 'LOS', 'LPB', 'SAC', 'CP', 'EHS', 'RO', 'GG', 'MS', 'CW', 'SO', 'ATT', + 'AFG', 'EHB', 'RP', 'FO', 'PC', 'APE', 'AF', 'DMW', 'BRS', 'GEN', 'ABS', + 'CHA', 'TR', 'H2', 'BDW', 'LOM', 'ACR', 'AL', 'FW', 'COND', 'CCCW', 'IA', + 'GSS', 'BOL', 'SSB', 'CO', 'OA', 'CTH-UPD', 'AS', 'DP' ) - ).group_by( - WorkOrderData.location - ).order_by( - func.count(WorkOrderData.wonum).desc() - ) + AND w.reportdate IS NOT NULL + AND w.actstart IS NOT NULL + AND w.actfinish IS NOT NULL + AND w.asset_unit IN ('3', '00') + AND w.reportdate >= '2015-01-01' + AND w.wonum NOT LIKE 'T%' +) +SELECT + asset_location, + SUM(total_wo_cost)::numeric / COUNT(wonum) AS avg_cost +FROM wo_costs +GROUP BY asset_location +ORDER BY COUNT(wonum) DESC; + """) + result = await collector_db.execute(query) - data = result.all() + data = [] + + for row in result: + data.append({ + "location_tag": row.asset_location, + "avg_cost": row.avg_cost + }) return { - data.location: data.avg_cost for data in data + item["location_tag"]: item["avg_cost"] for item in data }