Generating a Summary that has varying number of entries based

chiron

New Member
Joined
Dec 17, 2012
Messages
28
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
[TABLE="width: 553"]
<tbody>[TR]
[TD][/TD]
[TD]Section 1[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Item No.[/TD]
[TD]Description[/TD]
[TD]Budget[/TD]
[TD]Total Invoice[/TD]
[TD]Current Invoice[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]AAAA[/TD]
[TD]10[/TD]
[TD]10[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]BBBB[/TD]
[TD]10[/TD]
[TD]5[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]CCCC[/TD]
[TD]10[/TD]
[TD]0[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]DDDD[/TD]
[TD]10[/TD]
[TD]3[/TD]
[TD]3[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]Subtotal[/TD]
[TD]40[/TD]
[TD]18[/TD]
[TD]5[/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD]Section 2[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]Item No.[/TD]
[TD]Description[/TD]
[TD]Budget[/TD]
[TD]Total Invoice[/TD]
[TD]Current Invoice[/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]E[/TD]
[TD]10[/TD]
[TD]10[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]F[/TD]
[TD]10[/TD]
[TD]5[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]G[/TD]
[TD]10[/TD]
[TD]0[/TD]
[TD]0[/TD]
[/TR]
[TR]
[TD][/TD]
[TD]Subtotal[/TD]
[TD]30[/TD]
[TD]15[/TD]
[TD]2[/TD]
[/TR]
</tbody>[/TABLE]


I want to automatically generate a summary that looks like this in a different sheet;

[TABLE="width: 208"]
<tbody>[TR]
[TD]Item No.[/TD]
[TD] Current Invoice[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD="align: right"]3[/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD="align: right"]2[/TD]
[/TR]
[TR]
[TD]Total[/TD]
[TD="align: right"]7[/TD]
[/TR]
</tbody>[/TABLE]

I cannot change the structure of the original table and it has titles repeated as text for each section. What is a good way to do this? The way I am doing it now is to filter and then copy visible cells into the next sheet and total but I think there must be a way to do dynamically generate this table based on the data entered.
 
Last edited:
Hi, Try the following vba code in your sheet "summary", it's very simple. Each time you select the sheet the data is updated automatically.

Change data in red by your information.

Code:
Private Sub Worksheet_Activate()
    Dim sh1 As Worksheet, sh2 As Worksheet
    Set sh1 = Sheets("[COLOR=#ff0000]Original[/COLOR]")
    Set sh2 = Sheets("[COLOR=#ff0000]Summary[/COLOR]")
    sh2.Cells.ClearContents
    lr = sh1.Range("A" & Rows.Count).End(xlUp).Row
    If sh1.AutoFilterMode Then sh1.AutoFilterMode = False
    sh1.Range("A2:E" & lr).AutoFilter Field:=5, Criteria1:=">0"
    sh1.Range("A2:E" & lr).AutoFilter Field:=2, Criteria1:="<>Subtotal"
    sh1.Range("A2:A" & lr & ",E2:E" & lr).Copy
    sh2.Range("A1").PasteSpecial xlPasteValues
    sh1.ShowAllData
    lr = sh2.Range("B" & Rows.Count).End(xlUp).Row
    sh2.Cells(lr + 1, "A").Value = "Total"
    sh2.Cells(lr + 1, "B").Value = WorksheetFunction.Sum(sh2.Range("B2:B" & lr))
End Sub

SHEET EVENT
Right click the tab of the sheet you want this to work ("Summary"), select view code & paste the code into the window that opens up.
 
Upvote 0

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Hi, Try the following vba code in your sheet "summary", it's very simple. Each time you select the sheet the data is updated automatically.

Change data in red by your information.

Code:
Private Sub Worksheet_Activate()
    Dim sh1 As Worksheet, sh2 As Worksheet
    Set sh1 = Sheets("[COLOR=#ff0000]Original[/COLOR]")
    Set sh2 = Sheets("[COLOR=#ff0000]Summary[/COLOR]")
    sh2.Cells.ClearContents
    lr = sh1.Range("A" & Rows.Count).End(xlUp).Row
    If sh1.AutoFilterMode Then sh1.AutoFilterMode = False
    sh1.Range("A2:E" & lr).AutoFilter Field:=5, Criteria1:=">0"
    sh1.Range("A2:E" & lr).AutoFilter Field:=2, Criteria1:="<>Subtotal"
    sh1.Range("A2:A" & lr & ",E2:E" & lr).Copy
    sh2.Range("A1").PasteSpecial xlPasteValues
    sh1.ShowAllData
    lr = sh2.Range("B" & Rows.Count).End(xlUp).Row
    sh2.Cells(lr + 1, "A").Value = "Total"
    sh2.Cells(lr + 1, "B").Value = WorksheetFunction.Sum(sh2.Range("B2:B" & lr))
End Sub

SHEET EVENT
Right click the tab of the sheet you want this to work ("Summary"), select view code & paste the code into the window that opens up.

Thanks. This is exactly what I was looking for. I'm having a hard time trying to understand how the PowerQuery solution works but I think I will be able to adapt this to my sheets.
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,183
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

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