Commit 06faa9b2 authored by dwentzel's avatar dwentzel

changed IOStalls to log finer-grain data (db data file level) as well as

automatically calculate disk latencies.
parent 3a1c3fbe
PRINT '-----------------------------------------------------------------------------------------------------------------'
PRINT '-- PerformanceCollector.IOStalls'
PRINT '-----------------------------------------------------------------------------------------------------------------'
IF EXISTS (
select *
from sys.objects so
join sys.columns sc on so.object_id = sc.object_id
WHERE so.object_id = OBJECT_ID('PerformanceCollector.IOStalls')
AND sc.name = 'io_mb'
)
BEGIN
--drop the old version of the table
EXEC ('DROP TABLE PerformanceCollector.IOStalls;');
END;
GO
IF OBJECT_ID('PerformanceCollector.IOStalls') IS NULL
BEGIN
CREATE TABLE PerformanceCollector.IOStalls
......@@ -8,9 +20,18 @@ CREATE TABLE PerformanceCollector.IOStalls
, ServerName varchar(200)
, DbName varchar(200)
, FileType varchar(100)
, io_mb decimal (18,6)
, io_stall_ms decimal (18,6)
, io_stall_pct decimal (18,6)
, num_of_writes bigint
, num_of_reads bigint
, num_of_bytes_written bigint
, num_of_bytes_read bigint
, io_stall_write_ms decimal(18,6)
, io_stall_read_ms decimal(18,6)
, io_stall decimal(18,6)
, ReadLatency decimal(18,6)
, WriteLatency decimal(18,6)
, Latency decimal(18,6)
, Drive varchar(2)
, PhysicalFileName varchar(200)
)
END
ELSE BEGIN
......
......@@ -20,40 +20,25 @@ BEGIN
--let's run this about every 7 hours.
if datediff (hh,COALESCE(@nowprev,'1/1/1980'),@now) > @PollingInterval
BEGIN
--Step 1:
--io stalls
WITH DBIO AS
(
Select
db_name(ivfs.database_id) as db,
case when mf.type = 1 THEN 'log' else 'data' end as file_type,
sum(ivfs.num_of_bytes_read + ivfs.num_of_bytes_written) as io,
sum(ivfs.io_stall) as io_stall
from sys.dm_io_virtual_file_STATS(NULL,NULL) AS IVFS
JOIN sys.master_files as mf
ON ivfs.database_id = mf.database_id
AND ivfs.file_id = mf.file_id
GROUP BY db_name(ivfs.database_id), mf.type
)
, Totals AS
(
SELECT db,file_type,
cast(1. * io/(1024*1024) as decimal(12,2)) as io_mb,
cast(io_stall/1000. as decimal(12,2)) as io_stall_ms,
cast(100. * io_stall/sum(io_stall) over() as decimal(10,2)) as io_stall_pct
from dbio
)
INSERT INTO PerformanceCollector.IOStalls
SELECT
GETDATE(),
@@SERVERNAME,
db,
file_type,
io_mb,
io_stall_ms,
io_stall_pct
FROM Totals
WHERE io_stall_pct > 1
--Disk Latencies and io_stalls
INSERT INTO PerformanceCollector.IOStalls (CurrTime, ServerName, DbName, FileType, num_of_writes,
num_of_reads, num_of_bytes_written, num_of_bytes_read, io_stall_write_ms, io_stall_read_ms,
io_stall, ReadLatency, WriteLatency, Latency, Drive,PhysicalFileName)
SELECT GETDATE(),@@SERVERNAME,db_name(vfs.database_id) as db,case when mf.type = 1 THEN 'log' else 'data' end as file_type,vfs.num_of_writes,
vfs.num_of_reads,vfs.num_of_bytes_written, vfs.num_of_bytes_read, vfs.io_stall_write_ms, vfs.io_stall_read_ms,
vfs.io_stall,
CASE WHEN vfs.[num_of_reads] = 0 THEN 0 ELSE (vfs.[io_stall_read_ms] / vfs.[num_of_reads]) END,
CASE WHEN vfs.[num_of_writes] = 0 THEN 0 ELSE (vfs.[io_stall_write_ms] / vfs.[num_of_writes]) END,
CASE WHEN (vfs.[num_of_reads] = 0 AND vfs.[num_of_writes] = 0) THEN 0 ELSE (vfs.[io_stall] / (vfs.[num_of_reads] + vfs.[num_of_writes])) END,
LEFT (mf.[physical_name], 2) AS [Drive],
mf.[physical_name]
FROM
sys.dm_io_virtual_file_stats (NULL,NULL) AS vfs
JOIN sys.master_files AS mf
ON vfs.[database_id] = mf.[database_id]
AND vfs.[file_id] = mf.[file_id]
END;
END
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment