Concatenating Strings of texts with set limits to # of characters, and need spaces if characters do not reach limit

Fraser120

New Member
Joined
Jul 13, 2022
Messages
1
Office Version
  1. 365
Platform
  1. Windows
i have strings of text that have limits to how many characters they can be. they also each have a specific location in the entire string that they must begin at.

I need a formula that will concatenate B+C+D+E+F+G+H+I+J. You will see that not all the values in each column are the same length, if they are not I need to add spaces to the end so that the next string of characters when combined, starts at the specific location for that column.

in rows 18,19, and 20 I have manually entered what I require the formula to return for the 3 examples I provided. the red characters correspond with the first character index ( 0=first character, 9=eleventh, T=twenty forth, 4=forty second, A=fifty forth, and so on)

I have set up data validation for the cells, what I need help with is a concatenate formula that will include the necessary amount of spaces following the value if it doesn't exceed the allowed length.
1657733330814.png


1657733371842.png
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
77,914
Office Version
  1. 365
Platform
  1. Windows
Hi & welcome to MrExcel.
You can do that like
Excel Formula:
=B4&REPT(" ",10-LEN(B4))&C4&REPT(" ",13-LEN(C4))&D4&REPT(" ",18-LEN(D4))
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
77,914
Office Version
  1. 365
Platform
  1. Windows
Good spot, now corrected. :)
 

Anthony47

Well-known Member
Joined
Mar 29, 2006
Messages
2,997
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
Didn't understand if the question is now fixed...
I should suggest, in B18:
Excel Formula:
=LET(DataR,B4:J4,LenR,$B$1:$J$1,Rdata,DataR&REPT(" ",MAX(0,LenR-LEN(DataR))),TEXTJOIN("",TRUE,Rdata))
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
77,914
Office Version
  1. 365
Platform
  1. Windows
Slight mod to Anthony47's idea
Excel Formula:
=LET(DataR,B4:J4,LenR,$B$1:$J$1,Rdata,DataR&REPT(" ",LenR-LEN(DataR)),TEXTJOIN("",TRUE,Rdata))
and if you don't have the allowed length in row 1
Excel Formula:
=LET(DataR,B4:J4,LenR,{10,13,18,10,24,10,10,3,18},Rdata,DataR&REPT(" ",LenR-LEN(DataR)),TEXTJOIN("",TRUE,Rdata))
 

Anthony47

Well-known Member
Joined
Mar 29, 2006
Messages
2,997
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
I added MAX(0, etc etc) to cope with possible strings whose lenght be longer then the "allowed lenght"; I didn't tested its effect, but @Fluff did and removed that portion, but now the formula could return the #VALUE! error in that situation.
To avoid that risk, my penultimate proposal is:
Excel Formula:
=LET(DataR,B4:J4,LenR,$B$1:$J$1,Rdata,DataR&REPT(" ",(LenR)),TEXTJOIN("",TRUE,LEFT(Rdata,LenR)))
 

Forum statistics

Threads
1,176,673
Messages
5,904,392
Members
435,089
Latest member
blackstapler

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