To list down data from another sheet using IFERROR formula with INDEX, SMALL and ROW function

Kenor

Board Regular
Joined
Dec 8, 2020
Messages
116
Office Version
  1. 2016
Platform
  1. Windows
Hi All,

Need anyone helps. What's wrong with the below formula?

I want to use this formula

=IFERROR(INDEX(STORAGE_DATA!$E$3:$E$200,SMALL(IF(1=((--(INV_A6082!$I$1=STORAGE_DATA!$D$3:$D$200))*(--(INV_A6082!$K$1=STORAGE_DATA!$G$3:$G$200))),ROW(STORAGE_DATA!$E$3:$E$200)-4,""),ROW()-4)),"")

To list down data based on multiple criteria from the below 'STORAGE_DATA' sheet

1648612090407.png


To 'INV_A6082' sheet

1648612212332.png
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Could be more things that I haven't noticed yet but it's possible that your excess coercion methods are conflicting with each other, either use -- or * but not both in the same formula. For this type of formula you need to use * anyway.

Also, ROW()-4 is going to cause an error as the first reference will be negative which is invalid.

This should work, if it doesn't then that suggests that there are no matching records in the data. Note that this formula does not need to be array confirmed.
Excel Formula:
=IFERROR(INDEX(STORAGE_DATA!$E:$E,AGGREGATE(15,6,(ROW(STORAGE_DATA!$E$3:$E$200)/($I$1=STORAGE_DATA!$D$3:$D$200)*($K$1=STORAGE_DATA!$G$3:$G$200),ROWS($H$3:$H3))),"")
 
Upvote 0
What are you expecting that formula to do?
Should it be returning data from the rows that match, or from 2 rows above the matching data?
 
Upvote 0
Could be more things that I haven't noticed yet but it's possible that your excess coercion methods are conflicting with each other, either use -- or * but not both in the same formula. For this type of formula you need to use * anyway.

Also, ROW()-4 is going to cause an error as the first reference will be negative which is invalid.

This should work, if it doesn't then that suggests that there are no matching records in the data. Note that this formula does not need to be array confirmed.
Excel Formula:
=IFERROR(INDEX(STORAGE_DATA!$E:$E,AGGREGATE(15,6,(ROW(STORAGE_DATA!$E$3:$E$200)/($I$1=STORAGE_DATA!$D$3:$D$200)*($K$1=STORAGE_DATA!$G$3:$G$200),ROWS($H$3:$H3))),"")
[/QUOTE]

It shows this error

[ATTACH type="full" width="358px"]61276[/ATTACH]
 

Attachments

  • 1648646973792.png
    1648646973792.png
    14.3 KB · Views: 13
Upvote 0
Had a typo in the formula, fixed now.
Excel Formula:
=IFERROR(INDEX(STORAGE_DATA!$E:$E,AGGREGATE(15,6,ROW(STORAGE_DATA!$E$3:$E$200)/($I$1=STORAGE_DATA!$D$3:$D$200)*($K$1=STORAGE_DATA!$G$3:$G$200),ROWS($H$3:$H3))),"")
 
Upvote 0
What are you expecting that formula to do?
Should it be returning data from the rows that match, or from 2 rows above the matching data?
It should return data from that row that matches those two criteria ($1$1 and $K$1)

But the formula doesn’t work well, I’m not sure what’s wrong.
 
Upvote 0
Had a typo in the formula, fixed now.
Excel Formula:
=IFERROR(INDEX(STORAGE_DATA!$E:$E,AGGREGATE(15,6,ROW(STORAGE_DATA!$E$3:$E$200)/($I$1=STORAGE_DATA!$D$3:$D$200)*($K$1=STORAGE_DATA!$G$3:$G$200),ROWS($H$3:$H3))),"")

No errors, but no data coming out.
 
Upvote 0
I would seem to be invisible today :(
 
Upvote 0
It should return data from that row that matches those two criteria ($1$1 and $K$1)

But the formula doesn’t work well, I’m not sure what’s wrong.
Sorry, I already answered your question
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,208
Members
452,618
Latest member
Tam84

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