![]() |
Mortgage calculation after a large extra payment
Hello World, The information I am looking for is a math expression. If you would like to offer some additional explanations and comments and so on, that would be fine too, but remember, all I'm looking for is a math expression. I need a math expression, that can be used in Excel, to calculate the principal portion of a monthly payment, in a specific month, after a large one-time extra payment is applied the previous month. Let's look at an example. Question: What is the mathematical calculation (in Excel) that results in the number $418.15. Conditions: Loan amount is $260,000 Rate is 5.625% Loan term is 360 months One extra payment of $25,000 is made at month number 17. State is California. When I use a webpage calculator I get this amortization: The amount of monthly payment applied to principal in month 16 is 298.16. The amount of monthly payment applied to principal in month 17 is 299.56. An extra payment towards principal is made in month 17 of $25,000. The amount of monthly payment applied to principal in month 18 is 418.15 (instead of 300.96). As an example of the type of nomenclature I am looking for, the Excel calculation that results in month 17 $299.56 is: PPMT(5.625%, 17, 360, 260000) equals 299.56 (negated). My problem is that I cannot formulate an expression that accurately results in the month 18 principal of 418.15. I predicted the "right answer" using this web page: http://www.decisionaide.com/mpcalcul...aPayments1.asp According to the web page, this reduces the months by 70, from 360 to 290. I don't know how to calculation the 290 either, so if you can help me with that too that would be great. Thanks World! |
Mortgage calculation after a large extra payment
=-PMT(0.05625/12,360,260000)-0.05625/12*(260000*(1-(1-(1+0.05625/12)^17)/(1-(1+0.05625/12)^360))-25000)
Dave |
Mortgage calculation after a large extra payment
For the number of months,
=NPER(0.05625/12,PMT(0.05625/12,360,260000),(260000*(1-(1-(1+0.05625/12)^17)/(1-(1+0.05625/12)^360))-25000))+17 Dave |
Mortgage calculation after a large extra payment
What is the mathematical calculation (in Excel) that results in the
number $418.15. Hi. Just for a general discussion: Your monthly payment is fixed at: =PMT(5.625%/12,360,-260000) or $1,496.71 After 17 months, you have paid off the loan by: =CUMPRINC(5.625%/12,360,260000,1,17,0) or -4906.68 Your new balance is now: =260000 -4906.68 -25000 or 230,093.32 The interest you should pay on the next payment in month 18 is just 230,093.32 * 5.625%/12 or 1,078.56 What's left over on your payment goes towards principle: 1496.71 - 1078.56 or 418.15 -- HTH. :) Dana DeLouis Windows XP, Office 2003 "Gary Wachs" wrote in message ... Hello World, The information I am looking for is a math expression. If you would like to offer some additional explanations and comments and so on, that would be fine too, but remember, all I'm looking for is a math expression. I need a math expression, that can be used in Excel, to calculate the principal portion of a monthly payment, in a specific month, after a large one-time extra payment is applied the previous month. Let's look at an example. Question: What is the mathematical calculation (in Excel) that results in the number $418.15. Conditions: Loan amount is $260,000 Rate is 5.625% Loan term is 360 months One extra payment of $25,000 is made at month number 17. State is California. When I use a webpage calculator I get this amortization: The amount of monthly payment applied to principal in month 16 is 298.16. The amount of monthly payment applied to principal in month 17 is 299.56. An extra payment towards principal is made in month 17 of $25,000. The amount of monthly payment applied to principal in month 18 is 418.15 (instead of 300.96). As an example of the type of nomenclature I am looking for, the Excel calculation that results in month 17 $299.56 is: PPMT(5.625%, 17, 360, 260000) equals 299.56 (negated). My problem is that I cannot formulate an expression that accurately results in the month 18 principal of 418.15. I predicted the "right answer" using this web page: http://www.decisionaide.com/mpcalcul...aPayments1.asp According to the web page, this reduces the months by 70, from 360 to 290. I don't know how to calculation the 290 either, so if you can help me with that too that would be great. Thanks World! |
Mortgage calculation after a large extra payment
=-PMT(0.05625/12,360,260000)-0.05625/12*(260000*(1-(1-(1+0.05625/12)^17)/(1-(1+0.05625/12)^360))-25000)
Perhaps we could merge Excel's PMT function into your excellent equation from above. = r * (((r + 1) ^ n * s) / ((r + 1) ^ 360 - 1) + xp) Here's the vba version if the op wishes to follow... Sub Demo() '// Dana DeLouis Dim r, n, s, xp r = 0.05625 / 12 s = 260000 xp = 25000 n = 17 Debug.Print _ r * (((r + 1) ^ n * s) / ((r + 1) ^ 360 - 1) + xp) ' 418.144224788268 End Sub -- HTH. :) Dana DeLouis Windows XP, Office 2003 "Dave Dodson" wrote in message ups.com... =-PMT(0.05625/12,360,260000)-0.05625/12*(260000*(1-(1-(1+0.05625/12)^17)/(1-(1+0.05625/12)^360))-25000) Dave |
All times are GMT +1. The time now is 06:04 AM. |
Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com