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.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
If you need to switch between viewing formulas and viewing the results of those formulas, you'll love the keyboard ...
Discover MoreWhen doing a systematic search for rescue purposes, it isn't unusual to implement what is termed an "expanding square." ...
Discover MoreIf you have a mixture of numbers and letters in a cell, you may be looking for a way to access and use the numeric ...
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 © 2022 Sharon Parq Associates, Inc.
Comments