Forum

Parse Sheets of dat...
 
Notifications
Clear all

Parse Sheets of data Based on Criteria List

15 Posts
2 Users
0 Reactions
92 Views
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

I need to be able to parse out data based on multiple sheets.  When this happens there will be a ne sheet created and renamed with the data in Column B on the Master.  Now, not all data on the Master will be used, the QCH # in column B of the Master MUST appear on Column A of the Status Percent Sheet, otherwise, it is not included.

 

Sheet Name: Master, Named Range: Table2, Column: B (Change Number)

Sheet Name: Status Percent, Named Range: Table1, Column: A (Change Number)

 

I would like the newly parsed sheets to be renamed based on the QCH number, for example "QCH00059634".  Then all records with that QCH # would appear on that sheet.  Some of these sheets may contain only a few records while others will contain a great many.  And if possible, I would like the set of new QCH sheets to appear in a new workbook and the file would be saved as "Transformation QCHs Lates - MM-DD-YYYY.xlsx  Thanks so much!!!!

 
Posted : 11/01/2022 6:15 pm
(@catalinb)
Posts: 1937
Member Admin
 

Hi Sherry,

Is there a reason why you need to split data into sheets? Most of the times, data is best used if it's in one place.

 
Posted : 13/01/2022 2:29 pm
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

I agree, but the manager will use this, and each of those tabs that is is split into will be accessed by different people.  I have already suggested filtering and such.  However management is set in their ways on how they want the final result.  There is no changing their minds about it.

 
Posted : 14/01/2022 2:39 pm
(@catalinb)
Posts: 1937
Member Admin
 

Hi Sherry,

Put the following code in a normal vba module (included also in the file attached), should do what you need:

Option Explicit

Sub ExportData()
Dim Status As ListObject: Set Status = ThisWorkbook.Worksheets("Status Percent").ListObjects("Table1")
Dim Master As ListObject: Set Master = ThisWorkbook.Worksheets("Master").ListObjects("Table2")
If Status.DataBodyRange Is Nothing Or Master.DataBodyRange Is Nothing Then Exit Sub
'load source data into arrays
Dim ArrStatus As Variant: ArrStatus = Status.DataBodyRange.Value
Dim ArrMaster As Variant: ArrMaster = Master.DataBodyRange.Value
Dim i As Long, ArrResults() As Variant, Counter As Long, ChangeCode As String, aKey As Variant

'build Dictionaries
Dim StatusDict As Object: Set StatusDict = CreateObject("scripting.dictionary")
Dim MasterDict As Object: Set MasterDict = CreateObject("scripting.dictionary")

For i = 1 To UBound(ArrStatus)
ChangeCode = ArrStatus(i, Status.ListColumns("Change Number").Index)
StatusDict(ChangeCode) = ChangeCode
Next

For i = 1 To UBound(ArrMaster)
ChangeCode = ArrMaster(i, Master.ListColumns("Change Number").Index)
If StatusDict.Exists(ChangeCode) Then
If MasterDict.Exists(ChangeCode) = True Then
ArrResults = MasterDict(ChangeCode)
Counter = UBound(ArrResults, 2) + 1
Else
Counter = 1
ReDim ArrResults(1 To Master.ListColumns.Count, 1 To Counter)
'add headers
ArrResults(Master.ListColumns("Org. Entity").Index, Counter) = "Org. Entity"
ArrResults(Master.ListColumns("Change Number").Index, Counter) = "Change Number"
ArrResults(Master.ListColumns("Process Area (Alignment)").Index, Counter) = "Process Area (Alignment)"
ArrResults(Master.ListColumns("QMS Process").Index, Counter) = "QMS Process"
Counter = Counter + 1
End If

ReDim Preserve ArrResults(1 To Master.ListColumns.Count, 1 To Counter)
ArrResults(Master.ListColumns("Org. Entity").Index, Counter) = ArrMaster(i, Master.ListColumns("Org. Entity").Index)
ArrResults(Master.ListColumns("Change Number").Index, Counter) = ChangeCode
ArrResults(Master.ListColumns("Process Area (Alignment)").Index, Counter) = ArrMaster(i, Master.ListColumns("Process Area (Alignment)").Index)
ArrResults(Master.ListColumns("QMS Process").Index, Counter) = ArrMaster(i, Master.ListColumns("QMS Process").Index)

MasterDict(ChangeCode) = ArrResults
End If
Next

If MasterDict.Count > 0 Then
Dim NewWb As Workbook: Set NewWb = Workbooks.Add
Dim DestFolder As String: DestFolder = ThisWorkbook.Path & Application.PathSeparator & "Exports"
If Len(Dir$(DestFolder, vbDirectory)) = 0 Then MkDir DestFolder
NewWb.SaveAs DestFolder & Application.PathSeparator & "Transformation QCHs Lates - " & Format(Date, "mm-dd-yyyy") & ".xlsx"
Dim NewSh As Worksheet, Rng As Range
For Each aKey In MasterDict.Keys
Counter = UBound(MasterDict(aKey), 2)
'add new sheet
Set NewSh = NewWb.Worksheets.Add
NewSh.Name = CStr(aKey)
If Counter > 0 Then
Set Rng = NewSh.Range(NewSh.Cells(1), NewSh.Cells(Counter, Master.ListColumns.Count))
Rng.Value = TransposeArray(MasterDict(aKey))
Rng.Columns.AutoFit
NewSh.ListObjects.Add xlSrcRange, Rng, , xlYes
End If

