Fix RATE, PRICE, XIRR, and XNPV Functions (#1456)

There were about 20 skipped tests for RATE and PRICE marked
"This test should be fixed". This change does that by fixing
the code for those functions, validating the existing tests,
and adding new ones. XIRR and XNPV are also substantially changed.
As part of this change, the following functions also have minor changes:

  - isValidFrequency
  - COUPDAYBS
  - COUPNUM (additional tests)
  - DB
  - DDB

PhpUnit reports 100% coverage for all the changed functions.

Since I was dealing with skipped tests, I also fixed
tests/PhpSpreadsheetTests/Writer/Xlsx/LocaleFloatsTest,
which was being skipped in Windows. I also delete the temporary
file which it creates.
There is now only one remaining test which is skipped -
ODS Reader is not complete enough to run some tests against it.
Unfortunately, that test is too complicated for me to deal with now.

In researching this change, I found several places in the code where special code was added for Gnumeric claiming:

   - Gnumeric does not handle free-format string dates
   - Gnumeric adds extra options, not available in Excel,
     for the frequency parameter for functions such as YIELD
   - Gnumeric rounds the results for DB and DDB to 2 decimal places

None of these claims is true, at least not on a recent version
of Gnumeric, and the code which supports these differences is removed.
There did not appear to be any tests targeted for
these supposed properties of Gnumeric.

The PRICE function needed relatively minor changes - mostly
additional tests for invalid input. The main problem with the PRICE
tests is that Excel appears to have a bug. The algorithm is published:
https://support.office.com/en-us/article/price-function-3ea9deac-8dfa-436f-a7c8-17ea02c21b0a
The results that Excel returns for basis codes 2 and 3 appear to be
incorrect in many cases. I have segregated these tests into a
new test PRICE3. The results of these tests agree with the published
algorithm, and to the results for LibreOffice and Gnumeric.
The results returned by Excel do not agree with them.
The tests which remain in the test PRICE all use basis codes other
than 2 or 3, and all agree with Excel, LibreOffice, and Gnumeric.

For the RATE function, there appears to be a problem with how the
secant method was implemented. I studied the implementation of RATE
in Python numpy, and adapted its implementation of secant method.
The results now agree with numpy, and, more important, with Excel.

XIRR, which calls XNPV, permits its dates to be earlier than the
start date, whereas XNPV does not. I dealt with this by renaming
the existing XNPV function to xnpvOrdered, adding a parameter to
indicate whether start date has to be earliest. XNPV calls the new
function with that parameter set to TRUE, and XIRR calls it with
the parameter set to FALSE. Some additional error checking was
added to xnpvOrdered, and also to XIRR. XIRR tests benefited
from increasing the value of FINANCIAL_MAX_ITERATIONS.

Finally, since this change is very test-related:
samples/Basic/13_CalculationCyclicFormulae
PhpUnit started reporting an error like "too much regression".
The test deals with an infinite cyclic formula, and allowed
the calculation engine to run for 100 cycles. The actual number of cycles
seems irrelevant for the purpose of this test. I changed it to 15,
and PhpUnit no longer complains.
This commit is contained in:
oleibman 2020-05-17 03:50:01 -07:00 committed by GitHub
parent 8eaceb0f92
commit 9ae521cdd4
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
10 changed files with 739 additions and 218 deletions

View File

@ -59,17 +59,13 @@ class DateTime
/**
* getDateValue.
*
* @param string $dateValue
* @param mixed $dateValue
*
* @return mixed Excel date/time serial value, or string if error
*/
public static function getDateValue($dateValue)
{
if (!is_numeric($dateValue)) {
if ((is_string($dateValue)) &&
(Functions::getCompatibilityMode() == Functions::COMPATIBILITY_GNUMERIC)) {
return Functions::VALUE();
}
if ((is_object($dateValue)) && ($dateValue instanceof \DateTimeInterface)) {
$dateValue = Date::PHPToExcel($dateValue);
} else {

View File

@ -6,7 +6,7 @@ use PhpOffice\PhpSpreadsheet\Shared\Date;
class Financial
{
const FINANCIAL_MAX_ITERATIONS = 32;
const FINANCIAL_MAX_ITERATIONS = 128;
const FINANCIAL_PRECISION = 1.0e-08;
@ -50,10 +50,6 @@ class Financial
if (($frequency == 1) || ($frequency == 2) || ($frequency == 4)) {
return true;
}
if ((Functions::getCompatibilityMode() == Functions::COMPATIBILITY_GNUMERIC) &&
(($frequency == 6) || ($frequency == 12))) {
return true;
}
return false;
}
@ -133,10 +129,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -390,10 +382,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -426,6 +414,10 @@ class Financial
$daysPerYear = self::daysPerYear(DateTime::YEAR($settlement), $basis);
$prev = self::couponFirstPeriodDate($settlement, $maturity, $frequency, false);
if ($basis == 1) {
return abs(DateTime::DAYS($prev, $settlement));
}
return DateTime::YEARFRAC($prev, $settlement, $basis) * $daysPerYear;
}
@ -449,10 +441,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -523,10 +511,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -582,10 +566,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -640,10 +620,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -673,19 +649,9 @@ class Financial
return Functions::NAN();
}
$daysPerYear = self::daysPerYear(DateTime::YEAR($settlement), $basis);
$daysBetweenSettlementAndMaturity = DateTime::YEARFRAC($settlement, $maturity, $basis) * $daysPerYear;
$yearsBetweenSettlementAndMaturity = DateTime::YEARFRAC($settlement, $maturity, 0);
switch ($frequency) {
case 1: // annual payments
case 2: // half-yearly
case 4: // quarterly
case 6: // bimonthly
case 12: // monthly
return ceil($daysBetweenSettlementAndMaturity / $daysPerYear * $frequency);
}
return Functions::VALUE();
return ceil($yearsBetweenSettlementAndMaturity * $frequency);
}
/**
@ -708,10 +674,6 @@ class Financial
* 1 Annual
* 2 Semi-Annual
* 4 Quarterly
* If working in Gnumeric Mode, the following frequency options are
* also available
* 6 Bimonthly
* 12 Monthly
* @param int $basis The type of day count to use.
* 0 or omitted US (NASD) 30/360
* 1 Actual/actual
@ -894,6 +856,7 @@ class Financial
// Loop through each period calculating the depreciation
$previousDepreciation = 0;
$depreciation = 0;
for ($per = 1; $per <= $period; ++$per) {
if ($per == 1) {
$depreciation = $cost * $fixedDepreciationRate * $month / 12;
@ -904,9 +867,6 @@ class Financial
}
$previousDepreciation += $depreciation;
}
if (Functions::getCompatibilityMode() == Functions::COMPATIBILITY_GNUMERIC) {
$depreciation = round($depreciation, 2);
}
return $depreciation;
}
@ -962,13 +922,11 @@ class Financial
// Loop through each period calculating the depreciation
$previousDepreciation = 0;
$depreciation = 0;
for ($per = 1; $per <= $period; ++$per) {
$depreciation = min(($cost - $previousDepreciation) * ($factor / $life), ($cost - $salvage - $previousDepreciation));
$previousDepreciation += $depreciation;
}
if (Functions::getCompatibilityMode() == Functions::COMPATIBILITY_GNUMERIC) {
$depreciation = round($depreciation, 2);
}
return $depreciation;
}
@ -1650,22 +1608,54 @@ class Financial
return $interestAndPrincipal[1];
}
private static function validatePrice($settlement, $maturity, $rate, $yield, $redemption, $frequency, $basis)
{
if (is_string($settlement)) {
return Functions::VALUE();
}
if (is_string($maturity)) {
return Functions::VALUE();
}
if (!is_numeric($rate)) {
return Functions::VALUE();
}
if (!is_numeric($yield)) {
return Functions::VALUE();
}
if (!is_numeric($redemption)) {
return Functions::VALUE();
}
if (!is_numeric($frequency)) {
return Functions::VALUE();
}
if (!is_numeric($basis)) {
return Functions::VALUE();
}
return '';
}
public static function PRICE($settlement, $maturity, $rate, $yield, $redemption, $frequency, $basis = 0)
{
$settlement = Functions::flattenSingleValue($settlement);
$maturity = Functions::flattenSingleValue($maturity);
$rate = (float) Functions::flattenSingleValue($rate);
$yield = (float) Functions::flattenSingleValue($yield);
$redemption = (float) Functions::flattenSingleValue($redemption);
$frequency = (int) Functions::flattenSingleValue($frequency);
$basis = ($basis === null) ? 0 : (int) Functions::flattenSingleValue($basis);
$rate = Functions::flattenSingleValue($rate);
$yield = Functions::flattenSingleValue($yield);
$redemption = Functions::flattenSingleValue($redemption);
$frequency = Functions::flattenSingleValue($frequency);
$basis = Functions::flattenSingleValue($basis);
if (is_string($settlement = DateTime::getDateValue($settlement))) {
return Functions::VALUE();
}
if (is_string($maturity = DateTime::getDateValue($maturity))) {
return Functions::VALUE();
$settlement = DateTime::getDateValue($settlement);
$maturity = DateTime::getDateValue($maturity);
$rslt = self::validatePrice($settlement, $maturity, $rate, $yield, $redemption, $frequency, $basis);
if ($rslt) {
return $rslt;
}
$rate = (float) $rate;
$yield = (float) $yield;
$redemption = (float) $redemption;
$frequency = (int) $frequency;
$basis = (int) $basis;
if (($settlement > $maturity) ||
(!self::isValidFrequency($frequency)) ||
@ -1865,7 +1855,7 @@ class Financial
* @param float $guess Your guess for what the rate will be.
* If you omit guess, it is assumed to be 10 percent.
*
* @return float
* @return float|string
*/
public static function RATE($nper, $pmt, $pv, $fv = 0.0, $type = 0, $guess = 0.1)
{
@ -1877,38 +1867,39 @@ class Financial
$guess = ($guess === null) ? 0.1 : Functions::flattenSingleValue($guess);
$rate = $guess;
if (abs($rate) < self::FINANCIAL_PRECISION) {
$y = $pv * (1 + $nper * $rate) + $pmt * (1 + $rate * $type) * $nper + $fv;
} else {
$f = exp($nper * log(1 + $rate));
$y = $pv * $f + $pmt * (1 / $rate + $type) * ($f - 1) + $fv;
// rest of code adapted from python/numpy
$close = false;
$iter = 0;
while (!$close && $iter < self::FINANCIAL_MAX_ITERATIONS) {
$nextdiff = self::rateNextGuess($rate, $nper, $pmt, $pv, $fv, $type);
if (!is_numeric($nextdiff)) {
break;
}
$y0 = $pv + $pmt * $nper + $fv;
$y1 = $pv * $f + $pmt * (1 / $rate + $type) * ($f - 1) + $fv;
// find root by secant method
$i = $x0 = 0.0;
$x1 = $rate;
while ((abs($y0 - $y1) > self::FINANCIAL_PRECISION) && ($i < self::FINANCIAL_MAX_ITERATIONS)) {
$rate = ($y1 * $x0 - $y0 * $x1) / ($y1 - $y0);
$x0 = $x1;
$x1 = $rate;
if (($nper * abs($pmt)) > ($pv - $fv)) {
$x1 = abs($x1);
}
if (abs($rate) < self::FINANCIAL_PRECISION) {
$y = $pv * (1 + $nper * $rate) + $pmt * (1 + $rate * $type) * $nper + $fv;
} else {
$f = exp($nper * log(1 + $rate));
$y = $pv * $f + $pmt * (1 / $rate + $type) * ($f - 1) + $fv;
$rate1 = $rate - $nextdiff;
$close = abs($rate1 - $rate) < self::FINANCIAL_PRECISION;
++$iter;
$rate = $rate1;
}
$y0 = $y1;
$y1 = $y;
++$i;
return $close ? $rate : Functions::NAN();
}
return $rate;
private static function rateNextGuess($rate, $nper, $pmt, $pv, $fv, $type)
{
if ($rate == 0) {
return Functions::NAN();
}
$tt1 = pow($rate + 1, $nper);
$tt2 = pow($rate + 1, $nper - 1);
$numerator = $fv + $tt1 * $pv + $pmt * ($tt1 - 1) * ($rate * $type + 1) / $rate;
$denominator = $nper * $tt2 * $pv - $pmt * ($tt1 - 1) * ($rate * $type + 1) / ($rate * $rate)
+ $nper * $pmt * $tt2 * ($rate * $type + 1) / $rate
+ $pmt * ($tt1 - 1) * $type / $rate;
if ($denominator == 0) {
return Functions::NAN();
}
return $numerator / $denominator;
}
/**
@ -2183,6 +2174,84 @@ class Financial
return Functions::VALUE();
}
private static function bothNegAndPos($neg, $pos)
{
return $neg && $pos;
}
private static function xirrPart2(&$values)
{
$valCount = count($values);
$foundpos = false;
$foundneg = false;
for ($i = 0; $i < $valCount; ++$i) {
$fld = $values[$i];
if (!is_numeric($fld)) {
return Functions::VALUE();
} elseif ($fld > 0) {
$foundpos = true;
} elseif ($fld < 0) {
$foundneg = true;
}
}
if (!self::bothNegAndPos($foundneg, $foundpos)) {
return Functions::NAN();
}
return '';
}
private static function xirrPart1(&$values, &$dates)
{
if ((!is_array($values)) && (!is_array($dates))) {
return Functions::NA();
}
$values = Functions::flattenArray($values);
$dates = Functions::flattenArray($dates);
if (count($values) != count($dates)) {
return Functions::NAN();
}
$datesCount = count($dates);
for ($i = 0; $i < $datesCount; ++$i) {
$dates[$i] = DateTime::getDateValue($dates[$i]);
if (!is_numeric($dates[$i])) {
return Functions::VALUE();
}
}
return self::xirrPart2($values);
}
private static function xirrPart3($values, $dates, $x1, $x2)
{
$f = self::xnpvOrdered($x1, $values, $dates, false);
if ($f < 0.0) {
$rtb = $x1;
$dx = $x2 - $x1;
} else {
$rtb = $x2;
$dx = $x1 - $x2;
}
$rslt = Functions::VALUE();
for ($i = 0; $i < self::FINANCIAL_MAX_ITERATIONS; ++$i) {
$dx *= 0.5;
$x_mid = $rtb + $dx;
$f_mid = self::xnpvOrdered($x_mid, $values, $dates, false);
if ($f_mid <= 0.0) {
$rtb = $x_mid;
}
if ((abs($f_mid) < self::FINANCIAL_PRECISION) || (abs($dx) < self::FINANCIAL_PRECISION)) {
$rslt = $x_mid;
break;
}
}
return $rslt;
}
/**
* XIRR.
*
@ -2202,73 +2271,37 @@ class Financial
*/
public static function XIRR($values, $dates, $guess = 0.1)
{
if ((!is_array($values)) && (!is_array($dates))) {
return Functions::VALUE();
}
$values = Functions::flattenArray($values);
$dates = Functions::flattenArray($dates);
$guess = Functions::flattenSingleValue($guess);
if (count($values) != count($dates)) {
return Functions::NAN();
}
$datesCount = count($dates);
for ($i = 0; $i < $datesCount; ++$i) {
$dates[$i] = DateTime::getDateValue($dates[$i]);
if (!is_numeric($dates[$i])) {
return Functions::VALUE();
}
}
if (min($dates) != $dates[0]) {
return Functions::NAN();
$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);
$x1 = 0.0;
$x2 = $guess;
$f1 = self::XNPV($x1, $values, $dates);
if (!is_numeric($f1)) {
return $f1;
}
$f2 = self::XNPV($x2, $values, $dates);
if (!is_numeric($f2)) {
return $f2;
}
$x2 = $guess ? $guess : 0.1;
$f1 = self::xnpvOrdered($x1, $values, $dates, false);
$f2 = self::xnpvOrdered($x2, $values, $dates, false);
$found = false;
for ($i = 0; $i < self::FINANCIAL_MAX_ITERATIONS; ++$i) {
if (!is_numeric($f1) || !is_numeric($f2)) {
break;
}
if (($f1 * $f2) < 0.0) {
$found = true;
break;
} elseif (abs($f1) < abs($f2)) {
$f1 = self::XNPV($x1 += 1.6 * ($x1 - $x2), $values, $dates);
$f1 = self::xnpvOrdered($x1 += 1.6 * ($x1 - $x2), $values, $dates, false);
} else {
$f2 = self::XNPV($x2 += 1.6 * ($x2 - $x1), $values, $dates);
$f2 = self::xnpvOrdered($x2 += 1.6 * ($x2 - $x1), $values, $dates, false);
}
}
if (($f1 * $f2) > 0.0) {
if (!$found) {
return Functions::NAN();
}
$f = self::XNPV($x1, $values, $dates);
if ($f < 0.0) {
$rtb = $x1;
$dx = $x2 - $x1;
} else {
$rtb = $x2;
$dx = $x1 - $x2;
}
for ($i = 0; $i < self::FINANCIAL_MAX_ITERATIONS; ++$i) {
$dx *= 0.5;
$x_mid = $rtb + $dx;
$f_mid = self::XNPV($x_mid, $values, $dates);
if ($f_mid <= 0.0) {
$rtb = $x_mid;
}
if ((abs($f_mid) < self::FINANCIAL_PRECISION) || (abs($dx) < self::FINANCIAL_PRECISION)) {
return $x_mid;
}
}
return Functions::VALUE();
return self::xirrPart3($values, $dates, $x1, $x2);
}
/**
@ -2293,32 +2326,61 @@ class Financial
*/
public static function XNPV($rate, $values, $dates)
{
$rate = Functions::flattenSingleValue($rate);
return self::xnpvOrdered($rate, $values, $dates, true);
}
private static function validateXnpv($rate, $values, $dates)
{
if (!is_numeric($rate)) {
return Functions::VALUE();
}
if ((!is_array($values)) || (!is_array($dates))) {
return Functions::VALUE();
}
$values = Functions::flattenArray($values);
$dates = Functions::flattenArray($dates);
$valCount = count($values);
if ($valCount != count($dates)) {
return Functions::NAN();
}
if ((min($values) > 0) || (max($values) < 0)) {
if ($valCount > 1 && ((min($values) > 0) || (max($values) < 0))) {
return Functions::NAN();
}
$date0 = DateTime::getDateValue($dates[0]);
if (is_string($date0)) {
return Functions::VALUE();
}
return '';
}
private static function xnpvOrdered($rate, $values, $dates, $ordered = true)
{
$rate = Functions::flattenSingleValue($rate);
$values = Functions::flattenArray($values);
$dates = Functions::flattenArray($dates);
$valCount = count($values);
$date0 = DateTime::getDateValue($dates[0]);
$rslt = self::validateXnpv($rate, $values, $dates);
if ($rslt) {
return $rslt;
}
$xnpv = 0.0;
for ($i = 0; $i < $valCount; ++$i) {
if (!is_numeric($values[$i])) {
return Functions::VALUE();
}
$xnpv += $values[$i] / pow(1 + $rate, DateTime::DATEDIF($dates[0], $dates[$i], 'd') / 365);
$datei = DateTime::getDateValue($dates[$i]);
if (is_string($datei)) {
return Functions::VALUE();
}
if ($date0 > $datei) {
$dif = $ordered ? Functions::NAN() : -DateTime::DATEDIF($datei, $date0, 'd');
} else {
$dif = DateTime::DATEDIF($date0, $datei, 'd');
}
if (!is_numeric($dif)) {
return $dif;
}
$xnpv += $values[$i] / pow(1 + $rate, $dif / 365);
}
return (is_finite($xnpv)) ? $xnpv : Functions::VALUE();
return is_finite($xnpv) ? $xnpv : Functions::VALUE();
}
/**

View File

@ -436,10 +436,8 @@ class FinancialTest extends TestCase
*/
public function testPRICE($expectedResult, ...$args)
{
$this->markTestIncomplete('TODO: This test should be fixed');
$result = Financial::PRICE(...$args);
self::assertEqualsWithDelta($expectedResult, $result, 1E-8);
self::assertEqualsWithDelta($expectedResult, $result, 1E-7);
}
public function providerPRICE()
@ -447,6 +445,25 @@ class FinancialTest extends TestCase
return require 'tests/data/Calculation/Financial/PRICE.php';
}
/**
* @dataProvider providerPRICE3
*
* @param mixed $expectedResult
*/
public function testPRICE3($expectedResult, ...$args)
{
// These results (PRICE function with basis codes 2 and 3)
// agree with published algorithm, LibreOffice, and Gnumeric.
// They do not agree with Excel.
$result = Financial::PRICE(...$args);
self::assertEqualsWithDelta($expectedResult, $result, 1E-7);
}
public function providerPRICE3()
{
return require 'data/Calculation/Financial/PRICE3.php';
}
/**
* @dataProvider providerPRICEDISC
*
@ -486,8 +503,6 @@ class FinancialTest extends TestCase
*/
public function testRATE($expectedResult, ...$args)
{
$this->markTestIncomplete('TODO: This test should be fixed');
$result = Financial::RATE(...$args);
self::assertEqualsWithDelta($expectedResult, $result, 1E-8);
}
@ -506,7 +521,15 @@ class FinancialTest extends TestCase
public function testXIRR($expectedResult, $message, ...$args)
{
$result = Financial::XIRR(...$args);
self::assertEqualsWithDelta($expectedResult, $result, Financial::FINANCIAL_PRECISION, $message);
if (is_numeric($result) && is_numeric($expectedResult)) {
if ($expectedResult != 0) {
$frac = $result / $expectedResult;
if ($frac > 0.999999 && $frac < 1.000001) {
$result = $expectedResult;
}
}
}
self::assertEquals($expectedResult, $result, $message);
}
public function providerXIRR()
@ -514,6 +537,31 @@ class FinancialTest extends TestCase
return require 'tests/data/Calculation/Financial/XIRR.php';
}
/**
* @dataProvider providerXNPV
*
* @param mixed $expectedResult
* @param mixed $message
*/
public function testXNPV($expectedResult, $message, ...$args)
{
$result = Financial::XNPV(...$args);
if (is_numeric($result) && is_numeric($expectedResult)) {
if ($expectedResult != 0) {
$frac = $result / $expectedResult;
if ($frac > 0.999999 && $frac < 1.000001) {
$result = $expectedResult;
}
}
}
self::assertEquals($expectedResult, $result, $message);
}
public function providerXNPV()
{
return require 'data/Calculation/Financial/XNPV.php';
}
/**
* @dataProvider providerPDURATION
*

View File

@ -14,7 +14,7 @@ class LocaleFloatsTest extends TestCase
{
$this->currentLocale = setlocale(LC_ALL, '0');
if (!setlocale(LC_ALL, 'fr_FR.UTF-8')) {
if (!setlocale(LC_ALL, 'fr_FR.UTF-8', 'fra_fra')) {
$this->localeAdjusted = false;
return;
@ -45,6 +45,7 @@ class LocaleFloatsTest extends TestCase
$reader = new \PhpOffice\PhpSpreadsheet\Reader\Xlsx();
$spreadsheet = $reader->load($filename);
unlink($filename);
$result = $spreadsheet->getActiveSheet()->getCell('A1')->getValue();

View File

@ -73,4 +73,39 @@ return [
4,
0,
],
[
16,
'1-Apr-2012',
'31-Mar-2020',
2,
0,
],
[
16,
'1-Apr-2012',
'31-Mar-2020',
2,
1,
],
[
16,
'1-Apr-2012',
'31-Mar-2020',
2,
2,
],
[
16,
'1-Apr-2012',
'31-Mar-2020',
2,
3,
],
[
16,
'1-Apr-2012',
'31-Mar-2020',
2,
4,
],
];

View File

@ -1,14 +1,144 @@
<?php
// Settlement, Maturity, Rate, Yield, Redemption, Frequency, Basis, Result
// Result, Settlement, Maturity, Rate, Yield, Redemption, Frequency, Basis
return [
[
'#VALUE!',
'xyz',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
0,
],
[
'#VALUE!',
'15-Feb-2008',
'xyz',
0.0575,
0.065,
100,
2,
0,
],
[
'#VALUE!',
'15-Feb-2008',
'15-Nov-2017',
'xyz',
0.065,
100,
2,
0,
],
[
'#VALUE!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
'xyz',
100,
2,
0,
],
[
'#VALUE!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
'xyz',
2,
0,
],
[
'#VALUE!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
'xyz',
0,
],
[
'#VALUE!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
'xyz',
],
[
'#NUM!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
-1, // invalid basis
],
[
'#NUM!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
5, // invalid basis
],
[
'#NUM!',
'15-Nov-2017', // maturity before settlement
'15-Feb-2008',
0.0575,
0.065,
100,
2,
0,
],
[
'#NUM!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
5, // invalid frequency
0,
],
[
'#NUM!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
6, // had been coded as valid for gnumeric, but it isn't
0,
],
[
'#NUM!',
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
12, // had been coded as valid for gnumeric, but it isn't
0,
],
[
94.6343616213221,
'15-Feb-2008',
'15-Nov-2017',
0.057500000000000002,
0.065000000000000002,
0.0575,
0.065,
100,
2,
0,
@ -17,80 +147,69 @@ return [
94.635449207877201,
'15-Feb-2008',
'15-Nov-2017',
0.057500000000000002,
0.065000000000000002,
0.0575,
0.065,
100,
2,
1,
],
[
94.636564030025099,
94.67215001,
'15-Feb-2008',
'15-Nov-2017',
0.057500000000000002,
0.065000000000000002,
0.0575,
0.065,
100,
2,
2,
],
[
94.635174796784497,
'15-Feb-2008',
'15-Nov-2017',
0.057500000000000002,
0.065000000000000002,
100,
2,
3,
1,
0,
],
[
110.83448359321601,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10000000000000001,
0.10,
100,
2,
null,
],
[
110.834537395859,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10000000000000001,
0.10,
100,
2,
1,
],
[
110.83448359321601,
110.9216934,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10000000000000001,
100,
2,
2,
],
[
110.83452855143901,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10000000000000001,
100,
2,
3,
],
[
110.921732963198,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10000000000000001,
0.10,
100,
4,
3,
0,
],
[
110.9217251,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
4,
1,
],
[
110.9216934,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
4,
4,
],
];

View File

@ -0,0 +1,78 @@
<?php
// Result, Settlement, Maturity, Rate, Yield, Redemption, Frequency, Basis
// On the result line, the value is ODS's calculation.
// This agrees with Gnumeric, PhpSpreadsheet, and the published algorithm at:
//https://support.office.com/en-us/article/price-function-3ea9deac-8dfa-436f-a7c8-17ea02c21b0a.
// The commented-out value on the next line is Excel's result.
// I do not know how best to reconcile the different results.
// The problem seems restricted to basis codes 2 and 3.
return [
[
94.60241717687768,
// 94.636564030025099,
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
2,
],
[
94.643594548258,
// 94.635174796784497,
'15-Feb-2008',
'15-Nov-2017',
0.0575,
0.065,
100,
2,
3,
],
[
110.74436592216529,
// 110.83448359321601,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
2,
2,
],
[
110.81970970927745,
// 110.83452855143901,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
2,
3,
],
[
110.8912556,
// 110.9216934,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
4,
2,
],
[
110.9292394066714,
// 110.921732963198,
'01-Apr-2012',
'31-Mar-2020',
0.12,
0.10,
100,
4,
3,
],
];

View File

@ -69,4 +69,38 @@ return [
126068,
0,
],
[
'#NUM!',
0,
1,
8000,
],
[
'#NUM!',
208,
-700,
8000,
0,
0,
0,
],
[
-1.000125, // Excel says #NUM!, but I believe this is correct
1,
1,
8000,
],
[
6.9258100553578E-10,
208,
-700,
137600,
8000,
],
[
0.00054607632544395,
208,
-700,
137600,
],
];

View File

@ -7,37 +7,72 @@ return [
'#NUM!',
'If values and dates contain a different number of values, returns the #NUM! error value',
[4000, -46000],
['01/04/2015'],
['2015-01-04'],
0.1
],
[
'#NUM!',
'Expects at least one positive cash flow and one negative cash flow; otherwise returns the #NUM! error value',
[-4000, -46000],
['01/04/2015', '2019-06-27'],
['2015-01-04', '2019-06-27'],
0.1
],
[
'#NUM!',
'Expects at least one positive cash flow and one negative cash flow; otherwise returns the #NUM! error value',
[4000, 46000],
['01/04/2015', '2019-06-27'],
['2015-01-04', '2019-06-27'],
0.1
],
[
'#VALUE!',
'If any number in dates is not a valid date, returns the #VALUE! error value',
[4000, -46000],
['01/04/2015', '2019X06-27'],
['2015-01-04', '2019X06-27'],
0.1
],
[
'#VALUE!',
'If any entry in values is not numeric, returns the #VALUE! error value',
['y', -46000],
['2015-01-04', '2019-06-27'],
0.1
],
[
'#NUM!',
'If any number in dates precedes the starting date, XIRR returns the #NUM! error value',
'If values is not an array, returns the #NUM! error value',
-46000,
['2015-01-04', '2019-06-27'],
0.1
],
[
'#NUM!',
'If dates is not an array but values is, returns the #NUM! error value',
[4000, -46000],
'2015-01-04',
0.1
],
[
'#N/A',
'If neither dates nor values is an array, returns the #N/A error value',
4000,
'2015-01-04',
0.1
],
[
0.137963527441025,
'Dates can be in any order after all',
[1893.67, 139947.43, 52573.25, 48849.74, 26369.16, -273029.18],
['2019-06-27', '2019-06-20', '2019-06-21', '2019-06-24', '2019-06-27', '2019-07-27'],
0.1
],
[
0.77868869226873,
'XIRR calculation #0 is incorrect',
[4000, -46000],
['2015-04-01', '2019-06-27'],
0.1
],
[
0.137963527441025,
'XIRR calculation #1 is incorrect',
@ -53,10 +88,40 @@ return [
0.1
],
[
'#NUM!',
'Can\'t find a result that works after FINANCIAL_MAX_ITERATIONS tries, the #NUM! error value is returned',
3235.159644,
'XIRR calculation #3 is incorrect',
[1.0, 1893.67, 52573.25, 48849.74, 26369.16, -273029.18],
['2019-06-27', '2019-06-27', '2019-06-21', '2019-06-24', '2019-06-27', '2019-07-27'],
],
[
0.15467888,
'XIRR calculation #4 is incorrect',
[1893.67, 139947.43, 52573.25, 48849.74, 26369.16, -273029.18],
['2019-06-20', '2019-06-27', '2019-06-21', '2019-06-24', '2019-06-27', '2019-07-27'],
],
[
-0.197387315,
'XIRR calculation #5 is incorrect',
[-100, 20, 40, 25],
['2010-01-01', '2010-04-01', '2010-10-01', '2011-02-01'],
],
[
3.434984565,
'XIRR calculation #6 is incorrect',
[-10000, 2750, 4250, 3250, 2750, 46000],
['2008-01-01', '2008-03-01', '2008-10-30', '2009-02-15', '2009-04-01', '2009-06-01'],
],
[
0.13796353,
'Substitute for guess=0',
[139947.43, 1893.67, 52573.25, 48849.74, 26369.16, -273029.18],
['2019-06-20', '2019-06-27', '2019-06-21', '2019-06-24', '2019-06-27', '2019-07-27'],
0.00000
],
[
'#NUM!',
'Can\'t find a result2 that works after FINANCIAL_MAX_ITERATIONS tries, the #NUM! error value is returned',
[-10000, 10000, -10000, 5],
['2010-01-15', '2010-04-16', '2010-07-16', '2010-10-15'],
],
];

View File

@ -0,0 +1,83 @@
<?php
// result, message, rate, values, dates
return [
[
'#VALUE!',
'If rate is not numeric, returns the #VALUE! error value',
'xyz',
[0, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000],
['2018-06-30', '2018-12-31', '2019-12-31', '2020-12-31', '2021-12-31', '2022-12-31', '2023-12-31', '2024-12-31', '2025-12-31', '2026-12-31', '2027-12-31'],
],
[
1000.0,
'Okay to specify values and dates as non-array',
0.10,
1000.0,
'2018-06-30',
],
[
'#NUM!',
'If different number of elements in values and dates, return NUM',
0.10,
[1000.0, 1000.1],
'2018-06-30',
],
[
'#NUM!',
'If minimum value > 0, return NUM',
0.10,
[1000.0, 1000.1],
['2018-06-30', '2018-07-30'],
],
[
'#NUM!',
'If maximum value < 0, return NUM',
0.10,
[-1000.0, -1000.1],
['2018-06-30', '2018-07-30'],
],
[
'#VALUE!',
'If any value is non-numeric, return VALUE',
0.10,
[-1000.0, 1000.1, "x"],
['2018-06-30', '2018-07-30', '2018-08-30'],
],
[
'#VALUE!',
'If first date is non-numeric, return VALUE',
0.10,
[-1000.0, 1000.1, 1000.2],
['2018-06x30', '2018-07-30', '2018-08-30'],
],
[
'#VALUE!',
'If any other date is non-numeric, return VALUE',
0.10,
[-1000.0, 1000.1, 1000.2],
['2018-06-30', '2018-07-30', '2018-08z30'],
],
[
'#NUM!',
'If any date is before first date, return NUM',
0.10,
[-1000.0, 1000.1, 1000.2],
['2018-06-30', '2018-07-30', '2018-05-30'],
],
[
772830.734,
'XNPV calculation #1 is incorrect',
0.10,
[0, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000, 120000],
['2018-06-30', '2018-12-31', '2019-12-31', '2020-12-31', '2021-12-31', '2022-12-31', '2023-12-31', '2024-12-31', '2025-12-31', '2026-12-31', '2027-12-31'],
],
[
22.257507852701,
'Gnumeric gets this right, Excel returns #NUM, Libre returns incorrect result',
-0.10,
[-100.0, 110.0],
['2019-12-31', '2020-12-31'],
],
];