GRANT (permisos de base de datos de Transact-SQL)GRANT Database Permissions (Transact-SQL)

SE APLICA A: síSQL Server síAzure SQL Database síAzure SQL Data Warehouse síAlmacenamiento de datos paralelos APPLIES TO: yesSQL Server yesAzure SQL Database yesAzure SQL Data Warehouse yesParallel Data Warehouse

Concede permisos en una base de datos de SQL ServerSQL Server.Grants permissions on a database in SQL ServerSQL Server.

Icono de vínculo de tema Convenciones de sintaxis de Transact-SQLTopic link icon Transact-SQL Syntax Conventions

SintaxisSyntax


GRANT <permission> [ ,...n ]
    TO <database_principal> [ ,...n ] [ WITH GRANT OPTION ]
    [ AS <database_principal> ]

<permission>::=
permission | ALL [ PRIVILEGES ]

<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

ArgumentosArguments

permission Especifica un permiso que se puede conceder para una base de datos.permission Specifies a permission that can be granted on a database. Para obtener una lista de permisos, vea la sección Comentarios que se muestra posteriormente en este tema.For a list of the permissions, see the Remarks section later in this topic.

ALL Esta opción no concede todos los permisos posibles.ALL This option does not grant all possible permissions. Conceder ALL es equivalente a conceder los siguientes permisos: BACKUP DATABASE, BACKUP LOG, CREATE DATABASE, CREATE DEFAULT, CREATE FUNCTION, CREATE PROCEDURE, CREATE RULE, CREATE TABLE y CREATE VIEW.Granting ALL is equivalent to granting the following permissions: BACKUP DATABASE, BACKUP LOG, CREATE DATABASE, CREATE DEFAULT, CREATE FUNCTION, CREATE PROCEDURE, CREATE RULE, CREATE TABLE, and CREATE VIEW.

PRIVILEGES Incluido por compatibilidad con ISO.PRIVILEGES Included for ISO compliance. No cambia el comportamiento de ALL.Does not change the behavior of ALL.

WITH GRANT OPTION Indica que la entidad de seguridad también podrá conceder el permiso especificado a otras entidades de seguridad.WITH GRANT OPTION Indicates that the principal will also be given the ability to grant the specified permission to other principals.

AS <database_principal> especifica una entidad de seguridad de la que la entidad de seguridad que ejecuta esta consulta deriva su derecho de conceder el permiso.AS <database_principal> Specifies a principal from which the principal executing this query derives its right to grant the permission.

Database_user Especifica un usuario de base de datos.Database_user Specifies a database user.

Database_role Especifica un rol de la base de datos.Database_role Specifies a database role.

Application_role Se aplica a: desde SQL Server 2008SQL Server 2008 hasta SQL Server 2017SQL Server 2017, SQL DatabaseSQL DatabaseApplication_role Applies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017, SQL DatabaseSQL Database

Especifica un rol de aplicación.Specifies an application role.

Database_user_mapped_to_Windows_User Se aplica a: desde SQL Server 2008SQL Server 2008 a hasta SQL Server 2017SQL Server 2017Database_user_mapped_to_Windows_User Applies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017

Especifica un usuario de base de datos asignado a un usuario de Windows.Specifies a database user mapped to a Windows user.

Database_user_mapped_to_Windows_Group Se aplica a: desde SQL Server 2008SQL Server 2008 hasta SQL Server 2017SQL Server 2017Database_user_mapped_to_Windows_Group Applies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017

Especifica un usuario de base de datos asignado a un grupo de Windows.Specifies a database user mapped to a Windows group.

Database_user_mapped_to_certificate Se aplica a: desde SQL Server 2008SQL Server 2008 hasta SQL Server 2017SQL Server 2017Database_user_mapped_to_certificate Applies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017

Especifica un usuario de base de datos asignado a un certificado.Specifies a database user mapped to a certificate.

Database_user_mapped_to_asymmetric_key Se aplica a: desde SQL Server 2008SQL Server 2008 hasta SQL Server 2017SQL Server 2017Database_user_mapped_to_asymmetric_key Applies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017

Especifica un usuario de base de datos asignado a una clave asimétrica.Specifies a database user mapped to an asymmetric key.

Database_user_with_no_login Especifica un usuario de base de datos sin entidad de seguridad de servidor correspondiente.Database_user_with_no_login Specifies a database user with no corresponding server-level principal.

