Hello people,
All right with you ?
In this post I will demonstrate a very cool script that I developed that aims to generate SQL scripts to back up (reverse engineer) permissions, users, logins and roles of an instance in SQL Server.
This script is designed to be used for instance migrations, either for a new server or for a version upgrade of your SQL Server instance, in a practical and easy to use way. If you also want to migrate SQL Agent jobs to another instance as well, see more by accessing the post. SQL Server - How to back up all SQL Agent jobs via command line (CLR C # or Powershell).
Using the Stored Procedure below, you can generate SQL commands to perform the following tasks:
- Script for logging backup (Windows AD and SQL Server Authentication)
- Script to backup instance login permissions (Server level permissions)
- Script for backing up roles in instance roles (Server roles permissions)
- Script for backing up user creation in databases (COM and SEM login)
- Script to backup database login permissions (Database level permissions)
- Script for backing up database roles permissions
As prerequisites for using stpExporta_Logins, you will need:
- A user with sysadmin permission to perform the Stored Procedure
- Create the Stored Procedure stpWrite_File_File, available in post File Operations Using OLE Automation in SQL Server.
The script of stpExports_Logins, which I will present in this post, was inspired by the post's Stored Procedure SQL Server - How to copy / replicate a user's permissions, where the procedure in this post aims to generate SQL files to replicate permissions to another environment, while the script in another post aims to copy permissions from one user to another in the same instance and therefore has no validations and checks, such as logging in.
StpExporta_Logins Procedure Source Code
To perform all tasks easily, simply run the source code below and create stpExporta_Logins in a database of your choice.
This Stored Procedure uses SP stpWrite_File_File to physically write the files to disk, which requires the resource to Ole Automation Procedures is enabled on the instance.
However, you do not have to worry about this part as SP has a check that if this feature is not enabled on the instance, SP itself will enable it during execution and will disable it after the generation of files, keeping this setting just as it was before the procedure was executed.
Source code:
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 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 |
IF (OBJECT_ID('dbo.stpExporta_Logins') IS NULL) EXEC('CREATE PROCEDURE dbo.stpExporta_Logins AS SELECT 1') GO ALTER PROCEDURE dbo.stpExporta_Logins ( @Ds_Diretorio_Saida VARCHAR(500), @Fl_Permissoes_Database BIT = 0, @Fl_Arquivo_Unico BIT = 0 ) AS BEGIN SET NOCOUNT ON DECLARE @Fl_Ole_Automation_Ativo BIT = (SELECT (CASE WHEN CAST([value] AS VARCHAR(MAX)) = '1' THEN 1 ELSE 0 END) FROM sys.configurations WHERE [name] = 'Ole Automation Procedures') --------------------------------------------------------------------------------------- -- CRIAÇÃO DE TABELAS --------------------------------------------------------------------------------------- IF (OBJECT_ID('tempdb..#Permissoes_Database') IS NOT NULL) DROP TABLE #Permissoes_Database CREATE TABLE [dbo].[#Permissoes_Database] ( [database] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [username] [sys].[sysname] NOT NULL, [schema] [sys].[sysname] NULL, [object] [sys].[sysname] NULL, [cmd_state] [varchar] (60) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [permission_name] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) IF (OBJECT_ID('tempdb..#Permissoes_Roles') IS NOT NULL) DROP TABLE #Permissoes_Roles CREATE TABLE [dbo].[#Permissoes_Roles] ( [database] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [username] [sys].[sysname] NOT NULL, [login_type] [sys].[sysname] NULL, [role] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) IF (OBJECT_ID('tempdb..#Permissoes_Servidor') IS NOT NULL) DROP TABLE #Permissoes_Servidor CREATE TABLE [dbo].[#Permissoes_Servidor] ( [username] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [type_desc] [sys].[sysname] NOT NULL, [is_disabled] BIT NOT NULL, [class_desc] varchar(40) NOT NULL, [type] varchar(40) NOT NULL, [permission_name] varchar(50) NOT NULL, [state_desc] varchar(20) NOT NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) IF (OBJECT_ID('tempdb..#Permissoes_Roles_Servidor') IS NOT NULL) DROP TABLE #Permissoes_Roles_Servidor CREATE TABLE [dbo].[#Permissoes_Roles_Servidor] ( [username] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [type_desc] [sys].[sysname] NOT NULL, [is_disabled] BIT NOT NULL, [role] [sys].[sysname] NOT NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) IF (OBJECT_ID('tempdb..#Cria_Usuarios') IS NOT NULL) DROP TABLE #Cria_Usuarios CREATE TABLE [dbo].[#Cria_Usuarios] ( [database] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [username] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [type_desc] [sys].[sysname] NOT NULL, [default_schema_name] [varchar] (128) NULL, [authentication_type_desc] [varchar] (128) NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) IF (OBJECT_ID('tempdb..#Cria_Logins') IS NOT NULL) DROP TABLE #Cria_Logins CREATE TABLE [dbo].[#Cria_Logins] ( [username] [varchar] (128) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [type_desc] [sys].[sysname] NOT NULL, [default_database_name] [varchar] (128) NULL, [default_language_name] [varchar] (128) NULL, [is_fixed_role] [bit] NULL, [is_disabled] [BIT] NULL, [is_policy_checked] [BIT] NULL, [is_expiration_checked] [BIT] NULL, [grant_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL, [revoke_command] [varchar] (MAX) COLLATE SQL_Latin1_General_CP1_CI_AI NULL ) DECLARE @Query_Permissao_Database VARCHAR(MAX) = ' SELECT DISTINCT DB_NAME() AS [database], E.[name] AS [username], D.[name] AS [Schema], C.[name] AS [Object], (CASE WHEN A.state_desc = ''GRANT_WITH_GRANT_OPTION'' THEN ''GRANT'' ELSE A.state_desc END) AS cmd_state, A.[permission_name], (CASE WHEN C.[name] IS NULL THEN ''USE ['' + DB_NAME() + '']; '' + (CASE WHEN A.state_desc = ''GRANT_WITH_GRANT_OPTION'' THEN ''GRANT'' ELSE A.state_desc END) + '' '' + A.[permission_name] + '' TO ['' + E.[name] + ''];'' ELSE ''USE ['' + DB_NAME() + '']; '' + (CASE WHEN A.state_desc = ''GRANT_WITH_GRANT_OPTION'' THEN ''GRANT'' ELSE A.state_desc END) + '' '' + A.[permission_name] + '' ON ['' + DB_NAME() + ''].['' + d.[name] + ''].['' + c.[name] + ''] TO ['' + E.[name] + ''];'' END) COLLATE DATABASE_DEFAULT AS GrantCommand, (CASE WHEN C.[name] IS NULL THEN ''USE ['' + DB_NAME() + '']; '' + ''REVOKE '' + A.[permission_name] + '' FROM ['' + E.[name] + ''];'' ELSE ''USE ['' + DB_NAME() + '']; '' + ''REVOKE '' + A.[permission_name] + '' ON ['' + DB_NAME() + ''].['' + d.[name] + ''].['' + c.[name] + ''] FROM ['' + E.[name] + ''];'' END) COLLATE DATABASE_DEFAULT AS RevokeCommand FROM sys.database_permissions A WITH(NOLOCK) LEFT JOIN sys.schemas B WITH(NOLOCK) ON A.major_id = B.[schema_id] LEFT JOIN sys.all_objects C WITH(NOLOCK) JOIN sys.schemas D WITH(NOLOCK) ON C.[schema_id] = D.[schema_id] ON A.major_id = C.[object_id] JOIN sys.database_principals E WITH(NOLOCK) ON A.grantee_principal_id = E.principal_id WHERE E.[name] NOT IN ( ''dbo'', ''guest'', ''INFORMATION_SCHEMA'', ''sys'' ) AND E.[name] NOT LIKE ''NT SERVICE\%'' AND E.[name] NOT LIKE ''##MS_%''' DECLARE @Query_Permissoes_Roles VARCHAR(MAX) = ' SELECT DB_NAME() AS [database], A.[name] AS [username], A.[type_desc] AS LoginType, C.[name] AS [role], ''EXEC ['' + DB_NAME() + ''].sys.sp_addrolemember '''''' + C.[name] + '''''', '''''' + a.[name] + '''''';'' AS GrantCommand, ''EXEC ['' + DB_NAME() + ''].sys.sp_droprolemember '''''' + C.[name] + '''''', '''''' + a.[name] + '''''';'' AS RevokeCommand FROM sys.database_principals A WITH(NOLOCK) JOIN sys.database_role_members B WITH(NOLOCK) ON A.principal_id = B.member_principal_id JOIN sys.database_principals C WITH(NOLOCK) ON B.role_principal_id = C.principal_id WHERE A.[name] NOT IN ( ''TargetServersRole'', ''SQLAgentUserRole'', ''SQLAgentReaderRole'', ''SQLAgentOperatorRole'', ''DatabaseMailUserRole'', ''db_ssisadmin'', ''db_ssisltduser'', ''db_ssisoperator'', ''dc_operator'', ''dc_admin'', ''dc_proxy'', ''MS_DataCollectorInternalUser'', ''PolicyAdministratorRole'', ''ServerGroupAdministratorRole'', ''ServerGroupReaderRole'', ''##MS_PolicyEventProcessingLogin##'', ''##MS_PolicyTsqlExecutionLogin##'', ''##MS_AgentSigningCertificate##'', ''UtilityCMRReader'', ''UtilityIMRWriter'', ''UtilityIMRReader'', ''db_owner'', ''db_accessadmin'', ''db_securityadmin'', ''db_ddladmin'', ''db_backupoperator'', ''db_datareader'', ''db_datawriter'', ''db_denydatareader'', ''db_denydatawriter'', ''sa'', ''AUTORIDADE NT\SISTEMA'', ''NT AUTHORITY\SYSTEM'', ''dbo'', ''guest'', ''INFORMATION_SCHEMA'', ''sys'' ) AND A.[name] NOT LIKE ''NT SERVICE\%'' AND A.[name] NOT LIKE ''##MS_%''' IF (@Fl_Permissoes_Database = 1) BEGIN DECLARE @Query_Alterada VARCHAR(MAX) --------------------------------------------------------------------------------------- -- PERMISSÕES DE TODOS OS DATABASES --------------------------------------------------------------------------------------- SET @Query_Alterada = ' USE [?]; ' + @Query_Permissao_Database INSERT INTO #Permissoes_Database EXEC master.dbo.sp_MSforeachdb @Query_Alterada -- Remove usuários padrão do SQL Server (Não removi no WHERE por causa do limite de 2k caracteres do sp_MSforeachdb) DELETE FROM #Permissoes_Database WHERE username IN ( 'TargetServersRole', 'SQLAgentUserRole', 'SQLAgentReaderRole', 'SQLAgentOperatorRole', 'DatabaseMailUserRole', 'db_ssisadmin', 'db_ssisltduser', 'db_ssisoperator', 'dc_operator', 'dc_admin', 'dc_proxy', 'MS_DataCollectorInternalUser', 'PolicyAdministratorRole', 'ServerGroupAdministratorRole', 'ServerGroupReaderRole', '##MS_PolicyEventProcessingLogin##', '##MS_PolicyTsqlExecutionLogin##', '##MS_AgentSigningCertificate##', 'UtilityCMRReader', 'UtilityIMRWriter', 'UtilityIMRReader', 'db_owner', 'db_accessadmin', 'db_securityadmin', 'db_ddladmin', 'db_backupoperator', 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter', 'sa', 'AUTORIDADE NT\SISTEMA', 'NT AUTHORITY\SYSTEM' ) OR (username = 'public' AND ([schema] = 'sys' OR [database] IN ('msdb', 'master'))) OR ([database] IN ('tempdb', 'model')) --------------------------------------------------------------------------------------- -- PERMISSÕES EM ROLES DE TODOS OS DATABASES --------------------------------------------------------------------------------------- SET @Query_Alterada = ' USE [?]; ' + @Query_Permissoes_Roles INSERT INTO #Permissoes_Roles EXEC master.dbo.sp_MSforeachdb @Query_Alterada END --------------------------------------------------------------------------------------- -- CRIAÇÃO DE LOGINS --------------------------------------------------------------------------------------- INSERT INTO #Cria_Logins SELECT A.[name] AS username, A.[type_desc], A.default_database_name, A.default_language_name, A.is_fixed_role, A.is_disabled, B.is_policy_checked, B.is_expiration_checked, 'USE [master]; CREATE LOGIN [' + A.[name] + ']' + (CASE WHEN A.[type_desc] = 'SQL_LOGIN' THEN ' WITH PASSWORD = ' + COALESCE(UPPER(sys.fn_varbintohexstr(CONVERT(VARBINARY(MAX), password_hash))), '') + ' HASHED,' ELSE ' FROM WINDOWS WITH' END) + ' DEFAULT_DATABASE=[' + A.default_database_name + ']' + (CASE WHEN A.default_language_name IS NOT NULL THEN ', DEFAULT_LANGUAGE=[' + A.default_language_name + ']' ELSE '' END) + (CASE WHEN B.is_policy_checked IS NOT NULL THEN ', CHECK_POLICY=ON' ELSE '' END) + (CASE WHEN B.is_expiration_checked IS NOT NULL THEN ', CHECK_EXPIRATION=ON' ELSE '' END) + (CASE WHEN A.is_disabled = 1 THEN '; ALTER LOGIN [' + A.[name] + '] DISABLE' ELSE '' END) + ';' AS GrantCommand, 'USE [master]; DROP LOGIN [' + A.[name] + '];' AS RevokeCommand FROM sys.server_principals A WITH(NOLOCK) LEFT JOIN sys.sql_logins B WITH(NOLOCK) ON A.[name] = B.[name] WHERE A.is_fixed_role = 0 -- Não precisa recriar roles padrão do SQL Server AND A.principal_id > 200 -- Não trazer os usuários padrão do SQL Server AND A.[name] NOT IN ( 'TargetServersRole', 'SQLAgentUserRole', 'SQLAgentReaderRole', 'SQLAgentOperatorRole', 'DatabaseMailUserRole', 'db_ssisadmin', 'db_ssisltduser', 'db_ssisoperator', 'dc_operator', 'dc_admin', 'dc_proxy', 'MS_DataCollectorInternalUser', 'PolicyAdministratorRole', 'ServerGroupAdministratorRole', 'ServerGroupReaderRole', '##MS_PolicyEventProcessingLogin##', '##MS_PolicyTsqlExecutionLogin##', '##MS_AgentSigningCertificate##', 'UtilityCMRReader', 'UtilityIMRWriter', 'UtilityIMRReader', 'db_owner', 'db_accessadmin', 'db_securityadmin', 'db_ddladmin', 'db_backupoperator', 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter', 'sa', 'AUTORIDADE NT\SISTEMA', 'NT AUTHORITY\SYSTEM' ) AND A.[name] NOT LIKE 'NT SERVICE\%' AND A.[name] NOT LIKE '##MS_%' --------------------------------------------------------------------------------------- -- PERMISSÕES NA INSTÂNCIA --------------------------------------------------------------------------------------- INSERT INTO #Permissoes_Servidor SELECT DISTINCT A.[name], A.[type_desc], A.is_disabled, B.class_desc, B.[type], B.[permission_name], B.state_desc, 'USE [master]; ' + B.state_desc + ' ' + B.[permission_name] + ' TO [' + A.[name] COLLATE SQL_Latin1_General_CP1_CI_AI + '];' AS GrantCommand, 'USE [master]; REVOKE ' + B.[permission_name] + ' FROM [' + A.[name] COLLATE SQL_Latin1_General_CP1_CI_AI + '];' AS RevokeCommand FROM sys.server_principals A WITH(NOLOCK) JOIN sys.server_permissions B WITH(NOLOCK) ON A.principal_id = B.grantee_principal_id WHERE A.[name] NOT IN ( 'TargetServersRole', 'SQLAgentUserRole', 'SQLAgentReaderRole', 'SQLAgentOperatorRole', 'DatabaseMailUserRole', 'db_ssisadmin', 'db_ssisltduser', 'db_ssisoperator', 'dc_operator', 'dc_admin', 'dc_proxy', 'MS_DataCollectorInternalUser', 'PolicyAdministratorRole', 'ServerGroupAdministratorRole', 'ServerGroupReaderRole', '##MS_PolicyEventProcessingLogin##', '##MS_PolicyTsqlExecutionLogin##', '##MS_AgentSigningCertificate##', 'UtilityCMRReader', 'UtilityIMRWriter', 'UtilityIMRReader', 'db_owner', 'db_accessadmin', 'db_securityadmin', 'db_ddladmin', 'db_backupoperator', 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter', 'sa', 'AUTORIDADE NT\SISTEMA', 'NT AUTHORITY\SYSTEM' ) AND A.[name] NOT LIKE 'NT SERVICE\%' AND A.[name] NOT LIKE '##MS_%' --------------------------------------------------------------------------------------- -- PERMISSÕES EM SERVER ROLES INSTÂNCIA --------------------------------------------------------------------------------------- INSERT INTO #Permissoes_Roles_Servidor SELECT A.[name] AS username, A.[type_desc], A.is_disabled, C.[name] AS [role], 'EXEC [master].[dbo].sp_addsrvrolemember ''' + A.[name] + ''', ''' + C.[name] + ''';' AS GrantCommand, 'EXEC [master].[dbo].sp_dropsrvrolemember ''' + A.[name] + ''', ''' + C.[name] + ''';' AS RevokeCommand FROM sys.server_principals A WITH(NOLOCK) JOIN sys.server_role_members B WITH(NOLOCK) ON A.principal_id = B.member_principal_id JOIN sys.server_principals C WITH(NOLOCK) ON B.role_principal_id = C.principal_id WHERE A.[name] NOT IN ( 'TargetServersRole', 'SQLAgentUserRole', 'SQLAgentReaderRole', 'SQLAgentOperatorRole', 'DatabaseMailUserRole', 'db_ssisadmin', 'db_ssisltduser', 'db_ssisoperator', 'dc_operator', 'dc_admin', 'dc_proxy', 'MS_DataCollectorInternalUser', 'PolicyAdministratorRole', 'ServerGroupAdministratorRole', 'ServerGroupReaderRole', '##MS_PolicyEventProcessingLogin##', '##MS_PolicyTsqlExecutionLogin##', '##MS_AgentSigningCertificate##', 'UtilityCMRReader', 'UtilityIMRWriter', 'UtilityIMRReader', 'db_owner', 'db_accessadmin', 'db_securityadmin', 'db_ddladmin', 'db_backupoperator', 'db_datareader', 'db_datawriter', 'db_denydatareader', 'db_denydatawriter', 'sa', 'AUTORIDADE NT\SISTEMA', 'NT AUTHORITY\SYSTEM' ) AND A.[name] NOT LIKE 'NT SERVICE\%' AND A.[name] NOT LIKE '##MS_%' --------------------------------------------------------------------------------------- -- CRIA OS USUÁRIOS DE DATABASE --------------------------------------------------------------------------------------- DECLARE @Comando VARCHAR(MAX) = '' IF (@Fl_Permissoes_Database = 1) BEGIN DECLARE @Query_Cria_Usuarios VARCHAR(MAX) = ' USE [?]; SELECT DB_NAME() AS [database], A.[name] AS username, A.[type_desc], A.default_schema_name, A.authentication_type_desc, ''USE ['' + DB_NAME() + '']; '' + (CASE WHEN A.[type_desc] LIKE ''%ROLE%'' THEN ''CREATE ROLE ['' + A.[name] + ''];'' ELSE ''CREATE USER ['' + A.[name] + '']'' + (CASE WHEN A.[type_desc] = ''SQL_USER'' AND B.[name] IS NOT NULL THEN '' FOR LOGIN ['' + B.[name] + '']'' WHEN A.[type_desc] = ''SQL_USER'' THEN '''' ELSE '' FOR LOGIN ['' + A.[name] + '']'' END) + '' WITH DEFAULT_SCHEMA=['' + ISNULL(a.default_schema_name, ''dbo'') + ''];'' END) AS GrantCommand, ''USE ['' + DB_NAME() + '']; DROP '' + (CASE WHEN A.[type_desc] LIKE ''%ROLE%'' THEN ''ROLE'' ELSE ''USER'' END) + '' ['' + A.[name] + ''];'' AS RevokeCommand FROM sys.database_principals A WITH(NOLOCK) LEFT JOIN sys.sql_logins B WITH(NOLOCK) ON A.[sid] = B.[sid] WHERE A.[name] NOT IN ( ''TargetServersRole'', ''SQLAgentUserRole'', ''SQLAgentReaderRole'', ''SQLAgentOperatorRole'', ''DatabaseMailUserRole'', ''db_ssisadmin'', ''db_ssisltduser'', ''db_ssisoperator'', ''dc_operator'', ''dc_admin'', ''dc_proxy'', ''MS_DataCollectorInternalUser'', ''PolicyAdministratorRole'', ''ServerGroupAdministratorRole'', ''ServerGroupReaderRole'', ''##MS_PolicyEventProcessingLogin##'', ''##MS_PolicyTsqlExecutionLogin##'', ''##MS_AgentSigningCertificate##'', ''UtilityCMRReader'', ''UtilityIMRWriter'', ''UtilityIMRReader'', ''db_owner'', ''db_accessadmin'', ''db_securityadmin'', ''db_ddladmin'', ''db_backupoperator'', ''db_datareader'', ''db_datawriter'', ''db_denydatareader'', ''db_denydatawriter'', ''sa'', ''AUTORIDADE NT\SISTEMA'', ''NT AUTHORITY\SYSTEM'', ''dbo'', ''guest'', ''INFORMATION_SCHEMA'', ''sys'', ''public'' )' INSERT INTO #Cria_Usuarios EXEC master.dbo.sp_MSforeachdb @Query_Cria_Usuarios END --------------------------------------------------------------------------------------- -- GERA OS ARQUIVOS --------------------------------------------------------------------------------------- -- Ativa o OLE Automation (caso não esteja ativo) IF (@Fl_Ole_Automation_Ativo = 0) BEGIN EXEC sp_configure 'show advanced options', 1 RECONFIGURE; EXEC sp_configure 'Ole Automation Procedures', 1; RECONFIGURE; END DECLARE @Nm_Arquivo VARCHAR(1000), @ConteudoArquivo VARCHAR(MAX) = '' IF (@Fl_Arquivo_Unico = 1) BEGIN SET @Nm_Arquivo = @Ds_Diretorio_Saida + 'sql_logins_' + @@SERVICENAME + '.sql' SET @ConteudoArquivo += '-- CRIAÇÃO DOS LOGINS ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Cria_Logins ORDER BY username SET @ConteudoArquivo += ' -- PERMISSÕES NA INSTÂNCIA ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Servidor ORDER BY username SET @ConteudoArquivo += ' -- PERMISSÕES NAS ROLES DA INSTÂNCIA ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Roles_Servidor ORDER BY username IF (@Fl_Permissoes_Database = 1) BEGIN SET @ConteudoArquivo += ' -- CRIA USUÁRIOS NOS DATABASES' + ' ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Cria_Usuarios ORDER BY [database], username SET @ConteudoArquivo += ' -- PERMISSÕES NOS DATABASES ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Database ORDER BY [database], [username] SET @ConteudoArquivo += ' -- PERMISSÕES NAS ROLES DOS DATABASES' + ' ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Roles ORDER BY [database], [role], [username] END EXEC dbo.stpEscreve_Arquivo_FSO @String = @ConteudoArquivo, -- varchar(max) @Ds_Arquivo = @Nm_Arquivo -- varchar(1501) END ELSE BEGIN IF (OBJECT_ID('tempdb..#Permissoes_por_Usuario') IS NOT NULL) DROP TABLE #Permissoes_por_Usuario CREATE TABLE #Permissoes_por_Usuario ( ranking INT IDENTITY(1, 1) NOT NULL, username VARCHAR(128) NOT NULL ) INSERT INTO #Permissoes_por_Usuario SELECT DISTINCT username COLLATE SQL_Latin1_General_CP1_CI_AI FROM #Cria_Logins UNION SELECT DISTINCT username COLLATE SQL_Latin1_General_CP1_CI_AI FROM #Cria_Usuarios UNION SELECT DISTINCT username COLLATE SQL_Latin1_General_CP1_CI_AI FROM #Permissoes_Database UNION SELECT DISTINCT username COLLATE SQL_Latin1_General_CP1_CI_AI FROM #Permissoes_Roles DECLARE @Contador INT = 1, @Total INT = (SELECT COUNT(*) FROM #Permissoes_por_Usuario), @Usuario VARCHAR(128) WHILE(@Contador <= @Total) BEGIN SELECT @Usuario = username FROM #Permissoes_por_Usuario WHERE ranking = @Contador SET @Nm_Arquivo = @Ds_Diretorio_Saida + REPLACE(@@SERVERNAME, '\', '-') + '_' + REPLACE(@Usuario, '\', '-') + '.sql' SET @ConteudoArquivo = '-- CRIAÇÃO DOS LOGINS ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Cria_Logins WHERE username = @Usuario ORDER BY username SET @ConteudoArquivo += ' -- PERMISSÕES NA INSTÂNCIA ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Servidor WHERE username = @Usuario ORDER BY username SET @ConteudoArquivo += ' -- PERMISSÕES NAS ROLES DA INSTÂNCIA ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Roles_Servidor WHERE username = @Usuario ORDER BY username IF (@Fl_Permissoes_Database = 1) BEGIN SET @ConteudoArquivo += ' -- CRIA USUÁRIOS NOS DATABASES ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Cria_Usuarios WHERE username = @Usuario ORDER BY [database], username SET @ConteudoArquivo += ' -- PERMISSÕES NOS DATABASES ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Database WHERE username = @Usuario ORDER BY username SET @ConteudoArquivo += ' -- PERMISSÕES NAS ROLES DOS DATABASES ' SELECT TOP 9999999999 @ConteudoArquivo += grant_command + ' ' FROM #Permissoes_Roles WHERE username = @Usuario ORDER BY username END EXEC dbo.stpEscreve_Arquivo_FSO @String = @ConteudoArquivo, -- varchar(max) @Ds_Arquivo = @Nm_Arquivo -- varchar(1501) SET @Contador += 1 END END -- Desativa o OLE Automation (Caso esteja desativado antes de executar a SP) IF (@Fl_Ole_Automation_Ativo = 0) BEGIN EXEC sp_configure 'Ole Automation Procedures', 0; RECONFIGURE; END END |
Examples of use
1 Example: Exporting 1 Script by User
1 2 3 4 |
EXEC dbo.stpExporta_Logins @Ds_Diretorio_Saida = 'C:\Teste\', -- varchar(500) @Fl_Permissoes_Database = 1, -- bit @Fl_Arquivo_Unico = 0 -- bit |
Windows AD Authentication User:
User with SQL authentication and password expiration and security policies:
User with SQL authentication and no login:
User with SQL authentication and different user login:
2 Example: Exporting 1 Script Per Instance
1 2 3 4 |
EXEC dbo.stpExporta_Logins @Ds_Diretorio_Saida = 'C:\Teste\', -- varchar(500) @Fl_Permissoes_Database = 1, -- bit @Fl_Arquivo_Unico = 1 -- bit |
Preview of the generated script:
That's it, guys.
I hope this post was helpful to you.
Hug!
SQL Server - How to transfer logins between instances generating user backups, logins and permissions reverse engineering backup logins users permissions roles server database migrate logins transfer logins users
SQL Server - How to transfer logins between instances generating user backups, logins and permissions reverse engineering backup logins users permissions roles server database migrate logins transfer logins users
Good afternoon Dirceu,
I executed the procedure and returned this message, edited and changed the collation to what is configured on the server, even so it returned the message, I ended up getting the script inside the procedure that helped me but I found it so efficient.
Msg 451, Level 16, State 1, Line 6
It is not possible to resolve the grouping conflict between "Latin1_General_CI_AI" and "SQL_Latin1_General_CP1_CI_AI" in the CASE operator that occurs in the SELECT 6 statement column.