Thứ Tư, 25 tháng 2, 2026

Script runbook daily, weekly, monthly trong SQL Server

Mặc định SQL Server 2022 + FULL recovery + log backup mỗi 15 phút và “đóng gói” bộ Runbook scripts theo đúng cấu trúc thư mục để FO/NOC/DBA chạy ngay.

Dưới đây là nội dung copy–paste tạo file.

0) Cấu trúc thư mục

sqlserver_runbook/
├── daily/
│ ├── DAILY_01_INSTANCE_HEALTH.sql
│ ├── DAILY_02_BLOCKING.sql
│ ├── DAILY_03_TOP_CPU.sql
│ ├── DAILY_04_SPACE.sql
│ └── DAILY_05_BACKUP_STATUS.sql
├── weekly/
│ ├── WEEKLY_01_CHECKDB_ALL.sql
│ ├── WEEKLY_02_INDEX_FRAG_REPORT.sql
│ ├── WEEKLY_03_INDEX_MAINT_ALL.sql
│ ├── WEEKLY_04_UPDATE_STATS_ALL.sql
│ └── WEEKLY_05_WAITS.sql
└── monthly/
├── MONTHLY_01_CLEAN_MSDB.sql
├── MONTHLY_02_CONFIG_REVIEW.sql
└── MONTHLY_03_DB_GROWTH_REPORT.sql

1) DAILY scripts

daily/DAILY_01_INSTANCE_HEALTH.sql

SET NOCOUNT ON;

PRINT '=== INSTANCE INFO ===';
SELECT @@SERVERNAME AS server_name, @@VERSION AS version;

SELECT
SERVERPROPERTY('MachineName') AS MachineName,
SERVERPROPERTY('ServerName') AS ServerName,
SERVERPROPERTY('InstanceName') AS InstanceName,
SERVERPROPERTY('Edition') AS Edition,
SERVERPROPERTY('ProductVersion') AS ProductVersion;

PRINT '=== DATABASE STATE ===';
SELECT
name,
state_desc,
user_access_desc,
recovery_model_desc,
log_reuse_wait_desc
FROM sys.databases
ORDER BY name;

PRINT '=== AGENT JOB SUMMARY (LAST 24H FAIL) ===';
SELECT TOP 50
j.name AS job_name,
msdb.dbo.agent_datetime(h.run_date, h.run_time) AS run_datetime,
h.step_name,
h.message,
h.run_status
FROM msdb.dbo.sysjobhistory h
JOIN msdb.dbo.sysjobs j ON h.job_id = j.job_id
WHERE h.step_id <> 0
AND h.run_status = 0
AND msdb.dbo.agent_datetime(h.run_date, h.run_time) >= DATEADD(HOUR, -24, GETDATE())
ORDER BY run_datetime DESC;

daily/DAILY_02_BLOCKING.sql

SET NOCOUNT ON;

PRINT '=== TOP REQUESTS (CPU) ===';
SELECT TOP 50
r.session_id,
r.blocking_session_id,
r.status,
r.cpu_time,
r.total_elapsed_time,
r.wait_type,
r.wait_time,
r.wait_resource,
DB_NAME(r.database_id) AS dbname,
s.login_name,
s.host_name,
s.program_name,
t.text
FROM sys.dm_exec_requests r
JOIN sys.dm_exec_sessions s ON r.session_id = s.session_id
CROSS APPLY sys.dm_exec_sql_text(r.sql_handle) t
WHERE r.session_id <> @@SPID
ORDER BY r.cpu_time DESC;

PRINT '=== ACTIVE BLOCKING CHAINS ===';
;WITH blk AS (
SELECT
r.session_id,
r.blocking_session_id,
r.wait_type,
r.wait_time,
DB_NAME(r.database_id) AS dbname
FROM sys.dm_exec_requests r
WHERE r.blocking_session_id <> 0
)
SELECT * FROM blk ORDER BY wait_time DESC;

daily/DAILY_03_TOP_CPU.sql

SET NOCOUNT ON;

PRINT '=== TOP SQL BY CPU ===';
SELECT TOP 20
qs.total_worker_time/1000 AS total_cpu_ms,
qs.execution_count,
(qs.total_worker_time/NULLIF(qs.execution_count,0))/1000 AS avg_cpu_ms,
qs.total_elapsed_time/1000 AS total_elapsed_ms,
qs.total_logical_reads AS total_logical_reads,
SUBSTRING(t.text, (qs.statement_start_offset/2)+1,
((CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(t.text)
ELSE qs.statement_end_offset END - qs.statement_start_offset)/2)+1) AS stmt
FROM sys.dm_exec_query_stats qs
CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) t
ORDER BY qs.total_worker_time DESC;

daily/DAILY_04_SPACE.sql

