returning a concatenated text list reflecting non-zero values

pingpong777

New Member
Joined
Apr 6, 2015
Messages
42
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?

[TABLE="width: 384"]
<tbody>[TR]
[TD="width: 64"][/TD]
[TD="width: 64, align: right"]2002[/TD]
[TD="width: 64, align: right"]2003[/TD]
[TD="width: 64, align: right"]2004[/TD]
[TD="width: 64, align: right"]2005[/TD]
[TD="width: 64, align: right"]2006[/TD]
[/TR]
[TR]
[TD]rust[/TD]
[TD="class: xl64, align: right"]1[/TD]
[TD="class: xl63, align: right"]1[/TD]
[TD="class: xl63, align: right"]4[/TD]
[TD="class: xl63, align: right"]4[/TD]
[TD="class: xl63, align: right"]4[/TD]
[/TR]
[TR]
[TD]orange[/TD]
[TD="class: xl65, align: right"]2[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]purple[/TD]
[TD="class: xl65, align: right"]0[/TD]
[TD="align: right"]7[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]pink[/TD]
[TD="class: xl65, align: right"]0[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]1[/TD]
[TD="align: right"]0[/TD]
[/TR]
[TR]
[TD]navy[/TD]
[TD="class: xl65, align: right"]6[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]2[/TD]
[TD="align: right"]3[/TD]
[TD="align: right"]4[/TD]
[/TR]
[TR]
[TD]cyan[/TD]
[TD="class: xl65, align: right"]1[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]0[/TD]
[TD="align: right"]7[/TD]
[TD="align: right"]1[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
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.
 
Upvote 0
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:


Book1
ABCDEF
120022003200420052006
2rust11444
3orange20010
4purple07202
5pink03010
6navy60234
7cyan10071
8
9rust, orange, navy, cyanrust, purple, pinkrust, purple, navyrust, orange, pink, navy, cyanrust, purple, navy, cyan
Sheet581
Cell Formulas
RangeFormula
B9=IF(B2,$A2,"")&IF(B3,", "&$A3,"")&IF(B4,", "&$A4,"")&IF(B5,", "&$A5,"")&IF(B6,", "&$A6,"")&IF(B7,", "&$A7,"")
 
Upvote 0
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]

[Table="width:, class:head"]
[tr=bgcolor:#FFFFFF][td=bgcolor:#5B9BD5]Color[/td][td=bgcolor:#5B9BD5]
2002
[/td][td=bgcolor:#5B9BD5]
2003
[/td][td=bgcolor:#5B9BD5]
2004
[/td][td=bgcolor:#5B9BD5]
2005
[/td][td=bgcolor:#5B9BD5]
2006
[/td][td][/td][td=bgcolor:#70AD47]Attribute[/td][td=bgcolor:#70AD47]Color[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]rust[/td][td=bgcolor:#DDEBF7]
1​
[/td][td=bgcolor:#DDEBF7]
1​
[/td][td=bgcolor:#DDEBF7]
4​
[/td][td=bgcolor:#DDEBF7]
4​
[/td][td=bgcolor:#DDEBF7]
4​
[/td][td][/td][td=bgcolor:#E2EFDA]2002[/td][td=bgcolor:#E2EFDA]rust, orange, navy, cyan[/td][/tr]

[tr=bgcolor:#FFFFFF][td]orange[/td][td]
2​
[/td][td]
0​
[/td][td]
0​
[/td][td]
1​
[/td][td]
0​
[/td][td][/td][td]2003[/td][td]rust, purple, pink, black[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]purple[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
7​
[/td][td=bgcolor:#DDEBF7]
2​
[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
2​
[/td][td][/td][td=bgcolor:#E2EFDA]2004[/td][td=bgcolor:#E2EFDA]rust, purple, navy[/td][/tr]

[tr=bgcolor:#FFFFFF][td]pink[/td][td]
0​
[/td][td]
3​
[/td][td]
0​
[/td][td]
1​
[/td][td]
0​
[/td][td][/td][td]2005[/td][td]rust, orange, pink, navy, cyan[/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]navy[/td][td=bgcolor:#DDEBF7]
6​
[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
2​
[/td][td=bgcolor:#DDEBF7]
3​
[/td][td=bgcolor:#DDEBF7]
4​
[/td][td][/td][td=bgcolor:#E2EFDA]2006[/td][td=bgcolor:#E2EFDA]rust, purple, navy, cyan, black[/td][/tr]

[tr=bgcolor:#FFFFFF][td]cyan[/td][td]
1​
[/td][td]
0​
[/td][td]
0​
[/td][td]
7​
[/td][td]
1​
[/td][td][/td][td][/td][td][/td][/tr]

[tr=bgcolor:#FFFFFF][td=bgcolor:#DDEBF7]black[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
3​
[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
0​
[/td][td=bgcolor:#DDEBF7]
8​
[/td][td][/td][td][/td][td][/td][/tr]
[/table]
 
Last edited:
Upvote 0
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:
Upvote 0
Sorry, got interrupted...

Here's the correct modified version:


Book1
ABCDEF
120022003200420052006
2rust11044
3orange20010
4purple07202
5pink03010
6navy60234
7cyan10071
8
9rust, orange, navy, cyanrust, purple, pinkpurple, navyrust, orange, pink, navy, cyanrust, purple, navy, cyan
Sheet581
Cell Formulas
RangeFormula
B9=SUBSTITUTE(TRIM(IF(B2,$A2&" ","")&IF(B3,$A3&" ","")&IF(B4,$A4&" ","")&IF(B5,$A5&" ","")&IF(B6,$A6&" ","")&IF(B7,$A7,""))," ",", ")
 
Upvote 0
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?
 
Upvote 0
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?
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,177
Members
453,021
Latest member
Justyna P

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