Count words in column (with cells having more than 1 word)

goble

New Member
Joined
Oct 7, 2010
Messages
46
Office Version
  1. 2019
Platform
  1. Windows
Hi,

I have a column (data) with words separated by comas. I would like to count how many times the words appear.

I have seen a similar post in this forum where you define the words and then you get the word count. Here I need to get both the list of the words (Column B) and their occurrence (Column C).

Thanks !

DataResult 1Result 2 (Count)
boy,girl,man,womanaunt3
uncle,aunt,fatherboy2
aunt,man,boyfather2
woman,father,auntgirl1
man2
uncle1
woman2
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Assuming your column A data is in cells A2:A5, and "aunt" is in B2, put this formula in cell C2:
Excel Formula:
=SUMPRODUCT(--(ISNUMBER(SEARCH($B2,$A$2:$A$5))))
and copy down.
 
Upvote 0
Hi and thanks @Joe4

However I don't have the list in Column C. I need excel to find the (specific) words and then count them.
 
Upvote 0
Assuming your data is in Column A starting at Row 2 (where Row 1 is assumed to be the headers you show), then this macro will produce the two result lists shown in Columns B and C...
VBA Code:
Sub GetWordsAndCount()
  Dim N As Long, X As Long, Words As Variant, Arr As Variant
  Arr = Range("A2", Cells(Rows.Count, "A").End(xlUp))
  With CreateObject("Scripting.Dictionary")
    For X = 1 To UBound(Arr)
      Words = Split(Arr(X, 1), ",")
      For N = 0 To UBound(Words)
        .Item(Words(N)) = .Item(Words(N)) + 1
      Next
    Next
    Range("B2").Resize(.Count) = Application.Transpose(.Keys)
    Range("C2").Resize(.Count) = Application.Transpose(.Items)
    Range("B2:C2").Resize(.Count).Sort Range("B2")
  End With
End Sub
HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, 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. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (GetWordsAndCount) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and 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
Solution
Thank you !

I'm incredibly amazed by the level of support you provide ! Again thank you so much ! ;)
 
Upvote 0

Forum statistics

Threads
1,214,935
Messages
6,122,337
Members
449,077
Latest member
Jocksteriom

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