Excel- concatenate cells into 1 cell that have a coinciding marker

dhopler625

New Member
Joined
May 23, 2018
Messages
3
Good morning. I have a spreadsheet where I want to find a formula that I can put in a cell that looks at all cells to the right and for each instance where it finds an "x", concatenates the column headers into that cell. For instance in the example below:

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Sites[/TD]
[TD]Site 1[/TD]
[TD]Site 2[/TD]
[TD]Site 3[/TD]
[TD]Site 4[/TD]
[/TR]
[TR]
[TD]Person 1[/TD]
[TD]Site 1, Site 3[/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Person 2[/TD]
[TD]Site 2[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Person 3[/TD]
[TD]Site 2, Site 3, Site 4[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[/TR]
[TR]
[TD]Person 4[/TD]
[TD]Site 1, Site 2[/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

I want to put a formula in the Sites column that produces the above result based on if there's an "x" in the corresponding columns for that row.

Thank you.
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.
Good morning. I have a spreadsheet where I want to find a formula that I can put in a cell that looks at all cells to the right and for each instance where it finds an "x", concatenates the column headers into that cell. For instance in the example below:

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Name[/TD]
[TD]Sites[/TD]
[TD]Site 1[/TD]
[TD]Site 2[/TD]
[TD]Site 3[/TD]
[TD]Site 4[/TD]
[/TR]
[TR]
[TD]Person 1[/TD]
[TD]Site 1, Site 3[/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Person 2[/TD]
[TD]Site 2[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Person 3[/TD]
[TD]Site 2, Site 3, Site 4[/TD]
[TD][/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[/TR]
[TR]
[TD]Person 4[/TD]
[TD]Site 1, Site 2[/TD]
[TD="align: center"]x[/TD]
[TD="align: center"]x[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

I want to put a formula in the Sites column that produces the above result based on if there's an "x" in the corresponding columns for that row.
How many sites do you have in total?
 
Upvote 0
Rick,
Currently I have 21 but as new facilities come on board that number may change.
I do not know how to do what you want in any practical way with a formula for that many columns. Here is a macro that will do what you want though...
Code:
[table="width: 500"]
[tr]
	[td]Sub ConcatSites()
  Dim R As Long, C As Long, LastRow As Long, LastCol As Long, Sites As String
  LastRow = Cells(Rows.Count, "A").End(xlUp).Row
  LastCol = Cells(1, Columns.Count).End(xlToLeft).Column
  For R = 2 To LastRow
    Sites = ""
    For C = 3 To LastCol
      If Cells(R, C) Like "[Xx]" Then Sites = Sites & ", " & Cells(1, C)
    Next
    Cells(R, "B") = Mid(Sites, 3)
  Next
End Sub[/td]
[/tr]
[/table]

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (ConcatSites) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "Yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,313
Members
452,634
Latest member
cpostell

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