Microsoft Office Forums

Go Back   Microsoft Office Forums > >

Reply
 
Thread Tools Display Modes
  #1  
Old 06-14-2015, 02:07 AM
gn28 gn28 is offline find IP in range / find number between numbers Windows 7 64bit find IP in range / find number between numbers Office 2010 32bit
Novice
find IP in range / find number between numbers
 
Join Date: Jun 2015
Posts: 2
gn28 is on a distinguished road
Exclamation find IP in range / find number between numbers

Hi everyone,



I am trying to find a way to go through a list of around 18'000 applications and identify in which of the 2'000 IP Sublets (ranges) they fit in. So far I thought of 2 options, but both go beyond my skills so help would be greatly appreciated. To make it easier the output below only mentions 7 applications and 5 zones.

1. turn all the primary IP addresses into numbers (done) and then find a way (probably a index/match/if/and formula) to identify which IP falls into which subnet (number between numbers) and then retrieve the name of the associated security zone.

2. create a list with all the IPs imaginable and then find a way to go through the list of primary and secondary IPs, retrieve the name of the application... then turn the IPs into numbers and find a way to identify which of them falls into which subnet and then retrieve the name of the security zone.

The 2nd option seems far more precise, but both go beyond my excel skills when needing to find a number between 2 numbers and get the name of the security zone.


A
BCD1
Application name
Primary IP AddressPrimary IP into NumberSecondary IP2
Application 110.100.1.1510,100,001,015
3
Application 210.100.1.7310,100,001,073
4
Application 3192.168.20.55192,168,020,055
5
Application 483.1.25.1083,001,025,01083.1.25.97, 83.1.25.103, 83.1.25.2096
Application 5
109.11.93.195109,011,093,195
7
Application 683.1.25.1583,001,025,015
8
Application 7109.11.93.199109,011,093,199109.11.93.200, 109.11.93.201


FGHIJ1
Security zoneIP Range startIP Range endRange start into numberRange end into number2Internet-Zone 283.1.25.083.1.25.25583,001,025,00083,001,025,2553Internal-voip10.100.1.6410.100.1.12710,100,001,06410,100,00 1,1274DMZ192.168.20.0192.168.20.255192,168,020,000192,16 8,020,2555Internet-Zone 1109.11.93.192109.11.92.255109,011,093,192109,011, 092,2556Internal-restricted10.100.1.010.100.1.6310,100,001,00010,10 0,001,063

Desired table
ABC11
Application name
IP AddressSecurity zone12Application 110.100.1.15
Internal-restricted13


14

Book1.xlsx


Thanks in advance !
Reply With Quote
  #2  
Old 06-14-2015, 05:25 AM
macropod's Avatar
macropod macropod is offline find IP in range / find number between numbers Windows 7 64bit find IP in range / find number between numbers Office 2010 32bit
Administrator
 
Join Date: Dec 2010
Location: Canberra, Australia
Posts: 21,962
macropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond repute
Default

If you sort the data in columns F-H so the IP ranges are in ascending order, thus:
Code:
Internal-restricted    10.100.1.0       10.100.1.63
Internal-voip         10.100.1.64      10.100.1.127
Internet-Zone 2         83.1.25.0       83.1.25.255
Internet-Zone 1     109.11.93.192     109.11.92.255
DMZ                  192.168.20.0    192.168.20.255
in D13 you can use an array formula like:
Code:
=INDEX($G$2:$G$7,MATCH(TEXT(LEFT(C13,FIND(".",C13)),"000")&TEXT(MID(C13,FIND(".",C13)+1,FIND(".",C13,FIND(".",C13)+1)-1-FIND(".",C13)),"000")&TEXT(MID(C13,FIND(".",C13,FIND(".",C13)+1)+1,FIND(".",C13,FIND(".",C13,FIND(".",C13)+1)+1)-1-FIND(".",C13,FIND(".",C13)+1)),"000")&TEXT(MID(C13,FIND(".",C13,FIND(".",C13,FIND(".",C13)+1)+1)+1,LEN(C13)),"000"),TEXT(LEFT($H$2:$H$7,FIND(".",$H$2:$H$7)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7)+1,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)-1-FIND(".",$H$2:$H$7)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1)-1-FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1)+1,LEN($H$2:$H$7)),"000"),1))
Note: You should probably also interleave the valid ranges with the IP addresses that are invalid (e.g. 83.1.26.0 - 109.11.93.191), otherwise you may end up with false matches. If you can't do that and there is a risk of IP addresses that are invalid being input, a rather more complex version of the above formula would be required.
__________________
Cheers,
Paul Edstein
[Fmr MS MVP - Word]
Reply With Quote
  #3  
Old 06-14-2015, 09:27 AM
Pecoflyer's Avatar
Pecoflyer Pecoflyer is offline find IP in range / find number between numbers Windows 7 64bit find IP in range / find number between numbers Office 2010 64bit
Expert
 
