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,".","")))))
Summary 

To extract the top level domain (TLD) (i.e. "com", "net", "org")  from a domain name or email address, you can use a formula based on several text functions: MID, RIGHT, FIND, LEN, and SUBSTITUTE. In the example shown, the formula in  cell C5 is:

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

Note: In the generic form of the formula "domain" represents a domain or email address like "www.domain.com".

Explanation 

In the example, cell C5 contains this formula:

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

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, n:

=RIGHT(B5,n) // n = ??

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

How does the formula know to replace only the last dot? This is the clever part. The key is here:

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

This snippet does the actual replacement of the last dot with an asterisk (*).

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

To figure out which instance to replace, the LEN function is used:

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"

Author 
Dave Bruns

Excel Formula Training

Formulas are the key to getting things done in Excel. In this accelerated 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. Instant access. See details here.

Download 200+ Excel Shortcuts

Get over 200 Excel shortcuts for Windows and Mac in one handy PDF.