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 return 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 (2580) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Using GEOMEAN with a Large List.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
If you need to count the number of blank cells in a range, the function to use is COUNTBLANK. This tip discusses the ...
Discover MoreExcel allows you to use functions and formulas to analyze your data. One way you can analyze your data is to use the ...
Discover MoreYou can use the COUNTIF function to determine how many cells in a range fit your criteria. One criterion is easy; using ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2016-06-13 15:28:27
Candan
When I tried the function above with a small sample it did not generate a geometric mean value equivalent to the GEOMEAN function in Excel. I believe the problem is that--at least in my version of Excel (2007)-- AVERAGE(LN(A1:A3500)) is not the equivalent of AVERAGE(LN(A1)+LN(A2)+...+LN(3499)+LN(3500)). I therefore calculated the LNs in a new column and then used the formula above, minus the LN part; e.g., =EXP(AVERAGE(B1:B3500)) where the B column values equal LN of the A column values. This generates values that are equivalent to the GEOMEAN function.
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2021 Sharon Parq Associates, Inc.
Comments