-- get data file growth based on the backup history
DECLARE @endDate datetime, @months smallint;
SET @endDate = GetDate(); -- Include in the statistic all backups from today
SET @months = 6; -- back to the last 6 months.
;WITH HIST AS
(SELECT BS.database_name AS DatabaseName
,YEAR(BS.backup_start_date) * 100
+ MONTH(BS.backup_start_date) AS YearMonth
,CONVERT(numeric(10, 1), MIN(BF.file_size / 1048576.0)) AS MinSizeMB
,CONVERT(numeric(10, 1), MAX(BF.file_size / 1048576.0)) AS MaxSizeMB
,CONVERT(numeric(10, 1), AVG(BF.file_size / 1048576.0)) AS AvgSizeMB
FROM msdb.dbo.backupset as BS
INNER JOIN
msdb.dbo.backupfile AS BF
ON BS.backup_set_id = BF.backup_set_id
WHERE NOT BS.database_name IN
('master', 'msdb', 'model', 'tempdb')
AND BF.file_type = 'D'
AND BS.backup_start_date BETWEEN DATEADD(mm, - @months, @endDate) AND @endDate
GROUP BY BS.database_name
,YEAR(BS.backup_start_date)
,MONTH(BS.backup_start_date) )
SELECT MAIN.DatabaseName
,MAIN.YearMonth
,MAIN.MinSizeMB
,MAIN.MaxSizeMB
,MAIN.AvgSizeMB
,MAIN.AvgSizeMB
- ( SELECT TOP 1 SUB.AvgSizeMB
FROM HIST AS SUB
WHERE SUB.DatabaseName = MAIN.DatabaseName
AND SUB.YearMonth < MAIN.YearMonth
ORDER BY SUB.YearMonth DESC ) AS GrowthMB
FROM HIST AS MAIN
ORDER BY MAIN.DatabaseName
,MAIN.YearMonth
-----------------------------------------------------------------------------------------------------------------------------
-- data file and log file size as per today
SELECT DB_NAME(database_id) AS [Database Name],
[file_id], name AS [Logical Name], physical_name, type_desc, state_desc,
--is_percent_growth, growth,
CONVERT(bigint, size/128.0) AS [Total Size in MB],
CONVERT(DECIMAL(18,2), size/131072.0) AS [Total Size in GB],cast (sysdatetime() as date) taken_date
FROM sys.master_files WITH (NOLOCK)
WHERE database_id > 4
AND database_id <> 32767
OR database_id = 2
ORDER BY DB_NAME(database_id) OPTION (RECOMPILE);
-----------------------------------------------------------------------------------------------------------------------------
--Get Table and Index storage size in sql server
with pages as (
SELECT object_id, SUM (reserved_page_count) as reserved_pages, SUM (used_page_count) as used_pages,
SUM (case
when (index_id < 2) then (in_row_data_page_count + lob_used_page_count + row_overflow_used_page_count)
else lob_used_page_count + row_overflow_used_page_count
end) as pages
FROM sys.dm_db_partition_stats
group by object_id
), extra as (
SELECT p.object_id, sum(reserved_page_count) as reserved_pages, sum(used_page_count) as used_pages
FROM sys.dm_db_partition_stats p, sys.internal_tables it
WHERE it.internal_type IN (202,204,211,212,213,214,215,216) AND p.object_id = it.object_id
group by p.object_id
)
SELECT object_schema_name(p.object_id) + '.' + object_name(p.object_id) as TableName, (p.reserved_pages + isnull(e.reserved_pages, 0)) * 8 as reserved_kb,
pages * 8 as data_kb,
(CASE WHEN p.used_pages + isnull(e.used_pages, 0) > pages THEN (p.used_pages + isnull(e.used_pages, 0) - pages) ELSE 0 END) * 8 as index_kb,
(CASE WHEN p.reserved_pages + isnull(e.reserved_pages, 0) > p.used_pages + isnull(e.used_pages, 0) THEN (p.reserved_pages + isnull(e.reserved_pages, 0) - p.used_pages + isnull(e.used_pages, 0)) else 0 end) * 8 as unused_kb
from pages p
left outer join extra e on p.object_id = e.object_id
order by TableName
No comments:
Post a Comment