List Visible Sheet Names (with Hyperlinks if possible?)

voyto

New Member
Joined
Sep 30, 2018
Messages
7
Hi All,

I currently use workbook to manage my purchase orders at work. It's made up of a "Start" sheet, the "Template" and followed by all my orders. When orders are invoiced, I hide the sheet.

My start sheet is just a button (that duplicates the template, numbers the sheet, etc)

The template is self explanatory

What I'm trying to do is make a list on my start sheet showing all the visible sheets (minus sheets 1 and 2 (start and template) - essentially my "current open orders".
In the adjacent cell to each number, I'd also like the customer name, which can be easily taken from cell A9 within each order sheet
Also, if it's do-able, each number to be a hyperlink to that specific sheet

I'm assuming this would be done on sheet start-up, so possibly needs clearing before listing again?

This would make it really easy for me to see all the current orders when the sheet is loaded :)

Many thanks in advance.
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
How about
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 2
   With Sheets("Start")
      .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub
This needs to go in the ThisWorkbook module & will run when you open the workbook.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
How about
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 2
   With Sheets("Start")
      .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub
This needs to go in the ThisWorkbook module & will run when you open the workbook.

Sorry for being a pain - I've tried to adjust but I clearly just don't understand properly. Would you mind tweaking slightly?

- results to be sheetName, H20, A9 from the order sheet, not just sheetName and A9
- results to start from the 8th row. They are currently starting on the second row
 
Upvote 0
How about
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 8
   With Sheets("Start")
      .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("H20").Value
               .Offset(, 2).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub
 
Upvote 0
How about
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 8
   With Sheets("Start")
      .Range("A2:B" & .Range("A" & Rows.Count).End(xlUp).Row).ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("H20").Value
               .Offset(, 2).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub

That also worked great, thanks.

Promise this will be the last adjustment now (if you don't mind of course).

Can you limit the "clear contents" to only the first 100 rows? I have data below that's getting wiped out
 
Upvote 0
Try
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 8
   With Sheets("Start")
      .Range("A8:C100").ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("H20").Value
               .Offset(, 2).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub
 
Upvote 0
Try
VBA Code:
Private Sub Workbook_Open()
   Dim i As Long, j As Long

   j = 8
   With Sheets("Start")
      .Range("A8:C100").ClearContents
      For i = 3 To Sheets.Count
         If Sheets(i).Visible = xlSheetVisible Then
            With .Range("A" & j)
               .Value = Sheets(i).Name
               .Hyperlinks.Add .Offset(0), "", "'" & Sheets(i).Name & "'!A9", Sheets(i).Name
               .Offset(, 1).Value = Sheets(i).Range("H20").Value
               .Offset(, 2).Value = Sheets(i).Range("A9").Value
               j = j + 1
            End With
         End If
      Next i
   End With
End Sub
I can't thank you enough! That's saved me loads of time.
 
Last edited by a moderator:
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,913
Members
448,532
Latest member
9Kimo3

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top