Copy and Realign Data on New Sheet

boilermaker1997

New Member
Joined
Sep 20, 2007
Messages
41
I have an Excel file that contains two sheet - Data Drop and Data Upload. Data drop contains a table with country and currency codes. The data is arranged in a tabular format so that currencies are running both across a row and down a column. The intersection of two currencies is their exchange rate. I need a macro that would copy the data from 'Data Drop' and rearrange it in 'Data Upload'.

Data Upload rearranges the data so that the currencies/countries listed in the column are copied and stacked on top of each other based on the number of currencies listed in row 2. The currencies in row 2 are then assigned to each grouping in the stack.

Finally the rates that are associated with each combination are then copied and pasted in Data Upload.

The image below shows the two tabs and how they should look.

The number of currencies in both row 2 (in the example 3) and column B (in the example 5) can vary from month to month.

Can anyone help with a macro that would automate this process and take into account the variability in the rows and columns on a monthly basis?

Thanks,
Boilermaker


<b>Excel 2003</b><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th><th>F</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-decoration: underline;;">Sheet: Data Drop</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="font-weight: bold;text-align: right;text-decoration: underline;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-decoration: underline;;">Column</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style=";">Row</td><td style="font-weight: bold;text-align: center;;">A</td><td style="font-weight: bold;text-align: center;;">B</td><td style="font-weight: bold;text-align: center;;">C</td><td style="font-weight: bold;text-align: center;;">D</td><td style="font-weight: bold;text-align: center;;">E</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="font-weight: bold;text-align: center;;">1</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">India</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">Indonesia</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">Italy</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="font-weight: bold;text-align: center;;">2</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">INR</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">IDR</td><td style="font-weight: bold;text-align: center;text-decoration: underline;;">EURO</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="font-weight: bold;text-align: center;;">3</td><td style="font-weight: bold;;">Australia</td><td style="font-weight: bold;;">AUD</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td><td style="text-align: right;;">5</td><td style="text-align: right;;">9</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="font-weight: bold;text-align: center;;">4</td><td style="font-weight: bold;;">Belgium</td><td style="font-weight: bold;;">EURO</td><td style="text-align: right;;">1</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td><td style="text-align: right;;">10</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="font-weight: bold;text-align: center;;">5</td><td style="font-weight: bold;;">Canada</td><td style="font-weight: bold;;">CAD</td><td style="text-align: right;;">2</td><td style="text-align: right;;">6</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="font-weight: bold;text-align: center;;">6</td><td style="font-weight: bold;;">Chile</td><td style="font-weight: bold;;">CLP</td><td style="text-align: right;;">3</td><td style="text-align: right;;">7</td><td style="text-align: right;;">11</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="font-weight: bold;text-align: center;;">7</td><td style="font-weight: bold;;">China</td><td style="font-weight: bold;;">CNY</td><td style="text-align: right;;">4</td><td style="text-align: right;;">8</td><td style="text-align: right;;">12</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">14</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">15</td><td style="font-weight: bold;text-decoration: underline;;">Sheet Data Upload</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">16</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-decoration: underline;;">Column</td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">17</td><td style="text-align: right;;"></td><td style="font-weight: bold;text-align: right;text-decoration: underline;;"></td><td style="font-weight: bold;text-align: right;;"></td><td style="font-weight: bold;text-align: center;text-decoration: underline;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">18</td><td style=";">Row</td><td style="font-weight: bold;text-align: center;;">A</td><td style="font-weight: bold;text-align: center;;">B</td><td style="font-weight: bold;text-align: center;;">C</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">19</td><td style="font-weight: bold;text-align: center;;">1</td><td style=";">INR</td><td style=";">Australia</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">20</td><td style="font-weight: bold;text-align: center;;">2</td><td style=";">INR</td><td style=";">Belgium</td><td style="text-align: right;;">1</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">21</td><td style="font-weight: bold;text-align: center;;">3</td><td style=";">INR</td><td style=";">Canada</td><td style="text-align: right;;">2</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">22</td><td style="font-weight: bold;text-align: center;;">4</td><td style=";">INR</td><td style=";">Chile</td><td style="text-align: right;;">3</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">23</td><td style="font-weight: bold;text-align: center;;">5</td><td style=";">INR</td><td style=";">China</td><td style="text-align: right;;">4</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">24</td><td style="font-weight: bold;text-align: center;;">6</td><td style=";">IDR</td><td style=";">Australia</td><td style="text-align: right;;">5</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">25</td><td style="font-weight: bold;text-align: center;;">7</td><td style=";">IDR</td><td style=";">Belgium</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">26</td><td style="font-weight: bold;text-align: center;;">8</td><td style=";">IDR</td><td style=";">Canada</td><td style="text-align: right;;">6</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">27</td><td style="font-weight: bold;text-align: center;;">9</td><td style=";">IDR</td><td style=";">Chile</td><td style="text-align: right;;">7</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">28</td><td style="font-weight: bold;text-align: center;;">10</td><td style=";">IDR</td><td style=";">China</td><td style="text-align: right;;">8</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">29</td><td style="font-weight: bold;text-align: center;;">11</td><td style=";">EURO</td><td style=";">Australia</td><td style="text-align: right;;">9</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">30</td><td style="font-weight: bold;text-align: center;;">12</td><td style=";">EURO</td><td style=";">Belgium</td><td style="text-align: right;;">10</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">31</td><td style="font-weight: bold;text-align: center;;">13</td><td style=";">EURO</td><td style=";">Canada</td><td style="font-weight: bold;text-align: center;text-decoration: underline;background-color: #C0C0C0;;"></td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">32</td><td style="font-weight: bold;text-align: center;;">14</td><td style=";">EURO</td><td style=";">Chile</td><td style="text-align: right;;">11</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr><tr ><td style="color: #161120;text-align: center;">33</td><td style="font-weight: bold;text-align: center;;">15</td><td style=";">EURO</td><td style=";">China</td><td style="text-align: right;;">12</td><td style="text-align: right;;"></td><td style="text-align: right;;"></td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet1</p><br /><br />
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Try this:-
Code:
[COLOR="Navy"]Sub[/COLOR] MG29Sep13
[COLOR="Navy"]Dim[/COLOR] Rng     [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Dn      [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] c       [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Last    [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Ac      [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
c = 1
[COLOR="Navy"]With[/COLOR] Sheets("Data Drop")
    Last = .Cells("2", Columns.Count).End(xlToLeft).Column
    [COLOR="Navy"]Set[/COLOR] Rng = .Range(.Range("A3"), .Range("A" & Rows.Count).End(xlUp)).Resize(, Last)
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]For[/COLOR] Ac = 3 To Last
    [COLOR="Navy"]With[/COLOR] Sheets("Data Upload")
        .Cells(c, 2).Resize(Rng.Rows.Count, 2) = Application.Index(Rng, Evaluate("row(1:" & Rng.Rows.Count & ")"), Array(1, Ac))
        .Cells(c, 1).Resize(Rng.Rows.Count) = Cells(2, Ac)
        c = c + Rng.Rows.Count
    [COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]Next[/COLOR] Ac
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
I've tested the code a few times. At first glance, it looks like it is working perfectly. I'm going to try it a few more times. I'll let you know if there are issues.

Thanks for your help.
 
Upvote 0

Forum statistics

Threads
1,224,537
Messages
6,179,405
Members
452,911
Latest member
a_barila

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