Change Table Formatting

Pestomania

Active Member
Joined
May 30, 2018
Messages
292
Office Version
  1. 365
Platform
  1. Windows
Good day,

How can I cycle through a much larger table than you see here, but with this formatting and rearrange the results to look like the second table below?

Program 1Program 2Program 3
1/31/2024​
84​
63​
0​
2/29/2024​
84​
63​
0​
3/31/2024​
84​
63​
7​
4/30/2024​
84​
63​
0​
5/31/2024​
84​
63​
7​
6/30/2024​
84​
63​
0​
7/31/2024​
84​
63​
0​
8/31/2024​
84​
63​
7​
9/30/2024​
84​
63​
0​
10/31/2024​
84​
63​
7​
11/30/2024​
84​
63​
0​
12/31/2024​
84​
63​
7​
1/31/2025​
84​
63​
0​
2/28/2025​
84​
63​
0​
3/31/2025​
84​
63​
7​
4/30/2025​
84​
63​
0​
5/31/2025​
84​
63​
7​
6/30/2025​
84​
63​
0​
7/31/2025​
84​
63​
0​
8/31/2025​
84​
63​
7​
9/30/2025​
84​
63​
0​


1/31/2024​
84​
Program 1
2/29/2024​
84​
Program 1
3/31/2024​
84​
Program 1
4/30/2024​
84​
Program 1
5/31/2024​
84​
Program 1
6/30/2024​
84​
Program 1
7/31/2024​
84​
Program 1
8/31/2024​
84​
Program 1
9/30/2024​
84​
Program 1
10/31/2024​
84​
Program 1
11/30/2024​
84​
Program 1
12/31/2024​
84​
Program 1
1/31/2025​
84​
Program 1
2/28/2025​
84​
Program 1
3/31/2025​
84​
Program 1
4/30/2025​
84​
Program 1
5/31/2025​
84​
Program 1
6/30/2025​
84​
Program 1
7/31/2025​
84​
Program 1
8/31/2025​
84​
Program 1
1/31/2024​
63​
Program 2
2/29/2024​
63​
Program 2
3/31/2024​
63​
Program 2
4/30/2024​
63​
Program 2
5/31/2024​
63​
Program 2
6/30/2024​
63​
Program 2
7/31/2024​
63​
Program 2
8/31/2024​
63​
Program 2
9/30/2024​
63​
Program 2
10/31/2024​
63​
Program 2
11/30/2024​
63​
Program 2
12/31/2024​
63​
Program 2
1/31/2025​
63​
Program 2
2/28/2025​
63​
Program 2
3/31/2025​
63​
Program 2
4/30/2025​
63​
Program 2
5/31/2025​
63​
Program 2
6/30/2025​
63​
Program 2
7/31/2025​
63​
Program 2
8/31/2025​
63​
Program 2
3/31/2024​
7​
Program 3
5/31/2024​
7​
Program 3
8/31/2024​
7​
Program 3
10/31/2024​
7​
Program 3
12/31/2024​
7​
Program 3
3/31/2025​
7​
Program 3
5/31/2025​
7​
Program 3
8/31/2025​
7​
Program 3


It rearranges them to put them in the correct format of:

First column = Date
Second Column = Qty (I exclude all zeroes from the new table)
Third Column = Program Name
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
You can use Power Query to Un-Pivot data which is what you're asking for.
There are also formulas, but they are more complicated. Since you say you already have tables, the data is easily imported into Power Query.

Here is a video that explains it:
 
Upvote 0
Here's one of those complicated formulas:

Book1
ABCDEFGH
1Program 1Program 2Program 3
21/31/2024846301/31/202484Program 1
32/29/2024846302/29/202484Program 1
43/31/2024846373/31/202484Program 1
54/30/2024846304/30/202484Program 1
65/31/2024846375/31/202484Program 1
76/30/2024846306/30/202484Program 1
87/31/2024846307/31/202484Program 1
98/31/2024846378/31/202484Program 1
109/30/2024846309/30/202484Program 1
1110/31/20248463710/31/202484Program 1
1211/30/20248463011/30/202484Program 1
1312/31/20248463712/31/202484Program 1
141/31/2025846301/31/202584Program 1
152/28/2025846302/28/202584Program 1
163/31/2025846373/31/202584Program 1
174/30/2025846304/30/202584Program 1
185/31/2025846375/31/202584Program 1
196/30/2025846306/30/202584Program 1
207/31/2025846307/31/202584Program 1
218/31/2025846378/31/202584Program 1
229/30/2025846309/30/202584Program 1
231/31/202463Program 2
242/29/202463Program 2
253/31/202463Program 2
264/30/202463Program 2
275/31/202463Program 2
286/30/202463Program 2
297/31/202463Program 2
308/31/202463Program 2
319/30/202463Program 2
3210/31/202463Program 2
3311/30/202463Program 2
3412/31/202463Program 2
351/31/202563Program 2
362/28/202563Program 2
373/31/202563Program 2
384/30/202563Program 2
395/31/202563Program 2
406/30/202563Program 2
417/31/202563Program 2
428/31/202563Program 2
439/30/202563Program 2
443/31/20247Program 3
455/31/20247Program 3
468/31/20247Program 3
4710/31/20247Program 3
4812/31/20247Program 3
493/31/20257Program 3
505/31/20257Program 3
518/31/20257Program 3
Sheet2
Cell Formulas
RangeFormula
F2:H51F2=LET(d,A2:D22,h,B1:D1,rw,ROWS(d),cl,COLUMNS(d)-1,s,SEQUENCE(rw*cl,,0),acol,INDEX(d,MOD(s,rw)+1,1),bcol,INDEX(d,MOD(s,rw)+1,INT(s/rw)+2),ccol,INDEX(h,INT(s/rw)+1),t,CHOOSE({1,2,3},acol,bcol,ccol),tt,FILTER(t,bcol>0),SORT(tt,{3,1},{1,1}))
Dynamic array formulas.


