VBA code to change format of table

KK3008

New Member
Joined
May 8, 2019
Messages
8
Hi,

I am trying to change the format of this table (un-pivot)-

[TABLE="class: cms_table_outer_border, width: 500"]
<tbody>[TR]
[TD][/TD]
[TD][/TD]
[TD]A1[/TD]
[TD]A1[/TD]
[TD]A1[/TD]
[TD][/TD]
[TD]A2[/TD]
[TD]A2[/TD]
[TD]A2[/TD]
[/TR]
[TR]
[TD]YEAR[/TD]
[TD]Floorset[/TD]
[TD]Target[/TD]
[TD]Instore[/TD]
[TD]Newness[/TD]
[TD][/TD]
[TD]Target[/TD]
[TD]Instore[/TD]
[TD]Newness[/TD]
[/TR]
[TR]
[TD]FY20[/TD]
[TD][/TD]
[TD]100[/TD]
[TD]89[/TD]
[TD]25[/TD]
[TD][/TD]
[TD]200[/TD]
[TD]193[/TD]
[TD]55[/TD]
[/TR]
</tbody>[/TABLE]


To look like this-

[TABLE="class: cms_table_outer_border, width: 500"]
<tbody>[TR]
[TD]Business[/TD]
[TD]YEAR[/TD]
[TD]Floorset[/TD]
[TD]Target[/TD]
[TD]Instore[/TD]
[TD]Newness[/TD]
[/TR]
[TR]
[TD]A1[/TD]
[TD]FY20[/TD]
[TD][/TD]
[TD]100[/TD]
[TD]89[/TD]
[TD]25[/TD]
[/TR]
[TR]
[TD]A2[/TD]
[TD]FY20[/TD]
[TD][/TD]
[TD]200[/TD]
[TD]193[/TD]
[TD]55[/TD]
[/TR]
</tbody>[/TABLE]


Could someone help me with the VBA code for this please?

Thanks in advance!
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
If your data is like this

<table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Sheet1</b></td></tr></table>
<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td><td >I</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; "> </td><td style="background-color:#92d050; "> </td><td style="background-color:#92d050; ">A1</td><td style="background-color:#92d050; ">A1</td><td style="background-color:#92d050; ">A1</td><td style="background-color:#92d050; "> </td><td style="background-color:#92d050; ">A2</td><td style="background-color:#92d050; ">A2</td><td style="background-color:#92d050; ">A2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >YEAR</td><td >Floorset</td><td >Target</td><td >Instore</td><td >Newness</td><td > </td><td >Target</td><td >Instore</td><td >Newness</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >FY20</td><td > </td><td style="text-align:right; ">100</td><td style="text-align:right; ">89</td><td style="text-align:right; ">25</td><td > </td><td style="text-align:right; ">200</td><td style="text-align:right; ">193</td><td style="text-align:right; ">55</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >FY21</td><td > </td><td style="text-align:right; ">101</td><td style="text-align:right; ">90</td><td style="text-align:right; ">26</td><td > </td><td style="text-align:right; ">201</td><td style="text-align:right; ">194</td><td style="text-align:right; ">56</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >FY22</td><td > </td><td style="text-align:right; ">102</td><td style="text-align:right; ">91</td><td style="text-align:right; ">27</td><td > </td><td style="text-align:right; ">202</td><td style="text-align:right; ">195</td><td style="text-align:right; ">57</td></tr></table>

The result will be like this
<table style="font-family:Arial; font-size:12pt; border-style: groove ;border-color:#0000FF;background-color:#fffcf9; color:#000000; "><tr><td ><b>Sheet2</b></td></tr></table>
<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Business</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">YEAR</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Floorset</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Target</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Instore</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Newness</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >A1</td><td >FY20</td><td > </td><td style="text-align:right; ">100</td><td style="text-align:right; ">89</td><td style="text-align:right; ">25</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >A2</td><td >FY20</td><td > </td><td style="text-align:right; ">200</td><td style="text-align:right; ">193</td><td style="text-align:right; ">55</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >A1</td><td >FY21</td><td > </td><td style="text-align:right; ">101</td><td style="text-align:right; ">90</td><td style="text-align:right; ">26</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >A2</td><td >FY21</td><td > </td><td style="text-align:right; ">201</td><td style="text-align:right; ">194</td><td style="text-align:right; ">56</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >A1</td><td >FY22</td><td > </td><td style="text-align:right; ">102</td><td style="text-align:right; ">91</td><td style="text-align:right; ">27</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >A2</td><td >FY22</td><td > </td><td style="text-align:right; ">202</td><td style="text-align:right; ">195</td><td style="text-align:right; ">57</td></tr></table>

