Index/Match for Nonblanks

StorminASU

New Member
Joined
Aug 9, 2011
Messages
36
Hello Everyone,
I'm designing a sheet that is to be used as a tally for a strawman poll before a real vote is held on some projects being considered at my company. Some of these polls will have comments on them when returned. I'd like to list all comments, though most will be blank with no comments.

I have attached a sample of the worksheet, but I cannot get my index/match (I am terrible at this formula base; vlookup is my comfort zone) to return all non-blanks, while ignoring the "Comments" header which is there to facilitate data entry.

Can anyone please help me with this, and maybe the logic of how to understand index/match going forward?

https://docs.google.com/spreadsheets/d/1ljIZb8oNeChFNtQJn8uvtGn5YVup9-RMn5mTKrk2E0Y/edit?usp=sharing
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
Hi,

See if this works for cell Q8

Code:
=INDEX(E24:E323,MATCH(1,INDEX((E24:E323 <> "")*(ISERROR(SEARCH("Comments",E24:E323))),0,0),0))
 
Upvote 0
Hi,

See if this works for cell Q8

Code:
=INDEX(E24:E323,MATCH(1,INDEX((E24:E323 <> "")*(ISERROR(SEARCH("Comments",E24:E323))),0,0),0))

Aryatect,
Thanks so much for your help! The formula in Q8 did pull the first comment, but did not continue pulling other comments below it. The formula simply kept returning the first comment only as I dragged the formula to Q9, Q10, etc. Thanks so much for the great start though, that's way more than I was getting.
 
Upvote 0
Hi,

Try this

Code:
=IFERROR(INDEX($E$25:$E$325,AGGREGATE(15,6,(ROW($E$25:$E$325)-ROW($E$25)+1)/((MATCH($E$25:$E$325,$E$25:$E$325,0)=ROW($E$25:$E$325)-ROW($E$25)+1)*($E$25:$E$325 <> "")*(ISERROR(SEARCH("Comments",$E$25:$E$325)))),ROWS(Q$8:Q8))),"")

in Q8 and copy it down
 
Last edited:
Upvote 0
Hi,

Try this

Code:
=IFERROR(INDEX($E$25:$E$325,AGGREGATE(15,6,(ROW($E$25:$E$325)-ROW($E$25)+1)/((MATCH($E$25:$E$325,$E$25:$E$325,0)=ROW($E$25:$E$325)-ROW($E$25)+1)*($E$25:$E$325 <> "")*(ISERROR(SEARCH("Comments",$E$25:$E$325)))),ROWS(Q$8:Q8))),"")

in Q8 and copy it down

I can't thank you enough Aryatect. Do you recommend any resources to learn how to use this power?
 
Upvote 0
Hi Glad could help :)

I am a big fan of Mike "excelisfun" Girvin. He has a youtube channel by name "excelisfun" with lots of information.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,152
Members
453,021
Latest member
Justyna P

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