SQL Server – Query to get DDL changes from default trace

Occasionally I need to read the default trace to get recent DDL changes from SQL Server. Here is a handy query that I wrote to read the default trace look for recent DDL changes.

Here is the query that I use:

SELECT
  a.StartTime as [EventTime]
, a.EndTime
, a.ServerName
, b.name as [EventClass_Descr]
, d.name as [Category_Descr]
, c.subclass_name as [EventSubClass_Descr]
, case isnull(a.ObjectType, -123456)
			when 8259 then 'Check Constraint'
			when 8260 then 'Default (constraint or standalone)'
			when 8262 then 'Foreign-key Constraint'
			when 8272 then 'Stored Procedure'
			when 8274 then 'Rule'
			when 8275 then 'System Table'
			when 8276 then 'Trigger on Server'
			when 8277 then '(User-defined) Table'
			when 8278 then 'View'
			when 8280 then 'Extended Stored Procedure'
			when 16724 then 'CLR Trigger'
			when 16964 then 'Database'
			when 16975 then 'Object'
			when 17222 then 'FullText Catalog'
			when 17232 then 'CLR Stored Procedure'
			when 17235 then 'Schema'
			when 17475 then 'Credential'
			when 17491 then 'DDL Event'
			when 17741 then 'Management Event'
			when 17747 then 'Security Event'
			when 17749 then 'User Event'
			when 17985 then 'CLR Aggregate Function'
			when 17993 then 'Inline Table-valued SQL Function'
			when 18000 then 'Partition Function'
			when 18002 then 'Replication Filter Procedure'
			when 18004 then 'Table-valued SQL Function'
			when 18259 then 'Server Role'
			when 18263 then 'Microsoft Windows Group'
			when 19265 then 'Asymmetric Key'
			when 19277 then 'Master Key'
			when 19280 then 'Primary Key'
			when 19283 then 'ObfusKey'
			when 19521 then 'Asymmetric Key Login'
			when 19523 then 'Certificate Login'
			when 19538 then 'Role'
			when 19539 then 'SQL Login'
			when 19543 then 'Windows Login'
			when 20034 then 'Remote Service Binding'
			when 20036 then 'Event Notification on Database'
			when 20037 then 'Event Notification'
			when 20038 then 'Scalar SQL Function'
			when 20047 then 'Event Notification on Object'
			when 20051 then 'Synonym'
			when 20307 then 'Sequence'
			when 20549 then 'End Point'
			when 20801 then 'Adhoc Queries which may be cached'
			when 20816 then 'Prepared Queries which may be cached'
			when 20819 then 'Service Broker Service Queue'
			when 20821 then 'Unique Constraint'
			when 21057 then 'Application Role'
			when 21059 then 'Certificate'
			when 21075 then 'Server'
			when 21076 then 'Transact-SQL Trigger'
			when 21313 then 'Assembly'
			when 21318 then 'CLR Scalar Function'
			when 21321 then 'Inline scalar SQL Function'
			when 21328 then 'Partition Scheme'
			when 21333 then 'User'
			when 21571 then 'Service Broker Service Contract'
			when 21572 then 'Trigger on Database'
			when 21574 then 'CLR Table-valued Function'
			when 21577 then 'Internal Table (For example, XML Node Table, Queue Table.)'
			when 21581 then 'Service Broker Message Type'
			when 21586 then 'Service Broker Route'
			when 21587 then 'Statistics'
			when 21825 then 'User'
			when 21827 then 'User'
			when 21831 then 'User'
			when 21843 then 'User'
			when 21847 then 'User'
			when 22099 then 'Service Broker Service'
			when 22601 then 'Index'
			when 22604 then 'Certificate Login'
			when 22611 then 'XMLSchema'
			when 22868 then 'Type'
            when -123456 then case when a.EventClass in (108, 104) then 'Login' when a.EventClass in (109, 110) then 'User' else 'Unknown' end
            else 'Unknown'
          end as [ObjectType_Description]
, a.DatabaseName
, a.ObjectName
, a.LoginName
, a.NTUserName
, a.NTDomainName
, a.HostName
, a.ApplicationName
, a.DBUserName

, a.TargetUserName
, a.TargetLoginName
, a.RoleName

, convert(nvarchar(max), a.TextData) as [TextData]
, a.DatabaseID
, a.ObjectID        -----------------------
, a.IndexID
, a.Duration

