Create new worksheet for each vendor

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
97
Hi,

I have an excel sheet that has about 5000+ Sku's from over 150+ vendors, my excel sheet has a vendor column ( C ), I am going throught this manually which has taken me days to copy paste each vendor in a worksheet.

I am 5 hours in and realized i did about 50%, anyway i can automate this with a code or formula?

Thank you
 
Ok how about
Code:
Sub i8ur4re()
   Dim Cl As Range
   Dim Ws As Worksheet
   Dim Ky As Variant
   Dim UsdRws As Long
   
   Set Ws = ActiveSheet
   UsdRws = Ws.Range("C" & Rows.Count).End(xlUp).Row
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("C2:C" & UsdRws)
         .Item(Cl.Value) = Empty
      Next Cl
      For Each Ky In .keys
         Ws.Range("A1:Z" & UsdRws).AutoFilter 3, Ky
         Sheets.Add(, Sheets(Sheets.Count)).Name = Ky
         Ws.AutoFilter.Range.Copy Range("A1")
      Next Ky
      Ws.AutoFilterMode = False
   End With
End Sub

Its not importing the data to the sheets and its still giving me the same error with the characters, etc.

Ws.Range("A1:Z" & UsdRws).AutoFilter 3, Ky

Would you like me to send you a copy of the excel sheet to take a look at, maybe im missing something on my end.
 
Upvote 0

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
You can upload the file to a share site such as OneDrive, DropBox, GoogleDrive. Then mark for sharing & post the link to the thread.
 
Upvote 0
That's asking me to sign-in. You need to mark it for sharing & then post the link it gives you.
 
Upvote 0
Thanks for the file, the problem is that your vendors are in col H, not col C. Try this instead.
Code:
Sub i8ur4re()
   Dim Cl As Range
   Dim Ws As Worksheet
   Dim Ky As Variant
   Dim UsdRws As Long
   
   Set Ws = ActiveSheet
   Application.ScreenUpdating = False
   UsdRws = Ws.Range("H" & Rows.Count).End(xlUp).Row
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("H2:H" & UsdRws)
         .Item(Cl.Value) = Empty
      Next Cl
      For Each Ky In .keys
         Ws.Range("A1:AR1" & UsdRws).AutoFilter 8, Ky
         Sheets.Add(, Sheets(Sheets.Count)).Name = Left(Ky, 30)
         Ws.AutoFilter.Range.Copy Range("A1")
      Next Ky
      Ws.AutoFilterMode = False
   End With
End Sub
 
Upvote 0
Thanks for the file, the problem is that your vendors are in col H, not col C. Try this instead.
Code:
Sub i8ur4re()
   Dim Cl As Range
   Dim Ws As Worksheet
   Dim Ky As Variant
   Dim UsdRws As Long
   
   Set Ws = ActiveSheet
   Application.ScreenUpdating = False
   UsdRws = Ws.Range("H" & Rows.Count).End(xlUp).Row
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("H2:H" & UsdRws)
         .Item(Cl.Value) = Empty
      Next Cl
      For Each Ky In .keys
         Ws.Range("A1:AR1" & UsdRws).AutoFilter 8, Ky
         Sheets.Add(, Sheets(Sheets.Count)).Name = Left(Ky, 30)
         Ws.AutoFilter.Range.Copy Range("A1")
      Next Ky
      Ws.AutoFilterMode = False
   End With
End Sub


That was the most beautiful thing ive seen all day, thank you so much for your help, beyond appreciated.
 
Upvote 0
Glad to help & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,213,504
Messages
6,114,020
Members
448,543
Latest member
MartinLarkin

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