In column A there will be a list of names in column B team and column C location
in cell D1 and D2, i want two names they need to be different and not from same location or team.
Is this something that can be done by formula
In column A there will be a list of names in column B team and column C location
in cell D1 and D2, i want two names they need to be different and not from same location or team.
Is this something that can be done by formula
Hi,
Assuming entries in A1:C20:
In D1:
=INDEX(A1:A20,RANDBETWEEN(1,COUNTA(A1:A20)))
In D2, array formula**:
=INDEX(A1:A20,INDEX(MODE.MULT(IF(MMULT(N(B1:C20=INDEX(B1:C20,MATCH(D1,A1:A20,0),)),{1;1})={0,0},ROW(B1:C20))),RANDBETWEEN(1,COUNT(1/(MMULT(N(B1:C20=INDEX(B1:C20,MATCH(D1,A1:A20,0),)),{1;1})=0)))))
I chose an end row reference of 20 here, which obviously you can amend to meet your requirements, though you should be careful not to make it too arbitrarily large (and certainly don't reference entire columns!), since, for each additional cell referenced, extra calculation will be required (array formulas calculate over all cells passed to them, whether technically beyond the last-used cells in those ranges or not).
**Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
Hi on some names D2 just brings back a 0, any ideas?
Do you have any blanks in any of the ranges you used in your version of the formula?
Regards
Its working now, no idea what i had done wrong
Ok, glad you got it sorted!
Cheers
There are currently 1 users browsing this thread. (0 members and 1 guests)
Bookmarks