DENY Server Permissions (Transact-SQL)
Denies permissions on a server.
Syntax
DENY permission [ ,...n ]
TO <grantee_principal> [ ,...n ]
[ CASCADE ]
[ AS <grantor_principal> ]
<grantee_principal> ::=SQL_Server_login
| SQL_Server_login_mapped_to_Windows_login
| SQL_Server_login_mapped_to_Windows_group
| SQL_Server_login_mapped_to_certificate
| SQL_Server_login_mapped_to_asymmetric_key<grantor_principal> ::=SQL_Server_login
| SQL_Server_login_mapped_to_Windows_login
| SQL_Server_login_mapped_to_Windows_group
| SQL_Server_login_mapped_to_certificate
| SQL_Server_login_mapped_to_asymmetric_key
Arguments
permission
Specifies a permission that can be denied on a server. For a list of the permissions, see the Remarks section later in this topic.CASCADE
Indicates that the permission being denied is also denied to other principals to which it has been granted by this principal.TO <server_principal>
Specifies the principal to which the permission is denied.AS <grantor_principal>
Specifies the principal from which the principal executing this query derives its right to deny the permission.SQL_Server_login
Specifies a SQL Server login.SQL_Server_login_mapped_to_Windows_login
Specifies a SQL Server login mapped to a Windows login.SQL_Server_login_mapped_to_Windows_group
Specifies a SQL Server login mapped to a Windows group.SQL_Server_login_mapped_to_certificate
Specifies a SQL Server login mapped to a certificate.SQL_Server_login_mapped_to_asymmetric_key
Specifies a SQL Server login mapped to an asymmetric key.
Remarks
Permissions at the server scope can be denied only when the current database is master.
Information about server permissions is visible in the sys.server_permissions catalog view, and information about server principals is visible in the sys.server_principals catalog view. Information about membership of server roles is visible in the sys.server_role_members catalog view.
A server is the highest level of the permissions hierarchy. The most specific and limited permissions that can be denies on a server are listed in the following table.
Server permission |
Implied by server permission |
---|---|
ADMINISTER BULK OPERATIONS |
CONTROL SERVER |
ALTER ANY CONNECTION |
CONTROL SERVER |
ALTER ANY CREDENTIAL |
CONTROL SERVER |
ALTER ANY DATABASE |
CONTROL SERVER |
ALTER ANY ENDPOINT |
CONTROL SERVER |
ALTER ANY EVENT NOTIFICATION |
CONTROL SERVER |
ALTER ANY LINKED SERVER |
CONTROL SERVER |
ALTER ANY LOGIN |
CONTROL SERVER |
ALTER ANY SERVER AUDIT |
CONTROL SERVER |
ALTER RESOURCES |
CONTROL SERVER |
ALTER SERVER STATE |
CONTROL SERVER |
ALTER SETTINGS |
CONTROL SERVER |
ALTER TRACE |
CONTROL SERVER |
AUTHENTICATE SERVER |
CONTROL SERVER |
CONNECT SQL |
CONTROL SERVER |
CONTROL SERVER |
CONTROL SERVER |
CREATE ANY DATABASE |
ALTER ANY DATABASE |
CREATE DDL EVENT NOTIFICATION |
ALTER ANY EVENT NOTIFICATION |
CREATE ENDPOINT |
ALTER ANY ENDPOINT |
CREATE TRACE EVENT NOTIFICATION |
ALTER ANY EVENT NOTIFICATION |
EXTERNAL ACCESS ASSEMBLY |
CONTROL SERVER |
SHUTDOWN |
CONTROL SERVER |
UNSAFE ASSEMBLY |
CONTROL SERVER |
VIEW ANY DATABASE |
VIEW ANY DEFINITION |
VIEW ANY DEFINITION |
CONTROL SERVER |
VIEW SERVER STATE |
ALTER SERVER STATE |
Permissions
Requires CONTROL SERVER permission or ownership of the securable. If you use the AS clause, the specified principal must own the securable on which permissions are being denied.
Examples
A. Denying CONNECT SQL permission to a SQL Server login and principals to which the login has regranted it
The following example denies CONNECT SQL permission to the SQL Server login Annika and to the principals to which she has granted the permission.
USE master;
DENY CONNECT SQL TO Annika CASCADE;
GO
B. Denying CREATE ENDPOINT permission to a SQL Server login using the AS option
The following example denies CREATE ENDPOINT permission to the user ArifS. The example uses the AS option to specify MandarP as the principal from which the executing principal derives the authority to do so.
USE master;
DENY CREATE ENDPOINT TO ArifS AS MandarP;
GO
See Also