cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
jingxiawang
Regular Visitor

Calculate End Time to use the Start Time of the event for the same unit

Hi,

 

I'm looking for a DAX to calculate below End Time.

 

Here is the example:

Unit                              Start Time                               End Time

Unit 1                           1/1/2022 7:00:00am

Unit 1                           1/1/2022 7:05:00am

Unit 2                            1/1/2022 7:00:00am

Unit 2                            1/1/2022 7:10:00am

 

  • Start Time: The table data has the start time
  • End Time: Needs to be calculated, I need to build the logic to look at the same unit, have the End equals to the Start of the next event for the same unit.

If there’s no other event for the same unit, use the last Power BI dataset refresh time stamp as the End.

If the two events for the same unit spans different months, use the midnight time stamp 00:00 on the last day of the month as the End for the 1st event of the two events.

 

Can anyone help me with the DAX to achieve this?

1 ACCEPTED SOLUTION

Hi @jingxiawang ,

 

Please try this calculated column

End Time =
VAR _next =
    MAXX (
        FILTER (
            'Table',
            [Unit] = EARLIER ( 'Table'[Unit] )
                && [Start Time] > EARLIER ( 'Table'[Start Time] )
        ),
        [Start Time]
    )
VAR _last =
    MAXX (
        FILTER (
            'Table',
            [Unit] = EARLIER ( 'Table'[Unit] )
                && [Start Time] < EARLIER ( 'Table'[Start Time] )
        ),
        [Start Time]
    )
RETURN
    IF (
        ISBLANK ( _next ),
        IF (
            DATEDIFF ( _last, [Start Time], MONTH ) > 0,
            EOMONTH ( [Start Time], 0 ),
            NOW ()
        ),
        _next
    )

Here's the results:

vstephenmsft_0-1648716927892.png

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
jingxiawang
Regular Visitor

Thanks, Amit. It worked perfectly to handle the 1st part of the calculation. But it still does not handle below logic:

  •  If there’s no other event for the same unit, use the last Power BI dataset refresh time stamp as the End.
  • If the two events for the same unit spans different months, use the midnight time stamp 00:00 on the last day of the month as the End for the 1st event of the two events.

Is there anyway we can include these two logic in the DAX?

amitchandak
Super User
Super User

@jingxiawang , a new column

 

minx(filter(Table, [Unit] = EARLIER([Unit]) && [Start Time] > earlier([[Start Time]) ),[Start Time])

 

or

 

 

coalesce(minx(filter(Table, [Unit] = EARLIER([Unit]) && [Start Time] > earlier([[Start Time]) ),[Start Time]), [Start Time])

Thanks, Amit. It worked perfectly to handle the 1st part of the calculation. But it still does not handle below logic:

  •  If there’s no other event for the same unit, use the last Power BI dataset refresh time stamp as the End.
  • If the two events for the same unit spans different months, use the midnight time stamp 00:00 on the last day of the month as the End for the 1st event of the two events.

Is there anyway we can include these two logic in the DAX?

Hi @jingxiawang ,

 

Please try this calculated column

End Time =
VAR _next =
    MAXX (
        FILTER (
            'Table',
            [Unit] = EARLIER ( 'Table'[Unit] )
                && [Start Time] > EARLIER ( 'Table'[Start Time] )
        ),
        [Start Time]
    )
VAR _last =
    MAXX (
        FILTER (
            'Table',
            [Unit] = EARLIER ( 'Table'[Unit] )
                && [Start Time] < EARLIER ( 'Table'[Start Time] )
        ),
        [Start Time]
    )
RETURN
    IF (
        ISBLANK ( _next ),
        IF (
            DATEDIFF ( _last, [Start Time], MONTH ) > 0,
            EOMONTH ( [Start Time], 0 ),
            NOW ()
        ),
        _next
    )

Here's the results:

vstephenmsft_0-1648716927892.png

 

 

Best Regards,

Stephen Tao

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Vote for T-Shirt Design

Power BI T-Shirt Design Challenge 2023

Vote for your favorite t-shirt design now through March 28.

March 2023 Update3

Power BI March 2023 Update

Find out more about the March 2023 update.

March Events 2023A

March 2023 Events

Find out more about the online and in person events happening in March!

Top Solution Authors