split characters from numbers

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
Your "need" appears to only separate 1990Norcross and Road with a blank. That doesn't match your "split characters from numbers" statement.
 
Upvote 0
This "ugly" formula will extract the numbers from any string in A1 (then fill down for others):

Code:
=SUMPRODUCT(MID(0&A1, LARGE(INDEX(ISNUMBER(--MID(A1, ROW(INDIRECT("1:"&LEN(A1))), 1)) * ROW(INDIRECT("1:"&LEN(A1))), 0), ROW(INDIRECT("1:"&LEN(A1))))+1, 1) * 10^ROW(INDIRECT("1:"&LEN(A1)))/10)

In your example, it will extract the 1990.

If you have Excel 365, this will do it:

Code:
=TEXTJOIN(, 1, TEXT(MID(A8, ROW($A$1:INDEX($A$1:$A$1000, LEN(A8))), 1), "#;-#;0;"))
 
Last edited:
Upvote 0
Here is a UDF (user defined function) that I think will do what you want...
Code:
Function InsertBlanks(ByVal Text As String) As String
  Dim X As Long
  For X = Len(Text) To 2 Step -1
    If Mid(Text, X - 1, 2) Like "[0-9a-z][A-Z]" Then
      Text = Left(Text, X - 1) & " " & Mid(Text, X)
    End If
  Next
  InsertBlanks = Text
End Function

HOW TO INSTALL UDFs
------------------------------------
If you are new to UDFs, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. You can now use InsertBlanks just like it was a built-in Excel function. For example,

=InsertBlanks(A1)

If you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.xlsm) and answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.
 
  • Like
Reactions: ISY
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,264
Members
448,558
Latest member
aivin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top