Next aKey
End If

End Sub

Function TransposeArray(myarray As Variant) As Variant
Dim X As Long
Dim Y As Long
Dim Xupper As Long
Dim Yupper As Long
Dim tempArray As Variant
Xupper = UBound(myarray, 2)
Yupper = UBound(myarray, 1)
ReDim tempArray(LBound(myarray, 2) To Xupper, LBound(myarray, 1) To Yupper)
For X = LBound(myarray, 2) To Xupper
For Y = LBound(myarray, 1) To Yupper
tempArray(X, Y) = myarray(Y, X)
Next Y
Next X
TransposeArray = tempArray
End Function

 
Posted : 15/01/2022 12:54 am
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

First sorry for my delay in responding.  My boss had me on an Urgent project, and there was no spare time.  Thank you for looking into this for me.  I tried the macro in the workbook you attached, and it resulted in an error message.  Attached is the error message and where it shows when I went to attempt to debug.

 

2022-01-31_9-38-36.jpg2022-01-31_9-44-07.jpg

 
Posted : 01/02/2022 11:37 am
(@catalinb)
Posts: 1937
Member Admin
 

Where did you saved the test file?

Location is important.

OneDrive has some specific issues, so I suggest saving the file in a location where you have rights to create folders, but not OneDrive.

 
Posted : 01/02/2022 11:58 am
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

I hate OneDrive... they force us to use it at work.  This is great, but I do have one question.  It worked perfectly, however, it also added a blank sheet called "Sheet1", is there a way to prevent that?

 
Posted : 02/02/2022 12:25 pm
(@catalinb)
Posts: 1937
Member Admin
 

Sheet1is not added by code, it is the initial sheet that is in the newly added workbook (when you create a new workbook, it does not come empty, there is at least 1 sheet in it).

After all necessary sheets are added, we can write a code to delete initial empty "SheetX" sheets.

If you need to use it in OneDrive, it can be done, but OneDrive is a complex environment. For example, there is OneDrive Personal environment, OneDrive Business, SharePoint Site files. If you have multiple office licenses, there will be multiple onedrive link types.

Let me know if you have to use it in OneDrive, I can prepare a solution to manage these environments.

 
Posted : 02/02/2022 2:19 pm
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

What code would need to be added to delete Sheet1 (or whatever empty sheet) , and where would it be added?  I am still learning how to code.

As for OneDrive, I think it would be easier for me to have my user run this process from their download folder.  I have already confirmed your macro works in that folder.  The end user can then email the file directly from that location.  So we don't need to try to overcomplicate things due to OneDrive.  I appreciate your willingness on that though.

 
Posted : 02/02/2022 2:49 pm
(@catalinb)
Posts: 1937
Member Admin
 

Before this line:

If MasterDict.Count > 0 Then

The following code should be added:

Dim Wks as worksheet

Application.DisplayAlerts=False

For Each Wks in ThisWorkbook.Worksheets

If Wks.Name like "Sheet*" then Wks.Delete

Next Wks

Application.DisplayAlerts=True

 
Posted : 02/02/2022 3:56 pm
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

I added the code, and ran the macro from my Downloads folder, and I still got the blank Sheet1.  Did I do something wrong? New text you told me to add to the code is in Red. NOTE:  I looked for code tags but did not see any, I am sorry.

Option Explicit

Sub ExportData()
Dim Status As ListObject: Set Status = ThisWorkbook.Worksheets("Status Percent").ListObjects("Table1")
Dim Master As ListObject: Set Master = ThisWorkbook.Worksheets("Master").ListObjects("Table2")
If Status.DataBodyRange Is Nothing Or Master.DataBodyRange Is Nothing Then Exit Sub
'load source data into arrays
Dim ArrStatus As Variant: ArrStatus = Status.DataBodyRange.Value
Dim ArrMaster As Variant: ArrMaster = Master.DataBodyRange.Value
Dim i As Long, ArrResults() As Variant, Counter As Long, ChangeCode As String, aKey As Variant

'build Dictionaries
Dim StatusDict As Object: Set StatusDict = CreateObject("scripting.dictionary")
Dim MasterDict As Object: Set MasterDict = CreateObject("scripting.dictionary")

For i = 1 To UBound(ArrStatus)
ChangeCode = ArrStatus(i, Status.ListColumns("Change Number").Index)
StatusDict(ChangeCode) = ChangeCode
Next

