June 2017 | SansSQL

Sunday, June 25, 2017

SQL Coding Best Practices and Design Considerations

As the business demand the applications to be more flexible and user friendly, the data access layers become more critical. For the applications to be flexible and quick responsive, the database reads and writes should be at optimum performance levels leaving the developers and DBA's an mandatory option to following the coding standards and best practices.

Superior coding techniques and programming practices are hallmarks of a professional programmer. The bulk of programming consists of making a large number of small choices while attempting to solve a larger set of problems. How wisely those choices are made depends largely upon the programmer's skill and expertise.

The readability of source code has a direct impact on how well a developer comprehends a software system. Code maintainability refers to how easily that software system can be changed to add new features, modify existing features, fix bugs, or improve performance. Although readability and maintainability are the result of many factors, one particular facet of software development upon which all developers have an influence is coding technique. The easiest method to ensure that a team of developers will yield quality code is to establish a coding standard, which is then enforced at routine code reviews.

This post and the underlying presentation aims at the fundamentals of SQL Coding Best Practices and Design Considerations. To read further, download the copy of presentation from here.

Saturday, June 24, 2017

T-SQL to find Memory Used by Database and its Objects

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 and we use this for calculating the memory used by the Databases and its objects.

-- Memory Used by All Databases
SELECT 
 CAST (COUNT(1)*8/1024 AS decimal(8,2)) AS [MemoryUsedByAllDB's(MB)]
,CAST (COUNT(1)*8/1024/1024 AS decimal(8,2)) AS [MemoryUsedByAllDB's(GB)]
FROM sys.dm_os_buffer_descriptors
GO

-- Memory Used by Individual Databases
SELECT
 CASE WHEN database_id = 32767 
      THEN 'ResourceDB' 
      ELSE DB_NAME(database_id) 
 END AS [DatabaseName]
,COUNT(1) AS [CachedPages]
,CAST (COUNT(1)*8/1024 AS decimal(8,2)) AS [MemoryUsed(MB)]
,CAST(COUNT(1)*8/1024/1024 AS decimal(8,2)) AS [MemoryUsed(GB)]
,CASE WHEN is_modified = 1 
      THEN 'Dirty Page' 
      ELSE 'Clean Page' 
 END AS [PageState]
FROM
sys.dm_os_buffer_descriptors
GROUP BY database_id
	,is_modified
ORDER BY CachedPages DESC
	,DB_NAME(database_id)
GO

-- Memory Used by Objects within a Database. Change the <<database name>> to your desiged Database Name
USE <<database name>>
GO
SELECT
 CASE WHEN database_id = 32767 
      THEN 'ResourceDB' 
      ELSE DB_NAME(database_id) 
 END AS [DatabaseName],
 InnerData.ObjectName,
 InnerData.ObjectType,
 InnerData.IndexName,
 InnerData.IndexType
,COUNT(1) AS [CachedPages]
,CAST (COUNT(1)*8/1024 AS decimal(8,2)) AS [MemoryUsed(MB)]
,CAST(COUNT(1)*8/1024/1024 AS decimal(8,2)) AS [MemoryUsed(GB)]
,CASE WHEN is_modified = 1 
      THEN 'Dirty Page' 
      ELSE 'Clean Page' 
 END AS [PageState]
FROM
sys.dm_os_buffer_descriptors SBD INNER JOIN 
(
SELECT
SAU.allocation_unit_id, 
SO.name AS [ObjectName],
SO.type_desc AS [ObjectType],
SI.name AS [IndexName],
SI.type_desc AS [IndexType]
FROM sys.allocation_units SAU INNER JOIN sys.partitions SP
ON SAU.container_id = SP.partition_id INNER JOIN sys.objects SO
ON SP.object_id = SO.object_id INNER JOIN sys.indexes SI
ON SO.object_id = SI.object_id
WHERE SO.is_ms_shipped=0
) AS InnerData
ON SBD.allocation_unit_id = InnerData.allocation_unit_id
WHERE DB_NAME(SBD.database_id) = DB_NAME()
GROUP BY database_id
	,is_modified
	,InnerData.ObjectName
	,InnerData.ObjectType
	,InnerData.IndexName
	,InnerData.IndexType
ORDER BY CachedPages DESC
	,InnerData.ObjectName
GO

Ads