Permissions

Permissions (Database Engine)

 

Updated: March 24, 2016

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Every SQL Server securable has associated permissions that can be granted to a principal. Permissions in the Database Engine are managed at the server level assigned to logins and server roles, and at the database level assigned to database users and database roles. The model for SQL Database has the same system for the database permissions, but the server level permissions are not available. This topic contains the complete list of permissions. For a typical implementation of the permissions, see Getting Started with Database Engine Permissions.

SQL Server 2016 has 230 permissions. SQL Server 2014 has 219 permissions. SQL Server 2012 has 214 permissions. SQL Server 2008 R2 has 195 permissions. SQL Database, SQL Data Warehouse, and Analytics Platform System have fewer permissions because they expose only a portion of the database engine, though each have some permissions that do not apply to SQL Server. The following graphic shows the permissions and their relationships to each other. Some of the higher level permissions (such as CONTROL SERVER) are listed many times. In this topic, the poster is far to small to read. Download the Database Engine Permissions Poster from http://go.microsoft.com/fwlink/?LinkId=229142.

The following describes the general conventions that are followed for naming permissions:

  • CONTROL

    Confers ownership-like capabilities on the grantee. The grantee effectively has all defined permissions on the securable. A principal that has been granted CONTROL can also grant permissions on the securable. Because the SQL Server security model is hierarchical, CONTROL at a particular scope implicitly includes CONTROL on all the securables under that scope. For example, CONTROL on a database implies all permissions on the database, all permissions on all assemblies in the database, all permissions on all schemas in the database, and all permissions on objects within all schemas within the database.

  • ALTER

    Confers the ability to change the properties, except ownership, of a particular securable. When granted on a scope, ALTER also bestows the ability to alter, create, or drop any securable that is contained within that scope. For example, ALTER permission on a schema includes the ability to create, alter, and drop objects from the schema.

  • ALTER ANY <Server Securable>, where Server Securable can be any server securable.

    Confers the ability to create, alter, or drop individual instances of the Server Securable. For example, ALTER ANY LOGIN confers the ability to create, alter, or drop any login in the instance.

  • ALTER ANY <Database Securable>, where Database Securable can be any securable at the database level.

    Confers the ability to CREATE, ALTER, or DROP individual instances of the Database Securable. For example, ALTER ANY SCHEMA confers the ability to create, alter, or drop any schema in the database.

  • TAKE OWNERSHIP

    Enables the grantee to take ownership of the securable on which it is granted.

  • IMPERSONATE <Login>

    Enables the grantee to impersonate the login.

  • IMPERSONATE <User>

    Enables the grantee to impersonate the user.

  • CREATE <Server Securable>

    Confers to the grantee the ability to create the Server Securable.

  • CREATE <Database Securable>

    Confers to the grantee the ability to create the Database Securable.

  • CREATE <Schema-contained Securable>

    Confers the ability to create the schema-contained securable. However, ALTER permission on the schema is required to create the securable in a particular schema.

  • VIEW DEFINITION

    Enables the grantee to access metadata.

  • REFERENCES

    The REFERENCES permission on a table is needed to create a FOREIGN KEY constraint that references that table.

    The REFERENCES permission is needed on an object to create a FUNCTION or VIEW with the WITH SCHEMABINDING clause that references that object.

For a poster sized chart of all Database Engine permissions in pdf format, see http://go.microsoft.com/fwlink/?LinkId=229142.

The following table lists major classes of permissions and the kinds of securables to which they may be applied.

