Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
Hi, I have a really tricky calculation for me that I can't resolve. I have a wage table where is all wages of employees. I need to calculate how much have the wage increased. There can be multiple wage increases/employee and it has to be calculated from the two latest agreement.
For example Employee.Id 1: Calculate(sum(monthlywage1-monthlywage2) where employee.id = 1 and monthlywage1=latestwage and monthlywage2 =secondlatest wage.
Id | Employee.Id | Startdate | MonthlyWage |
1 | 1 | 01.01.2018 | 1000 |
2 | 2 | 10.01.2019 | 3000 |
3 | 1 | 01.01.2019 | 1500 |
4 | 2 | 05.11.2020 | 3200 |
5 | 1 | 01.01.2021 | 2000 |
6 | 3 | 28.10.2020 | 1500 |
7 | 3 | 01.09.2021 | 1600 |
Solved! Go to Solution.
Hi @Anonymous ,
You can create two calculated columns
rank =
RANKX (
FILTER ( 'Table', [Employee.Id] = EARLIER ( 'Table'[Employee.Id] ) ),
[Startdate],
,
ASC,
DENSE
)
increase amount =
VAR _amount =
CALCULATE (
SUM ( 'Table'[MonthlyWage] ),
FILTER (
'Table',
[Employee.Id] = EARLIER ( 'Table'[Employee.Id] )
&& [rank]
= EARLIER ( 'Table'[rank] ) - 1
)
)
RETURN
IF ( ISBLANK ( _amount ), 0, [MonthlyWage] - _amount )
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous ,
You can create two calculated columns
rank =
RANKX (
FILTER ( 'Table', [Employee.Id] = EARLIER ( 'Table'[Employee.Id] ) ),
[Startdate],
,
ASC,
DENSE
)
increase amount =
VAR _amount =
CALCULATE (
SUM ( 'Table'[MonthlyWage] ),
FILTER (
'Table',
[Employee.Id] = EARLIER ( 'Table'[Employee.Id] )
&& [rank]
= EARLIER ( 'Table'[rank] ) - 1
)
)
RETURN
IF ( ISBLANK ( _amount ), 0, [MonthlyWage] - _amount )
Best Regards,
Stephen Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi,
Great this works like a charm :)! Thank you very much!
@Anonymous ,
Meausre =
var _max = calculate(Max(Table[Startdate]), allexcept(Table, Table[Employee.ID]))
var _max2 = calculate(MaxX(Filter(Table, Table[Startdate]<_max),Table[Startdate] ), allexcept(Table, Table[Employee.ID]))
return
calculate(sumX(values(Table[employee.id]) , calculate(sum(Table[MonthlyWage]), filter(Table, Table[Startdate]=_max)) -calculate(sum(Table[MonthlyWage]), filter(Table, Table[Startdate]=_max1))))
Hi @amitchandak for some reason the calculation returns incorrect result. for example previous wage has been 1337 and new wage is 3000. The result should be 1663(the difference between current and previous wage) but calculation returns -1337
User | Count |
---|---|
84 | |
78 | |
70 | |
47 | |
41 |
User | Count |
---|---|
108 | |
53 | |
50 | |
40 | |
40 |