Consulting

Results 1 to 5 of 5

Thread: Can't figure it out .... Weird Bug!!

  1. #1

    Can't figure it out .... Weird Bug!!

    Hello.

    I can't figure out why this is not working. It was working for a bit but then I added some titles in the first row of a few sheets in the workbook then the code started giving errors. Confusing!
    Basically, this part of the VBA code just goes through and clears all the sheets in the workbook from row 2 colume 1 on (so it leave the titles in the first row). So it works fine for the sheet called "Cover Sheet" but then gives a a weird error (The error just says "400") for any of the others that have different sheet names. I've verified that the sheet names in the code match exactly the sheet names in my excel workbook. They do. I changed the logic to Range(A2:AA65536).clear for the Sheet "Protect" and it works fine for the other sheets. But it wont using the range(cells(2,1), Cells(65536,100)).clear for any sheets other that "Cover Sheet" Any idea whats going on????
    Here is the snippet of code
    [VBA] Set basebook = ThisWorkbook
    'clear all cells on the first sheet
    basebook.Sheets("Cover Sheet").Range(Cells(2, 1), Cells(65536, 100)).Clear
    'basebook.Sheets("Protect").Range(Cells(2, 1), Cells(65536, 100)).Clear (This won't Work)
    basebook.Sheets("Protect").Range("A2:AA65536").Clear (This does work)
    basebook.Sheets("Enable ANSF").Range(Cells(2, 1), Cells(65536, 100)).Clear
    basebook.Sheets("Socio-Economic Dev").Range(Cells(2, 1), Cells(65536, 50)).Clear
    basebook.Sheets("Governance").Range(Cells(2, 1), Cells(65536, 100)).Clear
    basebook.Sheets("Measures of Performance").Range(Cells(2, 1), Cells(65536, 50)).Clear
    basebook.Sheets("Commander's Assessment").Range(Cells(2, 1), Cells(65536, 50)).Clear[/VBA]

  2. #2
    Moderator VBAX Master austenr's Avatar
    Joined
    Sep 2004
    Location
    Maine
    Posts
    2,033
    Location
    Why don't you post a sample workbook.
    Peace of mind is found in some of the strangest places.

  3. #3
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,726
    Location
    Using Cells this way applies to the activesheet and "Protect" is probably not the activesheet

    [vba]
    'basebook.Sheets("Protect").Range(Cells(2, 1), Cells(65536, 100)).Clear (This won't Work)
    [/vba]

    Maybe this

    [vba]
    basebook.Sheets("Protect").Range(Cells(2, 1).Resize(65536, 100).Clear
    [/VBA]

    Paul

  4. #4
    VBAX Guru Kenneth Hobs's Avatar
    Joined
    Nov 2005
    Location
    Tecumseh, OK
    Posts
    4,956
    Location
    Don't assume that your workbook and worksheet exists.

    [VBA]Sub Test_Clear2toEnd()
    Clear2toEnd ThisWorkbook.Name, "Sheet1x"
    End Sub
    Sub Clear2toEnd(Swb As String, Sst As String)
    Dim wb As Workbook
    Dim st As Worksheet
    On Error Resume Next

    Set wb = Workbooks(Swb)
    If Err.Number = 9 Then
    MsgBox "Workbook, " & Swb & ", does not exist!", vbCritical
    Exit Sub
    End If

    Set st = wb.Worksheets(Sst)
    If Err.Number = 9 Then
    MsgBox "WorkSheet, " & Sst & ", does not exist!", vbCritical
    Exit Sub
    End If

    Dim lastRow As Long
    lastRow = st.Cells.Rows.Count
    st.Range(st.Cells(2, "A"), st.Cells(lastRow, "AA")).Clear

    Set wb = Nothing
    Set st = Nothing
    End Sub[/VBA]

  5. #5
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    When using the two argument form of Range, qualification is done on the arguments, not on the function. In
    [vba]basebook.Sheets("Protect").Range(Cells(2, 1), Cells(65536, 100)).Clear
    [/vba]The Cells are unqualified and refer to the ActiveSheet, not basebook.Sheets("protect")

    That could be replaced with
    [vba]With basebook.Sheets("Protect")
    Range(.Cells(2,1), .Cells(65536,100)).Clear
    End With[/vba]
    As one can see from my first sentence, I find it useful to think of the two argument form of Range as a function and the one argument form as a Property.

Posting Permissions

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