XL: How to Calculate Interest Paid for Multiple Periods

ID: Q71952


The information in this article applies to:
  • Microsoft Excel for Windows, versions 2.x, 3.x, 4.x, 5.0, 5.0c
  • Microsoft Excel for Windows NT, version 5.0
  • Microsoft Excel for Windows 95, version 7.0
  • Microsoft Excel 97 for Windows
  • Microsoft Excel for the Macintosh, versions 5.0, 5.0a
  • Microsoft Excel 98 Macintosh Edition


SUMMARY

If you are using Microsoft Excel version 4.0 or later, you can use the CUMIPMT function to return the cumulative interest paid on a loan between a start period and an end period.

In all versions of Microsoft Excel, you can use the IPMT function to return the interest payment for a single given period for an investment based on periodic and constant payments, and a constant interest rate. To calculate the total interest paid over a range of time (multiple periods), the IPMT function can be used in an array formula as described in the "More Information" section of this article.

Note also that if you are using Microsoft Excel for Windows 95, you can use the Loan Manager template to analyze various aspects of your loan including the interest saved by refinancing or prepaying principal.


MORE INFORMATION

To determine the total interest paid for the first year (periods 1-12), assuming that the annual interest rate is 13 percent, the number of periods is equal to 360 months, and the present value of the loan is equal to negative $100,000; enter the following in a worksheet:


    A1: Total interest paid in Year 1
    A2: =SUM(IPMT(13%/12,ROW(A1:A12),360,-100000)) 


NOTE: The formula in A2 must be entered as an array formula. To enter a formula as an array formula in Microsoft Excel for Windows, press CTRL+SHIFT+ENTER. To enter a formula as an array in Microsoft Excel for the Macintosh, press COMMAND+RETURN.

The value returned in cell A2 is $12,983.05.

The ROW function is used in this formula to return an array of period numbers and any range can be used here. In this example, ROW(A1:A12) returns {1;2;3;4;5;6;7;8;9;10;11;12}.

This method works for any other range of periods. For example, to calculate

the interest paid for the second year, type the range A13:A24 in place of A1:A12 in the ROW function.


REFERENCES

For more information about the Loan Manager template, click the Index tab in Microsoft Excel 7.0 Help, type the following text


   loan manager 


and then double-click the selected text to go to the "Templates included with Microsoft Excel" topic.

"Function Reference," version 4.0, page 246
"Function Reference," version 3.0, page 133
"Functions and Macros," version 2.x, page 310

Additional query words: 98 97 2.0 2.00 2.01 2.1 2.10 2.2 2.20 2.21 3.0 3.00 4.0 4.00 4.0a 4.00a 5.0 XL98 XL97 XL7 XL5 XL4 XL3

Keywords : kbdta xlformula
Version : WINDOWS:2.0,3.0,4.0,5.0,5.0c,7.0,97; MACINTOSH:5.0,5.0a,98
Platform : MACINTOSH WINDOWS
Issue type : kbhowto kbinfo


Last Reviewed: March 22, 1999
© 2000 Microsoft Corporation. All rights reserved. Terms of Use.