Join Date: Nov 2011
Location: Brussels Belgium
Posts: 2,771
Pecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant futurePecoflyer has a brilliant future
Default

Do not crosspost your question on multiple forums without including links here to the other threads on other forums.

Cross-posting is when you post the same question in other forums on the web. The last thing you want to do is waste people's time working on an issue you have already resolved elsewhere. We prefer that you not cross-post at all, but if you do (and it's unlikely to go unnoticed), you MUST provide a link (copy the url from the address bar in your browser) to the cross-post.


Read this to understand why we ask you to do this, and then please edit your first post to include links to any and all cross-posts in any other forums (not just this site).
http://www.excelguru.ca/forums/showt...etween-numbers
__________________
Did you know you can thank someone who helped you? Click on the tiny scale in the right upper hand corner of your helper's post
Reply With Quote
  #4  
Old 06-14-2015, 11:59 AM
gn28 gn28 is offline find IP in range / find number between numbers Windows 7 64bit find IP in range / find number between numbers Office 2010 32bit
Novice
find IP in range / find number between numbers
 
Join Date: Jun 2015
Posts: 2
gn28 is on a distinguished road
Default

Quote:
Originally Posted by macropod View Post
If you sort the data in columns F-H so the IP ranges are in ascending order, thus:
Code:
Internal-restricted    10.100.1.0       10.100.1.63
Internal-voip         10.100.1.64      10.100.1.127
Internet-Zone 2         83.1.25.0       83.1.25.255
Internet-Zone 1     109.11.93.192     109.11.92.255
DMZ                  192.168.20.0    192.168.20.255
in D13 you can use an array formula like:
Code:
=INDEX($G$2:$G$7,MATCH(TEXT(LEFT(C13,FIND(".",C13)),"000")&TEXT(MID(C13,FIND(".",C13)+1,FIND(".",C13,FIND(".",C13)+1)-1-FIND(".",C13)),"000")&TEXT(MID(C13,FIND(".",C13,FIND(".",C13)+1)+1,FIND(".",C13,FIND(".",C13,FIND(".",C13)+1)+1)-1-FIND(".",C13,FIND(".",C13)+1)),"000")&TEXT(MID(C13,FIND(".",C13,FIND(".",C13,FIND(".",C13)+1)+1)+1,LEN(C13)),"000"),TEXT(LEFT($H$2:$H$7,FIND(".",$H$2:$H$7)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7)+1,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)-1-FIND(".",$H$2:$H$7)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1)-1-FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)),"000")&TEXT(MID($H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7,FIND(".",$H$2:$H$7)+1)+1)+1,LEN($H$2:$H$7)),"000"),1))
Note: You should probably also interleave the valid ranges with the IP addresses that are invalid (e.g. 83.1.26.0 - 109.11.93.191), otherwise you may end up with false matches. If you can't do that and there is a risk of IP addresses that are invalid being input, a rather more complex version of the above formula would be required.
Hi there,
First of all, thanks for the helping hand.

Was I suppose to do something special with the formula?
I am getting "a value used in the formula is of the wrong data type" error.

Thanks in advance
Reply With Quote
  #5  
Old 06-14-2015, 03:46 PM
macropod's Avatar
macropod macropod is offline find IP in range / find number between numbers Windows 7 64bit find IP in range / find number between numbers Office 2010 32bit
Administrator
 
Join Date: Dec 2010
Location: Canberra, Australia
Posts: 21,962
macropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond reputemacropod has a reputation beyond repute
Default

The formula, as posted, works fine in your workbook. See attached.
Attached Files
File Type: xlsx IP Correlations.xlsx (11.6 KB, 24 views)
__________________
Cheers,
Paul Edstein
[Fmr MS MVP - Word]
Reply With Quote
Reply



Similar Threads
Thread Thread Starter Forum Replies Last Post
How to find number of coma and then add that number of rows in word using macro? PRA007 Word VBA 7 05-27-2015 10:45 PM
find IP in range / find number between numbers Help!! find two number recurring numbers in row?? carrolld2 Excel 5 06-28-2014 05:43 PM
Find and Delete Rows based on a range damaniam Excel Programming 2 03-12-2014 06:06 AM
find IP in range / find number between numbers Find and Replace using Excel range dmarie123 Word VBA 15 04-02-2013 07:54 AM
Find and Replace within range anil3b2 Word VBA 3 12-01-2010 02:35 AM

Other Forums: Access Forums

All times are GMT -7. The time now is 03:13 AM.


Powered by vBulletin® Version 3.8.11
Copyright ©2000 - 2024, vBulletin Solutions Inc.
Search Engine Optimisation provided by DragonByte SEO (Lite) - vBulletin Mods & Addons Copyright © 2024 DragonByte Technologies Ltd.
MSOfficeForums.com is not affiliated with Microsoft