Find which range a value belongs in

manona

New Member
Joined
Mar 22, 2016
Messages
40
Hello hello,

I'm trying to find a way to return which category a certain value belongs in, based on a range of values.

Basically, in the table below, I'm trying to find the formula of E5, based on the value found in E2. The formula in E5 should be returning 3.

*Important, this example uses a small table, but I'm working with a very long list of values to find the category for, therefore I'm trying to avoid the formula (IF(AND(E2=>B2,E2=<C2)),A2,IF(...

A huge thank you in advance. :)

Manon

ABCDE
1CATEGORYMINMAXVALUE
2101020.2
321020
432030RANGE
543040???

<tbody>
</tbody>
 
Last edited:

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Re: Help: Find which range a value belongs in

If you have a large number of rows, what happens to the E column? Are the MIN and MAX always 10 apart?

Do you mean this:

Code:
=MATCH(E2,B2:B101,1)

On 100 data rows, it's instantaneous. Probably the same for considerably more.
 
Upvote 0
Re: Help: Find which range a value belongs in

Hi kweaver,

Thanks for the reply. Well I have about 100 lines in which column E is the column that has the values to look up, and in column F is where I want the category to be returned.

My min values are in J, max in K. The increments of the range differ at some points (so not always 10 increments).

Hope this answers your question!



If you have a large number of rows, what happens to the E column? Are the MIN and MAX always 10 apart?

Do you mean this:

Code:
=MATCH(E2,B2:B101,1)

On 100 data rows, it's instantaneous. Probably the same for considerably more.
 
Upvote 0
Re: Help: Find which range a value belongs in

Try this

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">CATEGORY</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">MIN</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">MAX</td><td style="background-color:#ffff00; font-weight:bold; "> </td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">VALUE</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="text-align:right; ">1</td><td style="text-align:right; ">0</td><td style="text-align:right; ">10</td><td > </td><td style="text-align:right; ">20.2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="text-align:right; ">2</td><td style="text-align:right; ">10</td><td style="text-align:right; ">20</td><td > </td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="text-align:right; ">3</td><td style="text-align:right; ">20</td><td style="text-align:right; ">30</td><td > </td><td >RANGE</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="text-align:right; ">4</td><td style="text-align:right; ">30</td><td style="text-align:right; ">40</td><td > </td><td style="text-align:right; ">3</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >E5</td><td >=INDEX(A1:A5,MATCH(E2,B1:B5,1))</td></tr></table></td></tr></table>
 
Upvote 0
Re: Help: Find which range a value belongs in

How about:

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:15.21px;" /><col style="width:15.21px;" /><col style="width:15.21px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:10.46px;" /><col style="width:10.46px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td><td >J</td><td >K</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td > </td><td > </td><td > </td><td style="background-color:#ffff00; font-weight:bold; "> </td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">VALUE</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">CATEGORY</td><td > </td><td > </td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">CATEGORY</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">MIN</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">MAX</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">20.2</td><td style="text-align:right; ">3</td><td > </td><td > </td><td style="text-align:right; ">1</td><td style="text-align:right; ">0</td><td style="text-align:right; ">10</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">2</td><td style="text-align:right; ">10</td><td style="text-align:right; ">20</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">3</td><td style="text-align:right; ">20</td><td style="text-align:right; ">30</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td > </td><td style="text-align:right; ">4</td><td style="text-align:right; ">30</td><td style="text-align:right; ">40</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >F2</td><td >=INDEX($I$1:$I$100,MATCH(E2,$J$1:J100,1))</td></tr></table></td></tr></table>
 
Upvote 0
Re: Help: Find which range a value belongs in

Hi DanteAmor,

It worked perfectly, this makes my life much easier, thank you so much! :)

Manon




How about:

ABCDEFGHIJK
1 VALUECATEGORY CATEGORYMINMAX
2 20.23 1010
3 21020
4 32030
5 43040

<colgroup><col style="font-weight:bold; width:30px; "><col style="width:15.21px;"><col style="width:15.21px;"><col style="width:15.21px;"><col style="width:76.04px;"><col style="width:76.04px;"><col style="width:76.04px;"><col style="width:10.46px;"><col style="width:10.46px;"><col style="width:76.04px;"><col style="width:76.04px;"><col style="width:76.04px;"></colgroup><tbody>
</tbody>

CellFormula
F2=INDEX($I$1:$I$100,MATCH(E2,$J$1:J100,1))

<tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
Re: Help: Find which range a value belongs in

I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,606
Messages
6,120,479
Members
448,967
Latest member
visheshkotha

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
Back
Top