Transpose and Summarize the data using VBA

kumark1

New Member
Joined
Mar 20, 2012
Messages
11
Hi All,

I got a project Requirement where i need to Transpose nad summarize the data, I tried doing it in Pivot, i could not get the output.
Can this be done thru the VBA


Output


[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Risk/Complexity[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Easy[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Medium[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 117"]
<tbody>[TR="class: grid"]
[TD="width: 117"]Difficult[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]High[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Project1_Project4[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Project3[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Low[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Project5[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[TD][TABLE="width: 117"]
<tbody>[TR="class: grid"]
[TD="width: 117"]Project2_Project6[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Moderate[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][/TD]
[TD][TABLE="width: 64"]
<tbody>[TR="class: grid"]
[TD="width: 64"]Project9[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD][TABLE="width: 117"]
<tbody>[TR="class: grid"]
[TD="width: 117"]Project7_Project8[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]


Input


[TABLE="class: grid, width: 500, align: left"]
<tbody>[TR]
[TD]Project[/TD]
[TD]Complex[/TD]
[TD]Risk[/TD]
[/TR]
[TR]
[TD]Project 1[/TD]
[TD]Easy[/TD]
[TD]High[/TD]
[/TR]
[TR]
[TD]Project 2[/TD]
[TD]difficult[/TD]
[TD]Low[/TD]
[/TR]
[TR]
[TD]Project 3[/TD]
[TD]Medium[/TD]
[TD]High[/TD]
[/TR]
[TR]
[TD]Project 4[/TD]
[TD]Easy[/TD]
[TD]High[/TD]
[/TR]
[TR]
[TD]Project 5[/TD]
[TD]Easy[/TD]
[TD]Low[/TD]
[/TR]
[TR]
[TD]Project 6[/TD]
[TD]difficult[/TD]
[TD]Low[/TD]
[/TR]
[TR]
[TD]Project 7[/TD]
[TD]difficult[/TD]
[TD]Moderate[/TD]
[/TR]
[TR]
[TD]Project 8[/TD]
[TD]difficult[/TD]
[TD]Moderate[/TD]
[/TR]
[TR]
[TD]Project 9[/TD]
[TD]Medium[/TD]
[TD]Moderate[/TD]
[/TR]
</tbody>[/TABLE]
 
Last edited:

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
kumark1,

Here is a macro solution for you to consider that is based on your flat text displays.

I assume that Input, and, Output, are worksheets that already exist.

Sample raw data worksheets:


Excel 2007
ABC
1ProjectComplexRisk
2Project 1EasyHigh
3Project 2difficultLow
4Project 3MediumHigh
5Project 4EasyHigh
6Project 5EasyLow
7Project 6difficultLow
8Project 7difficultModerate
9Project 8difficultModerate
10Project 9MediumModerate
11
Input



Excel 2007
ABCD
1Risk/ComplexityEasyMediumDifficult
2High
3Low
4Moderate
5
Output


And, after the macro in worksheet Output:


Excel 2007
ABCD
1Risk/ComplexityEasyMediumDifficult
2HighProject 1_Project 4Project 3
3LowProject 5Project 2_Project 6
4ModerateProject 9Project 7_Project 8
5
Output


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:
Option Compare Text
Sub ReorgData()
' hiker95, 04/06/2016, ME932716
Dim wi As Worksheet, wo As Worksheet
Dim c As Range
Dim h As Range, l As Range, m As Range
Dim emd As Range
Application.ScreenUpdating = False
Set wi = Sheets("Input")
Set wo = Sheets("Output")
With wi
  For Each c In .Range("C2", .Range("C" & Rows.Count).End(xlUp))
    Set h = wo.Columns(1).Find(c.Value, LookAt:=xlWhole)
    Set emd = wo.Rows(1).Find(c.Offset(, -1).Value, LookAt:=xlWhole)
    If (Not h Is Nothing) * (Not emd Is Nothing) Then
      If wo.Cells(h.Row, emd.Column) = vbEmpty Then
        wo.Cells(h.Row, emd.Column).Value = c.Offset(, -2).Value
      Else
        wo.Cells(h.Row, emd.Column).Value = wo.Cells(h.Row, emd.Column).Value & "_" & c.Offset(, -2).Value
      End If
    End If
  Next c
End With
With wo
  .Columns(1).Resize(, 4).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 ReorgData macro.
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,885
Members
452,364
Latest member
springate

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