Question about CONCATENATE

Emperor

Board Regular
Joined
Mar 25, 2010
Messages
225
Hi all,

I'm trying to use CONCATENATE for 4 columns.

<TABLE style="WIDTH: 304pt; BORDER-COLLAPSE: collapse" border=0 cellSpacing=0 cellPadding=0 width=405 x:str><COLGROUP><COL style="WIDTH: 72pt; mso-width-source: userset; mso-width-alt: 3510" width=96><COL style="WIDTH: 73pt; mso-width-source: userset; mso-width-alt: 3547" width=97><COL style="WIDTH: 78pt; mso-width-source: userset; mso-width-alt: 3803" width=104><COL style="WIDTH: 81pt; mso-width-source: userset; mso-width-alt: 3949" width=108><TBODY><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver 0.5pt solid; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>17</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver 0.5pt solid; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>2</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver 0.5pt solid; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num="3">03</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver 0.5pt solid; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>120</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>21</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>0</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num>20</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>110</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>42</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>6</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num="1">01</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>110</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>41</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>8</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num="1">01</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>110</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>41</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>8</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num="1">01</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>310</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>41</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>8</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num="1">01</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>311</TD></TR><TR style="HEIGHT: 12pt; mso-height-source: userset" height=16><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver 0.5pt solid; BACKGROUND-COLOR: transparent; WIDTH: 72pt; HEIGHT: 12pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 height=16 width=96 x:num>16</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 73pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl22 width=97 x:num>3</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 78pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl23 width=104 x:num>10</TD><TD style="BORDER-BOTTOM: silver 0.5pt solid; BORDER-LEFT: silver; BACKGROUND-COLOR: transparent; WIDTH: 81pt; BORDER-TOP: silver; BORDER-RIGHT: silver 0.5pt solid" class=xl24 width=108 x:num>420</TD></TR></TBODY></TABLE>
The columns are not saved as numbers, but as 0, 00 or 000 (depending on the amount of numbers) (otherwise the 0's will be deleted)

I would like to CONCATENATE this to get;
17|2|03|120
21|0|20|110
42|6|01|110
etc.

But the problem is when I use CONCATENATE it deletes the zero's in front of the single numbers;
17|2|3|120
21|0|20|110
42|6|1|110

Could somebody help me?

Mathijs.
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Try:

=TEXT(A1,REPT(0,LEN(A1)))&"|"&TEXT(B1,REPT(0,LEN(B1)))&"|"&TEXT(C1,REPT(0,LEN(C1)))&"|"&TEXT(D1,REPT(0,LEN(D1)))
 
Upvote 0
Peter,

Thanks for the clean code. I added the | myself and works really well.

MrKowz, also thanks for the effort!

Mathijs
 
Upvote 0
Peter,

Thanks for the clean code. I added the | myself and works really well.

MrKowz, also thanks for the effort!

Mathijs

Peter's code will work great if you have a consistent length of numbers in each column. The one I supplied will work for any combination of lengths (just wanted to post this explanation for future users who may have a similar requirement and come across this post)

<b>Excel 2007</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><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: #161120;text-align: center;">1</td><td style="text-align: right;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">17</td><td style="text-align: right;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">2</td><td style="text-align: right;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">03</td><td style="text-align: right;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">120</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">17|2|03|120</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">21</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">0005</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">20</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">110</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">21|0005|20|110</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">034</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">6</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">01</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">110</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">034|6|01|110</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">41</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">8</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">01</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">001001</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">41|8|01|001001</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">41</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">8</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">01</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">310</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">41|8|01|310</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">041</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">0008</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">000001</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">0311</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">041|0008|000001|0311</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">16</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">3</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">10</td><td style="text-align: right;border-top: 1px solid black;border-right: 1px solid black;border-bottom: 1px solid black;border-left: 1px solid black;background-color: #EFEFEF;;">420</td><td style="text-align: right;border-left: 1px solid black;;"></td><td style=";">16|3|10|420</td></tr></tbody></table><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style="background-color: #E0E0F0;text-align: center;color: #161120"><th><b>Sheet1</b></th></tr></td></thead></table><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><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: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><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: #E0E0F0;color: #161120">F1</th><td style="text-align:left">=TEXT(<font color="Blue">A1,REPT(<font color="Red">0,LEN(<font color="Green">A1</font>)</font>)</font>)&"|"&TEXT(<font color="Blue">B1,REPT(<font color="Red">0,LEN(<font color="Green">B1</font>)</font>)</font>)&"|"&TEXT(<font color="Blue">C1,REPT(<font color="Red">0,LEN(<font color="Green">C1</font>)</font>)</font>)&"|"&TEXT(<font color="Blue">D1,REPT(<font color="Red">0,LEN(<font color="Green">D1</font>)</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,557
Messages
6,179,508
Members
452,918
Latest member
Davion615

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