Which non-contiguous range contains value?

LloydFinancials

Well-known Member
Joined
Apr 24, 2015
Messages
518
A B
1 (14.73) (16.29)
2 500.00 600.00
3 1,045.92 1,156.02


A is one end of range, B is the other. Formula to determine which range contains the value 501.00 and return the row number. The next list may have 9 rows or more, so cannot enter if statements to check every single row. Formula preferred.
 

Some videos you may like

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
9,912
Try:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;">-14.73</td><td style="text-align: right;;">-16.29</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style=";">Value</td><td style=";">Row</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style="text-align: right;;">500</td><td style="text-align: right;;">600</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;">501</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style="text-align: right;;">1045.92</td><td style="text-align: right;;">1156.02</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet7</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">F2</th><td style="text-align:left">=AGGREGATE(<font color="Blue">15,6,ROW(<font color="Red">A1:A3</font>)/(<font color="Red">(<font color="Green">A1:A3<=E2</font>)*(<font color="Green">E2<=B1:B3</font>)</font>),1</font>)</td></tr></tbody></table></td></tr></table><br />
 

Eric W

MrExcel MVP
Joined
Aug 18, 2015
Messages
9,912
That's because -14.73 is greater than -16.29. The formula works if the lower values are in A, higher values in B. If you don't know what order they'll be in, the formula gets tougher. Like:

=AGGREGATE(15,6,ROW(A1:A3)/((SUBTOTAL(5,OFFSET(A1:B1,ROW(A1:A3)-ROW(A1),0))<=E2)*(E2<=SUBTOTAL(4,OFFSET(A1:B1,ROW(A1:A3)-ROW(A1),0)))),1)
 

LloydFinancials

Well-known Member
Joined
Apr 24, 2015
Messages
518
makes sense, thank you, I can reverse the order
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,209
Office Version
2007
Platform
Windows
Other option:

If you order the data from least to greatest

=SUMPRODUCT((A1:A3<=E2)*(B1:B3>=E2)*ROW(A1:A3))

If not:

=SUMPRODUCT(((A1:A3<=E2)*(B1:B3>=E2)+(A1:A3>=E2)*(B1:B3<=E2))*FILA(A1:A3))

 
Last edited:

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
45,255
Office Version
365
Platform
Windows
If not:

=SUMPRODUCT(((A1:A3<=E2)*(B1:B3>=E2)+(A1:A3>=E2)*(B1:B3<=E2))*FILA(A1:A3))

Hi Dante,

I assume that you are normally translating your formulas from Spanish to English & you missed FILA in that one.
so I assume should be

=SUMPRODUCT(((A1:A3<=E2)*(B1:B3>=E2)+(A1:A3>=E2)*(B1:B3<=E2))*ROW(A1:A3))

@LloydFinancials
With your pairs unsorted and any way around, I think this more concise one should also work for you. It does assume that the value being checked resides in at most one of the column A:B pairs.
If the value does not reside in any of the pairs the formula returns zero, as shown in row 4.

Excel Workbook
ABCDEF
1-14.73-16.29ValueRow
25006005012
31045.921156.02-151
47000
51156.023
65002
Row
 
Last edited:

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
45,255
Office Version
365
Platform
Windows
If you are only interested in row relative to your table then you could try the column F formula below. It is an array formula so should be entered without the {} but confirmed with Ctrl+Shift+Enter, not just Enter. If confirmed correctly, Excel will insert the {}. The formula can then be copied down.

If you prefer to avoid the array-entry then you could try the standard-entry version shown in column G.

In these instances you will see an error, rather than 0, is generated if the value does not occur in any pair.

Excel Workbook
ABCDEFG
3
4-14.73-16.29ValueRow
550060050122
61045.921156.02-1511
7700#N/A#N/A
81156.0233
950022
10
Row
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,209
Office Version
2007
Platform
Windows
Hi Dante,

I assume that you are normally translating your formulas from Spanish to English & you missed FILA in that one.
so I assume should be

=SUMPRODUCT(((A1:A3<=E2)*(B1:B3>=E2)+(A1:A3>=E2)*(B1:B3<=E2))*ROW(A1:A3))
I'm sorry about that. Appreciation is correct. thanks Peter.
 
Last edited by a moderator:

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
45,255
Office Version
365
Platform
Windows
I'm sorry about that. Appreciation is correct. thanks Peter.
No problem. It must be a bit annoying having to translate all the time. :mad:
Do you normally do it manually or use a translator like this?

BTW, I trimmed your quote of my post since you were really only referring to the part about the formula translation, not my other suggestion to the OP. :)
 

Watch MrExcel Video

Forum statistics

Threads
1,102,726
Messages
5,488,521
Members
407,643
Latest member
samerf86

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top