• 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

Interactive Excel Check Boxes

You are here: Home / Excel / Interactive Excel Check Boxes
excel check boxes
March 30, 2023 by Mynda Treacy

Excel check boxes are a type of form control that can be added to a spreadsheet with just a few clicks to create an interactive list of items that can be checked off.

You can also link them to formulas to dynamically turn off and on items you want displayed in a chart or conditional formatting and more.

In this tutorial we’ll look at a few ways we can use check boxes to make your spreadsheets more visually appealing and user friendly.


Table of Contents

  • Excel Check Boxes Video Tutorial
  • Download Example Workbook
  • Where to Find Excel Check Boxes
  • Check Box Task List
  • Check Boxes Toggle Conditional Formatting On and Off
  • Check Boxes Display/Hide Chart Series


Watch the Excel Check Boxes Video

Subscribe YouTube

Download the Excel File

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 containing the examples shown in this post.

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



Where to Find Excel Check Boxes

Excel check boxes are available from the Developer tab of the ribbon:

find check boxes on Excel Developer tab

If you don’t see the Developer tab in your Ribbon, right-click the Ribbon > Customize and check the box for the Developer tab in the Main Tabs list:

Customize Excel ribbon to show Developer tab

Excel Check Box Task List

One of the most common uses for Excel check boxes is to create a task list you can use to keep track of progress.

I created one for my son’s morning routine before school because I’m tired of reminding him what he needs to do each morning, so I delegated it to Excel!

Task list check boxes

How to Build a Check Box Task List

Enter the list of tasks and then on the Developer tab > Insert > Check Box:

insert check box from Ribbon

Draw the checkbox onto the cell beside the first task. Right click the text box > Edit Text:

edit text for check box

You could enter the task name here and do away with the need for the tasks in column B or simply delete the text box label, which is what I’ve done.

Next, resize the text box and place it in the centre of the cell. Then copy and paste the text box for the remaining tasks (watch the video above for tips on how to duplicate the text boxes and align them quickly).

Next set up the cell link which returns the status of the check box.

Checked will return TRUE and unchecked will return FALSE.

Right click the text box > Format Control:

format check box control

Select a cell to assign the text box status to in the Cell link field:

select cell to assign status to check box in cell link field

Tip: the cell link can be on any sheet in the file containing the check boxes.

Note: the cell will be blank until you check the box for the first time or select the ‘value’ in the Format Control dialog box shown above.

These TRUE and FALSE Boolean values can be used in formulas. When math operations are applied to a Boolean value, they are converted to their numeric equivalents of one and zero.

This means I can add a Progress Complete status bar using a formula to count the completed tasks divided by the count the total number of tasks:

using double unary to coerce boolean values

The formula above uses the double unary (- -) to coerce the Boolean values into their numeric equivalent.

See the video above for a more in-depth explanation and to see how I generate the custom message of encouragement in row 2:

custom message

Check Boxes Toggle Conditional Formatting On and Off

Conditional formatting check boxes

The check box is linked to cell F2.

The technique works because the Conditional Formatting formulas must return either TRUE or FALSE.

conditional formatting formula

The formats are applied when the formatting rule formula returns TRUE.

We can therefore tie check boxes to conditional formatting rules to turn the formatting on and off by wrapping the Conditional Format formula in the AND function and referencing the check box cell link cell e.g.:

=AND(your conditional format rule, check box cell link cell)

If the check box linked cell contains FALSE, the format is not applied because the AND function only returns TRUE if both arguments are TRUE.

To shade every other row the Conditional Formatting formula is:

=AND(MOD(SUBTOTAL(3,$A$4:$A4),2),$F$2)

In English the formula reads:

  • Count the number of visible rows in column A (that’s the SUBTOTAL(3… part, where 3 is the COUNTA function for SUBTOTAL)
  • Divide the count SUBTOTAL returns by 2, and return the remainder, (that’s the MOD part), which will always evaluate to either 1 or zero
  • AND check to see if cell F2 contains TRUE

I used the SUBTOTAL function because I only want to highlight visible rows and SUBTOTAL enables me to ignore hidden rows in the count. Learn more about the SUBTOTAL Function here.

The MOD function returns the remainder after a number is divided by a divisor. With 2 as the divisor of the count returned by SUBTOTAL, the result is either 1 or 0, which are the numeric equivalents for TRUE and FALSE required by the conditional formatting rule.

Finally, the AND function enables me to also see if the check box is checked. If the cell link contains FALSE, the conditional format is not applied.

Note: column A cannot have any blank cells, otherwise the count returned by SUBTOTAL will be wrong. In which case, choose a column that doesn’t have any blanks.

Check Boxes to Display/Hide Chart Series

Check boxes enable you to add interactive elements to charts, including and removing series at the click of a button.

check boxes to hide or show chart series

The source data from the chart is linked to the check box cell links. With all the check boxes checked, the table looks like this:

source data with check boxes checked

And with them unchecked, it looks like this:

source data with check boxes unchecked

The Average, Target and Trend series are hidden in the chart because #N/A errors do not display in charts.

The IF function syntax is:

=IF(logical test, value if true, value if false)

The IF formulas simply reference the check box cell link in the first argument, with TRUE returning the value if true argument and FALSE returning the NA Function, which results in #N/A.

excel check boxes

More Excel Posts

linear regression

Excel Linear Regression

Excel linear regression is easy with the built-in tools. Use charts to plot linear regression or use the Data Analysis Toolpak.
speed up slow excel files

How to Improve Excel Performance

How to improve Excel performance and the various causes of slow Excel files so you can speed up Excel and avoid problems in future.
Securely Share Excel Files

Securely Share Excel Files

Securely share Excel files stored locally, on OneDrive or SharePoint. Prevent editing or downloading, specify who can open and edit the file.
tips for working in multiple excel files

Hacks for Working in Multiple Excel Files

Awesome tips for navigating, arranging and working in multiple Excel files. Guaranteed to streamline your workflow and increase productivity.
chatgpt for excel

ChatGPT for Excel

Using ChatGPT for Excel can be hit and miss. Learn the best uses for ChatGPT to make your Excel life easier and what to avoid using it for.
excel templates

Where to Find Free Excel Templates

Where to find free Excel templates and how to create your own Excel templates. Using templates saves time and effort.
Easily Remove Password Protection from Excel Files

Easily Remove Excel Password Protection

How to remove Excel password protection when you’ve forgotten the password. Works for sheets, workbooks and read only files.
Import data from a picture to Excel

Import Data from a Picture to Excel

Import data from a picture to Excel. Works with pictures from a file or the clipboard and loads it to the spreadsheet.
excel online

5 Excel Online Features Better than Desktop

5 Excel Online Features Better than Desktop including searchable data validation, track changes, single line ribbon and more.

10 Common Excel Mistakes to Avoid

10 common Excel mistakes to avoid, including merge cells, external links, formatting entire rows/columns and more.


Category: Excel
Previous Post:Power Query if Statements incl. Nested ifs, if or, if and
Next Post:Securely Share Excel FilesSecurely Share Excel Files

Reader Interactions

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...

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