Use this:
Code:
Sub change_format()
    Dim sh1 As Worksheet, sh2 As Worksheet
    Dim c As Range, k As Long, j As Long
    
    Set sh1 = Sheets("Sheet1")
    Set sh2 = Sheets("Sheet2")
    
    sh2.Rows("2:" & Rows.Count).ClearContents
    k = 2
    For Each c In sh1.Range("A3", sh1.Range("A" & Rows.Count).End(xlUp))
        For j = 3 To sh1.Cells(1, Columns.Count).End(xlToLeft).Column Step 4
            sh2.Cells(k, "A").Value = sh1.Cells(1, j).Value
            sh2.Cells(k, "B").Value = c.Value
            sh2.Cells(k, "C").Value = c.Offset(0, 1).Value
            sh2.Cells(k, "D").Resize(1, 3).Value = sh1.Cells(c.Row, j).Resize(1, 3).Value
            k = k + 1
        Next
    Next
    MsgBox "End"
End Sub
 
Upvote 0
Hi Dante Amor, thank you so much!

How can the code be modified for such a modification in the table?-

Input table-

[TABLE="width: 896"]
<colgroup><col span="14"></colgroup><tbody>[TR]
[TD][/TD]
[TD][/TD]
[TD="colspan: 2, align: center"]A[/TD]
[TD] [/TD]
[TD] [/TD]
[TD="colspan: 2, align: center"]B[/TD]
[TD] [/TD]
[TD] [/TD]
[TD="colspan: 2, align: center"]C[/TD]
[TD] [/TD]
[TD] [/TD]
[/TR]
[TR]
[TD]STORE RECEIPT WEEK[/TD]
[TD]Floorset[/TD]
[TD]TARGET[/TD]
[TD]In Store[/TD]
[TD]Newness[/TD]
[TD]Actual Places[/TD]
[TD]TARGET[/TD]
[TD]In Store[/TD]
[TD]Newness[/TD]
[TD]Actual Places[/TD]
[TD]TARGET[/TD]
[TD]In Store[/TD]
[TD]Newness[/TD]
[TD]Actual Places[/TD]
[/TR]
[TR]
[TD]Apr Wk1[/TD]
[TD]APR PT 2 FLOORSET[/TD]
[TD]100[/TD]
[TD]89[/TD]
[TD]25[/TD]
[TD]100[/TD]
[TD]100[/TD]
[TD]89[/TD]
[TD]25[/TD]
[TD]100[/TD]
[TD]100[/TD]
[TD]89[/TD]
[TD]25[/TD]
[TD]100[/TD]
[/TR]
[TR]
[TD]Apr Wk2[/TD]
[TD] [/TD]
[TD]101[/TD]
[TD]89[/TD]
[TD]26[/TD]
[TD]101[/TD]
[TD]101[/TD]
[TD]89[/TD]
[TD]26[/TD]
[TD]101[/TD]
[TD]101[/TD]
[TD]89[/TD]
[TD]26[/TD]
[TD]101[/TD]
[/TR]
[TR]
[TD]Apr WK3[/TD]
[TD] [/TD]
[TD]102[/TD]
[TD]89[/TD]
[TD]27[/TD]
[TD]102[/TD]
[TD]102[/TD]
[TD]89[/TD]
[TD]27[/TD]
[TD]102[/TD]
[TD]102[/TD]
[TD]89[/TD]
[TD]27[/TD]
[TD]102[/TD]
[/TR]
[TR]
[TD]Apr WK4[/TD]
[TD] [/TD]
[TD]103[/TD]
[TD]89[/TD]
[TD]28[/TD]
[TD]103[/TD]
[TD]103[/TD]
[TD]89[/TD]
[TD]28[/TD]
[TD]103[/TD]
[TD]103[/TD]
[TD]89[/TD]
[TD]28[/TD]
[TD]103[/TD]
[/TR]
</tbody>[/TABLE]