NotasRemarks

Importante

En algunos casos, una combinación de los permisos ALTER y REFERENCE podría permitir al receptor ver datos o ejecutar funciones no autorizadas.A combination of ALTER and REFERENCE permissions in some cases could allow the grantee to view data or execute unauthorized functions. Por ejemplo: Un usuario con el permiso ALTER en una tabla y el permiso REFERENCE en una función puede crear una columna calculada sobre una función y hacer que se ejecute.For example: A user with ALTER permission on a table and REFERENCE permission on a function can create a computed column over a function and have it be executed. En este caso, el usuario también debe disponer del permiso SELECT en la columna calculada.In this case, the user must also have SELECT permission on the computed column.

Una base de datos es un elemento protegible que contiene el servidor, que es su entidad primaria en la jerarquía de permisos.A database is a securable contained by the server that is its parent in the permissions hierarchy. La mayoría de permisos limitados y específicos que se pueden conceder para una base de datos se muestran en la siguiente tabla, junto con permisos más generales que los incluyen por implicación.The most specific and limited permissions that can be granted on a database are listed in the following table, together with the more general permissions that include them by implication.

Permiso de base de datosDatabase permission Implícito en el permiso de base de datosImplied by database permission Implícito en el permiso de servidorImplied by server permission
ADMINISTER DATABASE BULK OPERATIONSADMINISTER DATABASE BULK OPERATIONS
Se aplica a: SQL DatabaseSQL Database.Applies to: SQL DatabaseSQL Database.
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
ALTERALTER CONTROLCONTROL ALTER ANY DATABASEALTER ANY DATABASE
ALTER ANY APPLICATION ROLEALTER ANY APPLICATION ROLE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY ASSEMBLYALTER ANY ASSEMBLY ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY ASYMMETRIC KEYALTER ANY ASYMMETRIC KEY ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY CERTIFICATEALTER ANY CERTIFICATE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY COLUMN ENCRYPTION KEYALTER ANY COLUMN ENCRYPTION KEY ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY COLUMN MASTER KEY DEFINITIONALTER ANY COLUMN MASTER KEY DEFINITION ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY CONTRACTALTER ANY CONTRACT ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY DATABASE AUDITALTER ANY DATABASE AUDIT ALTERALTER ALTER ANY SERVER AUDITALTER ANY SERVER AUDIT
ALTER ANY DATABASE DDL TRIGGERALTER ANY DATABASE DDL TRIGGER ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY DATABASE EVENT NOTIFICATIONALTER ANY DATABASE EVENT NOTIFICATION ALTERALTER ALTER ANY EVENT NOTIFICATIONALTER ANY EVENT NOTIFICATION
ALTER ANY DATABASE EVENT SESSIONALTER ANY DATABASE EVENT SESSION
Se aplica a: SQL DatabaseSQL Database.Applies to: SQL DatabaseSQL Database.
ALTERALTER ALTER ANY EVENT SESSIONALTER ANY EVENT SESSION
ALTER ANY DATABASE SCOPED CONFIGURATIONALTER ANY DATABASE SCOPED CONFIGURATION
Se aplica a: de SQL Server 2016 (13.x)SQL Server 2016 (13.x) a SQL Server 2017SQL Server 2017, SQL DatabaseSQL Database.Applies to: SQL Server 2016 (13.x)SQL Server 2016 (13.x) through SQL Server 2017SQL Server 2017, SQL DatabaseSQL Database.
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
ALTER ANY DATASPACEALTER ANY DATASPACE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY EXTERNAL DATA SOURCEALTER ANY EXTERNAL DATA SOURCE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY EXTERNAL FILE FORMATALTER ANY EXTERNAL FILE FORMAT ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY EXTERNAL LIBRARYALTER ANY EXTERNAL LIBRARY
Se aplica a: SQL Server 2017 (14.x)SQL Server 2017 (14.x).Applies to: SQL Server 2017 (14.x)SQL Server 2017 (14.x).
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
ALTER ANY FULLTEXT CATALOGALTER ANY FULLTEXT CATALOG ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY MASKALTER ANY MASK CONTROLCONTROL CONTROL SERVERCONTROL SERVER
ALTER ANY MESSAGE TYPEALTER ANY MESSAGE TYPE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY REMOTE SERVICE BINDINGALTER ANY REMOTE SERVICE BINDING ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY ROLEALTER ANY ROLE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY ROUTEALTER ANY ROUTE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY SCHEMAALTER ANY SCHEMA ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY SECURITY POLICYALTER ANY SECURITY POLICY
Se aplica a: Base de datos SQL de AzureAzure SQL Database.Applies to: Base de datos SQL de AzureAzure SQL Database.
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
ALTER ANY SERVICEALTER ANY SERVICE ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY SYMMETRIC KEYALTER ANY SYMMETRIC KEY ALTERALTER CONTROL SERVERCONTROL SERVER
ALTER ANY USERALTER ANY USER ALTERALTER CONTROL SERVERCONTROL SERVER
AUTHENTICATEAUTHENTICATE CONTROLCONTROL AUTHENTICATE SERVERAUTHENTICATE SERVER
BACKUP DATABASEBACKUP DATABASE CONTROLCONTROL CONTROL SERVERCONTROL SERVER
BACKUP LOGBACKUP LOG CONTROLCONTROL CONTROL SERVERCONTROL SERVER
CHECKPOINTCHECKPOINT CONTROLCONTROL CONTROL SERVERCONTROL SERVER
CONNECTCONNECT CONNECT REPLICATIONCONNECT REPLICATION CONTROL SERVERCONTROL SERVER
CONNECT REPLICATIONCONNECT REPLICATION CONTROLCONTROL CONTROL SERVERCONTROL SERVER
CONTROLCONTROL CONTROLCONTROL CONTROL SERVERCONTROL SERVER
CREATE AGGREGATECREATE AGGREGATE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE ANY EXTERNAL LIBRARYCREATE ANY EXTERNAL LIBRARY
Se aplica a: SQL Server 2017 (14.x)SQL Server 2017 (14.x).Applies to: SQL Server 2017 (14.x)SQL Server 2017 (14.x).
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
CREATE ASSEMBLYCREATE ASSEMBLY ALTER ANY ASSEMBLYALTER ANY ASSEMBLY CONTROL SERVERCONTROL SERVER
CREATE ASYMMETRIC KEYCREATE ASYMMETRIC KEY ALTER ANY ASYMMETRIC KEYALTER ANY ASYMMETRIC KEY CONTROL SERVERCONTROL SERVER
CREATE CERTIFICATECREATE CERTIFICATE ALTER ANY CERTIFICATEALTER ANY CERTIFICATE CONTROL SERVERCONTROL SERVER
CREATE CONTRACTCREATE CONTRACT ALTER ANY CONTRACTALTER ANY CONTRACT CONTROL SERVERCONTROL SERVER
CREATE DATABASECREATE DATABASE CONTROLCONTROL CREATE ANY DATABASECREATE ANY DATABASE
CREATE DATABASE DDL EVENT NOTIFICATIONCREATE DATABASE DDL EVENT NOTIFICATION ALTER ANY DATABASE EVENT NOTIFICATIONALTER ANY DATABASE EVENT NOTIFICATION CREATE DDL EVENT NOTIFICATIONCREATE DDL EVENT NOTIFICATION
CREATE DEFAULTCREATE DEFAULT ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE FULLTEXT CATALOGCREATE FULLTEXT CATALOG ALTER ANY FULLTEXT CATALOGALTER ANY FULLTEXT CATALOG CONTROL SERVERCONTROL SERVER
CREATE FUNCTIONCREATE FUNCTION ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE MESSAGE TYPECREATE MESSAGE TYPE ALTER ANY MESSAGE TYPEALTER ANY MESSAGE TYPE CONTROL SERVERCONTROL SERVER
CREATE PROCEDURECREATE PROCEDURE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE QUEUECREATE QUEUE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE REMOTE SERVICE BINDINGCREATE REMOTE SERVICE BINDING ALTER ANY REMOTE SERVICE BINDINGALTER ANY REMOTE SERVICE BINDING CONTROL SERVERCONTROL SERVER
CREATE ROLECREATE ROLE ALTER ANY ROLEALTER ANY ROLE CONTROL SERVERCONTROL SERVER
CREATE ROUTECREATE ROUTE ALTER ANY ROUTEALTER ANY ROUTE CONTROL SERVERCONTROL SERVER
CREATE RULECREATE RULE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE SCHEMACREATE SCHEMA ALTER ANY SCHEMAALTER ANY SCHEMA CONTROL SERVERCONTROL SERVER
CREATE SERVICECREATE SERVICE ALTER ANY SERVICEALTER ANY SERVICE CONTROL SERVERCONTROL SERVER
CREATE SYMMETRIC KEYCREATE SYMMETRIC KEY ALTER ANY SYMMETRIC KEYALTER ANY SYMMETRIC KEY CONTROL SERVERCONTROL SERVER
CREATE SYNONYMCREATE SYNONYM ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE TABLECREATE TABLE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE TYPECREATE TYPE ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE VIEWCREATE VIEW ALTERALTER CONTROL SERVERCONTROL SERVER
CREATE XML SCHEMA COLLECTIONCREATE XML SCHEMA COLLECTION ALTERALTER CONTROL SERVERCONTROL SERVER
DeleteDELETE CONTROLCONTROL CONTROL SERVERCONTROL SERVER
EjecuteEXECUTE CONTROLCONTROL CONTROL SERVERCONTROL SERVER
EXECUTE ANY EXTERNAL SCRIPTEXECUTE ANY EXTERNAL SCRIPT
Se aplica a: SQL Server 2016 (13.x)SQL Server 2016 (13.x).Applies to: SQL Server 2016 (13.x)SQL Server 2016 (13.x).
CONTROLCONTROL CONTROL SERVERCONTROL SERVER
EXECUTE EXTERNAL SCRIPTEXECUTE EXTERNAL SCRIPT
Se aplica a: SQL Server 2019SQL Server 2019.Applies to: SQL Server 2019SQL Server 2019.
EXECUTE ANY EXTERNAL SCRIPTEXECUTE ANY EXTERNAL SCRIPT CONTROL SERVERCONTROL SERVER
INSERTINSERT CONTROLCONTROL CONTROL SERVERCONTROL SERVER
KILL DATABASE CONNECTIONKILL DATABASE CONNECTION
Se aplica a: Base de datos SQL de AzureAzure SQL Database.Applies to: Base de datos SQL de AzureAzure SQL Database.
CONTROLCONTROL ALTER ANY CONNECTIONALTER ANY CONNECTION
REFERENCESREFERENCES CONTROLCONTROL CONTROL SERVERCONTROL SERVER
SELECTSELECT CONTROLCONTROL CONTROL SERVERCONTROL SERVER
SHOWPLANSHOWPLAN CONTROLCONTROL ALTER TRACEALTER TRACE
SUBSCRIBE QUERY NOTIFICATIONSSUBSCRIBE QUERY NOTIFICATIONS CONTROLCONTROL CONTROL SERVERCONTROL SERVER
TAKE OWNERSHIPTAKE OWNERSHIP CONTROLCONTROL CONTROL SERVERCONTROL SERVER
UNMASKUNMASK CONTROLCONTROL CONTROL SERVERCONTROL SERVER
UPDATEUPDATE CONTROLCONTROL CONTROL SERVERCONTROL SERVER
VIEW ANY COLUMN ENCRYPTION KEY DEFINITIONVIEW ANY COLUMN ENCRYPTION KEY DEFINITION CONTROLCONTROL VIEW ANY DEFINITIONVIEW ANY DEFINITION
VIEW ANY COLUMN MASTER KEY DEFINITIONVIEW ANY COLUMN MASTER KEY DEFINITION CONTROLCONTROL VIEW ANY DEFINITIONVIEW ANY DEFINITION
VIEW DATABASE STATEVIEW DATABASE STATE CONTROLCONTROL VIEW SERVER STATEVIEW SERVER STATE
VIEW DEFINITIONVIEW DEFINITION CONTROLCONTROL VIEW ANY DEFINITIONVIEW ANY DEFINITION

