Nested "IFERROR" & "IF" statements on multiple sheets

Dustinkli

New Member
Joined
Mar 26, 2019
Messages
48
Office Version
  1. 365
  2. 2011
Platform
  1. Windows
I have an excel document with multiple sheets that I am referencing using IFERROR and IF statements. I have tried multiple variations of it to no avail.

Here is my current formula:

Excel Formula:
=IFERROR(INDEX(sheet2!B$2:B$10000,MATCH($A3,sheet2!$A$2:$A$10000,0)),IFERROR(INDEX(sheet3!B$2:B$10000,MATCH($A3,sheet3!$A$2:$A$10000,0)),IFERROR(INDEX(sheet4!B$2:B$10000,MATCH($A3,sheet4!$A$2:$A$10000,0)),"EMPTY")))

What it does is an INDEX lookup referencing a cell in the current sheet a cell of the same name in Sheet2 Column A and if the cell doesn't exist in Sheet2 it looks in Sheet3 and if it doesn't exist in Shee3 it looks in Sheet4 and if it's not in Sheet4 it says "EMPTY".

This works, however I would like to add 2 more conditions. I would like it to move onto the next sheet if the value indexed is a "0" or is blank.

So, for example:

It looks for the the value of cell A3 (let's say it's "John") in Sheet2 column A
and if "John" is not in sheet2 column A, or if "John" is in sheet2 Column A but the corresponding value it finds in column B is blank or is "0" then it moves onto sheet 3
If "John" is in Sheet3 column A and there is a value in Sheet3 Column B other than "0" it returns that value
and if "John" is not in Sheet3 column A, or if it is but the corresponding cell in Sheet 3 column B is blank or is "0" it returns the word "EMPTY"
 

Some videos you may like

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.

Zot

Well-known Member
Joined
Nov 26, 2020
Messages
973
Office Version
  1. 2016
Platform
  1. Windows
Please update your profile so that others know what Excel version you are working on. Probably there is simple way with new Excel.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,420
Office Version
  1. 365
Platform
  1. Windows
Also, what would be found in column B if it is not empty, would it be numbers or text? If numbers then the solution will be easier.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,420
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

Adding your excel version to your profile as @Zot asked is more beneficial than telling us in a post.

Also, what is the content of column B that I asked about earlier?
 

Dustinkli

New Member
Joined
Mar 26, 2019
Messages
48
Office Version
  1. 365
  2. 2011
Platform
  1. Windows
Adding your excel version to your profile as @Zot asked is more beneficial than telling us in a post.

Also, what is the content of column B that I asked about earlier?
Numbers in Column B
 

Dustinkli

New Member
Joined
Mar 26, 2019
Messages
48
Office Version
  1. 365
  2. 2011
Platform
  1. Windows

ADVERTISEMENT

Essentially I'm trying to do "If Or If" statements without creating circular formulas.
If X is error, or if X is blank or if X is 0, then refer to next sheet to look for the same.
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,420
Office Version
  1. 365
Platform
  1. Windows
Having numbers makes it a lot easier. This will only give you the content of column B if it is a number other than 0.
Excel Formula:
=IFERROR(1/(1/INDEX(sheet2!B$2:B$10000,MATCH($A3,sheet2!$A$2:$A$10000,0))),IFERROR(1/(1/INDEX(sheet3!B$2:B$10000,MATCH($A3,sheet3!$A$2:$A$10000,0))),IFERROR(1/(1/INDEX(sheet4!B$2:B$10000,MATCH($A3,sheet4!$A$2:$A$10000,0))),"EMPTY")))
I was hoping that it wouldn't be text, that makes the formula much longer which means it is easier to get it wrong.
 
Solution

Dustinkli

New Member
Joined
Mar 26, 2019
Messages
48
Office Version
  1. 365
  2. 2011
Platform
  1. Windows
That appears to work!

I do have some places where I would need to use text but I can probably find a way around that.

What does the 1/(1/ mean in the formula?
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,420
Office Version
  1. 365
Platform
  1. Windows
It creates a deliberate error when the value is anything other than non zero number.

Let's say the result of the INDEX formula is 2, this part would be 1/(1/2) or 1/(0.5) which gives you the original value.
If the INDEX formula returns text or "" from a formula blank then it would create a #VALUE! error because it is not a valid number to perform the calculation on. If the INDEX formula returns 0 or finds an empty cell then it would create a #DIV/0 error, all of which will be picked up by IFERROR and move to the next sheet.
 

Watch MrExcel Video

Forum statistics

Threads
1,127,245
Messages
5,623,586
Members
415,981
Latest member
Baltwin

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