Pulling Apart a URL

Written by Allen Wyatt (last updated May 24, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


Jordan has a need to break apart a URL into its components. If the full URL (http://www.xyz.com/business) is in column A, he would like a way to have the main domain (xyz or xyz.com) in column B and the path (business) in column C.

There are multiple ways you can go about solving this issue. If you only need to do this a time or two, it might be easiest to use the Text to Columns tool, available on the Data tab of the ribbon. When you specify how you want the tool to pull the strings apart, indicate that you want it to use the slash (/) as a delimiter. Depending on the way your original URLs are put together, this may require a bit of "cleanup" after the tool is done, but it is quick and easy.

If you do this more often, then you might benefit from using a formula to do the manipulation of the URL. The first task is to pull the domain from the URL, but this is a bit trickier than it sounds. For instance, the URL may start with any number of protocol specifiers (such as http://, https://, ftp://, etc.) or it may not begin with a protocol specifier at all. Plus, you may want to strip off the "www." nomenclature, as some people consider it extraneous. To figure out where the "real" domain starts, you could use this formula in column B:

=IFERROR(FIND("www.",$A1)+4,IFERROR(FIND("://",$A1,1)+3,1))

What it does it to return the position of the first character after "www.", if it is available. If it is not present, then it returns the position of the first character after "://", if it is present. If that is not there, then the number 1 is returned, since the URL doesn't contain any protocol prefix or www.

With that value in column B, you can then start to actually pull out the parts you want. The following, placed in column C, will return the domain, as already described. It essentially returns everything from the character position shown in column B up to the next slash (/).

=MID(A1,B1,IFERROR(FIND("/",A1,B1)-B1,LEN(A1))

If the original URL included "www.xyz.com," then "xyz.com" is returned by the formula. If it contained a different subdomain other than "www" (such as "research.xyz.com"), then the full domain including the subdomain is returned. The IFERROR function is included in case there is no slash (/) after the domain name. (The FIND function returns a #VALUE error if it cannot find the item for which it is looking.)

To pick off the path after the domain, you can use the following formula in column D:

=IFERROR(MID(A1,FIND("/",A1,B1)+1,LEN(A1)),"")

The formula returns everything after the first slash (/) occurring after the domain name. If there is no slash after the domain name, then it returns nothing. (This is, again, thanks to the use of the IFERROR function.)

The key to using the above formulas, again, is the helper column in column B. If you wanted to do away with the need for column B, you would need to replace in the other two formulas all instances of B1 with the formula (without the equal sign) that belongs in B1. That would, of course, make the other two formulas quite long, especially the one noted for column C.

You can, if desired, create a macro that essentially does the same thing, without the need for a helper column. The following example expects you to make a selection and then pulls the parts of the URL out of the cells and places them into the two columns to the right of the selection.

Sub GetURLParts()
    Dim c As Range
    Dim sRaw As String
    Dim J As Integer
    
    For Each c In Selection
        sRaw = c.Text
        J = InStr(sRaw, "://")
        If J > 0 Then sRaw = Mid(sRaw, J + 3)
        If LCase(Left(sRaw, 4)) = "www." Then
            sRaw = Mid(sRaw, 5)
        End If
        J = InStr(sRaw, "/")
        If J > 0 Then
            c.Offset(0, 1) = Left(sRaw, J - 1)
            c.Offset(0, 2) = Mid(sRaw, J + 1)
        Else
            c.Offset(0, 1) = sRaw
            c.Offset(0, 2) = ""
        End If
    Next c
End Sub

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13320) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Spell-checking Uppercase Words

When Word checks the spelling of a document, it can either check or ignore words that are in uppercase letters. Here's ...

Discover More

Changing How Word Presents Your Document

Tired of the old black-on-white text displayed by Word? Depending on your program version, you can configure Word to show ...

Discover More

Ensuring Proper Page Numbers for a Table of Authorities

Automatically create a Table of Authorities entry in your document, and Word might place the necessary field at the wrong ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Generating a Web Page

Want your worksheets to be available to others on the Internet? Excel provides a way you can save your data in HTML ...

Discover More

Can't Use Hyperlinks

Before some features in Excel can function properly, you must have the correct permissions set for the user of the ...

Discover More

Extracting E-mail Addresses from Hyperlinks

If you have a list of hyperlinked e-mail addresses in a worksheet, you may want to extract the addresses from those ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 - 5?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.