SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Identifying long running queries SQL server


Identifying long running queries SQL server

Author
Message
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16794 Visits: 19121
Reviving a thread twice :-P


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
pmadhavapeddi22
pmadhavapeddi22
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1522 Visits: 1870
James,

We are getting nulls for object_name and database_name

Can you please advise on this
Grant Fritchey
Grant Fritchey
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40777 Visits: 32666
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

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
pmadhavapeddi22
pmadhavapeddi22
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1522 Visits: 1870
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
Grant Fritchey
Grant Fritchey
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40777 Visits: 32666
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

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
pmadhavapeddi22
pmadhavapeddi22
SSCommitted
SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)SSCommitted (1.5K reputation)

Group: General Forum Members
Points: 1522 Visits: 1870
Thanks grant
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search