Which non-contiguous range contains value?

LloydFinancials

Well-known Member
Joined
Apr 24, 2015
Messages
546
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.
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Try:


Book1
ABCDEF
1-14.73-16.29ValueRow
25006005012
31045.921156.02
Sheet7
Cell Formulas
RangeFormula
F2=AGGREGATE(15,6,ROW(A1:A3)/((A1:A3<=E2)*(E2<=B1:B3)),1)
 
Upvote 0
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)
 
Upvote 0
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:
Upvote 0
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:
Upvote 0
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
 
Upvote 0
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:
Upvote 0
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. :)
 
Upvote 0

Forum statistics

Threads
1,213,494
Messages
6,113,986
Members
448,538
Latest member
alex78

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