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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
pintobean87
Frequent Visitor

Calculating overtime hours on a bi-weekly basis

Hello all,

 

I was doing some research on a solution for my problem, but still haven't come across anything that matches my scenario; however, there is this old topic that calculates overtime hours on a weekly basis based on the sample table shown in the solution.

 

https://community.powerbi.com/t5/Desktop/Calculating-over-time-hours-for-employees/m-p/728653

 

However, I would like to calculate overtime for every two weeks (bi-weekly). Here is a sample table that I will be using.

 

pintobean87_0-1668538300039.png

 

Is there a way to do this or is it just not possible? I've tried so many ways and looking up information with no luck. 

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

Hi @pintobean87 ,

 

Please try:

Measure = 
var _a = RANKX(ALLEXCEPT('Table','Table'[Employee]),[Week Ending],MAX('Table'[Week Ending]),ASC,Dense)
var _b = MAXX(FILTER(ALLEXCEPT('Table','Table'[Employee]),[Week Ending]<MAX('Table'[Week Ending])),[Week Ending])
var _c = CALCULATE(SUM('Table'[Hours]),FILTER(ALL('Table'),[Employee]=MAX('Table'[Employee])&&[Week Ending]<=MAX('Table'[Week Ending])&&[Week Ending]>=_b))-40
return IF(_a=ODD(_a),BLANK(),_c)

Final output:

vjianbolimsft_0-1668578919137.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

5 REPLIES 5
v-jianboli-msft
Community Support
Community Support

Hi @pintobean87 ,

 

Please try:

Measure = 
var _a = RANKX(ALLEXCEPT('Table','Table'[Employee]),[Week Ending],MAX('Table'[Week Ending]),ASC,Dense)
var _b = MAXX(FILTER(ALLEXCEPT('Table','Table'[Employee]),[Week Ending]<MAX('Table'[Week Ending])),[Week Ending])
var _c = CALCULATE(SUM('Table'[Hours]),FILTER(ALL('Table'),[Employee]=MAX('Table'[Employee])&&[Week Ending]<=MAX('Table'[Week Ending])&&[Week Ending]>=_b))-40
return IF(_a=ODD(_a),BLANK(),_c)

Final output:

vjianbolimsft_0-1668578919137.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.

I have one last question! When an employee has less than 80 hours bi-weekly, a negative number is returned. This affects the total amount of hours for all employees (since I only want to see overtime hours). Is there a way to simply not return anything if overtime is below 80?

Hi @pintobean87 ,

 

Please try:

Measure = 
var _a = RANKX(ALLEXCEPT('Table','Table'[Employee]),[Week Ending],MAX('Table'[Week Ending]),ASC,Dense)
var _b = MAXX(FILTER(ALLEXCEPT('Table','Table'[Employee]),[Week Ending]<MAX('Table'[Week Ending])),[Week Ending])
var _c = CALCULATE(SUM('Table'[Hours]),FILTER(ALL('Table'),[Employee]=MAX('Table'[Employee])&&[Week Ending]<=MAX('Table'[Week Ending])&&[Week Ending]>=_b))-80
return IF(_a=ODD(_a)||_c<0,BLANK(),_c)

 

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.

Thank you so much! This worked great. I tried a variety of situational data, and it works perfect.

 

pintobean87
Frequent Visitor

Is this not possible?

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

Check out the February 2024 Power BI update to learn about new features.

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.