mirror of
https://dev.azure.com/effectory/Survey%20Software/_git/Cloud%20Engineering
synced 2026-02-27 18:52:18 +01:00
added documetation
This commit is contained in:
@@ -1,80 +1,156 @@
|
||||
/*
|
||||
================================================================================
|
||||
SQL SERVER DATABASE SIZE AND BACKUP ANALYSIS REPORT
|
||||
================================================================================
|
||||
|
||||
DESCRIPTION:
|
||||
Comprehensive analysis of SQL Server database sizes, space utilization,
|
||||
and backup information. This script provides detailed insights into:
|
||||
• Database file sizes (data and log files)
|
||||
• Actual space used vs. allocated space
|
||||
• Recovery model information
|
||||
• Latest backup information for both full and log backups
|
||||
• Backup size metrics including compression details
|
||||
|
||||
FEATURES:
|
||||
• Multi-database analysis across entire SQL Server instance
|
||||
• Real-time space usage calculation using dynamic SQL
|
||||
• Backup history analysis from msdb.backupset
|
||||
• Intelligent backup size reporting (compressed vs. uncompressed)
|
||||
• Results ordered by total database size (largest first)
|
||||
|
||||
OUTPUT COLUMNS:
|
||||
- database_id: SQL Server internal database identifier
|
||||
- name: Database name
|
||||
- state_desc: Database state (ONLINE, OFFLINE, etc.)
|
||||
- recovery_model_desc: Recovery model (FULL, SIMPLE, BULK_LOGGED)
|
||||
- total_size: Total allocated space (data + log files) in MB
|
||||
- data_size: Total allocated data file space in MB
|
||||
- data_used_size: Actual space used in data files in MB
|
||||
- log_size: Total allocated log file space in MB
|
||||
- log_used_size: Actual space used in log files in MB
|
||||
- full_last_date: Date/time of most recent full backup
|
||||
- full_size: Size of most recent full backup in MB
|
||||
- log_last_date: Date/time of most recent log backup
|
||||
- log_size: Size of most recent log backup in MB
|
||||
|
||||
USAGE SCENARIOS:
|
||||
• Database capacity planning and growth analysis
|
||||
• Storage optimization and space reclamation projects
|
||||
• Backup strategy review and optimization
|
||||
• Performance troubleshooting related to database size
|
||||
• Compliance reporting for backup procedures
|
||||
|
||||
TECHNICAL IMPLEMENTATION:
|
||||
• Uses temporary table to collect space usage across databases
|
||||
• Dynamic SQL generation to query each online database
|
||||
• Joins system catalog views (sys.databases, sys.master_files)
|
||||
• Integrates backup history from msdb.backupset
|
||||
• Handles compressed backup size calculations
|
||||
|
||||
PERMISSIONS REQUIRED:
|
||||
• VIEW SERVER STATE permission
|
||||
• Access to msdb database for backup history
|
||||
• Database access to calculate space usage (connects to each database)
|
||||
|
||||
COMPATIBILITY:
|
||||
• SQL Server 2008 R2 and later versions
|
||||
• Works with Azure SQL Database (with limited backup history)
|
||||
• Compatible with SQL Server on Linux
|
||||
|
||||
AUTHOR: Cloud Engineering Team
|
||||
CREATED: Database administration and monitoring toolkit
|
||||
UPDATED: Enhanced with comprehensive backup analysis and documentation
|
||||
|
||||
================================================================================
|
||||
*/
|
||||
|
||||
IF OBJECT_ID('tempdb.dbo.#space') IS NOT NULL
|
||||
DROP TABLE #space
|
||||
|
||||
-- Create temporary table to store actual space usage from each database
|
||||
CREATE TABLE #space (
|
||||
database_id INT PRIMARY KEY
|
||||
, data_used_size DECIMAL(18,2)
|
||||
, log_used_size DECIMAL(18,2)
|
||||
, data_used_size DECIMAL(18,2) -- Actual space used in data files (MB)
|
||||
, log_used_size DECIMAL(18,2) -- Actual space used in log files (MB)
|
||||
)
|
||||
|
||||
-- Variable to hold dynamically generated SQL for cross-database queries
|
||||
DECLARE @SQL NVARCHAR(MAX)
|
||||
|
||||
-- Generate dynamic SQL to collect actual space usage from each online database
|
||||
-- This approach is necessary because FILEPROPERTY() must be executed in the context of each database
|
||||
SELECT @SQL = STUFF((
|
||||
SELECT '
|
||||
USE [' + d.name + ']
|
||||
INSERT INTO #space (database_id, data_used_size, log_used_size)
|
||||
SELECT
|
||||
DB_ID()
|
||||
, SUM(CASE WHEN [type] = 0 THEN space_used END)
|
||||
, SUM(CASE WHEN [type] = 1 THEN space_used END)
|
||||
, SUM(CASE WHEN [type] = 0 THEN space_used END) -- Data files (type = 0)
|
||||
, SUM(CASE WHEN [type] = 1 THEN space_used END) -- Log files (type = 1)
|
||||
FROM (
|
||||
SELECT s.[type], space_used = SUM(FILEPROPERTY(s.name, ''SpaceUsed'') * 8. / 1024)
|
||||
SELECT s.[type], space_used = SUM(FILEPROPERTY(s.name, ''SpaceUsed'') * 8. / 1024) -- Convert pages to MB
|
||||
FROM sys.database_files s
|
||||
GROUP BY s.[type]
|
||||
) t;'
|
||||
FROM sys.databases d
|
||||
WHERE d.[state] = 0
|
||||
WHERE d.[state] = 0 -- Only include ONLINE databases
|
||||
FOR XML PATH(''), TYPE).value('.', 'NVARCHAR(MAX)'), 1, 2, '')
|
||||
|
||||
-- Execute the dynamic SQL to populate space usage data
|
||||
EXEC sys.sp_executesql @SQL
|
||||
|
||||
-- Main query: Combine database information, file sizes, space usage, and backup data
|
||||
SELECT
|
||||
d.database_id
|
||||
, d.name
|
||||
, d.state_desc
|
||||
, d.recovery_model_desc
|
||||
, t.total_size
|
||||
, t.data_size
|
||||
, s.data_used_size
|
||||
, t.log_size
|
||||
, s.log_used_size
|
||||
, bu.full_last_date
|
||||
, bu.full_size
|
||||
, bu.log_last_date
|
||||
, bu.log_size
|
||||
, d.state_desc -- Database state (ONLINE, OFFLINE, etc.)
|
||||
, d.recovery_model_desc -- Recovery model (FULL, SIMPLE, BULK_LOGGED)
|
||||
, t.total_size -- Total allocated space (data + log) in MB
|
||||
, t.data_size -- Allocated data file space in MB
|
||||
, s.data_used_size -- Actual space used in data files in MB
|
||||
, t.log_size -- Allocated log file space in MB
|
||||
, s.log_used_size -- Actual space used in log files in MB
|
||||
, bu.full_last_date -- Most recent full backup date
|
||||
, bu.full_size -- Most recent full backup size in MB
|
||||
, bu.log_last_date -- Most recent log backup date
|
||||
, bu.log_size -- Most recent log backup size in MB
|
||||
FROM (
|
||||
-- Calculate allocated file sizes from sys.master_files (covers all databases from master)
|
||||
SELECT
|
||||
database_id
|
||||
, log_size = CAST(SUM(CASE WHEN [type] = 1 THEN size END) * 8. / 1024 AS DECIMAL(18,2))
|
||||
, data_size = CAST(SUM(CASE WHEN [type] = 0 THEN size END) * 8. / 1024 AS DECIMAL(18,2))
|
||||
, total_size = CAST(SUM(size) * 8. / 1024 AS DECIMAL(18,2))
|
||||
FROM sys.master_files
|
||||
, log_size = CAST(SUM(CASE WHEN [type] = 1 THEN size END) * 8. / 1024 AS DECIMAL(18,2)) -- Log files
|
||||
, data_size = CAST(SUM(CASE WHEN [type] = 0 THEN size END) * 8. / 1024 AS DECIMAL(18,2)) -- Data files
|
||||
, total_size = CAST(SUM(size) * 8. / 1024 AS DECIMAL(18,2)) -- Total allocated
|
||||
FROM sys.master_files -- System view with all database files across instance
|
||||
GROUP BY database_id
|
||||
) t
|
||||
JOIN sys.databases d ON d.database_id = t.database_id
|
||||
LEFT JOIN #space s ON d.database_id = s.database_id
|
||||
JOIN sys.databases d ON d.database_id = t.database_id -- Join with database catalog
|
||||
LEFT JOIN #space s ON d.database_id = s.database_id -- Join with actual space usage data
|
||||
LEFT JOIN (
|
||||
-- Subquery to get latest backup information for each database
|
||||
SELECT
|
||||
database_name
|
||||
, full_last_date = MAX(CASE WHEN [type] = 'D' THEN backup_finish_date END)
|
||||
, full_size = MAX(CASE WHEN [type] = 'D' THEN backup_size END)
|
||||
, log_last_date = MAX(CASE WHEN [type] = 'L' THEN backup_finish_date END)
|
||||
, log_size = MAX(CASE WHEN [type] = 'L' THEN backup_size END)
|
||||
, full_last_date = MAX(CASE WHEN [type] = 'D' THEN backup_finish_date END) -- Latest full backup date
|
||||
, full_size = MAX(CASE WHEN [type] = 'D' THEN backup_size END) -- Latest full backup size
|
||||
, log_last_date = MAX(CASE WHEN [type] = 'L' THEN backup_finish_date END) -- Latest log backup date
|
||||
, log_size = MAX(CASE WHEN [type] = 'L' THEN backup_size END) -- Latest log backup size
|
||||
FROM (
|
||||
-- Inner query to get most recent backup of each type per database
|
||||
SELECT
|
||||
s.database_name
|
||||
, s.[type]
|
||||
, s.[type] -- 'D' = Full backup, 'L' = Log backup
|
||||
, s.backup_finish_date
|
||||
, backup_size =
|
||||
, backup_size = -- Smart backup size calculation
|
||||
CAST(CASE WHEN s.backup_size = s.compressed_backup_size
|
||||
THEN s.backup_size
|
||||
ELSE s.compressed_backup_size
|
||||
END / 1048576.0 AS DECIMAL(18,2))
|
||||
THEN s.backup_size -- No compression used
|
||||
ELSE s.compressed_backup_size -- Use compressed size
|
||||
END / 1048576.0 AS DECIMAL(18,2)) -- Convert bytes to MB
|
||||
, RowNum = ROW_NUMBER() OVER (PARTITION BY s.database_name, s.[type] ORDER BY s.backup_finish_date DESC)
|
||||
FROM msdb.dbo.backupset s
|
||||
WHERE s.[type] IN ('D', 'L')
|
||||
FROM msdb.dbo.backupset s -- SQL Server backup history
|
||||
WHERE s.[type] IN ('D', 'L') -- Full and Log backups only
|
||||
) f
|
||||
WHERE f.RowNum = 1
|
||||
WHERE f.RowNum = 1 -- Only most recent backup of each type
|
||||
GROUP BY f.database_name
|
||||
) bu ON d.name = bu.database_name
|
||||
ORDER BY t.total_size DESC
|
||||
) bu ON d.name = bu.database_name -- Join backup data with database info
|
||||
ORDER BY t.total_size DESC -- Order by largest databases first
|
||||
Reference in New Issue
Block a user