diff --git a/calc.go b/calc.go index a4b60132..a1a0dcb4 100644 --- a/calc.go +++ b/calc.go @@ -290,6 +290,8 @@ var tokenPriority = map[string]int{ // FLOOR // FLOOR.MATH // FLOOR.PRECISE +// FV +// FVSCHEDULE // GAMMA // GAMMALN // GCD @@ -374,11 +376,14 @@ var tokenPriority = map[string]int{ // NORMSINV // NOT // NOW +// NPER +// NPV // OCT2BIN // OCT2DEC // OCT2HEX // ODD // OR +// PDURATION // PERCENTILE.INC // PERCENTILE // PERMUT @@ -7423,6 +7428,78 @@ func (fn *formulaFuncs) EFFECT(argsList *list.List) formulaArg { return newNumberFormulaArg(math.Pow((1+rate.Number/npery.Number), npery.Number) - 1) } +// FV function calculates the Future Value of an investment with periodic +// constant payments and a constant interest rate. The syntax of the function +// is: +// +// FV(rate,nper,[pmt],[pv],[type]) +// +func (fn *formulaFuncs) FV(argsList *list.List) formulaArg { + if argsList.Len() < 3 { + return newErrorFormulaArg(formulaErrorVALUE, "FV requires at least 3 arguments") + } + if argsList.Len() > 5 { + return newErrorFormulaArg(formulaErrorVALUE, "FV allows at most 5 arguments") + } + rate := argsList.Front().Value.(formulaArg).ToNumber() + if rate.Type != ArgNumber { + return rate + } + nper := argsList.Front().Next().Value.(formulaArg).ToNumber() + if nper.Type != ArgNumber { + return nper + } + pmt := argsList.Front().Next().Next().Value.(formulaArg).ToNumber() + if pmt.Type != ArgNumber { + return pmt + } + pv, typ := newNumberFormulaArg(0), newNumberFormulaArg(0) + if argsList.Len() >= 4 { + if pv = argsList.Front().Next().Next().Next().Value.(formulaArg).ToNumber(); pv.Type != ArgNumber { + return pv + } + } + if argsList.Len() == 5 { + if typ = argsList.Back().Value.(formulaArg).ToNumber(); typ.Type != ArgNumber { + return typ + } + } + if typ.Number != 0 && typ.Number != 1 { + return newErrorFormulaArg(formulaErrorNA, formulaErrorNA) + } + if rate.Number != 0 { + return newNumberFormulaArg(-pv.Number*math.Pow(1+rate.Number, nper.Number) - pmt.Number*(1+rate.Number*typ.Number)*(math.Pow(1+rate.Number, nper.Number)-1)/rate.Number) + } + return newNumberFormulaArg(-pv.Number - pmt.Number*nper.Number) +} + +// FVSCHEDULE function calculates the Future Value of an investment with a +// variable interest rate. The syntax of the function is: +// +// FVSCHEDULE(principal,schedule) +// +func (fn *formulaFuncs) FVSCHEDULE(argsList *list.List) formulaArg { + if argsList.Len() != 2 { + return newErrorFormulaArg(formulaErrorVALUE, "FVSCHEDULE requires 2 arguments") + } + pri := argsList.Front().Value.(formulaArg).ToNumber() + if pri.Type != ArgNumber { + return pri + } + principal := pri.Number + for _, arg := range argsList.Back().Value.(formulaArg).ToList() { + if arg.Value() == "" { + continue + } + rate := arg.ToNumber() + if rate.Type != ArgNumber { + return rate + } + principal *= (1 + rate.Number) + } + return newNumberFormulaArg(principal) +} + // IPMT function calculates the interest payment, during a specific period of a // loan or investment that is paid in constant periodic payments, with a // constant interest rate. The syntax of the function is: @@ -7556,6 +7633,109 @@ func (fn *formulaFuncs) NOMINAL(argsList *list.List) formulaArg { return newNumberFormulaArg(npery.Number * (math.Pow(rate.Number+1, 1/npery.Number) - 1)) } +// NPER function calculates the number of periods required to pay off a loan, +// for a constant periodic payment and a constant interest rate. The syntax +// of the function is: +// +// NPER(rate,pmt,pv,[fv],[type]) +// +func (fn *formulaFuncs) NPER(argsList *list.List) formulaArg { + if argsList.Len() < 3 { + return newErrorFormulaArg(formulaErrorVALUE, "NPER requires at least 3 arguments") + } + if argsList.Len() > 5 { + return newErrorFormulaArg(formulaErrorVALUE, "NPER allows at most 5 arguments") + } + rate := argsList.Front().Value.(formulaArg).ToNumber() + if rate.Type != ArgNumber { + return rate + } + pmt := argsList.Front().Next().Value.(formulaArg).ToNumber() + if pmt.Type != ArgNumber { + return pmt + } + pv := argsList.Front().Next().Next().Value.(formulaArg).ToNumber() + if pv.Type != ArgNumber { + return pv + } + fv, typ := newNumberFormulaArg(0), newNumberFormulaArg(0) + if argsList.Len() >= 4 { + if fv = argsList.Front().Next().Next().Next().Value.(formulaArg).ToNumber(); fv.Type != ArgNumber { + return fv + } + } + if argsList.Len() == 5 { + if typ = argsList.Back().Value.(formulaArg).ToNumber(); typ.Type != ArgNumber { + return typ + } + } + if typ.Number != 0 && typ.Number != 1 { + return newErrorFormulaArg(formulaErrorNA, formulaErrorNA) + } + if pmt.Number == 0 { + return newErrorFormulaArg(formulaErrorNUM, formulaErrorNUM) + } + if rate.Number != 0 { + p := math.Log((pmt.Number*(1+rate.Number*typ.Number)/rate.Number-fv.Number)/(pv.Number+pmt.Number*(1+rate.Number*typ.Number)/rate.Number)) / math.Log(1+rate.Number) + return newNumberFormulaArg(p) + } + return newNumberFormulaArg((-pv.Number - fv.Number) / pmt.Number) +} + +// NPV function calculates the Net Present Value of an investment, based on a +// supplied discount rate, and a series of future payments and income. The +// syntax of the function is: +// +// NPV(rate,value1,[value2],[value3],...) +// +func (fn *formulaFuncs) NPV(argsList *list.List) formulaArg { + if argsList.Len() < 2 { + return newErrorFormulaArg(formulaErrorVALUE, "NPV requires at least 2 arguments") + } + rate := argsList.Front().Value.(formulaArg).ToNumber() + if rate.Type != ArgNumber { + return rate + } + val, i := 0.0, 1 + for arg := argsList.Front().Next(); arg != nil; arg = arg.Next() { + num := arg.Value.(formulaArg).ToNumber() + if num.Type != ArgNumber { + continue + } + val += num.Number / math.Pow(1+rate.Number, float64(i)) + i++ + } + return newNumberFormulaArg(val) +} + +// PDURATION function calculates the number of periods required for an +// investment to reach a specified future value. The syntax of the function +// is: +// +// PDURATION(rate,pv,fv) +// +func (fn *formulaFuncs) PDURATION(argsList *list.List) formulaArg { + if argsList.Len() != 3 { + return newErrorFormulaArg(formulaErrorVALUE, "PDURATION requires 3 arguments") + } + rate := argsList.Front().Value.(formulaArg).ToNumber() + if rate.Type != ArgNumber { + return rate + } + pv := argsList.Front().Next().Value.(formulaArg).ToNumber() + if pv.Type != ArgNumber { + return pv + } + fv := argsList.Back().Value.(formulaArg).ToNumber() + if fv.Type != ArgNumber { + return fv + } + if rate.Number <= 0 || pv.Number <= 0 || fv.Number <= 0 { + return newErrorFormulaArg(formulaErrorNUM, formulaErrorNUM) + } + return newNumberFormulaArg((math.Log(fv.Number) - math.Log(pv.Number)) / math.Log(1+rate.Number)) +} + // PMT function calculates the constant periodic payment required to pay off // (or partially pay off) a loan or investment, with a constant interest // rate, over a specified period. The syntax of the function is: diff --git a/calc_test.go b/calc_test.go index 74cc627d..e80e8b94 100644 --- a/calc_test.go +++ b/calc_test.go @@ -1159,6 +1159,13 @@ func TestCalcCellValue(t *testing.T) { // EFFECT "=EFFECT(0.1,4)": "0.103812890625", "=EFFECT(0.025,2)": "0.02515625", + // FV + "=FV(0.05/12,60,-1000)": "68006.08284084337", + "=FV(0.1/4,16,-2000,0,1)": "39729.46089416617", + "=FV(0,16,-2000)": "32000", + // FVSCHEDULE + "=FVSCHEDULE(10000,A1:A5)": "240000", + "=FVSCHEDULE(10000,0.5)": "15000", // IPMT "=IPMT(0.05/12,2,60,50000)": "-205.26988187971995", "=IPMT(0.035/4,2,8,0,5000,1)": "5.257455237829077", @@ -1168,6 +1175,14 @@ func TestCalcCellValue(t *testing.T) { "=ISPMT(0.05/12,2,1,50000)": "208.33333333333334", // NOMINAL "=NOMINAL(0.025,12)": "0.024718035238113", + // NPER + "=NPER(0.04,-6000,50000)": "10.338035071507665", + "=NPER(0,-6000,50000)": "8.333333333333334", + "=NPER(0.06/4,-2000,60000,30000,1)": "52.794773709274764", + // NPV + "=NPV(0.02,-5000,\"\",800)": "-4133.025759323337", + // PDURATION + "=PDURATION(0.04,10000,15000)": "10.33803507150765", // PMT "=PMT(0,8,0,5000,1)": "-625", "=PMT(0.035/4,8,0,5000,1)": "-600.8520271804658", @@ -2120,6 +2135,19 @@ func TestCalcCellValue(t *testing.T) { "=EFFECT(0,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax", "=EFFECT(0,0)": "#NUM!", "=EFFECT(1,0)": "#NUM!", + // FV + "=FV()": "FV requires at least 3 arguments", + "=FV(0,0,0,0,0,0,0)": "FV allows at most 5 arguments", + "=FV(0,0,0,0,2)": "#N/A", + "=FV(\"\",0,0,0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=FV(0,\"\",0,0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=FV(0,0,\"\",0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=FV(0,0,0,\"\",0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=FV(0,0,0,0,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax", + // FVSCHEDULE + "=FVSCHEDULE()": "FVSCHEDULE requires 2 arguments", + "=FVSCHEDULE(\"\",0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=FVSCHEDULE(0,\"x\")": "strconv.ParseFloat: parsing \"x\": invalid syntax", // IPMT "=IPMT()": "IPMT requires at least 4 arguments", "=IPMT(0,0,0,0,0,0,0)": "IPMT allows at most 6 arguments", @@ -2144,6 +2172,25 @@ func TestCalcCellValue(t *testing.T) { "=NOMINAL(0,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax", "=NOMINAL(0,0)": "#NUM!", "=NOMINAL(1,0)": "#NUM!", + // NPER + "=NPER()": "NPER requires at least 3 arguments", + "=NPER(0,0,0,0,0,0)": "NPER allows at most 5 arguments", + "=NPER(0,0,0)": "#NUM!", + "=NPER(0,0,0,0,2)": "#N/A", + "=NPER(\"\",0,0,0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=NPER(0,\"\",0,0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=NPER(0,0,\"\",0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=NPER(0,0,0,\"\",0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=NPER(0,0,0,0,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax", + // NPV + "=NPV()": "NPV requires at least 2 arguments", + "=NPV(\"\",0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + // PDURATION + "=PDURATION()": "PDURATION requires 3 arguments", + "=PDURATION(\"\",0,0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=PDURATION(0,\"\",0)": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=PDURATION(0,0,\"\")": "strconv.ParseFloat: parsing \"\": invalid syntax", + "=PDURATION(0,0,0)": "#NUM!", // PMT "=PMT()": "PMT requires at least 3 arguments", "=PMT(0,0,0,0,0,0)": "PMT allows at most 5 arguments",