Trying to pivot two columns

furthark

New Member
Joined
Aug 29, 2021
Messages
4
Office Version
  1. 365
Platform
  1. Windows
I am trying to take over 300,000 rows of information under two columns and pivot that information into two rows — header and data underneath those headers. One of the columns has repetitive headers alongside another which has the information that’s supposed to be under each header.

I have been looking for examples and have not worked with pivot features on Excel. Any assistance on this is greatly appreciated. I’m currently going line by line and doing the cut and paste method.

The provided image is simply an example of what I’m trying to accomplish.
 

Attachments

  • CB8980AA-89B9-4AC2-A825-A8913B6D391D.jpeg
    CB8980AA-89B9-4AC2-A825-A8913B6D391D.jpeg
    201.5 KB · Views: 7

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
Welcome to the MrExcel Message Board!

Your data in columns A and B, starting at A1.
Results in D1 onwards.

Try this macro:
VBA Code:
Sub pivot_two_columns()
  Dim a As Variant, b As Variant
  Dim dic As Object
  Dim i As Long, j As Long, k As Long, n As Long
 
  Set dic = CreateObject("Scripting.Dictionary")
  Range("D1", Cells(Rows.Count, Columns.Count)).ClearContents
 
  a = Range("A1", Range("B" & Rows.Count).End(3)).Value
  ReDim b(1 To UBound(a, 1), 1 To UBound(a, 1))
  For i = 1 To UBound(a, 1)
    If Not dic.exists(a(i, 2)) Then
      j = 2
      k = k + 1
      b(1, k) = a(i, 2)
    Else
      j = Split(dic(a(i, 2)), "|")(0) + 1
      k = Split(dic(a(i, 2)), "|")(1)
    End If
    dic(a(i, 2)) = j & "|" & k
    If j > n Then n = j
    b(j, k) = a(i, 1)
  Next
  Range("D1").Resize(n, k).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 (pivot_two_columns) 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.
 
Last edited:
Upvote 0
Solution
Welcome to the MrExcel Message Board!

Your data in columns A and B, starting at A1.
Results in D1 onwards.

Try this macro:
VBA Code:
Sub pivot_two_columns()
  Dim a As Variant, b As Variant
  Dim dic As Object
  Dim i As Long, j As Long, k As Long, n As Long
 
  Set dic = CreateObject("Scripting.Dictionary")
  Range("D1", Cells(Rows.Count, Columns.Count)).ClearContents
 
  a = Range("A1", Range("B" & Rows.Count).End(3)).Value
  ReDim b(1 To UBound(a, 1), 1 To UBound(a, 1))
  For i = 1 To UBound(a, 1)
    If Not dic.exists(a(i, 2)) Then
      j = 2
      k = k + 1
      b(1, k) = a(i, 2)
    Else
      j = Split(dic(a(i, 2)), "|")(0) + 1
      k = Split(dic(a(i, 2)), "|")(1)
    End If
    dic(a(i, 2)) = j & "|" & k
    If j > n Then n = j
    b(j, k) = a(i, 1)
  Next
  Range("D1").Resize(n, k).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 (pivot_two_columns) 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.
Dante,

I plugged in the VBA script and it’s giving me a Compiler error — Syntax on Line 2
Dim a As Variant, b As Variant


F
 
Upvote 0
What else does the error say

Repeat the steps again and paste the entire macro.
 
Upvote 0
Okay, I corrected two issues — one was an indentation issue, the ‘Syntax’ error and the second one being a Run-time error’7’: Out of memory. On the second one, I just divided the list into four sheets and ran it each sheet separately.

However, now I’m running into a new issue — not everything is being pivoted. Out of 26,954 rows, I should end up with 1,791 headers — each one with the the corresponding data underneath. Currently the total column header count is 183.

I’m going to continue working at it to see where the issue is at.
 
Upvote 0
Okay, it’s working the way it sh

I had to make modifications to the header data and make each one a unique value. So I added a sequential number to the end of each header value. I then broke it down further into 12 parts versus 4 so that the data was easier to manage.
The script works well for what I needed to accomplish — thank you sir for helping me out with this massive project.

So, lessons learned — 1. Check for proper indentation when copying from one medium to another. 2. When working with large amounts of data — a. Ensure the header columns are all unique and not repeated and b. Break the data down into smaller manageable chunks versus attempting to run this script on over 30,000 rows with over 2,000 unique headers.

Thank you sir and I’m thankful to have joined.

Respectfully,

Furthark
 
Upvote 0

Forum statistics

Threads
1,215,028
Messages
6,122,749
Members
449,094
Latest member
dsharae57

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