Creating New Worksheet/Workbooks based on Existing Data from Master Sheet

AGMGCM

New Member
Joined
Feb 8, 2018
Messages
5
I am in the process of automating some of my workflow and cannot figure out how to best approach this situation.


I have an inventory sheet that I would like to create new sheets off of based on categories. Each category would need its own file generated along with all items included.


The second image highlights how the data should sit within a pre-designed template, the information needing to line up with specific cells.






Please let me know what you think the best way to approach this would be.


Thank you.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,336
Office Version
365
Platform
Windows
Maybe
Code:
Sub splitDataToTemplate()

   Dim Cl As Range
   Dim Ws As Worksheet
   
Application.ScreenUpdating = False
   Set Ws = Sheets("Pcode")
   If Ws.AutoFilterMode Then Ws.AutoFilterMode = False
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("E2", Ws.Range("E" & Rows.count).End(xlUp))
         If Not .exists(Cl.Value) Then
            .Add Cl.Value, Nothing
            Sheets.Add.Name = Cl.Value
            Range("E1").Value = Cl.Value
            Ws.Range("A1:E1").AutoFilter 5, Cl.Value
            Intersect(Ws.AutoFilter.Range.Offset(1), Ws.Range("A:E")).SpecialCells(xlVisible).Copy Range("C3")
         End If
      Next Cl
      Ws.AutoFilterMode = False
   End With
End Sub
 

AGMGCM

New Member
Joined
Feb 8, 2018
Messages
5
Hi Fluff,

Thank you for your prompt reply, this code works great and I have learned much from it. The only trouble I am having is that this creates a blank sheet for each food category, is there any way of duplicating an existing sheet within the workbook for each category and pasting into C3 of those duplicated sheets? I would like to separate each category into a pre-designed template.

Any thoughts would be appreciated, thank you again.
 

AGMGCM

New Member
Joined
Feb 8, 2018
Messages
5
Hi Fluff,

It seems I may have posted too soon, I was trying something out and my only issue seems to have been the syntax.

I am using
Code:
   If Not .exists(Cl.Value) Then
            .Add Cl.Value, Nothing
            Worksheets("Template").Copy After:=Worksheets(Worksheets.Count)
            Worksheets(Worksheets.Count).Name = Cl.Value
to solve my issue, if you see any problems with this method please let me know otherwise thanks again so much for your help!
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
32,336
Office Version
365
Platform
Windows
Glad to help & thanks for the feedback.

And there's nothing wrong with what you've changed
 

Torimonoki

New Member
Joined
Apr 24, 2018
Messages
2
Hello

I am try to use this method in my work but it does not work when column 5 in the start of columns, how to make it work? Only workings when group column at end.

thanks
 

Torimonoki

New Member
Joined
Apr 24, 2018
Messages
2
Maybe
Code:
Sub splitDataToTemplate()

   Dim Cl As Range
   Dim Ws As Worksheet
   
Application.ScreenUpdating = False
   Set Ws = Sheets("Pcode")
   If Ws.AutoFilterMode Then Ws.AutoFilterMode = False
   With CreateObject("scripting.dictionary")
      For Each Cl In Ws.Range("E2", Ws.Range("E" & Rows.count).End(xlUp))
         If Not .exists(Cl.Value) Then
            .Add Cl.Value, Nothing
            Sheets.Add.Name = Cl.Value
            Range("E1").Value = Cl.Value
            Ws.Range("A1:E1").AutoFilter 5, Cl.Value
            Intersect(Ws.AutoFilter.Range.Offset(1), Ws.Range("A:E")).SpecialCells(xlVisible).Copy Range("C3")
         End If
      Next Cl
      Ws.AutoFilterMode = False
   End With
End Sub
Your datas as example



Column 5 in beginning
 

Forum statistics

Threads
1,082,389
Messages
5,365,161
Members
400,827
Latest member
Mitzescu

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top