Desired Output-

[TABLE="width: 448"]
<colgroup><col width="64" span="7" style="width: 48pt;"></colgroup><tbody>[TR]
[TD="class: xl78, width: 64"]Business[/TD]
[TD="class: xl65, width: 64"]STORE RECEIPT WEEK[/TD]
[TD="class: xl65, width: 64"]Floorset[/TD]
[TD="class: xl65, width: 64"]TARGET[/TD]
[TD="class: xl66, width: 64"]In Store[/TD]
[TD="class: xl66, width: 64"]Newness[/TD]
[TD="class: xl67, width: 64"]Actual Places[/TD]
[/TR]
[TR]
[TD="class: xl80"]A[/TD]
[TD="class: xl68"]Apr Wk1[/TD]
[TD="class: xl69"]APR PT 2 FLOORSET[/TD]
[TD="class: xl70"]100[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]25[/TD]
[TD="class: xl71"]100[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr Wk2[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]101[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]26[/TD]
[TD="class: xl71"]101[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr WK3[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]102[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]27[/TD]
[TD="class: xl71"]102[/TD]
[/TR]
[TR]
[TD="class: xl81"] [/TD]
[TD="class: xl75"]Apr WK4[/TD]
[TD="class: xl75"] [/TD]
[TD="class: xl76"]103[/TD]
[TD="class: xl77"]89[/TD]
[TD="class: xl74"]28[/TD]
[TD="class: xl77"]103[/TD]
[/TR]
[TR]
[TD="class: xl80"]B[/TD]
[TD="class: xl68"]Apr Wk1[/TD]
[TD="class: xl69"]APR PT 2 FLOORSET[/TD]
[TD="class: xl70"]100[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]25[/TD]
[TD="class: xl71"]100[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr Wk2[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]101[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]26[/TD]
[TD="class: xl71"]101[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr WK3[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]102[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]27[/TD]
[TD="class: xl71"]102[/TD]
[/TR]
[TR]
[TD="class: xl81"] [/TD]
[TD="class: xl75"]Apr WK4[/TD]
[TD="class: xl75"] [/TD]
[TD="class: xl76"]103[/TD]
[TD="class: xl77"]89[/TD]
[TD="class: xl74"]28[/TD]
[TD="class: xl77"]103[/TD]
[/TR]
[TR]
[TD="class: xl79"]C[/TD]
[TD="class: xl68"]Apr Wk1[/TD]
[TD="class: xl69"]APR PT 2 FLOORSET[/TD]
[TD="class: xl70"]100[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]25[/TD]
[TD="class: xl71"]100[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr Wk2[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]101[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]26[/TD]
[TD="class: xl71"]101[/TD]
[/TR]
[TR]
[TD="class: xl79"] [/TD]
[TD="class: xl73"]Apr WK3[/TD]
[TD="class: xl73"] [/TD]
[TD="class: xl70"]102[/TD]
[TD="class: xl71"]89[/TD]
[TD="class: xl72"]27[/TD]
[TD="class: xl71"]102[/TD]
[/TR]
[TR]
[TD="class: xl81"][/TD]
[TD="class: xl75"]Apr WK4[/TD]
[TD="class: xl75"] [/TD]
[TD="class: xl76"]103[/TD]
[TD="class: xl77"]89[/TD]
[TD="class: xl74"]28[/TD]
[TD="class: xl77"]103[/TD]
[/TR]
</tbody>[/TABLE]


Any help would be great.

Thank you!
 
Upvote 0

Forum statistics

Threads
1,223,897
Messages
6,175,269
Members
452,628
Latest member
dd2

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