-
Notifications
You must be signed in to change notification settings - Fork 827
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
SQL Resource Governor Usage & Usage By Database #157
Comments
We don't use this internally, so I don't have the counters to test with - can you provide some more detail on what you're querying? I'm not at all against adding a section to the instance dashboard if this functionality is enabled on a particular instance. |
Here are the scripts I use. The first one gives a great snapshot of what is happening by database: This second one is for the resource governors. This will only work on Sql 2014 due to the IOPS governors, if you remove that part it would work on Sql 2012.
Date: Wed, 23 Mar 2016 16:47:15 -0700 We don't use this internally, so I don't have the counters to test with - can you provide some more detail on what you're querying? I'm not at all against adding a section to the instance dashboard if this functionality is enabled on a particular instance. — |
Formatting here for readability soon as I can visualize this on a dashboard well: SELECT databaseName = db_name(ses.database_id),
runningProcesses = coalesce(sp.running, 0),
waitingProcesses = coalesce(sp.wating, 0),
totalSessions = count(DISTINCT ses.session_id),
totalSystemSessions = sum(CASE WHEN ses.is_user_process = 0 THEN 1 ELSE 0 END),
totalUserSessions = sum(CASE WHEN ses.is_user_process = 1 THEN 1 ELSE 0 END),
totalRequests = count(req.request_id),
totalSystemRequests = sum(CASE WHEN ses.is_user_process = 0
AND req.request_id IS NOT NULL THEN 1 ELSE 0 END),
totalUserRequests = sum(CASE WHEN ses.is_user_process = 1
AND req.request_id IS NOT NULL THEN 1 ELSE 0 END),
totalConnections = count(DISTINCT con.connection_id),
totalApplications = count(DISTINCT ses.program_name),
totalConnectedComputers = count(DISTINCT con.client_net_address),
totalWorkLoadGroups = count(DISTINCT wg.pool_id),
totalResourcePools = count(DISTINCT rp.NAME),
totalBlockedRequests = sum(CASE WHEN req.blocking_session_id > 0 THEN 1 ELSE 0 END)
FROM master.sys.dm_exec_sessions ses
LEFT JOIN master.sys.dm_exec_requests req ON (ses.session_id = req.session_id)
LEFT JOIN master.sys.resource_governor_workload_groups AS wg ON (ses.group_id = wg.group_id)
LEFT JOIN master.sys.resource_governor_resource_pools AS rp ON (wg.pool_id = rp.pool_id)
LEFT JOIN master.sys.dm_exec_connections con ON (con.session_id = ses.session_id)
LEFT JOIN (
SELECT databaseName = db_name(bsp.dbid),
running = sum(CASE WHEN bsp.waittime = 0 THEN 1 ELSE 0 END),
wating = sum(CASE WHEN bsp.waittime = 0 THEN 0 ELSE 1 END)
FROM master.sys.sysprocesses bsp
WHERE bsp.STATUS <> 'sleeping'
AND bsp.dbid > 0
GROUP BY bsp.dbid
) sp ON (db_name(ses.database_id) = sp.databaseName)
WHERE ses.database_id > 0
GROUP BY db_name(ses.database_id),
ses.database_id,
coalesce(sp.running, 0),
coalesce(sp.wating, 0)
ORDER BY ses.database_id
DECLARE @totalServerMemory BIGINT
SELECT @totalServerMemory = opc.cntr_value
FROM master.sys.dm_os_performance_counters opc
WHERE opc.object_name = 'SQLServer:Memory Manager'
AND opc.counter_name = 'Total Server Memory (KB)';
WITH perfMon (
objectName,
instanceName,
counterName,
value)
AS (
SELECT objectName = opc.object_name,
instanceName = opc.instance_name,
counterName = opc.counter_name,
value = opc.cntr_value
FROM master.sys.dm_os_performance_counters opc
WHERE opc.object_name = 'SQLServer:Resource Pool Stats'
AND opc.counter_name IN (
'CPU usage %',
'CPU usage % base',
'CPU usage target %',
'Used memory (KB)',
'Target memory (KB)',
'Disk Read IO/sec',
'Disk Write IO/sec'))
SELECT instanceName,
cpuUsage = cast([Cpu Usage %] AS FLOAT) / cast([CPU usage % base] AS FLOAT),
cpuUsageTarget = cast([Cpu Usage Target %] AS FLOAT) / 100,
usedMemory = cast([Used memory (KB)] AS FLOAT) / @totalServerMemory,
targetMemory = cast([Target memory (KB)] AS FLOAT) / @totalServerMemory,
diskIops = [Disk Read IO/sec] + [Disk Write IO/sec]
INTO #tb_stats
FROM (
SELECT tmp.instanceName,
tmp.counterName,
tmp.value
FROM perfMon tmp) pm
pivot(max(pm.value) FOR pm.counterName IN (
[Cpu Usage %],
[CPU usage % base],
[Cpu Usage Target %],
[Used memory (KB)],
[Target memory (KB)],
[Disk Read IO/sec],
[Disk Write IO/sec])) pv
ORDER BY instanceName SELECT instanceName = s.instanceName,
cpuUsage = s.cpuUsage,
cpuUsageTarget = s.cpuUsageTarget,
usedMemory = s.usedMemory,
targetMemory = s.targetMemory,
diskIops = s.diskIops,
maxIops = tmp.maxIops
FROM #tb_stats s
INNER JOIN (
SELECT instanceName = rp.NAME,
maxIops = rp.max_iops_per_volume
FROM master.sys.resource_governor_resource_pools rp
) tmp ON (s.instanceName = tmp.instanceName)
ORDER BY s.instanceName
DROP TABLE #tb_stats |
An additional note: On the first query by database, if there are any blockers, I highlight the row in red to make it visually easy to see that there is blocking going on. |
Any chance this can get some priority? I could implement it myself, but want it to match your coding schemes. |
@NickCraver I'd be happy to start on this. I'd like to see it on the instance tab, but not sure what your thoughts are. Can you comment on it? It should be a pretty easy add that I can do being queries. |
Is it possible to add info about resource governors? Currently in an in house app, I query the perfmon counters to get the CPU, Memory, and IOPS current usage AND target usage as defined by the resource governors. I also have data for databases summarized by what is running. It is basically a summarized view of whoIsActive but grouped by database.
The text was updated successfully, but these errors were encountered: