• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Excel for Operations Management Course
    • Excel for Decision Making Under Uncertainty Course
    • Excel for Finance Course
    • Excel Analysis ToolPak Course
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Highlight Cells Referenced in Excel Formulas

You are here: Home / Excel Formulas / Highlight Cells Referenced in Excel Formulas
Highlight Referenced Cells
September 19, 2017 by Mynda Treacy

In an ideal spreadsheet our formulas would always reference adjacent cells and columns and it would be obvious which cells contributed to a result, like this:

reference adjacent cells and columns

However, in financial modelling and reporting it’s often less obvious, like the example below:

financial model example

Let’s look at some ways we can easily identify which cells contribute to a result.

Download the Workbook

Enter your email address below to download the sample workbook.

By submitting your email address you agree that we can email you our Excel newsletter.
Please enter a valid email address.

Download the Excel Workbook. Note: This is a .xlsx file please ensure your browser doesn't change the file extension on download.

Trace Precedents and Dependents

We can use tools like Trace Precedents and Dependents (on the Formulas tab of the ribbon) to get a visual indication of what cells are involved in a formula. For example, in the image below we can see Trace Precedents arrow for cell F4:

Highlight Cells Referenced in Excel Formulas with trace precedents

And here is the Trace Dependents arrow for the same cell:

trace dependents

These arrows can be turned off by clicking the ‘Remove Arrows’ button on the Formulas tab.

Trace precedents and dependents arrows are useful for reasonably simple formulas, but they can quickly turn into pick-up sticks in more complex scenarios:

trace precedents and dependents

Another easy way to highlight cells referenced in a formula is to press F2 to edit the cell containing the formula in question. With this technique you get a nice color coded visual of the cells involved:

Highlight Cells Referenced in Excel Formulas with color coded cells

But that’s only good for one cell at a time.

Highlight Cells Referenced in Formulas with Conditional Formatting

Another tool we can use in Excel 2013 and 2016 is Conditional Formatting, it also comes with limitations, but first let’s look at the application.

In the image below, you can see the cells in column C that relate to the totals in cells C12 and C13 by way of color coding:

conditional formatting color codes

It gives a quick visual check that you can toggle off by unchecking the ‘Show Formatting’ button:

highlight referenced cells

Note: This is quite advanced but if you take your time and refer to the workbook I’m confident you can grasp it.

For this technique we use a Conditional Formatting formula to check if any cells in C5:C10 are referenced in the formula in cell C12.

technique using conditional formatting formula

If they are, the cell fill color is set to green. We repeat for the formula in cell C13 and format in pink.

These conditional formatting formulas use the following functions (it looks like a long list, but don’t be put off):

  • SEARCH(find_text, within_text, [start_num]) – returns the numeric starting position of text within text.
  • ADDRESS(row_num, column_num, [abs_num], [a1], [sheet_text]) – creates a cell reference as text
  • ROW([reference]) – returns the row number of a cell reference
  • COLUMN([reference]) – returns the column of a cell reference
  • FORMULATEXT(reference) – returns the formula as a string/text
  • SUBSTITUTE(text, old_text, new_text, [instance_num]) – replaces existing text with new text

Tip: Function arguments in square brackets are optional. E.g. [start_num] in the SEARCH function is an optional argument, meaning you can simply omit it.

Here is the conditional formatting formula we’ll use to check if any of the cells in the range C5:C10 are referenced in the formula in cell C12 (which is =C5+C6):

=SEARCH(ADDRESS(ROW(C5),COLUMN(C5),4,1),FORMULATEXT($C$12))

In English it reads, search the formula contained in cell C12 for the address of the cell at the intersection of ROW 5 and COLUMN C and make it a relative cell reference*. i.e. search for cell reference “C5“ in the formula in cell C12.

*we want relative references because that’s the format of the cell references in the formula in cell C12. More on that soon.

You can see the result below after the ADDRESS, ROW, COLUMN and FORMULATEXT functions are evaluated against cell C5:

=SEARCH("C5","=C5+C6")

And from here we can see that the text, C5, starts at the 2nd character in the string, =C5+C6, so SEARCH returns 2.

