Forum Discussion
DhritimanL
Jul 19, 2020Copper Contributor
Export Data From Power Query into Multiple Excel Sheets based on criteria
Please find here below the structure of the data I am working on, I would like to get some help to find a way that when I export the data from Power Query I am able to achieve 2 things.
1) The data for each area ( Column State ) goes into a separate Excel worksheet of the file. I have about 300+ areas so using the reference and add filter at state column may not be a smart way to work.
2) Additionally it would be great that the sheet gets renamed to the area name.
Look forward to some help on this please
Kind Regards
16 Replies
Sort By
- rgivens7Copper ContributorI keep getting "Run-time error '9':
Subscript out of range" and it takes me to
Set full_data_listobject = ActiveWorkbook.Worksheets("full data").ListObjects(1) - OwenPriceIron Contributor
Unfortunately, PowerQuery doesn't support output of one query to multiple sheets.
If your version of Excel supports Dynamic Arrays and the FILTER function, you can use this code:
Option Explicit Public Sub SplitTableToSheets() Dim full_data_listobject As ListObject Dim selected_range As Range Dim selected_data As Variant Dim selected_data_header As String Dim items_sheet As Worksheet Dim items_range As Range Dim item As String Dim i As Integer Dim new_item_sheet As Worksheet DeleteSheetWithoutWarning "items" Set full_data_listobject = ThisWorkbook.Worksheets("full data").ListObjects(1) ' get the range currently selected Set selected_range = Selection selected_data_header = Selection.Offset(-1, 0).Cells(1, 1) Set items_sheet = ThisWorkbook.Worksheets.Add items_sheet.Name = "items" selected_range.Copy items_sheet.Range("A1").PasteSpecial xlValues Set items_range = items_sheet.Range("A1").CurrentRegion items_range.RemoveDuplicates 1, xlNo 'loop through each item and create a new sheet with the filtered data For i = 1 To items_range.Rows.Count If items_range.Cells(i, 1) <> "" Then item = items_range.Cells(i, 1) DeleteSheetWithoutWarning item Set new_item_sheet = ThisWorkbook.Worksheets.Add With new_item_sheet .Name = item .Range("A1").Formula2 = "=" & full_data_listobject.Name & "[#Headers]" .Range("A2").Formula2 = "=FILTER(" & full_data_listobject.Name & _ "," & full_data_listobject.Name & "[" & selected_data_header & "] = """ & item & """)" ''optionally uncomment these two lines to paste the results as values in the destination sheet '.Range("A1").CurrentRegion.Copy '.Range("A1").PasteSpecial xlPasteValues End With Else Exit For End If Next i End Sub Private Sub DeleteSheetWithoutWarning(sheet_name As String) Application.DisplayAlerts = False On Error Resume Next ThisWorkbook.Worksheets(sheet_name).Delete On Error GoTo 0 Application.DisplayAlerts = True End Sub
Select a column in your data that contains the items you want to split by, then run the SplitTableToSheets sub-procedure.
The benefit of this is that it will keep the sub-sheets up to date when the data on the main sheet refreshes.
You can test it with my dataset using the attached file.
If this doesn't work for you because you don't have access to the FILTER function, let me know. There are other ways to do it.
- NickiP2022Copper ContributorThis is just what I needed! Works like a charm exactly as downloaded.
I will adapt for my precise use case but you've saved me quite some time - thanks OwenPrice - eglover770Copper Contributor
OwenPrice This is great! However at work we have an older version of excel, how hard would it be to get this to work or something similar. I actually need it to save new files to a new workbook instead of as worksheets in the same book.......
- OwenPriceIron ContributorWhich version of Excel are you using?