PermisosPermissions

El otorgante del permiso (o la entidad de seguridad especificada con la opción AS) debe tener el permiso con GRANT OPTION, o un permiso superior que implique el permiso que se va a conceder.The grantor (or the principal specified with the AS option) must have either the permission itself with GRANT OPTION, or a higher permission that implies the permission being granted.

Si utiliza la opción AS, se aplican los siguientes requisitos adicionales.If you are using the AS option, the following additional requirements apply.

AS granting_principalAS granting_principal Permiso adicional necesarioAdditional permission required
Usuario de la base de datosDatabase user Permiso IMPERSONATE para el usuario, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Usuario de la base de datos asignado a un inicio de sesión de WindowsDatabase user mapped to a Windows login Permiso IMPERSONATE para el usuario, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Usuario de la base de datos asignado a un grupo de WindowsDatabase user mapped to a Windows Group Pertenencia al grupo de Windows, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.Membership in the Windows group, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Usuario de la base de datos asignado a un certificadoDatabase user mapped to a certificate Pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.Membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Usuario de la base de datos asignado a una clave asimétricaDatabase user mapped to an asymmetric key Pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.Membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Usuario de la base de datos no asignado a una entidad de seguridad del servidorDatabase user not mapped to any server principal Permiso IMPERSONATE para el usuario, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.IMPERSONATE permission on the user, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Rol de base de datosDatabase role Permiso ALTER para el rol, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.ALTER permission on the role, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.
Rol de aplicaciónApplication role Permiso ALTER para el rol, pertenencia al rol fijo de base de datos db_securityadmin, pertenencia al rol fijo de base de datos db_owner o pertenencia al rol fijo de servidor sysadmin.ALTER permission on the role, membership in the db_securityadmin fixed database role, membership in the db_owner fixed database role, or membership in the sysadmin fixed server role.

