Present Value (PV) function for Power Query

Finally 2023 is here, the year we expect Power Query function libraries to ship. This will make it so much easier to re-use ready made function than M-extensions. So let’s start collecting some fodder for it, by creating a function to calculate the Present Value (PV) for Power Query:

Excel’s Present Value (PV) function for Power Query

Excel’s PV function returns the present value of a loan or an investment, based on a constant interest rate. Fortunately, this function is relatively new in the DAX-language so that I can simply borrow the calculation logic from Greg Deckler, who created tons of quick measures before their release:


let func =
(Rate as number, Nper as number, Pmt as number, optional Fv_ as number, optional Type_ as number) =>
let
// Source for calculation logic: https://community.powerbi.com/t5/Community-Blog/P-Q-Excel-to-DAX-Translation/ba-p/1061107
Type = if Type_ is null then 0 else Type_,
Fv = if Fv_ = null then 0 else Fv_,
Custom3 =
if Rate = 0
then -1 * ( (Pmt * Nper) + Fv)
else ( Pmt * ( 1 + Rate * Type) *
(( Number.Power(1 + Rate, Nper) -1 )/ Rate ) + Fv )
/ Number.Power(1 + Rate , Nper) * -1
in
Custom3 ,
documentation = [
Documentation.Name = " Xls.PV ",
Documentation.Description = " Returns the present value of a loan or an investment, based on a constant interest rate. ",
Documentation.LongDescription = " Returns the present value of a loan or an investment, based on a constant interest rate. Optional future value and type of payment can be used. ",
Documentation.Category = " Xls.Financial ",
Documentation.Source = " www.TheBIcountant.com . ",
Documentation.Version = " 1.0 ",
Documentation.Author = " Imke Feldmann ",
Documentation.Examples = {[Description = " ",
Code = " let
Rate = 0.08,
Nper = 20 ,
Pmt = 500,
Fv_ = 10000,
Type_ = 1,
FunctionCall = fnPV(Rate, Nper, Pmt, Fv_, Type_)
in
FunctionCall ",
Result = " -7447,28167406318
"]}]
in
Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation))

view raw

Xls.PV.pq

hosted with ❤ by GitHub

Function arguments

To keep it really convenient, the arguments for this function are identical with the Excel ones:

  • Rate    Required. The interest rate per period. For example, if you obtain an automobile loan at a 10 percent annual interest rate and make monthly payments, your interest rate per month is 10%/12, or 0.83%. You would enter 10%/12, or 0.83%, or 0.0083, into the formula as the rate.
  • Nper    Required. The total number of payment periods in an annuity. For example, if you get a four-year car loan and make monthly payments, your loan has 4*12 (or 48) periods. You would enter 48 into the formula for nper.
  • Pmt    Required. The payment made each period and cannot change over the life of the annuity. Typically, pmt includes principal and interest but no other fees or taxes. For example, the monthly payments on a $10,000, four-year car loan at 12 percent are $263.33. You would enter -263.33 into the formula as the pmt. If pmt is omitted, you must include the fv argument.
  • Fv    Optional. The future value, or a cash balance you want to attain after the last payment is made. If fv is omitted, it is assumed to be 0 (the future value of a loan, for example, is 0). For example, if you want to save $50,000 to pay for a special project in 18 years, then $50,000 is the future value. You could then make a conservative guess at an interest rate and determine how much you must save each month. If fv is omitted, you must include the pmt argument.
  • Type    Optional. The number 0 or 1 and indicates when payments are due:
Set type equal to If payments are due
0 or omitted At the end of the period
1 At the beginning of the period

Please check out the following video to see how to apply this function in your solution:

Enjoy and stay queryious 😉

Comment (1) Write a comment

  1. Pingback: Calculating Present Value in Power Query – Curated SQL

Leave a Reply