Cette requête permet de retrouver l’ensemble des privilèges attribués dans une base à tous les utilisateurs SQL
WITH T AS
(
SELECT CONNEXION.name AS LOGIN_NAME,
GRANTEE.default_schema_name AS DEFAULT_SCHEMA,
PRIVILEGE.state_desc AS SQL_ORDER,
GRANTOR.name AS GRANTOR,
GRANTEE.name AS GRANTEE,
PRIVILEGE."permission_name" AS PRIVILEGE,
s.name AS OBJECT_SCHEMA,
o.name AS OBJECT_NAME,
LTRIM(STUFF((SELECT ', ' + name
FROM sys.COLUMNS AS c
WHERE PRIVILEGE.major_id = c.object_id
AND PRIVILEGE.minor_id = c.column_id
FOR XML PATH('')), 1, 1, '' )) AS COLUMN_LIST,
PRIVILEGE.class_desc AS OBJECT_CLASS,
CASE PRIVILEGE.class
WHEN 0 THEN DB_NAME()
WHEN 1 THEN o.type_desc
WHEN 3 THEN ss.name COLLATE database_default
WHEN 4 THEN dbp.name
WHEN 5 THEN asb.name
WHEN 6 THEN typ.name
WHEN 10 THEN xsc.name
END AS OBJECT_TYPE_OR_NAME
FROM sys.database_principals AS GRANTEE
LEFT OUTER JOIN sys.server_principals AS CONNEXION
ON GRANTEE.sid = CONNEXION.sid
LEFT OUTER JOIN sys.database_permissions AS PRIVILEGE
ON GRANTEE.principal_id = PRIVILEGE.grantee_principal_id
LEFT OUTER JOIN sys.database_principals AS GRANTOR
ON PRIVILEGE.grantor_principal_id = GRANTOR.principal_id
-- lien avec les objets primaires
LEFT OUTER JOIN sys.objects AS o
ON PRIVILEGE.major_id = o.object_id AND PRIVILEGE.class = 1
LEFT OUTER JOIN sys.schemas AS s
ON o.schema_id = s.schema_id
-- lien avec les schémas
LEFT OUTER JOIN sys.schemas AS ss
ON PRIVILEGE.major_id = ss.schema_id
AND minor_id = 0 AND PRIVILEGE.class = 3
-- lien avec les "principals" de la base de données
LEFT OUTER JOIN sys.database_principals AS dbp
ON PRIVILEGE.major_id = dbp.principal_id
AND minor_id = 0 AND PRIVILEGE.class = 4
-- lien avec les "assembly"
LEFT OUTER JOIN sys.assemblies AS asb
ON PRIVILEGE.major_id = asb.assembly_id
AND minor_id = 0 AND PRIVILEGE.class = 5
-- lien avec les "type" 6 =
LEFT OUTER JOIN sys.types AS typ
ON PRIVILEGE.major_id = typ.user_type_id
AND minor_id = 0 AND PRIVILEGE.class = 6
-- lien avec les collections de schémas XML
LEFT OUTER JOIN sys.xml_schema_collections AS xsc
ON PRIVILEGE.major_id = xsc.xml_collection_id
AND minor_id = 0 AND PRIVILEGE.class = 10
-- lien avec les types de message
LEFT OUTER JOIN sys.service_message_types AS smt
ON PRIVILEGE.major_id = smt.message_type_id
AND minor_id = 0 AND PRIVILEGE.class = 15
-- lien avec les contrats de service
LEFT OUTER JOIN sys.service_contracts AS sc
ON PRIVILEGE.major_id = sc.service_contract_id
AND minor_id = 0 AND PRIVILEGE.class = 16
-- lien avec les services
LEFT OUTER JOIN sys.services AS srv
ON PRIVILEGE.major_id = srv.service_id
AND minor_id = 0 AND PRIVILEGE.class = 17
-- lien avec les liaisons de service distant
LEFT OUTER JOIN sys.remote_service_bindings AS rsb
ON PRIVILEGE.major_id = rsb.remote_service_binding_id
AND minor_id = 0 AND PRIVILEGE.class = 18
-- lien avec les 19 = Itinéraire
LEFT OUTER JOIN sys.routes AS r
ON PRIVILEGE.major_id = r.route_id
AND minor_id = 0 AND PRIVILEGE.class = 19
-- lien avec les cataloguec de texte intégral
LEFT OUTER JOIN sys.fulltext_catalogs AS ftc
ON PRIVILEGE.major_id = ftc.fulltext_catalog_id
AND minor_id = 0 AND PRIVILEGE.class = 23
-- lien avec les clés symétriques
LEFT OUTER JOIN sys.symmetric_keys AS sk
ON PRIVILEGE.major_id = sk.symmetric_key_id
AND minor_id = 0 AND PRIVILEGE.class = 24
-- lien avec les certificats
LEFT OUTER JOIN sys.certificates AS ctf
ON PRIVILEGE.major_id = ctf.certificate_id
AND minor_id = 0 AND PRIVILEGE.class = 25
-- lien avec les clés asymétriques
LEFT OUTER JOIN sys.asymmetric_keys AS ask
ON PRIVILEGE.major_id = ask.asymmetric_key_id
AND minor_id = 0 AND PRIVILEGE.class = 26
WHERE GRANTEE.TYPE = 'S' --> SQL_USER
)
SELECT COALESCE (N'EXECUTE AS USER = '''+ GRANTOR + N'''; ' +
SQL_ORDER + N' ' + PRIVILEGE + N' ON ' +
COALESCE('[' + OBJECT_SCHEMA + N'].[' + OBJECT_NAME +'] ' +
COALESCE(N'(' + COLUMN_LIST + N')', ''),
OBJECT_CLASS + N'::' + OBJECT_TYPE_OR_NAME) +
N' TO ' + GRANTEE +'; REVERT;', '') AS SQL_COMMAND,
*
FROM T;
(
SELECT CONNEXION.name AS LOGIN_NAME,
GRANTEE.default_schema_name AS DEFAULT_SCHEMA,
PRIVILEGE.state_desc AS SQL_ORDER,
GRANTOR.name AS GRANTOR,
GRANTEE.name AS GRANTEE,
PRIVILEGE."permission_name" AS PRIVILEGE,
s.name AS OBJECT_SCHEMA,
o.name AS OBJECT_NAME,
LTRIM(STUFF((SELECT ', ' + name
FROM sys.COLUMNS AS c
WHERE PRIVILEGE.major_id = c.object_id
AND PRIVILEGE.minor_id = c.column_id
FOR XML PATH('')), 1, 1, '' )) AS COLUMN_LIST,
PRIVILEGE.class_desc AS OBJECT_CLASS,
CASE PRIVILEGE.class
WHEN 0 THEN DB_NAME()
WHEN 1 THEN o.type_desc
WHEN 3 THEN ss.name COLLATE database_default
WHEN 4 THEN dbp.name
WHEN 5 THEN asb.name
WHEN 6 THEN typ.name
WHEN 10 THEN xsc.name
END AS OBJECT_TYPE_OR_NAME
FROM sys.database_principals AS GRANTEE
LEFT OUTER JOIN sys.server_principals AS CONNEXION
ON GRANTEE.sid = CONNEXION.sid
LEFT OUTER JOIN sys.database_permissions AS PRIVILEGE
ON GRANTEE.principal_id = PRIVILEGE.grantee_principal_id
LEFT OUTER JOIN sys.database_principals AS GRANTOR
ON PRIVILEGE.grantor_principal_id = GRANTOR.principal_id
-- lien avec les objets primaires
LEFT OUTER JOIN sys.objects AS o
ON PRIVILEGE.major_id = o.object_id AND PRIVILEGE.class = 1
LEFT OUTER JOIN sys.schemas AS s
ON o.schema_id = s.schema_id
-- lien avec les schémas
LEFT OUTER JOIN sys.schemas AS ss
ON PRIVILEGE.major_id = ss.schema_id
AND minor_id = 0 AND PRIVILEGE.class = 3
-- lien avec les "principals" de la base de données
LEFT OUTER JOIN sys.database_principals AS dbp
ON PRIVILEGE.major_id = dbp.principal_id
AND minor_id = 0 AND PRIVILEGE.class = 4
-- lien avec les "assembly"
LEFT OUTER JOIN sys.assemblies AS asb
ON PRIVILEGE.major_id = asb.assembly_id
AND minor_id = 0 AND PRIVILEGE.class = 5
-- lien avec les "type" 6 =
LEFT OUTER JOIN sys.types AS typ
ON PRIVILEGE.major_id = typ.user_type_id
AND minor_id = 0 AND PRIVILEGE.class = 6
-- lien avec les collections de schémas XML
LEFT OUTER JOIN sys.xml_schema_collections AS xsc
ON PRIVILEGE.major_id = xsc.xml_collection_id
AND minor_id = 0 AND PRIVILEGE.class = 10
-- lien avec les types de message
LEFT OUTER JOIN sys.service_message_types AS smt
ON PRIVILEGE.major_id = smt.message_type_id
AND minor_id = 0 AND PRIVILEGE.class = 15
-- lien avec les contrats de service
LEFT OUTER JOIN sys.service_contracts AS sc
ON PRIVILEGE.major_id = sc.service_contract_id
AND minor_id = 0 AND PRIVILEGE.class = 16
-- lien avec les services
LEFT OUTER JOIN sys.services AS srv
ON PRIVILEGE.major_id = srv.service_id
AND minor_id = 0 AND PRIVILEGE.class = 17
-- lien avec les liaisons de service distant
LEFT OUTER JOIN sys.remote_service_bindings AS rsb
ON PRIVILEGE.major_id = rsb.remote_service_binding_id
AND minor_id = 0 AND PRIVILEGE.class = 18
-- lien avec les 19 = Itinéraire
LEFT OUTER JOIN sys.routes AS r
ON PRIVILEGE.major_id = r.route_id
AND minor_id = 0 AND PRIVILEGE.class = 19
-- lien avec les cataloguec de texte intégral
LEFT OUTER JOIN sys.fulltext_catalogs AS ftc
ON PRIVILEGE.major_id = ftc.fulltext_catalog_id
AND minor_id = 0 AND PRIVILEGE.class = 23
-- lien avec les clés symétriques
LEFT OUTER JOIN sys.symmetric_keys AS sk
ON PRIVILEGE.major_id = sk.symmetric_key_id
AND minor_id = 0 AND PRIVILEGE.class = 24
-- lien avec les certificats
LEFT OUTER JOIN sys.certificates AS ctf
ON PRIVILEGE.major_id = ctf.certificate_id
AND minor_id = 0 AND PRIVILEGE.class = 25
-- lien avec les clés asymétriques
LEFT OUTER JOIN sys.asymmetric_keys AS ask
ON PRIVILEGE.major_id = ask.asymmetric_key_id
AND minor_id = 0 AND PRIVILEGE.class = 26
WHERE GRANTEE.TYPE = 'S' --> SQL_USER
)
SELECT COALESCE (N'EXECUTE AS USER = '''+ GRANTOR + N'''; ' +
SQL_ORDER + N' ' + PRIVILEGE + N' ON ' +
COALESCE('[' + OBJECT_SCHEMA + N'].[' + OBJECT_NAME +'] ' +
COALESCE(N'(' + COLUMN_LIST + N')', ''),
OBJECT_CLASS + N'::' + OBJECT_TYPE_OR_NAME) +
N' TO ' + GRANTEE +'; REVERT;', '') AS SQL_COMMAND,
*
FROM T;
La colonne SQL_COMMAND contient le script SQL destiné à reproduire l’exécution du privilège.
En sus, la sortie fournit les informations suivantes :
- LOGIN_NAME : le compte de connexion associé à l’utilisateur SQL
- DEFAULT_SCHEMA : le schéma SQL par défaut de l’utilisateur
- SQL_ORDER : l’ordre SQL du DCL (GRANT, DENY…)
- GRANTOR : le gratifiant
- GRANTEE : le gratifié
- PRIVILEGE : le privilège octroyé
- OBJECT_SCHEMA : le schéma SQL de l’objet
- OBJECT_NAME : le nom de l’objet relationnel
- COLUMN_LIST : la liste des colonnes privilégiées
- OBJECT_CLASS : le nom de classe de l’objet
- OBJECT_TYPE_OR_NAME : le nom de type de l’objet ou le nom de l’objet pour les objets non relationnels (conteneurs, types, assemblies…)
Frédéric Brouard, alias SQLpro, ARCHITECTE DE DONNÉES
Expert S.G.B.D relationnelles et langage S.Q.L
Moste Valuable Professionnal Microsoft SQL Server
Société SQLspot : modélisation, conseil, formation,
optimisation, audit, tuning, administration SGBDR
Enseignant: CNAM PACA, ISEN Toulon, CESI Aix en Prov.
Expert S.G.B.D relationnelles et langage S.Q.L
Moste Valuable Professionnal Microsoft SQL Server
Société SQLspot : modélisation, conseil, formation,
optimisation, audit, tuning, administration SGBDR
Enseignant: CNAM PACA, ISEN Toulon, CESI Aix en Prov.
L’entreprise SQL Spot
Le site web sur le SQL et les SGBDR