SQL Server DBA Monitor Database FileSize
2022-07-07
筆記 SQL Server 如何藉由設定作業排程,定時紀錄資料庫各資料表使用的資料列以及容量,精進 DBA 的管理工作,也藉由自動化更省力 😘
說明
首先建立資料表
USE DBA
DROP TABLE IF EXISTS TableRows
CREATE Table TableRows(
DatabaseName nvarchar(100),
TableName nvarchar(100),
RowCounts int,
TotalSpaceMB int,
UsedPaceMB int,
UnUsedSpaceMB int,
InsertDatetime datetime2
)
要定期執行的 Script,藉由 sp_MSforeachdb
來迭代向所有的資料庫取得資料表資訊,並且寫入 DBA 資料庫之中。
DECLARE @command varchar(4000)
SELECT @command = '
USE [?];
IF db_name() not in ("tempdb")
INSERT INTO DBA.dbo.TableRows
SELECT
db_name() AS DatabaseName,
t.NAME AS TableName,
--s.Name AS SchemaName,
p.rows AS RowCounts,
SUM(a.total_pages) * 8 /1024 AS TotalSpaceMB,
SUM(a.used_pages) * 8 /1024 AS UsedSpaceMB,
(SUM(a.total_pages) - SUM(a.used_pages)) * 8 /1024 AS UnusedSpaceMB,
GetDate()
FROM
sys.tables t
INNER JOIN
sys.indexes i ON t.OBJECT_ID = i.object_id
INNER JOIN
sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
INNER JOIN
sys.allocation_units a ON p.partition_id = a.container_id
LEFT OUTER JOIN
sys.schemas s ON t.schema_id = s.schema_id
WHERE
t.NAME NOT LIKE "dt%"
AND t.is_ms_shipped = 0
AND i.OBJECT_ID > 255
GROUP BY
t.Name, s.Name, p.Rows
ORDER BY
t.Name
ELSE
SELECT NULL
'
EXEC sp_MSforeachdb @command
加入排程作業,頻率不用太高,每天一次即可。
DBA_Auto_DatabaseTableInfo
參考資料
SQL Server 閃電般快速查詢指南 Quick Query⚡