A while ago a colleague of mine wrote a TSQL script to help with suggesting a MaxServerMemory value and a little less time ago we worked together to re-write that script for SQL 2012. While I haven't "checked" it against SQL 2014 the principals are the same, and the reason I am blogging it today is because I am always looking for the script or URL to direct people to so this post makes that easier :)
Of cause there is no black and white recommendation for MaxServerMemory as it is workload dependent. However this script can assist with understanding what that workload requirement is within a SQL Server Instance, please ensure you carefully consider all other memory needs of the server such as additional SQL Instances, and services such as AV, Backups, Monitoring, etc.
Ping back to Tara S. Jana's site http://sqlmasters.jimdo.com/scripts-tsql
Legal Stuff: As always the contents of this blog is provided “as-is”. The information, opinions and views expressed are those of the author and do not necessarily state or reflect those of any other company with affiliation to the products discussed. This includes any URLs or Tools. The author does not accept any responsibility from the use of the information or tools mentioned within this blog, and recommends adequate evaluation against your own requirements to measure suitability.
Of cause there is no black and white recommendation for MaxServerMemory as it is workload dependent. However this script can assist with understanding what that workload requirement is within a SQL Server Instance, please ensure you carefully consider all other memory needs of the server such as additional SQL Instances, and services such as AV, Backups, Monitoring, etc.
SET NOCOUNT ON; DECLARE --@pg_size INT, @Instancename varchar(50), --@RecMem int, @MaxMem int, @MaxRamServer int, @sql varchar(max), @SQLVersion tinyint SELECT @SQLVersion = @@MicrosoftVersion / 0x01000000 -- Get major version -- SELECT physical_memory_kb as ServerRAM_KB from sys.dm_os_sys_info -- SELECT @pg_size = low from master..spt_values where number = 1 and type = 'E' -- SELECT @Instancename = LEFT([object_name], (CHARINDEX(':',[object_name]))) FROM sys.dm_os_performance_counters WHERE counter_name = 'Buffer cache hit ratio' PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' PRINT 'Optimal MaxServermemory Setting for SQL Server instance ' + @@SERVERNAME + ' (' + CAST(SERVERPROPERTY('productversion') AS VARCHAR) + ' - ' + SUBSTRING(@@VERSION, CHARINDEX('X',@@VERSION),4) + ' - ' + CAST(SERVERPROPERTY('edition') AS VARCHAR) + ')' PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' IF @SQLVersion = 11 BEGIN PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' PRINT 'Total Memory on the Server (MB)' EXEC sp_executesql N'set @_MaxRamServer= (select physical_memory_kb/1024 from sys.dm_os_sys_info)', N'@_MaxRamServer int OUTPUT', @_MaxRamServer = @MaxRamServer OUTPUT Print @MaxRamServer PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' END ELSE IF @SQLVersion in (10,9) BEGIN PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' PRINT 'Total Memory on the Server (MB)' EXEC sp_executesql N'set @_MaxRamServer= (select physical_memory_in_bytes/1024/1024 from sys.dm_os_sys_info)', N'@_MaxRamServer int OUTPUT', @_MaxRamServer = @MaxRamServer OUTPUT Print @MaxRamServer PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' END ELSE BEGIN PRINT 'Script only supports SQL Server 2005 or later.' RETURN END --SELECT @RecMem=physical_memory_kb/1024 from sys.dm_os_sys_info SET @MaxMem = CASE WHEN @MaxRamServer < = 1024*2 THEN @MaxRamServer - 512 /*When the RAM is Less than or equal to 2GB*/ WHEN @MaxRamServer < = 1024*4 THEN @MaxRamServer - 1024 /*When the RAM is Less than or equal to 4GB*/ WHEN @MaxRamServer < = 1024*16 THEN @MaxRamServer - 1024 - Ceiling((@MaxRamServer-4096) / (4.0*1024))*1024 /*When the RAM is Less than or equal to 16GB*/ -- My machines memory calculation -- RAM= 16GB -- Case 3 as above:- 16384 RAM-> MaxMem= 16384-1024-[(16384-4096)/4096] *1024 -- MaxMem= 12106 WHEN @MaxRamServer > 1024*16 THEN @MaxRamServer - 4096 - Ceiling((@MaxRamServer-1024*16) / (8.0*1024))*1024 /*When the RAM is Greater than or equal to 16GB*/ END SET @sql=' EXEC sp_configure ''Show Advanced Options'',1; RECONFIGURE WITH OVERRIDE; EXEC sp_configure ''max server memory'','+CONVERT(VARCHAR(6), @maxMem)+'; RECONFIGURE WITH OVERRIDE;' PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------' PRINT 'Optimal MaxServerMemory Setting for this instance of SQL' Print (@sql) PRINT '------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------'
Ping back to Tara S. Jana's site http://sqlmasters.jimdo.com/scripts-tsql
Legal Stuff: As always the contents of this blog is provided “as-is”. The information, opinions and views expressed are those of the author and do not necessarily state or reflect those of any other company with affiliation to the products discussed. This includes any URLs or Tools. The author does not accept any responsibility from the use of the information or tools mentioned within this blog, and recommends adequate evaluation against your own requirements to measure suitability.
No comments:
Post a Comment