+ Reply to Thread
Results 1 to 4 of 4

creating separate worksheets

Hybrid View

  1. #1
    Registered User
    Join Date
    11-16-2010
    Location
    London
    MS-Off Ver
    Excel 2003
    Posts
    11

    creating separate worksheets

    Hi,

    In the attached I have a list of employees from different countries:

    CAN
    ESP
    FR
    GER
    UK
    US

    The country code is in Column B.

    I would like a macro which takes this workbook and creates 6 different workshhets
    for each country, with each worksheet containing employees from that respective country

    Thank yoiuo

  2. #2
    Forum Guru
    Join Date
    08-26-2007
    Location
    London
    Posts
    4,606

    Re: creating separate worksheets

    There is no attached. A workbook would be helpful.

  3. #3
    Forum Expert royUK's Avatar
    Join Date
    11-18-2003
    Location
    Derbyshire,UK
    MS-Off Ver
    Xp; 2007; 2010
    Posts
    26,200

    Re: creating separate worksheets

    Here's some code that I use for this job, you will need to change Column references

    
    'Option Explicit
    
    '---------------------------------------------------------------------------------------
    ' Module    : Module1
    ' DateTime  : 24/09/2006 22:48
    ' Author    : Roy Cox (royUK)
    ' Website   :  more examples
    ' Purpose   :  Create a sheet for each unique name in data
    ' Disclaimer; This code is offered as is with no guarantees. You may use it in your
    '             projects but please leave this header intact.
    '---------------------------------------------------------------------------------------
    
    Sub ExtractToSheets()
        Dim ws     As Worksheet
        Dim wsNew  As Worksheet
        Dim rData  As Range
        Dim rCl    As Range
        Dim sNm    As String
        Set ws = Sheet1
    
        'extract a list of unique names
        'first clear existing list
        With ws
            Set rData = .Range(.Cells(1, 1), .Cells(.Rows.Count, 9).End(xlUp))
            .Columns(.Columns.Count).Clear
            .Range(.Cells(2, 3), .Cells(.Rows.Count, 3).End(xlUp)).AdvancedFilter Action:=xlFilterCopy, CopyToRange:=.Cells(1, .Columns.Count), Unique:=True
    
            For Each rCl In .Range(.Cells(1, .Columns.Count), .Cells(.Rows.Count, .Columns.Count).End(xlUp))
                sNm = rCl.Text
                'add new sheet (only if required-NB uses UDF)
                If WksExists(sNm) Then
                    'so clear contents
                    Sheets(sNm).Cells.Clear
                Else
                    'new sheet required
                    Set wsNew = Sheets.Add
                    wsNew.Move After:=Worksheets(Worksheets.Count)    'move to end
                    wsNew.Name = sNm
                End If
                'AutoFilter & copy to relevant sheet
                rData.AutoFilter Field:=3, Criteria1:=sNm
                rData.Copy Destination:=Worksheets(sNm).Cells(1, 1)
            Next rCl
        End With
        ws.Columns(Columns.Count).ClearContents        'remove temporary list
        rData.AutoFilter        'switch off AutoFilter
    End Sub
    
    Function WksExists(wksName As String) As Boolean
        On Error Resume Next
        WksExists = CBool(Len(Worksheets(wksName).Name) > 0)
    End Function
    Last edited by royUK; 11-18-2010 at 01:59 PM.
    Hope that helps.

    RoyUK
    --------
    For Excel Tips & Solutions, free examples and tutorials why not check out my web site

    Free DataBaseForm example

  4. #4
    Forum Expert royUK's Avatar
    Join Date
    11-18-2003
    Location
    Derbyshire,UK
    MS-Off Ver
    Xp; 2007; 2010
    Posts
    26,200

    Re: creating separate worksheets

    This works in your example
    Option Explicit
    
    '---------------------------------------------------------------------------------------
    ' Module    : Module1
    ' DateTime  : 24/09/2006 22:48
    ' Author    : Roy Cox (royUK)
    ' Website   :  more examples
    ' Purpose   :  Create a sheet for each unique name in data
    ' Disclaimer; This code is offered as is with no guarantees. You may use it in your
    '             projects but please leave this header intact.
    '---------------------------------------------------------------------------------------
    
    Sub ExtractToSheets()
        Dim ws     As Worksheet
        Dim wsNew  As Worksheet
        Dim rData  As Range
        Dim rCl    As Range
        Dim sNm    As String
        Set ws = Sheet1
    
        'extract a list of unique names
        'first clear existing list
        With ws
            Set rData = .Range(.Cells(1, 1), .Cells(.Rows.Count, 7).End(xlUp))
            .Columns(.Columns.Count).Clear
            .Range(.Cells(2, 3), .Cells(.Rows.Count, 3).End(xlUp)).AdvancedFilter Action:=xlFilterCopy, CopyToRange:=.Cells(1, .Columns.Count), Unique:=True
    
            For Each rCl In .Range(.Cells(1, .Columns.Count), .Cells(.Rows.Count, .Columns.Count).End(xlUp))
                sNm = rCl.Text
                'add new sheet (only if required-NB uses UDF)
                If WksExists(sNm) Then
                    'so clear contents
                    Sheets(sNm).Cells.Clear
                Else
                    'new sheet required
                    Set wsNew = Sheets.Add
                    wsNew.Move After:=Worksheets(Worksheets.Count)    'move to end
                    wsNew.Name = sNm
                End If
                'AutoFilter & copy to relevant sheet
                rData.AutoFilter Field:=3, Criteria1:=sNm
                rData.Copy Destination:=Worksheets(sNm).Cells(1, 1)
            Next rCl
        End With
        ws.Columns(Columns.Count).ClearContents        'remove temporary list
        rData.AutoFilter        'switch off AutoFilter
    End Sub
    
    Function WksExists(wksName As String) As Boolean
        On Error Resume Next
        WksExists = CBool(Len(Worksheets(wksName).Name) > 0)
    End Function
    I'll add some code to separate workbooks later

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1