Highlight duplicate values in a cell range
The following conditional formula highlights only the second instance or more of a value in a cell range.
Conditional formatting formula:
How to apply conditional formatting
- Select your range B2:E5.
- Go to "Home" tab
- Press with left mouse button on Conditional formatting
- Press with left mouse button on "New Rule.."
- Press with left mouse button on "Use a formula to determine what cells to format"
- Copy and paste the above conditional formatting formula to "Format values where this formula is true:"
- Press with left mouse button on Format button
- Select a formatting you like. For example, cells filled with yellow.
- Press with left mouse button on OK
- Press with left mouse button on OK
Explaining CF formula in cell B2
There are two parts in this formula, one part determines if a value is a duplicate in the first column. The second part of the formula determines if a value is a duplicate in the remaining columns.
The reason the formula looks like this is because of the order of how Excel calculates cells.
IF(logical_expression, first_part, second_part)
Step 1 - Check if first column is being evaluated
The COLUMNS function counts columns in a cell reference. $A$1:A1 is an expanding cell reference, it grows because A1 is a relative cell reference that changes between cells.
COLUMNS($A$1:A1)=1
becomes
1=1 and returns TRUE.
Step 2 - Count cells based on a condition
The IF function changes the calculation based on the logical expression in the first argument. The second argument is calculated if the logical expression returns TRUE, the third argument is calculated if the logical expression returns FALSE.
The COUNTIF function makes sure that duplicates are not highlighted, only the first instance of each value. However this works only in the first column, the remaining columns need a different formula in order to do correct calculations.
IF(COLUMNS($A$1:A1)=1,COUNTIF($B$2:B2,B2),COUNTIF($B$2:B2,B2)+COUNTIF(OFFSET($B$2:$E$5,,,4,COLUMNS($A$1:A1)-1),B2))>1
becomes
IF(TRUE,COUNTIF($B$2:B2,B2),...)>1
becomes
IF(TRUE,COUNTIF(0,0),...)>1
becomes
1>1
and returns FALSE. Cell B2 is not highlighted.
Step 3 - Calculations in remaining columns
If we move to cell C2 the IF function behaves differently.
IF(COLUMNS($A$1:B1)=1, COUNTIF($B$2:C2, C2), COUNTIF($B$2:C2, C2)+COUNTIF(OFFSET($B$2:$E$5, ,,4, COLUMNS($A$1:B1)-1), B2))>1
becomes
IF(2=1, COUNTIF($B$2:C2, C2),COUNTIF($B$2:C2, C2)+COUNTIF(OFFSET($B$2:$E$5, , , 4, COLUMNS($A$1:B1)-1), C2))>1
becomes
IF(FALSE, COUNTIF($B$2:C2, C2), COUNTIF($B$2:C2, C2)+COUNTIF(OFFSET($B$2:$E$5, , , 4, COLUMNS($A$1:B1)-1), C2))>1
becomes
IF(FALSE, COUNTIF($B$2:C2, C2), COUNTIF({0,6}, 6)+COUNTIF(OFFSET($B$2:$E$5, , , 4, COLUMNS($A$1:B1)-1), C2))>1
The OFFSET function returns an expanding cell reference that grows as the CF moves from column to column.
IF(FALSE, COUNTIF($B$2:C2, C2), 1+COUNTIF(OFFSET($B$2:$E$5, , , 4, 1), C2))>1
becomes
IF(FALSE, COUNTIF($B$2:C2, C2), 1+COUNTIF($B$2:$B$5, C2))>1
becomes
IF(FALSE, COUNTIF($B$2:C2, C2), 1+COUNTIF({0;11;14;16},6))>1
becomes
IF(FALSE, COUNTIF($B$2:C2, C2), 1+0)>1
becomes
1>1 and returns FALSE. Cell C2 is not highlighted.
Highlight all duplicates
To highlight all duplicates is much easier, the formula simply counts how many times the current value exists in the cell range.
Get excel *.xlsx file
Cf duplicates category
This article shows you how to easily identify duplicate rows or records in a list. What's on this webpage Highlight […]
The image above demonstrates a conditional formatting formula applied to an Excel Table containing random data. The Excel Table has […]
The image above demonstrates a conditional formatting formula that highlights duplicate items based on date. The first instance is not highlighted, […]
Conditional formatting category
This article explains how to count cells highlighted with Conditional Formatting (CF). The image above shows data in cell range […]
The image above demonstrates a conditional formatting formula that colors a record if there is at least one record that […]
adam asks: Hi, I have a situation where I want to count if this value is duplicate and if it […]
Functions in this article
More than 1300 Excel formulas
Conditional Formatting categories
Excel categories
2 Responses to “Highlight duplicate values in a cell range”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
When you modiy to move to anu other column apart from 'A' the the first instance of the duplicate also highlights.
David Gordon,
You are right, I believe the new formula I have added to this post is more useful.
Thanks for commenting!