SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Get IP Addresses of all Hostnames using SQL Server


Get IP Addresses of all Hostnames using SQL Server

Author
Message
sumitagarwal.hcst
sumitagarwal.hcst
Forum Newbie
Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)Forum Newbie (7 reputation)

Group: General Forum Members
Points: 7 Visits: 128
Comments posted to this topic are about the item Get IP Addresses of all Hostnames using SQL Server
Mike Dougherty-384281
Mike Dougherty-384281
SSC-Addicted
SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)SSC-Addicted (478 reputation)

Group: General Forum Members
Points: 478 Visits: 944
Please tell me you are using a local/desktop instance of SQL server to run this code and that you're not doing this on a production server.

I might try to convince you to use a scripting environment for this task and have it contact your database to store the found/discovered data - but I also understand that if your comfort zone is T-SQL that's the language you'll use to solve the problem at hand. (when your only tool is a hammer all your problems look like nails)

Some other thoughts:
You're already using dynamic sql, why not make the column name in the table also passed into the procedure - in case the dynamic tablename has some other column name containing the hostnames.

Try updating your ping command to include -n 1 and -w 1 so you only ping once and only wait 1ms for a reply. Since you are only looking for the dns lookup "Pinging...[a.b.c.d]" line anyway you don't really even need the results of the ping. Sending 1 instead of the default 4 will be less wasteful (and faster) and timing-out quickly (especially on not-found hosts) will also help this task complete sooner. (which might not be important until you consider the resources consumed by executing xp_cmdshell 500+ times in a cursor)

btw, if you decide to store the IP address using 4 tinyint fields for the sake of indexing and easier grouping by various octets, you can use parsename() for a clever split:
select parsename('192.168.1.10',4) /* 192, or the "server" part of a 4part name */
select parsename('192.168.1.10',3) /* 168, or the "database" part of a 4part name */
select parsename('192.168.1.10',2) /* 1, or the "owner" part of a 4part name */
select parsename('192.168.1.10',1) /* 10, or the "table" part of a 4part name */
Miles Neale
Miles Neale
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3082 Visits: 1694
Tried to look at this to see what was what and could not get it to run. Messages were

Msg 8152, Level 16, State 14, Procedure usp_getIPAdress_frm_Hostname, Line 47
String or binary data would be truncated.



M.

Not all gray hairs are Dinosaurs!
rjoseph
rjoseph
Valued Member
Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)Valued Member (59 reputation)

Group: General Forum Members
Points: 59 Visits: 145
Pardon my lack of knowledge in the SQL environment. How do I really use this script and make us of it. It seems to be every interesting. I am really new to this. Thanks for sharing.
aleksey donskoy
aleksey donskoy
Valued Member
Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)

Group: General Forum Members
Points: 61 Visits: 519
Awesome script. Works like a clock. Thanks.
You do not need to have a stored procedure there.
Made 3 modifications:
1. Converted it an ad hoc query using the sysprocesses.hostname column
2. Expanded some string variables to hold longer strings
3. Filtered empty hostnames and duplicates as following (cut execution time by half):

EXEC('INSERT INTO #TblHostName (Hostname) Select distinct hostname from sysprocesses where hostname <> ''''')

The altered version below:

You could drop BEGIN/END (I did not bother)

use master;
BEGIN
CREATE TABLE #Results ( Results VARCHAR(4000) )

DECLARE @Commandstring VARCHAR(4000) ,
@IP VARCHAR(300) ,
@ctr VARCHAR(600) ,
@Hostname VARCHAR(128)
CREATE TABLE #TblHostName
(
ID INT IDENTITY(1, 1) ,
Hostname VARCHAR(255) ,
IpAddress VARCHAR(32)
)

EXEC('INSERT INTO #TblHostName (Hostname) Select distinct hostname from sysprocesses where hostname <> ''''')

SELECT @ctr = MAX(id)
FROM #TblHostName
WHILE @CTR > 0
BEGIN
SET @IP = 'NOT FOUND'
SELECT @Hostname = hostname
FROM #TblHostName
WHERE id = @ctr
SET @Commandstring = 'ping ' + @Hostname

--Insert the string in temp table

INSERT INTO #Results
EXEC master..xp_cmdshell @Commandstring


--Get the IP address from the string
SELECT @IP = SUBSTRING(Results, CHARINDEX('[', Results) + 1,
CHARINDEX(']', Results)
- CHARINDEX('[', Results) - 1)
FROM #Results
WHERE Results LIKE 'Pinging%'

UPDATE #TblHostName
SET IPADDRESS = @IP
WHERE id = @ctr

TRUNCATE TABLE #Results

SELECT @ctr = ( @ctr - 1 )
END
SELECT *
FROM #TblHostName
DROP TABLE #TblHostName
DROP TABLE #Results
END


Alex Donskoy
SQL DBA at GTLaw
Miami FL
Iwas Bornready
Iwas Bornready
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14116 Visits: 885
aleksey donskoy (10/13/2015)
Awesome script. Works like a clock. Thanks.
You do not need to have a stored procedure there.
Made 3 modifications:
1. Converted it an ad hoc query using the sysprocesses.hostname column
2. Expanded some string variables to hold longer strings
3. Filtered empty hostnames and duplicates as following (cut execution time by half):

EXEC('INSERT INTO #TblHostName (Hostname) Select distinct hostname from sysprocesses where hostname <> ''''')

The altered version below:
Thanks for the improvements.
aleksey donskoy
aleksey donskoy
Valued Member
Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)

Group: General Forum Members
Points: 61 Visits: 519
Found an easier way to do it. (Combined 2 scripts):

select distinct hostname, client_net_address from sysprocesses
inner join sys.dm_exec_connections ON sysprocesses.spid=sys.dm_exec_connections.session_id
where hostname <> ''

Alex Donskoy
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search