Advertisement
kromm77

[SQL SERVER] Query check grants in db

Jan 19th, 2023
154
0
Never
Not a member of Pastebin yet? Sign Up, it unlocks many cool features!
text 9.44 KB | None | 0 0
  1. /*
  2. Security Audit Report
  3. 1) List all access provisioned to a SQL user or Windows user/group directly
  4. 2) List all access provisioned to a SQL user or Windows user/group through a database or application role
  5. 3) List all access provisioned to the public role
  6.  
  7. Columns Returned:
  8. UserType : Value will be either 'SQL User', 'Windows User', or 'Windows Group'.
  9. This reflects the type of user/group defined for the SQL Server account.
  10. DatabaseUserName: Name of the associated user as defined in the database user account. The database user may not be the
  11. same as the server user.
  12. LoginName : SQL or Windows/Active Directory user account. This could also be an Active Directory group.
  13. Role : The role name. This will be null if the associated permissions to the object are defined at directly
  14. on the user account, otherwise this will be the name of the role that the user is a member of.
  15. PermissionType : Type of permissions the user/role has on an object. Examples could include CONNECT, EXECUTE, SELECT
  16. DELETE, INSERT, ALTER, CONTROL, TAKE OWNERSHIP, VIEW DEFINITION, etc.
  17. This value may not be populated for all roles. Some built in roles have implicit permission
  18. definitions.
  19. PermissionState : Reflects the state of the permission type, examples could include GRANT, DENY, etc.
  20. This value may not be populated for all roles. Some built in roles have implicit permission
  21. definitions.
  22. ObjectType : Type of object the user/role is assigned permissions on. Examples could include USER_TABLE,
  23. SQL_SCALAR_FUNCTION, SQL_INLINE_TABLE_VALUED_FUNCTION, SQL_STORED_PROCEDURE, VIEW, etc.
  24. This value may not be populated for all roles. Some built in roles have implicit permission
  25. definitions.
  26. Schema : Name of the schema the object is in.
  27. ObjectName : Name of the object that the user/role is assigned permissions on.
  28. This value may not be populated for all roles. Some built in roles have implicit permission
  29. definitions.
  30. ColumnName : Name of the column of the object that the user/role is assigned permissions on. This value
  31. is only populated if the object is a table, view or a table value function.
  32. */
  33.  
  34. --1) List all access provisioned to a SQL user or Windows user/group directly
  35. SELECT
  36. [UserType] = CASE princ.[type]
  37. WHEN 'S' THEN 'SQL User'
  38. WHEN 'U' THEN 'Windows User'
  39. WHEN 'G' THEN 'Windows Group'
  40. END,
  41. [DatabaseUserName] = princ.[name],
  42. [LoginName] = ulogin.[name],
  43. [Role] = NULL,
  44. [PermissionType] = perm.[permission_name],
  45. [PermissionState] = perm.[state_desc],
  46. [ObjectType] = CASE perm.[class]
  47. WHEN 1 THEN obj.[type_desc] -- Schema-contained objects
  48. ELSE perm.[class_desc] -- Higher-level objects
  49. END,
  50. [Schema] = objschem.[name],
  51. [ObjectName] = CASE perm.[class]
  52. WHEN 3 THEN permschem.[name] -- Schemas
  53. WHEN 4 THEN imp.[name] -- Impersonations
  54. ELSE OBJECT_NAME(perm.[major_id]) -- General objects
  55. END,
  56. [ColumnName] = col.[name]
  57. FROM
  58. --Database user
  59. sys.database_principals AS princ
  60. --Login accounts
  61. LEFT JOIN sys.server_principals AS ulogin ON ulogin.[sid] = princ.[sid]
  62. --Permissions
  63. LEFT JOIN sys.database_permissions AS perm ON perm.[grantee_principal_id] = princ.[principal_id]
  64. LEFT JOIN sys.schemas AS permschem ON permschem.[schema_id] = perm.[major_id]
  65. LEFT JOIN sys.objects AS obj ON obj.[object_id] = perm.[major_id]
  66. LEFT JOIN sys.schemas AS objschem ON objschem.[schema_id] = obj.[schema_id]
  67. --Table columns
  68. LEFT JOIN sys.columns AS col ON col.[object_id] = perm.[major_id]
  69. AND col.[column_id] = perm.[minor_id]
  70. --Impersonations
  71. LEFT JOIN sys.database_principals AS imp ON imp.[principal_id] = perm.[major_id]
  72. WHERE
  73. princ.[type] IN ('S','U','G')
  74. -- No need for these system accounts
  75. AND princ.[name] NOT IN ('sys', 'INFORMATION_SCHEMA')
  76.  
  77. UNION
  78.  
  79. --2) List all access provisioned to a SQL user or Windows user/group through a database or application role
  80. SELECT
  81. [UserType] = CASE membprinc.[type]
  82. WHEN 'S' THEN 'SQL User'
  83. WHEN 'U' THEN 'Windows User'
  84. WHEN 'G' THEN 'Windows Group'
  85. END,
  86. [DatabaseUserName] = membprinc.[name],
  87. [LoginName] = ulogin.[name],
  88. [Role] = roleprinc.[name],
  89. [PermissionType] = perm.[permission_name],
  90. [PermissionState] = perm.[state_desc],
  91. [ObjectType] = CASE perm.[class]
  92. WHEN 1 THEN obj.[type_desc] -- Schema-contained objects
  93. ELSE perm.[class_desc] -- Higher-level objects
  94. END,
  95. [Schema] = objschem.[name],
  96. [ObjectName] = CASE perm.[class]
  97. WHEN 3 THEN permschem.[name] -- Schemas
  98. WHEN 4 THEN imp.[name] -- Impersonations
  99. ELSE OBJECT_NAME(perm.[major_id]) -- General objects
  100. END,
  101. [ColumnName] = col.[name]
  102. FROM
  103. --Role/member associations
  104. sys.database_role_members AS members
  105. --Roles
  106. JOIN sys.database_principals AS roleprinc ON roleprinc.[principal_id] = members.[role_principal_id]
  107. --Role members (database users)
  108. JOIN sys.database_principals AS membprinc ON membprinc.[principal_id] = members.[member_principal_id]
  109. --Login accounts
  110. LEFT JOIN sys.server_principals AS ulogin ON ulogin.[sid] = membprinc.[sid]
  111. --Permissions
  112. LEFT JOIN sys.database_permissions AS perm ON perm.[grantee_principal_id] = roleprinc.[principal_id]
  113. LEFT JOIN sys.schemas AS permschem ON permschem.[schema_id] = perm.[major_id]
  114. LEFT JOIN sys.objects AS obj ON obj.[object_id] = perm.[major_id]
  115. LEFT JOIN sys.schemas AS objschem ON objschem.[schema_id] = obj.[schema_id]
  116. --Table columns
  117. LEFT JOIN sys.columns AS col ON col.[object_id] = perm.[major_id]
  118. AND col.[column_id] = perm.[minor_id]
  119. --Impersonations
  120. LEFT JOIN sys.database_principals AS imp ON imp.[principal_id] = perm.[major_id]
  121. WHERE
  122. membprinc.[type] IN ('S','U','G')
  123. -- No need for these system accounts
  124. AND membprinc.[name] NOT IN ('sys', 'INFORMATION_SCHEMA')
  125.  
  126. UNION
  127.  
  128. --3) List all access provisioned to the public role, which everyone gets by default
  129. SELECT
  130. [UserType] = '{All Users}',
  131. [DatabaseUserName] = '{All Users}',
  132. [LoginName] = '{All Users}',
  133. [Role] = roleprinc.[name],
  134. [PermissionType] = perm.[permission_name],
  135. [PermissionState] = perm.[state_desc],
  136. [ObjectType] = CASE perm.[class]
  137. WHEN 1 THEN obj.[type_desc] -- Schema-contained objects
  138. ELSE perm.[class_desc] -- Higher-level objects
  139. END,
  140. [Schema] = objschem.[name],
  141. [ObjectName] = CASE perm.[class]
  142. WHEN 3 THEN permschem.[name] -- Schemas
  143. WHEN 4 THEN imp.[name] -- Impersonations
  144. ELSE OBJECT_NAME(perm.[major_id]) -- General objects
  145. END,
  146. [ColumnName] = col.[name]
  147. FROM
  148. --Roles
  149. sys.database_principals AS roleprinc
  150. --Role permissions
  151. LEFT JOIN sys.database_permissions AS perm ON perm.[grantee_principal_id] = roleprinc.[principal_id]
  152. LEFT JOIN sys.schemas AS permschem ON permschem.[schema_id] = perm.[major_id]
  153. --All objects
  154. JOIN sys.objects AS obj ON obj.[object_id] = perm.[major_id]
  155. LEFT JOIN sys.schemas AS objschem ON objschem.[schema_id] = obj.[schema_id]
  156. --Table columns
  157. LEFT JOIN sys.columns AS col ON col.[object_id] = perm.[major_id]
  158. AND col.[column_id] = perm.[minor_id]
  159. --Impersonations
  160. LEFT JOIN sys.database_principals AS imp ON imp.[principal_id] = perm.[major_id]
  161. WHERE
  162. roleprinc.[type] = 'R'
  163. AND roleprinc.[name] = 'public'
  164. AND obj.[is_ms_shipped] = 0
  165.  
  166. ORDER BY
  167. [UserType],
  168. [DatabaseUserName],
  169. [LoginName],
  170. [Role],
  171. [Schema],
  172. [ObjectName],
  173. [ColumnName],
  174. [PermissionType],
  175. [PermissionState],
  176. [ObjectType]
Tags: sql
Advertisement
Add Comment
Please, Sign In to add comment
Advertisement