Excel combinations from multiple columns with no duplicates

andrew_milonavic

Board Regular
Joined
Nov 16, 2016
Messages
98
Hi,

Is there a non VBA way to return all possible combinations without duplicates with the returned values in separate columns?

Example below. Data in the first 8 columns / 10 rows, results starting in the 11th column.

NoNoNo1NoNoNo1NoNoNo1NoNoNo1
YesYesYes2YesYesYes2YesNoNo1NoNoNo1
33
44
55
66
77
88
99
1010

<tbody>
</tbody>


Thanks

Andrew
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
I'm not sure what you'd do with 256,000 combinations, but you can do it with formulas:

Cell Formulas
RangeFormula
K1:K20K1=INDEX(A:A,MOD(ROW()-1,COUNTA(A:A))+1)
L1:R20L1=INDEX(B:B,MOD(INT((ROW()-1)/PRODUCT(SUBTOTAL(3,OFFSET($A:$A,0,COLUMN($K1:K1)-COLUMN($K1))))),COUNTA(B:B))+1)
Press CTRL+SHIFT+ENTER to enter array formulas.


Put the K1 formula in and drag down as far as needed. Put the L1 formula in and drag down and to the right as far as needed. It's an array formula, so confirm with Control+Shift+Enter.


If you are OK with using some helper cells, you can simplify the formulas quite a bit and not need the array processing.

Cell Formulas
RangeFormula
K1:R16K1=INDEX(A:A,MOD(INT((ROW()-1)/S$2),S$1)+1)
S1:Z1S1=COUNTA(A:A)
T2:Z2T2=S2*COUNTA(A:A)


Put the S1 formula in and drag to Z1. Put 1 in S2. Put the T2 formula in and drag to Z2. Then put the K1 formula in, and copy down and across as far as needed.
 
Last edited by a moderator:
Upvote 0
Hey @Eric W or Anyone else,

Is there a way to edit Eric's formulas from above (the one without the helper column) and change it so that the results order is different? Currently it goes line by line and I'd rather it output like this three column example below. Possible?

Results are on the right.
CatCarPizzaCatCarPizza
DogTruckPastaCatCarPasta
ZebraVanAppleCatCarApple
MousePlaneOrangeCatCarOrange
ElephantBoatRiceCatCarRice

Eric's Formulas:

=INDEX(A:A,MOD(ROW()-1,COUNTA(A:A))+1)

=INDEX(B:B,MOD(INT((ROW()-1)/PRODUCT(SUBTOTAL(3,OFFSET($A:$A,0,COLUMN($K1:K1)-COLUMN($K1))))),COUNTA(B:B))+1)


Thanks

Andrew
 
Upvote 0
How about:

Cell Formulas
RangeFormula
K1:R33K1=IFERROR(INDEX(A:A,MOD(INT((ROW()-1)/PRODUCT(IFERROR(1/(1/SUBTOTAL(3,OFFSET(B:B,0,COLUMN(B:$I)-COLUMN(B:B)))),1))),COUNTA(A:A))+1),"")
Press CTRL+SHIFT+ENTER to enter array formulas surrounded with curly braces.


I took the rice off just to test columns of different sizes. This works out to column H/R if you want to add additional columns. There's no stopping condition, so after 5*5*4 rows, it'll just start to repeat itself, but I can add that if you want.
 
Last edited:
Upvote 0
Hey @Eric W or Anyone else,

Is there a way to adjust Eric's formula (see post above and formula below) to stop duplicates? i.e Cat Cat, if Cat is in the data of both columns A and B.

Eric's Formula: IFERROR(INDEX(A:A,MOD(INT((ROW()-1)/PRODUCT(IFERROR(1/(1/SUBTOTAL(3,OFFSET(B:B,0,COLUMN(B:$I)-COLUMN(B:B)))),1))),COUNTA(A:A))+1),"")

Thanks

Andrew
 
Upvote 0
You've about exceeded what you can reasonably do with formulas. Telling it to skip a row throws off the counters for everything after that row. The only non-VBA way to do this I can think of would be to set up the formulas as is in one set of columns, then in another set of columns set up another array formula that would skip the rows with duplicates. And I assume that a duplicate means the same value in more than one column, no matter how many columns you have?
 
Upvote 0

Forum statistics

Threads
1,214,973
Messages
6,122,534
Members
449,088
Latest member
RandomExceller01

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
Back
Top