You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
be-optimumoh/src/maximo/service.py

211 lines
6.6 KiB
Python

from datetime import datetime
from sqlalchemy import select, func, cast, Numeric, text
from sqlalchemy.orm import Session
from sqlalchemy import and_
from sqlalchemy.sql import not_
from src.maximo.model import WorkOrderData # Assuming this is where your model is
from src.database.core import CollectorDbSession
async def get_cm_cost_summary(collector_db: CollectorDbSession, last_oh_date:datetime, upcoming_oh_date:datetime):
query = text("""WITH part_costs AS (
SELECT
mu.wonum,
SUM(mu.itemqty * COALESCE(inv.avgcost, po.unit_cost, 0)) AS parts_total_cost
FROM maximo_workorder_materials 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'
)
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
)
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 {
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 = text("""
# WITH target_wo AS (
# -- Get work orders under a specific parent(s)
# SELECT
# wonum,
# xx_parent,
# assetnum,
# location_tag AS asset_location,
# actmatcost,
# actservcost,
# reportdate
# FROM public.wo_maxim
# WHERE xx_parent = ANY(:parent_nums)
# ),
# part_costs AS (
# -- Calculate parts cost per WO if actmatcost = 0
# SELECT
# wm.wonum,
# SUM(
# wm.itemqty *
# COALESCE(wm.inv_avgcost, po.unit_cost, 0)
# ) AS parts_total_cost
# FROM public.wo_maxim_material wm
# LEFT JOIN (
# SELECT item_num, AVG(unit_cost) AS unit_cost
# FROM public.maximo_sparepart_pr_po_line
# GROUP BY item_num
# ) po ON wm.itemnum = po.item_num
# WHERE wm.itemnum IS NOT NULL
# GROUP BY wm.wonum
# ),
# wo_costs AS (
# SELECT
# w.wonum,
# w.asset_location,
# CASE
# WHEN COALESCE(w.actmatcost, 0) > 0 THEN COALESCE(w.actmatcost, 0)
# ELSE COALESCE(pc.parts_total_cost, 0)
# END AS material_cost,
# COALESCE(w.actservcost, 0) AS service_cost
# FROM target_wo w
# LEFT JOIN part_costs pc ON w.wonum = pc.wonum
# )
# SELECT
# asset_location,
# ROUND(SUM(material_cost + service_cost)::numeric / COUNT(wonum), 2) AS avg_cost,
# COUNT(wonum) AS total_wo_count
# FROM wo_costs
# GROUP BY asset_location
# ORDER BY total_wo_count DESC;
# """)
# parent_nums = []
# result = await collector_db.execute(query, {"parent_nums": parent_nums})
# data = []
# for row in result:
# data.append({
# "location_tag": row.asset_location,
# "avg_cost": float(row.avg_cost or 0.0),
# "total_wo_count": row.total_wo_count,
# })
# return {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 = text("""
WITH part_costs AS (
SELECT
wm.wonum,
SUM(wm.itemqty * COALESCE(wm.inv_avgcost, po.unit_cost, 0)) AS parts_total_cost
FROM public.wo_maxim_material wm
LEFT JOIN (
SELECT item_num, AVG(unit_cost) AS unit_cost
FROM public.maximo_sparepart_pr_po_line
GROUP BY item_num
) po ON wm.itemnum = po.item_num
WHERE wm.itemnum IS NOT NULL
GROUP BY wm.wonum
),
wo_costs AS (
SELECT
w.wonum,
w.asset_location,
-- Use mat_cost_max if parts_total_cost = 0
CASE
WHEN COALESCE(pc.parts_total_cost, 0) = 0 THEN COALESCE(w.mat_cost_max , 0)
ELSE COALESCE(pc.parts_total_cost, 0)
END 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.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.wonum NOT LIKE 'T%'
)
SELECT
asset_location,
AVG(total_wo_cost) AS avg_cost
FROM wo_costs
GROUP BY asset_location
ORDER BY COUNT(wonum) DESC;
""")
result = await collector_db.execute(query)
data = []
for row in result:
data.append({
"location_tag": row.asset_location,
"avg_cost": row.avg_cost
})
return {
item["location_tag"]: item["avg_cost"] for item in data
}