• If you would like to post, please check out the MrExcel Message Board FAQ and click here to register.
    If you forgot your password, you can reset your password.
  • Excel articles and downloadable files provided in the articles have not been reviewed by MrExcel Publishing. Please apply the provided methods / codes and open the files at your own risk.
    If you have any questions regarding an article, please use the Article Discussion section.
DRSteele

All Permutations of Three Variables

In order to generate all the permutations for three variables, put the variables in an Excel Table (which is called Inventory here). You can add as many rows to the Table as desired and you can fill in all or just one of the rows for each variable. The exemplar here will spill down 60 rows, the number of permutations for this 4_3_5 = 60 setup.

These formulas rely on Excel's new dynamic calculation engine and powerful array functions (like SEQUENCE).

If you can figure out how to set this up for more than three variables, go ahead and share it with us!

Book1
HIJKLMNOPQ
5
Case-Lot-Shelf
Case
Lot
Shelf
6CaseLotShelf
A - w - 1
A
w
1
7Aw1A - w - 2Aw2
8Bx2A - w - 3Aw3
9Cy3A - w - 4Aw4
10D4A - w - 5Aw5
115A - x - 1Ax1
12A - x - 2Ax2
13
4
3
5
A - x - 3Ax3
14
60
A - x - 4Ax4
15A - x - 5Ax5
all permut
Cell Formulas
RangeFormula
O5O5=Inventory[[#Headers],[Case]]
P5P5=Inventory[[#Headers],[Lot]]
Q5Q5=Inventory[[#Headers],[Shelf]]
O6O6=INDEX(Inventory[Case],INT((SEQUENCE(J14)-1)/((COUNTA(Inventory[Lot])*(COUNTA(Inventory[Shelf])))))+1)
P6P6=INDEX(Inventory[Lot],MOD(INT((SEQUENCE(J14)-1)/COUNTA(Inventory[Shelf])),COUNTA(Inventory[Lot]))+1)
Q6Q6=INDEX(Inventory[Shelf],MOD((SEQUENCE(J14)-1),COUNTA(Inventory[Shelf]))+1)
M5M5=O5&"-"&P5&"-"&Q5
M6M6=INDEX(Inventory[Case],INT((SEQUENCE(J14)-1)/((COUNTA(Inventory[Lot])*(COUNTA(Inventory[Shelf])))))+1)&" - "&INDEX(Inventory[Lot],MOD(INT((SEQUENCE(J14)-1)/COUNTA(Inventory[Shelf])),COUNTA(Inventory[Lot]))+1)&" - "&INDEX(Inventory[Shelf],MOD((SEQUENCE(J14)-1),COUNTA(Inventory[Shelf]))+1)
H13H13=SUBTOTAL(103,[Case])
I13I13=SUBTOTAL(103,[Lot])
J13J13=SUBTOTAL(103,[Shelf])
J14J14=Inventory[[#Totals],[Case]]*Inventory[[#Totals],[Lot]]*Inventory[[#Totals],[Shelf]]
Excel Version
365
Author
DRSteele
Views
728
First release
Last update
Rating
0.00 star(s) 0 ratings

More Excel articles from DRSteele

Some videos you may like

This Week's Hot Topics

Top