FROM    sys.fn_trace_gettable(CONVERT(nvarchar(256), (SELECT case when charindex('_', convert(nvarchar(256), f.value)) = 0 then convert(nvarchar(256), f.value) else substring(convert(nvarchar(256), f.value), 1, charindex('_', convert(nvarchar(256), f.value))-1) end + '.trc'
                                                      FROM    sys.fn_trace_getinfo(1) f
                                                      WHERE   f.property = 2
                                                    )), DEFAULT) as [a]

        left outer JOIN sys.trace_events as [b] ON a.EventClass = b.trace_event_id
        left outer JOIN sys.trace_subclass_values c ON c.trace_event_id = b.trace_event_id
                                            AND c.subclass_value = a.EventSubClass
		left outer join sys.trace_categories as [d] on d.category_id = b.category_id
WHERE a.DatabaseName <> 'tempdb'
  and isnull(a.EventClass, -123456) in (46, --	Object:Created	Objects
										 47,  --	Object:Deleted	Objects
										 164 -- Object:Altered
)
  and isnull(a.ObjectType,0) <> 21587   -- don't get auto-statistics as it generates too much noise
order by a.StartTime desc

Capture

SQL Server – Find the size of database file – Find the size of log file

As a DBA you may sometimes have the need to gather some stats on the sizes of files in your databases.  Once again Microsoft has been kind enough to provide us with some handy tools get get at this information without having to use the clunky GUI.

If you are just simply looking for the size of the files and are not concerned about finding the used space and free space you can simply use the sys.master_files DMV.  This DMV has a column named “size” which represents the number of 8k pages in the database file.  To get to MB you would simply multiply size times 8 and then divide the total by 1024.  I like to throw in some rounding and conversion to make my result more readable.

Here is an example.

select db_name(database_id) as [DatabaseName]
, name as [Logical_Name]
, convert(decimal(18,2), round(((size * 8) / 1024.00),2)) as [SizeMB]
from sys.master_files
where db_name(database_id) = 'AdventureWorks2014'

And here are the results:

Capture

But what if I also want to determine the used space and free space in the file?

Well, its always been a bit of a source of irritation for me that this information cannot be obtained from sys.master_files.  Just seems like it would have been something that could have been included in this DMV and it would make it so much easier when trying to include this information in reports, queries, etc… but at least there is, in fact, still a pretty simple way to get at this info.

To get database file used space and free space we can use dbcc showfilestats.  When you execute this statement you will see columns named “TotalExtents” and “UsedExtents“.  These columns represent the number of 64k extents in the databse file.  So, for example, if you wanted to convert TotalExtents to MB you would need to multiply TotalExtents by 64 and then divide the total by 1024.   Again, I like to throw in some rounding and conversion to make my result more readable.  Unfortunately dbcc showfilestats will only display information for database files in the current database and it also does not include information about the log files, and since it is a DBCC command it’s not as easy to use it in select statements.  So first we will look at the output from the dbcc command and then I will show you a query that gives you the info in a format that is more useful.

To run this command you would just simply execute the following statement:

dbcc showfilestats with no_infomsgs;

And the result:

Capture2

As you can see, unless you are used to thinking in terms of EXTENTS instead of MB or GB, this isn’t very helpful.  So, as promised, here is another query that will take the results of the dbcc command and dump it into a temp table and then do the conversion for us:


use AdventureWorks2014;
go
if (select object_id('tempdb..#tempFileSize')) is not null
drop table #tempFileSize;

create table #tempFileSize (Fileid int, [FileGroup] int, TotalExtents bigint, UsedExtents bigint, Name nvarchar(128), [FileName] nvarchar(260))

declare @sql nvarchar(max);
set @sql = 'dbcc showfilestats with no_infomsgs;'

insert into #tempFileSize exec(@sql);
select db_name() as [DatabaseName],
 Name as [Logical_Name],
 convert(decimal(18,2), round(((TotalExtents * 64) / 1024.0),2)) as [TotalMB],
 convert(decimal(18,2), round(((UsedExtents * 64) / 1024.0),2)) as [UsedMB],
 convert(decimal(18,2), round((((TotalExtents - UsedExtents) * 64) / 1024.0),2)) as [FreeMB]
from #tempFileSize

And the results:

Capture3