+ Reply to Thread
Results 1 to 5 of 5

Find first numeric value in text string

  1. #1
    Rbp9ad
    Guest

    Find first numeric value in text string

    I need a formula that returns the account number and only the account number
    from a text string that looks like this.
    BAN 123456 10/1/05-10/31/05
    or
    ACCT 78-910 9/25/05 - 10/26/05
    or
    111213 1415 9/7/05 - 10/6/05
    the formula that I have so far is this.
    =TRIM(MID(TRIM(RRLookup(A9,11)),FIND("9",TRIM(RRLookup(A9,11))),FIND("/",RRLookup(A9,11))-2))
    RRLookup is a custom function that returns text strings like the examples.
    This formula is for an account number that begins with 9.
    I want it to be more general and just start at the first numeric character.
    Is there a way to do this?



  2. #2
    Biff
    Guest

    Re: Find first numeric value in text string

    Hi!

    > BAN 123456 10/1/05-10/31/05
    > ACCT 78-910 9/25/05 - 10/26/05
    > 111213 1415 9/7/05 - 10/6/05


    Where does the account number end in the 3rd example?

    If all strings were like the first 2 this would be relatively easy. If the
    account number always ends before the 2nd space this should not be too
    difficult. Find the 1st digit, find the 2nd space, return everything
    between. But, if some stings might look like this:

    ACCT 111213 1415 9/7/05 - 10/6/05
    BAN 123456 10/1/05-10/31/05
    ACCT 78-910 9/25/05 - 10/26/05
    111213 1415 9/7/05 - 10/6/05
    XX 111213 1415 04 9/7/05 - 10/6/05

    There may be too many variables to consider.

    Biff

    "Rbp9ad" <[email protected]> wrote in message
    news:[email protected]...
    >I need a formula that returns the account number and only the account
    >number from a text string that looks like this.
    > BAN 123456 10/1/05-10/31/05
    > or
    > ACCT 78-910 9/25/05 - 10/26/05
    > or
    > 111213 1415 9/7/05 - 10/6/05
    > the formula that I have so far is this.
    > =TRIM(MID(TRIM(RRLookup(A9,11)),FIND("9",TRIM(RRLookup(A9,11))),FIND("/",RRLookup(A9,11))-2))
    > RRLookup is a custom function that returns text strings like the examples.
    > This formula is for an account number that begins with 9.
    > I want it to be more general and just start at the first numeric
    > character. Is there a way to do this?
    >
    >




  3. #3
    Rbp9ad
    Guest

    Re: Find first numeric value in text string

    The account numbers are quite variable because they are from different
    vendors, but we have many account numbers with each vendor. The account
    number will always start at the first numeric value and end one or two
    spaces before the first / for the date. I want to drop the ACCT or BAN or
    Bill No. that appears in front of these numbers and the dates that are after
    them. If this can not be done then could you explain to me how to return the
    position in a string of the nth occurence of a character so I can write a
    formula for each vendor (Account numbers from the same vendor always have
    the same format).
    "Biff" <[email protected]> wrote in message
    news:%[email protected]...
    > Hi!
    >
    >> BAN 123456 10/1/05-10/31/05
    >> ACCT 78-910 9/25/05 - 10/26/05
    >> 111213 1415 9/7/05 - 10/6/05

    >
    > Where does the account number end in the 3rd example?
    >
    > If all strings were like the first 2 this would be relatively easy. If the
    > account number always ends before the 2nd space this should not be too
    > difficult. Find the 1st digit, find the 2nd space, return everything
    > between. But, if some stings might look like this:
    >
    > ACCT 111213 1415 9/7/05 - 10/6/05
    > BAN 123456 10/1/05-10/31/05
    > ACCT 78-910 9/25/05 - 10/26/05
    > 111213 1415 9/7/05 - 10/6/05
    > XX 111213 1415 04 9/7/05 - 10/6/05
    >
    > There may be too many variables to consider.
    >
    > Biff
    >
    > "Rbp9ad" <[email protected]> wrote in message
    > news:[email protected]...
    >>I need a formula that returns the account number and only the account
    >>number from a text string that looks like this.
    >> BAN 123456 10/1/05-10/31/05
    >> or
    >> ACCT 78-910 9/25/05 - 10/26/05
    >> or
    >> 111213 1415 9/7/05 - 10/6/05
    >> the formula that I have so far is this.
    >> =TRIM(MID(TRIM(RRLookup(A9,11)),FIND("9",TRIM(RRLookup(A9,11))),FIND("/",RRLookup(A9,11))-2))
    >> RRLookup is a custom function that returns text strings like the
    >> examples. This formula is for an account number that begins with 9.
    >> I want it to be more general and just start at the first numeric
    >> character. Is there a way to do this?
    >>
    >>

    >
    >




  4. #4
    Domenic
    Guest

    Re: Find first numeric value in text string

    Maybe...

    =TRIM(MID(A1,MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),(FIND("/"
    ,A1)-3)-(MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A1&"0123456789"))-1)))

    Hope this helps!

    In article <[email protected]>,
    "Rbp9ad" <[email protected]> wrote:

    > I need a formula that returns the account number and only the account number
    > from a text string that looks like this.
    > BAN 123456 10/1/05-10/31/05
    > or
    > ACCT 78-910 9/25/05 - 10/26/05
    > or
    > 111213 1415 9/7/05 - 10/6/05
    > the formula that I have so far is this.
    > =TRIM(MID(TRIM(RRLookup(A9,11)),FIND("9",TRIM(RRLookup(A9,11))),FIND("/",RRLoo
    > kup(A9,11))-2))
    > RRLookup is a custom function that returns text strings like the examples.
    > This formula is for an account number that begins with 9.
    > I want it to be more general and just start at the first numeric character.
    > Is there a way to do this?


  5. #5
    Biff
    Guest

    Re: Find first numeric value in text string

    Try Domenic's suggestion. It looks like it should work.

    >could you explain to me how to return the position in a string of the nth
    >occurence of a character


    Assuming you know how many instances of the character there are:

    Using this string as an example:

    ACCT 111213 1415 9/7/05 - 10/6/05

    =FIND("~",SUBSTITUTE(A1,"/","~",4))

    Returns the position of the 4th "/".

    Basically, what that does is substitutes the nth instance of "/" with "~"
    and uses the "~" as a "unique marker" for the Find function. I used the
    tilde character as it's a character that is not likely to appear in the
    string.

    To find out how many instances of any character there are in a string:

    =LEN(A1)-LEN(SUBSTITUTE(A1,"character_to_count",""))

    Biff

    "Rbp9ad" <[email protected]> wrote in message
    news:%[email protected]...
    > The account numbers are quite variable because they are from different
    > vendors, but we have many account numbers with each vendor. The account
    > number will always start at the first numeric value and end one or two
    > spaces before the first / for the date. I want to drop the ACCT or BAN or
    > Bill No. that appears in front of these numbers and the dates that are
    > after them. If this can not be done then could you explain to me how to
    > return the position in a string of the nth occurence of a character so I
    > can write a formula for each vendor (Account numbers from the same vendor
    > always have the same format).
    > "Biff" <[email protected]> wrote in message
    > news:%[email protected]...
    >> Hi!
    >>
    >>> BAN 123456 10/1/05-10/31/05
    >>> ACCT 78-910 9/25/05 - 10/26/05
    >>> 111213 1415 9/7/05 - 10/6/05

    >>
    >> Where does the account number end in the 3rd example?
    >>
    >> If all strings were like the first 2 this would be relatively easy. If
    >> the account number always ends before the 2nd space this should not be
    >> too difficult. Find the 1st digit, find the 2nd space, return everything
    >> between. But, if some stings might look like this:
    >>
    >> ACCT 111213 1415 9/7/05 - 10/6/05
    >> BAN 123456 10/1/05-10/31/05
    >> ACCT 78-910 9/25/05 - 10/26/05
    >> 111213 1415 9/7/05 - 10/6/05
    >> XX 111213 1415 04 9/7/05 - 10/6/05
    >>
    >> There may be too many variables to consider.
    >>
    >> Biff
    >>
    >> "Rbp9ad" <[email protected]> wrote in message
    >> news:[email protected]...
    >>>I need a formula that returns the account number and only the account
    >>>number from a text string that looks like this.
    >>> BAN 123456 10/1/05-10/31/05
    >>> or
    >>> ACCT 78-910 9/25/05 - 10/26/05
    >>> or
    >>> 111213 1415 9/7/05 - 10/6/05
    >>> the formula that I have so far is this.
    >>> =TRIM(MID(TRIM(RRLookup(A9,11)),FIND("9",TRIM(RRLookup(A9,11))),FIND("/",RRLookup(A9,11))-2))
    >>> RRLookup is a custom function that returns text strings like the
    >>> examples. This formula is for an account number that begins with 9.
    >>> I want it to be more general and just start at the first numeric
    >>> character. Is there a way to do this?
    >>>
    >>>

    >>
    >>

    >
    >




+ 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