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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
tonyclifton
Helper III
Helper III

Formula for Date closest to Today()

Hello community,

 

this is probably a trivial question but I could not find a solution yet.

 

Example: A product can have multiple shipping dates. I want to create a page level filter where the shipping date is closest to Today() so that only one row is being displayed.

If there were three dates (three rows) the colum "ClosestShippingDate" would contain two 0 values and one row with a 1 as value.

 

In a meassure I did something like this:

isClosestShippingDate = DATEDIFF(TODAY();MIN('Products'[ShippingDate]);DAY) 

which is not correct because I need the value closest to zero instead of MIN().

 

How can I achieve this? Ideally with PowerQuery since I don't think a measure can be a page level filter.

 

Thank you.

1 ACCEPTED SOLUTION

Hi @tonyclifton ,

 

Combined one as below.

 

isClosestShippingDate = 
VAR mindate =
    CALCULATE (
        MIN ( 'Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER ( Table1[product] ) && Table1[shipping date]>=TODAY() )
    )
VAR maxdate =
    CALCULATE (
        MAX('Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER (Table1[product]) && Table1[shipping date]<=TODAY() )
    )
RETURN
    IF (
        'Table1'[shipping date] = mindate,
        DATEDIFF ( TODAY (), mindate, DAY ),
        IF(Table1[shipping date]=maxdate,DATEDIFF(TODAY(),maxdate,DAY)
    )
)

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

View solution in original post

7 REPLIES 7
v-frfei-msft
Community Support
Community Support

Hi @tonyclifton ,

 

We can create a calculated column instead of meaure to work on it.

 

isClosestShippingDate = 
VAR mindate =
    CALCULATE (
        MIN ( 'Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER ( Table1[product] ) )
    )
RETURN
    IF (
        'Table1'[shipping date] = mindate,
        DATEDIFF ( TODAY (), mindate, DAY ),
        BLANK ()
    )

Capture.PNG

 

Then we can filter the blank value out to get the excepted result as we need.

 

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

@v-frfei-msftthank you for the sample - it is working great.
However, I forgot to mention that only ShippingDates greater or equal than today should be considered so I added an AND to the filter method.
But this way I have no information about products with dates in the past which is definitely needed sooner or later.

Is there a way to also deal with Projects that only have ShippingDates in the past, so that only the closest value to today is being displayed?


Here is how I modified your formula for the filter function:

isClosestShippingDate = 
VAR mindate = 
CALCULATE ( MIN ( 'Table1'[shipping date] ), 
FILTER ( Table1, Table1[product] = EARLIER ( Table1[product] ) 
		&& 'Table1'[shipping date] >= TODAY()
)) 
RETURN IF ( 'Table1'[shipping date] = mindate, 1, 0 )

Thank you.

Hi @tonyclifton ,

 

isClosestShippingDatepast = 
VAR maxdate =
    CALCULATE (
        MAX('Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER (Table1[product]) && Table1[shipping date]<=TODAY() )
    )
RETURN
    IF (
        'Table1'[shipping date] = maxdate,
        DATEDIFF ( TODAY (), maxdate, DAY ),
        BLANK ()
    )

2.PNG

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

@v-frfei-msftthanks. Any change to make a single column out of both so that filtering is easier?

Hi @tonyclifton ,

 

Combined one as below.

 

isClosestShippingDate = 
VAR mindate =
    CALCULATE (
        MIN ( 'Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER ( Table1[product] ) && Table1[shipping date]>=TODAY() )
    )
VAR maxdate =
    CALCULATE (
        MAX('Table1'[shipping date] ),
        FILTER ( Table1, Table1[product] = EARLIER (Table1[product]) && Table1[shipping date]<=TODAY() )
    )
RETURN
    IF (
        'Table1'[shipping date] = mindate,
        DATEDIFF ( TODAY (), mindate, DAY ),
        IF(Table1[shipping date]=maxdate,DATEDIFF(TODAY(),maxdate,DAY)
    )
)

 

Community Support Team _ Frank
If this post helps, then please consider Accept it as the solution to help the others find it more quickly.

Thanks alot @v-frfei-msft I finally got it working by changing the return statement to:

 

RETURN SWITCH(TRUE() ; mindate <> BLANK() && Table1[shipping date] = mindate; 1 
; maxdate <> BLANK() && mindate = BLANK() && 'Table1'[shipping date] = maxdate ;1 ;0)
Anonymous
Not applicable

@tonyclifton - You can use the ABS function to get the Absolute Value and then get the minimum.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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