'API function to find out the position of the cursor.
Declare Function GetCursorPos Lib "user32" (lppoint As CursorCoords) As Long
Type CursorCoords
X As Long
Y As Long
End Type
Dim pos As CursorCoords
'API function to find out height of the Windows caption bar.
Declare Function GetSystemMetrics Lib "user32" _
(ByVal nIndex As Long) As Long
Public Const SM_CYCAPTION = 4
Dim PreviousX As Long
Dim PreviousY As Long
Dim CurrentX As Long
Dim CurrentY As Long
Dim GetIt As Variant
Dim Yoffset As Single
Dim Xoffset As Single
Dim NextTime As Date
Dim TLTop As Single
Dim TLLeft As Single
Dim CurrentChart As Chart
Dim chrt As Object
Dim bar As Object
Dim Fix2D As Long
Dim I As Integer
Dim Counter As Integer
Dim X As Long
Dim Y As Long
Dim ElementID As Long
Dim SeriesIndex As Long
Dim PointIndex As Long
Dim F As String
Dim StartOfRange As Integer
Dim EndOfRange As Integer
Dim EndOfWorkbook As Integer
Dim SeriesRange As String
Dim SeriesWorkbook As String
Dim SeriesWorksheet As String
Sub XTipsOn()
NextTime = Now + TimeValue("00:00:01")
With Application
.Cursor = xlNorthwestArrow
.StatusBar = "Ready"
.ShowChartTipNames = False
.ShowChartTipValues = False
.OnTime NextTime, "XTipsOn" 'Starts a recursive loop.
End With
Call GetXoffset
Call GetYoffset
'Get the current position of the cursor.
PreviousX = pos.X - Xoffset - (Application.Left * 1.333) - 3
PreviousY = pos.Y - Yoffset - (Application.Top * 1.333) - 4
GetIt = GetCursorPos(pos)
CurrentX = pos.X - Xoffset - (Application.Left * 1.333) - 3
CurrentY = pos.Y - Yoffset - (Application.Top * 1.333) - 4
On Error Resume Next 'happens when no textbox is on the worksheet.
If CurrentX <> PreviousX Or CurrentY <> PreviousY _
Then 'The mouse is moving.
ActiveSheet.TextBoxes(1).Visible = msoFalse
Else: 'The mouse is at rest.
If ActiveSheet.TextBoxes(1).Visible = msoFalse Then DisplayTip
End If
On Error GoTo 0
End Sub
Sub DisplayTip()
'Gets the Top & Left values of the cell at the top,left of the screen.
TLTop = Cells(ActiveWindow.ScrollRow, ActiveWindow.ScrollColumn).Top
TLLeft = Cells(ActiveWindow.ScrollRow, ActiveWindow.ScrollColumn).Left
'Works out which chart is underneath the cursor.
For Each chrt In ActiveSheet.ChartObjects
If (chrt.Left - TLLeft) * 1.333 < CurrentX And _
(chrt.Left + chrt.Width - TLLeft) * 1.333 > CurrentX And _
(chrt.Top - TLTop) * 1.333 < CurrentY And _
(chrt.Top + chrt.Height - TLTop) * 1.333 > CurrentY _
Then
Set CurrentChart = ActiveSheet.ChartObjects(chrt.Index).Chart
Exit For
End If
If chrt.Index = ActiveSheet.ChartObjects.Count _
Then ' There is no chart underneath the cursor.
Exit Sub
End If
Next
'Makes an adjustment if the chart does not have a 3D effect.
On Error GoTo ChartIsNot3D
Fix2D = CurrentChart.Floor.Interior.ColorIndex
On Error GoTo 0
'X & Y will be passed to the GetChartElement method.
X = CurrentX - (CurrentChart.Parent.Left - TLLeft) * 1.333
Y = CurrentY - (CurrentChart.Parent.Top - TLTop) * 1.333
CurrentChart.GetChartElement X, Y, ElementID, SeriesIndex, PointIndex
If ElementID <> 3 Then Exit Sub
'Finds the range that contains the Series' Source Data.
F = CurrentChart.SeriesCollection(SeriesIndex).Formula
If Mid(F, 1, 10) <> "," _
Then 'The chart has a range specified for X-axis labels.
F = Left(F, 9) & Mid(F, InStr(10, F, ","))
End If
StartOfRange = InStr(1, F, "!")
EndOfRange = InStr(StartOfRange + 1, F, ",")
SeriesRange = Mid(F, StartOfRange + 1, _
EndOfRange - StartOfRange - 1)
'Finds the Workbook & Worksheet containing the Series' Source Data.
EndOfWorkbook = InStr(F, "]")
If EndOfWorkbook > 0 _
Then 'The Source Data is in a separate Workbook.
SeriesWorkbook = Mid(F, 13, EndOfWorkbook - 13)
SeriesWorksheet = Mid(F, EndOfWorkbook + 1, _
(StartOfRange - EndOfWorkbook - 2))
Else: 'The Source Data is in the Active Workbook.
SeriesWorkbook = ActiveWorkbook.Name
SeriesWorksheet = Mid(F, 11, InStr(1, F, "!") - 11)
End If
'Re-position, re-write & display the text box.
With ActiveSheet.TextBoxes(1)
.Left = (CurrentX / 1.333) + TLLeft + 5
.Top = (CurrentY / 1.333) + TLTop + 12
On Error GoTo WorkbookNotOpen
.Characters(1).Insert String:= _
Workbooks(SeriesWorkbook). _
Worksheets(SeriesWorksheet). _
Range(SeriesRange) _
.Offset(PointIndex - 1, 2).Resize(1, 1).Value
On Error GoTo 0
.AutoSize = True
.ShapeRange.ZOrder msoBringToFront
.Visible = msoTrue
End With
Exit Sub
WorkbookNotOpen: ActiveSheet.TextBoxes(1).Characters(1).Insert String:= _
"The workbook containing" & Chr(10) & _
"the source data for this" & Chr(10) & _
"chart needs to be open. "
Resume Next
Exit Sub
ChartIsNot3D: CurrentX = CurrentX - 1
CurrentY = CurrentY - 1
Resume Next
End Sub
Sub GetYoffset()
'Adds up the heights of all toolbars docked at the top of the screen.
'If multiple Toolbars share the same RowIndex, only one is counted.
Yoffset = 0
ReDim TheArray(0)
For Each bar In Application.CommandBars
If bar.Visible = True And bar.Position = msoBarTop Then
For I = 1 To UBound(TheArray)
If TheArray(I) = bar.RowIndex Then _
Yoffset = Yoffset - bar.Height _
: Exit For
Next I
Yoffset = Yoffset + bar.Height
Counter = Counter + 1
ReDim Preserve TheArray(Counter)
TheArray(Counter) = bar.RowIndex
End If
Next
'Accounts for the height of the Windows caption bar.
Yoffset = Yoffset + GetSystemMetrics(SM_CYCAPTION)
'Accounts for the height of the Formula Bar.
If Application.DisplayFormulaBar = True Then
Yoffset = Yoffset + 17
End If
'Accounts for the height of Column Headers.
On Error Resume Next
If ActiveWindow.DisplayHeadings = True Then
Yoffset = Yoffset + 17
End If
On Error GoTo 0
End Sub
Sub GetXoffset()
'Adds up the widths of all toolbars docked at the left of the screen.
'If multiple Toolbars share the same RowIndex, only one is counted.
Xoffset = 0
ReDim TheArray(0)
For Each bar In Application.CommandBars
If bar.Visible = True And bar.Position = msoBarLeft Then
For I = 1 To UBound(TheArray)
If TheArray(I) = bar.RowIndex Then _
Xoffset = Xoffset - bar.Width _
: Exit For
Next I
Xoffset = Xoffset + bar.Width
Counter = Counter + 1
ReDim Preserve TheArray(Counter)
TheArray(Counter) = bar.RowIndex
End If
Next
'Makes an adjustment if any toolbars are docked at the left.
If Xoffset > 0 Then Xoffset = Xoffset - 1
'Accounts for the width of Row Headers.
On Error Resume Next
If ActiveWindow.DisplayHeadings = True Then
Xoffset = Xoffset + 26
'If your charts are near row 1000 or row 10000 ,
'you may need to adjust the values 963 & 9963 .
If ActiveWindow.ScrollRow > 963 Then Xoffset = Xoffset + 7
If ActiveWindow.ScrollRow > 9963 Then Xoffset = Xoffset + 7
End If
On Error GoTo 0
End Sub
Sub XTipsOff()
With Application
.OnTime NextTime, "XTipsOn", schedule:=False
.Cursor = xlDefault
.StatusBar = False
.ShowChartTipNames = True
.ShowChartTipValues = True
End With
ActiveSheet.TextBoxes(1).Visible = msoTrue
End Sub