Results 1 to 7 of 7
  1. #1
    3 Star Lounger Jimmy-W's Avatar
    Join Date
    Jan 2001
    Location
    Helena, Montana, USA
    Posts
    220
    Thanks
    13
    Thanked 0 Times in 0 Posts

    Reverse first/last names (2003 SP3)

    I have a column (general format) that contains names in the form of John Doe and John A. Doe. I'd like to apply a function or formula to copy (A1) John Doe to (B1) as Doe John, or (A1) John A. Doe to (B1) as Doe John A. The length of the names varies, but there always is a space between the first and last names or between the middle inital and the last names. Thanks!
    JimmyW
    Helena, MT

  2. #2
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Reverse first/last names (2003 SP3)

    Here is one possibility. It is an array formula, i.e. confirm with Ctrl+Shift+Enter instead of just Enter.
    The formula is for B1, you can fill down as far as needed.
    <code>
    =MID(A1,MAX((MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40))+1,40)&" "&LEFT(A1,MAX((MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40))-1)</code>

  3. #3
    3 Star Lounger Jimmy-W's Avatar
    Join Date
    Jan 2001
    Location
    Helena, Montana, USA
    Posts
    220
    Thanks
    13
    Thanked 0 Times in 0 Posts

    Re: Reverse first/last names (2003 SP3)

    Hans, you're a genius! I have no idea of what an array formula is (I'll look it up) or how it worked in this case, but your suggestion worked perfectly, as usual. Thanks!
    JimmyW
    Helena, MT

  4. #4
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Reverse first/last names (2003 SP3)

    See Introducing array formulas in Excel and Array Formulas for some background.

    The formula I posted is a rather convoluted use of array formulas, inspired by Bob Umlas' Array Formulas.

  5. #5
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: Reverse first/last names (2003 SP3)

    Here's a breakdown of the formula:

    ROW($1:$40) returns a list (or array) of numbers 1, 2, ..., 40 (I have assumed that the full names are not longer than 40 characters; you can change the number 40 if desired/necessary.)

    MID(A1,ROW($1:$40),1) returns a list of the individual characters in the value of A1. For example, if A1 is "John A. Doe", this formula returns "J", "o", "h", "n", " ", "A", ".", " ", "D" , "o", "e", "", "", ...

    MID(A1,ROW($1:$40),1)=" " returns a list of TRUE/FALSE values: TRUE if a character in the above list is a space, FALSE otherwise: FALSE, FALSE, FALSE, FALSE, TRUE, FALSE, FALSE, TRUE, FALSE, FALSE, ...

    We now use that TRUE=1 and FALSE=0 in Excel.

    (MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40) multiplies the FALSE/TRUE values with the list of numbers 1, 2, ..., 40. The result is 0, 0, 0, 0, 5, 0, 0, 8, 0, 0, ...

    MAX((MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40)) returns the highest number in the above list, i.e. 8. This is the position of the LAST space in the name. Let's indicate this by P.

    MID(A1,MAX((MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40))+1,40) is equivalent to MID(A1,P+1,40), i.e. the part of A1 to the right of the last space: "Doe".

    LEFT(A1,MAX((MID(A1,ROW($1:$40),1)=" ")*ROW($1:$40))-1) is equivalent to LEFT(A1,P-1), i.e. the part of A1 to the left of the last space: "John A.".

    These two parts are concatenated with a space in between: "Doe John A.

  6. #6
    Silver Lounger
    Join Date
    Jul 2001
    Location
    Ottawa, Ontario, Canada
    Posts
    1,609
    Thanks
    0
    Thanked 1 Time in 1 Post

    Re: Reverse first/last names (2003 SP3)

    Thanks for the superb tutorial Hans. <img src=/S/thumbup.gif border=0 alt=thumbup width=15 height=15>
    Regards
    Don

  7. #7
    2 Star Lounger
    Join Date
    Aug 2004
    Posts
    123
    Thanks
    0
    Thanked 1 Time in 1 Post

    Re: Reverse first/last names (2003 SP3)

    Or try this non-array formula :

    =MID(A1&" "&A1,FIND(" ",A1,ISNUMBER(FIND("&",SUBSTITUTE(A1," ","&",2))-1)*5+1)+1,LEN(A1))

    Regards
    Bosco

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •