How to Move Subset of Data from Column to Rows

ohalloran_b

New Member
Joined
Jun 8, 2017
Messages
2
Hi Guys,
I've a scenario where I need to download data from a new tool, send it out to vendors for updates and then upload data back into the tool. Problem is the upload cannot be in the same layout as the download.
I'm having trouble automating the change in layout, transposing won't work, anyone with any ideas?

Download Layout;
<style><!--table {mso-displayed-decimal-separator:"\."; mso-displayed-thousand-separator:"\,";}@page {margin:.75in .7in .75in .7in; mso-header-margin:.3in; mso-footer-margin:.3in;}td {padding-top:1px; padding-right:1px; padding-left:1px; mso-ignore:padding; color:windowtext; font-size:10.0pt; font-weight:400; font-style:normal; text-decoration:none; font-family:Arial; mso-generic-font-family:auto; mso-font-charset:0; mso-number-format:General; text-align:general; vertical-align:top; border:none; mso-background-source:auto; mso-pattern:auto; mso-protection:locked visible; white-space:nowrap; mso-rotate:0;}.xl63 {mso-number-format:"Short Date"; text-align:right;}.xl64 {border:.5pt solid windowtext; background:#F2DCDB; mso-pattern:black none;}--></style>
ArticleSupplier NoHub 11Hub 12Hub 13Hub 14
XX123ZM/A00382601P21/06/201721/06/201721/06/201721/06/2017
ZZ123ZM/A00382601P28/06/201728/06/201728/06/201728/06/2017
AA123ZM/A00567001P05/07/201705/07/201705/07/201705/07/2017

<!--StartFragment--> <colgroup><col width="87" span="6" style="width:65pt"> </colgroup><tbody>
<!--EndFragment--></tbody>


Upload Layout;

Article Number Hub CodeSupplier Number Supply Landing Date
XX123ZM/AHub 1101234567P 21/06/2017
XX123ZM/AHub 1201234567P 21/06/2017
XX123ZM/AHub 1301234567P 21/06/2017
XX123ZM/AHub 1401234567P 21/06/2017
ZZ123ZM/AHub 1112345678P 28/06/2017
ZZ123ZM/AHub 1212345678P 28/06/2017
ZZ123ZM/AHub 1312345678P 28/06/2017
ZZ123ZM/AHub 1412345678P 28/06/2017
AA123ZM/AHub 1123456789P 05/07/2017
AA123ZM/AHub 1223456789P 05/07/2017
AA123ZM/AHub 1323456789P 05/07/2017
AA123ZM/AHub 1423456789P 05/07/2017

<colgroup><col><col><col><col></colgroup><tbody>
</tbody>
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
Try this for results starting "H1".
Code:
[COLOR="Navy"]Sub[/COLOR] MG08Jun49
[COLOR="Navy"]Dim[/COLOR] Ray [COLOR="Navy"]As[/COLOR] Variant, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ac [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] Ac2 [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
Ray = Cells(1).CurrentRegion
ReDim nray(1 To UBound(Ray, 1) * UBound(Ray, 2), 1 To 4)
nray(1, 1) = "Article Number": nray(1, 2) = "Hub Code"
nray(1, 3) = "Supplier Number": nray(1, 4) = "Supply Landing Date"
c = 1
[COLOR="Navy"]For[/COLOR] n = 2 To UBound(Ray, 1)
    [COLOR="Navy"]For[/COLOR] Ac = 3 To UBound(Ray, 2)
       c = c + 1
        nray(c, 1) = Ray(n, 1)
        nray(c, 2) = Ray(1, Ac)
        nray(c, 3) = Ray(n, 2)
        nray(c, 4) = Ray(n, Ac)
    [COLOR="Navy"]Next[/COLOR] Ac
[COLOR="Navy"]Next[/COLOR] n
Range("H1").Resize(c, 4).Value = nray
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
ohalloran_b,

Welcome to the MrExcel forum.


Where are you getting the Supplier Number's from for your Upload Layout?
 
Upvote 0
ohalloran_b,

Here is another macro solution for you to consider, that use two arrays in memory, that will adjust to the number of raw data rows, and, columns.

You can change the raw data worksheet name in the macro.

The macro will create a new worksheet Results.

Sample raw data:


Excel 2007
ABCDEFG
1ArticleSupplier NoHub 11Hub 12Hub 13Hub 14
2XX123ZM/A00382601P21/06/201721/06/201721/06/201721/06/2017
3ZZ123ZM/A00382601P28/06/201728/06/201728/06/201728/06/2017
4AA123ZM/A00567001P05/07/201705/07/201705/07/201705/07/2017
5
Sheet1


And, after the macro in a new worksheet Results:


Excel 2007
ABCD
1Article NumberHub CodeSupplier NumberSupply Landing Date
2XX123ZM/AHub 1100382601P21/06/2017
3XX123ZM/AHub 1200382601P21/06/2017
4XX123ZM/AHub 1300382601P21/06/2017
5XX123ZM/AHub 1400382601P21/06/2017
6ZZ123ZM/AHub 1100382601P28/06/2017
7ZZ123ZM/AHub 1200382601P28/06/2017
8ZZ123ZM/AHub 1300382601P28/06/2017
9ZZ123ZM/AHub 1400382601P28/06/2017
10AA123ZM/AHub 1100567001P05/07/2017
11AA123ZM/AHub 1200567001P05/07/2017
12AA123ZM/AHub 1300567001P05/07/2017
13AA123ZM/AHub 1400567001P05/07/2017
14
Upload


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ReorganizeData()
' hiker95, 06/08/2017, ME1008838
Dim w1 As Worksheet, wu As Worksheet
Dim a As Variant, i As Long, c As Long, lr As Long, lc As Long, n As Long
Dim o As Variant, j As Long
Application.ScreenUpdating = False
Set w1 = Sheets("Sheet1")     '<-- you can change the sheet name here
If Not Evaluate("ISREF(Upload!A1)") Then Worksheets.Add(After:=w1).Name = "Upload"
Set wu = Worksheets("Upload")
wu.UsedRange.Clear
With w1
  lr = .Cells(Rows.Count, 1).End(xlUp).Row
  lc = .Cells(1, Columns.Count).End(xlToLeft).Column
  a = .Range(.Cells(1, 1), .Cells(lr, lc))
  n = Application.CountA(.Range(.Cells(2, 3), .Cells(lr, lc)))
  ReDim o(1 To n + 1, 1 To 4)
  j = j + 1: o(j, 1) = "Article Number": o(j, 2) = "Hub Code"
  o(j, 3) = "Supplier Number": o(j, 4) = "Supply Landing Date"
End With
For i = 2 To lr
  For c = 3 To lc
    j = j + 1: o(j, 1) = a(i, 1): o(j, 2) = a(1, c): o(j, 3) = a(i, 2): o(j, 4) = a(i, c)
  Next c
Next i
With wu
  .Cells(1, 1).Resize(UBound(o, 1), UBound(o, 2)) = o
  .Cells(1, 1).Resize(, UBound(o, 2)).Font.Bold = True
  .UsedRange.Columns.AutoFit
  .Activate
End With
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the ReorganizeData macro.
 
Upvote 0
ohalloran_b,

You are very welcome. Glad we could help.

We will be watching for your next reply.
 
Upvote 0

Forum statistics

Threads
1,215,500
Messages
6,125,166
Members
449,210
Latest member
grifaz

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