Forum Discussion
In desperate need of a formula for a -basically- simple task
I am building a test file in which to store test results but I am at a total loss. This is my problem:
- Our products are sold in combination with 1, 2 or 3 accessories.
- Products are manufactured on demand, and from every batch a sample needs to be tested.
- We test the samples with only 1 of the possible accessories at a time: a matter of cost and time.
- We first test product 1 with accessory 1. The next time product 1 needs to be tested, we do it with accessory 2, the third time with accessory 3 and the fourth time with accessory 1 again. The same goes for all of our products.
Which formula will return the right accessory to test with next?
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),)))))
9 Replies
- Subodh_Tiwari_sktneerSilver Contributor
Please try this and see if this is what you were trying to achieve...
In H3
=INDEX(Table1[[accessory 1]:[accessory 3]],MATCH([@product],Table1[product],0),COUNTIF(F$3:F3,F3))
- BlogpapaCopper Contributor
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 🙂
- Subodh_Tiwari_sktneerSilver Contributor
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.
- BlogpapaCopper Contributor
Subodh_Tiwari_sktneer This seems to be working 🙂 I still have to translate it to the actual file but if this works, you are truly a life saver! Thank you so much!