Excel - Find Sequential Values with Conditional Formatting

ommni

New Member
Joined
Oct 14, 2006
Messages
6
Hello,

I'm try to devise a conditional formatting formula that will highlight all sequential values in a row. Have tried several variations of this formula (which finds dupes) without success:

=COUNTIF(A$7:F$7,A7)>1

Am aware that the solution can be done in VB but writing something from scratch is a bit outside my realm of skill.

Any suggestions or pointers would be very much appreciated.

-Ommni
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
Hi,

This example would work in conditional formatting I think:

OR(AND(ISNUMBER(A1),ISNUMBER(MATCH(A1+1,1:1,0))),AND(ISNUMBER(A1),ISNUMBER(MATCH(A1-1,1:1,0))))

This would work for row 1 and should be pasted into the conditional formatting for A1 and then copy...paste value...formats across the other cells in the row.

Dom
 
Upvote 0
This is the same thing, just better construct:

=AND(ISNUMBER(A1),OR(ISNUMBER(MATCH(A1+1,1:1,0)),ISNUMBER(MATCH(A1-1,1:1,0))))

One problem with this though is if you had 1,2,3,5,6,7 they would all highlight as being sequential which they kind of are but in two seperate groups. May not be what you're after.

Dom
 
Upvote 0
Re: Excel - Find Sequential Values with Conditional Formatti

I'm try to devise a conditional formatting formula that will highlight all sequential values in a row.

Can you give an example of values in a row and which ones should be highlighted?
 
Upvote 0
The values will always be percentages. A row consists of 6 values.

Here are a few sample rows:

43% 44% 27% 44% 42% 41%
(41, 42, 43, 44 should be highlighted)

40% 44% 27% 41% 46% 37%
(40, 41 should be highlighted)

28% 28% 13% 44% 43% 27%
(27, 28 should be highlighted)

The first and third rows have duplicate values (44% and 28%) which no doubt would be highlighted as well. In the instances of dupes in a row, highlighting only one of the dupes would be a bonus, but not critical.

Am impressed with the fast and knowledgeable feedback on this question.

Thank you all.

-Ommni
 
Upvote 0
28% 28% 13% 44% 43% 27%
(27, 28 should be highlighted)

* 43, 44 should be highlighted as well.

-Ommni
 
Upvote 0
Assuming the cells A7:F7 this would be the version of my formula but it has limitations as mention which may not suit you and will highlight all cells with duplicates.

Edited:

=AND(ISNUMBER(A7),OR(ISNUMBER(MATCH(A7+0.01,$A7:$F7,0)),ISNUMBER(MATCH(A7-0.01,$A7:$F7,0))))

Pasted into A7 and paste special format across.

Barry may come up with something better though.[/b]
 
Upvote 0
I would add that the values in a row are linked to another worksheet and are dynamically updated. Tried the following with no success:


=OR(AND(ISNUMBER(A1),ISNUMBER(MATCH(A1+1,1:1,0))),AND(ISNUMBER(A1),ISNUMBER(MATCH(A1-1,1:1,0))))

=AND(ISNUMBER(A1),OR(ISNUMBER(MATCH(A1+1,1:1,0)),ISNUMBER(MATCH(A1-1,1:1,0))))

Excel accepted each formula (each tested separately as 1 conditional). A copy and paste formats across a row was done as instructed. Cells having sequential values were not formatted with the selected color/pattern. Something to do with a range of comparison?

-Ommni
 
Upvote 0
I've edited it as the increment of a percentage would be + or -0.01 not + or - 1.
 
Upvote 0

Forum statistics

Threads
1,214,584
Messages
6,120,385
Members
448,956
Latest member
JPav

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top