A Microsoft Excel forum. ExcelBanter

If this is your first visit, be sure to check out the FAQ by clicking the link above. You may have to register before you can post: click the register link above to proceed. To start viewing messages, select the forum that you want to visit from the selection below.

Go Back   Home » ExcelBanter forum » Excel Newsgroups » Excel Worksheet Functions
Site Map Home Register Authors List Search Today's Posts Mark Forums Read Web Partners

how do i create a loan with a balloon payment in Excel?



 
 
Thread Tools Display Modes
  #1  
Old November 17th 06, 11:03 PM posted to microsoft.public.excel.worksheet.functions
Rox A.
external usenet poster
 
Posts: 1
Default how do i create a loan with a balloon payment in Excel?

I would like to create a loan that has the option of a balloon payment for
the 12th payment/
Ads
  #2  
Old November 18th 06, 12:16 AM posted to microsoft.public.excel.worksheet.functions
Ron Coderre
external usenet poster
 
Posts: 2,118
Default how do i create a loan with a balloon payment in Excel?

Loans with balloon payments:

With
B1: Orig Principal: $100,000
B2: Balloon Pmt: $10,000
B3: PV of Balloon: (see below)
B5: APR: 5.00%
B6: Mthly Rate: 0.416666%
B7: TermMthls: 12
B8: Mthly Payment (see below)


When there's a balloon payment, the borrower effectively has 2 loans
One they make payments on
The other, they payoff in one lump sum at the end.

So...that means if you will receive $10,000 in 12 months, and that amount
will include accrued interest....then you must present value the balloon
payment.
PV of Balloon:
=PV(rate,term,pmt,FV)
=PV(B6,B7+1,0,-B2)
=PV(0.41666%,13,0,)10000
=$9,473.81

Subtract that amount from the $100,000 pricipal and calculate the payment on
that loan

B4: PmtPrincipal
= Orig Principal less PV of Balloon
=100000-9473.81
=90,526.19

Now you can calculate the payment:
B8: Mthly Payment
=PMT(rate, nper,pv,fv)
=PMT(B6,B7,-B4,0)
=7,749.72

Here's how to test for reasonableness:

On another sheet
A1:A13 enter the series 0 through 13
B1: -100,000
B2:B13 7,749.72
B14: 10,000

C1: =IRR(B1:B14,0.3%)
C1 will return 0.417%
times 12 = 5.00%

Does that help?
***********
Regards,
Ron

XL2002, WinXP


"Rox A." wrote:

> I would like to create a loan that has the option of a balloon payment for
> the 12th payment/

 




Thread Tools
Display Modes

Posting Rules
You may not post new threads
You may not post replies
You may not post attachments
You may not edit your posts

vB code is On
Smilies are On
[IMG] code is On
HTML code is Off
Forum Jump

Similar Threads
Thread Thread Starter Forum Replies Last Post
Can I create an Excel calendar that references Excel spreadsheet? intern, aka: slave labor Excel Discussion (Misc queries) 1 July 24th 06 06:31 PM
Create database in excel? wirthless New Users to Excel 7 October 30th 05 03:57 PM
TRYING TO SET UP EXCEL SPREADSHEET ON MY COMPUTER MEGTOM New Users to Excel 5 October 27th 05 03:06 AM
Wrong answer after using the payment formula in excel punkyh New Users to Excel 8 April 28th 05 07:56 PM
create price list from excel sheet -keevill- Excel Discussion (Misc queries) 1 February 8th 05 01:02 AM


All times are GMT +1. The time now is 03:25 PM.


Powered by vBulletin® Version 3.6.4
Copyright ©2000 - 2014, Jelsoft Enterprises Ltd.
Copyright 2004-2014 ExcelBanter.
The comments are property of their posters.