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
 

Some videos you may like

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)

Aryatect

Active Member
Joined
Jun 17, 2019
Messages
308
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))
 

StorminASU

New Member
Joined
Aug 9, 2011
Messages
36
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.
 

Aryatect

Active Member
Joined
Jun 17, 2019
Messages
308
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:

StorminASU

New Member
Joined
Aug 9, 2011
Messages
36
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?
 

Aryatect

Active Member
Joined
Jun 17, 2019
Messages
308
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:

Forum statistics

Threads
1,089,299
Messages
5,407,451
Members
403,143
Latest member
CTremblay

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top