SQL Server – Memory Allocated/Unallocated per Database

Background

Still on the trail of high TempDB Allocation in our Memory.

 

Glossary

Here is a quick outline of terms that we will cover.

DMV Description Note
 sys.dm_os_buffer_descriptors Returns information about all the data pages that are currently in the SQL Server buffer pool.  The output of this view can be used to determine the distribution of database pages in the buffer pool according to database, object, or type.
sys.allocation_units Contains a row for each allocation unit in the database When a data page is read from disk, the page is copied into the SQL Server buffer pool and cached for reuse. Each cached data page has one buffer descriptor. Buffer descriptors uniquely identify each data page that is currently cached in an instance of SQL Server. sys.dm_os_buffer_descriptors returns cached pages for all user and system databases.

 

 

Code


; with cte
(
	  [database_id]
	, [cnt]
	, [allocatedMB]
	, [isCleanMB]
	, [isDirtyMB]
	, [unallocatedMB]
	, [%unallocated]

)
as
(

	select
	          tblDOSBD.[database_id]

			, [cnt]
				= ( count(*))

			, [allocatedMB]
				= (
					sum
						(
							case
								when ( tblSAU.[allocation_unit_id] is not null ) then 1
								else 0
							end
						) * 8
				  )	
				  / 1024

			, [isCleanMB]
				= (
					sum
						(
							case
								when 
									( 
										    ( tblSAU.[allocation_unit_id] is not null ) 
										and ( tblDOSBD.is_modified = 0 )
									) then 1
								else 0
							end
						) * 8
				  )	
				  / 1024

			, [isDirtyMB]
				= (
					sum
						(
							case
								when 
									( 
										    ( tblSAU.[allocation_unit_id] is not null ) 
										and ( tblDOSBD.is_modified = 1 )
									) then 1
								else 0
							end
						) * 8
				  )	
				  / 1024
				  	
			, [unallocatedMB]
				= (
					sum
					(
						case
							when ( tblSAU.[allocation_unit_id] is null ) then 1
							else 0
						end
					) * 8

				  ) / 1024		

			, [%unallocated]
				= cast
					(
						sum
						(
							case
								when ( tblSAU.[allocation_unit_id] is null ) then 1
								else 0
							end
						) * 100.00
						/
						count(*)
						as decimal(10,2)
					)

	from  sys.dm_os_buffer_descriptors tblDOSBD

	left outer join sys.allocation_units tblSAU

		on tblDOSBD.allocation_unit_id = tblSAU.[allocation_unit_id]

	group by

		tblDOSBD.[database_id]
)
select 

	  [database]
		= case
				when ( cte.database_id = 32767) then 'Resource DB'
				else db_name(cte.[database_id])
          end

	, cte.[allocatedMB]

	, cte.[isCleanMB]
	, cte.[isDirtyMB]	
	
	, cte.[unallocatedMB]

	, cte.[%unallocated]

from   cte

order by
      	 cte.[unallocatedMB] desc

 

Output

memroyallocatedandunallocated-ayso-prod-20161205_1037am

 

Summary

In follow-up postings we will delve more into why we have such a high percentile for unallocated data compared to Allocated data.

Again, keep in mind that unallocated seems to mean that the data is in memory, but corresponding entries do not seem to be present on disk.

 

One thought on “SQL Server – Memory Allocated/Unallocated per Database

Leave a Reply

Please log in using one of these methods to post your comment:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s