Quantity Relocated moves eliminated

This commit is contained in:
Raman Marikanti 2026-01-12 12:30:22 +05:30
parent 13cc147243
commit 025fad945d
1 changed files with 79 additions and 54 deletions

View File

@ -27,11 +27,13 @@ class SamashtiDashboard(models.AbstractModel):
# to_utc = to_local.astimezone(pytz.UTC) # to_utc = to_local.astimezone(pytz.UTC)
# Convert to string in Odoo datetime format # Convert to string in Odoo datetime format
fromDate = "'"+str(fields.Datetime.to_string(from_local))+"'" fromDate = "'" + fields.Datetime.to_string(from_local) + "'"
toDate = "'"+str(fields.Datetime.to_string(to_local))+"'" toDate = "'" + fields.Datetime.to_string(to_local) + "'"
sql = f""" sql = f"""
WITH stock_movements AS (
SELECT SELECT
pp.id as product_id,
pp.default_code AS product_code, pp.default_code AS product_code,
pt.name AS product_name, pt.name AS product_name,
pc.name AS category, pc.name AS category,
@ -44,58 +46,59 @@ class SamashtiDashboard(models.AbstractModel):
), 0) AS current_cost, ), 0) AS current_cost,
-- Opening Stock: includes inventory adjustments before fromDate -- Opening Stock: includes inventory adjustments before fromDate
COALESCE(SUM(CASE SUM(CASE
WHEN sm.date < {fromDate} AND sl_dest.usage = 'internal' AND sl_src.usage != 'internal' THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) WHEN sm.date < {fromDate} AND sl_dest.usage = 'internal' AND sl_src.usage != 'internal'
WHEN sm.date < {fromDate} AND sl_src.usage = 'internal' AND sl_dest.usage != 'internal' THEN -sm.product_uom_qty * (uom.factor /sm_uom.factor) THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
WHEN sm.date < {fromDate} AND (sl_src.usage = 'inventory' OR sl_dest.usage = 'inventory') THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) WHEN sm.date < {fromDate} AND sl_src.usage = 'internal' AND sl_dest.usage != 'internal'
THEN -sm.product_uom_qty * (uom.factor / sm_uom.factor)
WHEN sm.date < {fromDate} AND (sl_src.usage = 'inventory' OR sl_dest.usage = 'inventory')
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
ELSE 0 ELSE 0
END), 0) AS opening_stock, END) AS opening_stock,
-- Receipts: from supplier and inventory adjustments in date range -- Receipts: from supplier and inventory adjustments in date range
COALESCE(SUM(CASE SUM(CASE
WHEN sm.date BETWEEN {fromDate} AND {toDate} WHEN sm.date BETWEEN {fromDate} AND {toDate}
AND sl_dest.usage = 'internal' AND sl_dest.usage = 'internal'
AND sl_src.usage = 'supplier' THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) AND sl_src.usage = 'supplier'
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
ELSE 0 ELSE 0
END), 0) AS receipts, END) AS receipts,
-- Production: internal moves from production -- Production: internal moves from production
COALESCE(SUM(CASE SUM(CASE
WHEN sm.date BETWEEN {fromDate} AND {toDate} WHEN sm.date BETWEEN {fromDate} AND {toDate}
AND sl_dest.usage = 'internal' AND sl_dest.usage = 'internal'
AND sl_src.usage = 'production' AND sm.production_id IS NOT NULL THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) AND sl_src.usage = 'production' AND sm.production_id IS NOT NULL
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
ELSE 0 ELSE 0
END), 0) AS production, END) AS production,
-- Consumption: internal moves to production -- Consumption: internal moves to production
COALESCE(SUM(CASE SUM(CASE
WHEN sm.date BETWEEN {fromDate} AND {toDate} WHEN sm.date BETWEEN {fromDate} AND {toDate}
AND sl_src.usage = 'internal' AND sl_src.usage = 'internal'
AND sl_dest.usage = 'production' AND sm.production_id IS NOT NULL THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) AND sl_dest.usage = 'production' AND sm.production_id IS NOT NULL
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
ELSE 0 ELSE 0
END), 0) AS consumption, END) AS consumption,
-- Dispatch: internal moves to customer -- Dispatch: internal moves to customer
COALESCE(SUM(CASE SUM(CASE
WHEN sm.date BETWEEN {fromDate} AND {toDate} WHEN sm.date BETWEEN {fromDate} AND {toDate}
AND sl_src.usage = 'internal' AND sl_src.usage = 'internal'
AND sl_dest.usage = 'customer' THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) AND sl_dest.usage = 'customer'
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
ELSE 0 ELSE 0
END), 0) AS dispatch, END) AS dispatch,
-- Closing Stock = Opening + Receipts + Production - Consumption - Dispatch + Inventory adjustments -- Inventory Adjustments: inventory moves within date range
( SUM(CASE
COALESCE(SUM(CASE WHEN sm.date BETWEEN {fromDate} AND {toDate}
WHEN sm.date < {fromDate} AND sl_dest.usage = 'internal' AND sl_src.usage != 'internal' THEN sm.product_uom_qty * (uom.factor /sm_uom.factor) AND (sl_src.usage = 'inventory' OR sl_dest.usage = 'inventory')
WHEN sm.date < {fromDate} AND sl_src.usage = 'internal' AND sl_dest.usage != 'internal' THEN -sm.product_uom_qty * (uom.factor /sm_uom.factor) THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
WHEN sm.date < {fromDate} AND (sl_src.usage = 'inventory' OR sl_dest.usage = 'inventory') THEN sm.product_uom_qty * (uom.factor /sm_uom.factor)
WHEN sm.date BETWEEN {fromDate} AND {toDate} AND sl_dest.usage = 'internal' AND sl_src.usage IN ('supplier', 'production') THEN sm.product_uom_qty * (uom.factor /sm_uom.factor)
WHEN sm.date BETWEEN {fromDate} AND {toDate} AND (sl_src.usage = 'inventory' OR sl_dest.usage = 'inventory') THEN sm.product_uom_qty * (uom.factor /sm_uom.factor)
WHEN sm.date BETWEEN {fromDate} AND {toDate} AND sl_src.usage = 'internal' AND sl_dest.usage = 'production' THEN -sm.product_uom_qty * (uom.factor /sm_uom.factor)
WHEN sm.date BETWEEN {fromDate} AND {toDate} AND sl_src.usage = 'internal' AND sl_dest.usage = 'customer' THEN -sm.product_uom_qty * (uom.factor /sm_uom.factor)
ELSE 0 ELSE 0
END), 0) END) AS inventory_adjustments
) AS closing_stock
FROM FROM
stock_move sm stock_move sm
@ -118,15 +121,37 @@ class SamashtiDashboard(models.AbstractModel):
sl_src.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') AND sl_src.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') AND
sl_dest.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') AND sl_dest.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') AND
sm.state = 'done' AND sm.state = 'done' AND
pt.type = 'consu' AND pp.default_code is not null pt.type = 'consu' AND pp.default_code IS NOT NULL
GROUP BY GROUP BY
pp.default_code, pt.name, pc.name, uom.name, pp.id pp.id, pp.default_code, pt.name, pc.name, uom.name
)
SELECT
product_code,
product_name,
category,
uom,
current_cost,
COALESCE(opening_stock, 0) AS opening_stock,
COALESCE(receipts, 0) AS receipts,
COALESCE(production, 0) AS production,
COALESCE(consumption, 0) AS consumption,
COALESCE(dispatch, 0) AS dispatch,
COALESCE(inventory_adjustments, 0) AS inventory_adjustments,
-- Closing Stock = Opening + Receipts + Production - Consumption - Dispatch + Inventory Adjustments
COALESCE(opening_stock, 0) +
COALESCE(receipts, 0) +
COALESCE(production, 0) -
COALESCE(consumption, 0) -
COALESCE(dispatch, 0) +
COALESCE(inventory_adjustments, 0) AS closing_stock
FROM
stock_movements
ORDER BY ORDER BY
pt.name; product_name;
""" """
self.env.cr.execute(sql) self.env.cr.execute(sql)
data = self.env.cr.dictfetchall() data = self.env.cr.dictfetchall()
if data: if data: