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.

[TABLE="width: 320"]
<colgroup><col width="64" span="5" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl48890, width: 64"]Tool ID[/TD]
[TD="class: xl48891, width: 64"]A[/TD]
[TD="class: xl48890, width: 64"]B[/TD]
[TD="class: xl48890, width: 64"]C[/TD]
[TD="class: xl48890, width: 64"]D[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group1[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group2[/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group3[/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group4[/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group5[/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48892"] [/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
[TR]
[TD="class: xl48890"]Group6[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[TD="class: xl48893"]x[/TD]
[/TR]
</tbody>[/TABLE]

Something like this. The extra kicker is that there are ~100 rows and ~100 columns, so hand writing one big concatenation formula seems daunting.
[TABLE="width: 128"]
<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>[TR]
[TD="class: xl48892, width: 64"]Tool id[/TD]
[TD="class: xl48892, width: 64"]Items[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group1[/TD]
[TD="class: xl48891"]A,B,C,D[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group2[/TD]
[TD="class: xl48891"]C,D[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group3[/TD]
[TD="class: xl48891"]C,D[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group4[/TD]
[TD="class: xl48890"]C,D[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group5[/TD]
[TD="class: xl48890"]D[/TD]
[/TR]
[TR]
[TD="class: xl48891"]Group6[/TD]
[TD="class: xl48890"]A,B,C,D[/TD]
[/TR]
</tbody>[/TABLE]
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
This formula requires function TEXTJOIN, which is part of Excel 2016 only. Properly invoke B11 and then copy down.

ABCDE
Tool IDABCD
Group1xxxx
Group2xx
Group3xx
Group4xx
Group5x
Group6xxxx
Tool idItems
Group1
Group2
Group3
Group4
Group5
Group6

<colgroup><col style="width: 25pxpx"><col><col><col><col><col></colgroup><thead>
</thead><tbody>
[TD="align: center"]1[/TD]

[TD="align: center"]2[/TD]

[TD="align: center"]3[/TD]

[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]4[/TD]

[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]5[/TD]

[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]6[/TD]

[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]7[/TD]

[TD="align: center"]8[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]9[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]10[/TD]

[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]11[/TD]

[TD="bgcolor: #C6E0B4"]A, B, C, D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]12[/TD]

[TD="bgcolor: #C6E0B4"]C, D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]13[/TD]

[TD="bgcolor: #C6E0B4"]C, D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]14[/TD]

[TD="bgcolor: #C6E0B4"]C, D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]15[/TD]

[TD="bgcolor: #C6E0B4"]D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

[TD="align: center"]16[/TD]

[TD="bgcolor: #C6E0B4"]A, B, C, D[/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]
[TD="align: right"][/TD]

</tbody>
Sheet13

[TABLE="width: 85%"]
<tbody>[TR]
[TD]Array Formulas[TABLE="width: 100%"]
<thead>[TR="bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]
[TH="width: 10"]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
</thead><tbody>[TR]
[TH="width: 10, bgcolor: [URL=https://www.mrexcel.com/forum/usertag.php?do=list&action=hash&hash=DAE7F5]#DAE7F5[/URL] "]B11[/TH]
[TD="align: left"]{=TEXTJOIN(", ",1,IF(IF(A11=$A$2:$A$7,$B$2:$E$7,"")="x",$B$1:$E$1,""))}[/TD]
[/TR]
</tbody>[/TABLE]
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try to enter the {} manually yourself[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0

Forum statistics

Threads
1,223,897
Messages
6,175,269
Members
452,628
Latest member
dd2

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