PermissionApplies to
ALTERAll classes of objects except TYPE.
CONTROLAll classes of objects: AGGREGATE,
APPLICATION ROLE,
ASSEMBLY,
ASYMMETRIC KEY,
AVAILABILITY GROUP,
CERTIFICATE,
CONTRACT,
CREDENTIALS, DATABASE,
DATABASE SCOPED CONFIGURATION, DEFAULT,
ENDPOINT,
FULLTEXT CATALOG,
FULLTEXT STOPLIST,
FUNCTION,
LOGIN,
MESSAGE TYPE,
PROCEDURE,
QUEUE,
REMOTE SERVICE BINDING,
ROLE,
ROUTE,
RULE,
SCHEMA,
SEARCH PROPERTY LIST,
SERVER,
SERVER ROLE,
SERVICE,
SYMMETRIC KEY,
SYNONYM,
TABLE,
TYPE, USER,
VIEW, and
XML SCHEMA COLLECTION
DELETEAll classes of objects except DATABASE SCOPED CONFIGURATION, and SERVER.
EXECUTECLR types, external scripts, procedures (Transact-SQL and CLR), scalar and aggregate functions (Transact-SQL and CLR), and synonyms
IMPERSONATELogins and users
INSERTSynonyms, tables and columns, views and columns. Permission can be granted at the database, schema, or object level.
RECEIVEService Broker queues
REFERENCESAGGREGATE,
ASSEMBLY,
ASYMMETRIC KEY,
CERTIFICATE,
CONTRACT,
DATABASE,
FULLTEXT CATALOG,
FULLTEXT STOPLIST,
FUNCTION,
MESSAGE TYPE,
PROCEDURE,
QUEUE,
RULE
,SCHEMA,
SEARCH PROPERTY LIST,
SEQUENCE OBJECT, SYMMETRIC KEY,
SYNONYM,
TABLE,
TYPE,
VIEW, and
XML SCHEMA COLLECTION
SELECTSynonyms, tables and columns, views and columns. Permission can be granted at the database, schema, or object level.
TAKE OWNERSHIPAll classes of objects except DATABASE SCOPED CONFIGURATION, LOGIN, SERVER, and USER.
UPDATESynonyms, tables and columns, views and columns. Permission can be granted at the database, schema, or object level.
VIEW CHANGE TRACKINGSchemas and tables
VIEW DEFINITIONAll classes of objects except DATABASE SCOPED CONFIGURATION, and SERVER.
System_CAPS_ICON_caution.jpg Caution


The default permissions that are granted to system objects at the time of setup are carefully evaluated against possible threats and need not be altered as part of hardening the SQL Server installation. Any changes to the permissions on the system objects could limit or break the functionality and could potentially leave your SQL Server installation in an unsupported state.

The following table provides a complete list of SQL Server permissions. SQL Database permissions are only available for base securables that are supported. Server level permissions cannot be granted in SQL Database, however in some cases database permissions are available instead.

Base securableGranular permissions on base securablePermission type codeSecurable that contains base securablePermission on container securable that implies granular permission on base securable
APPLICATION ROLEALTERALDATABASEALTER ANY APPLICATION ROLE
APPLICATION ROLECONTROLCLDATABASECONTROL
APPLICATION ROLEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
ASSEMBLYALTERALDATABASEALTER ANY ASSEMBLY
ASSEMBLYCONTROLCLDATABASECONTROL
ASSEMBLYREFERENCESRFDATABASEREFERENCES
ASSEMBLYTAKE OWNERSHIPTODATABASECONTROL
ASSEMBLYVIEW DEFINITIONVWDATABASEVIEW DEFINITION
ASYMMETRIC KEYALTERALDATABASEALTER ANY ASYMMETRIC KEY
ASYMMETRIC KEYCONTROLCLDATABASECONTROL
ASYMMETRIC KEYREFERENCESRFDATABASEREFERENCES
ASYMMETRIC KEYTAKE OWNERSHIPTODATABASECONTROL
ASYMMETRIC KEYVIEW DEFINITIONVWDATABASEVIEW DEFINITION
AVAILABILITY GROUPALTERALSERVERALTER ANY AVAILABILITY GROUP
AVAILABILITY GROUPCONTROLCLSERVERCONTROL SERVER
AVAILABILITY GROUPTAKE OWNERSHIPTOSERVERCONTROL SERVER
AVAILABILITY GROUPVIEW DEFINITIONVWSERVERVIEW ANY DEFINITION
CERTIFICATEALTERALDATABASEALTER ANY CERTIFICATE
CERTIFICATECONTROLCLDATABASECONTROL
CERTIFICATEREFERENCESRFDATABASEREFERENCES
CERTIFICATETAKE OWNERSHIPTODATABASECONTROL
CERTIFICATEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
CONTRACTALTERALDATABASEALTER ANY CONTRACT
CONTRACTCONTROLCLDATABASECONTROL
CONTRACTREFERENCESRFDATABASEREFERENCES
CONTRACTTAKE OWNERSHIPTODATABASECONTROL
CONTRACTVIEW DEFINITIONVWDATABASEVIEW DEFINITION
DATABASEALTERALSERVERALTER ANY DATABASE
DATABASEALTER ANY APPLICATION ROLEALARSERVERCONTROL SERVER
DATABASEALTER ANY ASSEMBLYALASSERVERCONTROL SERVER
DATABASEALTER ANY ASYMMETRIC KEYALAKSERVERCONTROL SERVER
DATABASEALTER ANY CERTIFICATEALCFSERVERCONTROL SERVER
DATABASEALTER ANY COLUMN ENCRYPTION KEYALCK

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERCONTROL SERVER
DATABASEALTER ANY COLUMN MASTER KEYALCM

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERCONTROL SERVER
DATABASEALTER ANY CONTRACTALSCSERVERCONTROL SERVER
DATABASEALTER ANY DATABASE AUDITALDASERVERALTER ANY SERVER AUDIT
DATABASEALTER ANY DATABASE DDL TRIGGERALTGSERVERCONTROL SERVER
DATABASEALTER ANY DATABASE EVENT NOTIFICATIONALEDSERVERALTER ANY EVENT NOTIFICATION
DATABASEALTER ANY DATABASE EVENT SESSIONAADS

