2 Formulas, rearrange, CF.

serge

Well-known Member
Joined
Oct 8, 2008
Messages
1,444
Office Version
  1. 2007
Platform
  1. Windows
Hi everyone,

Im looking for 2 formulas, I cant really make 2 posts for it because they run together.


The first one would be to take the data from EC3:EY3 (with blanc columns in between ) which are " Span numbers " and rearrange them in numerical order starting from FA3 to FS3, its always gone by 19 numbers.


The second formula is a CF formula that will in the respected order highlight the right numbers.


For example if you look at row 3 you have number 1 in ED3, EH3, EN3, ES3 and EW3, but only EN3 and ES3 are highlighted, meaning the third and forth in the rearrange numerical order and so on for all the other number, they need to be highlighted according to their position in the chart.

See image below :

<a href="http://tinypic.com?ref=w9ed6a" target="_blank"><img src="http://i65.tinypic.com/w9ed6a.png" border="0" alt="Image and video hosting by TinyPic"></a>

Thank you.
Serge.
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
I made the pictures bigger to see and understand better.Thank you for any help.

<a href="http://tinypic.com?ref=qs829l" target="_blank"><img src="http://i68.tinypic.com/qs829l.png" border="0" alt="Image and video hosting by TinyPic"></a>

<a href="http://tinypic.com?ref=2rdf31y" target="_blank"><img src="http://i68.tinypic.com/2rdf31y.png" border="0" alt="Image and video hosting by TinyPic"></a>

Thank you.
Serge.
 
Upvote 0
Can anyone help me with this please ?

Thank you.
Serge.
 
Upvote 0
To put them in numerical order, you could put =SMALL($EC3:$EY3, COLUMNS($FA3:FA3)) in FA3 and drag right.

Formulas can't react to cell color.
 
Upvote 0
Thank you Mike, I guess what I need is not possible, that would had really help me in my analysis.
Serge.
 
Upvote 0
I hope someone will take the time to watch it, its only 3:37 mn long, I appreciate it.
Serge.
 
Last edited:
Upvote 0
To make things easier we should put the number of the groups in EC2:EY2, that is


