Forum Discussion
FILTER a Table using Spilled Dynamic Array as part of the "Include" Criteria
- Aug 24, 2023
I think you are looking for 2-D Lambda function here. Maybe something like (note it is untested and just thrown together to give you an idea of how to make it work):
=IFERROR(DROP(REDUCE("",L3#, LAMBDA(p,q, HSTACK(p, VSTACK(q, FILTER(ComponentPNs[Component PNs], ComponentPNs[Top Level PN]=q,"") )) )),,1),"")if you attach a that sample or give a link to it I'd be happy to test it and make sure it works too 🙂
BTW this also spits out the 'header' from L3# but if this formula will go in L4 then something more like this:
=IFERROR(DROP(REDUCE("",L3#, LAMBDA(p,q, HSTACK(p, FILTER(ComponentPNs[Component PNs], ComponentPNs[Top Level PN]=q,"") ) )),,1),"")note: I edited it to add the IFERROR wrap to remove the error values make it look nicer 🙂
=VSTACK(TRANSPOSE(SORT(INDIRECT("A2:A"&COUNTA(A:A)))),IFERROR(DROP(REDUCE("",SEQUENCE(1,COUNT(TRANSPOSE(SORT(INDIRECT("A2:A"&COUNTA(A:A)))))),LAMBDA(x,y,HSTACK(x,FILTER(I2:I24,G2:G24=INDEX(TRANSPOSE(SORT(INDIRECT("A2:A"&COUNTA(A:A)))),,y))))),,1),""))
This formula returns the intended result in similar sample data.
- OliverScheurichAug 25, 2023Gold Contributor
Does it work in the attached file?
- mtarlerAug 24, 2023Silver Contributor
I think you are looking for 2-D Lambda function here. Maybe something like (note it is untested and just thrown together to give you an idea of how to make it work):
=IFERROR(DROP(REDUCE("",L3#, LAMBDA(p,q, HSTACK(p, VSTACK(q, FILTER(ComponentPNs[Component PNs], ComponentPNs[Top Level PN]=q,"") )) )),,1),"")if you attach a that sample or give a link to it I'd be happy to test it and make sure it works too 🙂
BTW this also spits out the 'header' from L3# but if this formula will go in L4 then something more like this:
=IFERROR(DROP(REDUCE("",L3#, LAMBDA(p,q, HSTACK(p, FILTER(ComponentPNs[Component PNs], ComponentPNs[Top Level PN]=q,"") ) )),,1),"")note: I edited it to add the IFERROR wrap to remove the error values make it look nicer 🙂