fbpx
Search
Close this search box.

Show difference between cells in status bar – VBA Example

Share

Facebook
Twitter
LinkedIn

We can select a few cells in Excel and quickly see their count, sum etc. in the status bar. Ever wanted to customize the status bar to show something else, say difference? You can use VBA add-ins with application level events to achieve this. In this Example, learn how to customize status bar with Excel VBA. We will see how to set up a class module, application event in our personal macro add-in.

Show difference of selected cells in Excel Status Bar using VBA

Note: This is a reasonably advanced VBA example. If you are a VBA newbie, start with FREE Excel VBA Crash Course, and come back when you are ready.

If you just want to show difference in a specific worksheet…

Then you could use Worksheet_SelectionChange() Event in that sheet to set Application.StatusBar to what you need.

But our problem is a bit more complicated. We want to customize status bar to show difference in any Excel file.

Using Excel Add-in to customize status bar

Anytime you want to use a macro or automate things in multiple files, you need to create Excel add-ins. While this sounds complicated. making an add-in is rather simple. You just create the necessary VBA code and save the file as “Excel Add-in” type. Once such a file is saved, you can then install this add-in using Developer ribbon > Excel Add-in button. Now, you can use the add-in functionality from any open file.

For the purpose of our status bar customization, we will use Personal Macro workbook.

If you do not yet have a personal macro workbook, go make one. Refer to above link for instructions.

Step by step instructions to add status bar changing code

Step 1: Open Excel, go to Visual Basic Editor (ALT+F11) and locate your personal macro add-in file.

Step 2: Insert a class module. In the personal macro file, insert a class module. Name this module as clsApp.

Paste below code in the class.

Public WithEvents app As Application

This adds a variable (property) called app to the class clsApp.

Step 3: Insert a module. In this module, we will write necessary code to make an object instance of the clsApp.

Paste this code.

Option Explicit
'code originally from https://jkp-ads.com/Articles/buildexceladdin05.asp
'Variable to hold instance of class clsApp
Dim mcApp As clsApp

Public Sub Init()
    'Reset mcApp in case it is already loaded
    Set mcApp = Nothing
    'Create a new instance of clsApp
    Set mcApp = New clsApp
    'Pass the Excel object to it so it knows what application
    'it needs to respond to
    Set mcApp.app = Application
End Sub

What this code is doing? As annotated in the comments, this code is simply to initialize the mcApp variable with current Excel application.

Step 4: Go back to class module and add app level event. Now, let’s go back to the class module and click on on the drop-down above and select “app” and select the event SheetSelectionChange.

This adds a blank event at app level for SheetSelectionChange.

Paste below code.

Private Sub app_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)
    Application.StatusBar = ""
    On Error GoTo Finish
    If Selection.Cells.Count = 2 Then
        Application.StatusBar = "Diff: " & (Selection.Cells(1) - Selection.Cells(2))
    Else
        Application.StatusBar = ""
    End If
Finish:
End Sub

What’s going on here: This code simply checks with Selection has two cells. If so, it sets the statusbar to the word “Diff:” followed by actual difference.

In all other cases (including any errors), the status bar is set to empty (which resets it).

Step 5: Go to ThisWorkbook on the add-in file add code to init

Finally, we want to load mcApp (our instance for the Excel Application) whenever Excel is loaded. To do this, go to ThisWorkbook on the personal add-in file, double click on it and add the Workbook Open event.

Paste below code in there.

'code originally from https://jkp-ads.com/Articles/buildexceladdin05.asp
Private Sub Workbook_Open()
    Application.OnTime Now, "'" & ThisWorkbook.FullName & "'!Init"
End Sub

That is all. We have now created an application level event listener that monitors any selection changes across all open workbooks. If user selects two cells, then it will display the difference between them in the status bar.

Here is an illustration of the chain of actions that happen

Show cell difference in status bar – Video Tutorial

I made a video explaining the entire code and demoed the result. Watch it below if you are still hazy about the process. You can also watch this on my YouTube channel.

References & Resources to learn more…

Big thanks to Jan Karel Pieterse & late Chip Pearson for excellent info on class module driven application event listeners.

Setting up Personal Macro add-in Workbook

More info on Worksheet_SelectionChange event

Learn Excel VBA

This article is inspired from a question posted in my Facebook group by Istiyak.

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Overall I learned a lot and I thought you did a great job of explaining how to do things. This will definitely elevate my reporting in the future.
Rebekah S
Reporting Analyst
Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

3 Responses to “Show difference between cells in status bar – VBA Example”

  1. Fred says:

    Step 4 code only works if the values are next to each other. Here is a better method where it will evaluate the cells in the order you ctrl+click them and the values don't have to be side-by-side.

    Private Sub app_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)

    Application.StatusBar = ""
    On Error GoTo Finish
    If Target.Cells.Count = 2 Then

    Dim i As Long: i = 1
    Dim result1 As Variant
    Dim result2 As Variant
    Dim selectedCell As Range

    For Each selectedCell In Target.Cells
    If i = 1 Then
    result1 = cUtility.ToDouble(selectedCell.Value)
    Else
    result2 = cUtility.ToDouble(selectedCell.Value)
    End If

    i = i + 1
    Next selectedCell

    Application.StatusBar = "Difference: " & (result1 - result2)

    Set selectedCell = Nothing

    Else
    Application.StatusBar = ""
    End If
    Finish:

    End Sub

  2. Reid says:

    This is a great tutorial! Thank you Chandoo for your expertise. I do have two questions regarding this code:

    1. Is there a code that formats the text displayed in the status bar to match the same formatting of the cells being referenced? (commas, dollar signs, etc.)

    2. Is there a way to move the Application.StatusBar = "Diff" all the way to the right where the other applications are located?

    Thanks again!

  3. Roger says:

    Thanks for this great example.
    I am not seeing the Diff: string - it is getting overwritten by "Ready".
    The code is working OK - I can show the Diff string if pause the macro.

    Is there some setting I've missed?

Leave a Reply