Array trouble

txfireguy015

New Member
Joined
Jan 28, 2021
Messages
6
Office Version
  1. 2019
Platform
  1. Windows
I'm using INDEX/MATCH with 2 criteria to locate and transfer data from one spreadsheet to another in EXCEL 2019.
On sheet 1, column A is "die", column B is "copy" and column E is "weight per foot". In column E I am entering the formula below to search another spreadsheet columns D and E for the last entry of "die" and "copy" to always return the most recent "weight per foot" in column P. The sheet that I'm searching has data added daily so I need my ranges within the array to expand as many rows as possible, preferably the entire sheet as you'll notice in my formula. However, when I do this the result is always 0. If I limit my ranges to only the rows that contain data the it will return the proper value. If I increase my range by 1 row it goes back to 0. Currently I have 1,863 rows of data. Are my ranges too large? Am I limited to rows that contain actual data and no blank cells? Do I need to use a completely different formula?

{=INDEX('[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$P$2:$P$1048576,MATCH(1,(A1495='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$D$2:$D$1048576)*(B1495='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$E$2:$E$1048576),1))}
 
Are the 'text' numbers in the single criteria cell or in the main table range?

Main table
Excel Formula:
=INDEX('[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$P:$P,AGGREGATE(14,6,ROW('[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$D$2:$D$10000)/(A1495='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$D$2:$D$10000)/((B1495&"")='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$E$2:$E$10000),1))
Criteria
Excel Formula:
=INDEX('[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$P:$P,AGGREGATE(14,6,ROW('[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$D$2:$D$10000)/(A1495='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$D$2:$D$10000)/((B1495+0)='[Levi''s Efficiency Press Report 2020.xlsx]Extrude Production'!$E$2:$E$10000),1))
Note that the second one will fail if the criteria is not a number.
 
Upvote 0

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

Forum statistics

Threads
1,215,697
Messages
6,126,269
Members
449,308
Latest member
VerifiedBleachersAttendee

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