From bc18fb7e77f5b5c64c872960910907deaa5cfdf2 Mon Sep 17 00:00:00 2001 From: Mark Baker Date: Tue, 6 Apr 2021 12:45:37 +0200 Subject: [PATCH] more extraction of Excel Financial functions (#1989) * More Financial function extracts, this time looking at the Periodic Cashflow functions * Initial extract of Constant Periodic Interest and Payment functions --- .../Calculation/Calculation.php | 32 +- src/PhpSpreadsheet/Calculation/Financial.php | 451 ++++++------------ .../Financial/CashFlow/Constant/Periodic.php | 190 ++++++++ .../CashFlow/Constant/Periodic/Cumulative.php | 136 ++++++ .../CashFlow/Constant/Periodic/Interest.php | 209 ++++++++ .../Periodic/InterestAndPrincipal.php | 42 ++ .../CashFlow/Constant/Periodic/Payments.php | 119 +++++ .../CashFlow/Variable/NonPeriodic.php | 20 +- .../Functions/Financial/PmtTest.php | 34 ++ .../Functions/Financial/PpmtTest.php | 31 ++ tests/data/Calculation/Financial/CUMIPMT.php | 79 ++- tests/data/Calculation/Financial/CUMPRINC.php | 84 +++- tests/data/Calculation/Financial/FV.php | 82 +++- tests/data/Calculation/Financial/IPMT.php | 93 +++- tests/data/Calculation/Financial/ISPMT.php | 70 ++- tests/data/Calculation/Financial/NPER.php | 62 ++- tests/data/Calculation/Financial/PMT.php | 52 ++ tests/data/Calculation/Financial/PPMT.php | 64 +++ tests/data/Calculation/Financial/PV.php | 36 ++ tests/data/Calculation/Financial/RATE.php | 54 +++ 20 files changed, 1530 insertions(+), 410 deletions(-) create mode 100644 src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic.php create mode 100644 src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Cumulative.php create mode 100644 src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Interest.php create mode 100644 src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/InterestAndPrincipal.php create mode 100644 src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Payments.php create mode 100644 tests/PhpSpreadsheetTests/Calculation/Functions/Financial/PmtTest.php create mode 100644 tests/PhpSpreadsheetTests/Calculation/Functions/Financial/PpmtTest.php create mode 100644 tests/data/Calculation/Financial/PMT.php create mode 100644 tests/data/Calculation/Financial/PPMT.php diff --git a/src/PhpSpreadsheet/Calculation/Calculation.php b/src/PhpSpreadsheet/Calculation/Calculation.php index 1df103ca..9477131f 100644 --- a/src/PhpSpreadsheet/Calculation/Calculation.php +++ b/src/PhpSpreadsheet/Calculation/Calculation.php @@ -745,12 +745,12 @@ class Calculation ], 'CUMIPMT' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'CUMIPMT'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Cumulative::class, 'interest'], 'argumentCount' => '6', ], 'CUMPRINC' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'CUMPRINC'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Cumulative::class, 'principal'], 'argumentCount' => '6', ], 'DATE' => [ @@ -1137,12 +1137,12 @@ class Calculation ], 'FV' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'FV'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic::class, 'futureValue'], 'argumentCount' => '3-5', ], 'FVSCHEDULE' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'FVSCHEDULE'], + 'functionCall' => [Financial\CashFlow\Single::class, 'futureValue'], 'argumentCount' => '2', ], 'GAMMA' => [ @@ -1434,12 +1434,12 @@ class Calculation ], 'IPMT' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'IPMT'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Interest::class, 'payment'], 'argumentCount' => '4-6', ], 'IRR' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'IRR'], + 'functionCall' => [Financial\CashFlow\Variable\Periodic::class, 'rate'], 'argumentCount' => '1,2', ], 'ISBLANK' => [ @@ -1506,7 +1506,7 @@ class Calculation ], 'ISPMT' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'ISPMT'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Interest::class, 'schedulePayment'], 'argumentCount' => '4', ], 'ISREF' => [ @@ -1691,7 +1691,7 @@ class Calculation ], 'MIRR' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'MIRR'], + 'functionCall' => [Financial\CashFlow\Variable\Periodic::class, 'modifiedRate'], 'argumentCount' => '3', ], 'MMULT' => [ @@ -1826,12 +1826,12 @@ class Calculation ], 'NPER' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'NPER'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic::class, 'periods'], 'argumentCount' => '3-5', ], 'NPV' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'NPV'], + 'functionCall' => [Financial\CashFlow\Variable\Periodic::class, 'presentValue'], 'argumentCount' => '2+', ], 'NUMBERVALUE' => [ @@ -1893,7 +1893,7 @@ class Calculation ], 'PDURATION' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'PDURATION'], + 'functionCall' => [Financial\CashFlow\Single::class, 'periods'], 'argumentCount' => '3', ], 'PEARSON' => [ @@ -1958,7 +1958,7 @@ class Calculation ], 'PMT' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'PMT'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Payments::class, 'annuity'], 'argumentCount' => '3-5', ], 'POISSON' => [ @@ -1978,7 +1978,7 @@ class Calculation ], 'PPMT' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'PPMT'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Payments::class, 'interestPayment'], 'argumentCount' => '4-6', ], 'PRICE' => [ @@ -2013,7 +2013,7 @@ class Calculation ], 'PV' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'PV'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic::class, 'presentValue'], 'argumentCount' => '3-5', ], 'QUARTILE' => [ @@ -2073,7 +2073,7 @@ class Calculation ], 'RATE' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'RATE'], + 'functionCall' => [Financial\CashFlow\Constant\Periodic\Interest::class, 'rate'], 'argumentCount' => '3-6', ], 'RECEIVED' => [ @@ -2140,7 +2140,7 @@ class Calculation ], 'RRI' => [ 'category' => Category::CATEGORY_FINANCIAL, - 'functionCall' => [Financial::class, 'RRI'], + 'functionCall' => [Financial\CashFlow\Single::class, 'interestRate'], 'argumentCount' => '3', ], 'RSQ' => [ diff --git a/src/PhpSpreadsheet/Calculation/Financial.php b/src/PhpSpreadsheet/Calculation/Financial.php index fde1d3da..ebf5cec1 100644 --- a/src/PhpSpreadsheet/Calculation/Financial.php +++ b/src/PhpSpreadsheet/Calculation/Financial.php @@ -16,21 +16,6 @@ class Financial const FINANCIAL_PRECISION = 1.0e-08; - private static function interestAndPrincipal($rate = 0, $per = 0, $nper = 0, $pv = 0, $fv = 0, $type = 0) - { - $pmt = self::PMT($rate, $nper, $pv, $fv, $type); - $capital = $pv; - $interest = 0; - $principal = 0; - for ($i = 1; $i <= $per; ++$i) { - $interest = ($type && $i == 1) ? 0 : -$capital * $rate; - $principal = $pmt - $interest; - $capital += $principal; - } - - return [$interest, $principal]; - } - /** * ACCRINT. * @@ -140,7 +125,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the AMORDEGRC() method in the Financial\Amortization class instead + * @see Financial\Amortization::AMORDEGRC() + * Use the AMORDEGRC() method in the Financial\Amortization class instead * * @param float $cost The cost of the asset * @param mixed $purchased Date of the purchase of the asset @@ -174,7 +160,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the AMORLINC() method in the Financial\Amortization class instead + * @see Financial\Amortization::AMORLINC() + * Use the AMORLINC() method in the Financial\Amortization class instead * * @param float $cost The cost of the asset * @param mixed $purchased Date of the purchase of the asset @@ -206,7 +193,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPDAYBS() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPDAYBS() + * Use the COUPDAYBS() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -242,7 +230,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPDAYS() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPDAYS() + * Use the COUPDAYS() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -278,7 +267,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPDAYSNC() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPDAYSNC() + * Use the COUPDAYSNC() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -314,7 +304,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPNCD() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPNCD() + * Use the COUPNCD() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -352,7 +343,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPNUM() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPNUM() + * Use the COUPNUM() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -388,7 +380,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the COUPPCD() method in the Financial\Coupons class instead + * @see Financial\Coupons::COUPPCD() + * Use the COUPPCD() method in the Financial\Coupons class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue @@ -423,47 +416,26 @@ class Financial * Excel Function: * CUMIPMT(rate,nper,pv,start,end[,type]) * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Cumulative::interest() + * Use the interest() method in the Financial\CashFlow\Constant\Periodic\Cumulative class instead + * * @param float $rate The Interest rate * @param int $nper The total number of payment periods * @param float $pv Present Value * @param int $start The first period in the calculation. - * Payment periods are numbered beginning with 1. + * Payment periods are numbered beginning with 1. * @param int $end the last period in the calculation * @param int $type A number 0 or 1 and indicates when payments are due: - * 0 or omitted At the end of the period. - * 1 At the beginning of the period. + * 0 or omitted At the end of the period. + * 1 At the beginning of the period. * * @return float|string */ public static function CUMIPMT($rate, $nper, $pv, $start, $end, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $nper = (int) Functions::flattenSingleValue($nper); - $pv = Functions::flattenSingleValue($pv); - $start = (int) Functions::flattenSingleValue($start); - $end = (int) Functions::flattenSingleValue($end); - $type = (int) Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - if ($start < 1 || $start > $end) { - return Functions::VALUE(); - } - - // Calculate - $interest = 0; - for ($per = $start; $per <= $end; ++$per) { - $ipmt = self::IPMT($rate, $per, $nper, $pv, 0, $type); - if (is_string($ipmt)) { - return $ipmt; - } - - $interest += $ipmt; - } - - return $interest; + return Financial\CashFlow\Constant\Periodic\Cumulative::interest($rate, $nper, $pv, $start, $end, $type); } /** @@ -474,47 +446,26 @@ class Financial * Excel Function: * CUMPRINC(rate,nper,pv,start,end[,type]) * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Cumulative::principal() + * Use the principal() method in the Financial\CashFlow\Constant\Periodic\Cumulative class instead + * * @param float $rate The Interest rate * @param int $nper The total number of payment periods * @param float $pv Present Value * @param int $start The first period in the calculation. - * Payment periods are numbered beginning with 1. + * Payment periods are numbered beginning with 1. * @param int $end the last period in the calculation * @param int $type A number 0 or 1 and indicates when payments are due: - * 0 or omitted At the end of the period. - * 1 At the beginning of the period. + * 0 or omitted At the end of the period. + * 1 At the beginning of the period. * * @return float|string */ public static function CUMPRINC($rate, $nper, $pv, $start, $end, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $nper = (int) Functions::flattenSingleValue($nper); - $pv = Functions::flattenSingleValue($pv); - $start = (int) Functions::flattenSingleValue($start); - $end = (int) Functions::flattenSingleValue($end); - $type = (int) Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - if ($start < 1 || $start > $end) { - return Functions::VALUE(); - } - - // Calculate - $principal = 0; - for ($per = $start; $per <= $end; ++$per) { - $ppmt = self::PPMT($rate, $per, $nper, $pv, 0, $type); - if (is_string($ppmt)) { - return $ppmt; - } - - $principal += $ppmt; - } - - return $principal; + return Financial\CashFlow\Constant\Periodic\Cumulative::principal($rate, $nper, $pv, $start, $end, $type); } /** @@ -532,7 +483,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the DB() method in the Financial\Depreciation class instead + * @see Financial\Depreciation::DB() + * Use the DB() method in the Financial\Depreciation class instead * * @param float $cost Initial cost of the asset * @param float $salvage Value at the end of the depreciation. @@ -562,7 +514,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the DDB() method in the Financial\Depreciation class instead + * @see Financial\Depreciation::DDB() + * Use the DDB() method in the Financial\Depreciation class instead * * @param float $cost Initial cost of the asset * @param float $salvage Value at the end of the depreciation. @@ -646,7 +599,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the decimal() method in the Financial\Dollar class instead + * @see Financial\Dollar::decimal() + * Use the decimal() method in the Financial\Dollar class instead * * @param float $fractional_dollar Fractional Dollar * @param int $fraction Fraction @@ -670,7 +624,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the fractional() method in the Financial\Dollar class instead + * @see Financial\Dollar::fractional() + * Use the fractional() method in the Financial\Dollar class instead * * @param float $decimal_dollar Decimal Dollar * @param int $fraction Fraction @@ -693,7 +648,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the effective() method in the Financial\InterestRate class instead + * @see Financial\InterestRate::effective() + * Use the effective() method in the Financial\InterestRate class instead * * @param float $nominalRate Nominal interest rate * @param int $periodsPerYear Number of compounding payments per year @@ -713,6 +669,11 @@ class Financial * Excel Function: * FV(rate,nper,pmt[,pv[,type]]) * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic::futureValue() + * Use the futureValue() method in the Financial\CashFlow\Constant\Periodic class instead + * * @param float $rate The interest rate per period * @param int $nper Total number of payment periods in an annuity * @param float $pmt The payment made each period: it cannot change over the @@ -728,23 +689,7 @@ class Financial */ public static function FV($rate = 0, $nper = 0, $pmt = 0, $pv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $nper = Functions::flattenSingleValue($nper); - $pmt = Functions::flattenSingleValue($pmt); - $pv = Functions::flattenSingleValue($pv); - $type = Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - - // Calculate - if ($rate !== null && $rate != 0) { - return -$pv * (1 + $rate) ** $nper - $pmt * (1 + $rate * $type) * ((1 + $rate) ** $nper - 1) / $rate; - } - - return -$pv - $pmt * $nper; + return Financial\CashFlow\Constant\Periodic::futureValue($rate, $nper, $pmt, $pv, $type); } /** @@ -825,11 +770,17 @@ class Financial /** * IPMT. * - * Returns the interest payment for a given period for an investment based on periodic, constant payments and a constant interest rate. + * Returns the interest payment for a given period for an investment based on periodic, constant payments + * and a constant interest rate. * * Excel Function: * IPMT(rate,per,nper,pv[,fv][,type]) * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Interest::payment() + * Use the payment() method in the Financial\CashFlow\Constant\Periodic class instead + * * @param float $rate Interest rate per period * @param int $per Period for which we want to find the interest * @param int $nper Number of periods @@ -841,25 +792,7 @@ class Financial */ public static function IPMT($rate, $per, $nper, $pv, $fv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $per = (int) Functions::flattenSingleValue($per); - $nper = (int) Functions::flattenSingleValue($nper); - $pv = Functions::flattenSingleValue($pv); - $fv = Functions::flattenSingleValue($fv); - $type = (int) Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - if ($per <= 0 || $per > $nper) { - return Functions::NAN(); - } - - // Calculate - $interestAndPrincipal = self::interestAndPrincipal($rate, $per, $nper, $pv, $fv, $type); - - return $interestAndPrincipal[0]; + return Financial\CashFlow\Constant\Periodic\Interest::payment($rate, $per, $nper, $pv, $fv, $type); } /** @@ -876,6 +809,9 @@ class Financial * * @Deprecated 1.18.0 * + * @see Financial\CashFlow\Variable\Periodic::rate() + * Use the rate() method in the Financial\CashFlow\Variable\Periodic class instead + * * @param mixed $values An array or a reference to cells that contain numbers for which you want * to calculate the internal rate of return. * Values must contain at least one positive value and one negative value to @@ -883,9 +819,6 @@ class Financial * @param mixed $guess A number that you guess is close to the result of IRR * * @return float|string - * - *@see Financial\CashFlow\Variable\Periodic::rate() - * Use the IRR() method in the Financial\CashFlow\Variable\Periodic class instead */ public static function IRR($values, $guess = 0.1) { @@ -898,7 +831,12 @@ class Financial * Returns the interest payment for an investment based on an interest rate and a constant payment schedule. * * Excel Function: - * =ISPMT(interest_rate, period, number_payments, PV) + * =ISPMT(interest_rate, period, number_payments, pv) + * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Interest::schedulePayment() + * Use the schedulePayment() method in the Financial\CashFlow\Constant\Periodic class instead * * interest_rate is the interest rate for the investment * @@ -906,32 +844,11 @@ class Financial * * number_payments is the number of payments for the annuity * - * PV is the loan amount or present value of the payments + * pv is the loan amount or present value of the payments */ public static function ISPMT(...$args) { - // Return value - $returnValue = 0; - - // Get the parameters - $aArgs = Functions::flattenArray($args); - $interestRate = array_shift($aArgs); - $period = array_shift($aArgs); - $numberPeriods = array_shift($aArgs); - $principleRemaining = array_shift($aArgs); - - // Calculate - $principlePayment = ($principleRemaining * 1.0) / ($numberPeriods * 1.0); - for ($i = 0; $i <= $period; ++$i) { - $returnValue = $interestRate * $principleRemaining * -1; - $principleRemaining -= $principlePayment; - // principle needs to be 0 after the last payment, don't let floating point screw it up - if ($i == $numberPeriods) { - $returnValue = 0; - } - } - - return $returnValue; + return Financial\CashFlow\Constant\Periodic\Interest::schedulePayment(...$args); } /** @@ -946,7 +863,7 @@ class Financial * @Deprecated 1.18.0 * * @see Financial\CashFlow\Variable\Periodic::modifiedRate() - * Use the MIRR() method in the Financial\CashFlow\Variable\Periodic class instead + * Use the modifiedRate() method in the Financial\CashFlow\Variable\Periodic class instead * * @param mixed $values An array or a reference to cells that contain a series of payments and * income occurring at regular intervals. @@ -971,7 +888,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the nominal() method in the Financial\InterestRate class instead + * @see Financial\InterestRate::nominal() + * Use the nominal() method in the Financial\InterestRate class instead * * @param float $effectiveRate Effective interest rate * @param int $periodsPerYear Number of compounding payments per year @@ -988,6 +906,8 @@ class Financial * * Returns the number of periods for a cash flow with constant periodic payments (annuities), and interest rate. * + * @Deprecated 1.18.0 + * * @param float $rate Interest rate per period * @param int $pmt Periodic payment (annuity) * @param float $pv Present Value @@ -995,33 +915,13 @@ class Financial * @param int $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period * * @return float|string Result, or a string containing an error + * + *@see Financial\CashFlow\Constant\Periodic::periods() + * Use the periods() method in the Financial\CashFlow\Constant\Periodic class instead */ public static function NPER($rate = 0, $pmt = 0, $pv = 0, $fv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $pmt = Functions::flattenSingleValue($pmt); - $pv = Functions::flattenSingleValue($pv); - $fv = Functions::flattenSingleValue($fv); - $type = Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - - // Calculate - if ($rate !== null && $rate != 0) { - if ($pmt == 0 && $pv == 0) { - return Functions::NAN(); - } - - return log(($pmt * (1 + $rate * $type) / $rate - $fv) / ($pv + $pmt * (1 + $rate * $type) / $rate)) / log(1 + $rate); - } - if ($pmt == 0) { - return Functions::NAN(); - } - - return (-$pv - $fv) / $pmt; + return Financial\CashFlow\Constant\Periodic::periods($rate, $pmt, $pv, $fv, $type); } /** @@ -1031,10 +931,10 @@ class Financial * * @Deprecated 1.18.0 * - * @return float + * @see Financial\CashFlow\Variable\Periodic::presentValue() + * Use the presentValue() method in the Financial\CashFlow\Variable\Periodic class instead * - *@see Financial\CashFlow\Variable\Periodic::presentValue() - * Use the NPV() method in the Financial\CashFlow\Variable\Periodic class instead + * @return float */ public static function NPV(...$args) { @@ -1067,6 +967,11 @@ class Financial * * Returns the constant payment (annuity) for a cash flow with a constant interest rate. * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Payments::annuity() + * Use the annuity() method in the Financial\CashFlow\Constant\Periodic\Payments class instead + * * @param float $rate Interest rate per period * @param int $nper Number of periods * @param float $pv Present Value @@ -1077,29 +982,19 @@ class Financial */ public static function PMT($rate = 0, $nper = 0, $pv = 0, $fv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $nper = Functions::flattenSingleValue($nper); - $pv = Functions::flattenSingleValue($pv); - $fv = Functions::flattenSingleValue($fv); - $type = Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - - // Calculate - if ($rate !== null && $rate != 0) { - return (-$fv - $pv * (1 + $rate) ** $nper) / (1 + $rate * $type) / (((1 + $rate) ** $nper - 1) / $rate); - } - - return (-$pv - $fv) / $nper; + return Financial\CashFlow\Constant\Periodic\Payments::annuity($rate, $nper, $pv, $fv, $type); } /** * PPMT. * - * Returns the interest payment for a given period for an investment based on periodic, constant payments and a constant interest rate. + * Returns the interest payment for a given period for an investment based on periodic, constant payments + * and a constant interest rate. + * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Payments::interestPayment() + * Use the interestPayment() method in the Financial\CashFlow\Constant\Periodic\Payments class instead * * @param float $rate Interest rate per period * @param int $per Period for which we want to find the interest @@ -1112,25 +1007,7 @@ class Financial */ public static function PPMT($rate, $per, $nper, $pv, $fv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $per = (int) Functions::flattenSingleValue($per); - $nper = (int) Functions::flattenSingleValue($nper); - $pv = Functions::flattenSingleValue($pv); - $fv = Functions::flattenSingleValue($fv); - $type = (int) Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - if ($per <= 0 || $per > $nper) { - return Functions::NAN(); - } - - // Calculate - $interestAndPrincipal = self::interestAndPrincipal($rate, $per, $nper, $pv, $fv, $type); - - return $interestAndPrincipal[1]; + return Financial\CashFlow\Constant\Periodic\Payments::interestPayment($rate, $per, $nper, $pv, $fv, $type); } /** @@ -1140,7 +1017,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the price() method in the Financial\Securities\Price class instead + * @see Financial\Securities\Price::price() + * Use the price() method in the Financial\Securities\Price class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue date when the security @@ -1175,7 +1053,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the priceDiscounted() method in the Financial\Securities\Price class instead + * @see Financial\Securities\Price::priceDiscounted() + * Use the priceDiscounted() method in the Financial\Securities\Price class instead * * @param mixed $settlement The security's settlement date. * The security settlement date is the date after the issue date when the security @@ -1205,7 +1084,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the priceAtMaturity() method in the Financial\Securities\Price class instead + * @see Financial\Securities\Price::priceAtMaturity() + * Use the priceAtMaturity() method in the Financial\Securities\Price class instead * * @param mixed $settlement The security's settlement date. * The security's settlement date is the date after the issue date when the security @@ -1234,6 +1114,11 @@ class Financial * * Returns the Present Value of a cash flow with constant payments and interest rate (annuities). * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic::presentValue() + * Use the presentValue() method in the Financial\CashFlow\Constant\Periodic class instead + * * @param float $rate Interest rate per period * @param int $nper Number of periods * @param float $pmt Periodic payment (annuity) @@ -1244,23 +1129,7 @@ class Financial */ public static function PV($rate = 0, $nper = 0, $pmt = 0, $fv = 0, $type = 0) { - $rate = Functions::flattenSingleValue($rate); - $nper = Functions::flattenSingleValue($nper); - $pmt = Functions::flattenSingleValue($pmt); - $fv = Functions::flattenSingleValue($fv); - $type = Functions::flattenSingleValue($type); - - // Validate parameters - if ($type != 0 && $type != 1) { - return Functions::NAN(); - } - - // Calculate - if ($rate !== null && $rate != 0) { - return (-$pmt * (1 + $rate * $type) * (((1 + $rate) ** $nper - 1) / $rate) - $fv) / (1 + $rate) ** $nper; - } - - return -$fv - $pmt * $nper; + return Financial\CashFlow\Constant\Periodic::presentValue($rate, $nper, $pmt, $fv, $type); } /** @@ -1274,6 +1143,11 @@ class Financial * Excel Function: * RATE(nper,pmt,pv[,fv[,type[,guess]]]) * + * @Deprecated 1.18.0 + * + * @see Financial\CashFlow\Constant\Periodic\Interest::rate() + * Use the rate() method in the Financial\CashFlow\Constant\Periodic class instead + * * @param mixed $nper The total number of payment periods in an annuity * @param mixed $pmt The payment made each period and cannot change over the life * of the annuity. @@ -1294,47 +1168,7 @@ class Financial */ public static function RATE($nper, $pmt, $pv, $fv = 0.0, $type = 0, $guess = 0.1) { - $nper = (int) Functions::flattenSingleValue($nper); - $pmt = Functions::flattenSingleValue($pmt); - $pv = Functions::flattenSingleValue($pv); - $fv = ($fv === null) ? 0.0 : Functions::flattenSingleValue($fv); - $type = ($type === null) ? 0 : (int) Functions::flattenSingleValue($type); - $guess = ($guess === null) ? 0.1 : Functions::flattenSingleValue($guess); - - $rate = $guess; - // 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; - } - $rate1 = $rate - $nextdiff; - $close = abs($rate1 - $rate) < self::FINANCIAL_PRECISION; - ++$iter; - $rate = $rate1; - } - - return $close ? $rate : Functions::NAN(); - } - - private static function rateNextGuess($rate, $nper, $pmt, $pv, $fv, $type) - { - if ($rate == 0) { - return Functions::NAN(); - } - $tt1 = ($rate + 1) ** $nper; - $tt2 = ($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; + return Financial\CashFlow\Constant\Periodic\Interest::rate($nper, $pmt, $pv, $fv, $type, $guess); } /** @@ -1343,17 +1177,18 @@ class Financial * Returns the price per $100 face value of a discounted security. * * @param mixed $settlement The security's settlement date. - * The security settlement date is the date after the issue date when the security is traded to the buyer. + * The security settlement date is the date after the issue date when the security + * is traded to the buyer. * @param mixed $maturity The security's maturity date. - * The maturity date is the date when the security expires. + * The maturity date is the date when the security expires. * @param mixed $investment The amount invested in the security * @param mixed $discount The security's discount rate * @param mixed $basis The type of day count to use. - * 0 or omitted US (NASD) 30/360 - * 1 Actual/actual - * 2 Actual/360 - * 3 Actual/365 - * 4 European 30/360 + * 0 or omitted US (NASD) 30/360 + * 1 Actual/actual + * 2 Actual/360 + * 3 Actual/365 + * 4 European 30/360 * * @return float|string Result, or a string containing an error */ @@ -1410,7 +1245,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the SLN() method in the Financial\Depreciation class instead + * @see Financial\Depreciation::SLN() + * Use the SLN() method in the Financial\Depreciation class instead * * @param mixed $cost Initial cost of the asset * @param mixed $salvage Value at the end of the depreciation @@ -1430,7 +1266,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the SYD() method in the Financial\Depreciation class instead + * @see Financial\Depreciation::SYD() + * Use the SYD() method in the Financial\Depreciation class instead * * @param mixed $cost Initial cost of the asset * @param mixed $salvage Value at the end of the depreciation @@ -1451,10 +1288,12 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the bondEquivalentYield() method in the Financial\TreasuryBill class instead + * @see Financial\TreasuryBill::bondEquivalentYield() + * Use the bondEquivalentYield() method in the Financial\TreasuryBill class instead * * @param mixed $settlement The Treasury bill's settlement date. - * The Treasury bill's settlement date is the date after the issue date when the Treasury bill is traded to the buyer. + * The Treasury bill's settlement date is the date after the issue date when the + * Treasury bill is traded to the buyer. * @param mixed $maturity The Treasury bill's maturity date. * The maturity date is the date when the Treasury bill expires. * @param int $discount The Treasury bill's discount rate @@ -1473,7 +1312,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the price() method in the Financial\TreasuryBill class instead + * @see Financial\TreasuryBill::price() + * Use the price() method in the Financial\TreasuryBill class instead * * @param mixed $settlement The Treasury bill's settlement date. * The Treasury bill's settlement date is the date after the issue date @@ -1496,7 +1336,8 @@ class Financial * * @Deprecated 1.18.0 * - * @see Use the yield() method in the Financial\TreasuryBill class instead + * @see Financial\TreasuryBill::yield() + * Use the yield() method in the Financial\TreasuryBill class instead * * @param mixed $settlement The Treasury bill's settlement date. * The Treasury bill's settlement date is the date after the issue date @@ -1554,13 +1395,15 @@ class Financial * Use the presentValue() method in the Financial\CashFlow\Variable\NonPeriodic class instead * * @param float $rate the discount rate to apply to the cash flows - * @param float[] $values A series of cash flows that corresponds to a schedule of payments in dates. - * The first payment is optional and corresponds to a cost or payment that occurs at the beginning of the investment. - * If the first value is a cost or payment, it must be a negative value. All succeeding payments are discounted based on a 365-day year. - * The series of values must contain at least one positive value and one negative value. - * @param mixed[] $dates A schedule of payment dates that corresponds to the cash flow payments. - * 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[] $values A series of cash flows that corresponds to a schedule of payments in dates. + * The first payment is optional and corresponds to a cost or payment that occurs + * at the beginning of the investment. + * If the first value is a cost or payment, it must be a negative value. + * All succeeding payments are discounted based on a 365-day year. + * The series of values must contain at least one positive value and one negative value. + * @param mixed[] $dates A schedule of payment dates that corresponds to the cash flow payments. + * 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. * * @return float|mixed|string */ @@ -1619,11 +1462,11 @@ class Financial * @param int $rate The security's interest rate at date of issue * @param int $price The security's price per $100 face value * @param int $basis The type of day count to use. - * 0 or omitted US (NASD) 30/360 - * 1 Actual/actual - * 2 Actual/360 - * 3 Actual/365 - * 4 European 30/360 + * 0 or omitted US (NASD) 30/360 + * 1 Actual/actual + * 2 Actual/360 + * 3 Actual/365 + * 4 European 30/360 * * @return float|string Result, or a string containing an error */ diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic.php new file mode 100644 index 00000000..39a51875 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic.php @@ -0,0 +1,190 @@ +getMessage(); + } + + // Validate parameters + if ($numberOfPeriods < 0 || ($type !== 0 && $type !== 1)) { + return Functions::NAN(); + } + + return self::calculateFutureValue($rate, $numberOfPeriods, $payment, $presentValue, $type); + } + + /** + * PV. + * + * Returns the Present Value of a cash flow with constant payments and interest rate (annuities). + * + * @param mixed $rate Interest rate per period + * @param mixed $numberOfPeriods Number of periods as an integer + * @param mixed $payment Periodic payment (annuity) + * @param mixed $futureValue Future Value + * @param mixed $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period + * + * @return float|string Result, or a string containing an error + */ + public static function presentValue($rate, $numberOfPeriods, $payment = 0, $futureValue = 0, $type = 0) + { + $rate = Functions::flattenSingleValue($rate); + $numberOfPeriods = Functions::flattenSingleValue($numberOfPeriods); + $payment = ($payment === null) ? 0.0 : Functions::flattenSingleValue($payment); + $futureValue = ($futureValue === null) ? 0.0 : Functions::flattenSingleValue($futureValue); + $type = ($type === null) ? 0 : Functions::flattenSingleValue($type); + + try { + $rate = self::validateFloat($rate); + $numberOfPeriods = self::validateInt($numberOfPeriods); + $payment = self::validateFloat($payment); + $futureValue = self::validateFloat($futureValue); + $type = self::validateInt($type); + } catch (Exception $e) { + return $e->getMessage(); + } + + // Validate parameters + if ($numberOfPeriods < 0 || ($type !== 0 && $type !== 1)) { + return Functions::NAN(); + } + + return self::calculatePresentValue($rate, $numberOfPeriods, $payment, $futureValue, $type); + } + + /** + * NPER. + * + * Returns the number of periods for a cash flow with constant periodic payments (annuities), and interest rate. + * + * @param mixed $rate Interest rate per period + * @param mixed $payment Periodic payment (annuity) + * @param mixed $presentValue Present Value + * @param mixed $futureValue Future Value + * @param mixed $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period + * + * @return float|string Result, or a string containing an error + */ + public static function periods($rate, $payment, $presentValue, $futureValue = 0, $type = 0) + { + $rate = Functions::flattenSingleValue($rate); + $payment = Functions::flattenSingleValue($payment); + $presentValue = Functions::flattenSingleValue($presentValue); + $futureValue = ($futureValue === null) ? 0.0 : Functions::flattenSingleValue($futureValue); + $type = ($type === null) ? 0 : Functions::flattenSingleValue($type); + + try { + $rate = self::validateFloat($rate); + $payment = self::validateFloat($payment); + $presentValue = self::validateFloat($presentValue); + $futureValue = self::validateFloat($futureValue); + $type = self::validateInt($type); + } catch (Exception $e) { + return $e->getMessage(); + } + + // Validate parameters + if ($payment == 0.0 || ($type != 0 && $type != 1)) { + return Functions::NAN(); + } + + return self::calculatePeriods($rate, $payment, $presentValue, $futureValue, $type); + } + + private static function calculateFutureValue( + float $rate, + int $numberOfPeriods, + float $payment, + float $presentValue, + int $type + ): float { + if ($rate !== null && $rate != 0) { + return -$presentValue * + (1 + $rate) ** $numberOfPeriods - $payment * (1 + $rate * $type) * ((1 + $rate) ** $numberOfPeriods - 1) + / $rate; + } + + return -$presentValue - $payment * $numberOfPeriods; + } + + private static function calculatePresentValue( + float $rate, + int $numberOfPeriods, + float $payment, + float $futureValue, + int $type + ): float { + if ($rate != 0.0) { + return (-$payment * (1 + $rate * $type) + * (((1 + $rate) ** $numberOfPeriods - 1) / $rate) - $futureValue) / (1 + $rate) ** $numberOfPeriods; + } + + return -$futureValue - $payment * $numberOfPeriods; + } + + /** + * @return float|string + */ + private static function calculatePeriods( + float $rate, + float $payment, + float $presentValue, + float $futureValue, + int $type + ) { + if ($rate != 0.0) { + if ($presentValue == 0.0) { + return Functions::NAN(); + } + + return log(($payment * (1 + $rate * $type) / $rate - $futureValue) / + ($presentValue + $payment * (1 + $rate * $type) / $rate)) / log(1 + $rate); + } + + return (-$presentValue - $futureValue) / $payment; + } +} diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Cumulative.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Cumulative.php new file mode 100644 index 00000000..1e05a446 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Cumulative.php @@ -0,0 +1,136 @@ +getMessage(); + } + + // Validate parameters + if ($type !== 0 && $type !== 1) { + return Functions::NAN(); + } + if ($start < 1 || $start > $end) { + return Functions::NAN(); + } + + // Calculate + $interest = 0; + for ($per = $start; $per <= $end; ++$per) { + $ipmt = Financial::IPMT($rate, $per, $periods, $presentValue, 0, $type); + if (is_string($ipmt)) { + return $ipmt; + } + + $interest += $ipmt; + } + + return $interest; + } + + /** + * CUMPRINC. + * + * Returns the cumulative principal paid on a loan between the start and end periods. + * + * Excel Function: + * CUMPRINC(rate,nper,pv,start,end[,type]) + * + * @param mixed $rate The Interest rate + * @param mixed $periods The total number of payment periods as an integer + * @param mixed $presentValue Present Value + * @param mixed $start The first period in the calculation. + * Payment periods are numbered beginning with 1. + * @param mixed $end the last period in the calculation + * @param mixed $type A number 0 or 1 and indicates when payments are due: + * 0 or omitted At the end of the period. + * 1 At the beginning of the period. + * + * @return float|string + */ + public static function principal($rate, $periods, $presentValue, $start, $end, $type = 0) + { + $rate = Functions::flattenSingleValue($rate); + $periods = Functions::flattenSingleValue($periods); + $presentValue = Functions::flattenSingleValue($presentValue); + $start = Functions::flattenSingleValue($start); + $end = Functions::flattenSingleValue($end); + $type = ($type === null) ? 0 : Functions::flattenSingleValue($type); + + try { + $rate = self::validateFloat($rate); + $periods = self::validateInt($periods); + $presentValue = self::validateFloat($presentValue); + $start = self::validateInt($start); + $end = self::validateInt($end); + $type = self::validateInt($type); + } catch (Exception $e) { + return $e->getMessage(); + } + + // Validate parameters + if ($type !== 0 && $type !== 1) { + return Functions::NAN(); + } + if ($start < 1 || $start > $end) { + return Functions::VALUE(); + } + + // Calculate + $principal = 0; + for ($per = $start; $per <= $end; ++$per) { + $ppmt = Payments::interestPayment($rate, $per, $periods, $presentValue, 0, $type); + if (is_string($ppmt)) { + return $ppmt; + } + + $principal += $ppmt; + } + + return $principal; + } +} diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Interest.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Interest.php new file mode 100644 index 00000000..1bb63a2a --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Interest.php @@ -0,0 +1,209 @@ +getMessage(); + } + + // Validate parameters + if ($type != 0 && $type != 1) { + return Functions::NAN(); + } + if ($period <= 0 || $period > $numberOfPeriods) { + return Functions::NAN(); + } + + // Calculate + $interestAndPrincipal = new InterestAndPrincipal( + $interestRate, + $period, + $numberOfPeriods, + $presentValue, + $futureValue, + $type + ); + + return $interestAndPrincipal->interest(); + } + + /** + * ISPMT. + * + * Returns the interest payment for an investment based on an interest rate and a constant payment schedule. + * + * Excel Function: + * =ISPMT(interest_rate, period, number_payments, pv) + * + * interest_rate is the interest rate for the investment + * + * period is the period to calculate the interest rate. It must be betweeen 1 and number_payments. + * + * number_payments is the number of payments for the annuity + * + * pv is the loan amount or present value of the payments + */ + public static function schedulePayment($interestRate, $period, $numberOfPeriods, $principleRemaining) + { + $interestRate = Functions::flattenSingleValue($interestRate); + $period = Functions::flattenSingleValue($period); + $numberOfPeriods = Functions::flattenSingleValue($numberOfPeriods); + $principleRemaining = Functions::flattenSingleValue($principleRemaining); + + try { + $interestRate = self::validateFloat($interestRate); + $period = self::validateInt($period); + $numberOfPeriods = self::validateInt($numberOfPeriods); + $principleRemaining = self::validateFloat($principleRemaining); + } catch (Exception $e) { + return $e->getMessage(); + } + + if ($period <= 0 || $period > $numberOfPeriods) { + return Functions::NAN(); + } + // Return value + $returnValue = 0; + + // Calculate + $principlePayment = ($principleRemaining * 1.0) / ($numberOfPeriods * 1.0); + for ($i = 0; $i <= $period; ++$i) { + $returnValue = $interestRate * $principleRemaining * -1; + $principleRemaining -= $principlePayment; + // principle needs to be 0 after the last payment, don't let floating point screw it up + if ($i == $numberOfPeriods) { + $returnValue = 0.0; + } + } + + return $returnValue; + } + + /** + * RATE. + * + * Returns the interest rate per period of an annuity. + * RATE is calculated by iteration and can have zero or more solutions. + * If the successive results of RATE do not converge to within 0.0000001 after 20 iterations, + * RATE returns the #NUM! error value. + * + * Excel Function: + * RATE(nper,pmt,pv[,fv[,type[,guess]]]) + * + * @param mixed $numberOfPeriods The total number of payment periods in an annuity + * @param mixed $payment 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. + * @param mixed $presentValue The present value - the total amount that a series of future payments is worth now + * @param mixed $futureValue 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). + * @param mixed $type A number 0 or 1 and indicates when payments are due: + * 0 or omitted At the end of the period. + * 1 At the beginning of the period. + * @param mixed $guess Your guess for what the rate will be. + * If you omit guess, it is assumed to be 10 percent. + * + * @return float|string + */ + public static function rate($numberOfPeriods, $payment, $presentValue, $futureValue = 0.0, $type = 0, $guess = 0.1) + { + $numberOfPeriods = Functions::flattenSingleValue($numberOfPeriods); + $payment = Functions::flattenSingleValue($payment); + $presentValue = Functions::flattenSingleValue($presentValue); + $futureValue = ($futureValue === null) ? 0.0 : Functions::flattenSingleValue($futureValue); + $type = ($type === null) ? 0 : Functions::flattenSingleValue($type); + $guess = ($guess === null) ? 0.1 : Functions::flattenSingleValue($guess); + + try { + $numberOfPeriods = self::validateInt($numberOfPeriods); + $payment = self::validateFloat($payment); + $presentValue = self::validateFloat($presentValue); + $futureValue = self::validateFloat($futureValue); + $type = self::validateInt($type); + $guess = self::validateFloat($guess); + } catch (Exception $e) { + return $e->getMessage(); + } + + $rate = $guess; + // rest of code adapted from python/numpy + $close = false; + $iter = 0; + while (!$close && $iter < self::FINANCIAL_MAX_ITERATIONS) { + $nextdiff = self::rateNextGuess($rate, $numberOfPeriods, $payment, $presentValue, $futureValue, $type); + if (!is_numeric($nextdiff)) { + break; + } + $rate1 = $rate - $nextdiff; + $close = abs($rate1 - $rate) < self::FINANCIAL_PRECISION; + ++$iter; + $rate = $rate1; + } + + return $close ? $rate : Functions::NAN(); + } + + private static function rateNextGuess($rate, $nper, $pmt, $pv, $fv, $type) + { + if ($rate == 0) { + return Functions::NAN(); + } + $tt1 = ($rate + 1) ** $nper; + $tt2 = ($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; + } +} diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/InterestAndPrincipal.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/InterestAndPrincipal.php new file mode 100644 index 00000000..5e76f346 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/InterestAndPrincipal.php @@ -0,0 +1,42 @@ +interest = $interest; + $this->principal = $principal; + } + + public function interest(): float + { + return $this->interest; + } + + public function principal(): float + { + return $this->principal; + } +} diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Payments.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Payments.php new file mode 100644 index 00000000..a0c61586 --- /dev/null +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Constant/Periodic/Payments.php @@ -0,0 +1,119 @@ +getMessage(); + } + + // Validate parameters + if ($type != 0 && $type != 1) { + return Functions::NAN(); + } + + // Calculate + if ($interestRate != 0.0) { + return (-$futureValue - $presentValue * (1 + $interestRate) ** $numberOfPeriods) / + (1 + $interestRate * $type) / (((1 + $interestRate) ** $numberOfPeriods - 1) / $interestRate); + } + + return (-$presentValue - $futureValue) / $numberOfPeriods; + } + + /** + * PPMT. + * + * Returns the interest payment for a given period for an investment based on periodic, constant payments + * and a constant interest rate. + * + * @param mixed $interestRate Interest rate per period + * @param mixed $period Period for which we want to find the interest + * @param mixed $numberOfPeriods Number of periods + * @param mixed $presentValue Present Value + * @param mixed $futureValue Future Value + * @param mixed $type Payment type: 0 = at the end of each period, 1 = at the beginning of each period + * + * @return float|string Result, or a string containing an error + */ + public static function interestPayment( + $interestRate, + $period, + $numberOfPeriods, + $presentValue, + $futureValue = 0, + $type = 0 + ) { + $interestRate = Functions::flattenSingleValue($interestRate); + $period = Functions::flattenSingleValue($period); + $numberOfPeriods = Functions::flattenSingleValue($numberOfPeriods); + $presentValue = Functions::flattenSingleValue($presentValue); + $futureValue = ($futureValue === null) ? 0.0 : Functions::flattenSingleValue($futureValue); + $type = ($type === null) ? 0 : Functions::flattenSingleValue($type); + + try { + $interestRate = self::validateFloat($interestRate); + $period = self::validateInt($period); + $numberOfPeriods = self::validateInt($numberOfPeriods); + $presentValue = self::validateFloat($presentValue); + $futureValue = self::validateFloat($futureValue); + $type = self::validateInt($type); + } catch (Exception $e) { + return $e->getMessage(); + } + + // Validate parameters + if ($type != 0 && $type != 1) { + return Functions::NAN(); + } + if ($period <= 0 || $period > $numberOfPeriods) { + return Functions::NAN(); + } + + // Calculate + $interestAndPrincipal = new InterestAndPrincipal( + $interestRate, + $period, + $numberOfPeriods, + $presentValue, + $futureValue, + $type + ); + + return $interestAndPrincipal->principal(); + } +} diff --git a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Variable/NonPeriodic.php b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Variable/NonPeriodic.php index 58f8fdaf..40df776f 100644 --- a/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Variable/NonPeriodic.php +++ b/src/PhpSpreadsheet/Calculation/Financial/CashFlow/Variable/NonPeriodic.php @@ -178,14 +178,12 @@ class NonPeriodic $valCount = count($values); try { + self::validateXnpv($rate, $values, $dates); $date0 = DateTimeExcel\Helpers::getDateValue($dates[0]); } catch (Exception $e) { return $e->getMessage(); } - $rslt = self::validateXnpv($rate, $values, $dates); - if ($rslt) { - return $rslt; - } + $xnpv = 0.0; for ($i = 0; $i < $valCount; ++$i) { if (!is_numeric($values[$i])) { @@ -212,23 +210,17 @@ class NonPeriodic return is_finite($xnpv) ? $xnpv : Functions::VALUE(); } - private static function validateXnpv($rate, $values, $dates) + private static function validateXnpv($rate, $values, $dates): void { if (!is_numeric($rate)) { - return Functions::VALUE(); + throw new Exception(Functions::VALUE()); } $valCount = count($values); if ($valCount != count($dates)) { - return Functions::NAN(); + throw new Exception(Functions::NAN()); } if ($valCount > 1 && ((min($values) > 0) || (max($values) < 0))) { - return Functions::NAN(); + throw new Exception(Functions::NAN()); } - $date0 = DateTimeExcel\Helpers::getDateValue($dates[0]); - if (is_string($date0)) { - return Functions::VALUE(); - } - - return ''; } } diff --git a/tests/PhpSpreadsheetTests/Calculation/Functions/Financial/PmtTest.php b/tests/PhpSpreadsheetTests/Calculation/Functions/Financial/PmtTest.php new file mode 100644 index 00000000..9f7cf755 --- /dev/null +++ b/tests/PhpSpreadsheetTests/Calculation/Functions/Financial/PmtTest.php @@ -0,0 +1,34 @@ +