Concatenate and IF Formula

Ryske

New Member
Joined
Mar 22, 2017
Messages
6
Hi Everyone!
Below is the Row 1 is a commodity and in row 2 is the number of pallets. Anything that more than "0" the commodity will appear in "Output" but with "/" as a separator in each commodity, which I do not know what formula would it be? Thanks in advance.

=CONCATENATE(IF(A2>0,"BREAD",""),IF(B2>0,"FROZEN",""),IF(C2>0,"WATER",""),IF(D2>0,"FFV",""))

BREADFROZENWATERFFVTOTALOUTPUT
222511BREAD/FROZEN/WATER/FFV

<tbody>
</tbody>

 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
Welcome to the board Ryske,

How about something like this:

Code:
=CONCATENATE(IF(A2>0,A2&" BREAD/",""),IF(B2>0,B2&" FROZEN/",""),IF(C2>0,C2&" WATER/",""),IF(D2>0,D2&" FFV",""))

I hope this helps!
 
Upvote 0
If you have one of the newer versions of Excel (365 or some 2016), you can use the TEXTJOIN:


=TEXTJOIN("/",TRUE,IF(A2:D2>0,A$1:D$1,""))


or


=TEXTJOIN("/",TRUE,IF(A2:D2>0,A2:D2&" "&A$1:D$1,""))


both confirmed with Control+Shift+Enter.




If not, you can use S.H.A.D.O.'s formula. However, do you care if the result has a trailing "/" ? That will happen if FFV = 0. It would take a longer formula to get around that, something like:

=IF(SUM(A2:D2),SUBSTITUTE(IF(A2>0,"BREAD/","")&IF(B2>0,"FROZEN/","")&IF(C2>0,"WATER/","")&IF(D2>0,"FFV/",""),"/","",COUNTIF(A2:D2,">0")),"")
 
Upvote 0
Hello Eric W, thanks, this helps as well. I have used the first "textjoin" formula and it works perfectly.
To answer your question, FFV should not have "/". I have removed the "/" from FFV, the desired output is achieved. Thanks once again!
 
Upvote 0
Although you have got your answer, here is my way of doing it. Just few modification to the above answers.


Excel 2016
ABCDEF
1BREADFROZENWATERFFVTOTALOUTPUT
2222511BREAD/FROZEN/WATER/FFV/
310269BREAD/WATER/FFV/
442511BREAD/FROZEN/FFV/
Sheet3
Cell Formulas
RangeFormula
F2=CONCATENATE(IF(A2,$A$1&"/",""),IF(B2,$B$1&"/",""),IF(C2,$C$1&"/",""),IF(D2,$D$1&"/",""))



OR


Unknown
ABCDEF
1BREADFROZENWATERFFVTOTALOUTPUT
2222511BREAD/FROZEN/WATER/FFV
310269BREAD/WATER/FFV
442511BREAD/FROZEN/FFV
Sheet3
Cell Formulas
RangeFormula
F2{=TEXTJOIN("/",,IF(A2:D2,$A$1:$D$1,""))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
You can use both formulas,,

1. =CONCATENATE(IF(A2>0,A2&" BREAD/",""),IF(B2>0,B2&" FROZEN/",""),IF(C2>0,C2&" WATER/",""),IF(D2>0,D2&" FFV",""))

2. =
IF(SUM(A2:D2),SUBSTITUTE(IF(A2>0,"$A$1&"/","")&IF(B2>0,"$B$1&"/","")&IF(C2>0,"$C$1&"/","")&IF(D2>0,"$D$1&"/",""),"/","",COUNTIF(A2:D2,">0")),"")


Thanks,
Dinesh Babu K
****** id="cke_pastebin" style="position: absolute; top: 41px; width: 1px; height: 1px; overflow: hidden; left: -1000px;">
=CONCATENATE(IF(A2,$A$1&"/",""),IF(B2,$B$1&"/",""),IF(C2,$C$1&"/",""),IF(D2,$D$1&"/",""))

<tbody>
</tbody>
=CONCATENATE(IF(A2,$A$1&"/",""),IF(B2,$B$1&"/",""),IF(C2,$C$1&"/",""),IF(D2,$D$1&"/",""))

<tbody>
</tbody>
=CONCATENATE(IF(A2,$A$1&"/",""),IF(B2,$B$1&"/",""),IF(C2,$C$1&"/",""),IF(D2,$D$1&"/",""))

<tbody>
</tbody>
=CONCATENATE(IF(A2,$A$1&"/",""),IF(B2,$B$1&"/",""),IF(C2,$C$1&"/",""),IF(D2,$D$1&"/",""))

<tbody>
</tbody>
</body>
 
Upvote 0
Hi,

You can ues both the formulas,

1.
=CONCATENATE(IF(A2>0,A2&" BREAD/",""),IF(B2>0,B2&" FROZEN/",""),IF(C2>0,C2&" WATER/",""),IF(D2>0,D2&" FFV",""))

2.
=IF(SUM(A2:D2),SUBSTITUTE(IF(A2>0,$A$1&"/","")&IF(B2>0,$B$1&"/","")&IF(C2>0,$C$1&"/","")&IF(D2>0,$D$1&"/",""),"/","",COUNTIF(A2:D2,">0")),"")


Thanks,
Dinesh Babu.
 
Upvote 0

Forum statistics

Threads
1,214,591
Messages
6,120,431
Members
448,961
Latest member
nzskater

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