Last time, I talked about how clients communicate with SQL Server through TDS endpoints and how to disable endpoints to prevent user access. Today we’ll see how we can configure SQL Server to listen on multiple ports through the use of user-defined endpoints.
Create a new TDS endpoint
There can only be one Shared Memory and one Named Pipes endpoint per instance. You can, however, create additional TCP endpoints that each listen on their own assigned port.
create endpoint [AdminsOnly] state = started as tcp (listener_port = 5023) FOR tsql ()
When you create a new endpoint, SQL Server will automatically revoke connect privileges on the “TSQL Default TCP” endpoint from Public. In fact, you’ll get a message saying as much when you issue the CREATE ENDPOINT command:
“Creation of a TSQL endpoint will result in the revocation of any ‘Public’ connect permissions on the ‘TSQL Default TCP’ endpoint. If ‘Public’ access is desired on this endpoint, reapply this permission using ‘GRANT CONNECT ON ENDPOINT::[TSQL Default TCP] to [public]‘.”
So if you want users to continue to use the default endpoint for TCP, make sure you reapply connect permission. If we select from sys.endpoints and sys.tcp_endpoints, we can see the new AdminsOnly endpoint, listening on port 5023.
select * from sys.endpoints; select * from sys.tcp_endpoints
Granting permissions
Before anyone can use this endpoint, they have to be granted connect permission. Obviously, with a name like AdminsOnly, I probably intend this endpoint to be used by support personnel only. So I’ll grant connect permission to my “admin_user” login.
grant connect on endpoint::[AdminsOnly] to [admin_user] ;
I’ve now configured SQL Server to listen on two different ports, the default 1433 for average users and 5023 for the admin_user login. I should be able to connect to that endpoint, right? Not so fast. Remember, TDS endpoints will listen for messages on their respective protocol whether that protocol is enabled or not. Similarly, a TCP endpoint will listen on its assigned port even if the TCP protocol hasn’t been enabled for that port. So the last thing we need to do is configure the TCP/IP network protocol to use port 1433 and 5023. We do that using SQL Server Configuration Manager.
Connecting to the new endpoint
We should now be able to connect to port 5023 using the admin_user login. To do this in Management Studio, specify the instance name, followed by a comma and the port number.
To verify which port each connection is using, use the sys.dm_exec_connections DMV.
select s.session_id, s.login_name, s.endpoint_id, c.net_transport, c.local_tcp_port from sys.dm_exec_sessions s join sys.dm_exec_connections c on s.session_id = c.session_id where c.net_transport = 'TCP'
What’s the [end]point?
Why would you want to do this? Good question. Suppose you’d like administrators to be able to connect from home. Obviously you don’t want to open your firewall for port 1433 and allow just anybody to connect. What you can do is create a new TDS endpoint for TCP on another port, and expose that through your firewall. Or, if you’re using NUMA, you can map TCP/IP ports to NUMA nodes. Using custom TDS endpoints, you can then affinitize connections to specific processors.