+ Reply to Thread
Results 1 to 11 of 11

Find Position of a Character in a Cell

  1. #1
    Registered User
    Join Date
    02-07-2013
    Location
    Toronto, Canada
    MS-Off Ver
    Excel 2011
    Posts
    26

    Find Position of a Character in a Cell

    Top of the evening to you all!

    I'm actually a little surprised that I have not seen this question anywhere on here. I am looking to find the position of a character in a cell. In my case, I'm looking for the first instance of a number of 7 or over, but to ignore all zeros.

    For example: 0035375799

    In this case, I would like the cell to return a "4", because the first instance of a 7 or over (disregarding zeros) is at the fourth number.

    Does anyone have any suggestions for what formulae I should be using?

    Thanks a bunch!

  2. #2
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Find Position of a Character in a Cell

    Like this...

    =FIND(7,SUBSTITUTE(A1,0,""))
    Biff
    Microsoft MVP Excel
    Keep It Simple Stupid

    Let's Go Pens. We Want The Cup.

  3. #3
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Find Position of a Character in a Cell

    Ooops!

    I seem to have missed that the requirement is for a number >=7.

    So, that makes it a bit more complicated.

    Try this array formula**:

    =MATCH(TRUE,--MID(SUBSTITUTE(A1,0,""),ROW(INDIRECT("1:"&LEN(SUBSTITUTE(A1,0,"")))),1)>=7,0)


    ** array formulas need to be entered using the key
    combination of CTRL,SHIFT,ENTER (not just ENTER).
    Hold down both the CTRL key and the SHIFT key
    then hit ENTER.

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

    Re: Find Position of a Character in a Cell

    =find("^",substitute(substitute(substitute(substitute(a3,0,""),7,"^"),8,"^"),9,"^"))
    "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

  5. #5
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Find Position of a Character in a Cell

    I like that one!

  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: Find Position of a Character in a Cell

    but yours is more versatile for any number

  7. #7
    Registered User
    Join Date
    02-07-2013
    Location
    Toronto, Canada
    MS-Off Ver
    Excel 2011
    Posts
    26

    Re: Find Position of a Character in a Cell

    That worked beautifully! Thank you!

  8. #8
    Forum Guru AlKey's Avatar
    Join Date
    07-20-2009
    Location
    Lakeland, FL USA
    MS-Off Ver
    Microsoft Office 2010/ Office 365
    Posts
    8,903

    Re: Find Position of a Character in a Cell

    Or this

    =FIND(7,RIGHT(A1,(LEN(SUBSTITUTE(A1,0,"")))))
    If you like my answer please click on * Add Reputation
    Don't forget to mark threads as "Solved" if your problem has been resolved

    "Nothing is so firmly believed as what we least know."
    --Michel de Montaigne

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

    Re: Find Position of a Character in a Cell

    AlKey what happens if there is no 7?

  10. #10
    Forum Guru AlKey's Avatar
    Join Date
    07-20-2009
    Location
    Lakeland, FL USA
    MS-Off Ver
    Microsoft Office 2010/ Office 365
    Posts
    8,903

    Re: Find Position of a Character in a Cell

    Hmm... goofed

    =IFERROR(FIND(7,RIGHT(A1,(LEN(SUBSTITUTE(A1,0,""))))),IFERROR(FIND(8,RIGHT(A1,(LEN(SUBSTITUTE(A1,0,""))))),IFERROR(FIND(9,RIGHT(A1,(LEN(SUBSTITUTE(A1,0,""))))),"")))

  11. #11
    Forum Expert Tony Valko's Avatar
    Join Date
    12-31-2011
    Location
    Pittsburgh
    MS-Off Ver
    2002, 2007:2013
    Posts
    18,890

    Re: Find Position of a Character in a Cell

    You're welcome. Thanks for the feedback!

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Replies: 2
    Last Post: 08-06-2013, 08:49 AM
  2. Replies: 4
    Last Post: 07-14-2012, 07:26 AM
  3. Find last repeated character position from a text string
    By krjoshi in forum Excel Programming / VBA / Macros
    Replies: 2
    Last Post: 11-17-2011, 02:14 PM
  4. Replies: 2
    Last Post: 02-22-2007, 12:42 PM
  5. Find Character Position in String
    By SportsDave in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 05-21-2006, 04:49 PM

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