USE [msdb] GO DECLARE @jobid UNIQUEIDENTIFIER = NULL SELECT @jobid = job_id FROM msdb.dbo.sysjobs WHERE name = 'Cluster Memory Management' IF @jobid IS NOT NULL BEGIN EXEC msdb.dbo.sp_delete_job @job_id=@jobid, @delete_unused_schedule=1 END GO /****** Object: Job [Utility - Cluster Memory Management] Script Date: 11/10/2013 9:16:50 PM ******/ BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 /****** Object: JobCategory [Database Maintenance Utility] Script Date: 11/10/2013 9:16:50 PM ******/ IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance Utility' AND category_class=1) BEGIN EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance Utility' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback END DECLARE @jobId BINARY(16) EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Utility - Cluster Memory Management', @enabled=1, @notify_level_eventlog=0, @notify_level_email=0, @notify_level_netsend=0, @notify_level_page=0, @delete_level=0, @description=N'No description available.', @category_name=N'Database Maintenance Utility', @owner_login_name=N'LIBERTY\SITUtility', @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback /****** Object: Step [Configure memory] Script Date: 11/10/2013 9:16:50 PM ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Configure memory', @step_id=1, @cmdexec_success_code=0, @on_success_action=1, @on_success_step_id=0, @on_fail_action=2, @on_fail_step_id=0, @retry_attempts=0, @retry_interval=0, @os_run_priority=0, @subsystem=N'PowerShell', @command=N'function Get-SQLInstances { $Computer = [string](hostname) -replace ''(.*?)\..+'',''$1'' $Instances = $null [string[]]$InstanceList = $null Write-Verbose ("Checking {0}" -f $Computer) Try { $reg = [Microsoft.Win32.RegistryKey]::OpenRemoteBaseKey(''LocalMachine'', $Computer) $regKey= $reg.OpenSubKey("SOFTWARE\\Microsoft\\Microsoft SQL Server") If ($regKey.GetSubKeyNames() -contains "Instance Names") { $regKey= $reg.OpenSubKey("SOFTWARE\\Microsoft\\Microsoft SQL Server\\Instance Names\\SQL" ) $instances = @($regkey.GetValueNames()) } ElseIf ($regKey.GetValueNames() -contains ''InstalledInstances'') { $isCluster = $False $instances = $regKey.GetValue(''InstalledInstances'') } Else { Continue } If ($instances.count -gt 0) { ForEach ($instance in $instances) { $nodes = New-Object System.Collections.Arraylist $clusterName = $Null $isCluster = $False $instanceValue = $regKey.GetValue($instance) $instanceReg = $reg.OpenSubKey("SOFTWARE\\Microsoft\\Microsoft SQL Server\\$instanceValue") If ($instanceReg.GetSubKeyNames() -contains "Cluster") { $isCluster = $True $instanceRegCluster = $instanceReg.OpenSubKey(''Cluster'') $clusterName = $instanceRegCluster.GetValue(''ClusterName'') } $InstanceObject = New-Object PSObject -Property @{ Computername = $Computer SQLInstance = $instance isCluster = $isCluster ClusterName = $clusterName FullName = { If ($Instance -eq ''MSSQLSERVER'') { $clusterName } ElseIf ($Instance -ne ''SQLEXPRESS'') { "$clusterName\$instance" } Else { Continue } }.InvokeReturnAsIs()} $InstanceList = $InstanceList + $InstanceObject.FullName; } } } Catch { Write-Warning ("{0}: {1}" -f $Computer,$_.Exception.Message) } return $InstanceList; } #Get local machine [string]$Computer = [string](hostname) #Get total physical memory [int64]$total_memory_MB = (Get-WmiObject CIM_ComputerSystem).TotalPhysicalMemory / 1024 / 1024; #Populate array of instances and their clustered status $InstanceNames = $null $InstanceNames = Get-SQLInstances $LocalInstances = $null $LocalInstances = @() #Populate current host and memory values [System.Reflection.Assembly]::LoadWithPartialName(‘Microsoft.SqlServer.SMO’) | out-null foreach ($InstanceName in $InstanceNames) { $CurrentServer = $null $CurrentServer = New-Object (''Microsoft.SqlServer.Management.SMO.Server'') "$InstanceName" #Check for local host only if ([string]::Compare($Computer,[string]($CurrentServer.ComputerNamePhysicalNETBIOS), $true) -eq 0) { $LocalInstances += $InstanceName; } } #Calculate memory values [int64]$memory_per_instance_MB = $null [int64]$OS_memory_buffer_MB = $null #Calculate OS memory buffer switch -regex ($total_memory_MB) { "[1-2]\d{3}" {$OS_memory_buffer_MB = 512;} "[3-9]\d{3}" {$OS_memory_buffer_MB = 1024;} "[1]\d{4}" {$OS_memory_buffer_MB = 2048;} "[2]\d{4}" {$OS_memory_buffer_MB = 3072;} "[3-4]\d{4}" {$OS_memory_buffer_MB = 4096;} "[5-9]\d{4}" {$OS_memory_buffer_MB = 6144;} "\d{6}" {$OS_memory_buffer_MB = 8192;} } #Evenly distribute memory across all instances after taking into account the OS $memory_per_instance_MB = ($total_memory_MB - $OS_memory_buffer_MB) / $LocalInstances.length; #Alter memory values foreach ($LocalInstance in $LocalInstances) { $CurrentServer = $null $CurrentServer = New-Object (''Microsoft.SqlServer.Management.SMO.Server'') "$LocalInstance" #Don''t induce change if the net result is the same if ($CurrentServer.Configuration.MaxServerMemory.ConfigValue -ne $memory_per_instance_MB) { #Write-Host "-----------------------------------------------------------------------------" -ForegroundColor green #[int64]$CurrentMemoryValue = $CurrentServer.Configuration.MaxServerMemory.ConfigValue #Write-Host "Changing $LocalInstance''s maximum server memory from ($CurrentMemoryValue MB) to ($memory_per_instance_MB MB)." -ForegroundColor magenta $CurrentServer.Configuration.MaxServerMemory.ConfigValue = $memory_per_instance_MB; $CurrentServer.Alter(); #Write-Host "$LocalInstance''s maximum server memory is set." -ForegroundColor magenta } } ', @database_name=N'master', @flags=0, @proxy_name=N'UtilityProxy' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'Start up (on failover)', @enabled=1, @freq_type=64, @freq_interval=0, @freq_subday_type=0, @freq_subday_interval=0, @freq_relative_interval=0, @freq_recurrence_factor=0, @active_start_date=20131110, @active_end_date=99991231, @active_start_time=0, @active_end_time=235959 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback COMMIT TRANSACTION GOTO EndSave QuitWithRollback: IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION EndSave: GO