CPU Usage using T-SQL

  • Hi,

    Please help me, how can I get CPU usage in % using T-SQL?

    Regards

    - MSR

  • What exactly are you looking for?

    The CPU usage by SQL server in general or the CPU usage for a query?

    You can find some information about the general CPU usage in sys.dm_os_ring_buffers. But be aware that you only get info about the last 4 hours or so.

    Here's an example.

    DECLARE @ts_now BIGINT

    SELECT @ts_now = cpu_ticks / CONVERT(FLOAT, cpu_ticks_in_ms) FROM sys.dm_os_sys_info

    SELECT record_id,

    DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS EventTime,

    SQLProcessUtilization,

    SystemIdle,

    100 - SystemIdle - SQLProcessUtilization AS OtherProcessUtilization

    FROM (

    SELECT

    record.value('(./Record/@id)[1]', 'int') AS record_id,

    record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') AS SystemIdle,

    record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') AS SQLProcessUtilization,

    TIMESTAMP

    FROM (

    SELECT TIMESTAMP, CONVERT(XML, record) AS record

    FROM sys.dm_os_ring_buffers

    WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'

    AND record LIKE '% %') AS x

    ) AS y

    ORDER BY record_id DESC

    For CPU usage by query you can query sys.dm_exec_query_stats. But again you will only get info about query plans which are in cache.

    SELECT TOP 10 (total_worker_time * 1.0) / 1000000 AS CPU_Utilized_in_Seconds, text,*

    FROM sys.dm_exec_query_stats

    CROSS APPLY sys.dm_exec_sql_text(sql_handle)

    [font="Verdana"]Markus Bohse[/font]

  • If anyone knows a command from sql server that provides cpu utilization %, please post it.

    I need to save this in a table on an hourly basis, in order to report the peak cpu utilization each month.

    I think I may have to use a vbscript and perfmon to do this.

    Steve

  • You can consider using the DMV's available in SQL Server 2005

    You could also use some tools which includes Microsoft Add-on tools like Performance Dashboard reports which are extremely useful in getting CPU usage reports. However, with performance dashboard reports you would get current information only.

    Please check below links

    http://www.microsoft.com/downloads/details.aspx?familyid=1d3a4a0d-7e0c-4730-8204-e419218c1efc&displaylang=en

    http://www.sql-server-performance.com/articles/per/bm_performance_dashboard_2005_p1.aspx

    M&M

  • The dashboard might be good, but I doubt I am able to have it installed. I'll see.

    Since the link to the dashboard says it uses the dynamic mgt views, there ought to be a way to obtain cpu utilization by querying those views, but I have not found one yet.

    I only saw a column for cpu ticks, which is not helpful.

    Do you know of any views I can query?

    Steve

  • Steve,

    The DMVs updated by MarkusB are pretty good. Even the performance dashboard gives charts similar to the output. The first DMV gives CPU usage (SQL and non SQL) in the last 4 hours. Pretty hand.

    You could make use of that query for collecting the CPU usage.

    I checked the performance dashboard for CPU and it has a bar graph for SQL and non SQL. Just like the query.

    M&M

  • Yes, now I realize the MarkusB query is good.

    Do we know if perfmon would give the same results if I looked for processor objects and counters?

    I am not familiar with how he gets the information:

    record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int')

    What is this schedulermonitorevent?

    I'm looking for overall cpu utilization of the machine, so with his query, I would modify it to save 100 - SystemIdle.

  • The query from sys.dm_os_ring_buffers returns an XML column. The expression "record.value" pulls out some information from a given location within the XML and the "RecordMonitorEvent" is part of the XML returned from the sys.dm_os_ring_buffers table. The whole parameter is basically telling the "record.value" where to find the value to extract from the XML.

    If the query just returned the XML then it would be hard to read so it has been formatted nicely so you can read it using the XML queries.

    Alex

  • Hi...I get an ambiguous column error message with the record.value column reference...not sure why.

    record.value(‘(./Record/@id)[1]‘, ‘int’) as record_id,

    record.value(‘(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]‘, ‘int’)

    as SystemIdle,

    record.value(‘(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]‘,

    ‘int’) as SQLProcessUtilization,

  • You can set up a PerfMon log to populate a SQL table.

    Type PerfMon at a command prompt and go into help. After that, if you need more info, Google/Bing on PerfMon and SQL Logging.

    Regards;

    Greg

  • MarkusB (12/1/2008)


    What exactly are you looking for?

    The CPU usage by SQL server in general or the CPU usage for a query?

    You can find some information about the general CPU usage in sys.dm_os_ring_buffers. But be aware that you only get info about the last 4 hours or so.

    Here's an example.

    DECLARE @ts_now BIGINT

    SELECT @ts_now = cpu_ticks / CONVERT(FLOAT, cpu_ticks_in_ms) FROM sys.dm_os_sys_info

    SELECT record_id,

    DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS EventTime,

    SQLProcessUtilization,

    SystemIdle,

    100 - SystemIdle - SQLProcessUtilization AS OtherProcessUtilization

    FROM (

    SELECT

    record.value('(./Record/@id)[1]', 'int') AS record_id,

    record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]', 'int') AS SystemIdle,

    record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]', 'int') AS SQLProcessUtilization,

    TIMESTAMP

    FROM (

    SELECT TIMESTAMP, CONVERT(XML, record) AS record

    FROM sys.dm_os_ring_buffers

    WHERE ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'

    AND record LIKE '% %') AS x

    ) AS y

    ORDER BY record_id DESC

    For CPU usage by query you can query sys.dm_exec_query_stats. But again you will only get info about query plans which are in cache.

    SELECT TOP 10 (total_worker_time * 1.0) / 1000000 AS CPU_Utilized_in_Seconds, text,*

    FROM sys.dm_exec_query_stats

    CROSS APPLY sys.dm_exec_sql_text(sql_handle)

    Is there any script for SQL 2000 as above?

    Sanket Ahir
    Don't run behind the success, Try to be eligible & success will run behind u......

  • MarkusB , Thanks a lot for your query.

    Rajesh11Sept.

  • Lost and have been chasing this CPU query down for several days THANKS!!!:w00t:

  • Excellent script Markus!!! Huge help with what I was wanting to do.

    I made some minor tweaks to it to make it compatible with SQL 2008. I thought I'd post it back to save the next guy a few minutes. Again, thanks Markus for posting this script.

    /***************************************************************************************************************

    Description: This script will display CPU usage on the server. The data comes from

    dm_os_ring_buffers which only stored data for the past 4 HOURS. Within the ring buffers, data is averaged

    at the minute level. There are variables limit the results to a smaller time window and for hiding the

    details.

    Sources:

    http://www.sqlservercentral.com/Forums/Topic611107-146-2.aspx

    http://social.msdn.microsoft.com/Forums/en-US/sqldatabaseengine/thread/abbf67ab-fc8b-4567-b6d4-1c605bc9866c/

    ***************************************************************************************************************/

    /* Variables */

    DECLARE

    @StartTime DATETIME = '01/01/1900 00:00:00'

    ,@EndTime DATETIME = '01/01/2100 23:59:59'

    ,@ShowDetails BIT = 1 -- 1 = True, 0 = False

    /* Script Begin */

    /* Be careful modifying anything below */

    -- Find the timestamp for current server time

    DECLARE @ts_now BIGINT

    SELECT @ts_now = cpu_ticks / (cpu_ticks / ms_ticks)

    FROM sys.dm_os_sys_info;

    DECLARE @Results TABLE

    (record_ID BIGINT NOT NULL

    ,EventTime datetime NOT NULL

    ,SQLProcessUtilization tinyint NOT NULL

    ,SystemIdle tinyint NOT NULL

    ,OtherProcessUtilization tinyint NOT NULL

    )

    INSERT INTO

    @Results

    (

    record_ID

    ,EventTime

    ,SQLProcessUtilization

    ,SystemIdle

    ,OtherProcessUtilization

    )

    SELECT

    record_id

    ,DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) AS EventTime

    ,SQLProcessUtilization

    ,SystemIdle

    ,100 - SystemIdle - SQLProcessUtilization AS OtherProcessUtilization

    FROM

    (

    SELECT

    record.value('(./Record/@id)[1]', 'int') AS record_id

    ,record.value('(./Record/SchedulerMonitorEvent/SystemHealth/SystemIdle)[1]',

    'int') AS SystemIdle

    ,record.value('(./Record/SchedulerMonitorEvent/SystemHealth/ProcessUtilization)[1]',

    'int') AS SQLProcessUtilization

    ,TIMESTAMP

    FROM

    (

    SELECT

    TIMESTAMP

    ,CONVERT(XML, record) AS record

    FROM

    sys.dm_os_ring_buffers

    WHERE

    ring_buffer_type = N'RING_BUFFER_SCHEDULER_MONITOR'

    AND record LIKE '% %'

    AND DATEADD(ms, -1 * (@ts_now - [timestamp]), GETDATE()) BETWEEN @StartTime AND @EndTime

    ) AS x

    ) AS y

    --Return details

    IF @ShowDetails = 1

    BEGIN

    SELECT

    record_ID

    ,EventTime

    ,SQLProcessUtilization

    ,SystemIdle

    ,OtherProcessUtilization

    FROM @Results

    END

    --Return average

    SELECT

    AVG(SQLProcessUtilization)

    ,MIN(EVENTTIME) StartTime

    ,MAX(EVENTTIME) EndTime

    FROM

    @Results

  • Hi Jason,

    nice work.

    [font="Verdana"]Markus Bohse[/font]

Viewing 15 posts - 1 through 15 (of 15 total)

You must be logged in to reply to this topic. Login to reply