Forum Discussion
In desperate need of a formula for a -basically- simple task
- Sep 11, 2019
Here is the tweaked formula...
=INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),IF(MOD(COUNTIF(F$3:F3,F3),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))=0,COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)),MOD(COUNTIF(F$3:F3,F3),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))))
Subodh_Tiwari_sktneer It sounded too good to be true... It works perfectly for the first part, but two things are not working yet:
- after the 3 accessory options are tested, the fourth test should use accessory 1 again, the fifth test should use accessory 3 again, et cetera. So, a continuous loop.
- products that have only 2 test accessories should cycle through those 2 (1-2-1-2-1-2 instead of 1-2-0-1-2-0)
Think you can figure that out? That would be amazing 🙂
If you tweak your master data to fill the empty cells for any product, if any, manually, the following Array Formula will return the desired output.
e.g. Cell D5 in your master data is empty which you can fill manually with the first occurrence of the accessory which is 'a' in this case. I have filled it manually in the master data.
See if you can tweak the master data manually for those empty cells if any. If yes, you can try the following Array Formula which requires confirmation with Ctrl+Shift+Enter instead Enter alone...
In H3
=IFERROR(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),COUNTIF(F$3:F3,F3)),INDEX(H$2:H2,SMALL(IF(F$2:F2=[@product],ROW(F$2:F2)-ROW($F$2)+1),IF(MOD(COUNTIF(F$2:F2,[@product]),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))=0,1,MOD(COUNTIF(F$2:F2,[@product]),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))+1))))
Then confirm with Ctrl+Shift+Enter instead of Enter alone.
If you have access to the dynamic array formula, you don't need the special key stroke Ctrl+Shift+Enter to confirm an array formula, Enter is enough in that case.
- BlogpapaSep 11, 2019Copper Contributor
We're almost there! The only thing is: with this formula product 3 would be tested with accessories a-d-a-a-d-a-a-d-a-a-d-a, whil it should be a-d-a-d-a-d-a-d. This way I would test twice as much with 'a' as with 'd'. That would corrupt the outcome...
- Subodh_Tiwari_sktneerSep 11, 2019Silver Contributor
Here is the tweaked formula...
=INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),IF(MOD(COUNTIF(F$3:F3,F3),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))=0,COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)),MOD(COUNTIF(F$3:F3,F3),COUNTA(INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),)))))
- BlogpapaSep 11, 2019Copper Contributor
Holy crap Subodh_Tiwari_sktneer !
That looks fantastic! 🙂 I will build it in my masterfile and post the outcome here. This is really great stuff, thanks a lot!
Kind regards,
Arno
- Subodh_Tiwari_sktneerSep 11, 2019Silver Contributor
Please find the attached and let me know if the formula is working as desired now.
I am going to post the formula in the next reply because last time when I posted the formula, somehow the site considered it as spam and didn't allow me to post it.