[TABLE="class: grid"]
<tbody>[TR]
[TD="bgcolor: #DCE6F1"][/TD]
[TD="bgcolor: #DCE6F1"]
DW
[/TD]
[TD="bgcolor: #DCE6F1"]
DX
[/TD]
[TD="bgcolor: #DCE6F1"]
DY
[/TD]
[TD="bgcolor: #DCE6F1"]
DZ
[/TD]
[TD="bgcolor: #DCE6F1"]
EA
[/TD]
[TD="bgcolor: #DCE6F1"]
EB
[/TD]
[TD="bgcolor: #DCE6F1"]
EC
[/TD]
[TD="bgcolor: #DCE6F1"]
ED
[/TD]
[TD="bgcolor: #DCE6F1"]
EE
[/TD]
[TD="bgcolor: #DCE6F1"]
EF
[/TD]
[TD="bgcolor: #DCE6F1"]
EG
[/TD]
[TD="bgcolor: #DCE6F1"]
EH
[/TD]
[TD="bgcolor: #DCE6F1"]
EI
[/TD]
[TD="bgcolor: #DCE6F1"]
EJ
[/TD]
[TD="bgcolor: #DCE6F1"]
EK
[/TD]
[TD="bgcolor: #DCE6F1"]
EL
[/TD]
[TD="bgcolor: #DCE6F1"]
EM
[/TD]
[TD="bgcolor: #DCE6F1"]
EN
[/TD]
[TD="bgcolor: #DCE6F1"]
EO
[/TD]
[TD="bgcolor: #DCE6F1"]
EP
[/TD]
[TD="bgcolor: #DCE6F1"]
EQ
[/TD]
[TD="bgcolor: #DCE6F1"]
ER
[/TD]
[TD="bgcolor: #DCE6F1"]
ES
[/TD]
[TD="bgcolor: #DCE6F1"]
ET
[/TD]
[TD="bgcolor: #DCE6F1"]
EU
[/TD]
[TD="bgcolor: #DCE6F1"]
EV
[/TD]
[TD="bgcolor: #DCE6F1"]
EW
[/TD]
[TD="bgcolor: #DCE6F1"]
EX
[/TD]
[TD="bgcolor: #DCE6F1"]
EY
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
1
[/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
2
[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[TD]
1​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
2​
[/TD]
[TD]
2​
[/TD]
[TD]
2​
[/TD]
[TD][/TD]
[TD]
3​
[/TD]
[TD]
3​
[/TD]
[TD]
3​
[/TD]
[TD]
3​
[/TD]
[TD][/TD]
[TD]
4​
[/TD]
[TD]
4​
[/TD]
[TD]
4​
[/TD]
[TD]
4​
[/TD]
[TD][/TD]
[TD]
5​
[/TD]
[TD]
5​
[/TD]
[TD]
5​
[/TD]
[TD]
5​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
3
[/TD]
[TD]
4​
[/TD]
[TD]
5​
[/TD]
[TD]
4​
[/TD]
[TD]
4​
[/TD]
[TD]
2​
[/TD]
[TD][/TD]
[TD]
3​
[/TD]
[TD]
1​
[/TD]
[TD]
4​
[/TD]
[TD][/TD]
[TD]
6​
[/TD]
[TD]
1​
[/TD]
[TD]
5​
[/TD]
[TD]
20​
[/TD]
[TD][/TD]
[TD]
5​
[/TD]
[TD]
2​
[/TD]
[TD]
1​
[/TD]
[TD]
3​
[/TD]
[TD][/TD]
[TD]
15​
[/TD]
[TD]
4​
[/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD][/TD]
[TD]
7​
[/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD]
4​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
4
[/TD]
[TD]
3​
[/TD]
[TD]
2​
[/TD]
[TD]
2​
[/TD]
[TD]
5​
[/TD]
[TD]
4​
[/TD]
[TD][/TD]
[TD]
4​
[/TD]
[TD]
2​
[/TD]
[TD]
1​
[/TD]
[TD][/TD]
[TD]
7​
[/TD]
[TD]
2​
[/TD]
[TD]
6​
[/TD]
[TD]
1​
[/TD]
[TD][/TD]
[TD]
6​
[/TD]
[TD]
3​
[/TD]
[TD]
1​
[/TD]
[TD]
14​
[/TD]
[TD][/TD]
[TD]
16​
[/TD]
[TD]
5​
[/TD]
[TD]
1​
[/TD]
[TD]
3​
[/TD]
[TD][/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
5​
[/TD]
[/TR]
[TR]
[TD="bgcolor: #DCE6F1"]
5
[/TD]
[TD]
4​
[/TD]
[TD]
3​
[/TD]
[TD]
4​
[/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD][/TD]
[TD]
5​
[/TD]
[TD]
1​
[/TD]
[TD]
2​
[/TD]
[TD][/TD]
[TD]
8​
[/TD]
[TD]
3​
[/TD]
[TD]
7​
[/TD]
[TD]
2​
[/TD]
[TD][/TD]
[TD]
1​
[/TD]
[TD]
4​
[/TD]
[TD]
2​
[/TD]
[TD]
15​
[/TD]
[TD][/TD]
[TD]
17​
[/TD]
[TD]
6​
[/TD]
[TD]
2​
[/TD]
[TD]
1​
[/TD]
[TD][/TD]
[TD]
2​
[/TD]
[TD]
3​
[/TD]
[TD]
1​
[/TD]
[TD]
6​
[/TD]
[/TR]
</tbody>[/TABLE]


Then select FA3:FS5 and in CF use this formula
=INDEX($DW3:$EA3,SMALL(IF($EC3:$EY3=FA3,$EC$2:$EY$2),COUNTIF($FA3:FA3,FA3)))=INDEX($EC$1:$EY$1,SMALL(IF($EC3:$EY3=FA3,COLUMN($EC3:$EY3)-COLUMN($EC3)+1),COUNTIF($FA3:FA3,FA3)))
pick a format

Hope this helps

M.
 
Last edited:
Upvote 0
Thank you very much Marcelo, That's a very impressive formula, It works perfectly for my chart, You are incredible .

Thank you again.
Serge.
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,246
Members
452,623
Latest member
cliftonhandyman

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