+ Reply to Thread
Results 1 to 5 of 5

Another casing question

  1. #1
    Forum Contributor
    Join Date
    01-05-2006
    Posts
    113

    Another casing question

    cell C2 imports Last name and suffix in all caps. I need a formula for cell c3 that will convert it to proper casing

    Cell 2 Example:

    SMITH JR
    SMITH SR
    SMITH II
    SMITH III
    SMITH IV
    SMITH MD
    SMITH PHD

    Cell 3 need to convert to:
    Smith Jr
    Smith Sr
    Smith II
    Smith III
    Smith IV
    Smith MD
    Smith PhD

    I can't use the funtion PROPER by itself because it converts II to Ii...etc.

  2. #2
    Valued Forum Contributor
    Join Date
    03-25-2004
    Location
    Boston, MA US
    Posts
    1,094
    Not sure if this is the easiest way but it seemed to work for me. I created a cross-reference table in my sheet for each suffix. Column 1 contains the current imported formats. Column 2 contains what I want it to be.

    Column 1 (J)
    JR
    SR
    IV
    MD
    PHD

    Column 2 (K)
    Jr
    Sr
    IV
    MD
    PhD

    I then entered this formula where I wanted to do my conversion.

    =PROPER(LEFT(A1,FIND(" ",A1)))&VLOOKUP(RIGHT(A1,LEN(A1)-FIND(" ",A1,1)),J1:K11,2,FALSE)

    HTH

    Steve

  3. #3
    Forum Contributor
    Join Date
    01-05-2006
    Posts
    113

    Almost There

    This works when there is a suffix but if the field has no suffix it returns #VALUE!

    For example:

    "SMITH" returns #VALUE!
    "SMITH JR" returns "Smith Jr"

    What do I need to add to this so that it will recognize names without a suffix

  4. #4
    Valued Forum Contributor
    Join Date
    03-25-2004
    Location
    Boston, MA US
    Posts
    1,094
    Again, probably an easier way but this worked.


    =IF(ISERROR(PROPER(LEFT(A3,FIND(" ",A3)))),PROPER(LEFT(A3,LEN(A3))),PROPER(LEFT(A3,FIND(" ",A3)))&VLOOKUP(RIGHT(A3,LEN(A3)-FIND(" ",A3,1)),$J$1:$K$11,2,FALSE))

    One issue with this is if there is a space at the end of the last name but no suffix, it will return the #N/A error. Use the TRIM function to avoid this.

    =IF(ISERROR(PROPER(LEFT(TRIM(A3),FIND(" ",TRIM(A3))))),PROPER(LEFT(A3,LEN(A3))),PROPER(LEFT(A3,FIND(" ",A3)))&VLOOKUP(RIGHT(A3,LEN(A3)-FIND(" ",A3,1)),$J$1:$K$11,2,FALSE))

    Steve

  5. #5
    Forum Contributor
    Join Date
    01-05-2006
    Posts
    113

    Works Great

    Thank you very much

+ 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