diff --git a/stock_average_daily_sale/models/stock_average_daily_sale.py b/stock_average_daily_sale/models/stock_average_daily_sale.py
index 760201f8a..73b84499b 100644
--- a/stock_average_daily_sale/models/stock_average_daily_sale.py
+++ b/stock_average_daily_sale/models/stock_average_daily_sale.py
@@ -44,6 +44,25 @@ class StockAverageDailySale(models.Model):
help="The quantity delivered on average on one day for this product on "
"the period. The spikes are excluded from the average computation.",
)
+ average_daily_returns_count = fields.Float(
+ required=True,
+ digits="Product Unit of Measure",
+ help="How much returns on average for this product on the period. "
+ "The spikes are excluded from the average computation.",
+ )
+ average_qty_by_return = fields.Float(
+ required=True,
+ digits="Product Unit of Measure",
+ help="The quantity "
+ "returned on average for one return of this product on the period. "
+ "The spikes are excluded from the average computation.",
+ )
+ average_daily_return_qty = fields.Float(
+ digits="Product Unit of Measure",
+ required=True,
+ help="The quantity returned on average on one day for this product on "
+ "the period.",
+ )
config_id = fields.Many2one(
string="Stock Average Daily Sale Configuration",
comodel_name="stock.average.daily.sale.config",
@@ -75,6 +94,14 @@ class StockAverageDailySale(models.Model):
digits="Product Unit of Measure",
help="Minimal recommended quantity in stock. Formula: average daily qty * number days in stock + safety",
)
+ recommended_qty_incl_returns = fields.Float(
+ required=True,
+ digits="Product Unit of Measure",
+ help=(
+ "Minimal recommended quantity in stock taking into account returns. "
+ "Formula: (average daily qty - average return qty) * number days in stock + safety"
+ ),
+ )
sale_ok = fields.Boolean(
string="Can be Sold",
readonly=True,
@@ -227,7 +254,38 @@ def _create_materialized_view(self):
AND coalesce(sm.warehouse_id, sl_src.warehouse_id) = cfg.warehouse_id
WINDOW pid AS (PARTITION BY sm.product_id, sm.warehouse_id)
),
-
+ returns_last AS (
+ SELECT
+ sm.product_id,
+ sm.product_uom_qty,
+ sl_dest.warehouse_id,
+ (avg(product_uom_qty) OVER pid
+ - (stddev_samp(product_uom_qty) OVER pid * cfg.standard_deviation_exclude_factor)
+ ) as lower_bound,
+ (avg(product_uom_qty) OVER pid
+ + ( stddev_samp(product_uom_qty) OVER pid * cfg.standard_deviation_exclude_factor)
+ ) as upper_bound,
+ coalesce ((stddev_samp(product_uom_qty) OVER pid), 0) as standard_deviation,
+ cfg.nbr_days,
+ cfg.date_from,
+ cfg.date_to,
+ cfg.exclude_weekends,
+ cfg.id as config_id,
+ sm.date
+ FROM stock_move sm
+ JOIN stock_location sl_src ON sm.location_id = sl_src.id
+ JOIN stock_location sl_dest ON sm.location_dest_id = sl_dest.id
+ JOIN product_product pp ON pp.id = sm.product_id
+ JOIN product_template pt ON pp.product_tmpl_id = pt.id
+ JOIN cfg ON cfg.abc_classification_level = coalesce(pt.abc_storage, 'c')
+ WHERE
+ sl_src.usage in ('inventory')
+ AND sl_dest.usage in ('internal')
+ AND sm.date BETWEEN cfg.date_from AND cfg.date_to
+ AND sm.state = 'done'
+ AND coalesce(sm.warehouse_id, sl_dest.warehouse_id) = cfg.warehouse_id
+ WINDOW pid AS (PARTITION BY sm.product_id, sm.warehouse_id)
+ ),
averages AS(
SELECT
row_number() over (order by product_id) as id,
@@ -250,6 +308,28 @@ def _create_materialized_view(self):
FROM deliveries_last
GROUP BY product_id, warehouse_id, standard_deviation, nbr_days, date_from, date_to, config_id
),
+ averages_return AS(
+ SELECT
+ row_number() over (order by product_id) as id,
+ concat(warehouse_id, product_id)::integer as window_id,
+ product_id,
+ warehouse_id,
+ (avg(product_uom_qty) FILTER
+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
+ )::numeric AS average_qty_by_return,
+ (count(product_uom_qty) FILTER
+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
+ / nbr_days::numeric) AS average_daily_returns_count,
+ count(product_uom_qty) FILTER
+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)::double precision as nbr_returns,
+ standard_deviation::numeric AS ret_standard_deviation,
+ date_from AS ret_date_from,
+ date_to AS ret_date_to,
+ config_id AS ret_config_id,
+ nbr_days AS ret_nbr_days
+ FROM returns_last
+ GROUP BY product_id, warehouse_id, standard_deviation, nbr_days, date_from, date_to, config_id
+ ),
-- Compute the stock by product in locations under stock
stock_qty AS (
SELECT sq.product_id AS pp_id,
@@ -282,6 +362,28 @@ def _create_materialized_view(self):
GROUP BY product_id, warehouse_id, 1
) as averages_daily group by id, product_id, warehouse_id
+ ),
+ -- Compute the standard deviation of the average daily returns count
+ daily_standard_deviation_return AS(
+ SELECT
+ id,
+ product_id,
+ warehouse_id,
+ stddev_samp(daily_returns) as daily_standard_deviation
+ from (
+ SELECT
+ to_char(date_trunc('day', date), 'YYYY-MM-DD'),
+ concat(warehouse_id, product_id)::integer as id,
+ product_id,
+ warehouse_id,
+ (count(product_uom_qty) FILTER
+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
+ ) as daily_returns
+ FROM returns_last
+ WHERE exclude_weekends = False OR (EXTRACT(DOW FROM date) <> '0' AND EXTRACT(DOW FROM date) <> '6')
+ GROUP BY product_id, warehouse_id, 1
+ ) as averages_daily group by id, product_id, warehouse_id
+
)
-- Collect the data for the materialized view
@@ -292,6 +394,9 @@ def _create_materialized_view(self):
average_qty_by_sale,
average_daily_sales_count,
average_qty_by_sale * average_daily_sales_count as average_daily_qty,
+ average_qty_by_return,
+ average_daily_returns_count,
+ average_qty_by_return * average_daily_returns_count as average_daily_return_qty,
nbr_sales,
standard_deviation,
date_from,
@@ -308,13 +413,19 @@ def _create_materialized_view(self):
GREATEST(
(cfg.number_days_qty_in_stock * average_qty_by_sale * average_daily_sales_count) + (ds.daily_standard_deviation * cfg.safety_factor * sqrt(nbr_days)),
(cfg.number_days_qty_in_stock * average_qty_by_sale)
- ) as recommended_qty
+ ) as recommended_qty,
+ GREATEST(
+ (cfg.number_days_qty_in_stock * (average_qty_by_sale - average_qty_by_return) * (average_daily_sales_count - average_daily_returns_count)) + ((ds.daily_standard_deviation - dsr.daily_standard_deviation) * cfg.safety_factor * sqrt(nbr_days)),
+ (cfg.number_days_qty_in_stock * (average_qty_by_sale - average_qty_by_return))
+ ) as recommended_qty_incl_returns
FROM averages t
JOIN daily_standard_deviation ds on ds.id= t.window_id
JOIN stock_average_daily_sale_config cfg on cfg.id = t.config_id
JOIN stock_qty sqty on sqty.pp_id = t.product_id AND t.warehouse_id = sqty.warehouse_id
JOIN product_product pp on pp.id = t.product_id
JOIN product_template pt on pt.id = pp.product_tmpl_id
+ LEFT JOIN averages_return tr ON tr.window_id = t.window_id
+ LEFT JOIN daily_standard_deviation_return dsr on dsr.id= t.window_id
ORDER BY product_id
) WITH NO DATA;""",
{
diff --git a/stock_average_daily_sale/tests/common.py b/stock_average_daily_sale/tests/common.py
index 5ab9b8507..bbc0947e9 100644
--- a/stock_average_daily_sale/tests/common.py
+++ b/stock_average_daily_sale/tests/common.py
@@ -33,10 +33,18 @@ def setUpClass(cls):
{"name": "Area Location", "location_id": cls.location_zone.id}
)
cls.location_bin = cls.location_obj.create(
- {"name": "Bin Location", "location_id": cls.location_area.id}
+ {
+ "name": "Bin Location",
+ "location_id": cls.location_area.id,
+ "usage": "internal",
+ }
)
cls.location_bin_2 = cls.location_obj.create(
- {"name": "Bin Location 2", "location_id": cls.location_area.id}
+ {
+ "name": "Bin Location 2",
+ "location_id": cls.location_area.id,
+ "usage": "internal",
+ }
)
cls.scrap_location = cls.location_obj.create(
{
@@ -95,14 +103,19 @@ def _create_products(cls):
)
@classmethod
- def _create_move(cls, product, origin_location, qty):
+ def _create_move(cls, product, origin_location, qty, dest_location=None):
+ warehouse = origin_location.warehouse_id
+ if not warehouse and dest_location:
+ warehouse = dest_location.warehouse_id
move = cls.move_obj.create(
{
"product_id": product.id,
"name": product.name,
"location_id": origin_location.id,
- "warehouse_id": origin_location.warehouse_id.id,
- "location_dest_id": cls.customers.id,
+ "warehouse_id": warehouse.id,
+ "location_dest_id": dest_location.id
+ if dest_location
+ else cls.customers.id,
"product_uom_qty": qty,
"product_uom": product.uom_id.id,
"priority": "1",
diff --git a/stock_average_daily_sale/tests/test_average_daily_sale.py b/stock_average_daily_sale/tests/test_average_daily_sale.py
index e41d93333..dc895a147 100644
--- a/stock_average_daily_sale/tests/test_average_daily_sale.py
+++ b/stock_average_daily_sale/tests/test_average_daily_sale.py
@@ -150,6 +150,7 @@ def test_average_sale_multiple(self):
{
"nbr_sales": 2.0,
"average_qty_by_sale": 8.0,
+ "recommended_qty": 16.0,
"qty_in_stock": 44.0,
"warehouse_id": self.warehouse_0.id,
}
@@ -209,3 +210,56 @@ def test_view_refreshed(self):
],
cm.output,
)
+
+ def test_average_sale_with_returns(self):
+ # By default, products have abc_storage == 'b'
+ # So, the averages should correspond to 'b' one
+
+ # Create moves for product_1
+ move_1_date = Date.to_string(self.now - relativedelta(weeks=11))
+ with freeze_time(move_1_date):
+ move = self._create_move(self.product_1, self.location_bin, 10.0)
+ move._action_confirm()
+ move._action_assign()
+ move.quantity_done = move.product_uom_qty
+ move._action_done()
+
+ move_1_date = Date.to_string(self.now - relativedelta(weeks=10))
+ with freeze_time(move_1_date):
+ move = self._create_move(self.product_1, self.location_bin, 8.0)
+ move._action_confirm()
+ move._action_assign()
+ move.quantity_done = move.product_uom_qty
+ move._action_done()
+
+ # create a "return" move - from inventory location to stock
+ move_1_date = Date.to_string(self.now - relativedelta(weeks=10))
+ with freeze_time(move_1_date):
+ move = self._create_move(
+ self.product_1, self.scrap_location, 7.0, self.location_bin
+ )
+ move._action_confirm()
+ move._action_assign()
+ move.quantity_done = move.product_uom_qty
+ move._action_done()
+
+ self._refresh()
+
+ avg_product_1 = self.env["stock.average.daily.sale"].search(
+ [("product_id", "=", self.product_1.id)]
+ )
+
+ self.assertRecordValues(
+ avg_product_1,
+ [
+ {
+ "nbr_sales": 2.0,
+ "average_qty_by_sale": 9.0, # 18 units / 2 delivery moves
+ "average_qty_by_return": 7.0, # One return of 7 units
+ "recommended_qty": 18.0,
+ "recommended_qty_incl_returns": 4.0,
+ "qty_in_stock": 39.0,
+ "warehouse_id": self.warehouse_0.id,
+ }
+ ],
+ )
diff --git a/stock_average_daily_sale/views/stock_average_daily_sale.xml b/stock_average_daily_sale/views/stock_average_daily_sale.xml
index b58b1e08e..57f46fafb 100644
--- a/stock_average_daily_sale/views/stock_average_daily_sale.xml
+++ b/stock_average_daily_sale/views/stock_average_daily_sale.xml
@@ -47,10 +47,14 @@
+
+
+
+