VBA code: check what is currently selected in Excel

Often we want to determine what type of object has been selected in Excel. It helps with error checking prior to running a piece of code.

Basic code

This action is just a just a single line of code:

Sub testSelection()

MsgBox TypeName(Selection)

End Sub

Incorporate the check into a Select statement

If you want to treat selection types differently a case statement similar to the one below may be useful.

Sub testSelection()

Select Case TypeName(Selection)

    Case "ChartArea", "ChartTitle"
        'Do something to the Chart
 
    Case "Range"
        'Do something to the range
 
    Case Else
        'Oh dear, not an acceptable selection.
        'Do something else.

End Select

End Sub

Allowing any part of an object to be selected

Some objects, such as Charts can be difficult to select. Depending where the users clicks, the Selection might be on the Series, Legend or ErrorBars. All of these are parts of the ChartObject. To work with the chart no matter where the user clicked, move up the Document Object Model until the TypeName is “ChartObject”. Look at the code below for an example.

'Create a variable called tempSelection to hold the selection
Dim tempSelection As Object
Set tempSelection = Selection

'Loop keep finding the parent of the tempSelection until it reaches
'the top of the Document Object Model.
Do While TypeName(tempSelection) <> "Application"

    'If the tempSelection equals ChartObject exit the loop
    'else find the parent of the tempSelection and loop again
    If TypeName(tempSelection) = "ChartObject" Then
        Exit Do
    Else
        Set tempSelection = tempSelection.Parent
    End If

Loop

'If any part of an embedded chart was selected the MsgBox will show "ChartObject"
'if not it will show "Application"
MsgBox TypeName(tempSelection)

Charts can also be sheets, rather than embedded.  Their behaviours are slightly different, so differentiating between a chart sheet and embedded chart is important.

A chart sheet has the following Document Object Model structure.

Application -> Workbook -> Chart -> ChartArea ...

An embedded chart has the following Document Object Model structure.

Application -> Workbook -> Worksheet -> ChartObject -> Chart -> ChartArea ...

There is an easy way to tell the difference between the two types of Charts.

  • Only embedded charts have a ChartObject
  • If the parent of the Chart is a Workbook it is a chart sheet,

The code below will show a message of Chart if the selection is a chart sheet.

Dim tempSelection As Object 
Set tempSelection = Selection

Do While TypeName(tempSelection) <> "Application"
    If TypeName(tempSelection) = "Chart" And _
        TypeName(tempSelection.Parent) = "Workbook" Then
        Exit Do
    Else
        Set tempSelection = tempSelection.Parent
    End If

Loop

MsgBox TypeName(tempSelection)

A list of all possible selections

Based on information within the Object Browser, I believe the complete list of possible selections would be:

  • Axis
  • Axis Title
  • Chart
  • ChartArea
  • ChartObject
  • ChartObjects
  • Charts
  • ChartTitle
  • DataLabel
  • DataLabels
  • DataTable
  • DisplayUnitLabel
  • DownBars
  • DropLines
  • ErrorBars
  • Floor
  • Gridlines
  • HiLoLines
  • LeaderLines
  • Legend
  • LegendEntry
  • ListColumn
  • ListObject
  • ListRow
  • OLEObject
  • OLEObjects
  • PlotArea
  • Point
  • Range
  • Series
  • SeriesLines
  • Shape
  • ShapeRange
  • Sheets
  • TextRange2
  • TickLabels
  • Trendline
  • UpBars
  • Walls
  • Worksheet
  • Worksheets
  • Shapes
  • PivotTable

It is not necessary to treat each selection differently, similar objects can be treated in the same way.  See the Select Case example in the code above.


Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

Leave a Comment