Applies to SQL Database.
SERVERALTER ANY EVENT SESSION
DATABASEALTER ANY DATABASE SCOPED CONFIGURATIONALDC

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERCONTROL SERVER
DATABASEALTER ANY DATASPACEALDSSERVERCONTROL SERVER
DATABASEALTER ANY EXTERNAL DATA SOURCEAEDSSERVERCONTROL SERVER
DATABASEALTER ANY EXTERNAL FILE FORMATAEFFSERVERCONTROL SERVER
DATABASEALTER ANY FULLTEXT CATALOGALFTSERVERCONTROL SERVER
DATABASEALTER ANY MASKAAMK

Applies to SQL Server (SQL Server 2016 through current).
SERVERCONTROL SERVER
DATABASEALTER ANY MESSAGE TYPEALMTSERVERCONTROL SERVER
DATABASEALTER ANY REMOTE SERVICE BINDINGALSBSERVERCONTROL SERVER
DATABASEALTER ANY ROLEALRLSERVERCONTROL SERVER
DATABASEALTER ANY ROUTEALRTSERVERCONTROL SERVER
DATABASEALTER ANY SCHEMAALSMSERVERCONTROL SERVER
DATABASEALTER ANY SECURITY POLICYALSP

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERCONTROL SERVER
DATABASEALTER ANY SERVICEALSVSERVERCONTROL SERVER
DATABASEALTER ANY SYMMETRIC KEYALSKSERVERCONTROL SERVER
DATABASEALTER ANY USERALUSSERVERCONTROL SERVER
DATABASEAUTHENTICATEAUTHSERVERAUTHENTICATE SERVER
DATABASEBACKUP DATABASEBADBSERVERCONTROL SERVER
DATABASEBACKUP LOGBALOSERVERCONTROL SERVER
DATABASECHECKPOINTCPSERVERCONTROL SERVER
DATABASECONNECTCOSERVERCONTROL SERVER
DATABASECONNECT REPLICATIONCORPSERVERCONTROL SERVER
DATABASECONTROLCLSERVERCONTROL SERVER
DATABASECREATE AGGREGATECRAGSERVERCONTROL SERVER
DATABASECREATE ASSEMBLYCRASSERVERCONTROL SERVER
DATABASECREATE ASYMMETRIC KEYCRAKSERVERCONTROL SERVER
DATABASECREATE CERTIFICATECRCFSERVERCONTROL SERVER
DATABASECREATE CONTRACTCRSCSERVERCONTROL SERVER
DATABASECREATE DATABASECRDBSERVERCREATE ANY DATABASE
DATABASECREATE DATABASE DDL EVENT NOTIFICATIONCREDSERVERCREATE DDL EVENT NOTIFICATION
DATABASECREATE DEFAULTCRDFSERVERCONTROL SERVER
DATABASECREATE FULLTEXT CATALOGCRFTSERVERCONTROL SERVER
DATABASECREATE FUNCTIONCRFNSERVERCONTROL SERVER
DATABASECREATE MESSAGE TYPECRMTSERVERCONTROL SERVER
DATABASECREATE PROCEDURECRPRSERVERCONTROL SERVER
DATABASECREATE QUEUECRQUSERVERCONTROL SERVER
DATABASECREATE REMOTE SERVICE BINDINGCRSBSERVERCONTROL SERVER
DATABASECREATE ROLECRRLSERVERCONTROL SERVER
DATABASECREATE ROUTECRRTSERVERCONTROL SERVER
DATABASECREATE RULECRRUSERVERCONTROL SERVER
DATABASECREATE SCHEMACRSMSERVERCONTROL SERVER
DATABASECREATE SERVICECRSVSERVERCONTROL SERVER
DATABASECREATE SYMMETRIC KEYCRSKSERVERCONTROL SERVER
DATABASECREATE SYNONYMCRSNSERVERCONTROL SERVER
DATABASECREATE TABLECRTBSERVERCONTROL SERVER
DATABASECREATE TYPECRTYSERVERCONTROL SERVER
DATABASECREATE VIEWCRVWSERVERCONTROL SERVER
DATABASECREATE XML SCHEMA COLLECTIONCRXSSERVERCONTROL SERVER
DATABASEDELETEDLSERVERCONTROL SERVER
DATABASEEXECUTEEXSERVERCONTROL SERVER
DATABASEEXECUTE ANY EXTERNAL SCRIPTEAES