SET NOCOUNT ON;

PRINT '=== DB FILES (CURRENT DB) ===';
SELECT
DB_NAME() AS current_db,
name, type_desc, physical_name,
size*8/1024 AS size_MB,
FILEPROPERTY(name,'SpaceUsed')*8/1024 AS used_MB
FROM sys.database_files
ORDER BY type_desc, name;

PRINT '=== ALL DB SIZE (MASTER_FILES) ===';
SELECT
DB_NAME(database_id) AS dbname,
type_desc,
SUM(size)*8/1024 AS size_MB
FROM sys.master_files
GROUP BY database_id, type_desc
ORDER BY dbname, type_desc;

PRINT '=== TEMPDB USAGE ===';
USE tempdb;
SELECT
SUM(user_object_reserved_page_count)*8/1024 AS user_obj_MB,
SUM(internal_object_reserved_page_count)*8/1024 AS internal_obj_MB,
SUM(version_store_reserved_page_count)*8/1024 AS version_store_MB,
SUM(unallocated_extent_page_count)*8/1024 AS free_MB
FROM sys.dm_db_file_space_usage;

daily/DAILY_05_BACKUP_STATUS.sql

SET NOCOUNT ON;

PRINT '=== LAST BACKUP TIMES (FULL/DIFF/LOG) ===';
SELECT
d.name AS dbname,
d.recovery_model_desc,
MAX(CASE WHEN b.type='D' THEN b.backup_finish_date END) AS last_full,
MAX(CASE WHEN b.type='I' THEN b.backup_finish_date END) AS last_diff,
MAX(CASE WHEN b.type='L' THEN b.backup_finish_date END) AS last_log
FROM sys.databases d
LEFT JOIN msdb.dbo.backupset b ON b.database_name = d.name
WHERE d.name NOT IN ('tempdb')
GROUP BY d.name, d.recovery_model_desc
ORDER BY d.name;

PRINT '=== LOG REUSE WAIT (WATCH THIS) ===';
SELECT name, recovery_model_desc, log_reuse_wait_desc
FROM sys.databases
ORDER BY name;

2) WEEKLY scripts

weekly/WEEKLY_01_CHECKDB_ALL.sql

Chạy ngoài giờ, ưu tiên từng DB quan trọng. Script dưới chạy toàn bộ user DB.

SET NOCOUNT ON;

DECLARE @db SYSNAME, @sql NVARCHAR(MAX);

DECLARE dbs CURSOR FAST_FORWARD FOR
SELECT name
FROM sys.databases
WHERE database_id > 4 -- user DB
AND state_desc = 'ONLINE';

OPEN dbs;
FETCH NEXT FROM dbs INTO @db;

WHILE @@FETCH_STATUS = 0
BEGIN
PRINT '=== CHECKDB: ' + QUOTENAME(@db) + ' ===';
SET @sql = N'DBCC CHECKDB (' + QUOTENAME(@db) + N') WITH NO_INFOMSGS, ALL_ERRORMSGS;';
EXEC (@sql);

FETCH NEXT FROM dbs INTO @db;
END

CLOSE dbs;
DEALLOCATE dbs;

weekly/WEEKLY_02_INDEX_FRAG_REPORT.sql

SET NOCOUNT ON;
USE MyDB; -- đổi DB mục tiêu nếu cần

SELECT
OBJECT_SCHEMA_NAME(ps.object_id) AS [schema_name],
OBJECT_NAME(ps.object_id) AS [table_name],
i.name AS index_name,
ps.index_id,
ps.avg_fragmentation_in_percent,
ps.page_count
FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, 'SAMPLED') ps
JOIN sys.indexes i ON ps.object_id=i.object_id AND ps.index_id=i.index_id
WHERE ps.page_count > 1000
AND i.index_id > 0
ORDER BY ps.avg_fragmentation_in_percent DESC;

weekly/WEEKLY_03_INDEX_MAINT_ALL.sql

Chạy theo rule: 5–30% REORGANIZE, >30% REBUILD.
Script dưới chạy trên 1 DB (đổi USE MyDB).

SET NOCOUNT ON;
USE MyDB; -- đổi DB

DECLARE @schema SYSNAME, @table SYSNAME, @index SYSNAME, @sql NVARCHAR(MAX);
DECLARE @frag FLOAT, @pages BIGINT;

DECLARE c CURSOR FAST_FORWARD FOR
SELECT
OBJECT_SCHEMA_NAME(ps.object_id) AS schema_name,
OBJECT_NAME(ps.object_id) AS table_name,
i.name AS index_name,
ps.avg_fragmentation_in_percent,
ps.page_count
FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, 'SAMPLED') ps
JOIN sys.indexes i ON ps.object_id=i.object_id AND ps.index_id=i.index_id
WHERE ps.page_count > 1000
AND i.index_id > 0
AND i.is_disabled = 0
AND i.is_hypothetical = 0;

