March 3, 2020 at 11:40 am
Please assist I have faced a sharp growth in the size of my primary data file on SQL Server 2016.How can I identify the cause of the issue.
“When I hear somebody sigh, ‘Life is hard,’ I am always tempted to ask, ‘Compared to what?’” - Sydney Harris
March 3, 2020 at 1:39 pm
You can trace filegrowth with extended events https://www.sqlservercentral.com/blogs/finding-file-growths-with-extended-events
March 3, 2020 at 3:19 pm
Extended events will allow you to capture future file growths, but if you need to investigate file growths that have already happened, you can try to look at the default trace to see what caused the file growth:
SELECT td.DatabaseName, td.Filename, te.name AS Event, (IntegerData*8)/1024 AS Change_MB, td.StartTime, (Duration/1000) AS Duration_sec,
td.LoginName, td.HostName, td.ApplicationName, td.spid, td.ClientProcessID, td.IsSystem, td.SqlHandle, td.TextData
FROM sys.traces t
CROSS APPLY ::fn_trace_gettable(t.path, default) td
INNER JOIN sys.trace_events te ON td.EventClass = te.trace_event_id
WHERE t.is_default = 1
AND td.EventClass IN (92,93)
ORDER BY td.StartTime DESC;
note, EventClass 92 is "Data File Auto Grow"
and EventClass 93 is "Log File Auto Grow"
March 3, 2020 at 9:03 pm
Also - verify your auto growth settings. They should be a fixed size in MB and not set to the default percentage (or default 1MB which is way too small).
Jeffrey Williams
“We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”
― Charles R. Swindoll
How to post questions to get better answers faster
Managing Transaction Logs
March 3, 2020 at 11:21 pm
Last but not least, is the extra space "unallocated" or "unused"? If it's "unallocated", it could be from a recent index rebuild. If it's "unused", you might want to lookup Trace Flag 692.
I also agree with checking on the growth factors as folks pointed out above. They need to be set to MB instead of percent.
--Jeff Moden
Change is inevitable... Change for the better is not.
March 5, 2020 at 3:01 am
Enquiring minds want to know... what did you find out?
--Jeff Moden
Change is inevitable... Change for the better is not.
March 5, 2020 at 7:01 am
he finding was that there was an audit trail function that was enable and contributing to datbase growth.
“When I hear somebody sigh, ‘Life is hard,’ I am always tempted to ask, ‘Compared to what?’” - Sydney Harris
March 5, 2020 at 3:28 pm
he finding was that there was an audit trail function that was enable and contributing to datbase growth.
How'd you figure that out and what was the "audit trail function" that you speak of?
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply