Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Blocking Users by IP


Blocking Users by IP

Author
Message
Dugi
Dugi
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1318 Visits: 3511
Vampire (3/20/2009)
Thanks for the post Brian.

However, I am stuck with few issues. Hope you could throw some light on them and clarify .

1. I executed the Step to insert <local machine< into ValidIP table and still i am not able to connect from my local machine, bcoz of trigger execution.

2. I changed the trigger to capture the @IP value in troubleshooting the above said issue. Below is my code:

CREATE TRIGGER tr_logon_CheckIP
ON ALL SERVER
FOR LOGON
AS
DECLARE @IP NVARCHAR(15),@SqlCmd NVARCHAR(100);
SET @IP = (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)'));
INSERT INTO dbo.ValidIP (IP) VALUES (@IP);
BEGIN
IF IS_SRVROLEMEMBER('sysadmin') = 1
BEGIN

IF NOT EXISTS(SELECT IP FROM DBAWork.dbo.ValidIP WHERE IP = @IP)
ROLLBACK;
END;
END;
GO

But this is not inserting any @IP value in the ValidIP table. Does triggers have constraint of not inserting any value into the tables in execution.

3. If @IP value can't be inserted into the table ,as desired, is there any other way to see the output of EventData() or IP later.

Thanks in advance!!
Vampire



HeheHehe Your code here is like a virus for SQL Server ( never never can connect to SQL )

You should have the DAC ( Dedicated Admin Connection) available or active before working with this trigger. Then connect to SQL server with DAC like Brian said in the article and be sure that the SQL Browser is running ...so you will connect to the Server on master DB and you should disable or delete the trigger!

w00tw00tw00tw00tw00tw00tw00t

============================================================
SELECT YOUR PROBLEM FROM SSC.com WHERE PROBLEM DESCRIPTION =
http://www.sqlservercentral.com/articles/Best+Practices/61537/
K. Brian Kelley
K. Brian Kelley
Keeper of the Duck
Keeper of the Duck (6.8K reputation)

Group: Moderators
Points: 6826 Visits: 1917
Vampire (3/20/2009)
this is not inserting any @IP value in the ValidIP table. Does triggers have constraint of not inserting any value into the tables in execution.

3. If @IP value can't be inserted into the table ,as desired, is there any other way to see the output of EventData() or IP later.

Thanks in advance!!
Vampire


The trigger is still, for accessing other objects, executing in the context of the login that's coming in. That means all logins need INSERT rights agaisnt the ValidIP table. If that's in a separate database, they need to have access to said database.

K. Brian Kelley
@‌kbriankelley
Lonely Rogue
Lonely Rogue
SSC-Enthusiastic
SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)

Group: General Forum Members
Points: 193 Visits: 436
Brian,

I guess I dig grave for my own SQL Server Crying
I have executed this trigger on a SQL Instance .\Inst1 and now it is not allowing me to connect from my local machine. However, let me state few facts:

1. I have inserted <local machine>, My computer Name and my IP address as values into ValidIP table, and now when i connect to the Instance from my computer(the instance on which trigger is created, also resides on my computer), the trigger executes. The login am using is a SysAdmin Acct.

2. Based on the above fact, my question is : This trigger allows only connections from the computers listed in ValidIP table..right? If yes, though I inserted my computer name in the ValidIP table..why is trigger executing?

3. What does statement return : (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)'));
Returns value as "<local machine>"; if connected from my computer OR
IP address of Local machine or computer from which connection origins??

4. I have used your tip of DAC to break this trigger barrier..it seems my DAC is also failing. I am pasting the Error output of my DAC connection. My question here is..does SQL instances support DAC Or is DAC available only for default instances.


C:\Documents and Settings\vampire>sqlcmd -S ADMIN:.\inst1 -A -dMaster
HResult 0xFFFFFFFF, Level 16, State 1
SQL Network Interfaces: An error occurred while obtaining the dedicated administrator
connection (DAC) port. Make sure that SQL Browser is running, or check the
error log for the port number [xFFFFFFFF].
Sqlcmd: Error: Microsoft SQL Native Client : An error has occurred while establishing a connection to the server. When connecting to SQL Server 2005, this failure may be caused by the fact that under the default settings SQL Server does not allow remote connections..
Sqlcmd: Error: Microsoft SQL Native Client : Login timeout expired.


If DAC is available for SQL Instances also..so please based on the above output..can you suggest me some work around.

Thanks
Vampire

--In 'thoughts'...
Lonely Rogue
Dugi
Dugi
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1318 Visits: 3511
Vampire (3/24/2009)
Brian,

I guess I dig grave for my own SQL Server Crying
I have executed this trigger on a SQL Instance .\Inst1 and now it is not allowing me to connect from my local machine. However, let me state few facts:

