Consulting

Results 1 to 8 of 8

Thread: Select Sheet Tabs Dynamically

  1. #1

    Select Sheet Tabs Dynamically

    I'm using the code below to select a number of worksheets. Is it possible to list the sheetnames on a sheet called "Report" rather than hard code them in? The names will change as will the number of sheets I need to select.

    I've spent hours looking on the internet but cannot find an answer to this question.


    Sheets(Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday", "Saturday", "Sunday", "Week 01", "Week 02", "Week 03", "Week 04", "Week 05")).Select

  2. #2
    Administrator
    VP-Knowledge Base
    VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
    Have a look at this post
    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
    Thanks for the suggestion but it's not what I'm after. I need to be able to list the sheetnames in a range of cells and for this to be used in the array.

    This is what I've tried so far.

    Sub test1()
        Dim MyArray As Variant
        MyArray = Array(Sheets("Sheet1").Range("A1:A12"))
        'Sheets(Array("Monday", "Tuesday", "Wednesday", "Thursday", "Friday", "Saturday", "Sunday", "Week 01", "Week 02", "Week 03", '"Week 04", "Week 05")).Select
        Sheets(MyArray).Select
    End Sub

    Hope someone can assist further.
    Last edited by sapads; 11-01-2010 at 08:24 AM.

  4. #4
    VBAX Guru Kenneth Hobs's Avatar
    Joined
    Nov 2005
    Location
    Tecumseh, OK
    Posts
    4,956
    Location
    This method ran from a sheet adds hyperlinks to the sheets. Of course it is easy to just list and navigate by a rightclick on the navigation arrows. Just change ActiveSheet to your Report's sheet name. If you want to use the sheet name on the tag replace with Worksheets(Report).
    Sub ListSheetNames()
        Dim i As Long
        For i = 1 To Sheets.Count
            ActiveSheet.Hyperlinks.Add Anchor:=Cells(i, 1), Address:="", SubAddress:="#'" & Sheets(i).Name & "'!A1", TextToDisplay:=Sheets(i).Name
       Next i
    End Sub
    You could add some code to remove all or part of the Report sheet prior to this. Of course this could be triggered by a change to that sheet as well.

  5. #5
    Thanks again but not what I'm after.

    I need to enter the sheetnames manually in cells "A1:A12" so that I can decide which sheets are selected.

    The workbook I'm using will have over 50 worksheets so I need to be able to decide manually which ones I want selecting.

  6. #6
    Administrator
    VP-Knowledge Base VBAX Grand Master mdmackillop's Avatar
    Joined
    May 2004
    Location
    Scotland
    Posts
    14,489
    Location
     
    Sub SelectSheets()
        Dim Cel As Range
        Dim arrSheets()
        Dim i
        ReDim arrSheets(Range("SelSheets").Count)
        For Each Cel In Range("SelSheets")
            arrSheets(i) = Cel
            i = i + 1
        Next
        ReDim Preserve arrSheets(i - 1)
        Sheets(arrSheets).Select
    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'

  7. #7
    VBAX Guru Kenneth Hobs's Avatar
    Joined
    Nov 2005
    Location
    Tecumseh, OK
    Posts
    4,956
    Location
    You should probably use a listbox or something else like that I suspect.

    So, if I read what you asked for:
    Sub SelectReportSheets()
        Dim r As Range, cell As Range, ws As Sheets
        Set r = Worksheets("Report").Range("A1", Worksheets("Report").Range("A" & Rows.Count).End(xlUp))
        Set ws = Sheets(WorksheetFunction.Transpose(r))
        ws.Select
        'MsgBox ws.Count
        'application.CutCopyMode=false
        'Set r = Nothing
        'Set ws = Nothing
    End Sub

  8. #8
    Thankyou, that work's for me.

Tags for this Thread

Posting Permissions

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