HLOOKUP with Multiple Criteria

gldurand

Board Regular
Joined
Jun 8, 2006
Messages
178
Office Version
  1. 2016
Platform
  1. Windows
I am currently using a HLOOKUP to find a value within a table. But i have to change the Row reference each time for the position i am looking for in the table.
Does someone have a formula that I can insert in Cell L3 to replace my HLOOKUP.
I need to lookup BUCKET (Col H) and ROLE (Col B) and provide corresponding RATE without having to change the Row reference.


Screenshot 2022-04-13 085931.jpg
Screenshot 2022-04-13 085618.jpg
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
Can you please post your current formula, rather than just an image.
 
Upvote 0
2022 Contractors Matrix.xlsx
ABCDEFGHIJKL
2Resource NameRoleManagerResource TypeStart dateEnd dateTenureBucketAdjustment Contractor Rate Contractor Rate Matrix
3Developer28-Feb-22Open Ended0.120.5$ 45.00
Roster
Cell Formulas
RangeFormula
G3G3=(TODAY()-E3)/360
H3H3=IF(G3<0.5,0.5, IF(G3<1,1, IF(G3<1.5,1.5, IF(G3<2,2, IF(G3<2.5,2.5, IF(G3<3,3, IF(G3<4,4,">4")))))))
L3L3=IF(I3<>"", HLOOKUP(I3,Tables!$B$16:$I$25,7,FALSE), HLOOKUP(H3,Tables!$B$16:$I$25,7,FALSE))


2022 Contractors Matrix.xlsx
ABCDEFGHI
16Bucket -->0.511.522.534>4
17Role< 6 months6 to 1 yr1 to 1,5 yrs1,5 to 2 yrs2 to 2,5 yrs2,5 to 3 yrs3 to 4 yrs4+ yrs
18BA/PM$ 45.00$ 47.50$ 52.50$ 57.50$ 60.00$ 65.00$ 70.00$ 75.00
19Data Engineer$ 45.00$ 47.50$ 52.50$ 57.50$ 62.50$ 70.00$ 77.50$ 85.00
20Data Hunters$ 30.00$ 30.00$ 30.00$ 30.00$ 30.00$ 30.00$ 30.00$ 30.00
21Data Science$ 45.00$ 47.50$ 52.50$ 57.50$ 62.50$ 70.00$ 77.50$ 85.00
22Developer$ 45.00$ 47.50$ 52.50$ 57.50$ 62.50$ 70.00$ 77.50$ 85.00
23Project Coordinators$ 45.00$ 47.50$ 52.50$ 57.50$ 62.50$ 65.00$ 70.00$ 75.00
Tables
Cell Formulas
RangeFormula
B19:E19B19=B18
B21:E21B21=B18
 
Upvote 0
Thanks for that, how about
Excel Formula:
=IF(I3<>"",INDEX(Tables!$B$18:$I$25,MATCH(B3,Tables!$A$18:$A$25,0),MATCH(H3,Tables!$B$16:$I$16,0)),"")
 
Upvote 0
Solution
Thanks for that, how about
Excel Formula:
=IF(I3<>"",INDEX(Tables!$B$18:$I$25,MATCH(B3,Tables!$A$18:$A$25,0),MATCH(H3,Tables!$B$16:$I$16,0)),"")
Thanks for all your help, works like a charm
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,215,064
Messages
6,122,939
Members
449,094
Latest member
teemeren

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