VBA to create a loop on specific column, then use the ActiveCell.Value in that specific column to filter a table of data

Niggy Yeap

New Member
Joined
Apr 11, 2022
Messages
2
Office Version
  1. 2019
Platform
  1. Windows
HI ALL, I am currently creating a VBA macro to help my colleague to make their repetitive copy and paste work easier and faster.
So here's how my macro should work. Before I run a macro, I need to manually generate a column, that column contains a list of unique value Vendor Name.
This Vendor Name is originally from the table of data (the first row to be more specific).
The loop will look at this manually created column first, then it use the first value it gets to filter the whole table(this column does not have any header).
It will filter all the date in the table, using ActiveCell.Value as a Criteria1. This the drafted code I make. It won't work as I expexted, as help are appreciated.

VBA Code:
Sub loop_filter()

Dim x As Integer
NumRows = Range("L2", Range("L2").End(xlDown)).Rows.Count
Range("L2").Select 'Select first data

For x = 1 To NumRows
Cells.Select
Selection.AutoFilter
ActiveSheet.Range("$A:$J").AutoFilter Field:=1, Criteria1:=NumRows.ActiveCell
Cells.Select
Selection.Copy
Workbooks.Add
ActiveSheet.Paste
Application.CutCopyMode = False
ActiveWorkbook.SaveAs Filename:= _
"C:\Users\Easy IT Team\Desktop\Test\" + NumRows.ActiveCell.Value + ".xlsx", FileFormat:=xlOpenXMLWorkbook, CreateBackup:=False
ActiveWindow.Close
ActiveCell.Offset(1, 0).Select
Next
End Sub
VBA Code:
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Hi & welcome to MrExcel.
How about
VBA Code:
Sub NiggyYeap()
   Dim Cl As Range
   Dim Ws As Worksheet
   
   Application.ScreenUpdating = False
   Set Ws = ActiveSheet
   Ws.Range("A1", Ws.Range("A" & Rows.Count).End(xlUp)).AdvancedFilter xlFilterCopy, , Range("L2"), True
   For Each Cl In Ws.Range("L3", Ws.Range("L" & Rows.Count).End(xlUp))
      Ws.Range("A1:J1").AutoFilter 1, Cl.Value
      Workbooks.Add
      Ws.AutoFilter.Range.Copy Range("A1")
      With ActiveWorkbook
         .SaveAs "C:\Users\Easy IT Team\Desktop\Test\" & Cl.Value & ".xlsx", 51
         .Close False
      End With
   Next Cl
   Ws.ShowAllData
End Sub
 
Upvote 0
Solution
Hi & welcome to MrExcel.
How about
VBA Code:
Sub NiggyYeap()
   Dim Cl As Range
   Dim Ws As Worksheet
  
   Application.ScreenUpdating = False
   Set Ws = ActiveSheet
   Ws.Range("A1", Ws.Range("A" & Rows.Count).End(xlUp)).AdvancedFilter xlFilterCopy, , Range("L2"), True
   For Each Cl In Ws.Range("L3", Ws.Range("L" & Rows.Count).End(xlUp))
      Ws.Range("A1:J1").AutoFilter 1, Cl.Value
      Workbooks.Add
      Ws.AutoFilter.Range.Copy Range("A1")
      With ActiveWorkbook
         .SaveAs "C:\Users\Easy IT Team\Desktop\Test\" & Cl.Value & ".xlsx", 51
         .Close False
      End With
   Next Cl
   Ws.ShowAllData
End Sub
Thank You Fluff for the guidance, I'm glad that my mindset is same as yours. Yesterday, I use something like your suggestion and it works. Thank you for giving me the confidence that I am doing the right thing. Much Love and Much Thanks to you mate.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,795
Messages
6,121,624
Members
449,041
Latest member
Postman24

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