Calculating the Median Age of a Group of People

Written by Allen Wyatt (last updated January 1, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


1

Jan has a worksheet that has a list of ages in column A. The ages start at 1 and go through to 100. In column B she has the number of people in each of those ages. Jan needs a formula that will tell her the median age of this group of people.

At first blush you might think that you can use the MEDIAN function to calculate the median. That function works great if you have a simple list of values. For instance, if you were calculating the median for the ages alone, then MEDIAN would work fine. However, in Jan's case she needs the median value for the ages of the people, not for the ages themselves. In other words, the median needs to be weighted by the number of people that are each age. The MEDIAN function cannot handle such a requirement.

It should be pointed out that the median age is going to be different than the average age for a group of people. The average can be calculated most easily by multiplying the age by the number of people that is each age. For instance, in column C you could place a formula such as =A1*B1 and then copy it down the column. Add up the values in columns B and C, and then divide the sum in column C by the sum in column B. The result is the average age for the list of people.

The median age, on the other hand, is the age at which half of the people fall below that age and half above that age. The median age can best be calculated by use a formula, such as the following:

=MATCH(SUM($B$1:$B$100)/2,SUMIF($A$1:$A$100,
"<="&$A$1:$A$100,$B$1:$B$100))

This is a single formula (I broke it to two lines for display purposes only). In the version of Excel provided with Microsoft 365, you can just enter the formula in a cell and it works great. In older versions of Excel (IIRC, Excel 2016 and earlier), you'll need to enter the formula as an array formula by pressing Ctrl+Shift+Enter.

The SUMIF function in the formula is used to generate an array of the cumulative number of people who are less than or equal to each age. The SUM portion of the formula gives the midpoint of the total frequency of ages. The MATCH function is then used to look up the midpoint value in the array of cumulative frequencies. This yields an "index number" in the initial array, and since the array consists of the all ages 1 through 100, this index number is equivalent to the median age.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10595) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.

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

Getting Rid of Old Windows Updates

Microsoft is constantly updating Windows for various reasons. For most people, those updates are downloaded and installed ...

Discover More

Paragraph Numbers in Headers or Footers

If your documents routinely use numbered paragraphs, you may want to place the number of the page's first paragraph in ...

Discover More

Blank Page Printing after Table at End of Document

When you print, do you get an extra blank page printed at the end of the document? It could be because of the final ...

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 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Referencing Every Third External Cell

When you enter references to cells in a worksheet, using the Fill Handle to propagate the formulas to other cells can be ...

Discover More

Inserting Dashes between Letters and Numbers

If you need to add dashes between letters and numbers in a string, the work can quickly get tedious. This tip examines ...

Discover More

Calculating the Interval between Occurrences

With a long list of items in a worksheet, you may want to determine the last time a particular item appeared in the list. ...

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 four minus 0?

2022-07-20 21:28:37

Walter Szymanski

What if the list of ages shows no one (that is, a zero) in one or more of the ages? How do you calculate for that? Thank you.


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.