INDEX/MATCH, condense results

virtuosok

Board Regular
Joined
Sep 2, 2020
Messages
209
Office Version
  1. 365
Platform
  1. Windows
Hi,
I have the following formula in cell B4 (which then is pulled down):
Excel Formula:
=INDEX('Pt1'!$B3:$B1000,MATCH("Screen Failure",'Pt1'!C3:C1000,-1))
Capture2.PNG

It looks into another tab which goes as follows:
Capture.PNG

Question: is it possible to skip #N/A output, so that I only have numbers lined up in column B? In other words,
Current output: 1,2,3,#N/A,#N/A,7,#N/A
Desired output: 1,2,3,7,10...
I don't need blank cells (an easy solution which would be possible with IFERROR... "" or conditional formatting); filter is also suboptimal - ideally I'd need an upgraded formula which stacks up all meaningful results into column B.
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
How about
Excel Formula:
=IFERROR(INDEX('Pt1'!$B$3:$B$1000,AGGREGATE(15,6,(ROW('Pt1'!$B$3:$B$1000)-ROW('Pt1'!$B$3)+1)/('Pt1'!$C$3:$C$1000="Screen failure"),ROWS(B$4:B4))),"")
 
Upvote 0
Solution
Awesome! This works!!! THANKS!!!
Is it even possible to take it to the next level by inserting numbers which are not listed on second tab/second screenshot above in column B? In this example, that would be 5 and 8. So that ideal output would be 1,2,3,5,8,10
No condition here needed: if these numbers are missing they would need to be inserted regardless.
 
Upvote 0
Not that I know of for your version of Excel.
 
Upvote 0
Thanks! I'll fix that on the back end then. Appreciate fast and efficient response!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,212,929
Messages
6,110,743
Members
448,295
Latest member
Uzair Tahir Khan

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