Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Scott_HPD
New Member

Days Out of Stock - DateDiff between rows with 0 values in middle

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)

Scott_HPD_0-1605288414175.png

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

 

EntryDtStockCodeOnHandDays Out Of Stock
4/30/2019 0:00SKU122 
5/27/2019 0:00SKU122 
5/28/2019 0:00SKU120 
6/2/2019 0:00SKU140 
6/4/2019 0:00SKU140 
6/11/2019 0:00SKU138 
6/13/2019 0:00SKU136 
6/17/2019 0:00SKU134 
6/27/2019 0:00SKU134 
7/15/2019 0:00SKU132 
7/22/2019 0:00SKU131 
8/6/2019 0:00SKU127 
8/26/2019 0:00SKU125 
9/12/2019 0:00SKU125 
9/18/2019 0:00SKU123 
9/24/2019 0:00SKU119 
10/1/2019 0:00SKU117 
10/4/2019 0:00SKU115 
10/8/2019 0:00SKU112 
11/12/2019 0:00SKU110 
11/26/2019 0:00SKU110 
12/6/2019 0:00SKU18 
12/11/2019 0:00SKU14 
12/13/2019 0:00SKU124 
1/8/2020 0:00SKU120 
1/9/2020 0:00SKU118 
1/15/2020 0:00SKU114 
2/5/2020 0:00SKU16 
2/20/2020 0:00SKU14 
3/4/2020 0:00SKU12 
3/10/2020 0:00SKU10 
3/16/2020 0:00SKU10 
3/18/2020 0:00SKU10 
3/20/2020 0:00SKU10 
3/25/2020 0:00SKU10 
3/26/2020 0:00SKU10 
4/4/2020 0:00SKU10 
4/14/2020 0:00SKU10 
4/17/2020 0:00SKU10 
5/5/2020 0:00SKU12462
5/6/2020 0:00SKU122 
5/8/2020 0:00SKU120 
5/12/2020 0:00SKU118 
5/15/2020 0:00SKU118 
5/22/2020 0:00SKU116 
6/1/2020 0:00SKU114 
6/2/2020 0:00SKU112 
6/3/2020 0:00SKU18 
6/8/2020 0:00SKU14 
6/9/2020 0:00SKU12 
6/12/2020 0:00SKU11 
6/26/2020 0:00SKU125 
7/2/2020 0:00SKU125 
7/3/2020 0:00SKU121 
7/20/2020 0:00SKU119 
7/21/2020 0:00SKU118 
7/29/2020 0:00SKU118 
8/6/2020 0:00SKU116 
8/11/2020 0:00SKU112 
8/12/2020 0:00SKU138 
8/13/2020 0:00SKU137 
8/21/2020 0:00SKU141 
8/24/2020 0:00SKU137 
8/26/2020 0:00SKU133 
8/27/2020 0:00SKU131 
9/3/2020 0:00SKU129 
9/8/2020 0:00SKU127 
9/18/2020 0:00SKU125 
9/25/2020 0:00SKU123 
10/5/2020 0:00SKU121 
10/8/2020 0:00SKU128 
10/14/2020 0:00SKU128 
10/16/2020 0:00SKU126 
10/23/2020 0:00SKU124 
10/30/2020 0:00SKU122 
11/5/2020 0:00SKU152 
1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @Scott_HPD ,

 

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 ) )

STOCK.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

View solution in original post

1 REPLY 1
Icey
Community Support
Community Support

Hi @Scott_HPD ,

 

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 ) )

STOCK.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.