+ Reply to Thread
Results 1 to 4 of 4

Generate separate workbooks from main Workbook

Hybrid View

robbie58 Generate separate workbooks... 07-15-2012, 01:08 PM
WasWodge Re: Generate separate... 07-15-2012, 02:16 PM
jaslake Re: Generate separate... 07-15-2012, 02:51 PM
robbie58 Re: Generate separate... 07-15-2012, 05:08 PM
  1. #1
    Registered User
    Join Date
    06-14-2011
    Location
    Irelnad
    MS-Off Ver
    Excel 2007
    Posts
    2

    Generate separate workbooks from main Workbook

    Hi there,
    I have a spreadsheet with work sites located in Irish counties in a spreadsheet. The county that the site is in is located in column A, and there can be anything from 1 to 100 sites per county. I need to filter out all the sites in one county, copy all the data (column A to Column FF or something), paste this as transposed data in a new WB, and complete this for all the other counties.
    There are currently approximately 200 sites. I have a macro, but it is going to be very long winded as I don't know how to get it to run auutomatically for each county, so I am just reproducing the action for 20 odd counties. Can anyone make this shorter?
    Thanks in advance
    Attached Files Attached Files

  2. #2
    Valued Forum Contributor WasWodge's Avatar
    Join Date
    08-02-2010
    Location
    Hampshire,England
    MS-Off Ver
    Office 365 and Office 2010
    Posts
    882

    Re: Generate separate workbooks from main Workbook

    Try This Ron de Bruin code. Amend the bits in red (the number of columns and the file path). Obviously test on a copy of your data

    Sub Copy_To_Workbooks()
    'Note: This macro use the function LastRow
        Dim My_Range As Range
        Dim FieldNum As Long
        Dim FileExtStr As String
        Dim FileFormatNum As Long
        Dim CalcMode As Long
        Dim ViewMode As Long
        Dim ws2 As Worksheet
        Dim MyPath As String
        Dim foldername As String
        Dim Lrow As Long
        Dim cell As Range
        Dim CCount As Long
        Dim WSNew As Worksheet
        Dim ErrNum As Long
    
        'Set filter range on ActiveSheet: A1 is the top left cell of your filter range
        'and the header of the first column, D is the last column in the filter range.
        'You can also add the sheet name to the code like this :
        'Worksheets("Sheet1").Range("A1:D" & LastRow(Worksheets("Sheet1")))
        'No need that the sheet is active then when you run the macro when you use this.
        Set My_Range = Range("A1:F" & LastRow(ActiveSheet))
        My_Range.Parent.Select
    
        If ActiveWorkbook.ProtectStructure = True Or _
           My_Range.Parent.ProtectContents = True Then
            MsgBox "Sorry, not working when the workbook or worksheet is protected", _
                   vbOKOnly, "Copy to new workbook"
            Exit Sub
        End If
    
        'This example filters on the first column in the range(change the field if needed)
        'In this case the range starts in A so Field:=1 is column A, 2 = column B, ......
        FieldNum = 1
    
        'Turn off AutoFilter
        My_Range.Parent.AutoFilterMode = False
    
        'Set the file extension/format
        If Val(Application.Version) < 12 Then
            'You use Excel 97-2003
            FileExtStr = ".xls": FileFormatNum = -4143
        Else
            'You use Excel 2007-2010
            If ActiveWorkbook.FileFormat = 56 Then
                FileExtStr = ".xls": FileFormatNum = 56
            Else
                FileExtStr = ".xlsx": FileFormatNum = 51
            End If
        End If
    
        'Change ScreenUpdating, Calculation, EnableEvents, ....
        With Application
            CalcMode = .Calculation
            .Calculation = xlCalculationManual
            .ScreenUpdating = False
            .EnableEvents = False
        End With
        ViewMode = ActiveWindow.View
        ActiveWindow.View = xlNormalView
        ActiveSheet.DisplayPageBreaks = False
    
        'Delete the sheet RDBLogSheet if it exists
        On Error Resume Next
        Application.DisplayAlerts = False
        Sheets("RDBLogSheet").Delete
        Application.DisplayAlerts = True
        On Error GoTo 0
    
        ' Add worksheet to copy/Paste the unique list
        Set ws2 = Worksheets.Add(After:=Sheets(Sheets.Count))
        ws2.Name = "RDBLogSheet"
    
       MyPath = "C:\Users\WasWodge\Desktop\list files\"
    
        'Add a slash at the end if the user forget it
        If Right(MyPath, 1) <> "\" Then
            MyPath = MyPath & "\"
        End If
    
        'Create folder for the new files
        foldername = MyPath & Format(Now, "yyyy-mm-dd hh-mm-ss") & "\"
        MkDir foldername
    
        With ws2
            'first we copy the Unique data from the filter field to ws2
            My_Range.Columns(FieldNum).AdvancedFilter _
                    Action:=xlFilterCopy, _
                    CopyToRange:=.Range("A3"), Unique:=True
    
            'loop through the unique list in ws2 and filter/copy to a new sheet
            Lrow = .Cells(Rows.Count, "A").End(xlUp).Row
            For Each cell In .Range("A4:A" & Lrow)
    
                'Filter the range
                My_Range.AutoFilter Field:=FieldNum, Criteria1:="=" & _
                 Replace(Replace(Replace(cell.Value, "~", "~~"), "*", "~*"), "?", "~?")
    
                'Check if there are no more then 8192 areas(limit of areas)
                CCount = 0
                On Error Resume Next
                CCount = My_Range.Columns(1).SpecialCells(xlCellTypeVisible) _
                         .Areas(1).Cells.Count
                On Error GoTo 0
                If CCount = 0 Then
                    MsgBox "There are more than 8192 areas for the value : " & cell.Value _
                         & vbNewLine & "It is not possible to copy the visible data." _
                         & vbNewLine & "Tip: Sort your data before you use this macro.", _
                           vbOKOnly, "Split in worksheets"
                Else
                    'Add new workbook with one sheet
                    Set WSNew = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
    
                    'Copy/paste the visible data to the new workbook
                    My_Range.SpecialCells(xlCellTypeVisible).Copy
                    With WSNew.Range("A1")
                        ' Paste:=8 will copy the columnwidth in Excel 2000 and higher
                        ' Remove this line if you use Excel 97
                        .PasteSpecial Paste:=8
                        .PasteSpecial xlPasteValues
                        .PasteSpecial xlPasteFormats
                        Application.CutCopyMode = False
                        .Select
                    End With
    
                    'Save the file in the new folder and close it
                    On Error Resume Next
                    WSNew.Parent.SaveAs foldername & _
                                        cell.Value & FileExtStr, FileFormatNum
                    If Err.Number > 0 Then
                        Err.Clear
                        ErrNum = ErrNum + 1
    
                        WSNew.Parent.SaveAs foldername & _
                         "Error_" & Format(ErrNum, "0000") & FileExtStr, FileFormatNum
    
                        .Cells(cell.Row, "B").Formula = "=Hyperlink(""" & foldername & _
                          "Error_" & Format(ErrNum, "0000") & FileExtStr & """)"
    
                        .Cells(cell.Row, "A").Interior.Color = vbRed
                    Else
                        .Cells(cell.Row, "B").Formula = _
                        "=Hyperlink(""" & foldername & cell.Value & FileExtStr & """)"
                    End If
    
                    WSNew.Parent.Close False
                    On Error GoTo 0
                End If
    
                'Show all the data in the range
                My_Range.AutoFilter Field:=FieldNum
    
            Next cell
            .Cells(1, "A").Value = "Red cell: can't use the Unique name as file name"
            .Cells(1, "B").Value = "Created Files (Click on the link to open a file)"
            .Cells(3, "A").Value = "Unique Values"
            .Cells(3, "B").Value = "Full Path and File name"
            .Cells(3, "A").Font.Bold = True
            .Cells(3, "B").Font.Bold = True
            .Columns("A:B").AutoFit
    
        End With
    
        'Turn off AutoFilter
        My_Range.Parent.AutoFilterMode = False
    
        If ErrNum > 0 Then
            MsgBox "Rename every WorkSheet name that start with ""Error_"" manually" _
                 & vbNewLine & "There are characters in the name that are not allowed" _
                 & vbNewLine & "in a sheet name or the worksheet already exist."
        End If
    
        'Restore ScreenUpdating, Calculation, EnableEvents, ....
        My_Range.Parent.Select
        ActiveWindow.View = ViewMode
        ws2.Select
        With Application
            .ScreenUpdating = True
            .EnableEvents = True
            .Calculation = CalcMode
        End With
    
    End Sub
    
    
    Function LastRow(sh As Worksheet)
        On Error Resume Next
        LastRow = sh.Cells.Find(What:="*", _
                                After:=sh.Range("A1"), _
                                Lookat:=xlPart, _
                                LookIn:=xlValues, _
                                SearchOrder:=xlByRows, _
                                SearchDirection:=xlPrevious, _
                                MatchCase:=False).Row
        On Error GoTo 0
    End Function
    If my solution worked (or not) please let me know. If your question is answered then please remember to mark it solved

    Computers are like air conditioners. They work fine until you start opening windows. ~Author Unknown

  3. #3
    Forum Expert jaslake's Avatar
    Join Date
    02-21-2009
    Location
    Atwood Lake in Mid NE Ohio...look it up.
    MS-Off Ver
    Excel 2010 2019
    Posts
    12,749

    Re: Generate separate workbooks from main Workbook

    Hi Robbie58
    Welcome to the Forum!
    Take a look at these links...they both address what you describe. If you need help adapting the code to your file, upload a copy of the file and I'll look at it.
    http://www.excelforum.com/excel-prog...2007-file.html
    http://www.excelforum.com/excel-prog...-workbook.html

    PS: a Word Doc is of little value.
    John

    If you have issues with Code I've provided, I appreciate your feedback.

    In the event Code provided resolves your issue, please mark your Thread as SOLVED.

    If you're satisfied by any members response to your issue please use the star icon at the lower left of their post.

  4. #4
    Registered User
    Join Date
    06-14-2011
    Location
    Irelnad
    MS-Off Ver
    Excel 2007
    Posts
    2

    Re: Generate separate workbooks from main Workbook

    Thanks guys, I started fiddling with the first code provided by WasWodge and it did what I wanted after I changed a few things. Sorry about not providing the Excel sheet, I attach the one showing how far I have got with the macro. It is populated with false data but it shows where the data would be!

    Now that I have extracted the data I need two more things.
    1) on each sheet it needs the headings from the original sheet...there are three or four rows with important headings above all the data which is required in each summary sheet.
    2) I also need to transpose everything when it is moved to the new sheet, so that instead of presenting horizontally, it will be presented vertically. I think this is achievable by using an intermediate sheet, but I'm just wondering where to start.

    Thanks so much for your help!
    Attached Files Attached Files

+ 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