Applies to SQL Server (SQL Server 2016 through current).
SERVERCONTROL SERVER
DATABASEINSERTINSERVERCONTROL SERVER
DATABASEKILL DATABASE CONNECTIONKIDC

Only applies to SQL Database. Use ALTER ANY CONNECTION in SQL Server.
SERVERALTER ANY CONNECTION
DATABASEREFERENCESRFSERVERCONTROL SERVER
DATABASESELECTSLSERVERCONTROL SERVER
DATABASESHOWPLANSPLNSERVERALTER TRACE
DATABASESUBSCRIBE QUERY NOTIFICATIONSSUQNSERVERCONTROL SERVER
DATABASETAKE OWNERSHIPTOSERVERCONTROL SERVER
DATABASEUNMASKUMSK

Applies to SQL Server (SQL Server 2016 through current).
SERVERCONTROL SERVER
DATABASEUPDATEUPSERVERCONTROL SERVER
DATABASEVIEW ANY COLUMN ENCRYPTION KEY DEFINITIONVWCK

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERVIEW SERVER STATE
DATABASEVIEW ANY COLUMN MASTER KEY DEFINITIONvWCM

Applies to SQL Server (SQL Server 2016 through current), SQL Database.
SERVERVIEW SERVER STATE
DATABASEVIEW DATABASE STATEVWDSSERVERVIEW SERVER STATE
DATABASEVIEW DEFINITIONVWSERVERVIEW ANY DEFINITION
ENDPOINTALTERALSERVERALTER ANY ENDPOINT
ENDPOINTCONNECTCOSERVERCONTROL SERVER
ENDPOINTCONTROLCLSERVERCONTROL SERVER
ENDPOINTTAKE OWNERSHIPTOSERVERCONTROL SERVER
ENDPOINTVIEW DEFINITIONVWSERVERVIEW ANY DEFINITION
FULLTEXT CATALOGALTERALDATABASEALTER ANY FULLTEXT CATALOG
FULLTEXT CATALOGCONTROLCLDATABASECONTROL
FULLTEXT CATALOGREFERENCESRFDATABASEREFERENCES
FULLTEXT CATALOGTAKE OWNERSHIPTODATABASECONTROL
FULLTEXT CATALOGVIEW DEFINITIONVWDATABASEVIEW DEFINITION
FULLTEXT STOPLISTALTERALDATABASEALTER ANY FULLTEXT CATALOG
FULLTEXT STOPLISTCONTROLCLDATABASECONTROL
FULLTEXT STOPLISTREFERENCESRFDATABASEREFERENCES
FULLTEXT STOPLISTTAKE OWNERSHIPTODATABASECONTROL
FULLTEXT STOPLISTVIEW DEFINITIONVWDATABASEVIEW DEFINITION
LOGINALTERALSERVERALTER ANY LOGIN
LOGINCONTROLCLSERVERCONTROL SERVER
LOGINIMPERSONATEIMSERVERCONTROL SERVER
LOGINVIEW DEFINITIONVWSERVERVIEW ANY DEFINITION
MESSAGE TYPEALTERALDATABASEALTER ANY MESSAGE TYPE
MESSAGE TYPECONTROLCLDATABASECONTROL
MESSAGE TYPEREFERENCESRFDATABASEREFERENCES
MESSAGE TYPETAKE OWNERSHIPTODATABASECONTROL
MESSAGE TYPEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
OBJECTALTERALSCHEMAALTER
OBJECTCONTROLCLSCHEMACONTROL
OBJECTDELETEDLSCHEMADELETE
OBJECTEXECUTEEXSCHEMAEXECUTE
OBJECTINSERTINSCHEMAINSERT
OBJECTRECEIVERCSCHEMACONTROL
OBJECTREFERENCESRFSCHEMAREFERENCES
OBJECTSELECTSLSCHEMASELECT
OBJECTTAKE OWNERSHIPTOSCHEMACONTROL
OBJECTUPDATEUPSCHEMAUPDATE
OBJECTVIEW CHANGE TRACKINGVWCTSCHEMAVIEW CHANGE TRACKING
OBJECTVIEW DEFINITIONVWSCHEMAVIEW DEFINITION
REMOTE SERVICE BINDINGALTERALDATABASEALTER ANY REMOTE SERVICE BINDING
REMOTE SERVICE BINDINGCONTROLCLDATABASECONTROL
REMOTE SERVICE BINDINGTAKE OWNERSHIPTODATABASECONTROL
REMOTE SERVICE BINDINGVIEW DEFINITIONVWDATABASEVIEW DEFINITION
ROLEALTERALDATABASEALTER ANY ROLE
ROLECONTROLCLDATABASECONTROL
ROLETAKE OWNERSHIPTODATABASECONTROL
ROLEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
ROUTEALTERALDATABASEALTER ANY ROUTE
ROUTECONTROLCLDATABASECONTROL
ROUTETAKE OWNERSHIPTODATABASECONTROL
ROUTEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
SEARCH PROPERTY LISTALTERALSERVERALTER ANY FULLTEXT CATALOG
SEARCH PROPERTY LISTCONTROLCLSERVERCONTROL
SEARCH PROPERTY LISTREFERENCESRFSERVERREFERENCES
SEARCH PROPERTY LISTTAKE OWNERSHIPTOSERVERCONTROL
SEARCH PROPERTY LISTVIEW DEFINITIONVWSERVERVIEW DEFINITION
SCHEMAALTERALDATABASEALTER ANY SCHEMA
SCHEMACONTROLCLDATABASECONTROL
SCHEMACREATE SEQUENCECRSODATABASECONTROL
SCHEMADELETEDLDATABASEDELETE
SCHEMAEXECUTEEXDATABASEEXECUTE
SCHEMAINSERTINDATABASEINSERT
SCHEMAREFERENCESRFDATABASEREFERENCES
SCHEMASELECTSLDATABASESELECT
SCHEMATAKE OWNERSHIPTODATABASECONTROL
SCHEMAUPDATEUPDATABASEUPDATE
SCHEMAVIEW CHANGE TRACKINGVWCTDATABASEVIEW CHANGE TRACKING
SCHEMAVIEW DEFINITIONVWDATABASEVIEW DEFINITION
SERVERADMINISTER BULK OPERATIONSADBONot applicableNot applicable
SERVERALTER ANY AVAILABILITY GROUPALAGNot applicableNot applicable
SERVERALTER ANY CONNECTIONALCONot applicableNot applicable
SERVERALTER ANY CREDENTIALALCDNot applicableNot applicable
SERVERALTER ANY DATABASEALDBNot applicableNot applicable
SERVERALTER ANY ENDPOINTALHENot applicableNot applicable
SERVERALTER ANY EVENT NOTIFICATIONALESNot applicableNot applicable
SERVERALTER ANY EVENT SESSIONAAESNot applicableNot applicable
SERVERALTER ANY LINKED SERVERALLSNot applicableNot applicable
SERVERALTER ANY LOGINALLGNot applicableNot applicable
SERVERALTER ANY SERVER AUDITALAANot applicableNot applicable
SERVERALTER ANY SERVER ROLEALSRNot applicableNot applicable
SERVERALTER RESOURCESALRSNot applicableNot applicable
SERVERALTER SERVER STATEALSSNot applicableNot applicable
SERVERALTER SETTINGSALSTNot applicableNot applicable
SERVERALTER TRACEALTRNot applicableNot applicable
SERVERAUTHENTICATE SERVERAUTHNot applicableNot applicable
SERVERCONNECT ANY DATABASECADBNot applicableNot applicable
SERVERCONNECT SQLCOSQNot applicableNot applicable
SERVERCONTROL SERVERCLNot applicableNot applicable
SERVERCREATE ANY DATABASECRDBNot applicableNot applicable
SERVERCREATE AVAILABILITY GROUPCRACNot applicableNot applicable
SERVERCREATE DDL EVENT NOTIFICATIONCRDENot applicableNot applicable
SERVERCREATE ENDPOINTCRHENot applicableNot applicable
SERVERCREATE SERVER ROLECRSRNot applicableNot applicable
SERVERCREATE TRACE EVENT NOTIFICATIONCRTENot applicableNot applicable
SERVEREXTERNAL ACCESS ASSEMBLYXANot applicableNot applicable
SERVERIMPERSONATE ANY LOGINIALNot applicableNot applicable
SERVERSELECT ALL USER SECURABLESSUSNot applicableNot applicable
SERVERSHUTDOWNSHDNNot applicableNot applicable
SERVERUNSAFE ASSEMBLYXUNot applicableNot applicable
SERVERVIEW ANY DATABASEVWDBNot applicableNot applicable
SERVERVIEW ANY DEFINITIONVWADNot applicableNot applicable
SERVERVIEW SERVER STATEVWSSNot applicableNot applicable
SERVER ROLEALTERALSERVERALTER ANY SERVER ROLE
SERVER ROLECONTROLCLSERVERCONTROL SERVER
SERVER ROLETAKE OWNERSHIPTOSERVERCONTROL SERVER
SERVER ROLEVIEW DEFINITIONVWSERVERVIEW ANY DEFINITION
SERVICEALTERALDATABASEALTER ANY SERVICE
SERVICECONTROLCLDATABASECONTROL
SERVICESENDSNDATABASECONTROL
SERVICETAKE OWNERSHIPTODATABASECONTROL
SERVICEVIEW DEFINITIONVWDATABASEVIEW DEFINITION
SYMMETRIC KEYALTERALDATABASEALTER ANY SYMMETRIC KEY
SYMMETRIC KEYCONTROLCLDATABASECONTROL
SYMMETRIC KEYREFERENCESRFDATABASEREFERENCES
SYMMETRIC KEYTAKE OWNERSHIPTODATABASECONTROL
SYMMETRIC KEYVIEW DEFINITIONVWDATABASEVIEW DEFINITION
TYPECONTROLCLSCHEMACONTROL
TYPEEXECUTEEXSCHEMAEXECUTE
TYPEREFERENCESRFSCHEMAREFERENCES
TYPETAKE OWNERSHIPTOSCHEMACONTROL
TYPEVIEW DEFINITIONVWSCHEMAVIEW DEFINITION
USERALTERALDATABASEALTER ANY USER
USERCONTROLCLDATABASECONTROL
USERIMPERSONATEIMDATABASECONTROL
USERVIEW DEFINITIONVWDATABASEVIEW DEFINITION
XML SCHEMA COLLECTIONALTERALSCHEMAALTER
XML SCHEMA COLLECTIONCONTROLCLSCHEMACONTROL
XML SCHEMA COLLECTIONEXECUTEEXSCHEMAEXECUTE
XML SCHEMA COLLECTIONREFERENCESRFSCHEMAREFERENCES
XML SCHEMA COLLECTIONTAKE OWNERSHIPTOSCHEMACONTROL
XML SCHEMA COLLECTIONVIEW DEFINITIONVWSCHEMAVIEW DEFINITION

