Identifying long running queries SQL server

  • What is the step by step approach to identifying long running queries in the server. What services and panels do you utilize? What specifically do you look at? Would it be specific to a database? Is the approach similar in SQL 2000 and 2005?

    Thanks very much!!!

  • Well, if there is a "long running query" and I need to find the reason for "why" it is running so long, I proceed like this:

    1. Run SQL Profiler; searching for queries which have a high number of "Reads". This mostly indicates "Index Scans" which could cause the long runtime. Check the "Execution PLan" of those queries to optimize e.g. Indexes etc.. According to this you should check the Statistics and Fragmentation degree of that table and fix it if necessary

    2. Checking for Blocks. I proceed as described here: http://dynamicsuser.net/blogs/stryk/archive/2008/11/03/blocks-amp-deadlocks-in-nav-with-sql-server.aspx

    3. Check "Wait Statistics" to find out if theres an I/O problem, e.g. a problem with network or disk-subsystem. Therefore I look into the "sys.dm_os_wait_stats" DMV

    Jörg A. Stryk
    MVP - MS Dynamics NAV

  • SQL Server 2005 keeps alot of good information in the dynamic management views about this kind of thing. Below are the 2 main queries I use to find slow running application queries in our systems.

    Queries taking longest elapsed time:

    SELECT TOP 100

    qs.total_elapsed_time / qs.execution_count / 1000000.0 AS average_seconds,

    qs.total_elapsed_time / 1000000.0 AS total_seconds,

    qs.execution_count,

    SUBSTRING (qt.text,qs.statement_start_offset/2,

    (CASE WHEN qs.statement_end_offset = -1

    THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2

    ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS individual_query,

    o.name AS object_name,

    DB_NAME(qt.dbid) AS database_name

    FROM sys.dm_exec_query_stats qs

    CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) as qt

    LEFT OUTER JOIN sys.objects o ON qt.objectid = o.object_id

    where qt.dbid = DB_ID()

    ORDER BY average_seconds DESC;

    Queries doing most I/O:

    SELECT TOP 100

    (total_logical_reads + total_logical_writes) / qs.execution_count AS average_IO,

    (total_logical_reads + total_logical_writes) AS total_IO,

    qs.execution_count AS execution_count,

    SUBSTRING (qt.text,qs.statement_start_offset/2,

    (CASE WHEN qs.statement_end_offset = -1

    THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2

    ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS indivudual_query,

    o.name AS object_name,

    DB_NAME(qt.dbid) AS database_name

    FROM sys.dm_exec_query_stats qs

    CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) as qt

    LEFT OUTER JOIN sys.objects o ON qt.objectid = o.object_id

    where qt.dbid = DB_ID()

    ORDER BY average_IO DESC;

    Once you see the queries that have the longest elapsed time or most I/O, you can then look at the execution plans of those particular queries to see what inefficiencies are there, and look for possible places to improve indexes or even rewrite a query using a different approach.

  • I'm pretty similar in approach, Profiler is my bestest buddy.

    After that, since you're in 2005, you can look at sys.dm_exec_query_stats for an immediate picture into which queries are running long and how, for how long, etc., they've been running. That's aggregate information of queries that are currently in cache. You can go to sys.dm_exec_requests to see things that are currently executing. From that you can get the query handle and call to sys.dm_exec_sql_text to get the query text or sys.dm_exec_query_plan to see the execution plan.

    If you want to go a bit more old school you can still run sp_who2. It shows the basic information and any blocked processes as well as the process that is blocking.

    I still use execution time as a measure and look at wait stats to identify why things were running so long.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • Would the query below work?

    I'm looking for long-running queries that are currently running on the server, not a historic analysis of those stored in the cache.

    Queries are ordered by total_elapsed_time desc:

    SELECT

    r.session_id

    ,r.start_time

    ,TotalElapsedTime_ms = r.total_elapsed_time

    ,r.[status]

    ,r.command

    ,DatabaseName = DB_Name(r.database_id)

    ,r.wait_type

    ,r.last_wait_type

    ,r.wait_resource

    ,r.cpu_time

    ,r.reads

    ,r.writes

    ,r.logical_reads

    ,t.[text] AS [executing batch]

    ,SUBSTRING(

    t.[text], r.statement_start_offset / 2,

    (CASE WHEN r.statement_end_offset = -1 THEN DATALENGTH (t.[text])

    ELSE r.statement_end_offset

    END - r.statement_start_offset ) / 2

    ) AS [executing statement]

    ,p.query_plan

    FROM

    sys.dm_exec_requests r

    CROSS APPLY

    sys.dm_exec_sql_text(r.sql_handle) AS t

    CROSS APPLY

    sys.dm_exec_query_plan(r.plan_handle) AS p

    ORDER BY

    r.total_elapsed_time DESC;

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • Please note: 3 year old thread.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • GilaMonster (7/21/2011)


    Please note: 3 year old thread.

    I'll open a new post.

    __________________________________________________________________________________
    SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables[/url]
    Persisting SQL Server Index-Usage Statistics with MERGE[/url]
    Turbocharge Your Database Maintenance With Service Broker: Part 2[/url]

  • SELECT TOP 100 qs.total_elapsed_time / qs.execution_count / 1000000.0 AS average_seconds,

    qs.total_elapsed_time / 1000000.0 AS total_seconds, qs.execution_count,

    SUBSTRING (qt.text,qs.statement_start_offset/2, (CASE WHEN qs.statement_end_offset = -1

    THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS individual_query,

    o.name AS object_name, DB_NAME(qt.dbid) AS database_name FROM sys.dm_exec_query_stats qs

    CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) as qt

    LEFT OUTER JOIN sys.objects o ON qt.objectid = o.object_idwhere qt.dbid = DB_ID()

    ORDER BY average_seconds DESC;

    what´s the error -

    Msg 102, Level 15, State 1, Line 7

    Incorrect syntax near 'qt'.

  • --Corrected.

    SELECT TOP 100 qs.total_elapsed_time / qs.execution_count / 1000000.0 AS average_seconds,

    qs.total_elapsed_time / 1000000.0 AS total_seconds, qs.execution_count,

    SUBSTRING (qt.text,qs.statement_start_offset/2, (CASE WHEN qs.statement_end_offset = -1

    THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS individual_query,

    o.name AS object_name, DB_NAME(qt.dbid) AS database_name FROM sys.dm_exec_query_stats qs

    CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) as qt

    LEFT OUTER JOIN sys.objects o ON qt.objectid = o.object_id

    where qt.dbid = DB_ID()

    ORDER BY average_seconds DESC;

  • SELECT TOP 100 qs.total_elapsed_time / qs.execution_count / 1000000.0 AS average_seconds

    , qs.total_elapsed_time / 1000000.0 AS total_seconds

    , qs.execution_count

    , SUBSTRING (qt.text,qs.statement_start_offset/2

    , (CASE WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS individual_query

    , o.name AS object_name

    , DB_NAME(qt.dbid) AS database_name

    FROM sys.dm_exec_query_stats qs

    CROSS APPLY

    sys.dm_exec_sql_text(qs.sql_handle) as qt

    LEFT OUTER JOIN

    sys.objects o ON qt.objectid = o.object_id

    WHERE qt.dbid = DB_ID()

    ORDER

    BY average_seconds DESC;


    James E Bothamley
    Sr DBA
    Supreme Court of Wyoming
    JBothamley@Courts.State.WY.US
    JamesBothamley@Wyoming.Com

    "Once in a while you can get shown the light
    in the strangest of places if you look at it right"

    JG 1942-1995 RIP

  • Reviving a thread twice 😛

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • James,

    We are getting nulls for object_name and database_name

    Can you please advise on this

  • A NULL for the Object name would just imply that you're seeing ad hoc or prepared queries that don't have an object because they're not being called by a stored procedure. Instead it's just a query batch being passed in. That just makes sense. You can read more about it in the documentation in the Books Online. The db_id is null because a sql_handle can't uniquely identify which database a query came from, so they don't store that information. Read about it in this Connect item.

    In short, you're seeing normal behavior.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

  • hi grant,

    I tried with the below query using the reference

    http://msdn.microsoft.com/en-us/library/ms189472.aspx

    SELECT qs.plan_handle, pvt.sql_handle,pvt.dbid,

    (SELECT TOP 1 SUBSTRING(s2.text,statement_start_offset / 2+1 ,

    ( (CASE WHEN statement_end_offset = -1

    THEN (LEN(CONVERT(nvarchar(max),s2.text)) * 2)

    ELSE statement_end_offset END) - statement_start_offset) / 2+1)) AS sql_statement,

    qs.execution_count AS [Execution Count],

    qs.total_elapsed_time/(1000*1000) as [Total Time In Secs],

    qs.total_elapsed_time/1000 as [Total Time In Millisecs],

    qs.total_elapsed_time / (1000 * qs.execution_count) as [Avg Resp Time in Millisecs],

    qs.max_elapsed_time / (1000) as [Max Resp Time in Millisecs],

    qs.min_elapsed_time / (1000) as [Min Resp Time in Millisecs],

    qs.total_elapsed_time / qs.execution_count / 1000000.0 AS average_seconds,

    qs.total_elapsed_time / 1000000.0 AS total_seconds,

    qs.last_execution_time [Last Executed At]

    FROM (

    SELECT plan_handle, epa.attribute, epa.value

    FROM sys.dm_exec_cached_plans

    OUTER APPLY sys.dm_exec_plan_attributes(plan_handle) AS epa

    WHERE cacheobjtype = 'Compiled Plan') AS ecpa

    PIVOT (MAX(ecpa.value) FOR ecpa.attribute IN ("dbid", "sql_handle")) AS pvt

    inner join sys.dm_exec_query_stats AS qs on qs.sql_handle =pvt.sql_handle

    CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS s2

    where pvt.dbid =DB_ID()

    GO

    But sometime, some queries are appearing for two different databases :unsure:

  • It's possible the query is being run from more than one database.

    The real problem is, this is an imprecise mechanism for identifying long running queries. It's completely dependent on the queries being in cache. They can age out of cache, or never go there if the query has a RECOMPILE hint. If you really, really have to have perfect measures of exactly which queries runs on exactly which database, this is not the way to go about it. Instead, capture query metrics using trace events.

    "The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
    - Theodore Roosevelt

    Author of:
    SQL Server Execution Plans
    SQL Server Query Performance Tuning

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

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