Skip to content

Commit

Permalink
Refinement for XIRR (#2487)
Browse files Browse the repository at this point in the history
* Refinement for XIRR

Fix #2469. The algorithm used for XIRR is known not to converge in some cases, some of which are because the value is legitimately unsolvable; for others, using a different guess might help.

The algorithm uses continual guesses at a rate to hopefully converge on the solution. The code in Python package xirr (https://github.com/tarioch/xirr/) suggests a refinement when this rate falls below -1. Adopting this refinement solves the problem for the data in issue 2469 without any adverse effect on the existing tests. My thanks to @tarioch for that refinement.

The data from 2469 is, of course, added to the test cases. The user also mentions that an initial guess equal to the actual result doesn't converge either. A test is also added to confirm that that case now works.

The test cases are changed to run in the context of a spreadsheet rather than by direct calls to XIRR calculation routine. This revealed some data validation errors which are also cleaned up with this PR. This suggests that other financial tests might benefit from the same change; I will look into that.

* More Unit Tests

From https://github.com/RayDeCampo/java-xirr/blob/master/src/test/java/org/decampo/xirr/XirrTest.java
https://github.com/tarioch/xirr/blob/master/tests/test_math.py

Note that there are some cases where the PHP tests do not converge, but the non-PHP tests do. I have confirmed in each of those cases that Excel does not converge, so the PhpSpreadsheet results are good, at least for now. The discrepancies are noted in comments in the test member.
  • Loading branch information
oleibman authored Jan 14, 2022
1 parent 1509097 commit 95d9cc9
Show file tree
Hide file tree
Showing 5 changed files with 310 additions and 39 deletions.
10 changes: 0 additions & 10 deletions phpstan-baseline.neon
Original file line number Diff line number Diff line change
Expand Up @@ -930,11 +930,6 @@ parameters:
count: 1
path: src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/InterestAndPrincipal.php

-
message: "#^Parameter \\#4 \\$x2 of static method PhpOffice\\\\PhpSpreadsheet\\\\Calculation\\\\Financial\\\\CashFlow\\\\Variable\\\\NonPeriodic\\:\\:xirrPart3\\(\\) expects float, mixed given\\.$#"
count: 1
path: src/PhpSpreadsheet/Calculation/Financial/CashFlow/Variable/NonPeriodic.php

-
message: "#^Method PhpOffice\\\\PhpSpreadsheet\\\\Calculation\\\\Financial\\\\CashFlow\\\\Variable\\\\Periodic\\:\\:presentValue\\(\\) has parameter \\$args with no type specified\\.$#"
count: 1
Expand Down Expand Up @@ -7915,11 +7910,6 @@ parameters:
count: 1
path: tests/PhpSpreadsheetTests/Calculation/Functions/Financial/XNpvTest.php

-
message: "#^Parameter \\#3 \\$message of static method PHPUnit\\\\Framework\\\\Assert\\:\\:assertEquals\\(\\) expects string, mixed given\\.$#"
count: 1
path: tests/PhpSpreadsheetTests/Calculation/Functions/Financial/XirrTest.php

-
message: "#^Part \\$number \\(mixed\\) of encapsed string cannot be cast to string\\.$#"
count: 1
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,8 @@ class NonPeriodic

const FINANCIAL_PRECISION = 1.0e-08;

const DEFAULT_GUESS = 0.1;

/**
* XIRR.
*
Expand All @@ -25,21 +27,25 @@ class NonPeriodic
* @param mixed[] $dates A series of payment dates
* The first payment date indicates the beginning of the schedule of payments
* All other dates must be later than this date, but they may occur in any order
* @param float $guess An optional guess at the expected answer
* @param mixed $guess An optional guess at the expected answer
*
* @return float|string
*/
public static function rate($values, $dates, $guess = 0.1)
public static function rate($values, $dates, $guess = self::DEFAULT_GUESS)
{
$rslt = self::xirrPart1($values, $dates);
if ($rslt !== '') {
return $rslt;
}

// create an initial range, with a root somewhere between 0 and guess
$guess = Functions::flattenSingleValue($guess);
$guess = Functions::flattenSingleValue($guess) ?? self::DEFAULT_GUESS;
if (!is_numeric($guess)) {
return Functions::VALUE();
}
$guess = ($guess + 0.0) ?: self::DEFAULT_GUESS;
$x1 = 0.0;
$x2 = $guess ?: 0.1;
$x2 = $guess + 0.0;
$f1 = self::xnpvOrdered($x1, $values, $dates, false);
$f2 = self::xnpvOrdered($x2, $values, $dates, false);
$found = false;
Expand All @@ -54,9 +60,11 @@ public static function rate($values, $dates, $guess = 0.1)

break;
} elseif (abs($f1) < abs($f2)) {
$f1 = self::xnpvOrdered($x1 += 1.6 * ($x1 - $x2), $values, $dates, false);
$x1 += 1.6 * ($x1 - $x2);
$f1 = self::xnpvOrdered($x1, $values, $dates, false);
} else {
$f2 = self::xnpvOrdered($x2 += 1.6 * ($x2 - $x1), $values, $dates, false);
$x2 += 1.6 * ($x2 - $x1);
$f2 = self::xnpvOrdered($x2, $values, $dates, false);
}
}
if (!$found) {
Expand Down Expand Up @@ -104,11 +112,13 @@ private static function bothNegAndPos(bool $neg, bool $pos): bool
*/
private static function xirrPart1(&$values, &$dates): string
{
if (!is_array($values) && !is_array($dates)) {
return Functions::NA();
}
$values = Functions::flattenArray($values);
$dates = Functions::flattenArray($dates);
$valuesIsArray = count($values) > 1;
$datesIsArray = count($dates) > 1;
if (!$valuesIsArray && !$datesIsArray) {
return Functions::NA();
}
if (count($values) != count($dates)) {
return Functions::NAN();
}
Expand Down Expand Up @@ -219,7 +229,11 @@ private static function xnpvOrdered($rate, $values, $dates, bool $ordered = true
if (!is_numeric($dif)) {
return $dif;
}
$xnpv += $values[$i] / (1 + $rate) ** ($dif / 365);
if ($rate <= -1.0) {
$xnpv += -abs($values[$i]) / (-1 - $rate) ** ($dif / 365);
} else {
$xnpv += $values[$i] / (1 + $rate) ** ($dif / 365);
}
}

return is_finite($xnpv) ? $xnpv : Functions::VALUE();
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,116 @@
<?php

namespace PhpOffice\PhpSpreadsheetTests\Calculation\Functions\Financial;

use PhpOffice\PhpSpreadsheet\Calculation\Exception as CalcException;
use PhpOffice\PhpSpreadsheet\Calculation\Functions;
use PhpOffice\PhpSpreadsheet\Cell\DataType;
use PhpOffice\PhpSpreadsheet\Spreadsheet;
use PhpOffice\PhpSpreadsheet\Worksheet\Worksheet;
use PHPUnit\Framework\TestCase;

class AllSetupTeardown extends TestCase
{
/**
* @var string
*/
private $compatibilityMode;

/**
* @var ?Spreadsheet
*/
private $spreadsheet;

/**
* @var ?Worksheet
*/
private $sheet;

protected function setUp(): void
{
$this->compatibilityMode = Functions::getCompatibilityMode();
}

protected function tearDown(): void
{
Functions::setCompatibilityMode($this->compatibilityMode);
$this->sheet = null;
if ($this->spreadsheet !== null) {
$this->spreadsheet->disconnectWorksheets();
$this->spreadsheet = null;
}
}

protected static function setOpenOffice(): void
{
Functions::setCompatibilityMode(Functions::COMPATIBILITY_OPENOFFICE);
}

protected static function setGnumeric(): void
{
Functions::setCompatibilityMode(Functions::COMPATIBILITY_GNUMERIC);
}

/**
* @param mixed $expectedResult
*/
protected function mightHaveException($expectedResult): void
{
if ($expectedResult === 'exception') {
$this->expectException(CalcException::class);
}
}

/**
* @param mixed $value
*/
protected function setCell(string $cell, $value): void
{
if ($value !== null) {
if (is_string($value) && is_numeric($value)) {
$this->getSheet()->getCell($cell)->setValueExplicit($value, DataType::TYPE_STRING);
} else {
$this->getSheet()->getCell($cell)->setValue($value);
}
}
}

protected function getSpreadsheet(): Spreadsheet
{
if ($this->spreadsheet !== null) {
return $this->spreadsheet;
}
$this->spreadsheet = new Spreadsheet();

return $this->spreadsheet;
}

protected function getSheet(): Worksheet
{
if ($this->sheet !== null) {
return $this->sheet;
}
$this->sheet = $this->getSpreadsheet()->getActiveSheet();

return $this->sheet;
}

/**
* Adjust result if it is close enough to expected by ratio
* rather than offset.
*
* @param mixed $result
* @param mixed $expectedResult
*/
protected function adjustResult(&$result, $expectedResult): void
{
if (is_numeric($result) && is_numeric($expectedResult)) {
if ($expectedResult != 0) {
$frac = $result / $expectedResult;
if ($frac > 0.999999 && $frac < 1.000001) {
$result = $expectedResult;
}
}
}
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -2,35 +2,60 @@

namespace PhpOffice\PhpSpreadsheetTests\Calculation\Functions\Financial;

use PhpOffice\PhpSpreadsheet\Calculation\Financial;
use PhpOffice\PhpSpreadsheet\Calculation\Functions;
use PHPUnit\Framework\TestCase;

class XirrTest extends TestCase
class XirrTest extends AllSetupTeardown
{
protected function setUp(): void
{
Functions::setCompatibilityMode(Functions::COMPATIBILITY_EXCEL);
}

/**
* @dataProvider providerXIRR
*
* @param mixed $expectedResult
* @param mixed $message
* @param string $message
* @param mixed $values
* @param mixed $dates
* @param mixed $guess
*/
public function testXIRR($expectedResult, $message, ...$args): void
public function testXIRR($expectedResult, $message, $values = null, $dates = null, $guess = null): void
{
$result = Financial::XIRR(...$args);
if (is_numeric($result) && is_numeric($expectedResult)) {
if ($expectedResult != 0) {
$frac = $result / $expectedResult;
if ($frac > 0.999999 && $frac < 1.000001) {
$result = $expectedResult;
$this->mightHaveException($expectedResult);
$sheet = $this->getSheet();
$formula = '=XIRR(';
if ($values !== null) {
if (is_array($values)) {
$row = 0;
foreach ($values as $value) {
++$row;
$sheet->getCell("A$row")->setValue($value);
}
$formula .= "A1:A$row";
} else {
$sheet->getCell('A1')->setValue($values);
$formula .= 'A1';
}
if ($dates !== null) {
if (is_array($dates)) {
$row = 0;
foreach ($dates as $date) {
++$row;
$sheet->getCell("B$row")->setValue($date);
}
$formula .= ",B1:B$row";
} else {
$sheet->getCell('B1')->setValue($dates);
$formula .= ',B1';
}
if ($guess !== null) {
if ($guess !== 'C1') {
$sheet->getCell('C1')->setValue($guess);
}
$formula .= ', C1';
}
}
}
self::assertEquals($expectedResult, $result, $message);
$formula .= ')';
$sheet->getCell('D1')->setValue($formula);
$result = $sheet->getCell('D1')->getCalculatedValue();
$this->adjustResult($result, $expectedResult);

self::assertEqualsWithDelta($expectedResult, $result, 0.1E-7, $message);
}

public function providerXIRR(): array
Expand Down
Loading

0 comments on commit 95d9cc9

Please sign in to comment.