Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Pulling a Phone Number with a Known First and Last Name.

Pulling a Phone Number with a Known First and Last Name

Written by Allen Wyatt (last updated July 16, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


4

Kimm has a worksheet that has three columns in it. Column A contains the last name of a person, column B contains the first name, and column C contains the phone number for the individual. If Kimm knows the person's first and last name (say they are in cells F1 and F2, respectively), she wonders what sort of lookup formula she would use to return the phone number for the first person matching that first and last name.

There are actually several different formulas you could use to figure out the phone number. Most of the approaches involve using array formulas, which are always entered in a cell by using Ctrl+Shift+Enter. To make the formulas easier to understand, it is best to work with named ranges. For instance, set up the following names:

  • Select all the last names, in column A, and give them a name such as LNames.
  • Select all the first names, in column B, and give them a name such as FNames.
  • Select all the phone numbers, in column C, and give them a name such as Phones.

Here are a variety of array formulas you could use to find the phone number:

=SUMPRODUCT(--(LNames=F2),--(FNames=F1),Phones)
=INDEX(Phones,MATCH(F1&F2,FNames&LNames,))
=INDEX(Phones,INDEX(MATCH(F1&F2,FNames&LNames,0),))
=OFFSET(C1,MATCH(F1&F2,FNames&LNames,),)

In addition, you can construct an array formula that relies upon the ROW function, as shown here:

=INDEX(Phones,SUMPRODUCT((F1&F2=FNames&LNames)*(ROW(FNames)-1)))
=INDEX(Phones,MIN(IF((FNames=F1)*(LNames=F2),(ROW(Phones)-1))))

If you use this approach (relying upon the ROW function), you may need to adjust the "-1" portion of the formulas to reflect the number of rows that appear before your actual data. In this instance, the row is decremented by one because the first row of the data table consists of the headers for each column; the data itself begins in row 2.

Note that all of the formulas used thus far rely upon combining the first name with the last name in order to make a comparison. This has the chance of running into "false positives" in some instances. For example, let's say that two of the names you have in your data are Thom Astonfield and Thomas Tonfield. Since the case of the letters in the names doesn't matter in these formulas, when you combine first and last names of these individuals, they are exactly the same. Thus, if you are looking for the phone number for Thomas Tonfield and his name appears in the list after Thom Astonfield, then you'll always get Thom's phone number instead of Thomas'.

To get around this potential problem, you may want to include some sort of separator between the first and last name. Using one of the formulas from earlier in the tip, all you would need to do is make an adjustment, as shown here:

=INDEX(Phones,SUMPRODUCT((F1&":"&F2=FNames&":"&LNames)*(ROW(FNames)-1)))

The addition of the colon between the first and last names acts as a separator, eliminating the likelihood of false positives.

You should also realize that if cells F1 and F2 contain a name that doesn't appear in the data at all, the information you get back from the formula will be erroneous. Depending on the variation of the function used, you may get back an actual error condition (such as #N/A or #REF) or you may get back plain wrong data. In those instances where an error condition is returned, you may want to adjust your formula to account for the possibility of not finding a match, in this manner:

=IF(ISERROR(INDEX(Phones,MATCH(F1&":"&F2,FNames&":"&LNames,0))),
"no phone",INDEX(Phones,MATCH(F1&":"&F2,FNames&":"&LNames,0)))

There are some things that you should keep in mind when using these types of formulas. First and foremost, the reliability of the information you get back is going to depend largely on the quality of the information in your data list. If your data has misspellings in it, contains blanks, is sorted in some strange order, or there are multiple entries for the same person, it can affect what the formula returns.

If you aren't too sure about the quality of your data, you may want to simply use Excel's filtering capabilities rather than a formula. Apply an AutoFilter, and you can use the first two columns of your data to pick first and last name. This will then return any phone numbers for the individual you select. It is very simple to do and makes selecting the data you need easy.

Finally, you should realize that there are other approaches you can use to addressing the problem. For instance, you could create a formula that uses the DGET function but doing so would require the addition of a small criteria table to your worksheet or workbook. Since Kimm specified that she couldn't add intermediate results in a worksheet, then an editorial decision was made to not include the DGET function as a solution since it would require the addition of the criteria table.

In addition, if you are comfortable with using macros, you could also create a user-defined function that would examine the data and return the requested phone number. The benefit to using such an approach is that it provides you greater flexibility in processing the information that the function actually returns.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10479) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Pulling a Phone Number with a Known First and Last Name.

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

Problems with Nested Subtotals

If you have a worksheet that has nested subtotals, you may have run across a problem where the subtotals and grand total ...

Discover More

Grouping Records in a Mail Merge

Need to group records in some manner when they are used in a mail merge? It can be frustrating when your records are not ...

Discover More

Letters and Numbers in Page Numbers

A common task is to add page numbers to document headers and footers. If you want those page numbers to include more than ...

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)

Inserting the Workbook Name

Do you want to insert the name of your Excel workbook into a cell? There are a number of ways you can do this, as ...

Discover More

Counting Only Money Winners

If a series of cells contain the amount of money won by individuals, you may want to count the number of individuals who ...

Discover More

Criteria-Based Counting in a Filtered Column

The filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...

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 2 + 2?

2020-12-02 21:46:12

Peter

Another formulaic approach is to use dGet. The only difference in layout to Alan's scenario is that the first and last names are written side by side under headings E1 and F1 that match the column headings in the name list.
This formula gives the matching phone number or #NUM! if there is more than one or no matches.

=DGET(A1:C11,"Phone",E1:F2)

The word "Phone" can be substituted with 3 or C1 to represent that column. Each column has to have a heading. In this case the list of names and numbers fills the range A1:C11.

For a non-formulaic approach, you may be use an autofilter over columns A and B. When you will need to enter a name in the Search box if it is not immediately obvious in the list.


2020-12-01 03:04:13

Alex Blakenburg

If you are after an alternative non-sum product non-office 365 solution, this should work:
=LOOKUP(2,1/((FNames=F1)*(LNames=F2)),Phones)
https://www.contextures.com/excelfunctionlookup.html


2020-12-01 00:10:49

Mark

I was struggling to understand the logic of the SUMPRODUCT solution here so I created a worksheet to test it. And it didn't work. After some troubleshooting (and finally understanding the logic of using SUMPRODUCT), I figured out this only works if the phone number is stored as a 10-digit number without characters like 5551234567 vs. (555) 123-4567.


2020-11-21 05:53:13

Alex Blakenburg

And if you have Office 365 (now called Microsoft 365), either of these will work.
=XLOOKUP(1,(FNames=F1)*(LNames=F2),Phones,"Not Found")
=FILTER(Phones,(FNames=F1)*(LNames=F2),"Not Found")
Note: The "Not Found" text is an optional parameter.


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.