VBA goes past range requested

michaelehoudek

New Member
Joined
Jan 15, 2016
Messages
15
I have the following code. It works fine and does what I want, but then is continuing past the list of names. After the last named sheet is created, it throws an error after it creates the next new worksheet, but can't name it as it has created and named the last worksheet I wanted it to. The debug take me to the line bolded below. I'm thinking the error is caused by the Set MyRange line, but don't know what to do. Any ideas?

(code)
Dim MyCell As Range, MyRange As Range


Set MyRange = Selection
Set MyRange = Range(MyRange, MyRange.End(xlDown))
Application.DisplayAlerts = False


For Each MyCell In MyRange

Sheets("BASE").Select
Columns("A:BT").Select
Selection.Copy

Sheets.Add After:=Sheets(Sheets.Count) 'creates a new worksheet
Sheets(Sheets.Count).Name = MyCell.Value ' renames the new worksheet

Selection.PasteSpecial Paste:=xlPasteColumnWidths, Operation:=xlNone, _
SkipBlanks:=False, Transpose:=False
ActiveSheet.Paste

Range("a2").Value = MyCell.Value
Range("a2").Select

Next MyCell


Application.Calculation = xlCalculationAutomatic
Application.ScreenUpdating = True
Application.DisplayAlerts = True
End Sub
(End code)
 
Last edited:

njimack

Well-known Member
Joined
Jun 17, 2005
Messages
7,761
I suspect it's because you set 'MyRange' to Range(MyRange, MyRange.End(xlDown)). Depending on which cell(s) you select before running the code, this is potentially referring to more than 1 million rows. See if the below code helps (I've removed the unecessary selecting of sheets and cells).


Code:
Sub x()
Dim MyCell As Range
Dim MyRange As Range
With Application
    .Calculation = xlCalculationManual
    .ScreenUpdating = False
    .DisplayAlerts = False
End With

Set MyRange = Selection.activeregion
For Each MyCell In MyRange
    Sheets.Add after:=Sheets(Sheets.Count)
    Sheets(Sheets.Count).Name = MyCell.Value
    
    Sheets("Base").Columns("A:BT").Copy
    
    With Sheets(MyCell.Value)
        .PasteSpecial Paste:=xlPasteColumnWidths, Operation:=xlNone, SkipBlanks:=False, Transpose:=False
        .Paste
        .Range("A2") = MyCell.Value
    End With
Next MyCell

With Application
    .Calculation = xlCalculationAutomatic
    .ScreenUpdating = True
    .DisplayAlerts = True
End With

End Sub
 
Last edited:

Forum statistics

Threads
1,081,705
Messages
5,360,759
Members
400,595
Latest member
T_Dubs

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top