Hi there,
Having the below sample dataset within a query, I have a monthly transaction record for each Contract reference number, along with the contract's initial fee for the fiirst year, and then the percentage escalation that is to be applied year on year.
The CalculatedFee column is the one I wish to calculate.
I suspect that in addition to using the InitialFee and ContractAnnualEscalation values, I would first need to determine the number of months/years between the TransactionDate and the ContractStartDate. I'm having a few challenges with this (a Duration.Months function would be nice), however notwithstanding this, I'm at a loss at how to calculate the new compounded fee for each year.
ContractRef# TransactionDate ContractStartDate ContractEndDate InitialFee ContractAnnualEscalation (CalculatedFee)
1 2016/07/01 2016/07/01 2020/06/31 1000 10% 1000
1 2016/08/01 2016/07/01 2020/06/31 1000 10% 1000
....
1 2017/07/01 2016/07/01 2020/06/31 1000 10% 1100
1 2017/08/01 2016/07/01 2020/06/31 1000 10% 1100
....
1 2018/07/01 2016/07/01 2020/06/31 1000 10% 1210
1 2018/08/01 2016/07/01 2020/06/31 1000 10% 1210
....
1 2019/07/01 2016/07/01 2020/06/31 1000 10% 1331
1 2019/08/01 2016/07/01 2020/06/31 1000 10% 1331
Solved! Go to Solution.
Calculated Fee = 'Table'[InitialFee] * POWER ( 1 + 'Table'[ContractAnnualEscalation], DATEDIFF ( CALCULATE ( FIRSTDATE ( 'Table'[ContractStartDate] ), ALLEXCEPT ( 'Table', 'Table'[ContractRef#] ) ), 'Table'[TransactionDate], YEAR ) )
I had several versions of this - it seems this is the simplest so far!
Hope this helps!
Calculated Fee = 'Table'[InitialFee] * POWER ( 1 + 'Table'[ContractAnnualEscalation], DATEDIFF ( CALCULATE ( FIRSTDATE ( 'Table'[ContractStartDate] ), ALLEXCEPT ( 'Table', 'Table'[ContractRef#] ) ), 'Table'[TransactionDate], YEAR ) )
I had several versions of this - it seems this is the simplest so far!
Hope this helps!
Thanks @Sean - I truly appreciate the effort you took in testing different scenarios. Your suggested code works like a charm!
a wholly different approach would be to create a new separate table by DISTINCT Year; so there would be 1 record per year.
then calculate the fee as part of this table.
it might be useful in your data model in the long run, and can then also be joined back into your original table if you need the value with each record.
Even if you create another table the formula remains basically the same
Check out new user group experience and if you are a leader please create your group
100+ sessions, 100+ speakers, Product managers, MVPs, and experts. All about Power BI. Attend online or watch the recordings.
User | Count |
---|---|
403 | |
194 | |
86 | |
83 | |
62 |
User | Count |
---|---|
472 | |
217 | |
141 | |
95 | |
83 |