Creating account numbers

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
Hi All,

I have an excel spread sheet that lists all our our customer's business names in column D. I need to do a formula that will create an account number for each customer using the first 5 letters of the business names, excluding special characters, followed by a 4 digit numeric number. EG: A & B Flooring would need to have an account number of ABFLO0001.
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Welcome to the board.

How many special characters do you need to account for? Using your example above and assuming company names start in A2, enter this in B2 and copy down.

=LEFT(SUBSTITUTE(SUBSTITUTE(A2," ",""),"&",""),5)&TEXT(COUNTIF($B$1:B1,LEFT(SUBSTITUTE(SUBSTITUTE(A2," ",""),"&",""),5)&"*")+1,"0000")
 
Upvote 0
I have an excel spread sheet that lists all our our customer's business names in column D. I need to do a formula that will create an account number for each customer using the first 5 letters of the business names, excluding special characters, followed by a 4 digit numeric number. EG: A & B Flooring would need to have an account number of ABFLO0001.
What determines what the 4-digit number should be?
 
Upvote 0
Maybe

=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(A1," ",""),"&",""),5))&TEXT(ROW(A1),"000#")
 
Upvote 0
bbott that worked perfectly! Thank you so much! One quick questions, where/can I add UPPER into the formula somewhere?
 
Upvote 0
Like so:

=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(A2," ",""),"&",""),5))&TEXT(COUNTIF($B$1:B1,LEFT(SUBSTITUTE(SUBSTITUTE(A2," ",""),"&",""),5)&"*")+1,"0000")

But be aware that this formula will only account for ampersands. Any other special characters would be included.
 
Upvote 0
Hi Rick, in theory, I need it to change if that exact combo is already used...so...if I have 5 business that start with CARPE, it would need to recognize and change from CARPE0001; CARPE0002; CARPE0003. Possible?
 
Upvote 0
Thank you, bbott. I was able to include ' & - based off of your original post (though I'm still learning, so it did take me a second lol) :)
 
Upvote 0

Forum statistics

Threads
1,214,784
Messages
6,121,535
Members
449,037
Latest member
tmmotairi

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