Checking permissions can be complex. The permission check algorithm includes overlapping group memberships and ownership chaining, both explicit and implicit permission, and can be affected by the permissions on securable classes that contain the securable entity. The general process of the algorithm is to collect all the relevant permissions. If no blocking DENY is found, the algorithm searches for a GRANT that provides sufficient access. The algorithm contains three essential elements, the security context, the permission space, and the required permission.

System_CAPS_ICON_note.jpg Note


You cannot grant, deny, or revoke permissions to sa, dbo, the entity owner, information_schema, sys, or yourself.

  • Security context

    This is the group of principals that contribute permissions to the access check. These are permissions that are related to the current login or user, unless the security context was changed to another login or user by using the EXECUTE AS statement. The security context includes the following principals:

    • The login

    • The user

    • Role memberships

    • Windows group memberships

    • If module signing is being used, any login or user account for the certificate used to sign the module that the user is currently executing, and the associated role memberships of that principal.

  • Permission space

    This is the securable entity and any securable classes that contain the securable. For example, a table (a securable entity) is contained by the schema securable class and by the database securable class. Access can be affected by table-, schema-, database-, and server-level permissions. For more information, see Permissions Hierarchy (Database Engine).

  • Required permission

    The kind of permission that is required. For example, INSERT, UPDATE, DELETE, SELECT, EXECUTE, ALTER, CONTROL, and so on.

    Access can require multiple permissions, as in the following examples:

    • A stored procedure can require both EXECUTE permission on the stored procedure and INSERT permission on several tables that are referenced by the stored procedure.

    • A dynamic management view can require both VIEW SERVER STATE and SELECT permission on the view.

