Index, Filter and Sort across two tables

barney_t

New Member
Joined
Feb 24, 2021
Messages
20
Office Version
  1. 365
Platform
  1. Windows
Hi,
I am hoping for some assistance as I admitting defeat again!

I am trying to get a formula that will extract a data/ criteria from two tables.

I have been working with Index Sortby Filter with limited success.

On the below I need the result to be the product number with the highest stock which had unit sales of zero or less.

I also need it to be grouped by type and material, therefore referencing cells K2 & K3.

The order of the products will be different in the two tables and some products may not be on the first table and the assumption would be that their sales were zero.

Lastly, without the use of a helper column.

Thank you in advance for taking the time to look at this.

Kind regards

Barney
Book1.xlsx
ABCDEFGHIJKL
1typematerialproductunits soldtypematerialproductstock
2nutmetalproduct12nutmetalproduct15nut
3nutmetalproduct20nutmetalproduct26metal
4nutmetalproduct3-1nutmetalproduct37
5nutmetalproduct64nutmetalproduct45
6nutplasticproduct74boltplasticproduct59
7nutplasticproduct80nutmetalproduct65result
8boltmetalproduct98nutplasticproduct751st hightest stock productproduct3
9boltmetalproduct100nutplasticproduct852nd highest stock productproduct2
10boltmetalproduct1110boltmetalproduct953rd highest stock productproduct4
11boltplasticproduct120boltmetalproduct105
12boltmetalproduct115
13boltplasticproduct125
Sheet1 (3)
 

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

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
How about
+Fluff 1.xlsm
ABCDEFGHIJKL
1typematerialproductunits soldtypematerialproductstock
2nutmetalproduct12nutmetalproduct15nut
3nutmetalproduct20nutmetalproduct26metal
4nutmetalproduct3-1nutmetalproduct37
5nutmetalproduct64nutmetalproduct45
6nutplasticproduct74boltplasticproduct59
7nutplasticproduct80nutmetalproduct65result
8boltmetalproduct98nutplasticproduct751st hightest stock productproduct3
9boltmetalproduct100nutplasticproduct852nd highest stock productproduct2
10boltmetalproduct1110boltmetalproduct953rd highest stock productproduct4
11boltplasticproduct120boltmetalproduct105
12boltmetalproduct115
13boltplasticproduct125
14
Data
Cell Formulas
RangeFormula
L8:L10L8=LET(Fltr,FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),x,IFNA(XLOOKUP(Fltr,C2:C11,D2:D11),0),Sold,FILTER(Fltr,x<=0),SORTBY(Sold,FILTER(I2:I13,ISNUMBER(MATCH(H2:H13,Sold,0))),-1))
Dynamic array formulas.
 

barney_t

New Member
Joined
Feb 24, 2021
Messages
20
Office Version
  1. 365
Platform
  1. Windows
Hi Fluff
Thank you for your time again!
I am not getting the formula to work when i copy it into my file - i get #NAME?
It looks like it should work but something is amiss - any thoughts?

kind regards
barney
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
Do you have the LET function?
 

barney_t

New Member
Joined
Feb 24, 2021
Messages
20
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

looking at the function arguments i don't think i do
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
In that case how about
+Fluff 1.xlsm
ABCDEFGHIJKL
1typematerialproductunits soldtypematerialproductstock
2nutmetalproduct12nutmetalproduct15nut
3nutmetalproduct20nutmetalproduct26metal
4nutmetalproduct3-1nutmetalproduct37
5nutmetalproduct64nutmetalproduct45
6nutplasticproduct74boltplasticproduct59
7nutplasticproduct80nutmetalproduct65result
8boltmetalproduct98nutplasticproduct751st hightest stock productproduct3
9boltmetalproduct100nutplasticproduct852nd highest stock productproduct2
10boltmetalproduct1110boltmetalproduct953rd highest stock productproduct4
11boltplasticproduct120boltmetalproduct105
12boltmetalproduct115
13boltplasticproduct125
Data
Cell Formulas
RangeFormula
L8:L10L8=SORTBY(FILTER(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),IFNA(XLOOKUP(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),C2:C11,D2:D11),0)<=0),FILTER(I2:I13,ISNUMBER(MATCH(H2:H13,FILTER(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),IFNA(XLOOKUP(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),C2:C11,D2:D11),0)<=0),0))),-1)
Dynamic array formulas.
 

