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.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
Excel allows you to easily convert values from decimal to other numbering systems, such as hexadecimal. This tip explains ...
Discover MoreNeed to know the character value of the first character in a string? It's easy to do, without using a macro, by using the ...
Discover MoreWant to return more than a value when doing a lookup? Here are a couple of ways to do it by adding an IF clause to your ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments