Excel Question regarding accounting coding

jerrymoon1

Board Regular
Joined
Nov 15, 2006
Messages
139
Every month the locations that I am responsible for send in their list of cost to accrue. Unfortunately they do not put the coding correctly (its been an uphill battle trying to get them to do it right).

The way they send the coding is 7300.395.55290.5 and it should be 7300395.55290.5

The last digit is optional, so it could also come as 7300.395.55290 and should be 7300395.55290

Any way to have this done with a formula? Unfortunately there are sometimes over 50 lines of data. Thanks.
 

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.
are you basically just wanting to remove the 1st Period???

=SUBSTITUTE(A1,".","",1)
 
Upvote 0
Hi

Give this a try:

Code:
=SUBSTITUTE(TEXT(LEFT(TEXT(SUBSTITUTE(A1,".","")+0,"000000000000\0"),13)+0,"0000000\.00000\.0"),".0","")

EDIT: Nope, mine will fail if there are other instances of .0 in the acct code. A longer and more messy formula could be:

Code:
=IF(RIGHT(TEXT(LEFT(TEXT(SUBSTITUTE(A1,".","")+0,"000000000000\0"),13)+0,"0000000\.00000\.0"),2)=".0",TEXT(SUBSTITUTE(A1,".","")+0,"0000000\.00000"),TEXT(LEFT(TEXT(SUBSTITUTE(A1,".","")+0,"000000000000\0"),13)+0,"0000000\.00000\.0"))

Presumably there is a chance that the acct code comes thru correctly, so the formula needs to allow for this.
 
Upvote 0
This formula worked for me with your examples.

=IF(FIND(".",A1,1)>7,A1,SUBSTITUTE(A1,".","",1))

Richard's looks like it'll likely work no matter how they send the data.
 
Upvote 0

Forum statistics

Threads
1,222,042
Messages
6,163,558
Members
451,844
Latest member
ddnndd1234

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