Everyone! We've moved to WordPress.

How to Create a Rollover Effect in Excel: Execute a Macro When Your Mouse is over a Cell

372
"Rollover B8 OV1" (like Rollover Beethoven...? get it?)

Update 17 July 2011: This blog entry was featured in Chandoo's latest post. So if you're coming here from his site -- welcome!

original post:
This post was inspired by Chandoo's post on hyperlinks in Excel. If you haven't checked his website out yet - you should. It's excellent.

In this post, I suggest a method for creating a "Rollover" effect for your mouse on an Excel spreadsheet. Rollover techniques (also called "Mouseovers") are useful to (1) display quick information to the user; (2) to execute a function when a user puts their mouse over a specific region; and (3) to make neat graphical effects.

For item 1, my technique isn't really necessary. If you want to display brief information to the user when he or she rolls over a cell, the best way to do this is to insert a comment.

But comments are pretty limited. You can only write so much information in a comment before it becomes too cluttered to be useful. Moreover, comments are static. What if you want the information concerning the "target" cell (that is, the cell to be rolled over) to change based on different items in your spreadsheet? We can use the in-cell Hyperlink() formula to accomplish this.

The Hyperlink() formula looks like this:

=Hyperlink(location, [Friendly Text])
location - Here you write the intended address of your hyperlink. This can be a webpage (i.e. "http://www.google.com") or a file on your computer.
[Friendly Text] - This is an optional field that provides a caption to your hyperlink. If you leave it blank, it will simply display the address in the previous parameter.

To begin our example, you'll need to create a User Defined Function (UDF) to be executed when the rollover event is initiated. So go into the Visual Basic Environment, create or find a free module and create a UDF that looks something like this.

Public Function MyMouseOverEvent()
Sheet1.Range("A1").Value = "Event Fired!"
End Function
I can understand if you're puzzled at this point. UDFs are not really allowed to change values in other cells. However, since we'll be calling this function from within the Hyperlink() formula, you'll see this limitation no longer exists.

So now go to Sheet1 and click on cell A2. In that cell, type in the following formula:

=HYPERLINK(MyMouseOverEvent(),"Click here")
Upon hitting Enter, you should get a #VALUE! error, but ignore it for a second. Roll your mouse over cell A2 - and viola! - Cell A1 should now say "Event Fired!"

But what about that pesky #VALUE! error? Remember the limitation that UDFs can't change other cells? Well, even though Excel let's you change a value from within your UDF, it still recognizes that it wasn't supposed to! To get rid of that error is pretty simple. Just rewrite the function in your cell as follows:

=IFERROR(HYPERLINK(MyMouseOverEvent(),"Click here"), "Click here")

And that's it. If you like this technique and find some cool uses for it, drop me an email and show me.

Here's some graphical fun I created using this technique. Putting the mouse inside the black rectangle creates a fading snake-like pattern based on your mouse movements. Check out the screen capture:


Make sure to check out my latest (and greatest) example of this technique, here: