La procédure que Microsoft fournit pour transférer les connexions d’une instance de SQL Server à l’autre s’applique très bien à SQL Server 2000, qui a près de 13 ans ! Pourtant, avec les possibilités de transtypage ajoutées aux versions suivantes de SQL Server, une requête suffit pour générer le script de création des logins.
En sus, je vous donne les requêtes nécessaires à la génération des rôles, des utilisateurs, et de leurs privilèges respectifs.
Voici donc la requête qui permet de scripter les connexions :
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | SELECT 'CREATE LOGIN [' + name + '] FROM WINDOWS' AS sql_statement FROM sys.server_principals WHERE type_desc IN ('WINDOWS_LOGIN', 'WINDOWS_GROUP') AND is_disabled = 0 AND name NOT IN ('NT AUTHORITY\SYSTEM', '') AND name NOT LIKE '%sqlserveragent%' UNION ALL SELECT 'CREATE LOGIN ' + name + ' WITH PASSWORD = ' + CONVERT(varchar(max), password_hash, 1) + ' HASHED' + ', SID = ' + CONVERT(varchar(max), sid, 1) AS sql_statement FROM sys.sql_logins WHERE type_desc IN ('WINDOWS_LOGIN', 'SQL_LOGIN') AND is_disabled = 0 AND name NOT IN ('sa', 'NT AUTHORITY\SYSTEM') ORDER BY sql_statement |
Ci-dessous, la requête qui scripte les rôles de base de données :
1 2 3 4 5 6 7 | SELECT 'CREATE ROLE [' + name + '] AUTHORIZATION dbo' AS create_role_statement FROM sys.database_principals WHERE type_desc = 'DATABASE_ROLE' AND name NOT LIKE 'MS%' COLLATE SQL_Latin1_General_CP1_CS_AS AND name NOT IN ('public') AND is_fixed_role = 0 ORDER BY name |
Puis les utilisateurs de base de données :
1 2 3 4 5 | SELECT 'CREATE USER [' + name + '] FOR LOGIN [' + name + ']' AS create_user_statement FROM sys.database_principals WHERE type_desc IN ('SQL_USER', 'WINDOWS_USER') AND name NOT IN ('dbo', 'guest', 'sys', 'INFORMATION_SCHEMA') ORDER BY name |
Et enfin l’appartenance des utilisateurs aux rôles, pour SQL Server 2005 et 2008 :
1 2 3 4 5 6 7 8 9 | SELECT 'EXEC sp_addrolemember ''' + R.name + ''', ''' + M.name + '''' AS role_members_statement FROM sys.database_role_members AS RM INNER JOIN sys.database_principals AS R ON R.principal_id = RM.role_principal_id INNER JOIN sys.database_principals AS M ON M.principal_id = RM.member_principal_id WHERE R.name NOT LIKE 'MS%' COLLATE SQL_Latin1_General_CP1_CS_AS AND M.name 'dbo' ORDER BY role_members_statement |
Et pour SQL Server 2012 :
1 2 3 4 5 6 7 8 9 | SELECT 'ALTER ROLE ' + R.name + ' ADD MEMBER ' + M.name AS role_members_statement FROM sys.database_role_members AS RM INNER JOIN sys.database_principals AS R ON R.principal_id = RM.role_principal_id INNER JOIN sys.database_principals AS M ON M.principal_id = RM.member_principal_id WHERE R.name NOT LIKE 'MS%' COLLATE SQL_Latin1_General_CP1_CS_AS AND M.name 'dbo' ORDER BY role_members_statement |
Il nous faut enfin les privilèges des rôles :
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 | ;WITH CTE AS ( SELECT R.name AS role_name , G.permission_name , CASE G.class WHEN 1 THEN O.name WHEN 3 THEN S.name WHEN 0 THEN DB_NAME() END AS object_name , CASE G.class WHEN 1 THEN O.type_desc WHEN 3 THEN 'SCHEMA' WHEN 0 THEN 'DATABASE' END AS object_type_desc FROM sys.database_principals AS R INNER JOIN sys.database_permissions AS G ON G.grantee_principal_id = R.principal_id LEFT JOIN sys.schemas AS S ON G.major_id = S.schema_id LEFT JOIN sys.objects AS O ON G.major_id = O.object_id WHERE R.name 'public' AND G.permission_name 'CONNECT' --ORDER BY R.name, object_name, G.permission_name ) SELECT 'GRANT ' COLLATE database_default + permission_name + ' ON ' + CASE WHEN object_name IS NULL THEN 'SCHEMA::dbo TO [' ELSE object_name + ' TO [' END + role_name + ']' AS role_grant_statement FROM CTE |
Et nous terminons avec les privilèges des utilisateurs :
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 | ;WITH CTE AS ( SELECT DB_USER.name AS user_name , DB_GRANT.class_desc , DB_GRANT.state_desc , DB_GRANT.permission_name , CASE DB_GRANT.class_desc WHEN 'OBJECT_OR_COLUMN' THEN O.name WHEN 'SCHEMA' THEN S.name WHEN 'TYPE' THEN TY.name ELSE O.name END AS object_name , O.type_desc AS DB_object_type FROM sys.database_permissions AS DB_GRANT INNER JOIN sys.database_principals AS DB_USER ON DB_GRANT.grantee_principal_id = DB_USER.principal_id LEFT JOIN sys.objects AS O ON O.object_id = DB_GRANT.major_id LEFT JOIN sys.types AS TY ON TY.user_type_id = DB_GRANT.major_id LEFT JOIN sys.schemas AS S ON S.schema_id = DB_GRANT.major_id WHERE DB_USER.name 'public' AND DB_GRANT.permission_name 'CONNECT' ) SELECT state_desc COLLATE database_default + ' ' + permission_name + CASE WHEN object_name IS NULL THEN '' ELSE ' ON ' + object_name END + ' TO [' + user_name + ']' AS create_user_statement FROM CTE ORDER BY create_user_statement |
Bon transfert d’entités de sécurité !
ElSüket