unique entry lookup in large table

luke w

Board Regular
Joined
Oct 23, 2002
Messages
53
Hello Excel Gurus

Well i've pulled enough hair that i thought I should ask the experts.

I have a large table of employee names, approximately 1000. We have a phone operator that actually scrolls through this list to find the name of the person they are looking for...can you say boring?

Anyway, what I would like to do is put something together that allows them to enter the first name of the person in a cell and have it return all of the unique entries with that name, which of course would include their extension number in a new table.

Vlookup won't work, and i'm trying an Offset Match in the following format, but am stuck because it will only return one entry as well.

=OFFSET('Formatted Data'!$A$1,MATCH($B$1,'Formatted Data'!$A$2:$A$1000,0),1)
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
Wouldn't AutoFilter do the job? If not, care to provide a small sample? Also, are you on Excel 2003?
 

pgc01

MrExcel MVP
Joined
Apr 25, 2006
Messages
19,884
Hi Luke

Here is one solution.

This solution accepts an input string that does not have to be the first name, any part of the name will do (I think it is more flexible).

In the example I post, the operador typed rob and 2 names were found

John ROBbins
ROBin Ford

In E3
Code:
=IF(SUM(--ISNUMBER(SEARCH($E$1,$A$2:$A$1000)))<=ROW()-ROW($E$3),"",INDEX($A:$A,SMALL(IF(ISNUMBER(SEARCH($E$1,$A$2:$A$1000)),ROW($A$2:$A$1000),1000000),ROW()-ROW($E$3)+1)))
This is an array formula and so MUST be entered with CTRL+SHIFT+ENTER and not just ENTER.

In F3
Code:
=IF(SUM(--ISNUMBER(SEARCH($E$1,$A$2:$A$1000)))<=ROW()-ROW($E$3),"",INDEX($B:$B,SMALL(IF(ISNUMBER(SEARCH($E$1,$A$2:$A$1000)),ROW($A$2:$A$1000),1000000),ROW()-ROW($E$3)+1)))
This is an array formula and so MUST be entered with CTRL+SHIFT+ENTER and not just ENTER.

Copy down 10 rows, to get the first 10 matches.

Hope this helps
PGC
Book1.xls
ABCDEFGH
1NamesTelNamerob
2JohnSmith1234
3MaryRiley5678MatchesJohnRobbins0912
4JohnRobbins0912RobinFord8858
5KarenGrey2258  
6JohnClark3365  
7RobinFord8858  
8  
9  
10  
Sheet3
 

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,209
Book3
ABCDEFGH
1First NameLast NameExtensionFirstJohn
2JohnSmith1234Last
3MaryRiley5678Count3
4JohnRobbins912First NameLast NameExtension
5KarenGrey22581JohnSmith1234
6JohnClark33653JohnRobbins912
7RobinFord88585JohnClark3365
8    
9
Sheet1


F1:F2 is for user entered-value(s). It can consist of either just a first name or a last name or both.

F3:

=SUMPRODUCT(ISNUMBER(SEARCH(F1&"#"&F2,$A$2:$A$7&"#"&$B$2:$B$7))+0)

E5:

=IF(ROWS($E$5:E5)<=$F$3,SMALL(IF(ISNUMBER(SEARCH($F$1&"#"&$F$2,$A$2:$A$7&"#"&$B$2:$B$7)),ROW($A$2:$A$7)-ROW($A$2)+1),ROWS($E$5:E5)),"")

which is confirmed with control+shift+enter (not just with enter) then copied down.

F5, copied across and down:

=IF(N($E5),INDEX(A$2:A$7,$E5),"")
 

luke w

Board Regular
Joined
Oct 23, 2002
Messages
53
sorry spoke too soon. i'm getting a "#REF!" in the cells that don't have matches for the names. i don't know if the name i enter will return with 5 10 15 etc. names with the same match.

i've tried conditional formatting but for some reason its not working. any other suggestions...perhaps an addition to the code?
 

Forum statistics

Threads
1,140,925
Messages
5,703,183
Members
421,280
Latest member
Jaycee01

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Top