+ Reply to Thread
Results 1 to 5 of 5

Too many functions?

  1. #1
    Guy Lydig
    Guest

    Too many functions?

    I have a column of first names that has some blank cells, some with 1 name,
    and some with 2 names. I inserted another column and want to have only
    initials but if the first or second name begin with "Ch" or "Sh", I want the
    "Ch" or "Sh" as the initial.

    My function takes care of:
    Blank cell
    One name and the first two letters are Ch or Sh
    One name and the first two letter are NOT Ch or Sh
    Two names and the first and second names both begin with Sh or Ch
    Two names and the first begins with Ch or Sh but not the second

    Here's where the problem begins:
    There are TWO other possibilities: the second name begins with Ch or Sh but
    not the first OR there are two names and neither begins with Ch or Sh.

    If I pretend there's only ONE other possibility (and put the last bit in the
    If False part of the If function) all is well except that either I will have
    "Ben Bob" as "B. Bo." OR "Ben Charles" as "B. C." depending on how I write
    the last piece.

    I should really be able to add one more piece to the formula to fix this but
    every time I do, the formula sticks. Is there a limitation on the number of
    Find, Mid, etc. functions?

    Here's the formula I used (which ignores the case of only the 2nd of two
    names beginning with "Ch" or "Sh"):
    =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    ",B2)+1,1)&".",LEFT(B2,1)&". "&MID(B2,FIND(" ",B2)+1,1)&".")))))

    I tried to amend it to:
    =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    ",B2)+1,1)&".",IF(AND(FIND(" ",B2),OR((MID(B2,FIND("
    ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,1)&".
    "&MID(B2,FIND(" ",B2)+1,2)&".",LEFT(B2,1)&". "&MID(B2,FIND("
    ",B2)+1,1)&".")))))

    but it's hanging on MID after the last OR.

    I'm stumped. Any ideas why I can't fix this one glitch?

    I'd appreciate any assistance. (I hate to admit defeat and ask but....)
    Sorry for the length of this post.

    TIA

    Guy

  2. #2
    Bernard Liengme
    Guest

    Re: Too many functions?

    You have hit the limit of 7 nested functions (any function, not just IF).
    Generally when one need more than 7 IF conditions the solution is to use
    look-up function. Read help on VLOOKUP and see if you can find a way to use
    it; if not come back for more.
    best wishes
    --
    Bernard V Liengme
    www.stfx.ca/people/bliengme
    remove caps from email

    "Guy Lydig" <[email protected]> wrote in message
    news:[email protected]...
    >I have a column of first names that has some blank cells, some with 1 name,
    > and some with 2 names. I inserted another column and want to have only
    > initials but if the first or second name begin with "Ch" or "Sh", I want
    > the
    > "Ch" or "Sh" as the initial.
    >
    > My function takes care of:
    > Blank cell
    > One name and the first two letters are Ch or Sh
    > One name and the first two letter are NOT Ch or Sh
    > Two names and the first and second names both begin with Sh or Ch
    > Two names and the first begins with Ch or Sh but not the second
    >
    > Here's where the problem begins:
    > There are TWO other possibilities: the second name begins with Ch or Sh
    > but
    > not the first OR there are two names and neither begins with Ch or Sh.
    >
    > If I pretend there's only ONE other possibility (and put the last bit in
    > the
    > If False part of the If function) all is well except that either I will
    > have
    > "Ben Bob" as "B. Bo." OR "Ben Charles" as "B. C." depending on how I write
    > the last piece.
    >
    > I should really be able to add one more piece to the formula to fix this
    > but
    > every time I do, the formula sticks. Is there a limitation on the number
    > of
    > Find, Mid, etc. functions?
    >
    > Here's the formula I used (which ignores the case of only the 2nd of two
    > names beginning with "Ch" or "Sh"):
    > =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    > ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    > ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".",LEFT(B2,1)&". "&MID(B2,FIND(" ",B2)+1,1)&".")))))
    >
    > I tried to amend it to:
    > =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    > ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    > ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".",IF(AND(FIND(" ",B2),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,1)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",LEFT(B2,1)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".")))))
    >
    > but it's hanging on MID after the last OR.
    >
    > I'm stumped. Any ideas why I can't fix this one glitch?
    >
    > I'd appreciate any assistance. (I hate to admit defeat and ask but....)
    > Sorry for the length of this post.
    >
    > TIA
    >
    > Guy




  3. #3
    Biff
    Guest

    Re: Too many functions?

    Dude, what a nightmare! <vbg>

    If these are the possible entries: (as per your other post)

    ........A...............................Result
    S. C..................................S. C.
    Charles.............................Ch.
    Sharlene............................Sh.
    (empty).....................................
    Ben....................................B.
    Ben Charles........................B. Ch.
    Sharlene Charley................Sh. Ch.
    Ben James..........................B. J.
    Charlie Ben........................Ch. B.
    D.......................................D.
    Charlie Sharlie....................Ch. Sh.

    =IF(A11="","",IF(OR(LEFT(A11,2)={"ch","sh"}),LEFT(A11,2)&".",""))&IF(LEN(A11),IF(LEFT(A11,2)<>"ch",IF(LEFT(A11,2)<>"sh",LEFT(A11)&".",""),""),"")&"
    "&IF(ISNUMBER(FIND(" ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)="ch","Ch.",""),"")&IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)="sh","Sh.",""),"")&IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)<>"ch",IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)<>"sh",MID(A11,FIND(" ",A11)+1,1)&".",""),""),""),"")

    What a thing of beauty, eh?

    Watch out for line wrap possibly "disguising" " " as "".

    Biff

    "Guy Lydig" <[email protected]> wrote in message
    news:[email protected]...
    >I have a column of first names that has some blank cells, some with 1 name,
    > and some with 2 names. I inserted another column and want to have only
    > initials but if the first or second name begin with "Ch" or "Sh", I want
    > the
    > "Ch" or "Sh" as the initial.
    >
    > My function takes care of:
    > Blank cell
    > One name and the first two letters are Ch or Sh
    > One name and the first two letter are NOT Ch or Sh
    > Two names and the first and second names both begin with Sh or Ch
    > Two names and the first begins with Ch or Sh but not the second
    >
    > Here's where the problem begins:
    > There are TWO other possibilities: the second name begins with Ch or Sh
    > but
    > not the first OR there are two names and neither begins with Ch or Sh.
    >
    > If I pretend there's only ONE other possibility (and put the last bit in
    > the
    > If False part of the If function) all is well except that either I will
    > have
    > "Ben Bob" as "B. Bo." OR "Ben Charles" as "B. C." depending on how I write
    > the last piece.
    >
    > I should really be able to add one more piece to the formula to fix this
    > but
    > every time I do, the formula sticks. Is there a limitation on the number
    > of
    > Find, Mid, etc. functions?
    >
    > Here's the formula I used (which ignores the case of only the 2nd of two
    > names beginning with "Ch" or "Sh"):
    > =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    > ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    > ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".",LEFT(B2,1)&". "&MID(B2,FIND(" ",B2)+1,1)&".")))))
    >
    > I tried to amend it to:
    > =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    > ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    > ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    > ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".",IF(AND(FIND(" ",B2),OR((MID(B2,FIND("
    > ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,1)&".
    > "&MID(B2,FIND(" ",B2)+1,2)&".",LEFT(B2,1)&". "&MID(B2,FIND("
    > ",B2)+1,1)&".")))))
    >
    > but it's hanging on MID after the last OR.
    >
    > I'm stumped. Any ideas why I can't fix this one glitch?
    >
    > I'd appreciate any assistance. (I hate to admit defeat and ask but....)
    > Sorry for the length of this post.
    >
    > TIA
    >
    > Guy




  4. #4
    Biff
    Guest

    Re: Too many functions?

    One minor glitch:

    Cells that do not contain a space:

    > Charles
    > Sharlene
    > (empty)
    > Ben


    Will return a space concatenated to the end of the string:

    > Charles.............Ch.<sp>
    > Sharlene............Sh.<sp>
    > (empty)..............<sp>
    > Ben....................B.<sp>


    Trying to wrap that whole formula inside TRIM causes a general formula error
    (probably nesting limit).

    Maybe you can find a better way to do this and eliminate that problem. If
    not, maybe you can hide the column this formula is in and use another column
    with the helper formula of:

    =TRIM(A11)

    Biff

    "Biff" <[email protected]> wrote in message
    news:[email protected]...
    > Dude, what a nightmare! <vbg>
    >
    > If these are the possible entries: (as per your other post)
    >
    > .......A...............................Result
    > S. C..................................S. C.
    > Charles.............................Ch.
    > Sharlene............................Sh.
    > (empty).....................................
    > Ben....................................B.
    > Ben Charles........................B. Ch.
    > Sharlene Charley................Sh. Ch.
    > Ben James..........................B. J.
    > Charlie Ben........................Ch. B.
    > D.......................................D.
    > Charlie Sharlie....................Ch. Sh.
    >
    > =IF(A11="","",IF(OR(LEFT(A11,2)={"ch","sh"}),LEFT(A11,2)&".",""))&IF(LEN(A11),IF(LEFT(A11,2)<>"ch",IF(LEFT(A11,2)<>"sh",LEFT(A11)&".",""),""),"")&"
    > "&IF(ISNUMBER(FIND(" ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    > ",A11)),""),2)="ch","Ch.",""),"")&IF(ISNUMBER(FIND("
    > ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    > ",A11)),""),2)="sh","Sh.",""),"")&IF(ISNUMBER(FIND("
    > ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    > ",A11)),""),2)<>"ch",IF(ISNUMBER(FIND("
    > ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    > ",A11)),""),2)<>"sh",MID(A11,FIND(" ",A11)+1,1)&".",""),""),""),"")
    >
    > What a thing of beauty, eh?
    >
    > Watch out for line wrap possibly "disguising" " " as "".
    >
    > Biff
    >
    > "Guy Lydig" <[email protected]> wrote in message
    > news:[email protected]...
    >>I have a column of first names that has some blank cells, some with 1
    >>name,
    >> and some with 2 names. I inserted another column and want to have only
    >> initials but if the first or second name begin with "Ch" or "Sh", I want
    >> the
    >> "Ch" or "Sh" as the initial.
    >>
    >> My function takes care of:
    >> Blank cell
    >> One name and the first two letters are Ch or Sh
    >> One name and the first two letter are NOT Ch or Sh
    >> Two names and the first and second names both begin with Sh or Ch
    >> Two names and the first begins with Ch or Sh but not the second
    >>
    >> Here's where the problem begins:
    >> There are TWO other possibilities: the second name begins with Ch or Sh
    >> but
    >> not the first OR there are two names and neither begins with Ch or Sh.
    >>
    >> If I pretend there's only ONE other possibility (and put the last bit in
    >> the
    >> If False part of the If function) all is well except that either I will
    >> have
    >> "Ben Bob" as "B. Bo." OR "Ben Charles" as "B. C." depending on how I
    >> write
    >> the last piece.
    >>
    >> I should really be able to add one more piece to the formula to fix this
    >> but
    >> every time I do, the formula sticks. Is there a limitation on the number
    >> of
    >> Find, Mid, etc. functions?
    >>
    >> Here's the formula I used (which ignores the case of only the 2nd of two
    >> names beginning with "Ch" or "Sh"):
    >> =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    >> ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    >> ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    >> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    >> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    >> "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    >> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    >> ",B2)+1,1)&".",LEFT(B2,1)&". "&MID(B2,FIND(" ",B2)+1,1)&".")))))
    >>
    >> I tried to amend it to:
    >> =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    >> ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    >> ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    >> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    >> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    >> "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    >> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    >> ",B2)+1,1)&".",IF(AND(FIND(" ",B2),OR((MID(B2,FIND("
    >> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,1)&".
    >> "&MID(B2,FIND(" ",B2)+1,2)&".",LEFT(B2,1)&". "&MID(B2,FIND("
    >> ",B2)+1,1)&".")))))
    >>
    >> but it's hanging on MID after the last OR.
    >>
    >> I'm stumped. Any ideas why I can't fix this one glitch?
    >>
    >> I'd appreciate any assistance. (I hate to admit defeat and ask but....)
    >> Sorry for the length of this post.
    >>
    >> TIA
    >>
    >> Guy

    >
    >




  5. #5
    Biff
    Guest

    Re: Too many functions?

    Ok, this takes care of that concatenated space glitch:

    =IF(A11="","",IF(OR(LEFT(A11,2)={"ch","sh"}),LEFT(A11,2)&".",""))&IF(LEN(A11),IF(LEFT(A11,2)<>"ch",IF(LEFT(A11,2)<>"sh",LEFT(A11)&".",""),""),"")&IF(ISNUMBER(FIND("
    ",A11))," ","")&IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)="ch","Ch.",""),"")&IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)="sh","Sh.",""),"")&IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)<>"ch",IF(ISNUMBER(FIND("
    ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    ",A11)),""),2)<>"sh",MID(A11,FIND(" ",A11)+1,1)&".",""),""),""),"")

    Biff

    "Biff" <[email protected]> wrote in message
    news:[email protected]...
    > One minor glitch:
    >
    > Cells that do not contain a space:
    >
    >> Charles
    >> Sharlene
    >> (empty)
    >> Ben

    >
    > Will return a space concatenated to the end of the string:
    >
    >> Charles.............Ch.<sp>
    >> Sharlene............Sh.<sp>
    >> (empty)..............<sp>
    >> Ben....................B.<sp>

    >
    > Trying to wrap that whole formula inside TRIM causes a general formula
    > error (probably nesting limit).
    >
    > Maybe you can find a better way to do this and eliminate that problem. If
    > not, maybe you can hide the column this formula is in and use another
    > column with the helper formula of:
    >
    > =TRIM(A11)
    >
    > Biff
    >
    > "Biff" <[email protected]> wrote in message
    > news:[email protected]...
    >> Dude, what a nightmare! <vbg>
    >>
    >> If these are the possible entries: (as per your other post)
    >>
    >> .......A...............................Result
    >> S. C..................................S. C.
    >> Charles.............................Ch.
    >> Sharlene............................Sh.
    >> (empty).....................................
    >> Ben....................................B.
    >> Ben Charles........................B. Ch.
    >> Sharlene Charley................Sh. Ch.
    >> Ben James..........................B. J.
    >> Charlie Ben........................Ch. B.
    >> D.......................................D.
    >> Charlie Sharlie....................Ch. Sh.
    >>
    >> =IF(A11="","",IF(OR(LEFT(A11,2)={"ch","sh"}),LEFT(A11,2)&".",""))&IF(LEN(A11),IF(LEFT(A11,2)<>"ch",IF(LEFT(A11,2)<>"sh",LEFT(A11)&".",""),""),"")&"
    >> "&IF(ISNUMBER(FIND(" ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    >> ",A11)),""),2)="ch","Ch.",""),"")&IF(ISNUMBER(FIND("
    >> ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    >> ",A11)),""),2)="sh","Sh.",""),"")&IF(ISNUMBER(FIND("
    >> ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    >> ",A11)),""),2)<>"ch",IF(ISNUMBER(FIND("
    >> ",A11)),IF(LEFT(SUBSTITUTE(A11,LEFT(A11,FIND("
    >> ",A11)),""),2)<>"sh",MID(A11,FIND(" ",A11)+1,1)&".",""),""),""),"")
    >>
    >> What a thing of beauty, eh?
    >>
    >> Watch out for line wrap possibly "disguising" " " as "".
    >>
    >> Biff
    >>
    >> "Guy Lydig" <[email protected]> wrote in message
    >> news:[email protected]...
    >>>I have a column of first names that has some blank cells, some with 1
    >>>name,
    >>> and some with 2 names. I inserted another column and want to have only
    >>> initials but if the first or second name begin with "Ch" or "Sh", I want
    >>> the
    >>> "Ch" or "Sh" as the initial.
    >>>
    >>> My function takes care of:
    >>> Blank cell
    >>> One name and the first two letters are Ch or Sh
    >>> One name and the first two letter are NOT Ch or Sh
    >>> Two names and the first and second names both begin with Sh or Ch
    >>> Two names and the first begins with Ch or Sh but not the second
    >>>
    >>> Here's where the problem begins:
    >>> There are TWO other possibilities: the second name begins with Ch or Sh
    >>> but
    >>> not the first OR there are two names and neither begins with Ch or Sh.
    >>>
    >>> If I pretend there's only ONE other possibility (and put the last bit in
    >>> the
    >>> If False part of the If function) all is well except that either I will
    >>> have
    >>> "Ben Bob" as "B. Bo." OR "Ben Charles" as "B. C." depending on how I
    >>> write
    >>> the last piece.
    >>>
    >>> I should really be able to add one more piece to the formula to fix this
    >>> but
    >>> every time I do, the formula sticks. Is there a limitation on the number
    >>> of
    >>> Find, Mid, etc. functions?
    >>>
    >>> Here's the formula I used (which ignores the case of only the 2nd of two
    >>> names beginning with "Ch" or "Sh"):
    >>> =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    >>> ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    >>> ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    >>> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    >>> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    >>> "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    >>> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    >>> ",B2)+1,1)&".",LEFT(B2,1)&". "&MID(B2,FIND(" ",B2)+1,1)&".")))))
    >>>
    >>> I tried to amend it to:
    >>> =IF(ISBLANK(B2),"",IF(AND(ISERROR(FIND("
    >>> ",B2)),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&".",IF(ISERROR(FIND("
    >>> ",B2)),LEFT(B2,1)&".",IF(AND(FIND("
    >>> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch"),OR((MID(B2,FIND("
    >>> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,2)&".
    >>> "&MID(B2,FIND(" ",B2)+1,2)&".",IF(AND(FIND("
    >>> ",B2),OR(LEFT(B2,2)="Sh",LEFT(B2,2)="Ch")),LEFT(B2,2)&". "&MID(B2,FIND("
    >>> ",B2)+1,1)&".",IF(AND(FIND(" ",B2),OR((MID(B2,FIND("
    >>> ",B2)+1,2)="Ch"),MID(B2,FIND(" ",B2)+1,2)="Sh")),LEFT(B2,1)&".
    >>> "&MID(B2,FIND(" ",B2)+1,2)&".",LEFT(B2,1)&". "&MID(B2,FIND("
    >>> ",B2)+1,1)&".")))))
    >>>
    >>> but it's hanging on MID after the last OR.
    >>>
    >>> I'm stumped. Any ideas why I can't fix this one glitch?
    >>>
    >>> I'd appreciate any assistance. (I hate to admit defeat and ask but....)
    >>> Sorry for the length of this post.
    >>>
    >>> TIA
    >>>
    >>> Guy

    >>
    >>

    >
    >




+ 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