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.

Data.jpg


Goal.jpg



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


Thank you.
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
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
 
Upvote 0
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.
 
Upvote 0
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!
 
Upvote 0
Glad to help & thanks for the feedback.

And there's nothing wrong with what you've changed
 
Upvote 0
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
 
Upvote 0
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

1q91zegf.jpg


Column 5 in beginning
 
Upvote 0

Forum statistics

Threads
1,223,888
Messages
6,175,206
Members
452,618
Latest member
Tam84

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