Los propietarios de objetos pueden conceder permisos para los objetos que poseen.Object owners can grant permissions on the objects they own. Las entidades de seguridad que tienen el permiso CONTROL para un elemento protegible pueden conceder permisos para ese elemento.Principals that have CONTROL permission on a securable can grant permission on that securable.

Los receptores del permiso CONTROL SERVER como los miembros del rol fijo de servidor sysadmin pueden conceder los permisos sobre cualquier elemento protegible en el servidor.Grantees of CONTROL SERVER permission, such as members of the sysadmin fixed server role, can grant any permission on any securable in the server.

EjemplosExamples

A.A. Conceder el permiso para crear tablasGranting permission to create tables

En el siguiente ejemplo se concede el permiso CREATE TABLE para la base de datos AdventureWorks al usuario MelanieK.The following example grants CREATE TABLE permission on the AdventureWorks database to user MelanieK.

USE AdventureWorks;
GRANT CREATE TABLE TO MelanieK;
GO

B.B. Conceder el permiso SHOWPLAN para un rol de aplicaciónGranting SHOWPLAN permission to an application role

En el siguiente ejemplo se concede el permiso SHOWPLAN para la base de datos AdventureWorks2012 al rol de aplicación AuditMonitor.The following example grants SHOWPLAN permission on the AdventureWorks2012 database to application role AuditMonitor.

