ClearCacheOnNrEntriesTreshold.sql 1.5 KB

12345678910111213141516171819202122232425262728293031323334
  1. SET NOCOUNT ON;
  2. DECLARE @sqlcmd NVARCHAR(4000), @params NVARCHAR(500), @ErrorMessage NVARCHAR(1000)
  3. DECLARE @cacheentries bigint, @cachename NVARCHAR(256), @entriesthreshold int
  4. DECLARE @tmpCacheTbl AS TABLE (cachename NVARCHAR(256), entries_count bigint, is_done bit)
  5. SET @entriesthreshold = 10000 -- Triggers cache cleanup if exceeded
  6. -- Populate cache table
  7. INSERT INTO @tmpCacheTbl
  8. SELECT name, entries_count, 0
  9. FROM sys.dm_os_memory_cache_counters
  10. WHERE name IN ('Object Plans', 'SQL Plans', 'Bound Trees', 'Extended Stored Procedures', 'Temporary Tables & Table Variables')
  11. WHILE (SELECT COUNT(cachename) FROM @tmpCacheTbl WHERE is_done = 0) > 0
  12. BEGIN
  13. SELECT TOP 1 @cachename = cachename, @cacheentries = entries_count FROM @tmpCacheTbl WHERE is_done = 0
  14. IF @cacheentries >= @entriesthreshold
  15. BEGIN
  16. SELECT @ErrorMessage = CONVERT(NVARCHAR(50), GETDATE()) + ': ' + @cachename + ' will be evicted because it exceeds ' + CONVERT(NVARCHAR(12), @entriesthreshold) + ' number of objects (' + CONVERT(NVARCHAR(12), @cacheentries) + ').'
  17. RAISERROR (@ErrorMessage, 10, 1, N'Manual cache eviction');
  18. EXECUTE ('DBCC FREESYSTEMCACHE (''' + @cachename + ''') WITH MARK_IN_USE_FOR_REMOVAL')
  19. END
  20. ELSE
  21. BEGIN
  22. SELECT @ErrorMessage = CONVERT(NVARCHAR(50), GETDATE()) + ': ' + @cachename + ' does not exceed ' + CONVERT(NVARCHAR(12), @entriesthreshold) + ' number of objects (' + CONVERT(NVARCHAR(12), @cacheentries) + ').'
  23. RAISERROR (@ErrorMessage, 10, 1, N'Manual cache eviction');
  24. END
  25. UPDATE @tmpCacheTbl
  26. SET is_done = 1
  27. WHERE cachename = @cachename
  28. END
  29. GO