ref #65: new formula function XIRR

This commit is contained in:
xuri 2021-11-21 15:49:29 +08:00
parent 9b0aa7ac30
commit a6c8803e91
No known key found for this signature in database
GPG Key ID: BA5E5BB1C948EDF7
2 changed files with 126 additions and 0 deletions

88
calc.go
View File

@ -596,6 +596,7 @@ type formulaFuncs struct {
// WEEKDAY
// WEIBULL
// WEIBULL.DIST
// XIRR
// XNPV
// XOR
// YEAR
@ -11182,6 +11183,93 @@ func (fn *formulaFuncs) prepareXArgs(name string, values, dates formulaArg) (val
return
}
// xirr is an implementation of the formula function XIRR.
func (fn *formulaFuncs) xirr(values, dates []float64, guess float64) formulaArg {
positive, negative := false, false
for i := 0; i < len(values); i++ {
if values[i] > 0 {
positive = true
}
if values[i] < 0 {
negative = true
}
}
if !positive || !negative {
return newErrorFormulaArg(formulaErrorNUM, formulaErrorNUM)
}
result, epsMax, count, maxIterate, err := guess, 1e-10, 0, 50, false
for {
resultValue := xirrPart1(values, dates, result)
newRate := result - resultValue/xirrPart2(values, dates, result)
epsRate := math.Abs(newRate - result)
result = newRate
count++
if epsRate <= epsMax || math.Abs(resultValue) <= epsMax {
break
}
if count > maxIterate {
err = true
break
}
}
if err || math.IsNaN(result) || math.IsInf(result, 0) {
return newErrorFormulaArg(formulaErrorNUM, formulaErrorNUM)
}
return newNumberFormulaArg(result)
}
// xirrPart1 is a part of implementation of the formula function XIRR.
func xirrPart1(values, dates []float64, rate float64) float64 {
r := rate + 1
result := values[0]
vlen := len(values)
firstDate := dates[0]
for i := 1; i < vlen; i++ {
result += values[i] / math.Pow(r, (dates[i]-firstDate)/365)
}
return result
}
// xirrPart2 is a part of implementation of the formula function XIRR.
func xirrPart2(values, dates []float64, rate float64) float64 {
r := rate + 1
result := 0.0
vlen := len(values)
firstDate := dates[0]
for i := 1; i < vlen; i++ {
frac := (dates[i] - firstDate) / 365
result -= frac * values[i] / math.Pow(r, frac+1)
}
return result
}
// XIRR function returns the Internal Rate of Return for a supplied series of
// cash flows (i.e. a set of values, which includes an initial investment
// value and a series of net income values) occurring at a series of supplied
// dates. The syntax of the function is:
//
// XIRR(values,dates,[guess])
//
func (fn *formulaFuncs) XIRR(argsList *list.List) formulaArg {
if argsList.Len() != 2 && argsList.Len() != 3 {
return newErrorFormulaArg(formulaErrorVALUE, "XIRR requires 2 or 3 arguments")
}
values, dates, err := fn.prepareXArgs("XIRR", argsList.Front().Value.(formulaArg), argsList.Front().Next().Value.(formulaArg))
if err.Type != ArgEmpty {
return err
}
guess := newNumberFormulaArg(0)
if argsList.Len() == 3 {
if guess = argsList.Back().Value.(formulaArg).ToNumber(); guess.Type != ArgNumber {
return newErrorFormulaArg(formulaErrorNUM, formulaErrorNUM)
}
if guess.Number <= -1 {
return newErrorFormulaArg(formulaErrorVALUE, "XIRR requires guess > -1")
}
}
return fn.xirr(values, dates, guess.Number)
}
// XNPV function calculates the Net Present Value for a schedule of cash flows
// that is not necessarily periodic. The syntax of the function is:
//

View File

@ -3456,6 +3456,44 @@ func TestCalcMIRR(t *testing.T) {
}
}
func TestCalcXIRR(t *testing.T) {
cellData := [][]interface{}{
{-100.00, "01/01/2016"},
{20.00, "04/01/2016"},
{40.00, "10/01/2016"},
{25.00, "02/01/2017"},
{8.00, "03/01/2017"},
{15.00, "06/01/2017"},
{-1e-10, "09/01/2017"}}
f := prepareCalcData(cellData)
formulaList := map[string]string{
"=XIRR(A1:A4,B1:B4)": "-0.196743861298328",
"=XIRR(A1:A6,B1:B6)": "0.09443907444452",
"=XIRR(A1:A6,B1:B6,0.1)": "0.0944390744445201",
}
for formula, expected := range formulaList {
assert.NoError(t, f.SetCellFormula("Sheet1", "C1", formula))
result, err := f.CalcCellValue("Sheet1", "C1")
assert.NoError(t, err, formula)
assert.Equal(t, expected, result, formula)
}
calcError := map[string]string{
"=XIRR()": "XIRR requires 2 or 3 arguments",
"=XIRR(A1:A4,B1:B4,-1)": "XIRR requires guess > -1",
"=XIRR(\"\",B1:B4)": "#NUM!",
"=XIRR(A1:A4,\"\")": "#NUM!",
"=XIRR(A1:A4,B1:B4,\"\")": "#NUM!",
"=XIRR(A2:A6,B2:B6)": "#NUM!",
"=XIRR(A2:A7,B2:B7)": "#NUM!",
}
for formula, expected := range calcError {
assert.NoError(t, f.SetCellFormula("Sheet1", "C1", formula))
result, err := f.CalcCellValue("Sheet1", "C1")
assert.EqualError(t, err, expected, formula)
assert.Equal(t, "", result, formula)
}
}
func TestCalcXNPV(t *testing.T) {
cellData := [][]interface{}{{nil, 0.05},
{"01/01/2016", -10000, nil},