Written by Allen Wyatt (last updated December 10, 2020)
This tip applies to Excel 2007, 2010, 2013, and 2016
John has a worksheet that, in column A, has a large number of very long text strings. He needs to individually pull the first 249 characters from each string, placing a single character in each cell to the right of the string.
There are a couple of ways that you can accomplish this task. It is quite easy to do through the use of a simple formula. For instance, if your first text string is in cell A1, put the following formula to its right, in cell B1:
=MID($A1,COLUMN()-1,1)
This formula uses Excel worksheet functions to pull apart the text string. The COLUMN function, in this case, returns the value 2 since the formula is in column B and that is the second column in the worksheet. This value is decremented by 1, and then used as a pointer into the string in cell A1, marking where the extracted character should come from. When you copy this formula right, for however many cells desired, you end up with individual characters from the string, in consecutive order.
Of course, if you have quite a few strings in the worksheet (as John does), then copying this formula over 249 columns and down, say, several hundred rows can make for a very sluggish worksheet. In such situations it may be desirable to use a macro to split apart the strings instead of a formula. The following macro, SplitUp, is one approach to doing the actual tearing apart.
Sub SplitUp() Dim c As Range Dim r As Range Dim sTemp As String Dim z As Integer Set r = Range("A1", Range("A1048576").End(xlUp)) For Each c In r sTemp = Left(c, 249) For z = 1 To Len(sTemp) c.Offset(0, z) = Mid(sTemp, z, 1) Next z Next End Sub
The macro starts by defining a range (r) that consists of all the cells in column A that contain values. The c variable is then used to represent each cell in the range, and the first 249 characters pulled from each cell. A For ... Next loop is then used to pull each character from the string and stuff it into a cell to the right of the string.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12059) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Pulling Apart Characters in a Long String.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
If you have a macro that takes a long time to process a workbook, you might want to continue working in Excel while the ...
Discover MoreOne of the things you can do with macros is to work with disk files. As you do so, you may have a need to create a new ...
Discover MoreGot a macro that you need to run on each of a number of workbooks? Excel provides a number of ways to go about this task, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-04-20 13:32:18
peter livingston
I copied and pasted the sample ( the original one sub splitup), but it only seems to work on Cell A1.
what is the purpose of the line "Set r = Range("A1", Range("A1048576").End(xlUp))" if it does not function against all cells in column "A".
I did try the the one in the comments and it works on all cells that have data ( well to be honest only the cells that have data populate info across the columns, if blanks are populated i have no idea of determining that).
I set watches for all the variables in that original macro "splitup" ( r, c, stemp, z, and even x1up). it only cycles through the first cell 249 times ( actually 250 times as the last one is the one it stops on).
is there a typo in that macro? Others seem to indicate it works, but don't say how many rows it is working for.
2017-04-16 05:46:53
Willy Vanhaelen
@Brian Lair
249 characters was a requirement from John. You can choose any number of characters up to Excel's limit: 16384-1 columns.
2017-04-15 13:23:37
Brian Lair
Great solutions, both the simple formula & the macro! There's one thing I can't figure out about the macro code, though. You said "...and the first 249 characters pulled from each cell" (sTemp = Left(c, 249)). Why is this required? I looked at the Excel specs & limits on support.office.com, and I can't see anything that would require this restriction. Thanks!
2017-04-15 12:41:30
Willy Vanhaelen
This macro (half size) is 5 times faster because it uses an Excel powerfull array formula:
Sub PlitUp()
Dim c As Range, r As Range
Set r = Range("A1", Cells(Rows.Count, 1).End(xlUp))
For Each c In r
c.Offset(0, 1).Resize(1, 249) = Evaluate("IF({1},MID(" & c.Address & ",COLUMN(2:250),1))")
Next c
End Sub
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments