Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
How could I calculate the avg days on the shelf from a table like this (rows with PO number is receiving, the ones with SO number are shipments)
The way I approached this, I calculated the average days since received and subtracted the average days since shipped. The issue is when not all the received qty is shipped. If I have qty still sitting on the shelf, it skewes the average. The error increase with the ratio of onhand qty / shipped qty.
Thank you,
Solved! Go to Solution.
Hi, @AyubSherif
According to your description, you want to judge whether all the things of a product have been shipped according to the [qty] field and. If the delivery is completed, the number of days between [date] and today () is taken; if the delivery is not completed, the number of days between the current [date] and the date value of the largest so number is taken. Right?
Here are the steps you can follow:
(1)This is my test data:
(2)We can create a calculated column : “Days Since”
Days Since =
VAR _current_id = 'Table'[Product ID]
VAR _current_PO = 'Table'[PO Number]
VAR _current_SO = 'Table'[SO Number]
VAR _pro_PO =
SUMX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[PO Number] <> BLANK ()
),
[QTY]
)
VAR _pro_SO =
SUMX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[SO Number] <> BLANK ()
),
[QTY]
)
VAR _pro_max_SO =
MAXX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[SO Number] <> BLANK ()
),
[Date]
)
RETURN
IF (
'Table'[PO Number] = BLANK (),
DATEDIFF ( 'Table'[Date], TODAY (), DAY ),
IF (
_pro_PO = _pro_SO,
DATEDIFF ( 'Table'[Date], TODAY (), DAY ),
DATEDIFF ( 'Table'[Date], _pro_max_SO, DAY )
)
)
(3)Then we can meet your need , the result is as follow:
If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Hi, @AyubSherif
According to your description, you want to judge whether all the things of a product have been shipped according to the [qty] field and. If the delivery is completed, the number of days between [date] and today () is taken; if the delivery is not completed, the number of days between the current [date] and the date value of the largest so number is taken. Right?
Here are the steps you can follow:
(1)This is my test data:
(2)We can create a calculated column : “Days Since”
Days Since =
VAR _current_id = 'Table'[Product ID]
VAR _current_PO = 'Table'[PO Number]
VAR _current_SO = 'Table'[SO Number]
VAR _pro_PO =
SUMX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[PO Number] <> BLANK ()
),
[QTY]
)
VAR _pro_SO =
SUMX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[SO Number] <> BLANK ()
),
[QTY]
)
VAR _pro_max_SO =
MAXX (
FILTER (
'Table',
'Table'[Product ID] = _current_id
&& 'Table'[SO Number] <> BLANK ()
),
[Date]
)
RETURN
IF (
'Table'[PO Number] = BLANK (),
DATEDIFF ( 'Table'[Date], TODAY (), DAY ),
IF (
_pro_PO = _pro_SO,
DATEDIFF ( 'Table'[Date], TODAY (), DAY ),
DATEDIFF ( 'Table'[Date], _pro_max_SO, DAY )
)
)
(3)Then we can meet your need , the result is as follow:
If this method does not meet your needs, you can provide us with your special sample data and the desired output sample data in the form of tables, so that we can better help you solve the problem.
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly
Thank you! I made some tweeks, but this was very helpful.
(1) What exactly is the "he avg days on the shelf" you want to calculate?
I am trying to calculate how long a product has stayed in our warehouse. The period from when it is received until it is shipped.
(2) The [Date] field indicates the date when the goods were received and sent, and the [QTY] field is the quantity of goods shipped. How is [Days since] calculated?
The days since is just Days since = DATEDIFF('Product History'[Date], TODAY(), DAY)
(3) How is "when not all the received qty is shipped/ qty still sitting on the shelf" judged?
Ex, when 100 items are received and only 20 shipped, I have 80 on the shelf (on hand).
For simplicity, take this table as an example:
Here is my current measure:
Hi, @AyubSherif
I'm sorry, I have a few questions about your question:
(1) What exactly is the "he avg days on the shelf" you want to calculate?
(2) The [Date] field indicates the date when the goods were received and sent, and the [QTY] field is the quantity of goods shipped. How is [Days since] calculated?
(3) How is "when not all the received qty is shipped/ qty still sitting on the shelf" judged?
(4) What data do you ultimately want the ball to have?
Can you show your sample data in the form of a table, and show us the results you want to get in the form of a table, so that we can better help you analyze the problem.
Best Regards,
Aniya Zhang
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
25 | |
21 | |
20 | |
14 | |
13 |
User | Count |
---|---|
44 | |
37 | |
25 | |
24 | |
23 |