General Steps of the Algorithm

When the algorithm is determining whether to allow access to a securable, the precise steps that it uses can vary, depending on the principals and the securables that are involved. However, the algorithm performs the following general steps:

  1. Bypass the permission check if the login is a member of the sysadmin fixed server role or if the user is the dbo user in the current database.

  2. Allow access if ownership chaining is applicable and the access check on the object earlier in the chain passed the security check.

  3. Aggregate the server-level, database-level, and signed-module identities that are associated with the caller to create the security context.

  4. For that security context, collect all the permissions that are granted or denied for the permission space. The permission can be explicitly stated as a GRANT, GRANT WITH GRANT, or DENY; or the permissions can be an implied or covering permission GRANT or DENY. For example, CONTROL permission on a schema implies CONTROL on a table. And CONTROL on a table implies SELECT. Therefore, if CONTROL on the schema was granted, SELECT on the table is granted. If CONTROL was denied on the table, SELECT on the table is denied.

    System_CAPS_ICON_note.jpg Note


    A GRANT of a column-level permission overrides a DENY at the object level.

  5. Identify the required permission.

  6. Fail the permission check if the required permission is directly or implicitly denied to any of the identities in the security context for the objects in the permission space.

  7. Pass the permission check if the required permission was not denied and the required permission contains a GRANT or a GRANT WITH GRANT permission either directly or implicitly to any of the identities in the security context for any object in the permission space.

