returning a concatenated text list reflecting non-zero values

pingpong777

New Member
Joined
Apr 6, 2015
Messages
41
Hi. I have a data set that is annual values for various colors. For each of these colors, in any year the value will be 0 or greater. For each year, I would like to have a cell list all the colors that are non-zero for that year. For instance, for the table below (apologies for formatting), 2002 would read "rust, orange, navy, cyan", 2003 would read "rust, purple, pink", and so on. Is there an elegant way to do this in a single cell for each year, or am I stuck building a 2-3 step process?

20022003200420052006
rust11444
orange20010
purple07202
pink03010
navy60234
cyan10071

<tbody>
</tbody>
 
Last edited:

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,975
Office Version
  1. 2016
Platform
  1. Windows
Maybe this macro does what you want...
Code:
[table="width: 500"]
[tr]
	[td]Sub GetColorsByYear()
  Dim Col As Long
  For Col = 2 To Cells(1, Columns.Count).End(xlToLeft).Column
    Cells(9, Col).Value = Application.Trim(Join(Application.Transpose(Evaluate("IF(" & Cells(2, Col).Resize(6).Address & "=0,"""",A2:A7)"))))
  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 (GetColorsByYear) 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.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows
Hi,

If you have the TEXTJOIN function, available with an Office365 subscription, it should do the job rather easily.

I don't have that function, so this Concatenate method would work, but if you have a rather Long list of Colors, the formula can grow quite large.

This assumes you want the results in the Same Column for the Year, formula copied across:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">2002</td><td style="text-align: right;;">2003</td><td style="text-align: right;;">2004</td><td style="text-align: right;;">2005</td><td style="text-align: right;;">2006</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">rust</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;">4</td><td style="text-align: right;;">4</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">orange</td><td style="text-align: right;;">2</td><td style="text-align: right;;">0</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">purple</td><td style="text-align: right;;">0</td><td style="text-align: right;;">7</td><td style="text-align: right;;">2</td><td style="text-align: right;;">0</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">pink</td><td style="text-align: right;;">0</td><td style="text-align: right;;">3</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style=";">navy</td><td style="text-align: right;;">6</td><td style="text-align: right;;">0</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style=";">cyan</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td><td style="text-align: right;;">0</td><td style="text-align: right;;">7</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">9</td><td style="text-align: right;;"></td><td style=";">rust, orange, navy, cyan</td><td style=";">rust, purple, pink</td><td style=";">rust, purple, navy</td><td style=";">rust, orange, pink, navy, cyan</td><td style=";">rust, purple, navy, cyan</td></tr></tbody></table><p style="width:6.4em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet581</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B9</th><td style="text-align:left">=IF(<font color="Blue">B2,$A2,""</font>)&IF(<font color="Blue">B3,", "&$A3,""</font>)&IF(<font color="Blue">B4,", "&$A4,""</font>)&IF(<font color="Blue">B5,", "&$A5,""</font>)&IF(<font color="Blue">B6,", "&$A6,""</font>)&IF(<font color="Blue">B7,", "&$A7,""</font>)</td></tr></tbody></table></td></tr></table><br />
 

sandy666

Banned - Rules violations
Joined
Oct 24, 2015
Messages
7,499
you can also try PowerQuery

Code:
[SIZE=1]let
    Source = Excel.CurrentWorkbook(){[Name="Table2"]}[Content],
    UnPivot = Table.UnpivotOtherColumns(Source, {"Color"}, "Attribute", "Value"),
    Filter = Table.SelectRows(UnPivot, each ([Value] <> 0)),
    Group = Table.Group(Filter, {"Attribute"}, {{"Count", each _, type table}}),
    List = Table.AddColumn(Group, "Color", each Table.Column([Count],"Color")),
    Extract = Table.TransformColumns(List, {"Color", each Text.Combine(List.Transform(_, Text.From), ", "), type text}),
    RemCols = Table.RemoveColumns(Extract,{"Count"})
in
    RemCols[/SIZE]

Color
2002
2003
2004
2005
2006
AttributeColor
rust
1​
1​
4​
4​
4​
2002rust, orange, navy, cyan
orange
2​
0​
0​
1​
0​
2003rust, purple, pink, black
purple
0​
7​
2​
0​
2​
2004rust, purple, navy
pink
0​
3​
0​
1​
0​
2005rust, orange, pink, navy, cyan
navy
6​
0​
2​
3​
4​
2006rust, purple, navy, cyan, black
cyan
1​
0​
0​
7​
1​
black
0​
3​
0​
0​
8​
 
Last edited:

pingpong777

New Member
Joined
Apr 6, 2015
Messages
41

ADVERTISEMENT

thank you, this makes perfect sense, and there are only 6-7 colors. well done.
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows
Oops, use this modified version of my formula instead, for in cases where the First color is 0 (so it won't produce a result with a leading comma space ", "):

Will post back.
 
Last edited:

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
6,007
Office Version
  1. 2016
Platform
  1. Windows

ADVERTISEMENT

Sorry, got interrupted...

Here's the correct modified version:

<b></b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;">2002</td><td style="text-align: right;;">2003</td><td style="text-align: right;;">2004</td><td style="text-align: right;;">2005</td><td style="text-align: right;;">2006</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">rust</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td><td style="text-align: right;;">4</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">orange</td><td style="text-align: right;;">2</td><td style="text-align: right;;">0</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">purple</td><td style="text-align: right;;">0</td><td style="text-align: right;;">7</td><td style="text-align: right;;">2</td><td style="text-align: right;;">0</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">pink</td><td style="text-align: right;;">0</td><td style="text-align: right;;">3</td><td style="text-align: right;;">0</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style=";">navy</td><td style="text-align: right;;">6</td><td style="text-align: right;;">0</td><td style="text-align: right;;">2</td><td style="text-align: right;;">3</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style=";">cyan</td><td style="text-align: right;;">1</td><td style="text-align: right;;">0</td><td style="text-align: right;;">0</td><td style="text-align: right;;">7</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">9</td><td style="text-align: right;;"></td><td style=";">rust, orange, navy, cyan</td><td style=";">rust, purple, pink</td><td style=";">purple, navy</td><td style=";">rust, orange, pink, navy, cyan</td><td style=";">rust, purple, navy, cyan</td></tr></tbody></table><p style="width:6.4em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet581</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B9</th><td style="text-align:left">=SUBSTITUTE(<font color="Blue">TRIM(<font color="Red">IF(<font color="Green">B2,$A2&" ",""</font>)&IF(<font color="Green">B3,$A3&" ",""</font>)&IF(<font color="Green">B4,$A4&" ",""</font>)&IF(<font color="Green">B5,$A5&" ",""</font>)&IF(<font color="Green">B6,$A6&" ",""</font>)&IF(<font color="Green">B7,$A7,""</font>)</font>)," ",", "</font>)</td></tr></tbody></table></td></tr></table><br />
 

pingpong777

New Member
Joined
Apr 6, 2015
Messages
41
actually, this doesn't quite work. if any year has a 0 value for rust, then the list starts out with a comma. any other suggestions?
 

Rick Rothstein

MrExcel MVP
Joined
Apr 18, 2011
Messages
36,975
Office Version
  1. 2016
Platform
  1. Windows
actually, this doesn't quite work. if any year has a 0 value for rust, then the list starts out with a comma. any other suggestions?

I am guessing you are not interested in the macro solution that I posted in Message #2 , correct?
 

Watch MrExcel Video

Forum statistics

Threads
1,129,573
Messages
5,637,142
Members
416,959
Latest member
Mohzein

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
Top