Converting number to fixed length field

TheRedCardinal

Active Member
Joined
Jul 11, 2019
Messages
250
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
Hi all,

Not VBA related at this stage but I will be hoping to convert it into VBA in the long run.

I need to convert a number, which will be of indeterminate length, into a text string of fixed length. The length is 14 characters long.

To fill the length, I need to add leading zeros to the start of the number. So far I have come up with this:

[TABLE="width: 500"]
<tbody>[TR]
[TD]Data Cell[/TD]
[TD]B1[/TD]
[/TR]
[TR]
[TD]Value in Data Cell[/TD]
[TD]12345,67[/TD]
[/TR]
[TR]
[TD]Result Cell[/TD]
[TD]C1
[/TD]
[/TR]
[TR]
[TD]Formula in Result Cell[/TD]
[TD]=REPT(0,14-LEN(TEXT(B1,"0.00")))&TEXT(B1,"0.00")[/TD]
[/TR]
</tbody>[/TABLE]


The problem is the result I get include the decimal place (fairly obviously):

00000123456.70


But I can't figure out how to get it without the decimal place:

00000012345670

I can't use LEFT and MID functions because the "." moves around and in fact in case where there is no decimal place, isn't even there.
I have tried formatting the numbers to be two decimal places but while it looks right on the screen: 1234 when formatted to 2 decimal places looks like 1234.00, but converts to 1234, and 1234.5, when formatted to two decimal places looks like 1234.50, but the Text function returns 1234.5.

Thanks!
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Not the most efficient, but does the job...
PHP:
=TEXT(INT(B1)&IF(B1<>INT(B1),RIGHT(ROUND((B1-INT(B1)),2),2),""),"00000000000000")
 
Upvote 0
Hi!

Thanks for that.

It doesn't quite work but this might be because my request was not clear.

When the number has full decimal places, it works fine, so 13663.13 becomes 00000001366313 as expected.

However 10152.00 just becomes 00000000010152 - i.e. the ".00" is ignored.
It should be 00000001015200

Likewise when having an exact 10th in the decimal, I lose all the decimals:

56462.1 becomes 00000000056462.
It should be 00000005646240.
 
Upvote 0
I think you are overcomplicating this unnecessarily.
Just multiply your original number by 100, and zero pad that.
 
Upvote 0
How about = RIGHT("00000000000000" & SUBSTITUTE(A1,".",""), 14) which handles any location of the decimal point.
 
Upvote 0
Mike,

If the entry is truly a numeric entry (maybe with formatting to show decimals):
I need to convert a number, which will be of indeterminate length,

Then your code wouldn't work in this case:
However 10152.00 just becomes 00000000010152 - i.e. the ".00" is ignored.
It should be 00000001015200
Now, if 10152.00 was entered as Text, then it would work...
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,892
Messages
6,175,236
Members
452,621
Latest member
Laura_PinksBTHFT

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