@@ -309,7 +309,8 @@ VALUES
309309(1 , 1510 , ' Most of the IDENTITY range is used' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1510' , ' VIEW DATABASE STATE' ),
310310(1 , 1520 , ' Most of the sequence range is used' , 95 , ' https://aka.ms/sqldbtipswiki#tip_id-1520' , ' VIEW DATABASE STATE' ),
311311(1 , 1530 , ' Disabled or not trusted constraints found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1530' , ' VIEW DATABASE STATE' ),
312- (1 , 1540 , ' Page compression is ineffective for some indexes' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1540' , ' VIEW SERVER STATE' )
312+ (1 , 1540 , ' Page compression is ineffective for some indexes' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1540' , ' VIEW SERVER STATE' ),
313+ (1 , 1550 , ' Recent high severity memory pressure found' , 90 , ' https://aka.ms/sqldbtipswiki#tip_id-1550' , ' VIEW SERVER STATE' )
313314;
314315
315316-- Top queries
@@ -3994,6 +3995,46 @@ SELECT 1450 AS tip_id,
39943995FROM local_storage_quota
39953996WHERE quota_usage > @MinLocalStorageQuotaUsageRatio;
39963997
3998+ -- Recent high severity memory pressure
3999+ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1550 ) AND execute_indicator = 1 )
4000+
4001+ WITH memory_health_agg AS
4002+ (
4003+ SELECT TOP (3 ) clerk_type,
4004+ MAX (pages_allocated_kb) AS max_pages_allocated_kb,
4005+ MIN (allocation_potential_memory_mb) AS min_allocation_potential_memory_mb
4006+ FROM sys .dm_os_memory_health_history
4007+ CROSS APPLY OPENJSON (top_memory_clerks)
4008+ WITH (
4009+ clerk_type SYSNAME ' $.clerk_type' ,
4010+ pages_allocated_kb BIGINT ' $.pages_allocated_kb'
4011+ )
4012+ WHERE severity_level_desc = ' HIGH'
4013+ GROUP BY clerk_type
4014+ ORDER BY max_pages_allocated_kb DESC
4015+ ),
4016+ memory_health_tip AS
4017+ (
4018+ SELECT MIN (min_allocation_potential_memory_mb) AS min_allocation_potential_memory_mb,
4019+ STRING_AGG (clerk_type, ' , ' ) WITHIN GROUP (ORDER BY max_pages_allocated_kb DESC ) AS top_clerks
4020+ FROM memory_health_agg
4021+ HAVING COUNT (1 ) > 0
4022+ )
4023+ INSERT INTO @DetectedTip (tip_id, details)
4024+ SELECT 1550 AS tip_id,
4025+ CONCAT (
4026+ @NbspCRLF,
4027+ ' In the last hour, there were occurrences of high-severity memory pressure in the ' ,
4028+ IIF (dso .service_objective = ' ElasticPool' , CONCAT (QUOTENAME (dso .elastic_pool_name ), ' elastic pool.' ), CONCAT (QUOTENAME (DB_NAME (dso .database_id )), ' database.' )), @CRLF,
4029+ ' Minimum allocation potential memory (MB): ' , FORMAT (min_allocation_potential_memory_mb, ' #,0.00' ), @CRLF,
4030+ ' Top memory clerks ordered by allocated memory pages: ' ,
4031+ top_clerks, @CRLF
4032+ ) AS details
4033+ FROM memory_health_tip
4034+ CROSS JOIN sys .database_service_objectives AS dso
4035+ WHERE dso .database_id = DB_ID ()
4036+ ;
4037+
39974038END ; -- end tips requiring VIEW SERVER STATE
39984039
39994040-- Return detected tips
0 commit comments