Exceljet

Quick, clean, and to the point

Get top level domain (TLD)

Excel formula: Get top level domain (TLD)
Generic formula 
=RIGHT(domain,LEN(domain)-FIND("*",SUBSTITUTE(domain,".","*",LEN(domain)-LEN(SUBSTITUTE(domain,".","")))))
Explanation 

To extract the top level domain (called "TLD")  from a list of domain names or email addresses, you can use a rather complex formula that uses several functions. In the generic form of the formula (above), domain represents a domain or email address in normal "dot" syntax.

In the example, the active cell contains this formula:

=RIGHT(B5,LEN(B5)-FIND("*",SUBSTITUTE(B5,".","*",LEN(B5)-LEN(SUBSTITUTE(B5,".","")))))

How the formula works:

At the core, this formula uses the RIGHT function to extract characters starting from the right.

The other functions in this formula just do one thing: they figure out how many characters need to be extracted.

At a high level, the formula replaces the last dot "." in the domain with an asterisk "*" and then uses FIND to locate the position of the asterisk. Once the position is known, the RIGHT function can extract the TLD.

You may wonder how the formula knows to replace only the last dot? 

This is the clever part of the formula.

The key is this part:

SUBSTITUTE(B5,".","*",LEN(B5)-LEN(SUBSTITUTE(B5,".","")))

which does the actual replacement of the last dot with "*".

The trick is that SUBSTITUTE has a forth (optional) argument that specifies which "instance" of the find text should be replaced. If nothing is supplied for this argument, all instances are replaced. However, if, say the number 2 is supplied, only the second instance is replaced.

So, the formula needs to figure out which instance to replace, which is done here:

LEN(B5)-LEN(SUBSTITUTE(B5,".",""))

The length of the domain without any dots is subtracted from the full length of the domain. The result is the number of dots in the domain.

In the example name in B5, there are two dots in the domain, so the number 2 is used as in the instance number:

SUBSTITUTE(B5," ","*",2)

This replaces only second dot with "*". The name then looks like this:

"www.domain*com"

The FIND function then takes over to figure out exactly where the asterisk is in the text:

FIND("*", "www.domain*com")

The result is 11 (the * is in the 11th position) which is subtracted from the total length of the domain:

LEN(B5)-11

Since the name is 15 characters, we have:

14-11 = 3

Finally, the number 3 is used by RIGHT like so:

=RIGHT(B5,3)

Which results in "com"

So there you have it. That's how this formula extracts only the top level domain from a full domain name or email address.

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting work done in Excel. In this step-by-step training, you'll learn how to use formulas to manipulate text, work with dates and times, lookup values with VLOOKUP and INDEX & MATCH, count and sum with criteria, dynamically rank values, and create dynamic ranges. You'll also learn how to troubleshoot, trace errors, and fix problems. Start building valuable skills with Excel formulas today. Learn more.

I watched a few videos this morning and learned one key thing that will save me hours at work!
Excel foundational video course
Excel Pivot Table video training course
Excel formulas and functions video training course
Excel Shortcuts Video Course
Excel Charts video training course