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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
wi11iamr
Advocate II
Advocate II

Calculate compound increased fee from initial start date (Power Query)

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

1 ACCEPTED SOLUTION
Sean
Community Champion
Community Champion

Calculated Fee = 
'Table'[InitialFee]
    * POWER (
        1 + 'Table'[ContractAnnualEscalation],
        DATEDIFF (
            CALCULATE (
                FIRSTDATE ( 'Table'[ContractStartDate] ),
                ALLEXCEPT ( 'Table', 'Table'[ContractRef#] )
            ),
            'Table'[TransactionDate],
            YEAR
        )
    )

Annual Rate Increase Calculation.png

I had several versions of this - it seems this is the simplest so far!

Hope this helps! Smiley Happy

View solution in original post

5 REPLIES 5
Sean
Community Champion
Community Champion

Calculated Fee = 
'Table'[InitialFee]
    * POWER (
        1 + 'Table'[ContractAnnualEscalation],
        DATEDIFF (
            CALCULATE (
                FIRSTDATE ( 'Table'[ContractStartDate] ),
                ALLEXCEPT ( 'Table', 'Table'[ContractRef#] )
            ),
            'Table'[TransactionDate],
            YEAR
        )
    )

Annual Rate Increase Calculation.png

I had several versions of this - it seems this is the simplest so far!

Hope this helps! Smiley Happy

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.

www.CahabaData.com

The separate table approach could be helpful if the interest rate changes. Although you can still handle this with a single table using iterators.

To learn more about DAX visit : aka.ms/practicalDAX

Proud to be a Datanaut!

Even if you create another table the formula remains basically the same Smiley Happy

 Annual Rate Increase Calculation2.png

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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