Note: Conditional formatting will be applied when a formula evaluates to any number other than zero, so in this case the formatting is applied.

Handling Absolute References

But what if the formula in C12 contains absolute references, or what if someone thinks they’ll be “helpful” and they later add them?

Well, then we should make this formula more robust so it can handle this scenario. We’ll use the SUBSTITUTE function to replace any dollar signs found in the formula text with nothing, effectively converting any absolute references back to relative references.

=SEARCH(ADDRESS(ROW(C5),COLUMN(C5),4,1),SUBSTITUTE(FORMULATEXT($C$12),"$",""))

Now if anyone changes the formula in cell C12 to contain absolute references they’ll be ignored when the conditional format formula is evaluated.

Alternatives to ADDRESS

A word on the ADDRESS function; we use the ADDRESS function to return the cell reference for each cell we want to check in the range C5:C10. With this formula structure we can apply the conditional format across a range of columns and ADDRESS will dynamically return the correct cell without any modifications.

However, if you just want to check one column, for example column C, then you can simply build your cell reference by concatenating ‘C’ to the ROW function like this:

=SEARCH("C"&ROW(C5),SUBSTITUTE(FORMULATEXT($C$13),"$",""))*$E$3

Alternatively, you could use the CELL function instead of ADDRESS, like so:

=SEARCH(CELL("address",C5),FORMULATEXT($C$13))*$E$3

It’s a bit more succinct, but the CELL function returns an absolute reference so you’d be wise to strip out the $ signs with SUBSTITUTE here too to avoid inconsistencies in the references:

=SEARCH(SUBSTITUTE(CELL("address",C5),"$",""), SUBSTITUTE(FORMULATEXT($C$13) ,"$",""))*$E$3

And now it’s not really any better than the original formula.

Set up the Toggle Excel Party Trick

set up the toggle

To implement the formatting on/off toggle we simply multiply the formula by the TRUE/FALSE returned by the ‘Show Formatting’ check box form control in cell E3 shown in the image above:

=SEARCH(ADDRESS(ROW(C5),COLUMN(C5),4,1),SUBSTITUTE(FORMULATEXT($C$12),"$",""))*$E$3

Tip: When you perform a math function on TRUE or FALSE they are converted to their numeric equivalents of 1 and 0. So by multiplying the formula by FALSE we’re effectively multiplying by 0, and anything multiplied by 0 = 0, so the Conditional Formatting is not applied.

Learn how to toggle Conditional Formatting on/off.

Conditional Formatting Limitations

  1. The Conditional Formatting technique only works with formulas that individually reference cells, i.e. won’t work with a range e.g. =SUM(A1:A5) but will work with =SUM(A1,A2,A3,A4,A5)
  2. It only works with Excel 2013 or later as it requires the FORMULATEXT function which was new in Excel 2013.

Related Lessons

  • Setting up Conditional Formatting using formulas
  • Absolute and Relative References
  • Toggle Conditional Formatting On/Off
  • SEARCH Function
  • CELL Function
  • Form Controls
Highlight Referenced Cells

More Excel Formulas Posts

excel formula by example

Excel Formula by Example

Excel can now write a formula by example. Simply give it an example or two of the result and Excel will write the formula.
ai-aided excel formula editor

AI Aided Excel Formula Editor

Save time with this free AI Excel formula editor add-in that writes, edits, improves and interprets formulas for you!
top excel functions for data analysts

Top Excel Functions for Data Analysts

Must know Excel Functions for Data Analysts and what functions you don’t have to waste time learning and why.
excel advanced formula environment

Excel Advanced Formula Environment

Excel Advanced Formula Environment is a long awaited, new improved way to write, name and store Excel formulas.
Pro Excel Formula Writing Tips

Pro Excel Formula Writing Tips

Must know Excel formula writing tips, tricks and tools to make you an Excel formula ninja, including a new formula editor.
excel shaping arrays

New Array Shaping Excel Functions

The Excel Shaping Array Functions makes it easier than ever to reshape arrays and ranges using these purpose built functions
excel nested if functions what not to do

Excel IF Formulas and What Not To Do

Excel IF formulas can get out of hand when you nest too many IFs. Not only do they become unwieldy they’re difficult for anyone to understand
excel image function

