- Excel Version
- 365
Using REDUCE function in Office 365 we can get combinations of items in different columns very easily.
The second parameter of REDUCE function is B1:D1, so the function will calculate B1, C1, D1 one by one. Let's see what happend when calculating B1.
1. When calculating B1, y stands for B1, [OFFSET(B1,,,99)] returns range B1:B99 (0 for blank cells):
2. Use TOROW function transform values in B1:B99 to a row and ignore blanks:
3.The initial x is {"A";"B";"C";"D"} in column A so [x&"-"&TOROW(OFFSET(y,,,99),1)] returns:
4.Use TOCOL function tranform the result in step 3 to one column:
5.Above result becomes a new x in REDUCE function and will calculate with items in column C.
If you have more columns to add, just need to change the second parameter:
Excel Formula:
=REDUCE(A1:A4,B1:D1,LAMBDA(x,y,TOCOL(x&"-"&TOROW(OFFSET(y,,,99),1))))
REDUCE.xlsx | ||||||||
---|---|---|---|---|---|---|---|---|
A | B | C | D | E | F | |||
1 | A | UP | 1 | Apple | A-UP-1-Apple | |||
2 | B | DOWN | 2 | Orange | A-UP-1-Orange | |||
3 | C | 3 | Pear | A-UP-1-Pear | ||||
4 | D | 4 | A-UP-2-Apple | |||||
5 | 5 | A-UP-2-Orange | ||||||
6 | A-UP-2-Pear | |||||||
7 | A-UP-3-Apple | |||||||
8 | A-UP-3-Orange | |||||||
9 | A-UP-3-Pear | |||||||
10 | A-UP-4-Apple | |||||||
11 | A-UP-4-Orange | |||||||
12 | A-UP-4-Pear | |||||||
13 | A-UP-5-Apple | |||||||
14 | A-UP-5-Orange | |||||||
15 | A-UP-5-Pear | |||||||
16 | A-DOWN-1-Apple | |||||||
17 | A-DOWN-1-Orange | |||||||
18 | A-DOWN-1-Pear | |||||||
19 | A-DOWN-2-Apple | |||||||
20 | A-DOWN-2-Orange | |||||||
21 | A-DOWN-2-Pear | |||||||
22 | A-DOWN-3-Apple | |||||||
23 | A-DOWN-3-Orange | |||||||
24 | A-DOWN-3-Pear | |||||||
25 | A-DOWN-4-Apple | |||||||
26 | A-DOWN-4-Orange | |||||||
27 | A-DOWN-4-Pear | |||||||
28 | A-DOWN-5-Apple | |||||||
29 | A-DOWN-5-Orange | |||||||
30 | A-DOWN-5-Pear | |||||||
31 | B-UP-1-Apple | |||||||
32 | B-UP-1-Orange | |||||||
33 | B-UP-1-Pear | |||||||
34 | B-UP-2-Apple | |||||||
35 | B-UP-2-Orange | |||||||
36 | B-UP-2-Pear | |||||||
37 | B-UP-3-Apple | |||||||
38 | B-UP-3-Orange | |||||||
39 | B-UP-3-Pear | |||||||
40 | B-UP-4-Apple | |||||||
41 | B-UP-4-Orange | |||||||
42 | B-UP-4-Pear | |||||||
43 | B-UP-5-Apple | |||||||
44 | B-UP-5-Orange | |||||||
45 | B-UP-5-Pear | |||||||
46 | B-DOWN-1-Apple | |||||||
47 | B-DOWN-1-Orange | |||||||
48 | B-DOWN-1-Pear | |||||||
49 | B-DOWN-2-Apple | |||||||
50 | B-DOWN-2-Orange | |||||||
51 | B-DOWN-2-Pear | |||||||
52 | B-DOWN-3-Apple | |||||||
53 | B-DOWN-3-Orange | |||||||
54 | B-DOWN-3-Pear | |||||||
55 | B-DOWN-4-Apple | |||||||
56 | B-DOWN-4-Orange | |||||||
57 | B-DOWN-4-Pear | |||||||
58 | B-DOWN-5-Apple | |||||||
59 | B-DOWN-5-Orange | |||||||
60 | B-DOWN-5-Pear | |||||||
61 | C-UP-1-Apple | |||||||
62 | C-UP-1-Orange | |||||||
63 | C-UP-1-Pear | |||||||
64 | C-UP-2-Apple | |||||||
65 | C-UP-2-Orange | |||||||
66 | C-UP-2-Pear | |||||||
67 | C-UP-3-Apple | |||||||
68 | C-UP-3-Orange | |||||||
69 | C-UP-3-Pear | |||||||
70 | C-UP-4-Apple | |||||||
71 | C-UP-4-Orange | |||||||
72 | C-UP-4-Pear | |||||||
73 | C-UP-5-Apple | |||||||
74 | C-UP-5-Orange | |||||||
75 | C-UP-5-Pear | |||||||
76 | C-DOWN-1-Apple | |||||||
77 | C-DOWN-1-Orange | |||||||
78 | C-DOWN-1-Pear | |||||||
79 | C-DOWN-2-Apple | |||||||
80 | C-DOWN-2-Orange | |||||||
81 | C-DOWN-2-Pear | |||||||
82 | C-DOWN-3-Apple | |||||||
83 | C-DOWN-3-Orange | |||||||
84 | C-DOWN-3-Pear | |||||||
85 | C-DOWN-4-Apple | |||||||
86 | C-DOWN-4-Orange | |||||||
87 | C-DOWN-4-Pear | |||||||
88 | C-DOWN-5-Apple | |||||||
89 | C-DOWN-5-Orange | |||||||
90 | C-DOWN-5-Pear | |||||||
91 | D-UP-1-Apple | |||||||
92 | D-UP-1-Orange | |||||||
93 | D-UP-1-Pear | |||||||
94 | D-UP-2-Apple | |||||||
95 | D-UP-2-Orange | |||||||
96 | D-UP-2-Pear | |||||||
97 | D-UP-3-Apple | |||||||
98 | D-UP-3-Orange | |||||||
99 | D-UP-3-Pear | |||||||
100 | D-UP-4-Apple | |||||||
101 | D-UP-4-Orange | |||||||
102 | D-UP-4-Pear | |||||||
103 | D-UP-5-Apple | |||||||
104 | D-UP-5-Orange | |||||||
105 | D-UP-5-Pear | |||||||
106 | D-DOWN-1-Apple | |||||||
107 | D-DOWN-1-Orange | |||||||
108 | D-DOWN-1-Pear | |||||||
109 | D-DOWN-2-Apple | |||||||
110 | D-DOWN-2-Orange | |||||||
111 | D-DOWN-2-Pear | |||||||
112 | D-DOWN-3-Apple | |||||||
113 | D-DOWN-3-Orange | |||||||
114 | D-DOWN-3-Pear | |||||||
115 | D-DOWN-4-Apple | |||||||
116 | D-DOWN-4-Orange | |||||||
117 | D-DOWN-4-Pear | |||||||
118 | D-DOWN-5-Apple | |||||||
119 | D-DOWN-5-Orange | |||||||
120 | D-DOWN-5-Pear | |||||||
Sheet1 |
Cell Formulas | ||
---|---|---|
Range | Formula | |
F1:F120 | F1 | =REDUCE(A1:A4,B1:D1,LAMBDA(x,y,TOCOL(x&"-"&TOROW(OFFSET(y,,,99),1)))) |
Dynamic array formulas. |
The second parameter of REDUCE function is B1:D1, so the function will calculate B1, C1, D1 one by one. Let's see what happend when calculating B1.
1. When calculating B1, y stands for B1, [OFFSET(B1,,,99)] returns range B1:B99 (0 for blank cells):
2. Use TOROW function transform values in B1:B99 to a row and ignore blanks:
3.The initial x is {"A";"B";"C";"D"} in column A so [x&"-"&TOROW(OFFSET(y,,,99),1)] returns:
4.Use TOCOL function tranform the result in step 3 to one column:
5.Above result becomes a new x in REDUCE function and will calculate with items in column C.
If you have more columns to add, just need to change the second parameter:
I don't know if I have understood you correctly. Do you mean to list the contents of the string “A-UP-1” in three cells, such as A1="A", B1="UP", and C1="1"?