sqlserver2008r2数据库使用触发器对sa及其他数据库账号访问进行IP限制

时间:2022-04-24 18:51:50

一、只允许指定IP访问数据库

创建测试账号
CREATE LOGIN testuser WITH PASSWORD = '123'
GO


CREATE TRIGGER [tr_connection_limit]
ON ALL SERVER WITH EXECUTE AS 'sa'
FOR LOGON
AS
BEGIN


--限制test这个帐号的连接
IF ORIGINAL_LOGIN()= 'test'
--允许test在本机和下面的IP登录
AND
(SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)'))
NOT IN('<local machine>','192.168.50.145','192.168.8.138')
     ROLLBACK;
END;


===========================================================================================


登录信息查询
SELECT 
a.[session_id],a.[login_time],a.[host_name],
a.[original_login_name],b.[client_net_address]
FROM MASTER.sys.dm_exec_sessions a 
INNER JOIN MASTER.sys.dm_exec_connections b 
ON a.session_id=b.session_id


===========================================================================================


二、限制角色只能运行指定IP访问



--创建测试数据库
USE MASTER
GO
CREATE DATABASE Logon_DB


--创建IP过滤表
USE Logon_DB
GO
CREATE TABLE dbo.ValidIP ( 
    IP NVARCHAR(15), 
    CONSTRAINT PK_ValidIP PRIMARY KEY CLUSTERED(IP) 
); 




--插入过滤IP
USE Logon_DB
GO
INSERT INTO dbo.ValidIP(IP) VALUES('<local machine>');
INSERT INTO dbo.ValidIP(IP) VALUES('192.168.8.138');
INSERT INTO dbo.ValidIP(IP) VALUES('192.168.8.16');


--创建登录触发器

CREATE TRIGGER [tr_logon_CheckIP] 
ON ALL SERVER 
FOR LOGON 
AS 
BEGIN 
    IF IS_SRVROLEMEMBER('sysadmin') = 1 
    BEGIN 
        DECLARE @IP NVARCHAR(15); 
        SET @IP = (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)')); 
        IF NOT EXISTS(SELECT IP FROM [Logon_DB].[dbo].[ValidIP] WHERE IP = @IP) 
        ROLLBACK;
    END;
END;


这次我们在IP为:192.168.50.145的机器上进行测试,这个IP之前是允许使用rone4acc帐号登陆的(tr_connection_limit),这次使用sa这个帐号登陆,返回了Figure3的错误信息,这是因为它违反了登陆触发器tr_logon_CheckIP的规则。在192.168.8.16通过sa登录成功,说明限制生效了


三、登陆名与有效IP对应表

USE Logon_DB
GO
CREATE TABLE [dbo].[ValidLogOn](
    [Id] INT IDENTITY(1,1) NOT NULL,
    [LoginName] [sysname] NOT NULL,
    [ValidIP] [nvarchar](15) NOT NULL,
    CONSTRAINT [PK_ValidLogOn] PRIMARY KEY CLUSTERED ([Id])
 )
--创建唯一约束索引
CREATE UNIQUE NONCLUSTERED INDEX [IX_ValidLogOn_LV] ON [dbo].[ValidLogOn] 
(
    [LoginName] ASC,
    [ValidIP] ASC
)
 --插入测试数据
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'mssql2\administrator', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'127.0.0.1')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'localhost')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'192.168.50.145')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'rone4acc', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'rone4acc', N'192.168.8.16')


--创建登录触发器


CREATE TRIGGER [tr_logon_CheckLogOn]
ON ALL SERVER WITH EXECUTE AS 'sa'
FOR LOGON
AS
BEGIN
    DECLARE @LoginName sysname
    DECLARE @IP NVARCHAR(15)
    SET @LoginName = ORIGINAL_LOGIN();
    SET @IP = (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)')); 
    --判断登录名和IP
    IF NOT EXISTS(SELECT [ValidIP] FROM [Logon_DB].[dbo].[ValidLogOn] WHERE [LoginName] = @LoginName AND [ValidIP] = @IP) 
        ROLLBACK;