Excel IMAGE Function

The Excel IMAGE Function enables you to embed images in a cell using a formula. It supports BMP, JPG/JPEG, GIF, TIFF, PNG, ICO, and WEBP files

Excel VSTACK and HSTACK Functions

New Excel VSTACK and HSTACK functions makes combining arrays of cells easy and with some clever tricks we can extend their capabilities.
identify overlapping dates and times in excel

Identify overlapping dates and times in Excel

How to identify overlapping dates and times in Excel with a formula that checks a range of cells. Works with Dates and Times.


Category: Excel Formulas
Previous Post:vba shellVBA Shell
Next Post:Dynamically Label Excel Chart Series Lines

Reader Interactions

Comments

  1. Michael

    October 3, 2019 at 6:46 pm

    I’m looking for a way to select only the formulas which contain (at leasat one) cell reference. Using the “go-to” command selects all formulas, including formulas which are self-contained and do not refer to other cells. Is there a way to select only the formulas which contain at least one referenced cell? E.g. =1+1 would not be selected but =A1+1 would be selected.

    Reply
    • Catalin Bombea

      October 4, 2019 at 5:56 am

      Hi Michael,
      Only in vba you will be able to do that, using a pattern that can identify a range reference in the formula text. The Go To tool does not have that behaviour, and I guess it never will.

      Reply
  2. Jozef

    September 20, 2017 at 11:44 pm

    just a small ammendment:
    if the alternative with CELL(info_type, [reference]) function is used, you may run into issues with different excel language versions, as the values of info_type parameter are language specific and not translated automatically, so the function then returns #VALUE error.
    cheers

    Reply
    • Mynda Treacy

      September 21, 2017 at 8:52 am

      Thanks for sharing that, Jozef.

      Reply
  3. Barry

    September 20, 2017 at 11:16 pm

    I also like to use CTRL + [ to find direct precedents, CTRL + ] for dependents
    And CTRL + { or CTRL + } – like the square brackets/braces, but finds more levels

    Reply
    • Mynda Treacy

      September 21, 2017 at 8:52 am

      Thanks for the shortcut keys, Barry.

      Reply
  4. Thomas H.

    September 20, 2017 at 10:17 pm

    Nice! Tried to build it up. But you have to turn off in the Excel options the R1C1 reference style, if applied. I always use the R1C1 style reference in my Excel applications.

    Reply
    • Mynda Treacy

      September 21, 2017 at 8:54 am

      Good point, Thomas. Not many use R1C1, but it’s good to know.

      Reply

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Current ye@r *

Leave this field empty

Sidebar

More results...

launch excel macros course excel vba course

Featured Content

  • 10 Common Excel Mistakes to Avoid
  • Top Excel Functions for Data Analysts
  • Secrets to Building Excel Dashboards in Less Than 15 Minutes
  • Pro Excel Formula Writing Tips
  • Hidden Excel Double-Click Shortcuts
  • Top 10 Intermediate Excel Functions
  • 5 Pro Excel Dashboard Design Tips
  • 5 Excel SUM Function Tricks
  • 239 Excel Keyboard Shortcuts

100 Excel Tips and Tricks eBook

Download Free Tips & Tricks

Subscribe to Our Newsletter

Receive weekly tutorials on Excel, Power Query, Power Pivot, Power BI and More.

We respect your email privacy

239 Excel Keyboard Shortcuts

Download Free PDF

mynda treacy microsoft mvpHi, I'm Mynda Treacy and I run MOTH with my husband, Phil. Through our blog, webinars, YouTube channel and courses we hope we can help you learn Excel, Power Pivot and DAX, Power Query, Power BI, and Excel Dashboards.

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
microsoft mvp logo
trustpilot excellent rating
Secured by Sucuri Badge
MyOnlineTrainingHub on YouTube Mynda Treacy on Linked In Mynda Treacy on Instagram Mynda Treacy on Twitter Mynda Treacy on Pinterest MyOnlineTrainingHub on Facebook
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk – For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved. Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.

Download A Free Copy of 100 Excel Tips & Tricks

excel tips and tricks ebook

We respect your privacy. We won’t spam you.

x