Forum Discussion
VBA code to split worksheet by invoice type
- Apr 29, 2020
pbolali I've attached your sample file. It contains two additional sheets. I also Tabled your data on Sheet1. The sheet 'PivotTables' is a PivotTable from the Table as the data source (it's easier to use Tables than standard ranges in my opinion). Then, I dropped the 'REMARKS' field into the Filter area and set it to the first value. Then, I copied the PivotTable two more times (there are only three PivotTables in this example).
PivotTable caveats:
They do not manually refresh. You have to refresh them yourself if data is added to the Table. I tend to add code to the worksheet housing a PivotTable to automatically refresh their data when the worksheet is activated. Also, and more importantly, this example has three PivotTables stacked vertically - this is generally not a good idea. Instead, having a PivotTable on each sheet would negate this issue. The reason is data will want to grow vertically, and two cannot overlap one another. This is also a general rule for Tables as well.
There is another sheet titled 'Subtotal'. This is a copy of the data, although it is not in a Table, because the subtotal feature doesn't work with them. With the data, on the Data ribbon tab, click the Subtotal button. Ensure each change is set for the field 'REMARKS' and you check the columns you want to sum. I've done this to mimic the example you set in Sheet2. It is a fast and easy way to see subtotals by a specific field. These subtotal values will automatically update when you re-apply this feature.
Regarding the VBA code you posted, if either of the above solutions work for you it would negate the need for it. I'm a very big fan of VBA, but if there is a native solution which will work for you, I'll generally recommend using it instead. With that being said, if you still want a VBA solution, I will code one for you.
pbolali I've attached your sample file. It contains two additional sheets. I also Tabled your data on Sheet1. The sheet 'PivotTables' is a PivotTable from the Table as the data source (it's easier to use Tables than standard ranges in my opinion). Then, I dropped the 'REMARKS' field into the Filter area and set it to the first value. Then, I copied the PivotTable two more times (there are only three PivotTables in this example).
PivotTable caveats:
They do not manually refresh. You have to refresh them yourself if data is added to the Table. I tend to add code to the worksheet housing a PivotTable to automatically refresh their data when the worksheet is activated. Also, and more importantly, this example has three PivotTables stacked vertically - this is generally not a good idea. Instead, having a PivotTable on each sheet would negate this issue. The reason is data will want to grow vertically, and two cannot overlap one another. This is also a general rule for Tables as well.
There is another sheet titled 'Subtotal'. This is a copy of the data, although it is not in a Table, because the subtotal feature doesn't work with them. With the data, on the Data ribbon tab, click the Subtotal button. Ensure each change is set for the field 'REMARKS' and you check the columns you want to sum. I've done this to mimic the example you set in Sheet2. It is a fast and easy way to see subtotals by a specific field. These subtotal values will automatically update when you re-apply this feature.
Regarding the VBA code you posted, if either of the above solutions work for you it would negate the need for it. I'm a very big fan of VBA, but if there is a native solution which will work for you, I'll generally recommend using it instead. With that being said, if you still want a VBA solution, I will code one for you.
Thanks for your help.
How do you control the tables not to overlap should the line items in a group increases please?
- pbolaliApr 30, 2020Brass ContributorI tried the code, it works pretty good but still shows an error in the loop
"For Column = 1 To 16
Output(Column, Row) = Table.ListRows(Index).Range(1, Column).Value
Next Column" - pbolaliApr 29, 2020Brass ContributorThank you so much. Would give it a try.
I agree it would have been good to have each pivot per sheet but the report was approved and imposed on me; I have to spend a lot of man hours to copy and paste data.
But thanks to you and this forum, you have been of great help. I appreciate - Zack BarresseApr 29, 2020Iron Contributor
pbolali this is exactly the reason you don't want to stack PivotTables or Tables vertically. They can grow. It's why I recommended they each go on their own sheet.
That being said, it's apparent you want a VBA solution. The below code will do what you want. Make sure you change the sheet names to what you have. Please note I did Table the data and referenced it as such in the code. More importantly, in your 'Date Paid' column you have some data which will give you an Overflow error. They are formatted as date, yet they reference the 'Budged Value' and add 30, seemingly arbitrarily. You can see this in cell N29. There were only 9 cells with this formula. If those aren't removed, the below code will fail. I did not code around it because I believe the user should know and clean their data first, not rely on code to do so.
Sub SplitInvoiceData() Dim Remarks As New Collection Dim SourceSheet As Worksheet Dim TargetSheet As Worksheet Dim Table As ListObject Dim Column As Long Dim Row As Long Dim Index As Long Dim NewRow As Long Dim RemarkIndex As Long Dim Remark As Variant Dim Output As Variant Const SourceTableName As String = "Table1" Const BufferRows As Long = 2 Set SourceSheet = ThisWorkbook.Worksheets("Sheet1") Set TargetSheet = ThisWorkbook.Worksheets("VBA Output") Set Table = SourceSheet.ListObjects(SourceTableName) For RemarkIndex = 1 To Table.ListRows.Count On Error Resume Next Remarks.Add Table.ListRows(RemarkIndex).Range(1, 1).Value, Table.ListRows(RemarkIndex).Range(1, 1).Value On Error GoTo 0 Next RemarkIndex TargetSheet.Cells.Clear For Each Remark In Remarks Row = 0 For Index = 1 To Table.ListRows.Count If Table.ListRows(Index).Range(1, 1) = Remark Then Row = Row + 1 If IsEmpty(Output) Then ReDim Output(1 To 16, 1 To Row) Else ReDim Preserve Output(1 To 16, 1 To Row) End If For Column = 1 To 16 Output(Column, Row) = Table.ListRows(Index).Range(1, Column).Value Next Column End If Next Index NewRow = TargetSheet.Cells(TargetSheet.Rows.Count, 1).End(xlUp).Row + BufferRows + 1 'Header TargetSheet.Cells(NewRow, 1).Resize(1, 16).Value = Table.HeaderRowRange.Value Table.HeaderRowRange.Copy TargetSheet.Cells(NewRow, 1).Resize(1, 16).PasteSpecial xlPasteFormats 'Data TargetSheet.Cells(NewRow + 1, 1).Resize(Row, 16).Value = Application.Transpose(Output) Table.ListRows(1).Range.Copy TargetSheet.Cells(NewRow + 1, 1).Resize(Row, 16).PasteSpecial xlPasteFormats 'Total formulas With TargetSheet.Cells(NewRow + Row + 1, 1).Resize(1, 16) .Interior.ColorIndex = 37 .Cells(1, 1).Value = "Total" .Cells(1, 10).Resize(1, 7).Formula = "=SUM(J" & NewRow & ":J" & NewRow + Row & ")" End With Application.CutCopyMode = False Next Remark TargetSheet.Cells.EntireColumn.AutoFit End SubThere's no real error handling or performance boosts here, so on larger data sets this might not be ideal or be the fastest. If you were going to have a larger data set I'd recommend using [additional] arrays for housing all of the data.
HTH