Find which port SQL Server is using to establish connections

  • SQLDCH

    SSChampion

    Points: 11400

    Comments posted to this topic are about the item Find which port SQL Server is using to establish connections

    ----------------------------------------------------------------------------
    Sacramento SQL Server users group - http://sac.sqlpass.org
    Follow me on Twitter - @SQLDCH
    ----------------------------------------------------------------------------

    Yeah, well...The Dude abides.
  • Avinash Barnwal

    Say Hey Kid

    Points: 686

    The third way doesn't seem to be option to find out which of the port SQL Server is listening, since if you are already connected to the SQL server, then you already know the Port.


    Kindest Regards,

    Avinash

    avin_barnwal@hotmail.com

  • spaghettidba

    SSC Guru

    Points: 105661

    Avinash Barnwal (9/7/2011)


    The third way doesn't seem to be option to find out which of the port SQL Server is listening, since if you are already connected to the SQL server, then you already know the Port.

    Not completely true. You can connect using a named instance and never know the port you're attaching to.

    The SQL Browser service listens on port UDP 1434 and returns the port of the named instances in a datagram. The client application parses the datagram and connects to the port returned by the SQL Browser.

  • Håvard

    Mr or Mrs. 500

    Points: 569

    I really liked this article. It's short and simple, and I learned something:-)

  • d.majoor

    Valued Member

    Points: 52

    If you are connected (using the instance name) you can also find it by query (SQl2000 and up):

    set nocount on

    go

    DECLARE @SqlPort Nvarchar(10), @instance_name Nvarchar(30), @reg_key Nvarchar(500), @value_name Nvarchar(20)

    if left(CAST(SERVERPROPERTY('ProductVersion')AS sysname),2) = '10'

    BEGIN

    select @instance_name = CAST(SERVERPROPERTY('instancename')AS sysname)

    if @instance_name is NULL

    BEGIN

    set @reg_key = 'SOFTWARE\Microsoft\MSSQLServer\MSSQlServer\SuperSocketNetLib\Tcp'

    END

    ELSE BEGIN

    set @reg_key = 'SOFTWARE\Microsoft\Microsoft SQL Server\' + @instance_name + '\MSSQLServer\SuperSocketNetLib\Tcp'

    END

    EXEC master..xp_regread @rootkey='HKEY_LOCAL_MACHINE',

    @key=@reg_key, @value_name='TcpPort',

    @value=@SqlPort output

    select CAST(SERVERPROPERTY('ServerName')AS sysname) as ServerName, @SqlPort as Port

    END

    if left(CAST(SERVERPROPERTY('ProductVersion')AS sysname),1) = '9'

    BEGIN

    select @instance_name = CAST(SERVERPROPERTY('instancename')AS sysname)

    if @instance_name is NULL

    BEGIN

    set @reg_key = 'SOFTWARE\Microsoft\MSSQLServer\MSSQlServer\SuperSocketNetLib\Tcp'

    END

    ELSE BEGIN

    set @reg_key = 'SOFTWARE\Microsoft\Microsoft SQL Server\' + @instance_name + '\MSSQLServer\SuperSocketNetLib\Tcp'

    END

    EXEC master..xp_regread @rootkey='HKEY_LOCAL_MACHINE',

    @key=@reg_key, @value_name='TcpPort',

    @value=@SqlPort output

    select CAST(SERVERPROPERTY('ServerName')AS sysname) as ServerName, @SqlPort as Port

    END

    if left(CAST(SERVERPROPERTY('ProductVersion')AS sysname),1) = '8'

    BEGIN

    Create table #Port_2000 (value nvarchar(20),Data nVarchar(10))

    insert into #Port_2000 exec master..xp_instance_regread 'HKEY_LOCAL_MACHINE', 'SOFTWARE\Microsoft\MSSQLServer\MSSQLServer\Supersocketnetlib\tcp', 'tcpPort'

    select @SqlPort = Data from #Port_2000

    select CAST(SERVERPROPERTY('ServerName')AS sysname) as ServerName, @SqlPort as Port

    drop table #Port_2000

    END

  • bertrand.leroy

    SSC Rookie

    Points: 44

    Thanks for the tips;

    For info:

    I found out though that the only way that worked for me was to check the event details - although for that I had to restart the server to generate new events.

    With regards to the second option, I have no values displayed in that field, or any other fields labeled "Port" in that IP-Addresses tab.

    The third option had to be tinkered with a wee bit -

    @@SERVICENAME returns MSSS2008R2

    but the key is actually found under MSSQL10_50.MSSQLSERVER2008R2

    and then, just like for option 2, that tcp key value is empty anyway:

    Value Data

    tcpPort NULL

    thanks again for the tips,

    B

  • Lawrence Moore

    Ten Centuries

    Points: 1203

    How about using this for a TSQL based solution?:

    SELECT DISTINCT(local_tcp_port) FROM sys.dm_exec_connections

    WHERE net_transport='TCP'

  • robotpukeko

    Valued Member

    Points: 60

    You can also use the following from the command line :

    netstat -n -b

    You can then check the returned values for the executable you're interested in to see the port (or ports) being listened on.

  • M&M

    SSC-Insane

    Points: 21679

    Nice simple article. We could also get this information from SQL Server error log.

    M&M

  • tskelley

    SSCommitted

    Points: 1846

    Figured I would throw one more method, albeit quite a bit more manual. You can also check the error log in found in the Log folder where your SQL Server is installed (for example, C:\Program Files\Microsoft SQL Server\MSSQL.1\Log). The latest log file will be named ERRORLOG (w/out the numbered extension). Using a standard text editor, like Notepad, you can do a quick search for the text 'listening'.

  • noelc

    SSC Enthusiast

    Points: 109

    on 2K8:

    xp_ReadErrorLog 0, 1, 'listening'

    -- Parameters defined:

    -- Parameter 1 (int), is the number of the log file you want to read, default is "0" for current log.

    -- Parameter 2 (int), value of 1 reads SQL error logs, value of 2 reads SQL Server Agent logs, with a default value of 1.

    -- Parameter 3 varchar (255), is a search string for the log entry, with a default value of NULL.

    -- Parameter 4 varchar (255), is another search string for the log entry, with a default value of NULL

  • GAF

    SSC-Addicted

    Points: 406

    Thank you. Good discussion started, good job.

Viewing 12 posts - 1 through 12 (of 12 total)

You must be logged in to reply to this topic. Login to reply