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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Sushil9104
New Member

Month on Month employee Cost based on date of joining and date of exit.

I have data which contains employee cost, Name, Date of joining, Date of exit for last 5 years and the current monthly cost. Want to present in a dashboard pro rata monthly cost based on date of joining and date of exit for each month. Please help as tried many dax formula but not getting the results. 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Sushil9104 ,

Please have a try.

Create a measure.

Pro Rata Monthly Cost = 
VAR CurrentMonth = SELECTEDVALUE ( 'Date'[Month & Year] )
VAR CurrentEmployee = SELECTEDVALUE ( 'Employee'[Name] )
VAR DateOfJoining = CALCULATE ( MIN ( 'Employee'[Date of joining] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
VAR DateOfExit = CALCULATE ( MAX ( 'Employee'[Date of exit] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
VAR DaysInMonth = DAY ( EOMONTH ( CurrentMonth, 0 ) )
VAR DaysWorked = COUNTROWS ( DATESBETWEEN ( 'Date'[Date], MAX ( DateOfJoining, EOMONTH ( CurrentMonth, -1 ) + 1 ), MIN ( DateOfExit, EOMONTH ( CurrentMonth, 0 ) ) ) )
VAR MonthlyCost = CALCULATE ( SUM ( 'Employee'[Current monthly cost] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
RETURN
DIVIDE ( MonthlyCost, DaysInMonth ) * DaysWorked

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Rongtie

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
Anonymous
Not applicable

Hi @Sushil9104 ,

Please have a try.

Create a measure.

Pro Rata Monthly Cost = 
VAR CurrentMonth = SELECTEDVALUE ( 'Date'[Month & Year] )
VAR CurrentEmployee = SELECTEDVALUE ( 'Employee'[Name] )
VAR DateOfJoining = CALCULATE ( MIN ( 'Employee'[Date of joining] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
VAR DateOfExit = CALCULATE ( MAX ( 'Employee'[Date of exit] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
VAR DaysInMonth = DAY ( EOMONTH ( CurrentMonth, 0 ) )
VAR DaysWorked = COUNTROWS ( DATESBETWEEN ( 'Date'[Date], MAX ( DateOfJoining, EOMONTH ( CurrentMonth, -1 ) + 1 ), MIN ( DateOfExit, EOMONTH ( CurrentMonth, 0 ) ) ) )
VAR MonthlyCost = CALCULATE ( SUM ( 'Employee'[Current monthly cost] ), FILTER ( 'Employee', 'Employee'[Name] = CurrentEmployee ) )
RETURN
DIVIDE ( MonthlyCost, DaysInMonth ) * DaysWorked

How to Get Your Question Answered Quickly 

 

If it does not help, please provide more details with your desired output and pbix file without privacy information (or some sample data) .

 

Best Regards
Community Support Team _ Rongtie

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

some_bih
Super User
Super User

Hi @Sushil9104 provide some example data with wanted output as example.





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!






Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

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

July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.