Formula which uses data from a list with certain identifying codes

sobrien1234

Board Regular
Joined
May 10, 2016
Messages
162
Office Version
  1. 365
Platform
  1. Windows
I have a huge list. In column A there is a unique code that appears randomly several times. In column b in a number. I want a formula that provides me with the median for that unique code (i.e. without having to autofilter than work it ou manually).

For example:
=median(all numbers on column B that have the same number in column A)

Hope that makes sense?

Thanks!!
 

Some videos you may like

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,201
If D1 houses a unique code, in E1 control+shift+enter, not just enter:

=MEDIAN(IF($A$2:$A$1000=$D1,$B$2:$B$1000))

If you want the calculation to take place in column C, in C2 control+shift+enter, not just enter, and copy down:

=MEDIAN(IF($A$2:$A$1000=$A2,$B$2:$B$1000))
 

Tetra201

MrExcel MVP
Joined
Oct 14, 2016
Messages
3,631
Or, if your Excel has the AGGREGATE function, try the following normally-entered formula:

=AGGREGATE(17,6,$B$2:$B$1000/($A$2:$A$1000=$A2),2)
 

Watch MrExcel Video

Forum statistics

Threads
1,122,469
Messages
5,596,316
Members
414,053
Latest member
Dual Showman

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top