VBA Help Need - Creating a Table of Contents Sheet with Hyperlinks

bbalch

Board Regular
Joined
Feb 23, 2015
Messages
61
Hello everyone. I'm trying to create a macro that will insert a new tab called "SheetList" at the beginning of my workbook. This tab has "Table of Contents" in cell A4. I would like for the sheet names to be listed starting in cell B5 and continuing down until all sheets are listed. Beside the sheets names in B5 down I'm trying to create a hyperlink formula that links to corresponding tab. The code below inserts the sheet names and hyperlinks, however it starts the sheet list in B1. Any suggestions on how to modify so that the sheet names start in B5 instead of B1?

I'm not sure if it matters but I'm using Excel 2016 on Office 365.

Thanks in advance for your help and suggestions.


Code:
Sub SheetList()' Add SheetList at beginning of workbook


    Sheets.Add Before:=Sheets(1)
    Sheets(ActiveSheet.Name).Name = "SheetList"
    
'Add title and formatting


    Range("A4").Select
    Selection.FormulaR1C1 = "Table of Contents"
    Cells.Select
    With Selection.Font
        .Name = "Segoe UI Light"
        .FontStyle = "Regular"
      
    End With
    Range("A3").Select
    With Selection.Font
        .Name = "Segoe UI Light"
        .FontStyle = "Bold"
        .Size = 20


    End With
    
    
  ' Add Sheet Names in workbook
    
    Dim x As Integer
    For x = 1 To Worksheets.Count
    Cells(x, 2).Value = Worksheets(x).Name
    Next x
    
' Add hypyerlinks to tabs
    
     Dim LastRowColumnB As Long
       LastRowColumnB = Cells(Rows.Count, 2).End(xlUp).Row
        Range("C1:C" & LastRowColumnB).Formula = "=HYPERLINK(""#'""&RC[-1]&""'!A1"",RC[-1])"
    
    
End Sub
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Try this:
Code:
Sub SheetList() ' Add SheetList at beginning of workbook
'Modified 4-24-18 7:35 PM EDT
    Sheets.Add Before:=Sheets(1)
    Sheets(ActiveSheet.Name).Name = "SheetList"
    
'Add title and formatting

    Range("A4").Select
    Selection.FormulaR1C1 = "Table of Contents"
    Cells.Select
    With Selection.Font
        .Name = "Segoe UI Light"
        .FontStyle = "Regular"
      
    End With
    Range("A3").Select
    With Selection.Font
        .Name = "Segoe UI Light"
        .FontStyle = "Bold"
        .Size = 20

    End With
    
    
  ' Add Sheet Names in workbook
    
    Dim x As Integer
    For x = 1 To Worksheets.Count
    Cells(x + 4, 2).Value = Worksheets(x).Name 'Modified this line
    Next x
    
' Add hypyerlinks to tabs
    
     Dim LastRowColumnB As Long
       LastRowColumnB = Cells(Rows.Count, 2).End(xlUp).Row
        Range("C5:C" & LastRowColumnB).Formula = "=HYPERLINK(""#'""&RC[-1]&""'!A1"",RC[-1])" 'Modified this line
    
    
End Sub
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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