OPEN c;
FETCH NEXT FROM c INTO @schema, @table, @index, @frag, @pages;

WHILE @@FETCH_STATUS = 0
BEGIN
IF @frag >= 30
SET @sql = N'ALTER INDEX ' + QUOTENAME(@index) + N' ON ' + QUOTENAME(@schema) + N'.' + QUOTENAME(@table)
+ N' REBUILD WITH (SORT_IN_TEMPDB = ON);';
ELSE IF @frag >= 5
SET @sql = N'ALTER INDEX ' + QUOTENAME(@index) + N' ON ' + QUOTENAME(@schema) + N'.' + QUOTENAME(@table)
+ N' REORGANIZE;';
ELSE
SET @sql = NULL;

IF @sql IS NOT NULL
BEGIN
PRINT CONCAT('IndexMaint: ', @schema, '.', @table, ' / ', @index, ' frag=', @frag, '% pages=', @pages);
EXEC sp_executesql @sql;
END

FETCH NEXT FROM c INTO @schema, @table, @index, @frag, @pages;
END

CLOSE c;
DEALLOCATE c;

weekly/WEEKLY_04_UPDATE_STATS_ALL.sql

SET NOCOUNT ON;
USE MyDB; -- đổi DB

EXEC sp_updatestats;

weekly/WEEKLY_05_WAITS.sql

SET NOCOUNT ON;

SELECT TOP 30
wait_type,
waiting_tasks_count,
wait_time_ms/1000.0 AS wait_s,
(wait_time_ms*1.0/NULLIF(waiting_tasks_count,0)) AS avg_wait_ms
FROM sys.dm_os_wait_stats
WHERE wait_type NOT LIKE '%SLEEP%'
ORDER BY wait_time_ms DESC;

3) MONTHLY scripts

monthly/MONTHLY_01_CLEAN_MSDB.sql

SET NOCOUNT ON;

-- Dọn backup history 30 ngày
EXEC msdb.dbo.sp_delete_backuphistory
@oldest_date = DATEADD(DAY, -30, GETDATE());

-- Dọn job history 30 ngày
EXEC msdb.dbo.sp_purge_jobhistory
@oldest_date = DATEADD(DAY, -30, GETDATE());

PRINT 'MSDB cleanup done.';

monthly/MONTHLY_02_CONFIG_REVIEW.sql

SET NOCOUNT ON;

EXEC sp_configure 'show advanced options', 1; RECONFIGURE;

EXEC sp_configure 'max server memory (MB)';
EXEC sp_configure 'max degree of parallelism';
EXEC sp_configure 'cost threshold for parallelism';
EXEC sp_configure 'backup compression default';
EXEC sp_configure 'optimize for ad hoc workloads';

PRINT 'Review: confirm Max Memory / MAXDOP / CTFP match workload & NUMA.';

monthly/MONTHLY_03_DB_GROWTH_REPORT.sql

SET NOCOUNT ON;

SELECT
DB_NAME(database_id) AS dbname,
type_desc,
SUM(size)*8/1024 AS size_MB
FROM sys.master_files
GROUP BY database_id, type_desc
ORDER BY size_MB DESC;

-- IO latency theo file (để biết nghẽn data/log)
SELECT TOP 50
DB_NAME(vfs.database_id) AS dbname,
mf.type_desc,
mf.physical_name,
vfs.num_of_reads,
CASE WHEN vfs.num_of_reads=0 THEN 0 ELSE vfs.io_stall_read_ms*1.0/vfs.num_of_reads END AS avg_read_ms,
vfs.num_of_writes,
CASE WHEN vfs.num_of_writes=0 THEN 0 ELSE vfs.io_stall_write_ms*1.0/vfs.num_of_writes END AS avg_write_ms
FROM sys.dm_io_virtual_file_stats(NULL, NULL) vfs
JOIN sys.master_files mf
ON vfs.database_id=mf.database_id AND vfs.file_id=mf.file_id
ORDER BY (vfs.io_stall_read_ms + vfs.io_stall_write_ms) DESC;

4) Lịch chạy khuyến nghị (đưa cho FO/NOC/DBA)

  • Daily

    • 08:00 / 14:00 / 20:00: chạy nhóm DAILY_* (hoặc dashboard hóa)

    • Backup:

      • Full: 01:00

      • Diff: 12:00 (tuỳ policy)

      • Log: mỗi 15 phút (FULL recovery)

  • Weekly

    • Thứ 7 23:00: CHECKDB_ALL (hoặc DB quan trọng trước)

    • Chủ nhật 01:00: INDEX_MAINT + UPDATE_STATS

  • Monthly

    • Ngày 1 02:00: cleanup msdb + config review + growth report

    • Restore test: theo quy trình DR/UAT (bắt buộc có biên bản)

