Max range between values based on category column (variable range sizes and categories)

GregDz11

New Member
Joined
Mar 13, 2017
Messages
14
Right now I've got a large list of IP addresses due to using /24 subnet breakdowns, however I want to reduce my subnets to the tightest possible subnet to accommodate IPs in the range. To this I need to know the difference between the minimum and maximum of the values within the /24 range. My data looks like the following:

[TABLE="width: 500"]
<tbody>[TR]
[TD]IP SUBNET[/TD]
[TD]IP[/TD]
[TD]4th_Oct[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.1[/TD]
[TD]1[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.24[/TD]
[TD]24[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.158[/TD]
[TD]158[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.2[/TD]
[TD]2[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.4[/TD]
[TD]4[/TD]
[/TR]
</tbody>[/TABLE]


And I'd like to know the following two columns:
[TABLE="width: 500"]
<tbody>[TR]
[TD]IP SUBNET[/TD]
[TD]IP[/TD]
[TD]4th_Oct[/TD]
[TD]Difference in Sub between min and Max[/TD]
[TD]Min IP[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.1[/TD]
[TD]1[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.24[/TD]
[TD]24[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.158[/TD]
[TD]158[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.2[/TD]
[TD]2[/TD]
[TD]2[/TD]
[TD]192.168.2.2[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.4[/TD]
[TD]4[/TD]
[TD]2[/TD]
[TD]192.168.2.2[/TD]
[/TR]
</tbody>[/TABLE]


With that I can easily calculate the best subnet to use
[TABLE="width: 500"]
<tbody>[TR]
[TD]IP SUBNET[/TD]
[TD]IP[/TD]
[TD]4th_Oct[/TD]
[TD]Difference in Sub between min and Max[/TD]
[TD]Min IP[/TD]
[TD]Best Subnet[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.1[/TD]
[TD]1[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[TD]/24[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.24[/TD]
[TD]24[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[TD]/24[/TD]
[/TR]
[TR]
[TD]192.168.1.0/24[/TD]
[TD]192.168.1.158[/TD]
[TD]158[/TD]
[TD]157[/TD]
[TD]192.168.1.1[/TD]
[TD]/24[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.2[/TD]
[TD]2[/TD]
[TD]2[/TD]
[TD]192.168.2.2[/TD]
[TD]/31[/TD]
[/TR]
[TR]
[TD]192.168.2.0/24[/TD]
[TD]192.168.2.4[/TD]
[TD]4[/TD]
[TD]2[/TD]
[TD]192.168.2.2[/TD]
[TD]/31[/TD]
[/TR]
</tbody>[/TABLE]


Any help will be appreciated!
 

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
I share 5 formulas in cells D2, E2, F2, G2 and H2
The formulas E2 and F2 are array formulas.
Copy the 5 formulas down.
The result will be in columns G and H.

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:101.7px;" /><col style="width:93.15px;" /><col style="width:61.78px;" /><col style="width:91.25px;" /><col style="width:47.52px;" /><col style="width:42.77px;" /><col style="width:76.04px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td><td >E</td><td >F</td><td >G</td><td >H</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; ">IP SUBNET</td><td style="background-color:#92d050; ">IP</td><td style="background-color:#92d050; ">4th_Oct</td><td style="background-color:#ffc000; ">Segment</td><td style="background-color:#ffc000; ">Min</td><td style="background-color:#ffc000; ">Max</td><td style="background-color:#ffc000; ">Diference</td><td style="background-color:#ffc000; ">Min IP</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >192.168.1.0/24</td><td >192.168.1.1</td><td style="text-align:right; ">1</td><td >192.168.1</td><td style="text-align:right; ">1</td><td style="text-align:right; ">158</td><td style="text-align:right; ">157</td><td >192.168.1.1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >192.168.1.0/24</td><td >192.168.1.24</td><td style="text-align:right; ">24</td><td >192.168.1</td><td style="text-align:right; ">1</td><td style="text-align:right; ">158</td><td style="text-align:right; ">157</td><td >192.168.1.1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >192.168.1.0/24</td><td >192.168.1.158</td><td style="text-align:right; ">158</td><td >192.168.1</td><td style="text-align:right; ">1</td><td style="text-align:right; ">158</td><td style="text-align:right; ">157</td><td >192.168.1.1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >192.168.2.0/24</td><td >192.168.2.2</td><td style="text-align:right; ">2</td><td >192.168.2</td><td style="text-align:right; ">2</td><td style="text-align:right; ">4</td><td style="text-align:right; ">2</td><td >192.168.2.2</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >192.168.2.0/24</td><td >192.168.2.4</td><td style="text-align:right; ">4</td><td >192.168.2</td><td style="text-align:right; ">2</td><td style="text-align:right; ">4</td><td style="text-align:right; ">2</td><td >192.168.2.2</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Formeln der Tabelle</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Zelle</td><td >Formel</td></tr><tr><td >D2</td><td >=TRIM(LEFT(SUBSTITUTE(B2,".",REPT(" ",12),3),11))</td></tr><tr><td >E2</td><td >{=MIN(IF($D$2:$D$6=$D2,$C$2:$C$6))}</td></tr><tr><td >F2</td><td >{=MAX(IF($D$2:$D$6=$D2,$C$2:$C$6))}</td></tr><tr><td >G2</td><td >=F2-E2</td></tr><tr><td >H2</td><td >=INDEX($B$2:$B$6,MATCH(E2,$C$2:$C$6,0))</td></tr></table></td></tr></table>


Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself
 
Upvote 0
silly question, when I enter the array formula do I highlight the whole column, enter the formula, hit the combo keys or enter it into 1 cell (ctrl+shift+enter) then drag that down the column?
 
Upvote 0
silly question, when I enter the array formula do I highlight the whole column, enter the formula, hit the combo keys or enter it into 1 cell (ctrl+shift+enter) then drag that down the column?

You do it in the first cell and then copies down
 
Upvote 0

Forum statistics

Threads
1,223,896
Messages
6,175,263
Members
452,627
Latest member
KitkatToby

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