Se aplica a: SQL Server 2008SQL Server 2008 hasta SQL Server 2017SQL Server 2017, SQL DatabaseSQL DatabaseApplies to: SQL Server 2008SQL Server 2008 through SQL Server 2017SQL Server 2017, SQL DatabaseSQL Database

USE AdventureWorks2012;
GRANT SHOWPLAN TO AuditMonitor;
GO

C.C. Conceder CREATE VIEW con GRANT OPTIONGranting CREATE VIEW with GRANT OPTION

En el siguiente ejemplo se concede el permiso CREATE VIEW para la base de datos AdventureWorks2012 al usuario CarmineEs con el derecho para conceder CREATE VIEW a otras entidades de seguridad.The following example grants CREATE VIEW permission on the AdventureWorks2012 database to user CarmineEs with the right to grant CREATE VIEW to other principals.

USE AdventureWorks2012;
GRANT CREATE VIEW TO CarmineEs WITH GRANT OPTION;
GO

D.D. Conceder el permiso CONTROL a un usuario de base de datosGranting CONTROL permission to a database user

En el ejemplo siguiente se concede el permiso CONTROL para la base de datos AdventureWorks2012 al usuario de base de datos Sarah.The following example grants CONTROL permission on the AdventureWorks2012 database to the database user Sarah. El usuario debe existir en la base de datos y el contexto se debe establecer en la base de datos.The user must exist in the database and the context must be set to the database.

USE AdventureWorks2012;
GRANT CONTROL ON DATABASE::AdventureWorks2012 TO Sarah;
GO

Consulte tambiénSee Also