How to summarize a text planning grid?

SURFER349

Board Regular
Joined
Feb 22, 2017
Messages
50
So not sure quite what I'm asking here, but seeing if you could give me pointers? Let's say I've got a planning table like this below. I'm trying to think of a way to have a second table that will list each ToolID and a single cell that shows all the 'items' that have X for them, dynamically.

Tool IDABCD
Group1xxxx
Group2 xx
Group3 xx
Group4 xx
Group5 x
Group6xxxx

<colgroup><col width="64" span="5" style="width:48pt"> </colgroup><tbody>
</tbody>

Something like this. The extra kicker is that there are ~100 rows and ~100 columns, so hand writing one big concatenation formula seems daunting.
Tool idItems
Group1A,B,C,D
Group2C,D
Group3C,D
Group4C,D
Group5D
Group6A,B,C,D

<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>
</tbody>
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
This formula requires function TEXTJOIN, which is part of Excel 2016 only. Properly invoke B11 and then copy down.

ABCDE
1Tool IDABCD
2Group1xxxx
3Group2xx
4Group3xx
5Group4xx
6Group5x
7Group6xxxx
8
9
10Tool idItems
11Group1A, B, C, D
12Group2C, D
13Group3C, D
14Group4C, D
15Group5D
16Group6A, B, C, D

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>
Sheet13

Array Formulas
CellFormula
B11{=TEXTJOIN(", ",1,IF(IF(A11=$A$2:$A$7,$B$2:$E$7,"")="x",$B$1:$E$1,""))}

<thead>
</thead><tbody>
</tbody>
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try to enter the {} manually yourself

<tbody>
</tbody>
 
Upvote 0

Forum statistics

Threads
1,216,226
Messages
6,129,605
Members
449,520
Latest member
TBFrieds

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