April 30, 2012 at 9:17 am
In my environment I have a sql server 2008 database on 64bit architecture. The production database accessed by users is using sql authentication.
Currently I can have one security login mapped to one database user which can log into the database multiple time simultaneously. I have a need to restrict this ability.
Can I do so by specific security logins or database users? If so where can I set this feature?
If it isnt possible to do this by the security login or database user can it be set at the database level?
April 30, 2012 at 10:15 am
It would be a lot of custom coding, but you may be able to achieve it using a Server Logon Trigger, depending on exactly what behavior you're trying to restrict. If your requirement is strictly at the Database Level then you may be out of luck. There is no "logon" event that occurs at the database-level. If you just want to limit each Server Login to one connection, then a Logon Trigger can help.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
April 30, 2012 at 10:28 am
Would this be the code to use?
USE master;
GO
CREATE LOGIN login_test WITH PASSWORD = '3KHJ6dhx(0xVYsdf' MUST_CHANGE,
CHECK_EXPIRATION = ON;
GO
GRANT VIEW SERVER STATE TO login_test;
GO
CREATE TRIGGER connection_limit_trigger
ON ALL SERVER WITH EXECUTE AS 'login_test'
FOR LOGON
AS
BEGIN
IF ORIGINAL_LOGIN()= 'login_test' AND
(SELECT COUNT(*) FROM sys.dm_exec_sessions
WHERE is_user_process = 1 AND
original_login_name = 'login_test') > 3
ROLLBACK;
END;
April 30, 2012 at 11:57 am
That looks like the gist of it, but I am not sure you need to grant anyone VIEW SERVER STATE...all members of public are able to view their own sessions in sys.dm_exec_sessions, so I am not sure you need to use sys.dm_exec_sessions.
You'll need to carry some metadata somewhere to list the logins that get kicked out when they exceed the max number of sessions, whether that be in a table in a utility database or hardcoded into the trigger. At the end of the day though, this is a custom feature of the instance so make sure you full document it so it can be properly maintained. Compiling a bad logon trigger can have a major, negative effect on the instance.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
April 30, 2012 at 8:33 pm
If I need to have this trigger take effect on 4 logins would I just add the additional logins as such below.
USE master;
GO
CREATE TRIGGER connection_limit_trigger
ON ALL SERVER WITH EXECUTE AS 'login_test'
FOR LOGON
AS
BEGIN
IF ORIGINAL_LOGIN()= 'login_test' OR 'login_test2' OR 'login_test3' OR 'login_test4'
(SELECT COUNT(*) FROM sys.dm_exec_sessions
WHERE is_user_process = 1 AND
original_login_name = 'login_test') > 3
ROLLBACK;
END;
April 30, 2012 at 9:24 pm
You could keep a list of logins hardcoded in the trigger as the example shows, or as I said you would need to keep them in a separate table. Having them in a separate table would allow you to manage the list of logins without recompiling the trigger, but it could turn into a lot more code depending on how many properties you wanted to track in the table, and test for. Whatever you decide, keep the trigger as lightweight as possible.
The code sample in the BOL article is actually poorly put together in my opinion. I would setup a login to be used only to execute the trigger. The BOL example tests for login_test in the trigger itself, which does not make sense to me. Try it this way:
USE master;
GO
-- no one should ever use this login to actually logonto the server. it only exists for purposes of
-- executing the login trigger
CREATE LOGIN logon_trigger_login WITH PASSWORD = '3KHJ6dhx(0xVYsdf' MUST_CHANGE, CHECK_EXPIRATION = ON;
GO
GRANT VIEW SERVER STATE TO logon_trigger_login;
GO
-- create the logon trigger
CREATE TRIGGER connection_limit_trigger ON ALL SERVER
WITH EXECUTE AS 'logon_trigger_login'
FOR LOGON
AS
BEGIN
-- the list of logins to restrict
IF ORIGINAL_LOGIN() in ('login_test', 'login_test2', 'login_test3', 'login_test4')
AND (SELECT COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = ORIGINAL_LOGIN() ) > 2
BEGIN
ROLLBACK
END
END;
GO
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
May 1, 2012 at 1:16 am
I agree with opc.three and would recommend to create a table for logins that you are going to restrict (or any other custom operation in future) for user. Small tweaking in the code though…
SELECT COUNT(original_login_name) --COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = ORIGINAL_LOGIN() ) > 2
May 1, 2012 at 8:19 am
Dev (5/1/2012)
I agree with opc.three and would recommend to create a table for logins that you are going to restrict (or any other custom operation in future) for user. Small tweaking in the code though…
SELECT COUNT(original_login_name) --COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = ORIGINAL_LOGIN() ) > 2
Please do tell...why would you choose COUNT(original_login_name) over COUNT(*) ?
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
May 1, 2012 at 12:03 pm
How would I tie back a table such as the one below to the trigger?
USE GK50LIVE;
GO
SET NOCOUNT ON;
USE GK50LIVE
go
-- Create LIMITEDLOGINS Table
CREATE TABLE dbo.LimitedLogins
(
Id INT IDENTITY(100,1) PRIMARY KEY
,Login_Name VARCHAR (50) NOT NULL
,LOGIN_ID VARCHAR (50) NOT NULL
,NUM_ALLOWED TINYINT NOT NULL
,Date_Added Date NULL
);
--Add values to the LimitedLogins Table
USE GK50LIVE
go
INSERT INTO LimitedLogins
(Login_Name , LOGIN_ID, NUM_ALLOWED)
VALUES
('James Smith', 'jsmith','1')
,('Joe Kim', 'jkim','1')
,('Gary Harpogian', 'gharpogian','1');
May 1, 2012 at 12:19 pm
You would need to make sure logon_trigger_login can SELECT from the table:
USE GK50LIVE;
GO
CREATE USER [logon_trigger_login] FROM LOGIN [logon_trigger_login] WITH DEFAULT_SCHEMA = [dbo];
GO
GRANT SELECT ON dbo.LimitedLogins TO logon_trigger_login;
GO
Then you could modify your trigger like this:
USE master
GO
CREATE TRIGGER connection_limit_trigger ON ALL SERVER
WITH EXECUTE AS 'logon_trigger_login'
FOR LOGON
AS
BEGIN
-- the list of logins to restrict
IF (
SELECT NUM_ALLOWED
FROM GK50LIVE.dbo.LimitedLogins
WHERE LOGIN_ID = ORIGINAL_LOGIN()
) < (
SELECT COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = ORIGINAL_LOGIN()
)
BEGIN
ROLLBACK
END
END;
GO
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
May 1, 2012 at 12:21 pm
PS I would recommend making LOGIN_ID a SYSNAME and making it the unique clustered index of dbo.LimitedLogins.
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
May 1, 2012 at 12:25 pm
PPS I would also make NUM_ALLOWED an INT to match the data type that COUNT() returns.
And one other perfromance bump might be to capture the ORIGINAL_LOGIN() in a variable, instead of calling it twice, like so:
USE master
GO
CREATE TRIGGER connection_limit_trigger ON ALL SERVER
WITH EXECUTE AS 'logon_trigger_login'
FOR LOGON
AS
BEGIN
DECLARE @original_login SYSNAME = ORIGINAL_LOGIN();
-- the list of logins to restrict
IF (
SELECT NUM_ALLOWED
FROM GK50LIVE.dbo.LimitedLogins
WHERE LOGIN_ID = @original_login
) < (
SELECT COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = @original_login
)
BEGIN
ROLLBACK
END
END;
GO
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
May 1, 2012 at 3:42 pm
thanks OPC I'm going to put this on my test server now. I'll let you know how it turns out.
by the way why do you put the () after ORIGINAL_LOGIN() as if its a function?
May 1, 2012 at 3:48 pm
kwoznica (5/1/2012)
thanks OPC I'm going to put this on my test server now. I'll let you know how it turns out.
I tested it locally on a 2008R2 instance. Please post back your findings. Thanks.
by the way why do you put the () after ORIGINAL_LOGIN() as if its a function?
I have to...because it is a function. ORIGINAL_LOGIN (Transact-SQL)
This works:
SELECT ORIGINAL_LOGIN()
This throws an exception:
SELECT ORIGINAL_LOGIN
[font="Courier New"]Msg 207, Level 16, State 1, Line 1
Invalid column name 'ORIGINAL_LOGIN'.[/font]
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
November 23, 2012 at 2:48 pm
OPC,
How could I expand on this so that if a login is not in the login table then the login is allowed. Right now if a login is not in that particular table then the login is denied.
I imagine I would need to add onto the below code
Use master
go
-- create the logon trigger
CREATE TRIGGER connection_limit_trigger ON ALL SERVER
WITH EXECUTE AS 'logon_trigger_login'
FOR LOGON
AS
BEGIN
-- the list of logins to restrict
IF (
SELECT NUM_ALLOWED
FROM GK50LIVE.dbo.LimitedLogins
WHERE LOGIN_ID = ORIGINAL_LOGIN()
) < (
SELECT COUNT(*)
FROM sys.dm_exec_sessions
WHERE is_user_process = 1
AND original_login_name = ORIGINAL_LOGIN()
)
BEGIN
ROLLBACK
END
END;
GO
something like this....
ELSE
COMMIT
END
I couldn't find any ways to allow exceptions in BOL. When I put the commit Else....Commit statement in I receive an error.
Your suggestions are welcomed. thanks.
Viewing 15 posts - 1 through 15 (of 23 total)
You must be logged in to reply to this topic. Login to reply