Page 1 of 2 12 LastLast
Results 1 to 10 of 18

Thread: Create new worksheet for each vendor

  1. #1
    Board Regular
    Join Date
    Mar 2015
    Posts
    95
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Create new worksheet for each vendor

    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

  2. #2
    MrExcel MVP
    Moderator
    Fluff's Avatar
    Join Date
    Jun 2014
    Location
    Chippenham
    Posts
    28,353
    Post Thanks / Like
    Mentioned
    471 Post(s)
    Tagged
    47 Thread(s)

    Default Re: Create new worksheet for each vendor

    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
    - Posting Data try one of these tools
    - Posting guidelines, forum rules and terms of use
    - Read the FAQs

    Running Office 365 on Win 10

  3. #3
    Board Regular
    Join Date
    Mar 2015
    Posts
    95
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Create new worksheet for each vendor

    Quote Originally Posted by Fluff View Post
    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.

  4. #4
    MrExcel MVP
    Moderator
    Fluff's Avatar
    Join Date
    Jun 2014
    Location
    Chippenham
    Posts
    28,353
    Post Thanks / Like
    Mentioned
    471 Post(s)
    Tagged
    47 Thread(s)

    Default Re: Create new worksheet for each vendor

    What line gave that error?
    - Posting Data try one of these tools
    - Posting guidelines, forum rules and terms of use
    - Read the FAQs

    Running Office 365 on Win 10

  5. #5
    Board Regular
    Join Date
    Mar 2015
    Posts
    95
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Create new worksheet for each vendor

    Quote Originally Posted by i8ur4re View Post
    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 by i8ur4re; Sep 19th, 2019 at 02:41 PM.

  6. #6
    MrExcel MVP
    Moderator
    Fluff's Avatar
    Join Date
    Jun 2014
    Location
    Chippenham
    Posts
    28,353
    Post Thanks / Like
    Mentioned
    471 Post(s)
    Tagged
    47 Thread(s)

    Default Re: Create new worksheet for each vendor

    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.
    - Posting Data try one of these tools
    - Posting guidelines, forum rules and terms of use
    - Read the FAQs

    Running Office 365 on Win 10

  7. #7
    Board Regular
    Join Date
    Mar 2015
    Posts
    95
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Create new worksheet for each vendor

    Quote Originally Posted by Fluff View Post
    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.

  8. #8
    MrExcel MVP
    Moderator
    Fluff's Avatar
    Join Date
    Jun 2014
    Location
    Chippenham
    Posts
    28,353
    Post Thanks / Like
    Mentioned
    471 Post(s)
    Tagged
    47 Thread(s)

    Default Re: Create new worksheet for each vendor

    Do you have any blank rows in the data?
    - Posting Data try one of these tools
    - Posting guidelines, forum rules and terms of use
    - Read the FAQs

    Running Office 365 on Win 10

  9. #9
    Board Regular
    Join Date
    Mar 2015
    Posts
    95
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Create new worksheet for each vendor

    Quote Originally Posted by Fluff View Post
    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:

    Sku Dim.1 Dim.2 Dim.3 Dim.4 Store Description Vendor Department Product Number QTYAVL QOH SOLD COMIT QOO SO QTBP RECV TRAN OT IT ADJ Min Max QROP Lookups Dim.1 Group Dim.1 Description Dim.2 Group Dim.2 Description Dim.3 Group Dim.3 Description Dim.4 Group Dim.4 Description In Store Location Price ListCost AvgCost Brand Season Bin Picking# Tax1 Tax2 Tax3
    8024 True Terpenes .5ml Ceramic Cartridge White True Terpenes Extraction 19192 4830 0 0 0 0 25000 -1100 0 0 122 0 0 0 $0.99 $0.80 $0.80 True Terpenes Y
    6258 Cartridge Plastic Containers .5 ml ::$0.25 Ypsilanti Oil Company Extraction 17042 31327 0 0 0 0 54000 0 0 0 -5631 0 0 0 $0.25 $0.12 $0.11 $$$ Y

  10. #10
    MrExcel MVP
    Moderator
    Fluff's Avatar
    Join Date
    Jun 2014
    Location
    Chippenham
    Posts
    28,353
    Post Thanks / Like
    Mentioned
    471 Post(s)
    Tagged
    47 Thread(s)

    Default Re: Create new worksheet for each vendor

    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
    - Posting Data try one of these tools
    - Posting guidelines, forum rules and terms of use
    - Read the FAQs

    Running Office 365 on Win 10

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •