Consulting

Results 1 to 9 of 9

Thread: How can you use a variable to reference a worksheet object?

  1. #1

    How can you use a variable to reference a worksheet object?

    Module 1
      Public LastWS as String
    
    Sheet 3
    (Activate Event)
       LastWS = Me.Codename
    
    Sheet 2
    (Activate Event)
      LastWS = Me.Codename
    
    Sheet 1
    (Activate Event)
     Sheet1.Range("A3").Value = LastWS.Range("A2").Value

    And yes the value of LastWS exists before the activate event occurs for Sheet1.

    I have even tried cstr() with Sheets() and then Worksheets(LastWS) but nothing I try works. Everything gets thrown a subscript error. I need to use a variable to reference the worksheet by string because the last active sheet changes and that value determines what happens next.

    Bear in mind the reference to the object will be inside a for/next loop as well. Thank you.

  2. #2
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    'Module 1
    Public LastWS As Worksheet
    
    'Sheet Modules 2 & 3
    Private Sub Worksheet_Activate()
    Set LastWS = ActiveSheet
    End Sub
    
    'Sheet Module 1
    Private Sub Worksheet_Activate()
    Range("A3").Value = LastWS.Range("A2").Value
    End Sub
    MVP (Excel 2008-2010)

    Post a workbook with sample data and layout if you want a quicker solution.


    To help indent your macros try Smart Indent

    Please remember to mark threads 'Solved'

  3. #3
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,726
    Location
    You're using LastWS as if it were an object of Type Worksheet

    Sheet1.Range("A3").Value = LastWS.Range("A2").Value

    LastWS is a string with a .CodeName in it

    I think you wanted to use a string as an index / subscript into the Worksheets collection like this


    Sheet1.Range("A3").Value =Worksheets( LastWS).Range("A2").Value


    Personally, I think Mac's approach is cleaner since it strictly deals with the objects directly
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

  4. #4
    Guys here's the problem. I have tried both of these methods. It keeps throwing a Object Variable or With Block Not Set. Here is a look at the current IDE.


    Private Sub Worksheet_Activate()
    If LastWS.CodeName = "" Then Exit Sub
    MsgBox LastWS.CodeName
    For x = 1 to 3
    Sheet1.Range("A" & x).Value = LastWS.Range("A" & x).Value
    Sheet1.Range("B" & x).Value = LastWS.Range("B" & x).Value
    Sheet1.Range("C" & x).Value = LastWS.Range("C" & x).Value
    Next x
    End Sub

    Public LastWS As Worksheet (Module 1)

    Even with MsgBox LastWS.Codename alone in the sub it throws the same error.

  5. #5
    So evidently it looks like even though you use Set LastWS = ActiveSheet in the other deactivate events for other sheets.. it seems the value is not being stored? Because if I use the following code it works.

    Private Sub Worksheet_Activate()
    Set LastWS = Sheet3
    MsgBox LastWS.CodeName
    Sheet1.Range("A3").Value = LastWS.Range("A3").Value
    End Sub

  6. #6
    So on the activate event

    Set LastWS = ActiveSheet

    works fine but then once you deactivate the worksheet the value seems to be lost switching back to Sheet1 from any sheet in between 2 and 5 (5 total)

    Because I get an object with error unless I use Set LastWS in Sheet1 which is where the code above will compile
    Last edited by xmp1; 04-20-2018 at 03:08 PM.

  7. #7
    So the solution appears to be

    Activate a sheet when the workbook is open and all seems to work accordingly

  8. #8
    Moderator VBAX Sage SamT's Avatar
    Joined
    Oct 2006
    Location
    Near Columbia
    Posts
    7,814
    Location
    Module 1 Code
    Dim LastWs As Worksheet
    Sheets 2 and 3 Code
    Private Sub Worksheet_Activate()
       Set LastWs = Me
    End Sub
    Sheet1 code
    Private Sub Worksheet_Activate()
    MsgBox LastWS.CodeName
    
    
    For x = 1 to 3
    Sheet1.Range("A" & x).Value = LastWS.Range("A" & x).Value
    Sheet1.Range("B" & x).Value = LastWS.Range("B" & x).Value
    Sheet1.Range("C" & x).Value = LastWS.Range("C" & x).Value
    Next x
    
    Set LastWs = Nothing
    End Sub
    BTW, I'm not sure that you can refer to an object in the Sheets Collection by CodeName

    I gave Sheet1 a codename of Sheet11, but
    X = Sheets("Sheet11").Name
    Raises an Error.
    I expect the student to do their homework and find all the errrors I leeve in.


    Please take the time to read the Forum FAQ

  9. #9
    VBAX Sage
    Joined
    Apr 2007
    Location
    United States
    Posts
    8,726
    Location
    Maybe try this

    In a standard module

    Option Explicit
    
    Public LastWS As Worksheet
    In ThisWorkbook

    Option Explicit
    
    Private Sub Workbook_Open()
        Set LastWS = ActiveSheet
    End Sub
    
    Private Sub Workbook_SheetActivate(ByVal Sh As Object)
        MsgBox "Leaving " & LastWS.Name & " for " & Sh.Name
        
        If Sh Is Sheet1 Then
            Sheet1.Range("A3").Value = LastWS.Range("A2").Value
        End If
        
        
    End Sub
    
    Private Sub Workbook_SheetDeactivate(ByVal Sh As Object)
        Set LastWS = Sh
    End Sub
    Attached Files Attached Files
    ---------------------------------------------------------------------------------------------------------------------

    Paul


    Remember: Tell us WHAT you want to do, not HOW you think you want to do it

    1. Use [CODE] ....[/CODE ] Tags for readability
    [CODE]PasteYourCodeHere[/CODE ] -- (or paste your code, select it, click [#] button)
    2. Upload an example
    Go Advanced / Attachments - Manage Attachments / Add Files / Select Files / Select the file(s) / Upload Files / Done
    3. Mark the thread as [Solved] when you have an answer
    Thread Tools (on the top right corner, above the first message)
    4. Read the Forum FAQ, especially the part about cross-posting in other forums
    http://www.vbaexpress.com/forum/faq...._new_faq_item3

Posting Permissions

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