Binary search and return all matches as an array

revs92

New Member
Joined
Jul 15, 2023
Messages
7
Office Version
  1. 365
  2. 2021
  3. 2019
  4. 2016
Platform
  1. Windows
The last argument in XLOOKUP allows performing a binary search but XLOOKUP only returns one match.
IF(value=lookup_array,return_array,"") returns all matches in an array but is slow on large lookup ranges/does not do a binary search.

Would anyone know a fomula - or combination of - that both does a binary search on a sorted range and return all matches as an array?

Thanks in advance!
 
I doubt you will find anything faster than Filter, regardless of what type of search you do.
 
Upvote 0

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
I doubt you will find anything faster than Filter, regardless of what type of search you do.
I'm afraid so too, but I'll keep searching a little more. I'll reply to this post if I find anything.
Thank you for your suggestions so far (y)
 
Upvote 0
Not sure how fast this will be, but try
Excel Formula:
=INDEX(range1,SEQUENCE(COUNTIFS(range2,A2),,XMATCH(A2,Range2,0,2))))
 
Upvote 1
Solution
Not sure how fast this will be, but try
Excel Formula:
=INDEX(range1,SEQUENCE(COUNTIFS(range2,A2),,XMATCH(A2,Range2,0,2))))
That's it! Thank you so much Fluff. That formula perfomed about 15 times faster than FILTER in my tests.
Also, I had no idea COUNTIFS would be that fast, and it's apparenytly even faster on sorted ranges.
 
Upvote 0

Forum statistics

Threads
1,223,234
Messages
6,170,891
Members
452,366
Latest member
TePunaBloke

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