Advance your Data & AI career with 50 days of live learning, dataviz contests, hands-on challenges, study groups & certifications and more!
Get registeredJoin us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM. Register now.
Hi All,
I am trying to calculate how long we were out of stock of a product from an inventory snapshot table (actual data below)
In the screenshot above we sold our last unit of SKU1 on March 4th, we then received a new batch of product on May 5th. This means we were out of stock for 62 days. This can happen in multiple periods over the course of a single sku. The above sample is already filtered down to a single sku from a more massive table of all inventory edits by date. I can either calculate this in this table as an added column for each gap period or pull a total of time out of stock into a SKU reference table. Any help on this would be much appreciated.
EDIT: Added Actual Table Data
Thank you
Scott
| EntryDt | StockCode | OnHand | Days Out Of Stock |
| 4/30/2019 0:00 | SKU1 | 22 | |
| 5/27/2019 0:00 | SKU1 | 22 | |
| 5/28/2019 0:00 | SKU1 | 20 | |
| 6/2/2019 0:00 | SKU1 | 40 | |
| 6/4/2019 0:00 | SKU1 | 40 | |
| 6/11/2019 0:00 | SKU1 | 38 | |
| 6/13/2019 0:00 | SKU1 | 36 | |
| 6/17/2019 0:00 | SKU1 | 34 | |
| 6/27/2019 0:00 | SKU1 | 34 | |
| 7/15/2019 0:00 | SKU1 | 32 | |
| 7/22/2019 0:00 | SKU1 | 31 | |
| 8/6/2019 0:00 | SKU1 | 27 | |
| 8/26/2019 0:00 | SKU1 | 25 | |
| 9/12/2019 0:00 | SKU1 | 25 | |
| 9/18/2019 0:00 | SKU1 | 23 | |
| 9/24/2019 0:00 | SKU1 | 19 | |
| 10/1/2019 0:00 | SKU1 | 17 | |
| 10/4/2019 0:00 | SKU1 | 15 | |
| 10/8/2019 0:00 | SKU1 | 12 | |
| 11/12/2019 0:00 | SKU1 | 10 | |
| 11/26/2019 0:00 | SKU1 | 10 | |
| 12/6/2019 0:00 | SKU1 | 8 | |
| 12/11/2019 0:00 | SKU1 | 4 | |
| 12/13/2019 0:00 | SKU1 | 24 | |
| 1/8/2020 0:00 | SKU1 | 20 | |
| 1/9/2020 0:00 | SKU1 | 18 | |
| 1/15/2020 0:00 | SKU1 | 14 | |
| 2/5/2020 0:00 | SKU1 | 6 | |
| 2/20/2020 0:00 | SKU1 | 4 | |
| 3/4/2020 0:00 | SKU1 | 2 | |
| 3/10/2020 0:00 | SKU1 | 0 | |
| 3/16/2020 0:00 | SKU1 | 0 | |
| 3/18/2020 0:00 | SKU1 | 0 | |
| 3/20/2020 0:00 | SKU1 | 0 | |
| 3/25/2020 0:00 | SKU1 | 0 | |
| 3/26/2020 0:00 | SKU1 | 0 | |
| 4/4/2020 0:00 | SKU1 | 0 | |
| 4/14/2020 0:00 | SKU1 | 0 | |
| 4/17/2020 0:00 | SKU1 | 0 | |
| 5/5/2020 0:00 | SKU1 | 24 | 62 |
| 5/6/2020 0:00 | SKU1 | 22 | |
| 5/8/2020 0:00 | SKU1 | 20 | |
| 5/12/2020 0:00 | SKU1 | 18 | |
| 5/15/2020 0:00 | SKU1 | 18 | |
| 5/22/2020 0:00 | SKU1 | 16 | |
| 6/1/2020 0:00 | SKU1 | 14 | |
| 6/2/2020 0:00 | SKU1 | 12 | |
| 6/3/2020 0:00 | SKU1 | 8 | |
| 6/8/2020 0:00 | SKU1 | 4 | |
| 6/9/2020 0:00 | SKU1 | 2 | |
| 6/12/2020 0:00 | SKU1 | 1 | |
| 6/26/2020 0:00 | SKU1 | 25 | |
| 7/2/2020 0:00 | SKU1 | 25 | |
| 7/3/2020 0:00 | SKU1 | 21 | |
| 7/20/2020 0:00 | SKU1 | 19 | |
| 7/21/2020 0:00 | SKU1 | 18 | |
| 7/29/2020 0:00 | SKU1 | 18 | |
| 8/6/2020 0:00 | SKU1 | 16 | |
| 8/11/2020 0:00 | SKU1 | 12 | |
| 8/12/2020 0:00 | SKU1 | 38 | |
| 8/13/2020 0:00 | SKU1 | 37 | |
| 8/21/2020 0:00 | SKU1 | 41 | |
| 8/24/2020 0:00 | SKU1 | 37 | |
| 8/26/2020 0:00 | SKU1 | 33 | |
| 8/27/2020 0:00 | SKU1 | 31 | |
| 9/3/2020 0:00 | SKU1 | 29 | |
| 9/8/2020 0:00 | SKU1 | 27 | |
| 9/18/2020 0:00 | SKU1 | 25 | |
| 9/25/2020 0:00 | SKU1 | 23 | |
| 10/5/2020 0:00 | SKU1 | 21 | |
| 10/8/2020 0:00 | SKU1 | 28 | |
| 10/14/2020 0:00 | SKU1 | 28 | |
| 10/16/2020 0:00 | SKU1 | 26 | |
| 10/23/2020 0:00 | SKU1 | 24 | |
| 10/30/2020 0:00 | SKU1 | 22 | |
| 11/5/2020 0:00 | SKU1 | 52 |
Solved! Go to Solution.
Hi @Anonymous ,
Please check:
1. Add an index column.
2. Create calculated columns.
StartDate =
VAR CurrentRow = [Index]
VAR PreviousRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow - 1 )
VAR NextRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow + 1 )
VAR FirstIndexofeachStock =
CALCULATE ( MIN ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR LastIndexofeachStock =
CALCULATE ( MAX ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR StartDate_ =
IF (
[Index] <> FirstIndexofeachStock
&& [Index] <> LastIndexofeachStock,
IF ( [OnHand] <> 0 && PreviousRow <> 0 && NextRow = 0, [EntryDt] )
)
RETURN
StartDate_
Days Out Of Stock Column =
VAR ModifiedStartDate =
CALCULATE (
MAX ( Scott[StartDate] ),
FILTER (
Scott,
Scott[StockCode] = EARLIER ( Scott[StockCode] )
&& Scott[Index] <= EARLIER ( Scott[Index] )
)
)
VAR CurrentRow = [Index]
VAR PreviousRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow - 1 )
VAR NextRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow + 1 )
VAR FirstIndexofeachStock =
CALCULATE ( MIN ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR EndDate =
IF (
[Index] <> FirstIndexofeachStock,
IF ( [OnHand] <> 0 && PreviousRow = 0 && NextRow <> 0, [EntryDt] )
)
RETURN
IF ( EndDate <> BLANK (), DATEDIFF ( ModifiedStartDate, EndDate, DAY ) )
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
Hi @Anonymous ,
Please check:
1. Add an index column.
2. Create calculated columns.
StartDate =
VAR CurrentRow = [Index]
VAR PreviousRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow - 1 )
VAR NextRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow + 1 )
VAR FirstIndexofeachStock =
CALCULATE ( MIN ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR LastIndexofeachStock =
CALCULATE ( MAX ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR StartDate_ =
IF (
[Index] <> FirstIndexofeachStock
&& [Index] <> LastIndexofeachStock,
IF ( [OnHand] <> 0 && PreviousRow <> 0 && NextRow = 0, [EntryDt] )
)
RETURN
StartDate_
Days Out Of Stock Column =
VAR ModifiedStartDate =
CALCULATE (
MAX ( Scott[StartDate] ),
FILTER (
Scott,
Scott[StockCode] = EARLIER ( Scott[StockCode] )
&& Scott[Index] <= EARLIER ( Scott[Index] )
)
)
VAR CurrentRow = [Index]
VAR PreviousRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow - 1 )
VAR NextRow =
LOOKUPVALUE ( Scott[OnHand], Scott[Index], CurrentRow + 1 )
VAR FirstIndexofeachStock =
CALCULATE ( MIN ( Scott[Index] ), ALLEXCEPT ( Scott, Scott[StockCode] ) )
VAR EndDate =
IF (
[Index] <> FirstIndexofeachStock,
IF ( [OnHand] <> 0 && PreviousRow = 0 && NextRow <> 0, [EntryDt] )
)
RETURN
IF ( EndDate <> BLANK (), DATEDIFF ( ModifiedStartDate, EndDate, DAY ) )
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!
Check out the October 2025 Power BI update to learn about new features.
| User | Count |
|---|---|
| 76 | |
| 37 | |
| 31 | |
| 27 | |
| 27 |