The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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.
Solved! Go to Solution.
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.
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.
Hi @Sushil9104 provide some example data with wanted output as example.
Proud to be a Super User!
User | Count |
---|---|
25 | |
12 | |
8 | |
8 | |
7 |
User | Count |
---|---|
28 | |
13 | |
12 | |
12 | |
6 |