cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Niels_IRD
Frequent Visitor

How to write specific time formula

If the next row is in timespan within 30 minutes of the current row then increment count +1 else reset count.

 

Below you can see the desired output:

Niels_IRD_0-1669975132321.png

 

1 ACCEPTED SOLUTION
v-jianboli-msft
Community Support
Community Support

Hi @Niels_IRD ,

 

Please try:

First add an index column:

vjianbolimsft_0-1670230452865.png

Then create a calculated column:

Column =
VAR _a =
    CALCULATE (
        MAX ( 'Table'[Date] ) + MAX ( 'Table'[Time] ),
        FILTER ( 'Table', [Index] = EARLIER ( 'Table'[Index] ) - 1 )
    )
VAR _b = [Date] + [Time]
VAR _c =
    ADDCOLUMNS (
        'Table',
        "a",
            CALCULATE (
                MAX ( 'Table'[Date] ) + MAX ( 'Table'[Time] ),
                FILTER ( 'Table', [Index] = EARLIER ( 'Table'[Index] ) - 1 )
            ),
        "b", [Date] + [Time]
    )
VAR _diff =
    ADDCOLUMNS ( _c, "Diff", DATEDIFF ( [a], [b], MINUTE ) )
VAR _maxindex =
    MINX (
        FILTER ( _diff, [Diff] > 30 && [Index] >= EARLIER ( 'Table'[Index] ) ),
        [Index]
    )
VAR _minindex =
    MAXX (
        FILTER ( _diff, [Diff] > 30 && [Index] <= EARLIER ( 'Table'[Index] ) ),
        [Index]
    ) + 0
VAR _filtertable =
    FILTER ( 'Table', [Index] >= _minindex && [Index] <= _maxindex )
VAR _count =
    COUNTROWS ( FILTER ( _filtertable, [Index] <= EARLIER ( 'Table'[Index] ) ) )
RETURN
    _count

Final output:

vjianbolimsft_1-1670233977634.png

Best Regards,

Jianbo Li

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

2 REPLIES 2
v-jianboli-msft
Community Support
Community Support

Hi @Niels_IRD ,

 

Please try:

First add an index column:

vjianbolimsft_0-1670230452865.png

Then create a calculated column:

Column =
VAR _a =
    CALCULATE (
        MAX ( 'Table'[Date] ) + MAX ( 'Table'[Time] ),
        FILTER ( 'Table', [Index] = EARLIER ( 'Table'[Index] ) - 1 )
    )
VAR _b = [Date] + [Time]
VAR _c =
    ADDCOLUMNS (
        'Table',
        "a",
            CALCULATE (
                MAX ( 'Table'[Date] ) + MAX ( 'Table'[Time] ),
                FILTER ( 'Table', [Index] = EARLIER ( 'Table'[Index] ) - 1 )
            ),
        "b", [Date] + [Time]
    )
VAR _diff =
    ADDCOLUMNS ( _c, "Diff", DATEDIFF ( [a], [b], MINUTE ) )
VAR _maxindex =
    MINX (
        FILTER ( _diff, [Diff] > 30 && [Index] >= EARLIER ( 'Table'[Index] ) ),
        [Index]
    )
VAR _minindex =
    MAXX (
        FILTER ( _diff, [Diff] > 30 && [Index] <= EARLIER ( 'Table'[Index] ) ),
        [Index]
    ) + 0
VAR _filtertable =
    FILTER ( 'Table', [Index] >= _minindex && [Index] <= _maxindex )
VAR _count =
    COUNTROWS ( FILTER ( _filtertable, [Index] <= EARLIER ( 'Table'[Index] ) ) )
RETURN
    _count

Final output:

vjianbolimsft_1-1670233977634.png

Best Regards,

Jianbo Li

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

 

 

amitchandak
Super User
Super User

@Niels_IRD ,a new column

 

countx(filter(Table, [Date] =earlier([Date]) && [Time] <= earlier([Time]) ), [Date])

Helpful resources

Announcements
PBI Sept Update Carousel

Power BI September 2023 Update

Take a look at the September 2023 Power BI update to learn more.

Learn Live

Learn Live: Event Series

Join Microsoft Reactor and learn from developers.

Top Solution Authors