Exceljet

Quick, clean, and to the point

CAGR formula examples

Excel formula: CAGR formula examples
Generic formula 
=(end/start)^(1/periods)-1
Summary 

There are several ways to calculate CAGR in Excel. In Excel 2013 and later, the simplest way is to use the RRI function. In the example shown, the formula in H9 is:

=RRI(B11,C6,C11)
Explanation 

CAGR stands for Compound Annual Growth Rate. CAGR is the average rate of return for an investment over a period of time. It is the rate of return required for an investment to grow from the starting balance to the ending balance, assuming profits are reinvested each year, and interest compounds annually. There are several ways to calculate CAGR in Excel.

CAGR with the RRI function

In Excel 2013 and later, you can use the RRI function to calculate CAGR with a simple formula. The formula in H9 is:

=RRI(B11,C6,C11)

where C11 is the ending value in year 5, C6 is the starting value (initial investment), and B11 is the total number of periods.

Note: unlike most other financial functions in Excel, fv (future value, the third argument) does not need to be entered as a negative number in RRI.

CAGR with a manual formula

The formula for calculating CAGR manually is:

=(end/start)^(1/periods)-1

In the example shown, the formula in H7 is:

=(C11/C6)^(1/B11)-1

where C11 is the ending value in year 5, C6 is the starting value or initial investment, and B11 is the total number of periods.

The first part of the formula is a measure of total return, the second part of the formula annualizes the return over the life of the investment.

CAGR with the GEOMEAN function

The GEOMEAN function calculates geometric mean, and can also be used to calculate CAGR. To calculate CAGR with GEOMEAN, we need to use relative changes (percentage change + 1), sometimes called a growth factor. We have these values already in column E so we can use them directly in GEOMEAN the function. The formula in H8 is:

=GEOMEAN(E7:E11)-1
Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Instant access. See details here.

Download 200+ Excel Shortcuts

Get over 200 Excel shortcuts for Windows and Mac in one handy PDF.