Highlight opposite numbers
Pamela asks:
Ex. 1 with -1, 5000 with -5000, 75 with -75, etc.
Once I find those pairs, WITHOUT REPEATING
Ex. 75,-75,75, just the first TWO should get marked, and leave the last 75 alone.
Conditional formatting formula applied to cell range B3:B17:
Explaining CF formula in cell B3
COUNTIF($B$3:B3, B3)=1
The first COUNTIF function counts how many values there are in the first argument that match the second argument.
It returns TRUE if it is equal to 1, meaning this is the first instance of the value. In other words, this makes sure that duplicates are not highlighted.
The first argument is also a growing cell reference, the picture below shows what it returns in column D:
COUNTIF($B$3:B3, B3*-1)
The second COUNTIF function counts how many values there are in the first argument matching B3 but with a different sign, starting from the top.
This verifies that there is a number with a different sign above the current value.
The first argument has a growing cell reference meaning it expands as you copy the formula to cells below. In this case, I am using it as a Conditional Formatting formula, however, it behaves the same.
The picture below shows what it returns in column C:
MATCH(B3*-1,$B$3:$B$17,0)
The MATCH function looks for the number but with a different sign, this verifies it really exists a pair in the first place.
The MATCH function returns a #N/A error if a number is not found
COUNT(MATCH(B3*-1,$B$3:$B$17,0))
The COUNT function then converts error to a 0 (zero). The picture below shows what it returns in column E:
Then the formula adds the numbers in the two last arrays, like this COUNTIF($B$3:B3, B3*-1)+COUNT(MATCH(B3*-1, $B$3:$B$17, 0)
and lastly multiplies with COUNTIF($B$3:B3, B3)=1.
Get Excel *.xlsx file
Cf misc category
Here is how to highlight every other row using conditional formatting. Conditional formatting formula: =ISEVEN(ROW())*OR($B3:$D3<>"") Alternative CF formula: =EVEN(ROW())=ROW() This […]
Question: I have a list that I keep adding rows to. How do i create a border that expands as […]
This article demonstrates how to apply different cell formatting to a cell range based on a Drop Down list, column […]
The picture above shows Conditional Formatting highlighting cells in cell range F3:Y22 based on row and column values in column B […]
This article demonstrates a Conditional Formatting formula that lets you highlight cells based on numerical ranges specified in an Excel […]
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 […]
Question: How do I highlight dates that meet criteria using conditional formatting? Table of contents Highlight values in a column […]
This post demonstrates how to highlight records with the closest value to a criterion, you can also choose to highlight […]
The image above shows rows highlighted based on value in column C being the largest or smallest in that particular […]
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 […]
Here is how to highlight every other row using conditional formatting. Conditional formatting formula: =ISEVEN(ROW())*OR($B3:$D3<>"") Alternative CF formula: =EVEN(ROW())=ROW() This […]
Question: I have a list that I keep adding rows to. How do i create a border that expands as […]
The image above shows you how to highlight rows with multiple criteria using OR logic. The criteria are found in […]
In this article, I will demonstrate how to search a table using conditional formatting. The criteria highlight matching column and […]
Today I am going to show you how to quickly compare two tables using Conditional Formatting (CF). I am going […]
The image above demonstrates a conditional formatting formula that highlights duplicate items based on date. The first instance is not highlighted, […]
A conditional formatting formula highlights values in column B that also exist in column D. =COUNTIF($D$3:$D$7,B3) The same thing happens […]
In this post I am going to try to explain formula basics in conditional formatting. It is really good if […]
The image above shows conditional formatting highlighting unique distinct values, duplicates are not highlighted. Conditional Formatting Formula: =COUNTIF($B$3:B3, B3)=1 The […]
This article demonstrates how to apply different cell formatting to a cell range based on a Drop Down list, column […]
In this blog post I will demonstrate a conditional formatting formula that will highlight common records in two lists. The […]
The image above demonstrates a conditional formatting formula that highlights records that only exist in one table. There are two […]
Functions in this article
More than 1300 Excel formulas
Conditional Formatting categories
Excel categories
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.