If you want to copy an Azure SQL database across subscriptions there is no native way of doing this out-of-the-box in Azure.
You could do a backup and restore, but that is time-consuming and tedious work. Microsoft has pointed out in this article it can "only" be done by using T-SQL. Instead of manually going through this process every time, I decided to create a PowerShell script that encapsulates the SQL commands necessary to do the copy across subscriptions.
Requirements
Before we can proceed, please read the requirements:
- Make sure you have the library "Microsoft Active Directory Authentication Library for Microsoft SQL Server" installed in 64-bit
- Running at least PowerShell 5.1 or higher
Usage
You can use the following format for the script.
1 2 3 4 5 6 7 8 |
.\Copy-AzureSqlDatabase.ps1 -SourceDbServer '<source server>.database.windows.net' ` -SourceDbName '<source database>' ` -SourceLoginType '<AADPassword/SQLUser/AadContext>' ` -SourceUsername '' ` -TargetDbServer '<target server>.database.windows.net' ` -TargetDbName '<target db (will be created)>' ` -TargetLoginType '<AADPassword/SQLUser/AadContext>' ` -TargetUsername ''; |
When you are using either SQL user or AAD Password as a authentication provider, you must provide username and password (must be secure string) for SQL server login.
The code
In the following code which also can be found on GitHub, you only need to adjust from line 31 to 61 according to your environment.
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 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 |
# Must be running PowerShell version 5.1. #Requires -Version 5.1; # Must have the following modules installed. #Requires -Module Az.Accounts; # Make sure that you have the following dll (x64) installed: #https://www.microsoft.com/en-us/download/confirmation.aspx?id=48742 # Also make sure that you have installed the following modules: #Install-Module -Name Az.Accounts -SkipPublisherCheck -Force -Scope CurrentUser; <# .SYNOPSIS Copy Azure SQL Database from one server to another. .DESCRIPTION . .NOTES Version: 1.1 Author: Alex Ø. T. Hansen (ath@systemadmins.com) Creation Date: 12-05-2022 Purpose/Change: Initial script development #> #region begin boostrap ############### Bootstrap - Start ############### # Parameters. Param ( # Source - Username and password for the Azure SQL Server. [Parameter(Mandatory=$false)][string]$SourceUsername, [Parameter(Mandatory=$false)][securestring]$SourcePassword, # Source - Login type to user (AAD or SQL). [Parameter(Mandatory=$false)][ValidateSet("AADPassword", "SQLUser", "AadContext")][string]$SourceLoginType = 'AadContext', #or SQLUser / AadContext # Source - Server where the source database is stored. [Parameter(Mandatory=$true)][string]$SourceDbServer, # Source - Database to copy from. [Parameter(Mandatory=$true)][string]$SourceDbName, # Target - Username and password for the Azure SQL Server. [Parameter(Mandatory=$false)][string]$TargetUsername, [Parameter(Mandatory=$false)][securestring]$TargetPassword, # Target - Login type to user (AAD or SQL). [Parameter(Mandatory=$false)][ValidateSet("AADPassword", "SQLUser", "AadContext")][string]$TargetLoginType = 'AadContext', #or SQLUser / AadContext # Target - Server where the target database will be stored. [Parameter(Mandatory=$true)][string]$TargetDbServer, # Target - The database that will be created in the target with a copy. [Parameter(Mandatory=$true)][string]$TargetDbName ) # Clear host. #Clear-Host; # Import module(s). Import-Module -Name Az.Accounts -Force -DisableNameChecking; ############### Bootstrap - End ############### #endregion #region begin input ############### Input - Start ############### ############### Input - End ############### #endregion #region begin functions ############### Functions - Start ############### # Write to log. Function Write-Log { [cmdletbinding()] Param ( [Parameter(Mandatory=$false)][string]$Text ) # If text is not present. If([string]::IsNullOrEmpty($Text)) { # Write to the console. Write-Host(""); } Else { # Write to the console. Write-Host("[{0}]: {1}" -f (Get-Date).ToString("dd/MM-yyyy HH:mm:ss"), $Text); } } # Convert secure password to plain text. Function Convert-SecurePassword { [CmdletBinding()] param ( # Source and destination database server. [Parameter(Mandatory=$true)][securestring]$SecureString ) # Convert from secure string to plain text. $BSTR = [System.Runtime.InteropServices.Marshal]::SecureStringToBSTR($SecureString); [string]$UnsecurePassword = [System.Runtime.InteropServices.Marshal]::PtrToStringAuto($BSTR); # Return unsecure password. Return $UnsecurePassword; } # Execute query against SQL server. Function Invoke-SqlQuery { [CmdletBinding()] param ( # Connection string to the database. [Parameter(Mandatory=$true)]$ConnectionString, # Query to invoke. [Parameter(Mandatory=$true)][string]$Query ) # Write to log. #Write-Log -Text ("Executing query:"); #Write-Log -Text ($Query); # Create object with connection string. $DatabaseConnection = New-Object System.Data.SqlClient.SqlConnection; $DatabaseConnection.ConnectionString = $ConnectionString.ConnectionString; # If token is specificed. If($ConnectionString.AccessToken) { # Add the token. $DatabaseConnection.AccessToken = $ConnectionString.AccessToken; } # Connect to database. $DatabaseConnection.Open(); # Construct command. $DatabaseQuery = New-Object System.Data.SqlClient.SqlCommand; $DatabaseQuery.Connection = $ConnectionString; $DatabaseQuery.CommandText = $Query; $DatabaseQuery.CommandTimeout = 0;; # Fetch all results. $Dataset = New-Object System.Data.DataSet; $Adapter = New-Object System.Data.SqlClient.SqlDataAdapter; $Adapter.SelectCommand = $DatabaseQuery; $Adapter.Fill($Dataset) | Out-Null; # Close connection. $DatabaseConnection.Close(); # Return results. Return $Dataset.Tables; } # Get Azure access token. Function Get-AzureSqlToken { # Resource URL. $DbResourceUrl = 'https://database.windows.net/'; # Get the access token. $AccessToken = Get-AzAccessToken -ResourceUrl $dbResourceUrl; # Extract the token. [string]$Token = $accessToken.Token; # Return token. Return $Token; } # Construct SQL connection string. Function Get-SqlConnectionString { [CmdletBinding()] param ( # Server name. [Parameter(Mandatory=$true)][string]$Server, # Server port. [Parameter(Mandatory=$false)][int]$Port = 1433, # Server port. [Parameter(Mandatory=$false)][string]$Database = "master", # Username. [Parameter(Mandatory=$false)][string]$Username, # Password. [Parameter(Mandatory=$false)][securestring]$Password, # Connection type. [Parameter(Mandatory=$true)][ValidateSet("AADPassword", "SQLUser", "AadContext")][string]$LoginType ) # If the password is set. If($Password) { # Convert from secure string to plain text. [string]$UnsecurePassword = Convert-SecurePassword -SecureString $Password; } # If the login type is "Azure Active Directory - Passsword". If($LoginType -eq "AADPassword") { # Write to log. Write-Log ("Using Azure AD password login for server '{0}' for data '{1}'" -f $Server, $Database); # Get basic connection string. [string]$ConnectionString = ('Server=tcp:{0},{1};Persist Security Info=False;Authentication=Active Directory Password;User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=False;TrustServerCertificate=True;;' -f $Server, $Port, $Username, $UnsecurePassword); } # Else if the login type is "SQL Server Authentication". ElseIf($LoginType -eq "SQLUser") { # Write to log. Write-Log ("Using SQL login for server '{0}' for data '{1}'" -f $Server, $Database); # Get basic connection string. [string]$ConnectionString = ('Server=tcp:{0},{1};User ID={2};Password={3};MultipleActiveResultSets=False;Encrypt=False;TrustServerCertificate=True;' -f $Server, $Port, $Username, $UnsecurePassword); } # Else if the login type is "Azure AD Context". ElseIf($LoginType -eq "AadContext") { # Write to log. Write-Log ("Using Azure AD context login for server '{0}' for data '{1}'" -f $Server, $Database); # Get basic connection string. [string]$ConnectionString = ('Data Source={0};Trusted_Connection=False;Encrypt=True;' -f $Server); # Get Azure AD token. $AadAccessToken = Get-AzureSqlToken; } # If database is set else we will connect to "master". If(!([string]::IsNullOrEmpty($Database))) { # If Azure AD context authentication. If($LoginType -eq "AadContext") { # Add database to string. $ConnectionString += ('Initial Catalog={0};' -f $Database); } Else { # Add database to string. $ConnectionString += ('Database={0};' -f $Database); } } # Create object. $SqlConnection = [PSCustomObject]@{ ConnectionString = $ConnectionString; }; # If token is set. If($AadAccessToken) { # Set Azure AD token. $SqlConnection | Add-Member -MemberType NoteProperty -Name AccessToken -Value $AadAccessToken -Force; } # Return connection string. Return $SqlConnection; } # Create SQL login. Function New-SqlLogin { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName, # SID. [Parameter(Mandatory=$false)][string]$SID, # Password. [Parameter(Mandatory=$true)][securestring]$Password ) # If the password is set. If($Password) { # Convert from secure string to plain text. [string]$UnsecurePassword = Convert-SecurePassword -SecureString $Password; } # Get existing. $SqlLogins = Get-SqlLogin -ConnectionString $ConnectionString; # Check if login already exist. If($SqlLogins | Where-Object {$_.Name -eq $LoginName}) { # Write to log. Write-Log ("Login '{0}' already exist" -f $LoginName); # Update password. Reset-SqlLoginPassword -ConnectionString $ConnectionString -LoginName $LoginName -Password $Password; } Else { # Construct query. [string]$Query = @" CREATE LOGIN [$LoginName] WITH PASSWORD = N'$UnsecurePassword' "@; # If SID is set. If(!([string]::IsNullOrEmpty($SID))) { # Add to query. $Query = ("{0}, SID = {1}" -f $Query, $SID); } # Try to create. Try { # Create SQL login. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Creating new login named '{0}'" -f $LoginName); } Catch { # Write to log. Write-Log ("Something went wrong creating the login named '{0}'" -f $LoginName); } } } # Create SQL login. Function New-SqlUser { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName, # Default schema. [Parameter(Mandatory=$true)][ValidateSet("dbo")][string]$DefaultSchema ) # Get existing. $SqlUsers = Get-SqlUser -ConnectionString $ConnectionString; # Check if login already exist. If($SqlUsers | Where-Object {$_.Name -eq $LoginName}) { # Write to log. Write-Log ("SQL user '{0}' already exist" -f $LoginName); } Else { # Construct query. [string]$Query = @" CREATE USER [$LoginName] FOR LOGIN [$LoginName] WITH DEFAULT_SCHEMA=[$DefaultSchema]; "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Creating new user named '{0}' with the default schema '{1}'" -f $LoginName, $DefaultSchema); } Catch { # Write to log. Write-Log ("Something went wrong creating the login named '{0}' with the default schema '{1}'" -f $LoginName, $DefaultSchema); } } } # Reset SQL login password. Function Reset-SqlLoginPassword { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName, # Password. [Parameter(Mandatory=$true)][securestring]$Password ) # If the password is set. If($Password) { # Convert from secure string to plain text. [string]$UnsecurePassword = Convert-SecurePassword -SecureString $Password; } # Construct query. [string]$Query = @" ALTER LOGIN $LoginName WITH PASSWORD=N'$UnsecurePassword'; "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Changed password for login '{0}'" -f $LoginName); } Catch { # Write to log. Write-Log ("Something went wrong changing password for login '{0}'" -f $LoginName); } } # Add SQL role for login. Function Add-SqlLoginRole { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName, # Role. [Parameter(Mandatory=$true)][ValidateSet("dbmanager", "db_owner")][string]$Role ) # Construct query. [string]$Query = @" ALTER ROLE [$Role] ADD MEMBER [$LoginName]; "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Adding role to '{0}' with '{1}'" -f $LoginName, $Role); } Catch { # Write to log. Write-Log ("Something went wrong changing role for login '{0}'" -f $LoginName); } } # Get SQL login. Function Get-SqlLogin { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString ) # Construct query. [string]$Query = @" SELECT * FROM sysusers WHERE islogin = 1 "@; # Try to create. Try { # Invoke query. $Result = Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Return result. Return $Result; } Catch { # Write to log. Write-Log ("Something went wrong, getting logins from the database server"); } } # Get SQL user. Function Get-SqlUser { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString ) # Construct query. [string]$Query = @" select * from sys.database_principals where type not in ('A', 'G', 'R') and sid is not null and name != 'guest' "@; # Try to create. Try { # Invoke query. $Result = Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Return result. Return $Result; } Catch { # Write to log. Write-Log ("Something went wrong, getting logins from the database server"); } } # Convert binary SID to hash string. Function ConvertTo-SQLHashString { [CmdletBinding()] param ( [Parameter(Mandatory=$true)]$Binary ) # Add prefix to string. $Result = '0x'; # Foreach binary object. $Binary | ForEach-Object {$Result += ('{0:X}' -f $_).PadLeft(2, '0')}; # Return result. Return $Result; } # Create new database from copy. Function New-SqlDatabaseFromCopy { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Source server name. [Parameter(Mandatory=$true)][string]$SourceServer, # Source database name. [Parameter(Mandatory=$true)][string]$SourceDatabaseName, # Destination database name. [Parameter(Mandatory=$true)][string]$DestinationDatabaseName, # Elastic pool name. [Parameter(Mandatory=$false)][string]$ElasticPoolName ) # If elastic pool name is set. If(!([string]::IsNullOrEmpty($ElasticPoolName))) { # Construct query. [string]$Query = @" CREATE DATABASE [$DestinationDatabaseName] AS COPY OF [$SourceServer].[$SourceDatabaseName] (SERVICE_OBJECTIVE = ELASTIC_POOL(name =[$ElasticPoolName])); "@; } # No elastic pool name set. Else { # Construct query. [string]$Query = @" CREATE DATABASE [$DestinationDatabaseName] AS COPY OF [$SourceServer].[$SourceDatabaseName]; "@; } # Try to create. Try { # Write to log. Write-Log ("Copying database from '{0}' to '{1}'" -f $SourceDatabaseName, $DestinationDatabaseName); # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; } Catch { # Write to log. Write-Log ("Something went wrong, while copying the database"); } } # Get elastic pool name for databases. Function Get-SqlElasticPoolNameForDbs { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString ) # Construct query. [string]$Query = @" SELECT @@SERVERNAME as [ServerName], dso.elastic_pool_name, d.name as DatabaseName, dso.edition FROM sys.databases d inner join sys.database_service_objectives dso on d.database_id = dso.database_id WHERE d.Name <> 'master' "@; # Try to create. Try { # Invoke query. $Result = Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Retur result. Return $Result; } Catch { # Write to log. Write-Log ("Something went wrong, while getting the elastic pool names for databases"); } } # Drop SQL login. Function Remove-SqlLogin { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName ) # Construct query. [string]$Query = @" DROP LOGIN [$LoginName] "@; # Get SQL logins. $SqlLogins = Get-SqlLogin -ConnectionString $ConnectionString; # Check if login already exist. If(!($SqlLogins | Where-Object {$_.Name -eq $LoginName})) { # Write to log. Write-Log ("SQL login '{0}' doesnt exist" -f $LoginName); } # Login exist. Else { # Try to delete. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Dropped SQL login '{0}'" -f $LoginName); } Catch { # Write to log. Write-Log ("Something went wrong dropping SQL login '{0}'" -f $LoginName); } } } # Drop SQL user. Function Remove-SqlUser { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$LoginName ) # Construct query. [string]$Query = @" DROP USER [$LoginName] "@; # Get SQL logins. $SqlUsers = Get-SqlUser -ConnectionString $ConnectionString; # Check if login already exist. If(!($SqlUsers | Where-Object {$_.Name -eq $LoginName})) { # Write to log. Write-Log ("SQL user '{0}' doesnt exist" -f $LoginName); } # User exist. Else { # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Dropped SQL user '{0}'" -f $LoginName); } Catch { # Write to log. Write-Log ("Something went wrong dropping SQL user '{0}'" -f $LoginName); } } } # Drop SQL database. Function Remove-SqlDatabase { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString, # Login name. [Parameter(Mandatory=$true)][string]$Database ) # Construct query. [string]$Query = @" DROP DATABASE IF EXISTS [$Database]; "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; # Write to log. Write-Log ("Dropped database '{0}', if it existed" -f $Database); } Catch { # Write to log. Write-Log ("Something went wrong dropping SQL database '{0}'" -f $Database); } } # Copy SQL database from server to another in Azure. Function Copy-AzureSqlDatabase { [CmdletBinding()] param ( # Source database server/database details. [Parameter(Mandatory=$true)][string]$SourceDbServer, [Parameter(Mandatory=$true)][string]$SourceDbName, [Parameter(Mandatory=$false)][string]$SourceUsername, [Parameter(Mandatory=$false)][securestring]$SourcePassword, [Parameter(Mandatory=$true)][ValidateSet("AADPassword", "SQLUser", "AadContext")][string]$SourceLoginType, # Target database server/database details. [Parameter(Mandatory=$true)][string]$TargetDbServer, [Parameter(Mandatory=$true)][string]$TargetDbName, [Parameter(Mandatory=$false)][string]$TargetUsername, [Parameter(Mandatory=$false)][securestring]$TargetPassword, [Parameter(Mandatory=$true)][ValidateSet("AADPassword", "SQLUser", "AadContext")][string]$TargetLoginType ) # Name and password of the user which will be created to do the copy (it will be created). [string]$SqlUsername = 'SqlCopyAccount'; [securestring]$SqlPassword = (New-Password -Length 18 | ConvertTo-SecureString -AsPlainText -Force); # Create connection string to source master database. $SourceConnectionStringMaster = Get-SqlConnectionString -Server $SourceDbServer ` -Username $SourceUsername ` -Password $SourcePassword ` -LoginType $SourceLoginType; # Create connection string to source application database. $SourceConnectionStringApplication = Get-SqlConnectionString -Server $SourceDbServer ` -Database $SourceDbName ` -Username $SourceUsername ` -Password $SourcePassword ` -LoginType $SourceLoginType; # Write to log. Write-Log ("Connecting to '{0}' (source)" -f $SourceDbServer); # Drop existing login. Remove-SqlLogin -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername; # Drop existing user in master database. Remove-SqlUser -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername; # Drop existing user in application database. Remove-SqlUser -ConnectionString $SourceConnectionStringApplication -LoginName $SqlUsername; # New SQL login in master. New-SqlLogin -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername -Password $SqlPassword; # Create SQL user in master. New-SqlUser -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername -DefaultSchema dbo; # Add role to master. Add-SqlLoginRole -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername -Role dbmanager; # New SQL user on application database. New-SqlUser -ConnectionString $SourceConnectionStringApplication -LoginName $SqlUsername -DefaultSchema dbo; # Add role to application database. Add-SqlLoginRole -ConnectionString $SourceConnectionStringApplication -LoginName $SqlUsername -Role db_owner; # Get source SQL user SID. [string]$SourceSqlLoginSid = (Get-SqlLogin -ConnectionString $SourceConnectionStringMaster | Where-Object {$_.Name -eq $SqlUsername} | Select-Object @{Name = "SID"; Expression = {ConvertTo-SQLHashString -Binary $_.sid}}).SID; # Create connection string to target master database. $DestinationConnectionStringMaster = Get-SqlConnectionString -Server $TargetDbServer ` -Username $TargetUsername ` -Password $TargetPassword ` -LoginType $TargetLoginType; # Create connection string to target master database using SQL credentail. $DestinationConnectionStringMasterSqlCred = Get-SqlConnectionString -Server $TargetDbServer ` -Username $SqlUsername ` -Password $SqlPassword ` -LoginType SQLUser; # Write to log. Write-Log ""; Write-Log ("Connecting to '{0}' (target)" -f $TargetDbServer); # Check if source and destination is not the same. If($SourceDbServer -ne $TargetDbServer) { # Drop existing login. Remove-SqlLogin -ConnectionString $DestinationConnectionStringMaster -LoginName $SqlUsername; # Drop existing user in master database. Remove-SqlUser -ConnectionString $DestinationConnectionStringMaster -LoginName $SqlUsername; # New SQL login in master. New-SqlLogin -ConnectionString $DestinationConnectionStringMaster ` -LoginName $SqlUsername ` -Password $SqlPassword ` -SID $SourceSqlLoginSid; # New SQL user on master database. New-SqlUser -ConnectionString $DestinationConnectionStringMaster ` -LoginName $SqlUsername ` -DefaultSchema dbo; # Add role to master database. Add-SqlLoginRole -ConnectionString $DestinationConnectionStringMaster ` -LoginName $SqlUsername ` -Role dbmanager; } # Server source and destination is the same. Else { # Write to log. Write-Log ("Source and target database server is the same, skipping login/user creation" -f $TargetDbServer); } # Drop database on destination if it exists. Remove-SqlDatabase -ConnectionString $DestinationConnectionStringMaster -Database $TargetDbName; # Get elastic pool name. $TargetElasticPoolName = Get-SqlElasticPoolNameForDbs -ConnectionString $DestinationConnectionStringMaster | Select-Object -ExpandProperty elastic_pool_name -First 1; # Copy database from source to a new database. New-SqlDatabaseFromCopy -ConnectionString $DestinationConnectionStringMasterSqlCred ` -SourceServer ([string]($SourceDbServer -split "\.")[0]) ` -SourceDatabaseName $SourceDbName ` -DestinationDatabaseName $TargetDbName ` -ElasticPoolName $TargetElasticPoolName; # If CDC is enabled. If(Get-AzureSqlDatabaseCdc -ConnectionString $DestinationConnectionStringMaster | Where-Object {$_.Name -eq $TargetDbName}) { # Create connection string to target application database. $DestinationConnectionStringApplication = Get-SqlConnectionString -Server $TargetDbServer ` -Database $TargetDbName ` -Username $TargetUsername ` -Password $TargetPassword ` -LoginType $TargetLoginType; # Write to log. Write-Log ("Disabling CDC for database '{0}'" -f $TargetDbName); # Disable CDC. Disable-AzureSqlDatabaseCdc -ConnectionString $DestinationConnectionStringApplication; } # Clean up SQL login and user permission. Remove-SqlLogin -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername; Remove-SqlUser -ConnectionString $SourceConnectionStringMaster -LoginName $SqlUsername; Remove-SqlUser -ConnectionString $SourceConnectionStringApplication -LoginName $SqlUsername; Remove-SqlLogin -ConnectionString $DestinationConnectionStringMaster -LoginName $SqlUsername; Remove-SqlUser -ConnectionString $DestinationConnectionStringMaster -LoginName $SqlUsername; } # Generate password. Function New-Password { param ( [Parameter(Mandatory = $false)][int]$Length = 20 ) # Characters allowed. $CharSet = 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789!@$'.ToCharArray(); # Create new crypto object. $RNGCrypto = New-Object System.Security.Cryptography.RNGCryptoServiceProvider; # Convert length to bytes. $Bytes = New-Object byte[]($Length); # Get bytes. $RNGCrypto.GetBytes($Bytes); # New char object. $Result = New-Object char[]($Length); # For each byte. for ($i = 0 ; $i -lt $Length ; $i++) { # Add random char to result. $Result[$i] = $CharSet[$Bytes[$i]%$CharSet.Length]; } # Combine and return charset. Return (-join $Result) + "=="; } # Get database with CDC enabled. Function Get-AzureSqlDatabaseCdc { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString ) # Construct query. [string]$Query = @" SELECT name, database_id, is_cdc_enabled FROM sys.databases WHERE is_cdc_enabled = 1 "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; } Catch { # Write to log. Write-Log ("Something went wrong getting databases with CDC enabled"); } } # Disable database CDC. Function Disable-AzureSqlDatabaseCdc { [CmdletBinding()] param ( # Connection string. [Parameter(Mandatory=$true)]$ConnectionString ) # Construct query. [string]$Query = @" EXEC sys.sp_cdc_disable_db; "@; # Try to create. Try { # Invoke query. Invoke-SqlQuery -ConnectionString $ConnectionString -Query $Query; } Catch { # Write to log. Write-Log ("Something went wrong getting databases with CDC enabled"); } } ############### Functions - End ############### #endregion #region begin main ############### Main - Start ############### # Copy Azure SQL database. Copy-AzureSqlDatabase -SourceDbServer $SourceDbServer ` -SourceDbName $SourceDbName ` -SourceUsername $SourceUsername ` -SourcePassword $SourcePassword ` -SourceLoginType $SourceLoginType ` -TargetDbServer $TargetDbServer ` -TargetDbName $TargetDbName ` -TargetUsername $TargetUsername ` -TargetPassword $TargetPassword ` -TargetLoginType $TargetLoginType; ############### Main - End ############### #endregion #region begin finalize ############### Finalize - Start ############### ############### Finalize - End ############### #endregion |
Comments