The backup behavior on the instance was concerning - another item I'll have to address another day. While speculating what could be leading to database backup misbehavior on the system, I had a lot of trouble reconciling the read IO numbers reported by the Resource Governor resource pool, the perfmon LogicalDisk counters, and the perfmon Backup/Recovery counters. It seemed like Resource Governor was reporting twice as many read operations and twice as many read bytes for the backup operation as perfmon LogicalDisk Counters and the Backup/Recovery counters.
Here's a test script I used to explore this with a test database on my laptop, confirming the results on a few VMs as well.
DECLARE @mb_read NUMERIC(18,2), @reads BIGINT, @maxTran INT = 65536, @ij INT = 1, @db NVARCHAR(50) = 'T8666' SELECT @@version; WHILE @ij < 7 BEGIN CHECKPOINT; DBCC DROPCLEANBUFFERS; ALTER RESOURCE GOVERNOR RESET STATISTICS; SELECT @mb_read = CONVERT(NUMERIC(18,2), num_of_bytes_read/131072.), @reads = num_of_reads FROM sys.dm_io_virtual_file_stats(DB_ID(@db), 1) BACKUP DATABASE @db TO DISK = 'NUL' WITH MAXTRANSFERSIZE = @maxTran; SELECT @maxTran AS [maxtransfersize], rg.*, vfs.* FROM (SELECT CONVERT(NUMERIC(18,2), read_bytes_total/131072.) AS mb_read_rg, read_io_completed_total AS reads_rg FROM sys.dm_resource_governor_resource_pools where pool_id = 2) rg CROSS JOIN (SELECT CONVERT(NUMERIC(18,2), num_of_bytes_read/131072.) - @mb_read AS mb_read_vfs, num_of_reads - @reads AS reads_vfs FROM sys.dm_io_virtual_file_stats(DB_ID(@db), 1)) vfs SET @ij = @ij + 1; SET @maxTran = @maxTran * 2; END
And... here are the results from my test database. Not sure why this happens. I'll create a feedback item for it - I'd like to rely on the numbers that come from Resource Governor. Especially for backup activity - having the ability to separate backup activity into its own resource pool and account for its reads, read bytes, and read service time separately could be very powerful. But its gotta tell me the truth first :-)
If you really, really love this stuff you can see how I started wading into these waters - complete with some perfmon graphs, in the thread following the tweet linked below :_)
https://twitter.com/sqL_handLe/status/1059858313234604033
https://twitter.com/sqL_handLe/status/1059560423886733312
https://twitter.com/sqL_handLe/status/1059560423886733312
No comments:
Post a Comment