Help with numbers!

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
Hi all, I'm trying to create a customer database. I got some great help the other day and I'm hoping that someone might be able to help me with a second piece of the puzzle. I was able to create a formula to take the first 5 letters from a customer name and add 4 digits to the end (eg: ALLST0001).

My problem now is that I ended up with 4 accounts with that exact same company acct code. Is there any way to specify to only use "1" once? So that it would show like so:

ALLST0001
ALLST0002
ALLST0003
ALLST0004
ALLCI0001

 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,886
Office Version
  1. 365
Platform
  1. Windows
Hi. Try this with your companies in A2 downwards, it presumes you have headers:

=LEFT(A2,5)&TEXT(COUNTIF($A$2:A2,A2),"0000")
 
Upvote 0

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
Doesn't seem to make that last number change. The formula I am currently using is:

=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(D2," ",""),"&",""),"'",""),"-",""),5)&TEXT(COUNTIF($D$2:D3,LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(A2," ",""),"&",""),"'",""),"-",""),5)&"*")+1,"0000"))

IDK if something can be added to this??? But maybe will help explain what I'm trying to do....?
 
Upvote 0

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,886
Office Version
  1. 365
Platform
  1. Windows
The $D$2:D3 bit needs to say $D$2:D2 and im not sure why you have the +1 unless you want your numbers to start at 2? Aside from that seems to work my end.
 
Upvote 0

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,886
Office Version
  1. 365
Platform
  1. Windows
ADVERTISEMENT
Oh and you have an A2 in there which needs to be D2
 
Upvote 0

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
Ok, adjusted D2. When I take out the +1 it changes all of the numbers to 0000 rather than 0001....but still not increasing as it hits duplicates....
 
Upvote 0

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,886
Office Version
  1. 365
Platform
  1. Windows
ADVERTISEMENT
Can you paste the data you have in column D. Or an appropriate length sample if theres a lot.
 
Upvote 0

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
This is column C and D: (nothing in "A" or "B", they'll actually be deleted once this gets straight)

ALLPR0001 All Pro Carpet
ALLPR0001 All Pro Restoration Inc.
ALLST0001 All Star Flooring
ALLST0001 All State Carpet
ALLST0001 All State Flooring Distributors LP
ALLST0001 All Stiles Inc.
ALLCI0001 All-City Floor Covering Inc.
ALLEN0001 Allen Carpet & Floors
ALLIE0001 Allied Floor Service Inc.
ALLIE0001 Allied Flooring Systems Inc.
ALLIE0001 Allied Tile Mfg Corp.
 
Upvote 0

steve the fish

Well-known Member
Joined
Oct 20, 2009
Messages
8,886
Office Version
  1. 365
Platform
  1. Windows
This is ugly but seems to do it:

=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(D2," ",""),"&",""),"'",""),"-",""),5)&TEXT(SUMPRODUCT(--(UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE($D$2:D2," ",""),"&",""),"'",""),"-",""),5))=UPPER(LEFT(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(D2," ",""),"&",""),"'",""),"-",""),5)))),"0000"))
 
Upvote 0

meredunne

New Member
Joined
Jun 8, 2015
Messages
12
Steve the fish you are my hero! It wasn't pretty to start with, but I think it BEAUTIFUL now!!! :)

Thank you!
 
Upvote 0

Forum statistics

Threads
1,195,588
Messages
6,010,607
Members
441,558
Latest member
lambierules

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