If you’re trying to find the most frequent keywords in Google Sheets—especially from a list of blog post titles, product names, or article headlines—you’re in the right place.
In this tutorial, I’ll show you how to extract the most relevant keywords using formulas only (no scripts needed). We’ll also remove common words like “and,” “the,” or “of” so you get a cleaner list of meaningful terms.
Sample Titles
Let’s say you have this list of titles in column A:
Highlight Text Only in Google Sheets
How to Highlight Cells Based on Multiple Conditions in Google Sheets
Highlight All Cells with Formulas in Google Sheets
Highlight Rows When Value Changes in Google Sheets
How to Highlight Cells Based on Expiry Date in Google Sheets
Highlight Cells Containing Special Characters in Google Sheets
How to Highlight Every Nth Row or Column in Google Sheets
Highlight Rows by Issue and Return Status in Google Sheets
The goal is to find the most frequent keywords used across all these titles.
Step 1: Split Titles into Individual Words
In cell C2
, enter this formula:
=ArrayFormula(LOWER(TOCOL(SPLIT(TEXTJOIN(" ", TRUE, A2:A), " "))))
What this does:
- Joins all titles into one string (TEXTJOIN)
- Splits the string into words (SPLIT)
- Arranges them into a single column (TOCOL)
- Converts everything to lowercase (LOWER) so similar words are counted together
This gives you a raw list of all words used in the titles.

Step 2: Remove Common Stop Words
You don’t want words like “and,” “the,” or “in” showing up as top keywords, right?
In cell D2
, paste this formula to create a list of stop words:
=VSTACK("a", "an", "and", "are", "as", "at", "be", "because", "been", "before", "being", "between", "both", "but", "by", "can", "did", "do", "does", "doing", "down", "each", "few", "for", "from", "had", "has", "have", "he", "her", "here", "him", "his", "how", "i", "if", "in", "into", "is", "it", "its", "just", "me", "more", "most", "my", "no", "nor", "not", "of", "off", "on", "once", "only", "or", "other", "our", "out", "over", "own", "same", "she", "so", "some", "than", "that", "the", "their", "them", "then", "there", "these", "they", "this", "those", "through", "to", "too", "under", "until", "up", "very", "was", "we", "were", "what", "when", "where", "which", "while", "who", "whom", "why", "with", "you", "your")
Then in E2
, filter out those stop words:
=FILTER(C2:C, ISNA(XMATCH(C2:C, D2:D)))
Now you have a clean list of useful keywords.

Step 3: Count the Most Frequent Keywords
In F2
, use this formula to find the top 5:
=SORTN(
HSTACK(
UNIQUE(E2:E),
COUNTIF(E2:E, UNIQUE(E2:E))
),
5, 0, 2, FALSE
)
This will return the 5 most frequent keywords in your titles (excluding common stop words). If there are ties at the 5th spot and you want to include them, just replace the 0
with 1
in the formula.

Bonus: All-in-One Formula (No Helper Columns)
Prefer a one-cell solution? Paste this into any empty cell:
=ArrayFormula(LET(
split_titles, LOWER(TOCOL(SPLIT(TEXTJOIN(" ", TRUE, A2:A), " "))),
stop_words, VSTACK("a", "an", "and", "are", "as", "at", "be", "because", "been", "before", "being", "between", "both", "but", "by", "can", "did", "do", "does", "doing", "down", "each", "few", "for", "from", "had", "has", "have", "he", "her", "here", "him", "his", "how", "i", "if", "in", "into", "is", "it", "its", "just", "me", "more", "most", "my", "no", "nor", "not", "of", "off", "on", "once", "only", "or", "other", "our", "out", "over", "own", "same", "she", "so", "some", "than", "that", "the", "their", "them", "then", "there", "these", "they", "this", "those", "through", "to", "too", "under", "until", "up", "very", "was", "we", "were", "what", "when", "where", "which", "while", "who", "whom", "why", "with", "you", "your"),
clean_words, FILTER(split_titles, ISNA(XMATCH(split_titles, stop_words))),
top_keywords, SORTN(HSTACK(UNIQUE(clean_words), COUNTIF(clean_words, UNIQUE(clean_words))), 5, 0, 2, FALSE),
top_keywords
))
This does everything—from splitting and cleaning to counting—in a single step.
Wrapping Up
With just a few formulas, you can find the most frequent keywords in Google Sheets from any list of titles. Whether you’re analyzing blog posts, YouTube videos, or product listings, this approach gives you a clean and quick snapshot of what topics stand out.
Try adjusting the stop word list or the number of top results depending on your data.