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
Alanoudfahad
Frequent Visitor

Adjacent row formula using IF statement

Hello,

I have this problem that I couldn't find a work around in PBI and was hoping I could find some help here. I have a check in/check out system and I want to calculate the total time an employee spent at the office (i.e.: excluding breaks). the data is in a log fortmat as shown.

 

In the sample data below, I want column total time to first check if the person (Personnel ID) in the previous row is the same as the current row and then check if the day (Date) is also the same to calculate total number of hours per day by subtrackting the time in the 2 rows for each check in and check out.

 

1.jpg

 I appreciate any help.

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

Hi @Alanoudfahad ,

Try the following formula to create measures:

next_in/out = 
var next_time = 
    MINX(
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] > MAX('Table'[Time])
        ),
        'Table'[Time]
    )
var next_in_out = 
    CALCULATE(
        MAX('Table'[In/out]),
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] = next_time
        )
    )
return next_in_out
Diff_time = 
var next_time = 
    MINX(
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] > MAX('Table'[Time])
        ),
        'Table'[Time]
    )
return next_time - MAX('Table'[Time])
TotalTime = 
IF( 
    MAX('Table'[In/out]) = "IN" && [next_in/out] = "OUT",
    [Diff_time]
)

 image.png

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

7 REPLIES 7
v-kkf-msft
Community Support
Community Support

Hi @Alanoudfahad ,

Try the following formula to create measures:

next_in/out = 
var next_time = 
    MINX(
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] > MAX('Table'[Time])
        ),
        'Table'[Time]
    )
var next_in_out = 
    CALCULATE(
        MAX('Table'[In/out]),
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] = next_time
        )
    )
return next_in_out
Diff_time = 
var next_time = 
    MINX(
        FILTER(
            ALL('Table'),
            'Table'[Personnel ID] = MAX('Table'[Personnel ID]) && 'Table'[Date] = MAX('Table'[Date])
            && 'Table'[Time] > MAX('Table'[Time])
        ),
        'Table'[Time]
    )
return next_time - MAX('Table'[Time])
TotalTime = 
IF( 
    MAX('Table'[In/out]) = "IN" && [next_in/out] = "OUT",
    [Diff_time]
)

 image.png

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

Hi @v-kkf-msft  Thank you so much for the reply! I think we are almost there however, it's only showing my the IN and not the OUT, any idea?

Hi @Alanoudfahad ,

If you want to show total value, modify the measure:

TotalTime = 
var result = 
    IF( 
        MAX('Table'[In/out]) = "IN" && [next_in/out] = "OUT",
        [Diff_time],
        0
    )
return 
    IF(
        ISFILTERED('Table'[Time]),
        FORMAT(result,"hh:nn:ss"),
        FORMAT(
            SUMX(FILTER(ALL('Table'), 'Table'[In/out] = "IN" && [next_in/out] = "OUT"), [Diff_time] ),
            "hh:nn:ss"
        )
    )

 image.png

Hi @Alanoudfahad ,

 

Do you want show the OUT as 0:00:00 as shown before? If so, modify measure TotalTime to the following formula:

TotalTime = 
var result = 
    IF( 
        MAX('Table'[In/out]) = "IN" && [next_in/out] = "OUT",
        [Diff_time],
        0
    )
return FORMAT(result,"hh:nn:ss")

 image.png

If the problem is still not resolved, please provide detailed error information or the expected result you expect. Let me know immediately, looking forward to your reply.

Best Regards,
Winniz

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

@Alanoudfahad , Try a new column like this

if( [In/OUT] = "OUT" , datediff(maxx(filter(Table, [In/OUT] = "IN" && [Datetime] < earlier([[Datetime]])),[Datetime]),[Datetime], hour), blank())

 

and then you can sum this up in measure

Hello @amitchandak 
It gives me the following error:

Too many arguments were passed to the EARLIER function. The maximum argument count for the function is 2.

 

Any idea?

@Alanoudfahad , There is small correction in formula,

Create a new column first 

if( [In/OUT] = "OUT" , datediff(maxx(filter(Table, [In/OUT] = "IN" && [Datetime] < earlier([Datetime])),[Datetime]),[Datetime], hour), blank())

 

Then create a new measure with it.

 

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.