Index Match 3 Way Look Up

hiker8117

New Member
Joined
Mar 26, 2018
Messages
38
I am trying to pull Labor Dollars from Sheet1 into Sheet2 by using a 3 way lookup Index and Match Function.
The 3 criteria are JO, TSTSD and KO. Any help is appreciated. Thank you Gene

Sheet2
TSTSDJOKOLabor HoursTotal Dollars
JMR9
828MQ20495001
354
0
JIJ7
828MR60770
010
2700
JMR9
828MR607700202060

<colgroup><col style="mso-width-source:userset;mso-width-alt:3766; width:77pt" width="103" span="2"> <col style="mso-width-source:userset;mso-width-alt:1755;width:36pt" width="48"> <col style="mso-width-source:userset;mso-width-alt:3254;width:67pt" width="89"> <col style="mso-width-source:userset;mso-width-alt:3766;width:77pt" width="103"> </colgroup><tbody>
</tbody>

<tbody>
</tbody>

Sheet1
JO
TSTSDKOLabor Dollars
828MQ20495
JMR9
001
$15,843
828MR60770
JIJ7
010
$5,458
828MS41100
EEEW009$1,194
828MS41100
MFYX008
$913

<colgroup><col style="mso-width-source:userset;mso-width-alt:3766; width:77pt" width="103" span="4"> </colgroup><tbody>
</tbody>

<tbody>
</tbody>


<colgroup><col width="86"></colgroup><tbody>
</tbody>

<tbody>

<colgroup><col style="mso-width-source:userset;mso-width-alt:3108;width:64pt" width="85"> <col style="mso-width-source:userset;mso-width-alt:2194;width:45pt" width="60"> <col style="mso-width-source:userset;mso-width-alt:1499;width:31pt" width="41"> <col style="mso-width-source:userset;mso-width-alt:3766;width:77pt" width="103"> </colgroup><tbody>
</tbody>

<tbody>
</tbody>
</tbody>