1. I have inserted <local machine>, My computer Name and my IP address as values into ValidIP table, and now when i connect to the Instance from my computer(the instance on which trigger is created, also resides on my computer), the trigger executes. The login am using is a SysAdmin Acct.

2. Based on the above fact, my question is : This trigger allows only connections from the computers listed in ValidIP table..right? If yes, though I inserted my computer name in the ValidIP table..why is trigger executing?

3. What does statement return : (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)'));
Returns value as "<local machine>"; if connected from my computer OR
IP address of Local machine or computer from which connection origins??

4. I have used your tip of DAC to break this trigger barrier..it seems my DAC is also failing. I am pasting the Error output of my DAC connection. My question here is..does SQL instances support DAC Or is DAC available only for default instances.


C:\Documents and Settings\vampire>sqlcmd -S ADMIN:.\inst1 -A -dMaster
HResult 0xFFFFFFFF, Level 16, State 1
SQL Network Interfaces: An error occurred while obtaining the dedicated administrator
connection (DAC) port. Make sure that SQL Browser is running, or check the
error log for the port number [xFFFFFFFF].
Sqlcmd: Error: Microsoft SQL Native Client : An error has occurred while establishing a connection to the server. When connecting to SQL Server 2005, this failure may be caused by the fact that under the default settings SQL Server does not allow remote connections..
Sqlcmd: Error: Microsoft SQL Native Client : Login timeout expired.


If DAC is available for SQL Instances also..so please based on the above output..can you suggest me some work around.

Thanks
Vampire


I told you in my post above that you should be sure that the SQL Browser is running ... also the DAC is only available from a client on the server!!!

Or you can do something in sqlcmd like this:

sqlcmd –A –d master

A - it will use the DAC connection
d - connection to the master DB

then you can kill or drop the trigger!!

w00t

============================================================
SELECT YOUR PROBLEM FROM SSC.com WHERE PROBLEM DESCRIPTION =
http://www.sqlservercentral.com/articles/Best+Practices/61537/
Lonely Rogue
Lonely Rogue
SSC-Enthusiastic
SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)SSC-Enthusiastic (193 reputation)

Group: General Forum Members
Points: 193 Visits: 436
@Dugi

Thanks for your tip..it worked. Am now able to login. However,I have my SQL Browser running earlier too...

I earlier used this command to connect to DAC as Admin..but couldn't
sqlcmd -S ADMIN:.\inst1 -A -dMaster


Dugi/Brian:

Could either of you please let me know the difference between these two along with answers to other questions ( posted in my previous reply, as this reply of yours answers my 4th question only).

Thanks a lot!!
Vampire

--In 'thoughts'...
Lonely Rogue
K. Brian Kelley
K. Brian Kelley
Keeper of the Duck
Keeper of the Duck (6.8K reputation)

Group: Moderators
Points: 6826 Visits: 1917
Vampire (3/24/2009)
@Dugi

Thanks for your tip..it worked. Am now able to login. However,I have my SQL Browser running earlier too...

I earlier used this command to connect to DAC as Admin..but couldn't
sqlcmd -S ADMIN:.\inst1 -A -dMaster


Dugi/Brian:

Could either of you please let me know the difference between these two along with answers to other questions ( posted in my previous reply, as this reply of yours answers my 4th question only).

Thanks a lot!!
Vampire


That means you connected to the default instance, not a named instance if you followed Dugi's example and left off -S.

K. Brian Kelley
@‌kbriankelley
marina.carrasco
marina.carrasco
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 8
The idea is very nice, but I can´t make this work.
The problem is that value() does not work inside logon triggers. In fact, it seems xqueries don´t work inside logon triggers.
I don´t have any trouble using them inside DDL triggers.
What I can do in a logon trigger is inserting the result of EVENTDATA() into a xml column. That is not what I need.
If anyone has an explanation or a solution for this, I would appreciate it very much.
marina.carrasco
marina.carrasco
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 8
I will answer my own question. ARITHABORT must be on in order that xqueries such as VALUE() work.

So I began my logon trigger code with:

set arithabort on

and it worked nicely.

Thanxs Smile
Eric Hobbs
Eric Hobbs
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 48
Hopefully I'm not being dim here, but this seems like a lot of effort and increased overhead on your SQL database, for something that can be handled much more efficiently at the transport layer. In general, if you want to ensure that connections to a server are only made by a specific IP address, then you set the network card up to only accept connections from a specific IP, address, or you use a firewall, since this is more robust at detecting IP spoofing ect... by all means, limit the access of the security principle, but creating a trigger for each time a connection is made seems like a really bad idea.w00t
grahamc
grahamc
Mr or Mrs. 500
Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)Mr or Mrs. 500 (578 reputation)

Group: General Forum Members
Points: 578 Visits: 1039
In the past I have used IP restriction on the infrastructure side of things to get this done. Restricting PROD access to application, software management and SQL machines. But this is a nice way of doing it all in SQL.
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