ClearCacheOnMemTreshold.sql 2.0 KB

12345678910111213141516171819202122232425262728293031323334353637383940
  1. SET NOCOUNT ON;
  2. DECLARE @sqlcmd NVARCHAR(4000), @params NVARCHAR(500), @ErrorMessage NVARCHAR(1000)
  3. DECLARE @pages_MB bigint, @cachename NVARCHAR(256), @committed_MB bigint
  4. DECLARE @memthreshold_pct smallint
  5. DECLARE @tmpCacheTbl AS TABLE (cachename NVARCHAR(256), pages_kb bigint, is_done bit)
  6. -- Set percentage of committed memory used by prepared single use plans that triggers a cache eviction
  7. SET @memthreshold_pct = 10
  8. SET @sqlcmd = N'SELECT @committedOUT=committed_kb/1024 FROM sys.dm_os_sys_info (NOLOCK)'
  9. SET @params = N'@committedOUT bigint OUTPUT';
  10. EXECUTE sp_executesql @sqlcmd, @params, @committedOUT=@committed_MB OUTPUT;
  11. -- Populate cache table
  12. INSERT INTO @tmpCacheTbl
  13. SELECT name, pages_kb / 1024, 0
  14. FROM sys.dm_os_memory_cache_counters
  15. WHERE name IN ('Object Plans', 'SQL Plans', 'Bound Trees', 'Extended Stored Procedures', 'Temporary Tables & Table Variables')
  16. WHILE (SELECT COUNT(cachename) FROM @tmpCacheTbl WHERE is_done = 0) > 0
  17. BEGIN
  18. SELECT TOP 1 @cachename = cachename, @pages_MB = pages_kb FROM @tmpCacheTbl WHERE is_done = 0
  19. IF (@pages_MB * 100) / @committed_MB >= @memthreshold_pct
  20. BEGIN
  21. SELECT @ErrorMessage = CONVERT(NVARCHAR(50), GETDATE()) + ': ' + @cachename + ' will be evicted because it exceeds ' + CONVERT(NVARCHAR(12), @memthreshold_pct) + ' percent of total committed memory (' + CONVERT(NVARCHAR(12), @pages_MB) + 'MB of ' + CONVERT(NVARCHAR(12), @committed_MB) + 'MB).'
  22. RAISERROR (@ErrorMessage, 10, 1, N'Manual cache eviction');
  23. EXECUTE ('DBCC FREESYSTEMCACHE (''' + @cachename + ''') WITH MARK_IN_USE_FOR_REMOVAL')
  24. END
  25. ELSE
  26. BEGIN
  27. SELECT @ErrorMessage = CONVERT(NVARCHAR(50), GETDATE()) + ': ' + @cachename + ' does not exceed ' + CONVERT(NVARCHAR(12), @memthreshold_pct) + ' percent of total committed memory (' + CONVERT(NVARCHAR(12), @pages_MB) + 'MB of ' + CONVERT(NVARCHAR(12), @committed_MB) + 'MB).'
  28. RAISERROR (@ErrorMessage, 10, 1, N'Manual cache eviction');
  29. END
  30. UPDATE @tmpCacheTbl
  31. SET is_done = 1
  32. WHERE cachename = @cachename
  33. END
  34. GO