Create new worksheet for each vendor

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
95
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
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,476
Office Version
365
Platform
Windows
How about
Code:
Sub i8ur4re()
   Dim Cl As Range
   Dim Ws As Worksheet
   Dim Ky As Variant
   
   Set Ws = ActiveSheet
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("C2", Ws.Range("C" & Rows.Count).End(xlUp))
         .Item(Cl.Value) = Empty
      Next Cl
      For Each Ky In .keys
         Ws.Range("A1:Z1").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
 

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
95
How about
Code:
Sub i8ur4re()
   Dim Cl As Range
   Dim Ws As Worksheet
   Dim Ky As Variant
   
   Set Ws = ActiveSheet
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("C2", Ws.Range("C" & Rows.Count).End(xlUp))
         .Item(Cl.Value) = Empty
      Next Cl
      For Each Ky In .keys
         Ws.Range("A1:Z1").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
I got a run-time error 1004:
Application-define or oobject-defined error.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,476
Office Version
365
Platform
Windows
What line gave that error?
 

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
95
I got a run-time error 1004:
Application-define or oobject-defined error.
I fixed that error, but i did get a Run-Time error 1004

You typed an invalid name for a sheet or chart. Make sure that:
The name that you type does not exceed 31 characters.
The name does not contain any of the following characters: \ / ?* [ or ]
You did not leave the name blank.

I did notice some vendor names might surpass the 31 characters, anyway around this, maybe trim at 30 characters?

This line gave the error:

Sheets.Add(, Sheets(Sheets.Count)).Name = Ky
 
Last edited:

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,476
Office Version
365
Platform
Windows
You could use
Code:
Sheets.Add(, Sheets(Sheets.Count)).Name = Left(Ky,30)
as long as the vendor names don't contain any illegal characters.
 

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
95
You could use
Code:
Sheets.Add(, Sheets(Sheets.Count)).Name = Left(Ky,30)
as long as the vendor names don't contain any illegal characters.
That worked, the last problem im facing is it creates the new worksheets but they are empty, any chance i can take all the content for that vendor and move it to the new worksheet? Its currently only taking the header.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,476
Office Version
365
Platform
Windows
Do you have any blank rows in the data?
 

i8ur4re

Board Regular
Joined
Mar 1, 2015
Messages
95
Do you have any blank rows in the data?
Yes, I do have a few empty rows or missing data, here is what 2 rows look like, this is the original, i managed to clean it up prior, but at this rate, i can go with the information below:

SkuDim.1Dim.2Dim.3Dim.4StoreDescriptionVendorDepartmentProduct NumberQTYAVLQOHSOLDCOMITQOOSOQTBPRECVTRANOTITADJMinMaxQROPLookupsDim.1 GroupDim.1 DescriptionDim.2 GroupDim.2 DescriptionDim.3 GroupDim.3 DescriptionDim.4 GroupDim.4 DescriptionIn Store LocationPriceListCostAvgCostBrandSeasonBin Picking#Tax1Tax2Tax3
8024True Terpenes .5ml Ceramic Cartridge WhiteTrue TerpenesExtraction191924830000025000-110000122000$0.99$0.80$0.80True TerpenesY
6258Cartridge Plastic Containers .5 ml ::$0.25Ypsilanti Oil CompanyExtraction1704231327000054000000-5631000$0.25$0.12$0.11$$$Y

<colgroup><col><col span="4"><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col><col span="2"><col><col><col><col span="3"></colgroup><tbody>
</tbody>
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
30,476
Office Version
365
Platform
Windows
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
 

Forum statistics

Threads
1,078,368
Messages
5,339,785
Members
399,324
Latest member
darshank123

Some videos you may like

This Week's Hot Topics

Top