Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Using GEOMEAN with a Large List.

Using GEOMEAN with a Large List

Written by Allen Wyatt (last updated August 20, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


Ken wrote about a problem he was having with the GEOMEAN function. When he attempts to use the function on a large number of values (3,500 rows of data), he gets a #NUM error value returned.

The GEOMEAN function is used to return the geometric mean of a series of values. The GEOMEAN of n numbers is the n-th root of the product of the numbers. For example, if there are four values in a series (A through D), then the product of those numbers is A * B * C * D, and the GEOMEAN is the fourth root of that product.

The #NUM error would be returned if any of three conditions were met: any of the values was equal to zero, any of the values was negative, or the limits of Excel were exceeded. It is likely that it is this last condition that Ken is running into, particularly if any of his 3,500 values are large.

Since GEOMEAN finds the product of the 3,500 numbers (multiplies them all by each other) and then takes the nth root, the product may easily be too large for Excel. The largest positive number in Excel is 9.99999999999999 * 10^307 (in scientific notation this is written as 9.99999999999999E+307). If the product gets larger than this number, you will get a #NUM error for the function.

The solution is to use logs to do the calculation. This is easiest to understand when you look at a transformation of the GEOMEAN function:

GEOMEAN = (X1*X2*X3*...*Xn)^ (1/n)
ln(GEOMEAN) = ln((X1*X2*X3*...*Xn)^ (1/n))
ln(GEOMEAN) = (1/n) * ln(X1*X2*X3*...*Xn)
ln(GEOMEAN) = (1/n) * (ln(X1)+ln(X2)+ln(X3)+...+ln(Xn))
ln(GEOMEAN) = average(ln(X1)+ln(X2)+ln(X3)+...+ln(Xn))
GEOMEAN = exp(average(ln(X1)+ln(X2)+ln(X3)+...+ln(Xn)))

If you follow through the above, you see that GEOMEAN is equivalent to the exponent of the average of the logs of the values. You can calculate the desired result by using the following array formula instead of the GEOMEAN function:

=EXP(AVERAGE(LN(A1:A3500)))

This assumes that the desired values are in the range A1:A3500. Since it is an array formula, you must enter it into a cell by using Ctrl+Shift+Enter.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9328) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Using GEOMEAN with a Large List.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Replacing Two Tabs with a Space in Limited Situations

The Find and Replace feature of Word is very powerful, allowing you to finely target exactly what you want to search. ...

Discover More

Displaying the "Last Modified" Date

Want to know when a workbook was last modified? Want to put that date within the header of your worksheet? Here's how to ...

Discover More

Splitting Cells to Individual Columns

When you are working with data created by other systems or other people, you often need to convert the data into ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Cleaning Text

You can use the CLEAN worksheet function to remove any non-printable characters from a cell. This can come in handy when ...

Discover More

Ignoring Special Characters in COUNTIF

The COUNTIF function can be very handy when searching a range of cells for values. In some instances, though, it can ...

Discover More

Leaving a Cell Value Unchanged If a Condition Is False

Ever want the IF function to only return a value if the condition it is testing is true, and not if the condition is ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is seven less than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.