stock dashboard
This commit is contained in:
parent
bdea2c6c3e
commit
bc4672e695
|
|
@ -11,8 +11,12 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
_name = 'samashti.board'
|
||||
_description = "Samashti Dashboard"
|
||||
|
||||
|
||||
|
||||
|
||||
@api.model
|
||||
def get_stock_moves_data(self, from_date,to_date):
|
||||
def get_stock_moves_data(self, from_date, to_date):
|
||||
# Convert string dates to datetime objects
|
||||
from_date_obj = datetime.strptime(from_date, '%Y-%m-%d').date()
|
||||
to_date_obj = datetime.strptime(to_date, '%Y-%m-%d').date()
|
||||
|
||||
|
|
@ -30,14 +34,42 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
fromDate = "'" + fields.Datetime.to_string(from_local) + "'"
|
||||
toDate = "'" + fields.Datetime.to_string(to_local) + "'"
|
||||
|
||||
# Get opening stock at the beginning of the from_date
|
||||
opening_context = {
|
||||
'lang': 'en_US',
|
||||
'tz': 'Asia/Kolkata',
|
||||
'to_date': fields.Datetime.to_string(from_local)
|
||||
}
|
||||
opening_stock = self.env['product.product'].with_context(**opening_context).search_read(
|
||||
[('is_storable', '=', True)],
|
||||
['id', 'name', 'qty_available']
|
||||
)
|
||||
|
||||
# Create opening stock dictionary for easier lookup
|
||||
opening_dict = {product['id']: product['qty_available'] for product in opening_stock}
|
||||
|
||||
# Get closing stock at the end of the to_date
|
||||
closing_context = {
|
||||
'lang': 'en_US',
|
||||
'tz': 'Asia/Kolkata',
|
||||
'to_date': fields.Datetime.to_string(to_local)
|
||||
}
|
||||
closing_stock = self.env['product.product'].with_context(**closing_context).search_read(
|
||||
[('is_storable', '=', True)],
|
||||
['id', 'name', 'qty_available']
|
||||
)
|
||||
|
||||
# Create closing stock dictionary for easier lookup
|
||||
closing_dict = {product['id']: product['qty_available'] for product in closing_stock}
|
||||
|
||||
sql = f"""
|
||||
WITH stock_movements AS (
|
||||
SELECT
|
||||
pp.id as product_id,
|
||||
pp.default_code AS product_code,
|
||||
pt.name AS product_name,
|
||||
pt.name->>'en_US' AS product_name,
|
||||
pc.name AS category,
|
||||
uom.name AS uom,
|
||||
uom.name->>'en_US' AS uom,
|
||||
-- Current Cost (from Valuation Layer)
|
||||
COALESCE((
|
||||
SELECT SUM(svl.value) / NULLIF(SUM(svl.quantity), 0)
|
||||
|
|
@ -45,17 +77,6 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
WHERE svl.product_id = pp.id
|
||||
), 0) AS current_cost,
|
||||
|
||||
-- Opening Stock: includes inventory adjustments before fromDate
|
||||
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_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
|
||||
END) AS opening_stock,
|
||||
|
||||
-- Receipts: from supplier and inventory adjustments in date range
|
||||
SUM(CASE
|
||||
WHEN sm.date BETWEEN {fromDate} AND {toDate}
|
||||
|
|
@ -78,7 +99,7 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
SUM(CASE
|
||||
WHEN sm.date BETWEEN {fromDate} AND {toDate}
|
||||
AND sl_src.usage = 'internal'
|
||||
AND sl_dest.usage = 'production' AND sm.production_id IS NOT NULL
|
||||
AND sl_dest.usage = 'production'
|
||||
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
|
||||
ELSE 0
|
||||
END) AS consumption,
|
||||
|
|
@ -90,15 +111,7 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
AND sl_dest.usage = 'customer'
|
||||
THEN sm.product_uom_qty * (uom.factor / sm_uom.factor)
|
||||
ELSE 0
|
||||
END) AS dispatch,
|
||||
|
||||
-- Inventory Adjustments: inventory moves within date range
|
||||
SUM(CASE
|
||||
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)
|
||||
ELSE 0
|
||||
END) AS inventory_adjustments
|
||||
END) AS dispatch
|
||||
|
||||
FROM
|
||||
stock_move sm
|
||||
|
|
@ -121,48 +134,72 @@ class SamashtiDashboard(models.AbstractModel):
|
|||
sl_src.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') AND
|
||||
sl_dest.usage IN ('internal', 'supplier', 'production', 'customer', 'inventory') 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 AND
|
||||
pp.active = TRUE
|
||||
|
||||
GROUP BY
|
||||
pp.id, pp.default_code, pt.name, pc.name, uom.name
|
||||
)
|
||||
|
||||
SELECT
|
||||
product_id,
|
||||
product_code,
|
||||
product_name,
|
||||
category,
|
||||
uom,
|
||||
current_cost,
|
||||
GREATEST(COALESCE(opening_stock, 0), 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
|
||||
COALESCE(dispatch, 0) AS dispatch
|
||||
FROM
|
||||
stock_movements
|
||||
ORDER BY
|
||||
product_name;
|
||||
"""
|
||||
|
||||
self.env.cr.execute(sql)
|
||||
data = self.env.cr.dictfetchall()
|
||||
if data:
|
||||
for row in data:
|
||||
row['product_name'] = '[' + row['product_code'] + '] ' + list(row['product_name'].values())[0] if row[
|
||||
'product_name'] else ''
|
||||
row['uom'] = list(row['uom'].values())[0] if row['uom'] else '-'
|
||||
row['value'] = row['closing_stock'] * row['current_cost']
|
||||
return data
|
||||
else:
|
||||
return []
|
||||
|
||||
# Process the data
|
||||
processed_data = []
|
||||
for row in data:
|
||||
product_id = row['product_id']
|
||||
opening_qty = opening_dict.get(product_id, 0)
|
||||
closing_qty = closing_dict.get(product_id, 0)
|
||||
|
||||
# Calculate net movement during the period
|
||||
net_movement = (
|
||||
row['receipts'] +
|
||||
row['production'] -
|
||||
row['consumption'] -
|
||||
row['dispatch']
|
||||
)
|
||||
|
||||
# Verify calculation matches with actual closing stock
|
||||
calculated_closing = opening_qty + net_movement
|
||||
actual_closing = closing_qty
|
||||
|
||||
processed_row = {
|
||||
'product_id': product_id,
|
||||
'product_code': row['product_code'] or '',
|
||||
'product_name': f"[{row['product_code']}] {row['product_name']}" if row['product_code'] else row[
|
||||
'product_name'],
|
||||
'category': row['category'] or '',
|
||||
'uom': row['uom'] or '-',
|
||||
'current_cost': row['current_cost'],
|
||||
'opening_stock': opening_qty,
|
||||
'receipts': row['receipts'],
|
||||
'production': row['production'],
|
||||
'consumption': row['consumption'],
|
||||
'dispatch': row['dispatch'],
|
||||
'calculated_closing_stock': calculated_closing,
|
||||
'closing_stock': actual_closing,
|
||||
'variance': actual_closing - calculated_closing,
|
||||
'value': actual_closing * row['current_cost']
|
||||
}
|
||||
processed_data.append(processed_row)
|
||||
return processed_data
|
||||
|
||||
@api.model
|
||||
def get_dashboard_cards_data(self):
|
||||
|
|
|
|||
Loading…
Reference in New Issue