Consulting

Results 1 to 4 of 4

Thread: Error '9': Subscript out of range when trying to change codename of a sheet

  1. #1
    VBAX Newbie
    Joined
    Jul 2011
    Posts
    3
    Location

    Error '9': Subscript out of range when trying to change codename of a sheet

    Hi all,

    Here is the case:

    I have to:
    1) Add a new worksheet
    2) Name the worksheet "MATLAB Input"
    3) Change the codename of the worksheet to "Sheet4"

    I use this code:
    [VBA]
    Sheets.Add
    ActiveSheet.Name = "MATLAB Input"
    ActiveSheet.Move After:=ActiveWorkbook.Sheets("Producthistorie")
    ThisWorkbook.VBProject.VBComponents(ActiveSheet.CodeName).Name = "Sheet4"[/VBA]

    It works fine when I run it from VBE (play button). However when I call this macro from a button on a sheet I get error 9: Subscript out of range. How to do this?

    Best regards,


    Bart

  2. #2
    VBAX Guru mancubus's Avatar
    Joined
    Dec 2010
    Location
    "Where I lay my head is home" :D
    Posts
    2,644
    PLS DO NOT PM; OPEN A THREAD INSTEAD!!!

    1) Posting Code
    [CODE]PasteYourCodeHere[/CODE]
    (or paste your code, select it, click # button)

    2) Uploading File(s)
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) (multiple files can be selected while holding Ctrl key) / Upload Files / Done
    Replace company specific / sensitive / confidential data. Include so many rows and sheets etc in the uploaded workbook to enable the helpers visualize the data and table structure. Helpers do not need the entire workbook.

    3) Testing the Codes
    always back up your files before testing the codes.

    4) Marking the Thread as Solved
    from Thread Tools (on the top right corner, above the first message)

  3. #3
    Knowledge Base Approver VBAX Guru GTO's Avatar
    Joined
    Sep 2008
    Posts
    3,368
    Location
    Greetings Bart,

    I did not try yours, so not sure about the error. Try:

    [vba]
    Option Explicit

    Sub Main()
    Dim wksNew As Worksheet

    Const PRODHX As String = "Producthistorie"

    With ThisWorkbook
    '// Ensure 'Producthistorie' exists before placing/moving //
    If ShExists(PRODHX) Then
    Set wksNew = .Worksheets.Add(After:=.Worksheets(PRODHX))
    Else
    Set wksNew = .Worksheets.Add(After:=.Worksheets(.Worksheets.Count))
    End If
    '// Ensure we don't already have a sheet named 'MATLAB' //
    If Not ShExists("MATLAB", ThisWorkbook) Then
    wksNew.Name = "MATLAB"
    End If
    '// Ensure we don't already have a sheet w/CodeName of 'shtMATLAB'. Use the //
    '// hidden property '_CodeName' //
    If Not CodeNameExists("shtMATLAB", ThisWorkbook) Then
    wksNew.Parent.VBProject.VBComponents(wksNew.CodeName).Properties("_CodeName ") = "shtMATLAB"
    End If
    End With
    End Sub

    Function CodeNameExists(NewCodeName As String, Optional wb As Workbook) As Boolean

    If wb Is Nothing Then Set wb = ThisWorkbook

    On Error Resume Next
    CodeNameExists = Not wb.VBProject.VBComponents(NewCodeName) Is Nothing
    On Error GoTo 0
    End Function

    Function ShExists(ShName As String, Optional wb As Workbook) As Boolean

    If wb Is Nothing Then Set wb = ThisWorkbook

    On Error Resume Next
    ShExists = wb.Worksheets(ShName).Name = ShName
    On Error GoTo 0
    End Function
    [/vba]

    Hope that helps,

    Mark

  4. #4
    Mac Moderator VBAX Guru mikerickson's Avatar
    Joined
    May 2007
    Location
    Davis CA
    Posts
    2,778
    Is the code in the code module of the sheet whose code name is being changed? I would avoid that.

Posting Permissions

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