@@ -44,6 +44,25 @@ class StockAverageDailySale(models.Model):
4444 help = "The quantity delivered on average on one day for this product on "
4545 "the period. The spikes are excluded from the average computation." ,
4646 )
47+ average_daily_returns_count = fields .Float (
48+ required = True ,
49+ digits = "Product Unit of Measure" ,
50+ help = "How much returns on average for this product on the period. "
51+ "The spikes are excluded from the average computation." ,
52+ )
53+ average_qty_by_return = fields .Float (
54+ required = True ,
55+ digits = "Product Unit of Measure" ,
56+ help = "The quantity "
57+ "returned on average for one return of this product on the period. "
58+ "The spikes are excluded from the average computation." ,
59+ )
60+ average_daily_return_qty = fields .Float (
61+ digits = "Product Unit of Measure" ,
62+ required = True ,
63+ help = "The quantity returned on average on one day for this product on "
64+ "the period." ,
65+ )
4766 config_id = fields .Many2one (
4867 string = "Stock Average Daily Sale Configuration" ,
4968 comodel_name = "stock.average.daily.sale.config" ,
@@ -75,6 +94,14 @@ class StockAverageDailySale(models.Model):
7594 digits = "Product Unit of Measure" ,
7695 help = "Minimal recommended quantity in stock. Formula: average daily qty * number days in stock + safety" ,
7796 )
97+ recommended_qty_incl_returns = fields .Float (
98+ required = True ,
99+ digits = "Product Unit of Measure" ,
100+ help = (
101+ "Minimal recommended quantity in stock taking into account returns. "
102+ "Formula: (average daily qty - average return qty) * number days in stock + safety"
103+ ),
104+ )
78105 sale_ok = fields .Boolean (
79106 string = "Can be Sold" ,
80107 readonly = True ,
@@ -229,14 +256,22 @@ def _create_materialized_view(self):
229256 ),
230257 returns_last AS (
231258 SELECT
232- sm.product_id AS ret_product_id,
233- sm.product_uom_qty AS ret_product_uom_qty,
234- sl_src.warehouse_id AS ret_warehouse_id,
235- coalesce ((stddev_samp(product_uom_qty) OVER pid), 0) AS ret_standard_deviation,
236- cfg.nbr_days AS ret_nbr_days,
237- cfg.date_from AS ret_date_from,
238- cfg.date_to AS ret_date_to,
239- sm.date AS ret_date
259+ sm.product_id,
260+ sm.product_uom_qty,
261+ sl_dest.warehouse_id,
262+ (avg(product_uom_qty) OVER pid
263+ - (stddev_samp(product_uom_qty) OVER pid * cfg.standard_deviation_exclude_factor)
264+ ) as lower_bound,
265+ (avg(product_uom_qty) OVER pid
266+ + ( stddev_samp(product_uom_qty) OVER pid * cfg.standard_deviation_exclude_factor)
267+ ) as upper_bound,
268+ coalesce ((stddev_samp(product_uom_qty) OVER pid), 0) as standard_deviation,
269+ cfg.nbr_days,
270+ cfg.date_from,
271+ cfg.date_to,
272+ cfg.exclude_weekends,
273+ cfg.id as config_id,
274+ sm.date
240275 FROM stock_move sm
241276 JOIN stock_location sl_src ON sm.location_id = sl_src.id
242277 JOIN stock_location sl_dest ON sm.location_dest_id = sl_dest.id
@@ -251,14 +286,13 @@ def _create_materialized_view(self):
251286 AND sm.warehouse_id = cfg.warehouse_id
252287 WINDOW pid AS (PARTITION BY sm.product_id, sm.warehouse_id)
253288 ),
254-
255289 averages AS(
256290 SELECT
257291 row_number() over (order by product_id) as id,
258292 concat(warehouse_id, product_id)::integer as window_id,
259293 product_id,
260294 warehouse_id,
261- (avg(product_uom_qty - COALESCE(ret_product_uom_qty, 0) ) FILTER
295+ (avg(product_uom_qty) FILTER
262296 (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
263297 )::numeric AS average_qty_by_sale,
264298 (count(product_uom_qty) FILTER
@@ -272,15 +306,28 @@ def _create_materialized_view(self):
272306 config_id,
273307 nbr_days
274308 FROM deliveries_last
275- LEFT JOIN returns_last
276- ON
277- deliveries_last.product_id = returns_last.ret_product_id
278- AND
279- deliveries_last.warehouse_id = returns_last.ret_warehouse_id
280- AND
281- deliveries_last.date_from = returns_last.ret_date_from
282- AND
283- deliveries_last.date_to = returns_last.ret_date_to
309+ GROUP BY product_id, warehouse_id, standard_deviation, nbr_days, date_from, date_to, config_id
310+ ),
311+ averages_return AS(
312+ SELECT
313+ row_number() over (order by product_id) as id,
314+ concat(warehouse_id, product_id)::integer as window_id,
315+ product_id,
316+ warehouse_id,
317+ (avg(product_uom_qty) FILTER
318+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
319+ )::numeric AS average_qty_by_return,
320+ (count(product_uom_qty) FILTER
321+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
322+ / nbr_days::numeric) AS average_daily_returns_count,
323+ count(product_uom_qty) FILTER
324+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)::double precision as nbr_returns,
325+ standard_deviation::numeric AS ret_standard_deviation,
326+ date_from AS ret_date_from,
327+ date_to AS ret_date_to,
328+ config_id AS ret_config_id,
329+ nbr_days AS ret_nbr_days
330+ FROM returns_last
284331 GROUP BY product_id, warehouse_id, standard_deviation, nbr_days, date_from, date_to, config_id
285332 ),
286333 -- Compute the stock by product in locations under stock
@@ -315,6 +362,28 @@ def _create_materialized_view(self):
315362 GROUP BY product_id, warehouse_id, 1
316363 ) as averages_daily group by id, product_id, warehouse_id
317364
365+ ),
366+ -- Compute the standard deviation of the average daily returns count
367+ daily_standard_deviation_return AS(
368+ SELECT
369+ id,
370+ product_id,
371+ warehouse_id,
372+ stddev_samp(daily_returns) as daily_standard_deviation
373+ from (
374+ SELECT
375+ to_char(date_trunc('day', date), 'YYYY-MM-DD'),
376+ concat(warehouse_id, product_id)::integer as id,
377+ product_id,
378+ warehouse_id,
379+ (count(product_uom_qty) FILTER
380+ (WHERE product_uom_qty BETWEEN lower_bound AND upper_bound OR standard_deviation = 0)
381+ ) as daily_returns
382+ FROM returns_last
383+ WHERE exclude_weekends = False OR (EXTRACT(DOW FROM date) <> '0' AND EXTRACT(DOW FROM date) <> '6')
384+ GROUP BY product_id, warehouse_id, 1
385+ ) as averages_daily group by id, product_id, warehouse_id
386+
318387 )
319388
320389 -- Collect the data for the materialized view
@@ -325,6 +394,9 @@ def _create_materialized_view(self):
325394 average_qty_by_sale,
326395 average_daily_sales_count,
327396 average_qty_by_sale * average_daily_sales_count as average_daily_qty,
397+ average_qty_by_return,
398+ average_daily_returns_count,
399+ average_qty_by_return * average_daily_returns_count as average_daily_return_qty,
328400 nbr_sales,
329401 standard_deviation,
330402 date_from,
@@ -341,13 +413,19 @@ def _create_materialized_view(self):
341413 GREATEST(
342414 (cfg.number_days_qty_in_stock * average_qty_by_sale * average_daily_sales_count) + (ds.daily_standard_deviation * cfg.safety_factor * sqrt(nbr_days)),
343415 (cfg.number_days_qty_in_stock * average_qty_by_sale)
344- ) as recommended_qty
416+ ) as recommended_qty,
417+ GREATEST(
418+ (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)),
419+ (cfg.number_days_qty_in_stock * (average_qty_by_sale - average_qty_by_return))
420+ ) as recommended_qty_incl_returns
345421 FROM averages t
346422 JOIN daily_standard_deviation ds on ds.id= t.window_id
347423 JOIN stock_average_daily_sale_config cfg on cfg.id = t.config_id
348424 JOIN stock_qty sqty on sqty.pp_id = t.product_id AND t.warehouse_id = sqty.warehouse_id
349425 JOIN product_product pp on pp.id = t.product_id
350426 JOIN product_template pt on pt.id = pp.product_tmpl_id
427+ LEFT JOIN averages_return tr ON tr.window_id = t.window_id
428+ LEFT JOIN daily_standard_deviation_return dsr on dsr.id= t.window_id
351429 ORDER BY product_id
352430 ) WITH NO DATA;""" ,
353431 {
0 commit comments