Skip to content

Instantly share code, notes, and snippets.

@ncalm
Created June 23, 2022 15:18
Show Gist options
  • Star 1 You must be signed in to star a gist
  • Fork 1 You must be signed in to fork a gist
  • Save ncalm/4134e47518a05feca578e8d217278cda to your computer and use it in GitHub Desktop.
Save ncalm/4134e47518a05feca578e8d217278cda to your computer and use it in GitHub Desktop.
This Excel lambda function demonstrates a use of recursion in a financial context to calculate effective interest
/*
INTRATE.EFFECTIVE
Calculates the effective interest rate using a simplified assumption.
The intent here is to show an example of recursion in a financial function.
Inputs:
- opening_balance – the opening balance of some period of interest
- base_rate – the base rate of the instrument
- [interest] – OPTIONAL – this is used by the recursion to pass the calculated interest back into the formula to calculate the closing balance (and therefore average balance) during each iteration. Generally speaking, this should not be used when using this function to call from the downs
Please watch this video:
https://youtu.be/k5rG_MvIWWs
Explanatory post:
https://www.flexyourdata.com/blog/excel-lambda-intrate-effective-calculate-effective-interest-rate-in-excel-without-iterative-calculation/
*/
INTRATE.EFFECTIVE = LAMBDA(opening_balance, base_rate, [interest],
LET(
_int, IF(ISOMITTED(interest), 0, interest),
_new_close, opening_balance + _int,
_avg_balance, AVERAGE(opening_balance, _new_close),
_new_int, _avg_balance * base_rate,
_effective_rate, IF(
ROUND(_new_int, 2) = ROUND(_int, 2),
_new_int / opening_balance,
INTRATE.EFFECTIVE(opening_balance,base_rate,_new_int)
),
_effective_rate
)
);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment