Adding hyper links from summary page to tab?

N

Nelson

Good day, I am using this VB script to create my summary page

http://www.rondebruin.nl/summary.

Column A has the customer numbers that are the sheet tab names. what I need
to do now is have each customer number in the summary worksheet hyperlink to
the corresponding worksheet (worksheet tab) everytime the worksheet is rebuild

Any suggestions?

Thanks in advance
 
R

Ron de Bruin

Try this one

Sub Summary_All_Worksheets_With_Formulas()
Dim Sh As Worksheet
Dim Newsh As Worksheet
Dim myCell As Range
Dim ColNum As Integer
Dim RwNum As Long
Dim Basebook As Workbook

With Application
.Calculation = xlCalculationManual
.ScreenUpdating = False
End With

'Delete the sheet "Summary-Sheet" if it exist
Application.DisplayAlerts = False
On Error Resume Next
ThisWorkbook.Worksheets("Summary-Sheet").Delete
On Error GoTo 0
Application.DisplayAlerts = True

'Add a worksheet with the name "Summary-Sheet"
Set Basebook = ThisWorkbook
Set Newsh = Basebook.Worksheets.Add
Newsh.Name = "Summary-Sheet"

'The links to the first sheet will start in row 2
RwNum = 1

For Each Sh In Basebook.Worksheets
If Sh.Name <> Newsh.Name And Sh.Visible Then
ColNum = 1
RwNum = RwNum + 1
'Copy the sheet name in the A column
ActiveSheet.Hyperlinks.Add Anchor:=Newsh.Cells(RwNum, 1), Address:="", SubAddress:= _
Sh.Name & "!A1", TextToDisplay:=Sh.Name & "!A1"

For Each myCell In Sh.Range("A1,D5:E5,Z10") '<--Change the range
ColNum = ColNum + 1
Newsh.Cells(RwNum, ColNum).Formula = _
"='" & Sh.Name & "'!" & myCell.Address(False, False)
Next myCell

End If
Next Sh

Newsh.UsedRange.Columns.AutoFit

With Application
.Calculation = xlCalculationAutomatic
.ScreenUpdating = True
End With
End Sub
 
R

Ron de Bruin

After a private mail with a verry smart Excel Guru I decide
to add code this week to the webpage that use the Hyperlink worksheet function.

Check it out this week if you want

Good night

--

Regards Ron de Bruin
http://www.rondebruin.nl/tips.htm
 
D

Dave Peterson

Maybe with a credit to David McRitchie, too???

He was the first person I saw that used the =hyperlink() worksheet function with
that kind of subaddress.
 
N

Nelson

Thanks, I am missing something here and not seeing it, any suggestions

Dim Newsh As Worksheet
Dim myCell As Range
Dim ColNum As Integer
Dim RwNum As Long
Dim Basebook As Workbook

With Application
..Calculation = xlCalculationManual
..ScreenUpdating = False
End With

'Delete the sheet "Summary-Sheet" if it exist
Application.DisplayAlerts = False
On Error Resume Next
ThisWorkbook.Worksheets("Summary-Sheet").Delete
On Error GoTo 0
Application.DisplayAlerts = True

'Add a worksheet with the name "Summary-Sheet"
Set Basebook = ThisWorkbook
Set Newsh = Basebook.Worksheets.Add
Newsh.Name = "Summary-Sheet"

'The links to the first sheet will start in row 2
RwNum = 1

With Newsh.Cells
..HorizontalAlignment = xlCenter
..VerticalAlignment = xlCenter
End With
With Newsh.Range("A1:K1")
..Value = Array("Customer Number", "Renewal Quarter", _
"Customer Name", "ABC 2007", "ABC 2007", "ABC 2008", "ABC 2008", "ABC 2009",
"ABC 2009", "ABC 2010", "ABC 2010")
..Interior.ColorIndex = 15
..Font.Bold = True
..AutoFilter
End With

'Add headers

Newsh.Range("A1:K1").Value = Array("Customer Number", "Renewal Quarter",
"Customer Name", "PIM 2007", "CDI 2007", "PIM 2008", "CDI 2008", "PIM 2009",
"CDI 2009", "PIM 2010", "CDI 2010")

For Each Sh In Basebook.Worksheets
If Sh.Name <> Newsh.Name And Sh.Visible And Sh.Index > 3 Then
ColNum = 1
RwNum = RwNum + 1

'Copy the sheet name in the A column
ActiveSheet.Hyperlinks.Add Anchor:=Newsh.Cells(RwNum, 1), Address:="",
SubAddress:= _
Sh.Name & "!A1", TextToDisplay:=Sh.Name & "!A1"

For Each myCell In Sh.Range("A1,D5:E5,Z10") '<--Change the range
ColNum = ColNum + 1
Newsh.Cells(RwNum, ColNum).Formula = _
"='" & Sh.Name & "'!" & myCell.Address(False, False)
Next myCell

End If
Next Sh

Newsh.UsedRange.Columns.AutoFit

With Application
..Calculation = xlCalculationAutomatic
..ScreenUpdating = True
End With
End Sub
 
N

Nelson

EXCELLENT THANKS! Got it working...
--
Nelson


Nelson said:
Thanks, I am missing something here and not seeing it, any suggestions

Dim Newsh As Worksheet
Dim myCell As Range
Dim ColNum As Integer
Dim RwNum As Long
Dim Basebook As Workbook

With Application
.Calculation = xlCalculationManual
.ScreenUpdating = False
End With

'Delete the sheet "Summary-Sheet" if it exist
Application.DisplayAlerts = False
On Error Resume Next
ThisWorkbook.Worksheets("Summary-Sheet").Delete
On Error GoTo 0
Application.DisplayAlerts = True

'Add a worksheet with the name "Summary-Sheet"
Set Basebook = ThisWorkbook
Set Newsh = Basebook.Worksheets.Add
Newsh.Name = "Summary-Sheet"

'The links to the first sheet will start in row 2
RwNum = 1

With Newsh.Cells
.HorizontalAlignment = xlCenter
.VerticalAlignment = xlCenter
End With
With Newsh.Range("A1:K1")
.Value = Array("Customer Number", "Renewal Quarter", _
"Customer Name", "ABC 2007", "ABC 2007", "ABC 2008", "ABC 2008", "ABC 2009",
"ABC 2009", "ABC 2010", "ABC 2010")
.Interior.ColorIndex = 15
.Font.Bold = True
.AutoFilter
End With

'Add headers

Newsh.Range("A1:K1").Value = Array("Customer Number", "Renewal Quarter",
"Customer Name", "PIM 2007", "CDI 2007", "PIM 2008", "CDI 2008", "PIM 2009",
"CDI 2009", "PIM 2010", "CDI 2010")

For Each Sh In Basebook.Worksheets
If Sh.Name <> Newsh.Name And Sh.Visible And Sh.Index > 3 Then
ColNum = 1
RwNum = RwNum + 1

'Copy the sheet name in the A column
ActiveSheet.Hyperlinks.Add Anchor:=Newsh.Cells(RwNum, 1), Address:="",
SubAddress:= _
Sh.Name & "!A1", TextToDisplay:=Sh.Name & "!A1"

For Each myCell In Sh.Range("A1,D5:E5,Z10") '<--Change the range
ColNum = ColNum + 1
Newsh.Cells(RwNum, ColNum).Formula = _
"='" & Sh.Name & "'!" & myCell.Address(False, False)
Next myCell

End If
Next Sh

Newsh.UsedRange.Columns.AutoFit

With Application
.Calculation = xlCalculationAutomatic
.ScreenUpdating = True
End With
End Sub
 
R

Ron de Bruin

I do that Dave


Dave Peterson said:
Maybe with a credit to David McRitchie, too???

He was the first person I saw that used the =hyperlink() worksheet
function with
that kind of subaddress.




--

Dave Peterson

__________ Information from ESET Smart Security, version of virus
signature database 4148 (20090611) __________

The message was checked by ESET Smart Security.

http://www.eset.com


__________ Information from ESET Smart Security, version of virus signature database 4148 (20090611) __________

The message was checked by ESET Smart Security.

http://www.eset.com
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top