How to find minimum interval?

macfuller

Active Member
Joined
Apr 30, 2014
Messages
317
Office Version
  1. 365
Platform
  1. Windows
We have a file of order history for supplies. Within a storeroom I would like to find the minimum order time for each item within a selected time period. We run 2-bin Kanban so two orders on the same day would indicate a stockout.

Primary key is Storeroom_Item#_Unit of Measure e.g. ABC123_005678_Box
Data is (simplified):
Primary key Order Date Order Qty

First, I'm trying to think if there's a single measure I could write against the data to get the minimum interval between two dates without a helper column, but I haven't figured it out. It seemed more elegant...

More likely I would create a helper column in either PowerQuery or DAX to provide the interval between dates and then just do a MIN([Interval]) expression. I prefer to use PowerQuery but I think I'd have to do a self-merge, but the files are big and I don't want to slow down the already-lengthy daily refresh process. Off the top of my head a DAX calculated column would probably be something along the lines of

=EARLIER([Order Date]) - CALCULATE(MAX[Order Date], FILTER(Orders, EARLIER([Primary key] = [Primary key] && EARLIER([Order Date]) > [Order Date]))

plus some condition to apply a blank value if the record is the first order within the time period. (Would I have to copy the whole CALCULATE segment into a wraparound IF statement?)

That's why I'm hoping for something prettier!
:confused:
 

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
The actual DAX for the interval column (I welcome cleanup suggestions!) is

Code:
=
IF (
    ISBLANK (
        CALCULATE (
            COUNTROWS ( 'Order History' ),
            FILTER (
                'Order History',
                EARLIER ( 'Order History'[FK_CartItem] ) = 'Order History'[FK_CartItem]
                    && EARLIER ( 'Order History'[Demand Date] ) > 'Order History'[Demand Date]
            )
        )
    ),
    BLANK (),
    FORMAT (
        'Order History'[Demand Date]
            - CALCULATE (
                MAX ( 'Order History'[Demand Date] ),
                FILTER (
                    'Order History',
                    EARLIER ( 'Order History'[FK_CartItem] ) = 'Order History'[FK_CartItem]
                        && EARLIER ( 'Order History'[Demand Date] ) > 'Order History'[Demand Date]
                )
            ),
        "###"
    )
)

Yes, I'm stuck with Office 2013 at work so no DATEDIFF.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,552
Messages
6,114,278
Members
448,559
Latest member
MrPJ_Harper

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top