Index Match Iferror function

Status
Not open for further replies.

RAJESH1960

Well-known Member
Joined
Mar 26, 2020
Messages
1,426
Office Version
  1. 2019
Platform
  1. Windows
This post was solved earlier but when I format the cells to date in sheet2 cells A2:A13, the formula doesn't work.
I am trying to get the values from sheet2 to sheet1 using the formula. If the day in Sheet1 cell B1 is Monday to Friday then it should get the value of Sheet2 cell B2, If the day in Sheet1 cell B1 is Saturday then it should get the value of Sheet2 cell C2 and finally If the day in Sheet1 cell B1 is Saturday then it should get the value of Sheet2 cell D2.
Can someone please help and edit the formula accordingly.

Query Index .xlsx
ABCDEFGHIJ
101-04-202001-05-202001-06-202001-07-202001-08-202001-09-202001-10-202002-10-202003-10-2020
2
3#N/A#N/A#N/A#N/A#N/A#N/A#N/A
4
5
6
7
8
Sheet1
Cell Formulas
RangeFormula
I1:J1I1=H1+1
B3:H3B3=INDEX(Sheet2!$B$2:$D$13,MATCH(TEXT(B$1,"mmmm"),Sheet2!$A$2:$A$13,0),IFERROR(MATCH(TEXT(B$1,"ddd"),Sheet2!$B$1:$D$1,0),1))


Query Index .xlsx
ABCD
1Mon-FriSatSun
2Apr-2020100200300
3May-2020200300400
4Jun-2020300400500
5Jul-2020400500600
6Aug-2020500600700
7Sep-2020600700800
8Oct-2020700800900
9Nov-20208009001000
10Dec-202090010001100
11Jan-2021100011001200
12Feb-2021110012001300
13Mar-2021120013001400
Sheet2
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
5,682
Office Version
  1. 365
Platform
  1. MacOS
you could use
=IF(WEEKDAY(B1,2)<6,INDEX(Sheet2!$B$2:$B$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)),
IF(WEEKDAY(B1,2)=6,INDEX(Sheet2!$C$2:$C$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)),
IF(WEEKDAY(B1,2)=7,INDEX(Sheet2!$D$2:$D$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)))))

BUT you will get N/A if no date exists in table


Book2
ABCDEFGHIJ
14/1/205/1/206/1/207/1/208/1/209/1/2010/1/2010/2/2010/3/20
2
3#N/A#N/A#N/A#N/A#N/A#N/A#N/A
4100200300400600600700#N/A#N/A
Sheet1
Cell Formulas
RangeFormula
I1:J1I1=H1+1
B3:H3B3=INDEX(Sheet2!$B$2:$D$13,MATCH(TEXT(B$1,"mmmm"),Sheet2!$A$2:$A$13,0),IFERROR(MATCH(TEXT(B$1,"ddd"),Sheet2!$B$1:$D$1,0),1))
B4:J4B4=IF(WEEKDAY(B1,2)<6,INDEX(Sheet2!$B$2:$B$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)), IF(WEEKDAY(B1,2)=6,INDEX(Sheet2!$C$2:$C$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)), IF(WEEKDAY(B1,2)=7,INDEX(Sheet2!$D$2:$D$13,MATCH(Sheet1!B1,Sheet2!$A$2:$A$13,0)))))
 
Solution
Status
Not open for further replies.
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,128
Messages
5,835,564
Members
430,367
Latest member
glastonbury

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