How can I return multiple header values in a cell with non-blank criteria?

nabilahms99

New Member
Joined
Apr 23, 2018
Messages
3
[FONT=q_serif]Here is the table to help you understand the problem.

[/FONT]
r18BGAIDILINIWJTQG
ABU-KOE14
AEG-KNO7
AMQ-BXB1
AMQ-CGK1435147
RoutesCompetitor
ABU-KOEIW
AMQ-CGKGA, ID, JT, QG

<tbody>
</tbody>
[FONT=q_serif]
What formula should I use to get the result like those in “Competitor” column?[/FONT]
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
Hello,

Alright i think i went overboard on your solution lol but it works

First paste this code into a module in the VBA editor

Code:
Public Function Nabilah(route_name As String, route_search As Range, header_range As Range)
Dim r, q As Range
Dim route As String
Dim r_row As Integer
Nabilah = ""
r_row = Application.WorksheetFunction.Match(route_name, route_search, 0) + 1
Set r = header_range
For Each q In r
    If Not q.Offset(r_row - 1, 0) = "" Then
        Nabilah = Nabilah + "," + q.Text
    End If
Next
Nabilah = Right(Nabilah, Len(Nabilah) - 1)
End Function

then go to your cell where you want your result and type this

=Nabilah(A13,A2:A5,B1:I1)

This is assuming your cell with value "r1" is at cell A1 and your Routes and Competitor headers are in cells A12 and B12 respectively

these were my results

ABU-KOEIW
AMQ-CGKGA,ID,JT,QG

<tbody>
</tbody>
 
Last edited:
Upvote 0
Hi!

Maybe the Formulas below can helps.

In C9 and copy down and to the right - use Ctrl+Shift+Enter to enter the formula

=IFERROR(INDEX($B$1:$I$1,SMALL(IF(INDEX($B$2:$I$5,MATCH($A9,$A$2:$A$5,0),)<>"",
COLUMN($B$1:$I$1)-COLUMN($B$1)+1),COLUMNS($C9:C9))),"")


In B9 and copy down - use Enter to entre the formula

=SUBSTITUTE(TRIM(C9&" "&D9&" "&E9&" "&F9&" "&G9&" "&H9&" "&I9&" "&J9)," ",", ")


ABCDEFGHIJK
1r18BGAIDILINIWJTQG
2ABU-KOE14
3AEG-KNO7
4AMQ-BXB1
5AMQ-CGK1435147
6
7
8RoutesCompetitorHelpCol01HelpCol02HelpCol03HelpCol04HelpCol05HelpCol06HelpCol07HelpCol08
9ABU-KOEIWIW
10AEG-KNOIWIW
11AMQ-BXBIWIW
12AMQ-CGKGA, ID, JT, QGGAIDJTQG
13
***********************************************************************************************************

<tbody>
</tbody>

Markmzz
 
Upvote 0

Forum statistics

Threads
1,213,496
Messages
6,113,995
Members
448,539
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