For i = 1 To UBound(ArrMaster)
ChangeCode = ArrMaster(i, Master.ListColumns("Change Number").Index)
If StatusDict.Exists(ChangeCode) Then
If MasterDict.Exists(ChangeCode) = True Then
ArrResults = MasterDict(ChangeCode)
Counter = UBound(ArrResults, 2) + 1
Else
Counter = 1
ReDim ArrResults(1 To Master.ListColumns.Count, 1 To Counter)
'add headers
ArrResults(Master.ListColumns("Org. Entity").Index, Counter) = "Org. Entity"
ArrResults(Master.ListColumns("Change Number").Index, Counter) = "Change Number"
ArrResults(Master.ListColumns("Process Area (Alignment)").Index, Counter) = "Process Area (Alignment)"
ArrResults(Master.ListColumns("QMS Process").Index, Counter) = "QMS Process"
Counter = Counter + 1
End If

ReDim Preserve ArrResults(1 To Master.ListColumns.Count, 1 To Counter)
ArrResults(Master.ListColumns("Org. Entity").Index, Counter) = ArrMaster(i, Master.ListColumns("Org. Entity").Index)
ArrResults(Master.ListColumns("Change Number").Index, Counter) = ChangeCode
ArrResults(Master.ListColumns("Process Area (Alignment)").Index, Counter) = ArrMaster(i, Master.ListColumns("Process Area (Alignment)").Index)
ArrResults(Master.ListColumns("QMS Process").Index, Counter) = ArrMaster(i, Master.ListColumns("QMS Process").Index)

MasterDict(ChangeCode) = ArrResults
End If
Next

Dim Wks As Worksheet

Application.DisplayAlerts = False

For Each Wks In ThisWorkbook.Worksheets

If Wks.Name Like "Sheet*" Then Wks.Delete

Next Wks

Application.DisplayAlerts = True

If MasterDict.Count > 0 Then
Dim NewWb As Workbook: Set NewWb = Workbooks.Add
Dim DestFolder As String: DestFolder = ThisWorkbook.Path & Application.PathSeparator & "Exports"
If Len(Dir$(DestFolder, vbDirectory)) = 0 Then MkDir DestFolder
NewWb.SaveAs DestFolder & Application.PathSeparator & "Transformation QCHs Lates - " & Format(Date, "mm-dd-yyyy") & ".xlsx"
Dim NewSh As Worksheet, Rng As Range
For Each aKey In MasterDict.Keys
Counter = UBound(MasterDict(aKey), 2)
'add new sheet
Set NewSh = NewWb.Worksheets.Add
NewSh.Name = CStr(aKey)
If Counter > 0 Then
Set Rng = NewSh.Range(NewSh.Cells(1), NewSh.Cells(Counter, Master.ListColumns.Count))
Rng.Value = TransposeArray(MasterDict(aKey))
Rng.Columns.AutoFit
NewSh.ListObjects.Add xlSrcRange, Rng, , xlYes
End If

Next aKey
End If

End Sub

Function TransposeArray(myarray As Variant) As Variant
Dim X As Long
Dim Y As Long
Dim Xupper As Long
Dim Yupper As Long
Dim tempArray As Variant
Xupper = UBound(myarray, 2)
Yupper = UBound(myarray, 1)
ReDim tempArray(LBound(myarray, 2) To Xupper, LBound(myarray, 1) To Yupper)
For X = LBound(myarray, 2) To Xupper
For Y = LBound(myarray, 1) To Yupper
tempArray(X, Y) = myarray(Y, X)
Next Y
Next X
TransposeArray = tempArray
End Function

 
Posted : 02/02/2022 4:30 pm
(@catalinb)
Posts: 1937
Member Admin
 

Sorry, the place for the code is wrong, my mistake.

Please move the code just above End Sub line.

 
Posted : 03/02/2022 1:15 am
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

I moved that new code (the part in RED) from the original location you stated to above End Sub as you mentioned.  Sorry, I still cannot find where the code tags are on this forum.  The rest of the code works, it is just that the Sheet1, which is a blank in the new workbook exists.

End If

Code pasted here

End Sub

 
Posted : 03/02/2022 10:15 am
(@catalinb)
Posts: 1937
Member Admin
 

Hi Sherry,

The code is properly placed now, but I made a small mistake:

I referred to ThisWorkbook, where the code is, not to the NewWb, where the sheets are created.

Updated code (added also a new check, to make sure we do not delete all sheets, there must be at least one in a workbook, code will fail to delete the last sheet):

If NewWb is nothing then exit sub ' no new file was created
Dim Wks As Worksheet
Application.DisplayAlerts = False
For Each Wks In NewWb.Worksheets
Debug.Print Wks.Name
If Wks.Name Like "Sheet*" And NewWb.Worksheets.Count > 1 Then Wks.Delete
Next Wks
Application.DisplayAlerts = True

To add code tags, simply type the start and closing tags:

Screenshot-2022-02-02-172707.png

 
Posted : 03/02/2022 11:18 am
(@webbers)
Posts: 147
Estimable Member
Topic starter
 

Catalin Bombea,

Perfect!  Thanks so much for all your help on this.  It is amazing how the tiniest of errors, or a wrong location will cause the whole code to explode!  This is EXACTLY the way management wan ts the file files.  Although I do agree, it should be on 1 worksheet so it can be analyzed. An d thanks for the tip on the code tags, I know now for next time!

 
Posted : 03/02/2022 11:58 am
Share: