+ Reply to Thread
Results 1 to 11 of 11

How to replace any 7 digit number at a random position in a cell

Hybrid View

  1. #1
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    How to replace any 7 digit number at a random position in a cell

    Hey there,


    I tried to solve my problem by going through an endless number of existing threads but unfortunately nothing I found was quite what I was looking for.


    THE PROBLEM:
    I have a table with cells that contain mostly text in varying length. Somewhere in those cells, every now and then, in the middle of all the text there is one or more 7 digit numbers. I need to replace these numbers with XXXXXXX. Sounds simple, right? But I have no idea how...


    I am sure it is somehow possible with the right combination of IF, MID, LEFT, LOOKUP etc but I just couldn't it figure out.


    HELP!
    Last edited by eskimo; 11-24-2011 at 10:35 AM.

  2. #2
    Forum Expert tigeravatar's Avatar
    Join Date
    03-25-2011
    Location
    Colorado, USA
    MS-Off Ver
    Excel 2003 - 2013
    Posts
    5,361

    Re: How to replace any 7 digit number at a random position in a cell

    eskimo,

    Welcome to the forum!

    To best describe or illustrate your problem you would be better off attaching a dummy workbook, the workbook should contain the same structure and some dummy data of the same type as the type you have in your real workbook - so, if a cell contains numbers & letters in this format abc-123 then that should be reflected in the dummy workbook.

    If needed supply a before and after sheet in the workbook so the person helping you can see what you are trying to achieve.
    Hope that helps,
    ~tigeravatar

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

  3. #3
    Forum Expert darkyam's Avatar
    Join Date
    03-05-2008
    Location
    Houston, TX
    MS-Off Ver
    2013
    Posts
    2,191

    Re: How to replace any 7 digit number at a random position in a cell

    If you're looking for just a few specific sets of numbers, you can use Ctrl+H. If not, it might help to post a dummy workbook letting us know your exact layout. Would the numbers always be 7 digits?
    Life is about perseverance. Remember: today's mighty oak tree is just yesterday's nut that held its ground.

    If you like a post, please rate it with the scales icon (top right).
    If you feel really indebted, please consider a donation to charity, such as Feed the Children or Habitat for Humanity.

  4. #4
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    Re: How to replace any 7 digit number at a random position in a cell

    Hi again, I posted a dummy workbook below.

    The situation is as follows:

    The file contains mostly descriptions of various situations, including different account numbers with 7 digits. I need to make this file anonymous by replacing all the 7 digit account numbers with xxxxxxx. Also, there might be other regular numbers within the text that luckily do not have 7 digits. So the only way to distinguish those account numbers is the 7 digits. Sometimes there might be even 2 or 3 account numbers in one cell but I guess that shouldn't be a problem once the proper formula is used.

    THANKS again for your help!

    Attached Files Attached Files

  5. #5
    Forum Expert tigeravatar's Avatar
    Join Date
    03-25-2011
    Location
    Colorado, USA
    MS-Off Ver
    Excel 2003 - 2013
    Posts
    5,361

    Re: How to replace any 7 digit number at a random position in a cell

    eskimo,

    Attached is a modified version of you sample workbook. It contains a button named "Scrub Numbers". That button is assigned to the following macro:
    Sub tgr()
        
        Dim rngText As Range
        Dim arrText As Variant
        Dim arrTxtPart As Variant
        Dim TextIndex As Long
        Dim PartIndex As Long
        
        Set rngText = Range("A2", Cells(Rows.Count, "A").End(xlUp))
        arrText = Application.Transpose(rngText.Value)
        
        For TextIndex = 1 To UBound(arrText)
            arrTxtPart = Split(arrText(TextIndex), " ")
            For PartIndex = 0 To UBound(arrTxtPart)
                If Len(arrTxtPart(PartIndex)) = 7 And IsNumeric(arrTxtPart(PartIndex)) Then arrText(TextIndex) = Replace(arrText(TextIndex), arrTxtPart(PartIndex), "xxxxxxx")
            Next PartIndex
        Next TextIndex
        
        rngText.Value = Application.Transpose(arrText)
        
    End Sub


    To view macros in a workbook, use keyboard shortcut Alt+F11. The macro will take all 7-digit numbers in column A starting in row 2 (I used row 1 for the header) and replace them with "xxxxxxx"
    Attached Files Attached Files

  6. #6
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: How to replace any 7 digit number at a random position in a cell

    try more func addin then use something like
    =REGEX.SUBSTITUTE(A1," \d{7} "," xxxxxxx ")

    http://download.cnet.com/Morefunc/30...-10423159.html
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  7. #7
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    Re: How to replace any 7 digit number at a random position in a cell

    WOW. It's excel magic. You guys are digital wizards - the good kind.

    Thanks! That saved me hours and hours of work


  8. #8
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    Re: How to replace any 7 digit number at a random position in a cell

    ps: allow me one more question out of sheer curiosity - do you guys think it would have been at all possible to solve this with regular formulas and without a macro?

  9. #9
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    Re: How to replace any 7 digit number at a random position in a cell

    me again

    Unfortunately, I ran into some trouble trying to implement the solution from above.

    It seems this only works as long as the text is no longer than 255 characters per cell. If I copy/type more than 255 characters into one cell I get this error:

    "Run-time error '13':
    Type mismatch"

    Also, the macro currently captures only those 7 digit numbers that have a space before and after and not e.g. the ones that have a comma before or after, like in a listing: "1234567, 2345678, 3456789, ...". Do you think there is a way around this?

    If anybody got any ideas I would appreciate it enormously!

    thankyouthankyouthankyouthankyouthankyouthankyouthankyouthankyouthankyou

  10. #10
    Forum Expert tigeravatar's Avatar
    Join Date
    03-25-2011
    Location
    Colorado, USA
    MS-Off Ver
    Excel 2003 - 2013
    Posts
    5,361

    Re: How to replace any 7 digit number at a random position in a cell

    eskimo,

    The add-in martindwilson suggested should be able to accomodate what you're looking for. If you want to stick with the macro, I made a slight change to compensate for the comma issue. As for the 255 character limit, I'm not sure what's causing that
    Sub tgr()
        
        Dim rngText As Range
        Dim arrText As Variant
        Dim arrTxtPart As Variant
        Dim TextIndex As Long
        Dim PartIndex As Long
        
        Set rngText = Range("A2", Cells(Rows.Count, "A").End(xlUp))
        arrText = Application.Transpose(rngText.Value)
        
        For TextIndex = 1 To UBound(arrText)
            arrTxtPart = Split(Replace(arrText(TextIndex), ",", ""), " ")
            For PartIndex = 0 To UBound(arrTxtPart)
                If Len(arrTxtPart(PartIndex)) = 7 And IsNumeric(arrTxtPart(PartIndex)) Then arrText(TextIndex) = Replace(arrText(TextIndex), arrTxtPart(PartIndex), "xxxxxxx")
            Next PartIndex
        Next TextIndex
        
        rngText.Value = Application.Transpose(arrText)
        
    End Sub

  11. #11
    Registered User
    Join Date
    11-17-2011
    Location
    Zürich
    MS-Off Ver
    Excel 2003
    Posts
    6

    Re: How to replace any 7 digit number at a random position in a cell

    Yes that helps! Though, not being able to solve the 255 digit mystery, I finally got morefunc to run on my excel 2010 and that works perfectly.

    Thanks again to both of you!

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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