Home > Link, Microsoft SQL Server, MSBI, Optimization, Query, Script, SQL Mentalist, SQL PraRup, SQL Query, SQL Server, Technology,, TSQL, Vishal Pawar > BI SQL # 179 : SQL Server DBA Scripts : Log Growth Rate

BI SQL # 179 : SQL Server DBA Scripts : Log Growth Rate

Hi Folks,

In this article we are going to cover How to Log Growth Rate.

In this post we are going to discuss following points:

  • Problem Statement of SQL Script:
  • Description of SQL Script:
  • SQL Script Output Column
  • SQL Script Code
  • SQL Script Output Screenshot
  • User Level to execute

Problem Statement of SQL Script:

Get log growth rate of all database and types.

Description of SQL Script:

This Transact-SQL script will help in Check\maintain log growth rate of all database and types.

SQL Script Output Column

image

SQL Script Code

WITH logs
AS (
    SELECT DB.NAME AS DatabaseName
        ,MAX(DB.recovery_model_desc) AS RecoveryModel
        ,SUM(size * 8) AS TotalSizeKB
        ,SUM(CASE 
                WHEN MF.is_percent_growth = 0
                    THEN MF.growth
                ELSE MF.size * MF.growth / 100
                END * 8) AS TotalGrowthKB
    FROM sys.master_files AS MF
    INNER JOIN sys.databases AS DB ON MF.database_id = DB.
        database_id
    WHERE MF.[type] = 1
    GROUP BY DB.NAME
    )
    ,total
AS (
    SELECT OPC.[cntr_value] AS TotalCounter
    FROM sys.dm_os_performance_counters AS OPC
    WHERE OPC.[object_name] LIKE N'%SQL%:Databases%'
        AND OPC.[counter_name] = N'Log Growths'
        AND OPC.[instance_name] = N'_Total'
    )
    ,growth
AS (
    SELECT OPC.[instance_name] AS DatabaseName
        ,OPC.[cntr_value] AS Growths
    FROM sys.dm_os_performance_counters AS OPC
    WHERE OPC.[object_name] LIKE N'%SQL%:Databases%'
        AND OPC.[counter_name] = N'Log Growths'
        AND OPC.[instance_name] <> N'_Total'
    )
    ,shrinks
AS (
    SELECT OPC.[instance_name] AS DatabaseName
        ,OPC.[cntr_value] AS Shrinks
    FROM sys.dm_os_performance_counters AS OPC
    WHERE OPC.[object_name] LIKE N'%SQL%:Databases%'
        AND OPC.[counter_name] = N'Log Shrinks'
        AND OPC.[instance_name] <> N'_Total'
    )
SELECT logs.DatabaseName
    ,logs.RecoveryModel
    ,logs.TotalSizeKB
    ,logs.TotalGrowthKB
    ,shrinks.Shrinks
    ,growth.Growths
    ,CONVERT(DECIMAL(38, 2), CASE 
            WHEN total.TotalCounter = 0
                THEN 0.0
            ELSE 100.0 * growth.Growths / total.TotalCounter
            END) AS [GrowthRate %]
FROM logs
INNER JOIN growth ON logs.DatabaseName = growth.DatabaseName
INNER JOIN shrinks ON logs.DatabaseName = shrinks.DatabaseName
CROSS JOIN total
ORDER BY [GrowthRate %] DESC
    ,logs.DatabaseName ASC;

SQL Script Output Screenshot

image

User Level to execute

300

    Hope you will like How to Log Growth Rate.

    If you really like reading my blog and understood at least few thing then please don’t forget to subscribe my blog.

If you want daily link and analysis or interesting link go to following website which will give @ your inbox please subscribe our following link resource blog :

Link Resource Website

For More information related to BI World visit my Mentalist Blog

SQL Server Mentalist >> SQL Learning Blog

Business Intelligence Mentalist >> BI World

Infographic Mentalist >> Image worth explaining thousand Words

Microsoft Mentalist >> MVC,ASP.NET, WCF & LinQ

DBA Mentalist >>Advance SQL Server Blog

Microsoft BI Mentalist >> MS BI Development Update

Connect With me on

| FaceBook |Twitter | linkedIn| Google+ | WordPress | RSS |

Advertisement
  1. No comments yet.
  1. No trackbacks yet.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

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

Facebook photo

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

Connecting to %s

%d bloggers like this: