+ Reply to Thread
Results 1 to 10 of 10

Sequentially number occurences of a string in a list

  1. #1
    Forum Contributor Cerbera's Avatar
    Join Date
    07-06-2010
    Location
    Rotorua, New Zealand
    MS-Off Ver
    Excel 2007, 2013, 2016 & 365
    Posts
    137

    Smile Sequentially number occurences of a string in a list

    Hi guys,

    I'm just learning the more intricate parts of excel but have been handed a request from a colleague that i'm having difficulty completing.

    They have many lists such as the one below (each with several hundred values):

    AUD001
    AUT001
    AUT001
    AUT001
    AYL001
    BAI001
    BAL001
    BAR001
    BAR001
    BAR001
    BAR001

    They have asked me to create a formula (or macro, etc). that will go through the list and if their is a recurring value increase the number at the end, so in the list above it would be:

    AUD001
    AUT001
    AUT002
    AUT003
    AYL001
    BAI001
    BAL001
    BAR001
    BAR002
    BAR003
    BAR004

    If anyone can help i'd greatly appreciate it.

    Thanks,

    Tim
    Last edited by Cerbera; 07-06-2010 at 01:03 PM.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Need help with a formula

    Welcome to the forum,

    Your post does not comply with Rule 1 of our Forum RULES. Your post title should accurately and concisely describe your problem, not your anticipated solution. Use terms appropriate to a Google search. Poor thread titles, like Please Help, Urgent, Need Help, Formula Problem, Code Problem, and Need Advice will be addressed according to the OP's experience in the forum: If you have less than 10 posts, expect (and respond to) a request to change your thread title. If you have 10 or more posts, expect your post to be locked, so you can start a new thread with an appropriate title.
    To change a Title on your post, click EDIT then Go Advanced and change your title, if 2 days have passed ask a moderator to do it for you.

    PLEASE PM WHEN YOU HAVE DONE THIS AND I WILL DELETE THIS POST
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Contributor Cerbera's Avatar
    Join Date
    07-06-2010
    Location
    Rotorua, New Zealand
    MS-Off Ver
    Excel 2007, 2013, 2016 & 365
    Posts
    137

    Re: Need help with a formula

    After all that i've had "light bulb moment" and have solved it.

    Thanks anyway!

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Need help with a formula

    It would still be nice if you changed your title and posted your solution anyway.

    This would help others in the future looking for similar solution.

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sequentially number occurences of a string in a list

    Okay so you changed the title but no solution....

    ... not sure how you solved it, but this would be one suggestion.

    In an adjacent column enter:

    =IF(COUNTIF(A$1:A1,A1)>1,LEFT(A1,LEN(A1)-1)&COUNTIF(A$1:A1,A1),A1)

    where A1 contains first of your series of codes

    Copy down

    then

    Copy the new column and go to old column and do Edit|Paste Special and select Values.. then you can delete the formula column.

  6. #6
    Forum Contributor Cerbera's Avatar
    Join Date
    07-06-2010
    Location
    Rotorua, New Zealand
    MS-Off Ver
    Excel 2007, 2013, 2016 & 365
    Posts
    137

    Smile Re: Sequentially number occurences of a string in a list

    Hey Mr Moderator,

    Sorry for not posting the solution earlier - they grabbed me to implement it.

    I have to say that your solution is far more elegant than mine! (though it may need an if statement for when the count is greater than 9 else the addition of the count would make the string longer).

    In the column next to the list I put:

    =LEFT(A1,LEN(A1)-3)

    /this was to isolate the three letter code.

    In the next column i put:

    =IF(ROW(A1)=1,1,(IF(C1<>(INDIRECT("C"&ROW(C1)-1)),1,((INDIRECT("D"&ROW(C1)-1))+1))))

    / This was to put "1" if the value of the three letter code was different to the one above, else to add one to the number of the value in the cell above the formula. The use of indirect was to reference the cell above even when you are pasting it in the first row, without ruining the formula for when you copy it down into the cells below.


    The third column was:

    =C1&(IF(D1>9,"0","00")&D1)

    This combined the three letter code with the number from the previous cell, plus either one or two zeros in the middle.

    Like i said yours was a lot more elegant, but mine did the job - so i won't tell them that i could have done it better!

    Thanks for your help mr moderator, i will play about using the countif function - never used it before.

    Cheers,

    Tim
    Last edited by Cerbera; 07-06-2010 at 12:15 PM.

  7. #7
    Forum Contributor Cerbera's Avatar
    Join Date
    07-06-2010
    Location
    Rotorua, New Zealand
    MS-Off Ver
    Excel 2007, 2013, 2016 & 365
    Posts
    137

    Re: Sequentially number occurences of a string in a list

    Have played about with your solution to give:

    =IF(COUNTIF(A$1:A1,A1)>9,LEFT(A1,LEN(A1)-2)&COUNTIF(A$1:A1,A1),IF(COUNTIF(A$1:A1,A1)>1,LEFT(A1,LEN(A1)-1)&COUNTIF(A$1:A1,A1),A1))

    This should work for when there are upto 99 occurences of the same code.

    Thanks again,

    Tim

  8. #8
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sequentially number occurences of a string in a list

    Looking at it again... this one should be much better and allows for up to 999

    =LEFT(A1,3)&TEXT(COUNTIF(A$1:A1,A1),"000")

  9. #9
    Forum Contributor Cerbera's Avatar
    Join Date
    07-06-2010
    Location
    Rotorua, New Zealand
    MS-Off Ver
    Excel 2007, 2013, 2016 & 365
    Posts
    137

    Re: Sequentially number occurences of a string in a list

    Lol,

    Do you think we can get it any better!

    Muchos qudos to the moderator - excellent solution and i've learnt another new thing with the text command.

    Thanks again,

    Tim

    PS How do i mark the problem as solved?

  10. #10
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Sequentially number occurences of a string in a list

    If you want to learn yet another function, you could also use:


    =LEFT(A1,3)&TEXT(COUNTIF(A$1:A1,A1),REPT(0,3))



    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1