XL: Parsing Names in a Worksheet Without Data Parse in ExcelID: Q72573
|
You can parse data into separate cells by entering formulas into the first row of a worksheet and filling those formulas down. In those cases where using the Data Parse command isn't working properly, and you do not want to write a macro, this may be preferable.
The following example will accept names and parse the names into three
columns (first name, middle initial, last name), skipping the middle
initial column if no middle initial exists.
NOTE: The Microsoft Excel version 3.0 and 4.0 macro add-in, FLATFILE.XLA,
Data Smart Parse command will parse in a similar way, except that it does
not skip any columns.
A1: Mary J. Smith
A2: Joshua Johnston
B1: =SEARCH(" ",A1)
C1: =SEARCH(" ",A1,SEARCH(" ",A1)+1)
D1: =LEFT(A1,B1-1)
E1: =IF(ISERROR(C1)," ",MID(A1,B1+1,C1-B1))
F1: =IF(ISERROR(C1),RIGHT(A1,LEN(A1)-B1),RIGHT(A1,LEN(A1)-C1))
D1: Mary E1: J. F1: Smith
D2: Joshua E2: F2: Johnston
For more information about the Search function, click Contents And Index
on the Help menu, click the Index tab in Excel 97 Help, type the following
text
SEARCH worksheet function
Additional query words: 97 2.00 2.01 2.10 2.20 2.21 3.00 4.00
Keywords :
Version : WINDOWS:2.x,3.x,4.x,5.0,7.0,97
Platform :
Issue type :
Last Reviewed: March 21, 1999