Index Match data to provide multiple results in columns

lomond44

New Member
Joined
May 6, 2014
Messages
7
I need some help with a spreadsheet that contains 2 worksheets.

The first sheet contains part numbers and the assemblies that they are used in. Each part number can be used in many assemblies.

On the 2nd sheet is a list of just the part numbers without duplicates. The aim is to create columns to the right of each part number that identifies all the assemblies that the part is used in.

I have looked at this link How To Return Multiple Match Values in Excel Using INDEX-MATCH or VLOOKUP | eImagine Technology Group but I do not want the results to be down a column but to go across the row.

Any help appreciated :)
 
Hello Aladin,

The first code did the job for me.
The only problem is that if you have an empty cell for a "lookup" word, it returns all cells as true. I guess this is happening because SEARCH function finds " " in all my data and always returns TRUE.
But I am fine with this. I can fill the "lookup column" with some special characters and avoid empty cells.
Anyway, great job as always. Thank you very much.

For the record, the second code does not work if your lookup string does not start with the string in the search array.
e.g. "Mou" will return the expected results Mickey, Minnie but "ous" or "use" will not return anything

Control+shif+enter:
Rich (BB code):

=IFERROR(INDEX($B$2:$B$8,SMALL(IF(ISNUMBER(SEARCH(IF($D2="","##",$D2),
   $A$2:$A$8)),ROW($B$2:$B$8)-ROW($D$2)+1),COLUMNS($E2:E2))),"")
 
Upvote 0

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Hey I'm looking for some help in one similar to this however I have several variables I have to build in.
Here's the way my data is layed out

Column A is a customer name (what im searching for)
Column B is a Reference number (what i want to return)
Column C is a date of booking

What i need is to be able to search for a customer and return a list of the reference numbers, and to only return those that were booked between the date range.

Some of the customers in column A could have the same leters or first part of thier name, so i am looking for it to be an exact match to the one im looking for.
The customer i am looking for is always held in Cell B1 and the Date range is held B2 for Start date and C2 for the end date.

I have only provided the 3 columns above but i actually need to do this so it will return several results column B will change however it will always be looking for the same data in column A & C

Would appreciate any help that can be given.
Thanks
 
Upvote 0
Here's a Google doc with some basic data, 2 tabs one hold data the other is my desired results feel free to edit as required.

https://docs.google.com/spreadsheets/d/1Hs8BDYBNAncXGZpzkgkMANqMdgZzG-CjRzMOXQnu9cM/edit?usp=sharing

Thanks
Vulfen

It would be more convenient to have the sample data directly on the forum. Try to post an Excel readable, small sample, using one of the methods listed in the following: Attachments or using this add-in:https://app.box.com/s/soezox25h3w0q5s4rcyl instead of providing an outside link to a file.
 
Upvote 0
Of so i think ive done this right this would be the kind of data id be looking at.


*ABCD
1Customer NameReference NumberBooking DateQuantity
2Customer100888111C01/12/20151
3Customer100888112C01/12/20153
4Customer300888113C01/12/20151
5Customer100888114C01/12/20152
6Customer200888115C02/12/20151
7Customer100888116C02/12/20151
8Customer100888116C02/12/20151
9Customer200888117C07/10/20154
10Customer200888117C07/10/20154
11Customer200888117C07/10/20154
12Customer200888117C07/10/20151
13Customer300888118C07/10/20152
14Customer300888118C07/10/20151
15Customer300888118C07/10/20151
16Customer100888119C10/12/20153
17Customer100888120C10/12/20154

<tbody>
</tbody>

Excel tables to the web - Excel Jeanie Html 4


And This would be the desired result i would like.
The customer lookup must be exact match ups only
It is possible for a reference number to appear more than once and they have to appear in the results table on separate lines.
Currently i am just doing this by filtering and copy paste each customer, for around 100 customers #ballache


*ABCDE
1Customer NameCustomer1***
2Date Range01/12/201507/12/2015(date range included these dates)*
3*****
4Reference NumberQuantityDate Booked**
500888111C101/12/2015**
600888112C301/12/2015**
700888114C201/12/2015**
800888116C102/12/2015**
900888116C102/12/2015**

<tbody>
</tbody>

Excel tables to the web - Excel Jeanie Html 4
 
Upvote 0
Of so i think ive done this right this would be the kind of data id be looking at.

[...]

Exactly right...

And This would be the desired result i would like.
The customer lookup must be exact match ups only
It is possible for a reference number to appear more than once and they have to appear in the results table on separate lines.
Currently i am just doing this by filtering and copy paste each customer, for around 100 customers #ballache

That too. Thanks for providing the right type sample exhibits.

Sheet1

Row\Col
A​
B​
C​
D​
1​
Customer NameReference NumberBooking DateQuantity
2​
Customer100888111C
1/12/2015
1
3​
Customer100888112C
1/12/2015
3
4​
Customer300888113C
1/12/2015
1
5​
Customer100888114C
1/12/2015
2
6​
Customer200888115C
2/12/2015
1
7​
Customer100888116C
2/12/2015
1
8​
Customer100888116C
2/12/2015
1
9​
Customer200888117C
7/10/2015
4
10​
Customer200888117C
7/10/2015
4
11​
Customer200888117C
7/10/2015
4
12​
Customer200888117C
7/10/2015
1
13​
Customer300888118C
7/10/2015
2
14​
Customer300888118C
7/10/2015
1
15​
Customer300888118C
7/10/2015
1
16​
Customer100888119C
10/12/2015
3
17​
Customer100888120C
10/12/2015
4

Sheet2

Row\Col
A​
B​
C​
D​
1​
Customer NameCustomer1
5
2​
Date Range
1/12/2015
7/12/2015
3​
4​
Reference NumberQuantityBooking DateIdx
5​
00888111C
1
1/12/2015
2
6​
00888112C
3
1/12/2015
3
7​
00888114C
2
1/12/2015
5
8​
00888116C
1
2/12/2015
7
9​
00888116C
1
2/12/2015
8
10​

In C1 just enter:
Rich (BB code):

=COUNTIFS(Sheet1!A2:A17,B1,Sheet1!C2:C17,">="&B2,Sheet1!C2:C17,"<="&C2)<strike></strike>

In A5 just enter, copy across to C5, and copy down:
Rich (BB code):

=IF($D5="","",INDEX(Sheet1!$A$1:$D$17,$D5,
  MATCH(A$4,INDEX(Sheet1!$A$1:$D$17,1,0),0)))<strike></strike>

In D5 control+shift+enter, not just enter, and copy down:
Rich (BB code):

=IF(ROWS($D$5:D5)<=$C$1,SMALL(IF(Sheet1!$A$1:$A$17=$B$1,
  IF(Sheet1!$C$1:$C$17>=$B$2,IF(Sheet1!$C$1:$C$17<=$C$2,
  ROW(Sheet1!$A$1:$A$17)-ROW(Sheet1!$A$1)+1))),ROWS($D$5:D5)),"")<strike></strike>
 
Upvote 0

Forum statistics

Threads
1,214,936
Messages
6,122,340
Members
449,079
Latest member
rocketslinger

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
Back
Top