Built Formula for Comma-Separated String For Values Equal to "Yes"

Joe4

MrExcel MVP, Junior Admin
Joined
Aug 1, 2002
Messages
74,140
Office Version
  1. 365
Platform
  1. Windows
I have a grid of data that can contain one of three entries: Yes, No, and nothing (empty string).
I need to build a string for each row of values that will return a string of the headers, separated by commas, but only for the columns with "Yes" in them.

So in the image below, the black is my data grid, and the red is my desired result for each row of that grid:

1701803496201.png


I was trying to do it with TEXTJOIN, but it is a little more complicated than that. I could do it rather easily myself with VBA, but am looking for a formulaic solution.

Can anyone assist?
 

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
Try

Excel Formula:
=TEXTJOIN(",",,IF(A2:C2="Yes",$A$1:$C$1,""))
 
Upvote 0
Solution
Wow, I thought I was overlooking something obvious, and I was right! That was easier than I thought!
Thanks!
 
Upvote 0
Np! All in one go

Excel Formula:
=BYROW(IF(A2:C4="Yes",A1:C1,""),LAMBDA(a,TEXTJOIN(",",,a)))
 
Upvote 0
I was going to have a follow-up question, what if the headers in row 1 weren't exactly what you needed in the returned string, how could I tell it which ones to return.
But it was a relatively easy edit to the original formula you posted, i.e.
Excel Formula:
=TEXTJOIN(",",,IF(A2:C2="Yes",{"PHI","PII","PCI"},""))
or to your updated formula:
Excel Formula:
=BYROW(IF(A2:C10="Yes",{"PHI","PII","PCI"},""),LAMBDA(a,TEXTJOIN(",",,a)))
 
  • Like
Reactions: JEC
Upvote 0

Forum statistics

Threads
1,224,821
Messages
6,181,163
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