<tbody>
</tbody>

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Format cells as date
Select range and press Ctrl+Shift+3 to format cells as date. (Shift 3 is the # sign which sort of looks like a small calendar).

AhoyNC

Well-known Member
Joined
Oct 10, 2011
Messages
4,719
Office Version
  1. 365
Platform
  1. Windows
Try:
Copy formula down as needed.

Excel Workbook
ABCDE
1TSTSDJOKOLabor HoursTotal Dollars
2JMR9828MQ204951354$15,843
3JIJ7828MR6077010270$5,458
4JMR9828MR6077020206No Match
Sheet 2
Excel Workbook
ABCD
1JOTSTSDKOLabor Dollars
2828MQ20495JMR91$15,843
3828MR60770JIJ710$5,458
4828MS41100EEEW9$1,194
5828MS41100MFYX8$913
Sheet 1
 

hiker8117

New Member
Joined
Mar 26, 2018
Messages
38
Wow..could not have come up with this if my life depended upon it. Thank you so much.

Would you be so kind as to help me understand what this formula does in a one sentence description.

Thank you

Gene
 

AhoyNC

Well-known Member
Joined
Oct 10, 2011
Messages
4,719
Office Version
  1. 365
Platform
  1. Windows
You're welcome.
May take more than one sentence.

Using the example above:
This part of the formula
(ROW(Sheet1!$D$2:$D$5)-ROW(Sheet1!$D$2)+1) just returns the row numbers in your data set or
{1;2;3;4}

This part looks at the 3 criteria
((Sheet1!$A$2:$A$5=$B2)*(Sheet1!$B$2:$B$5=Sheet2!$A2)*(Sheet1!$C$2:$C$5=$C2)) and returns an array with 1 for a match and 0 for no match or:
{1;0;0;0}

When we divide {1;2;3;4}/{1;0;0;0} = {1;#DIV/0!;#DIV/0!;#DIV/0!}
The 6 in the AGGREGATE(15,6.... tells the function to ignore the error values of #DIV/0!

The function then returns the row number to the INDEX function.





<colgroup><col width="545"></colgroup><tbody>
</tbody>
 

hiker8117

New Member
Joined
Mar 26, 2018
Messages
38

ADVERTISEMENT

AhoyNC..

One more if I may: Why do we divide between the 2 statements and the * between the 3 criteria statements indicates that we multiply..correct?
Appreciate you response. Thanks again this was a big help.


=IFERROR(INDEX(Sheet1!$D$2:$D$64,AGGREGATE(15,6,(ROW(Sheet1!$D$2:$D$64)-ROW(Sheet1!$D$2)+1)/((Sheet1!$A$2:$A$64=$B2)*(Sheet1!$B$2:$B$64=Sheet2!$A2)*(Sheet1!$C$2:$C$64=$C2)),1)),"No Match")

Regards

Gene
 

AhoyNC

Well-known Member
Joined
Oct 10, 2011
Messages
4,719
Office Version
  1. 365
Platform
  1. Windows
In this case the "*" means "and". Criteria 1 "and" Criteria 2 and Criteria 3 all must be true. In Excel TRUE =1 and FALSE = 0. So if all three are TRUE
((Sheet1!$A$2:$A$5=$B2)*(Sheet1!$B$2:$B$5=Sheet2!$A2)*(Sheet1!$C$2:$C$5=$C2)) will return either a 1 or 0 for each row in the data set. So in the example above we would get the following array for the second row (where TSTSD = JIJ7) {0;1;0;0}

Since this (ROW(Sheet1!$D$2:$D$5)-ROW(Sheet1!$D$2)+1) returns the row numbers.
By dividing {1;2;3;4}/{0;1;0;0} it will return the array {#DIV/0!;2;#DIV/0!;#DIV/0!} which would return 2 (row 2) to the index function.

Instead of using the formula below which would require you to enter it with CTRL-SHIFT-ENTER. I replaced the SMALL part of the formula below with the AGGRERATE function which only requires ENTER. AGGREGATE(15....) is the same as SMALL.

Excel Workbook
ABCDE
1TSTSDJOKOLabor HoursTotal Dollars
2JMR9828MQ204951354$15,843
3JIJ7828MR6077010270$5,458
4JMR9828MR6077020206No Match
Sheet 2
Excel Workbook
ABCD
1JOTSTSDKOLabor Dollars
2828MQ20495JMR91$15,843
3828MR60770JIJ710$5,458
4828MS41100EEEW9$1,194
5828MS41100MFYX8$913
Sheet 1
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,594
Office Version
  1. 2007
Platform
  1. Windows

ADVERTISEMENT

How about the "regular formula" sumproduct


<table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>sheet2</b></td></tr></table><br /><table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:80.79px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.99px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">TSTSD</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">JO</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">KO</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Labor Hours</td><td style="background-color:#ffff00; font-weight:bold; text-align:center; ">Total Dollars</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >JMR9</td><td >828MQ20495</td><td style="text-align:right; ">1</td><td style="text-align:right; ">354</td><td style="text-align:right; ">$15,843.00</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >JIJ7</td><td >828MR60770</td><td style="text-align:right; ">10</td><td style="text-align:right; ">270</td><td style="text-align:right; ">$5,458.00</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >JMR9</td><td >828MR60770</td><td style="text-align:right; ">20</td><td style="text-align:right; ">206</td><td style="text-align:right; ">$0.00</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >EEEW</td><td >828MS41100</td><td style="text-align:right; ">9</td><td > </td><td style="text-align:right; ">$1,194.00</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >E2</td><td >=SUMPRODUCT((sheet1!$A$2:$A$5=B2)*(sheet1!$B$2:$B$5=A2)*(sheet1!$C$2:$C$5=C2)*(sheet1!$D$2:$D$5))</td></tr></table></td></tr></table> <br /><br />
 

hiker8117

New Member
Joined
Mar 26, 2018
Messages
38
Again can't thank you enough I totally get it. I wish there was a book to purchase that listed all functions and showed examples.

Regards

Gene
 

Watch MrExcel Video

Forum statistics

Threads
1,122,464
Messages
5,596,288
Members
414,052
Latest member
Dual Showman

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