DENY Object Permissions (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance
Denies permissions on a member of the OBJECT class of securables. These are the members of the OBJECT class: tables, views, table-valued functions, stored procedures, extended stored procedures, scalar functions, aggregate functions, service queues, and synonyms.
Transact-SQL syntax conventions
Syntax
DENY <permission> [ ,...n ] ON
[ OBJECT :: ][ schema_name ]. object_name [ ( column [ ,...n ] ) ]
TO <database_principal> [ ,...n ]
[ CASCADE ]
[ AS <database_principal> ]
<permission> ::=
ALL [ PRIVILEGES ] | permission [ ( column [ ,...n ] ) ]
<database_principal> ::=
Database_user
| Database_role
| Application_role
| Database_user_mapped_to_Windows_User
| Database_user_mapped_to_Windows_Group
| Database_user_mapped_to_certificate
| Database_user_mapped_to_asymmetric_key
| Database_user_with_no_login
Arguments
permission
Specifies a permission that can be denied on a schema-contained object. For a list of the permissions, see the Remarks section later in this topic.
ALL
Denying ALL does not deny all possible permissions. Denying ALL is equivalent to denying all ANSI-92 permissions applicable to the specified object. The meaning of ALL varies as follows:
- Scalar function permissions: EXECUTE, REFERENCES.
- Table-valued function permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.
- Stored Procedure permissions: EXECUTE.
- Table permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.
- View permissions: DELETE, INSERT, REFERENCES, SELECT, UPDATE.
PRIVILEGES
Included for ANSI-92 compliance. Does not change the behavior of ALL.
column
Specifies the name of a column in a table, view, or table-valued function on which the permission is being denied. The parentheses ( ) are required. Only SELECT, REFERENCES, and UPDATE permissions can be denied on a column. column can be specified in the permissions clause or after the securable name.
Caution
A table-level DENY does not take precedence over a column-level GRANT. This inconsistency in the permissions hierarchy has been preserved for backward compatibility. In SQL Server this behavior is different if the Server is configured to run with the Common Criteria Compliance Enabled Server Configuration. However, this should generally only be used with caution and not as a general practice.
ON [ OBJECT :: ] [ schema_name ] . object_name
Specifies the object on which the permission is being denied. The OBJECT phrase is optional if schema_name is specified. If the OBJECT phrase is used, the scope qualifier (::) is required. If schema_name is not specified, the default schema is used. If schema_name is specified, the schema scope qualifier (.) is required.
TO <database_principal>
Specifies the principal to which the permission is being denied.
CASCADE
Indicates that the permission being denied is also denied to other principals to which it has been granted by this principal.
AS <database_principal>
Specifies a principal from which the principal executing this query derives its right to deny the permission.
Database_user
Specifies a database user.
Database_role
Specifies a database role.
Application_role
Specifies an application role.
Database_user_mapped_to_Windows_User
Specifies a database user mapped to a Windows user.
Database_user_mapped_to_Windows_Group
Specifies a database user mapped to a Windows group.
Database_user_mapped_to_certificate
Specifies a database user mapped to a certificate.
Database_user_mapped_to_asymmetric_key
Specifies a database user mapped to an asymmetric key.
Database_user_with_no_login
Specifies a database user with no corresponding server-level principal.
Remarks
Information about objects is visible in various catalog views. For more information, see Object Catalog Views (Transact-SQL).
An object is a schema-level securable contained by the schema that is its parent in the permissions hierarchy. The most specific and limited permissions that can be denied on an object are listed in the following table, together with the more general permissions that include them by implication.
Object permission | Implied by object permission | Implied by schema permission |
---|---|---|
ALTER | CONTROL | ALTER |
CONTROL | CONTROL | CONTROL |
DELETE | CONTROL | DELETE |
EXECUTE | CONTROL | EXECUTE |
INSERT | CONTROL | INSERT |
RECEIVE | CONTROL | CONTROL |
REFERENCES | CONTROL | REFERENCES |
SELECT | RECEIVE | SELECT |
TAKE OWNERSHIP | CONTROL | CONTROL |
UPDATE | CONTROL | UPDATE |
VIEW CHANGE TRACKING | CONTROL | VIEW CHANGE TRACKING |
VIEW DEFINITION | CONTROL | VIEW DEFINITION |
Permissions
Requires CONTROL permission on the object.
If you use the AS clause, the specified principal must own the object on which permissions are being denied.
Examples
The following examples use the AdventureWorks database.
A. Denying SELECT permission on a table
The following example denies SELECT
permission to the user RosaQdM
on the table Person.Address
.
DENY SELECT ON OBJECT::Person.Address TO RosaQdM;
GO
B. Denying EXECUTE permission on a stored procedure
The following example denies EXECUTE
permission on the stored procedure HumanResources.uspUpdateEmployeeHireInfo
to an application role called Recruiting11
.
DENY EXECUTE ON OBJECT::HumanResources.uspUpdateEmployeeHireInfo
TO Recruiting11;
GO
C. Denying REFERENCES permission on a view with CASCADE
The following example denies REFERENCES
permission on the column BusinessEntityID
in the view HumanResources.vEmployee
to the user Wanida
with CASCADE
.
DENY REFERENCES (BusinessEntityID) ON OBJECT::HumanResources.vEmployee
TO Wanida CASCADE;
GO
See Also
GRANT Object Permissions (Transact-SQL)
REVOKE Object Permissions (Transact-SQL)
Object Catalog Views (Transact-SQL)
Permissions (Database Engine)
Principals (Database Engine)
Securables
sys.fn_builtin_permissions (Transact-SQL)
HAS_PERMS_BY_NAME (Transact-SQL)
sys.fn_my_permissions (Transact-SQL)