Break up and count concatenated string - text formula

jjobrien03

New Member
Joined
Sep 2, 2014
Messages
41
I have a 5,000 strings formatted as such: (in one cell)

0 0 0 0 0 0 0 12 12 12 12 12 15 15 15 15 18 18 25 25 25 25 25 25 25 100 100 100 100 100 100 100 100

These strings may be as long as 300 unique numbers with spaces in between each number. What I want to do is convert each string to the following format:

0 for 7, 12 for 5, 15 for 4, 18 for 2, 25 for 7, 100

Keeping in mind that both the numbers in between spaces and number of occurrences will be different for each string.

Appreciate any help, am familiar enough with VBA to use that as a solution as well.
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Give this UDF (user defined function) a try...
Code:
[table="width: 500"]
[tr]
	[td]Function ForCount(S As String)
  Dim X As Long, Kys As Variant, Nums() As String
  Nums = Split(S)
  With CreateObject("Scripting.Dictionary")
    For X = 0 To UBound(Nums)
      .Item(Nums(X)) = .Item(Nums(X)) + 1
    Next
    Kys = Split(Join(.keys))
    For X = 1 To .Count
      ForCount = ForCount & ", " & Kys(X - 1) & " for " & .Item(Kys(X - 1))
    Next
  End With
  ForCount = Mid(ForCount, 3)
End Function[/td]
[/tr]
[/table]

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 ForCount just like it was a built-in Excel function. For example,

=ForCount(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.
 
Upvote 0

Forum statistics

Threads
1,223,908
Messages
6,175,307
Members
452,633
Latest member
DougMo

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