Marcelo Branco

MrExcel MVP
Joined
Aug 23, 2010
Messages
16,526
Office Version
  1. 2019
  2. 2010
Platform
  1. Windows

ADVERTISEMENT

Very complex array formula...:eek:

Pasta1
ABCDEFGHIJKL
1typematerialproductunits soldtypematerialproductstock
2nutmetalproduct12nutmetalproduct15nut
3nutmetalproduct20nutmetalproduct26metal
4nutmetalproduct3-1nutmetalproduct37
5nutmetalproduct64nutmetalproduct45
6nutplasticproduct74boltplasticproduct59
7nutplasticproduct80nutmetalproduct65result
8boltmetalproduct98nutplasticproduct751st hightest stock productproduct3
9boltmetalproduct100nutplasticproduct852nd highest stock productproduct2
10boltmetalproduct1110boltmetalproduct953rd highest stock productproduct4
11boltplasticproduct120boltmetalproduct105
12boltmetalproduct115
13boltplasticproduct125
14
Plan7
Cell Formulas
RangeFormula
L8:L10L8=INDEX(H$2:H$13,SMALL(IF(F$2:F$13=K$2,IF(G$2:G$13=K$3,IF(SUMIF(C$2:C$11,H$2:H$13,D$2:D$11)<=0,IF(ISNA(MATCH(H$2:H$13,L$7:L7,0)),IF(I$2:I$13=LARGE(IF(F$2:F$13=K$2,IF(G$2:G$13=K$3,IF(ISNA(MATCH(H$2:H$13,L$7:L7,0)),IF(SUMIF(C$2:C$11,H$2:H$13,D$2:D$11)<=0,I$2:I$13)))),1),ROW(H$2:H$13)-ROW(H$2)+1))))),1))
Press CTRL+SHIFT+ENTER to enter array formulas.


M.
 

barney_t

New Member
Joined
Feb 24, 2021
Messages
20
Office Version
  1. 365
Platform
  1. Windows
Hi Fluff
This is now working, however is there a way to stop the spill? ( Only get the top records E.G a Large function so i can select how many i want to report)
many thanks
barney
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
56,856
Office Version
  1. 365
Platform
  1. Windows
How about
+Fluff 1.xlsm
ABCDEFGHIJKLM
1typematerialproductunits soldtypematerialproductstock
2nutmetalproduct12nutmetalproduct15nut
3nutmetalproduct20nutmetalproduct26metal
4nutmetalproduct3-1nutmetalproduct372
5nutmetalproduct64nutmetalproduct45
6nutplasticproduct74boltplasticproduct59
7nutplasticproduct80nutmetalproduct65result
8boltmetalproduct98nutplasticproduct751st hightest stock productproduct3product3
9boltmetalproduct100nutplasticproduct852nd highest stock productproduct2product2
10boltmetalproduct1110boltmetalproduct953rd highest stock product
11boltplasticproduct120boltmetalproduct105
12boltmetalproduct115
13boltplasticproduct125
14
Data
Cell Formulas
RangeFormula
L8:L9L8=LET(Fltr,FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),x,IFNA(XLOOKUP(Fltr,C2:C11,D2:D11),0),Sold,FILTER(Fltr,x<=0),INDEX(SORTBY(Sold,FILTER(I2:I13,ISNUMBER(MATCH(H2:H13,Sold,0))),-1),SEQUENCE(K4)))
M8:M9M8=INDEX(SORTBY(FILTER(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),IFNA(XLOOKUP(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),C2:C11,D2:D11),0)<=0),FILTER(I2:I13,ISNUMBER(MATCH(H2:H13,FILTER(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),IFNA(XLOOKUP(FILTER(H2:H13,(F2:F13=K2)*(G2:G13=K3)),C2:C11,D2:D11),0)<=0),0))),-1),SEQUENCE(K4))
Dynamic array formulas.
 
Solution

barney_t

New Member
Joined
Feb 24, 2021
Messages
20
Office Version
  1. 365
Platform
  1. Windows
Hi Fluff

Thank you once again for your help, all working now. (& thank you @Marcelo, this gives me another option, i will test and see which is faster to calculate)

Thank you both for saving the day.

kind regards
barney
 

Watch MrExcel Video

Forum statistics

Threads
1,130,124
Messages
5,640,249
Members
417,131
Latest member
Seanr19871

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