This would be easier with VSTACK.
 
Upvote 1
You can use Power Query to Un-Pivot data which is what you're asking for.
There are also formulas, but they are more complicated. Since you say you already have tables, the data is easily imported into Power Query.

Here is a video that explains it:
Unfortunately our company won't let us use Power Query :(

thank you for the recommendation though!
 
Upvote 0
Another formula option
Fluff.xlsm
ABCDEFGH
1Program 1Program 2Program 3
231/01/20248463031/01/202484Program 1
329/02/20248463029/02/202484Program 1
431/03/20248463731/03/202484Program 1
530/04/20248463030/04/202484Program 1
631/05/20248463731/05/202484Program 1
730/06/20248463030/06/202484Program 1
831/07/20248463031/07/202484Program 1
931/08/20248463731/08/202484Program 1
1030/09/20248463030/09/202484Program 1
1131/10/20248463731/10/202484Program 1
1230/11/20248463030/11/202484Program 1
1331/12/20248463731/12/202484Program 1
1431/01/20258463031/01/202584Program 1
1528/02/20258463028/02/202584Program 1
1631/03/20258463731/03/202584Program 1
1730/04/20258463030/04/202584Program 1
1831/05/20258463731/05/202584Program 1
1930/06/20258463030/06/202584Program 1
2031/07/20258463031/07/202584Program 1
2131/08/20258463731/08/202584Program 1
2230/09/20258463030/09/202584Program 1
2331/01/202463Program 2
2429/02/202463Program 2
2531/03/202463Program 2
2630/04/202463Program 2
2731/05/202463Program 2
2830/06/202463Program 2
2931/07/202463Program 2
3031/08/202463Program 2
3130/09/202463Program 2
3231/10/202463Program 2
3330/11/202463Program 2
3431/12/202463Program 2
3531/01/202563Program 2
3628/02/202563Program 2
3731/03/202563Program 2
3830/04/202563Program 2
3931/05/202563Program 2
4030/06/202563Program 2
4131/07/202563Program 2
4231/08/202563Program 2
4330/09/202563Program 2
4431/03/20247Program 3
4531/05/20247Program 3
4631/08/20247Program 3
4731/10/20247Program 3
4831/12/20247Program 3
4931/03/20257Program 3
5031/05/20257Program 3
5131/08/20257Program 3
52
Sheet6
Cell Formulas
RangeFormula
F2:H51F2=HSTACK(TOCOL(IF(B2:D200<>0,A2:A200,1/0),2,1),TOCOL(IF(B2:D200<>0,B2:D200,1/0),2,1),TOCOL(IF(B2:D200<>0,B1:D1,1/0),2,1))
Dynamic array formulas.
 
Upvote 1
Solution
Another formula option
Fluff.xlsm
ABCDEFGH
1Program 1Program 2Program 3
231/01/20248463031/01/202484Program 1
329/02/20248463029/02/202484Program 1
431/03/20248463731/03/202484Program 1
530/04/20248463030/04/202484Program 1
631/05/20248463731/05/202484Program 1
730/06/20248463030/06/202484Program 1
831/07/20248463031/07/202484Program 1
931/08/20248463731/08/202484Program 1
1030/09/20248463030/09/202484Program 1
1131/10/20248463731/10/202484Program 1
1230/11/20248463030/11/202484Program 1
1331/12/20248463731/12/202484Program 1
1431/01/20258463031/01/202584Program 1
1528/02/20258463028/02/202584Program 1
1631/03/20258463731/03/202584Program 1
1730/04/20258463030/04/202584Program 1
1831/05/20258463731/05/202584Program 1
1930/06/20258463030/06/202584Program 1
2031/07/20258463031/07/202584Program 1
2131/08/20258463731/08/202584Program 1
2230/09/20258463030/09/202584Program 1
2331/01/202463Program 2
2429/02/202463Program 2
2531/03/202463Program 2
2630/04/202463Program 2
2731/05/202463Program 2
2830/06/202463Program 2
2931/07/202463Program 2
3031/08/202463Program 2
3130/09/202463Program 2
3231/10/202463Program 2
3330/11/202463Program 2
3431/12/202463Program 2
3531/01/202563Program 2
3628/02/202563Program 2
3731/03/202563Program 2
3830/04/202563Program 2
3931/05/202563Program 2
4030/06/202563Program 2
4131/07/202563Program 2
4231/08/202563Program 2
4330/09/202563Program 2
4431/03/20247Program 3
4531/05/20247Program 3
4631/08/20247Program 3
4731/10/20247Program 3
4831/12/20247Program 3
4931/03/20257Program 3
5031/05/20257Program 3
5131/08/20257Program 3
52
Sheet6
Cell Formulas
RangeFormula
F2:H51F2=HSTACK(TOCOL(IF(B2:D200<>0,A2:A200,1/0),2,1),TOCOL(IF(B2:D200<>0,B2:D200,1/0),2,1),TOCOL(IF(B2:D200<>0,B1:D1,1/0),2,1))
Dynamic array formulas.

I like this one a lot too!! Easier to interpret :)

Thank you!
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,215,374
Messages
6,124,571
Members
449,173
Latest member
Kon123

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