Return variable list based on header

sergiopcrt

New Member
Joined
May 12, 2017
Messages
12
Hi Everyone,

I don't know if this is possible but I have 100+ columns like this

Cat1 | Cat2
place1 Place3
place2 Place5
place3 Place6
Place7

the columns have variable length and I need to transform them in

Cat1 | place1
Cat1 | place2
Cat1 | place3

And do this in either different sheet or workbook, one table for each Cat.
Do you know if this is possible? Any help would be appreciated.

Regards,
Sérgio
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Run this macro
Change the name of the sheets "origin" and "destination" to the names of your sheets.

VBA Code:
Sub Return_list()
  Dim a As Variant, b As Variant
  Dim lr As Long, lc As Long, i As Long, j As Long, k As Long
  Dim sh1 As Worksheet, sh2 As Worksheet
  '
  Set sh1 = Sheets("origin")
  Set sh2 = Sheets("destination")
  lr = sh1.UsedRange.Rows(sh1.UsedRange.Rows.Count).Row
  lc = sh1.Cells(1, Columns.Count).End(xlToLeft).Column
  '
  a = sh1.Range("A1", sh1.Cells(lr, lc)).Value2
  ReDim b(1 To lr, 1 To lc * 2)
  k = 1
  For j = 1 To UBound(a, 2)
    For i = 2 To UBound(a, 1)
      If a(i, j) <> "" Then b(i, k) = a(1, j)
      b(i, k + 1) = a(i, j)
    Next
    k = k + 2
  Next
  sh2.Range("A1").Resize(lr, lc * 2).Value = b
End Sub

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (Return_list) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.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.
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,383
Messages
6,119,196
Members
448,874
Latest member
Lancelots

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