CREATE login SysadminLogin WITH password ='password123~'
GO
CREATE login controlserverlogin WITH password ='password123~'
GO
EXEC sp_addsrvrolemember 'SysadminLogin','sysadmin'
GO
GRANT control server TO controlserverlogin
Now log in to the server using the controlserverlogin and you can access all the databases and perform any actions. Let us see what will happen on explicitly denying the server level permission.
DENY VIEW ANY DATABASE TO controlserverlogin
GO
DENY VIEW ANY DATABASE TO sysadminlogin
GO
Now log in to the server using both the login. You can notice that, in the session that connected with the controlserverlogin will list only Master and Tempdb databases while the session connected with sysadminlogin will list all available databases.
/* Fortunately this will fail */
EXEC sp_addsrvrolemember 'controlserverlogin','sysadmin';
GO
/* Unfortunately this will work even if sa account is disabled*/
EXECUTE AS LOGIN = 'sa';
GO
EXEC sp_addsrvrolemember 'controlserverlogin','sysadmin';
GO
REVERT;
Below script list the logins with sysadmin role membership and control server permission.
/* List login with membership to Sysadmin server role and Control Server right*/
SELECT p.[name] [Login], 'sysadmin Role Member' [Access] ,p.type_desc AS loginTypeFROM sys.server_principals p
JOIN sys.server_role_members RM
ON p.principal_id = rm.member_principal_id
JOIN sys.server_principals rp
ON rm.role_principal_id = rp.principal_id WHERE rp.NAME = 'sysadmin' UNION ALL SELECT p.[name], 'Control Server Right' ,p.type_desc AS loginTypeFROM sys.server_principals p
JOIN sys.server_permissions Sp
ON p.principal_id = sp.grantee_principal_id WHERE sp.class = 100
AND sp.[type] = 'CL'
AND state = 'G' GOBelow script will help to list the explicitly denied server level permission for logins which have control server permission.
/* List Explicitly denied permission for the login that has control server permission*/
SELECT CSL.*,sp.permission_name [Explicitly Denied Permission] FROM sys.server_permissions SP INNER JOIN (SELECT p.principal_id ,p.[name], p.type_desc AS loginTypeFROM sys.server_principals p
JOIN sys.server_permissions Sp
ON p.principal_id = sp.grantee_principal_id WHERE sp.class = 100
AND sp.[type] = 'CL'
AND state = 'G' ) CSL ON CSL.principal_id = sp.grantee_principal_id
WHERE state ='D'
If you liked this post, do like my page on FaceBook at http://www.facebook.com/practicalSqlDba