sys.server_role_members (Transact-SQL)

Returns one row for each member of each fixed and user-defined server role.

Column name

Data type

Description

role_principal_id

int

Server-Principal ID of the role.

member_principal_id

int

Server-Principal ID of the member.

To add or remove server role membership, use the ALTER SERVER ROLE (Transact-SQL)statement.

Permissions

Logins can view their own server role membership and can view the principal_id’s of the members of the fixed server roles. To view all server role membership requires the VIEW DEFINITION ON SERVER ROLE permission or membership in the securityadmin fixed server role.

For more information, see Metadata Visibility Configuration.

Examples

The following example returns the names and id's of the roles and their members.

SELECT sys.server_role_members.role_principal_id, role.name AS RoleName, 
    sys.server_role_members.member_principal_id, member.name AS MemberName
FROM sys.server_role_members
JOIN sys.server_principals AS role
    ON sys.server_role_members.role_principal_id = role.principal_id
JOIN sys.server_principals AS member
    ON sys.server_role_members.member_principal_id = member.principal_id;

See Also

Reference

Catalog Views (Transact-SQL)

Security Catalog Views (Transact-SQL)

Server-Level Roles

Concepts

Principals (Database Engine)