Share via


Powershell Script to Add New Database to Existing Availability Groups

One of the common tasks for DBA to add the new database to existing availability groups. This can be done fairly easy via SSMS. The requirement is how to deploy the new database from Team Foundation Server (TFS) to SQL Server Alway on AG listener and automatically add this database to Availability groups. Here is the script written for this purpose. I have used powershell as this one of the tool which is very useful and easy way to automate from TFS.

Write-host "Adding Database to existing Availability Groups";
  
$BackupLocation = "Provide the shared location where both nodes can access";
$dbName = "DatabaseName";
$ListenerName = "AGListener"
  
$ListReplicaNames = Invoke-Sqlcmd -Query "SELECT name, replica_server_name, role_desc FROM master.sys.availability_replicas as  AR
INNER JOIN master.sys.dm_hadr_availability_replica_states as  ARS ON AR.replica_id = ARS.replica_id
INNER JOIN master.sys.availability_groups as  AG ON AR.group_id = AG.group_id" -ServerInstance $ListenerName
$replica1 = $ListReplicaNames | Where-Object {$_.role_desc -eq "PRIMARY"}
$replica2 = $ListReplicaNames | Where-Object {$_.role_desc -eq "SECONDARY"}
$server1 = $replica1.replica_server_name
$server2 = $replica2.replica_server_name
$AGName = $replica1.name
$dateStamp=get-date
  
try
{
  
    #Create Backup of DB node 1
    $bakPath = $BackupLocation + $dbName + "_" + $dateStamp + ".bak"
    $trnPath = $BackupLocation + $dbName + "_" + $dateStamp + ".trn"
  
    set-location "SQLSERVER:\SQL\$server1\Databases"
    Write-Host "Backing up $server1 $dbName to $bakPath"
    Backup-SqlDatabase -database $dbName -backupFile $bakPath
    Write-Host " ... backup complete"
  
    Write-Host "Backing up $server1 $dbName to $trnPath"
    Backup-SqlDatabase -Database $dbName -BackupFile $trnPath -BackupAction Log
    Write-Host " ... backup complete"
  
    #Resotore Backup of DB in node 2
    set-location "SQLSERVER:\SQL\$server2\Databases"
    Write-Host "Restoring $server2 $dbName from $bakPath"
    Restore-SqlDatabase -Database $dbName -BackupFile $bakPath -ServerInstance $server2 -NoRecovery
    Write-Host " ... restoring complete"
  
    Write-Host "Restoring $server2 $dbName from $trnPath"
    Restore-SqlDatabase -Database $dbName -BackupFile $trnPath -ServerInstance $server2 -RestoreAction Log -NoRecovery
    Write-Host " ... restoring complete"
 
    #Add Database in AvailabilityGroups
    Write-Host "Add database: $dbName to availability group: $AGName"
    Add-SqlAvailabilityDatabase -Path SQLSERVER:\Sql\$server1\AvailabilityGroups\$AGName\AvailabilityDatabases -Database $dbName
    Add-SqlAvailabilityDatabase -Path SQLSERVER:\Sql\$server2\AvailabilityGroups\$AGName\AvailabilityDatabases -Database $dbName
    Write-Host " Database $dbname has been added"
}
catch
{
    $ErrorMessage = $_.Exception.Message
    Write-Host $ErrorMessage
}
finally
{
    # This will write the execution time logged in the AddDBToAG.log file
    $Time=Get-Date
    "This script executed at $Time" | out-file D:\logs\AddDBToAG.log -append
}

Regards,
Ramasankar Molleti