Combining two different subs w/ similar variables

M

Matthew Dyer

So I am using Ron de Bruin's codes from his website very successfully,
but I was wondering how to combine two of them into one executable
code. I am using his "create a new workbook" and his "create a new
sheet" codes. Ron's website is http://www.rondebruin.nl/copy5.htm ,
but for the sake of brevity I will post the two codes I'm using here.
I want to combine the two codes so that from one master list, it will
create the sepearate workbooks from the value of column A, and also
each new workbook would be seperated into sheets based on column B.

---------------------------------------------------------------------------------------------
Sheet Creator -

Sub Sheet_creator()
'Note: This macro use the function LastRow
Dim My_Range As Range
Dim FieldNum As Long
Dim CalcMode As Long
Dim ViewMode As Long
Dim ws2 As Worksheet
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, G 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:H" & 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 worksheet"
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 = 2

'Turn off AutoFilter
My_Range.Parent.AutoFilterMode = False

'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

'Add a worksheet to copy the a unique list and add the
CriteriaRange
Set ws2 = Worksheets.Add

With ws2
'first we copy the Unique data from the filter field to ws2
My_Range.Columns(FieldNum).AdvancedFilter _
Action:=xlFilterCopy, _
CopyToRange:=.Range("A1"), 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("A2: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 a new worksheet
Set WSNew = Worksheets.Add(After:=Sheets
(Sheets.Count))
On Error Resume Next
WSNew.Name = cell.Value
If Err.Number > 0 Then
ErrNum = ErrNum + 1
WSNew.Name = "Error_" & Format(ErrNum, "0000")
Err.Clear
End If
On Error GoTo 0

'Copy the visible data to the new worksheet
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
'Set column width for D and E
Columns("D:D").ColumnWidth = 5
Columns("E:E").ColumnWidth = 7.43

End With
With WSNew.PageSetup
.LeftMargin = Application.InchesToPoints(0.5)
.RightMargin = Application.InchesToPoints(0.5)
.TopMargin = Application.InchesToPoints(0.5)
.BottomMargin = Application.InchesToPoints(0.5)
.HeaderMargin = Application.InchesToPoints(0.5)
.FooterMargin = Application.InchesToPoints(0.5)
.PrintHeadings = False
.PrintGridlines = False
.PrintComments = xlPrintNoComments
.CenterHorizontally = False
.CenterVertically = False
.PaperSize = xlPaperLetter
.FirstPageNumber = xlAutomatic
.Orientation = xlPortrait
.Draft = False
.Order = xlDownThenOver
.BlackAndWhite = False
.Zoom = False
.PrintErrors = xlPrintErrorsDisplayed
.FitToPagesWide = 1
.FitToPagesTall = 3
End With
Cells.EntireColumn.AutoFit
Rows("1:1").Font.Bold = True



End If

'Show all data in the range
My_Range.AutoFilter Field:=FieldNum

Next cell

'Delete the ws2 sheet
On Error Resume Next
Application.DisplayAlerts = False
.Delete
Application.DisplayAlerts = True
On Error GoTo 0

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
With Application
.ScreenUpdating = True
.EnableEvents = True
.Calculation = CalcMode
.ScreenUpdating = True
End With

Application.DisplayAlerts = False
Sheets("Sheet1").Delete
Application.DisplayAlerts = True


End Sub
------------------------------------------------------
Workbook Creator -

Sub Workbook_Creator()
'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:H" & 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
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"

'Fill in the path\folder where you want the new folder with the
files
'you can use also this "C:\Users\Ron\test"
MyPath = "C:\Documents and Settings\E179342\Desktop
\Worklist_Detail_Report"

'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, "mm-dd-yyyy") & "\"
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
 
R

Ron de Bruin

Hi Matthew

Before the save line in the Copy_To_Workbooks macro call the other macro


Call Copy_To_Worksheets

'Save the file in the new folder and close it
On Error Resume Next
WSNew.Parent.SaveAs foldername & _
cell.Value & FileExtStr, FileFormatNum



In the Copy_To_Worksheets macro change the range so it start in A1

and change fieldnum to 2





--

Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm
 
M

Matthew Dyer

I placed the Call function where you specified and it works great...
up to a point. I get an error - run-time error '1004': select method
of worksheet class failed - and when I go into the debugger, the
last My_Range.Parent.Select line is highlighted in the workbook
creator sub. I also notice that none of the new workbooks that are
created are saved with the unique values in column A. This is not a
big deal since i can just save the files by hand, but the auto-safe
function was neat.
 
R

Ron de Bruin

I test it fast with the example workbook and it was OK

I test good when I am home from work
 
M

Matthew Dyer

I figured out what the issue is Ron, and I hope you can help me out.
When the Copy_To_Worksheets sub is initialized, I want to delete
Sheet1 from the newly created Workbooks. I am using the following code
to do so:

Application.DisplayAlerts = False
Sheets("Sheet1").Delete
Application.DisplayAlerts = True

I've entered it into the Copy_to_Worksheets macro after the ('Restore
ScreenUpdating, Calculation, EnableEvents, ....) commands and also in
the Copy_to_Workbooks macro right after the Call Copy_to_Worksheets
but it seems to mess with the Parent thing in either location. Any
ideas?
 
R

Ron de Bruin

We must change the code to do this
I hope I have time to create a example for you today
 
R

Ron de Bruin

I am fast <g>

Try this one


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
Dim WBNew As Workbook

'Set filter range on ActiveSheet: A11 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("A11: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("A11:D" & 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
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"

'Fill in the path\folder where you want the new folder with the files
'you can use also this "C:\Users\Ron\test"
MyPath = Application.DefaultFilePath

'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)
Set WBNew = ActiveWorkbook

'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

Call Copy_To_Worksheets

Application.DisplayAlerts = False
WSNew.Delete
Application.DisplayAlerts = True

'Save the file in the new folder and close it
On Error Resume Next
WBNew.SaveAs foldername & _
cell.Value & FileExtStr, FileFormatNum
If Err.Number > 0 Then
Err.Clear
ErrNum = ErrNum + 1

WBNew.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

WBNew.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



Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm
 
M

Matthew Dyer

Ron, you are the man! Works just how I wanted it to. I see the
WSNew.delete code you used instead of the Sheet1.delete code I used.
Do you know why it has to be done this way?
 
R

Ron de Bruin

Hi Matthew
WSNew.delete code you used instead of the Sheet1.delete code I used.

We already set a reference to this sheet so why not use it
And if you run the code in a non english version "Sheet1" is different
WSNew is always working

But there is more, the old code use

WSNew.parent to save and close the file
But if you delete this sheet WSNew = nothing so the code break

After we add the new workbook

Set WSNew = Workbooks.Add(xlWBATWorksheet).Worksheets(1)
Set WBNew = ActiveWorkbook

We set WBNew now so we can use that to save/close the file

WBNew.SaveAs foldername & _
cell.Value & FileExtStr, FileFormatNum


WBNew.Close False


--

Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm
 
M

Matthew Dyer

You sir are a Genius! End of story! Thank you for all the help you
provide myself and countless others in our Excel endeavors!
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top