=============================
TƯ VẤN: Click Here hoặc Hotline/Zalo 090.29.12.888
=============================
Website không chứa bất kỳ quảng cáo nào, mọi đóng góp để duy trì phát triển cho website (donation) xin vui lòng gửi về STK 90.2142.8888 - Ngân hàng Vietcombank Thăng Long - TRAN VAN BINH
=============================
Nếu bạn không muốn bị AI thay thế và tiết kiệm 3-5 NĂM trên con đường trở thành DBA chuyên nghiệp hay làm chủ Database thì hãy đăng ký ngay KHOÁ HỌC ORACLE DATABASE A-Z ENTERPRISE, được Coaching trực tiếp từ tôi với toàn bộ bí kíp thực chiến, thủ tục, quy trình của gần 20 năm kinh nghiệm (mà bạn sẽ KHÔNG THỂ tìm kiếm trên Internet/Google) từ đó giúp bạn dễ dàng quản trị mọi hệ thống Core tại Việt Nam và trên thế giới, đỗ OCP.
- CÁCH ĐĂNG KÝ: Gõ (.) hoặc để lại số điện thoại hoặc inbox https://m.me/tranvanbinh.vn hoặc Hotline/Zalo 090.29.12.888
- Chi tiết tham khảo:
https://bit.ly/oaz_w
=============================
2 khóa học online qua video giúp bạn nhanh chóng có những kiến thức nền tảng về Linux, Oracle, học mọi nơi, chỉ cần có Internet/4G:
- Oracle cơ bản: https://bit.ly/admin_1200
- Linux: https://bit.ly/linux_1200
=============================
KẾT NỐI VỚI CHUYÊN GIA TRẦN VĂN BÌNH:
📧 Mail: binhoracle@gmail.com
☎️ Mobile/Zalo: 0902912888
👨 Facebook: https://www.facebook.com/BinhOracleMaster
👨 Inbox Messenger: https://m.me/101036604657441 (profile)
👨 Fanpage: https://www.facebook.com/tranvanbinh.vn
👨 Inbox Fanpage: https://m.me/tranvanbinh.vn
👨👩 Group FB: https://www.facebook.com/groups/DBAVietNam
👨 Website: https://www.tranvanbinh.vn
👨 Blogger: https://tranvanbinhmaster.blogspot.com
🎬 Youtube: https://www.youtube.com/@binhguru
👨 Tiktok: https://www.tiktok.com/@binhguru
👨 Linkin: https://www.linkedin.com/in/binhoracle
👨 Twitter: https://twitter.com/binhguru
👨 Podcast: https://www.podbean.com/pu/pbblog-eskre-5f82d6
👨 Địa chỉ: Tòa nhà Sun Square - 21 Lê Đức Thọ - Phường Mỹ Đình 1 - Quận Nam Từ Liêm - TP.Hà Nội

=============================
cơ sở dữ liệu, cơ sở dữ liệu quốc gia, database, AI, trí tuệ nhân tạo, artificial intelligence, machine learning, deep learning, LLM, ChatGPT, DeepSeek, Grok, oracle tutorial, học oracle database, Tự học Oracle, Tài liệu Oracle 12c tiếng Việt, Hướng dẫn sử dụng Oracle Database, Oracle SQL cơ bản, Oracle SQL là gì, Khóa học Oracle Hà Nội, Học chứng chỉ Oracle ở đầu, Khóa học Oracle online,sql tutorial, khóa học pl/sql tutorial, học dba, học dba ở việt nam, khóa học dba, khóa học dba sql, tài liệu học dba oracle, Khóa học Oracle online, học oracle sql, học oracle ở đâu tphcm, học oracle bắt đầu từ đâu, học oracle ở hà nội, oracle database tutorial, oracle database 12c, oracle database là gì, oracle database 11g, oracle download, oracle database 19c/21c/23c/23ai, oracle dba tutorial, oracle tunning, sql tunning , oracle 12c, oracle multitenant, Container Databases (CDB), Pluggable Databases (PDB), oracle cloud, oracle security, oracle fga, audit_trail,oracle RAC, ASM, oracle dataguard, oracle goldengate, mview, oracle exadata, oracle oca, oracle ocp, oracle ocm , oracle weblogic, postgresql tutorial, mysql tutorial, mariadb tutorial, ms sql server tutorial, nosql, mongodb tutorial, oci, cloud, middleware tutorial, docker, k8s, micro service, hoc solaris tutorial, hoc linux tutorial, hoc aix tutorial, unix tutorial, securecrt, xshell, mobaxterm, putty

ĐỌC NHIỀU

Trần Văn Bình - Oracle Database Master