END;


用户登陆名与IP对应关系表[ValidLogOn],有几点需要注意的,mssql2\administrator这个是Windows 身份验证中操作系统的帐号,你需要根据你的实际情况进行修改;IP当中你则需要注意<local machine>和127.0.0.1这些特殊的地址,我个人还是建议在这个表中加入这些信息的。


实用举例:

sqlserver2008r2数据库使用触发器对sa及其他数据库账号访问进行IP限制

只允许指定IP访问
创建测试账号
CREATE LOGIN test WITH PASSWORD = '123'
GO


--创建测试数据库
USE MASTER
GO
CREATE DATABASE Logon_DB


USE Logon_DB
GO
CREATE TABLE [dbo].[ValidLogOn](
    [Id] INT IDENTITY(1,1) NOT NULL,
    [LoginName] [sysname] NOT NULL,
    [ValidIP] [nvarchar](15) NOT NULL,
    CONSTRAINT [PK_ValidLogOn] PRIMARY KEY CLUSTERED ([Id])
 )


--创建唯一约束索引
CREATE UNIQUE NONCLUSTERED INDEX [IX_ValidLogOn_LV] ON [dbo].[ValidLogOn] 
(
    [LoginName] ASC,
    [ValidIP] ASC
)
 --插入测试数据
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'mssql2\administrator', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'127.0.0.1')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'localhost')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'192.168.50.145')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'192.168.8.11')

INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'test', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'test', N'192.168.8.16')


--创建登录触发器

CREATE TRIGGER [tr_logon_CheckLogOn]
ON ALL SERVER WITH EXECUTE AS 'sa'
FOR LOGON
AS
BEGIN
    DECLARE @LoginName sysname
    DECLARE @IP NVARCHAR(15)
    SET @LoginName = ORIGINAL_LOGIN();
    SET @IP = (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)')); 
    --判断登录名和IP
    IF NOT EXISTS(SELECT [ValidIP] FROM [Logon_DB].[dbo].[ValidLogOn] WHERE [LoginName] = @LoginName AND [ValidIP] = @IP) 
        ROLLBACK;
END;


远端云服务器的配置:

列出数据库孤立用户
exec  sp_change_users_login 'report'
将用户关联起来
exec sp_change_users_login 'UPDATE_ONE','read','read'


只允许指定IP访问


--创建测试数据库
USE MASTER
GO
CREATE DATABASE Logon_DB


USE Logon_DB
GO
CREATE TABLE [dbo].[ValidLogOn](
    [Id] INT IDENTITY(1,1) NOT NULL,
    [LoginName] [sysname] NOT NULL,
    [ValidIP] [nvarchar](15) NOT NULL,
    CONSTRAINT [PK_ValidLogOn] PRIMARY KEY CLUSTERED ([Id])
 )


--创建唯一约束索引
CREATE UNIQUE NONCLUSTERED INDEX [IX_ValidLogOn_LV] ON [dbo].[ValidLogOn] 
(
    [LoginName] ASC,
    [ValidIP] ASC
)
 --插入测试数据
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'mssql\administrator', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'<local machine>')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'127.0.0.1')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'localhost')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'sa', N'192.168.1.4')
INSERT [dbo].[ValidLogOn] ([LoginName], [ValidIP]) VALUES (N'read', N'2.2.2.2')


--创建登录触发器


CREATE TRIGGER [tr_logon_CheckLogOn]
ON ALL SERVER WITH EXECUTE AS 'sa'
FOR LOGON
AS
BEGIN
    DECLARE @LoginName sysname
    DECLARE @IP NVARCHAR(15)
    SET @LoginName = ORIGINAL_LOGIN();
    SET @IP = (SELECT EVENTDATA().value('(/EVENT_INSTANCE/ClientHost)[1]', 'NVARCHAR(15)')); 
    --判断登录名和IP
    IF NOT EXISTS(SELECT [ValidIP] FROM [Logon_DB].[dbo].[ValidLogOn] WHERE [LoginName] = @LoginName AND [ValidIP] = @IP) 
        ROLLBACK;
END;