Last active
May 5, 2019 06:54
-
-
Save TheRockStarDBA/eac93e53c0f1ed01af37 to your computer and use it in GitHub Desktop.
AutogrowthSettings
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
/************************************************************************************************************************************************************************************************************************************ | |
************************************************************************************************************************************************************************************************************************************ | |
Author : Kin Shah | |
Purpose : Find Autogrowth Settings | |
Posted On : http://dba.stackexchange.com/a/82633/8783 | |
http://dba.stackexchange.com/a/53917/8783 | |
Disclaimer | |
The views expressed on my posts on this site are mine alone and do not reflect the views of my company. All posts of mine are provided "AS IS" with no warranties, and confers no rights. | |
The following disclaimer applies to all code, scripts and demos available on my posts: | |
This Sample Code is provided for the purpose of illustration only and is not intended to be used in a production environment. THIS SAMPLE CODE AND ANY RELATED INFORMATION ARE PROVIDED “AS IS” WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE IMPLIED WARRANTIES OF MERCHANTABILITY AND/OR FITNESS FOR A PARTICULAR PURPOSE. | |
I grant You a nonexclusive, royalty-free right to use and modify the Sample Code and to reproduce and distribute the object code form of the Sample Code, provided that You agree: | |
(i) to use my name, logo, or trademarks to market Your software product in which the Sample Code is embedded; | |
(ii) to include a valid copyright notice on Your software product in which the Sample Code is embedded; and | |
(iii) to indemnify, hold harmless, and defend me from and against any claims or lawsuits, including attorneys’ fees, that arise or result from the use or distribution of the Sample Code. | |
************************************************************************************************************************************************************************************************************************************ | |
*************************************************************************************************************************************************************************************************************************************/ | |
IF OBJECT_ID('tempdb..#autogrowthTotal') IS NOT NULL | |
DROP TABLE #autogrowthTotal; | |
IF OBJECT_ID('tempdb..#autogrowthTotal_Final') IS NOT NULL | |
DROP TABLE #autogrowthTotal_Final; | |
DECLARE @filename NVARCHAR(1000); | |
DECLARE @bc INT; | |
DECLARE @ec INT; | |
DECLARE @bfn VARCHAR(1000); | |
DECLARE @efn VARCHAR(10); | |
-- Get the name of the current default trace | |
SELECT @filename = CAST(value AS NVARCHAR(1000)) | |
FROM ::fn_trace_getinfo(DEFAULT) | |
WHERE traceid = 1 AND property = 2; | |
-- rip apart file name into pieces | |
SET @filename = REVERSE(@filename); | |
SET @bc = CHARINDEX('.',@filename); | |
SET @ec = CHARINDEX('_',@filename)+1; | |
SET @efn = REVERSE(SUBSTRING(@filename,1,@bc)); | |
SET @bfn = REVERSE(SUBSTRING(@filename,@ec,LEN(@filename))); | |
-- set filename without rollover number | |
SET @filename = @bfn + @efn | |
-- process all trace files | |
SELECT | |
ftg.StartTime | |
,te.name AS EventName | |
,DB_NAME(ftg.databaseid) AS DatabaseName | |
,ftg.[FileName] as LogicalFileName | |
,(ftg.IntegerData*8)/1024.0 AS GrowthMB | |
,(ftg.duration/1000)AS DurMS | |
,mf.physical_name AS PhysicalFileName | |
into #autogrowthTotal | |
FROM ::fn_trace_gettable(@filename, DEFAULT) AS ftg | |
INNER JOIN sys.trace_events AS te ON ftg.EventClass = te.trace_event_id | |
join sys.master_files mf on (mf.database_id = ftg.databaseid) and (mf.name = ftg.[FileName]) | |
WHERE (ftg.EventClass = 92 -- Data File Auto-grow | |
OR ftg.EventClass = 93) -- Log File Auto-grow | |
ORDER BY ftg.StartTime | |
select count(1) as NoOfTimesEventFired | |
, CONVERT(VARCHAR(10), StartTime, 120) as StartTime | |
, EventName | |
, DatabaseName | |
, [LogicalFileName] | |
, PhysicalFileName | |
, SUM(GrowthMB) as TotalGrowthMB | |
, SUM(DurMS) as TotalDurationMS | |
into #autogrowthTotal_Final | |
from #autogrowthTotal | |
group by CONVERT(VARCHAR(10), StartTime, 120),EventName,DatabaseName, [LogicalFileName], PhysicalFileName | |
--having count(1) > 5 or SUM(DurMS)/1000 > 60 -- change this for finetuning.... | |
order by CONVERT(VARCHAR(10), StartTime, 120) | |
select * from #autogrowthTotal_Final |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment