ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Multiple Criteria Lookup (https://www.excelbanter.com/excel-worksheet-functions/447419-multiple-criteria-lookup.html)

JIMCREWE

Multiple Criteria Lookup
 
1 Attachment(s)
Hi,

I have a sheet in which I am trying to use mutliple criteria to define a result.

The premis is that a Company is selected in Col A, then a Role is selected in Col B, then a Shift Time is selected in Col B, this will then generate the relevant hourly rate using a table of rates on the second worksheet.

The formula works sort of for the first entry but once I start to mix up the Company / Role / Shift Time info it does not calc, same when copying down the sheet.

Can anyone help please ? :)

Thanks

Jim

Claus Busch

Multiple Criteria Lookup
 
Hi Jim,

Am Thu, 18 Oct 2012 12:30:30 +0000 schrieb JIMCREWE:

The premis is that a Company is selected in Col A, then a Role is
selected in Col B, then a Shift Time is selected in Col B, this will
then generate the relevant hourly rate using a table of rates on the
second worksheet.


in F10 try:
=IF(C10="Day Shift",INDEX(Rates!$C$6:$C$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Night Shift",INDEX(Rates!$D$6:$D$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Weekend",INDEX(Rates! $E$6:$E$274,MATCH(A10&"|"&B10,Rates!$H$6:$H$274,0) ),"Data Not Found")))


Regards
Claus Busch
--
Win XP PRof SP2 / Vista Ultimate SP2
Office 2003 SP2 /2007 Ultimate SP2

Claus Busch

Multiple Criteria Lookup
 
Hallo Jim,

Am Thu, 18 Oct 2012 16:05:59 +0200 schrieb Claus Busch:

in F10 try:
=IF(C10="Day Shift",INDEX(Rates!$C$6:$C$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Night Shift",INDEX(Rates!$D$6:$D$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Weekend",INDEX(Rates! $E$6:$E$274,MATCH(A10&"|"&B10,Rates!$H$6:$H$274,0) ),"Data Not Found")))


a little bit shorter:
=IFERROR(INDEX(IF(C10="Day Shift",Rates!$C$6:$C$274,IF(C10="Night Shift",Rates!$D$6:$D$274,Rates!$E$6:$E$274)),MATCH (A10&"|"&B10,Rates!$H$6:$H$274,0)),"Data Not Found")


Regards
Claus Busch
--
Win XP PRof SP2 / Vista Ultimate SP2
Office 2003 SP2 /2007 Ultimate SP2

JIMCREWE

Quote:

Originally Posted by Claus Busch (Post 1606518)
Hallo Jim,

Am Thu, 18 Oct 2012 16:05:59 +0200 schrieb Claus Busch:

in F10 try:
=IF(C10="Day Shift",INDEX(Rates!$C$6:$C$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Night Shift",INDEX(Rates!$D$6:$D$274,MATCH(A10&"|"&B10,R ates!$H$6:$H$274,0)),IF(C10="Weekend",INDEX(Rates! $E$6:$E$274,MATCH(A10&"|"&B10,Rates!$H$6:$H$274,0) ),"Data Not Found")))


a little bit shorter:
=IFERROR(INDEX(IF(C10="Day Shift",Rates!$C$6:$C$274,IF(C10="Night Shift",Rates!$D$6:$D$274,Rates!$E$6:$E$274)),MATCH (A10&"|"&B10,Rates!$H$6:$H$274,0)),"Data Not Found")


Regards
Claus Busch
--
Win XP PRof SP2 / Vista Ultimate SP2
Office 2003 SP2 /2007 Ultimate SP2

Thanks Claus that works great !

Appreciate your time !


All times are GMT +1. The time now is 10:01 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com