Column level permissions are granted with the syntax <table_name>(<column _name>). For example:

GRANT SELECT ON OBJECT::Customer(CustomerName) TO UserJoe;

A DENY on the table is overridden by a GRANT on a column. However, a subsequent DENY on the table will remove the column GRANT.

The examples in this section show how to retrieve permissions information.

A. Returning the complete list of grantable permissions

The following statement returns all Database Engine permission by using the fn_builtin_permissions function. For more information, see sys.fn_builtin_permissions (Transact-SQL).

SELECT * FROM fn_builtin_permissions(default);  
GO  

B. Returning the permissions on a particular class of objects

The following example uses fn_builtin_permissions to view all the permissions that are available for a category of securable. The example returns permissions on assemblies.

SELECT * FROM fn_builtin_permissions('assembly');  
GO    

C. Returning the permissions granted to the executing principal on an object

The following example uses fn_my_permissions to return a list of the effective permissions that are held by the calling principal on a specified securable. The example returns permissions on an object named Orders55. For more information, see sys.fn_my_permissions (Transact-SQL).

SELECT * FROM fn_my_permissions('Orders55', 'object');  
GO  

D. Returning the permissions applicable to a specified object

The following example returns permissions applicable to an object called Yttrium. Notice that the built-in function OBJECT_ID is used to retrieve the ID of object Yttrium.

SELECT * FROM sys.database_permissions   
    WHERE major_id = OBJECT_ID('Yttrium');  
GO  

Permissions Hierarchy (Database Engine)
sys.database_permissions (Transact-SQL)

Show:
© 2016 Microsoft