常用SQL Server进行性能优化语句

1、锁监控

查看锁住的表:

select   request_session_id   spid,object_name(resource_associated_entity_id) tablename  
from   sys.dm_tran_locks where resource_type='object'

查看哪个会话引起阻塞并且它们在运行什么:

select  dtl.[request_session_id] as [session_id] ,
        db_name(dtl.[resource_database_id]) as [database] ,
        dtl.resource_type ,
        case when dtl.resource_type in ( 'database', 'file', 'metadata' )
             then dtl.resource_type
             when dtl.resource_type = 'object'
             then object_name(dtl.resource_associated_entity_id,
                              dtl.[resource_database_id])
             when dtl.resource_type in ( 'key', 'page', 'rid' )
             then ( select  object_name([object_id])
                    from    sys.partitions
                    where   sys.partitions.hobt_id = dtl.resource_associated_entity_id
                  )
             else 'unidentified'
        end as [parent object] ,
        dtl.request_mode as [lock type] ,
        dtl.request_status as [request status] ,
        der.[blocking_session_id] ,
        des.[login_name] ,
        case dtl.request_lifetime
          when 0 then dest_r.text
          else dest_c.text
        end as [statement]
from    sys.dm_tran_locks dtl
        left join sys.[dm_exec_requests] der on dtl.[request_session_id] = der.[session_id]
        inner join sys.dm_exec_sessions des on dtl.request_session_id = des.[session_id]
        inner join sys.dm_exec_connections dec on dtl.[request_session_id] = dec.[most_recent_session_id]
        outer apply sys.dm_exec_sql_text(dec.[most_recent_sql_handle]) as dest_c
        outer apply sys.dm_exec_sql_text(der.sql_handle) as dest_r
where   dtl.[resource_database_id] = db_id()
        and dtl.[resource_type] not in ( 'database', 'metadata' )
order by dtl.[request_session_id];

查看因为单条update语句锁住的用户表:

select  [resource_type] ,
        db_name([resource_database_id]) as [database name] ,
        case when dtl.resource_type in ( 'database', 'file', 'metadata' )
             then dtl.resource_type
             when dtl.resource_type = 'object'
             then object_name(dtl.resource_associated_entity_id,
                              dtl.[resource_database_id])
             when dtl.resource_type in ( 'key', 'page', 'rid' )
             then ( select  object_name([object_id])
                    from    sys.partitions
                    where   sys.partitions.hobt_id = dtl.resource_associated_entity_id
                  )
             else 'unidentified'
        end as requested_object_name ,
        [request_mode] ,
        [resource_description]
from    sys.dm_tran_locks dtl
where   dtl.[resource_type] <> 'database';

单库中的锁定和阻塞:

select  dtl.[resource_type] as [resource type] ,
        case when dtl.[resource_type] in ( 'database', 'file', 'metadata' )
             then dtl.[resource_type]
             when dtl.[resource_type] = 'object'
             then object_name(dtl.resource_associated_entity_id)
             when dtl.[resource_type] in ( 'key', 'page', 'rid' )
             then ( select  object_name([object_id])
                    from    sys.partitions
                    where   sys.partitions.[hobt_id] = dtl.[resource_associated_entity_id]
                  )
             else 'unidentified'
        end as [parent object] ,
        dtl.[request_mode] as [lock type] ,
        dtl.[request_status] as [request status] ,
        dowt.[wait_duration_ms] as [wait duration ms] ,
        dowt.[wait_type] as [wait type] ,
        dowt.[session_id] as [blocked session id] ,
        des_blocked.[login_name] as [blocked_user] ,
        substring(dest_blocked.text, der.statement_start_offset / 2,
                  ( case when der.statement_end_offset = -1
                         then datalength(dest_blocked.text)
                         else der.statement_end_offset
                    end - der.statement_start_offset ) / 2) as [blocked_command] ,
        dowt.[blocking_session_id] as [blocking session id] ,
        des_blocking.[login_name] as [blocking user] ,
        dest_blocking.[text] as [blocking command] ,
        dowt.resource_description as [blocking resource detail]
from    sys.dm_tran_locks dtl
        inner join sys.dm_os_waiting_tasks dowt on dtl.lock_owner_address = dowt.resource_address
        inner join sys.[dm_exec_requests] der on dowt.[session_id] = der.[session_id]
        inner join sys.dm_exec_sessions des_blocked on dowt.[session_id] = des_blocked.[session_id]
        inner join sys.dm_exec_sessions des_blocking on dowt.[blocking_session_id] = des_blocking.[session_id]
        inner join sys.dm_exec_connections dec on dtl.[request_session_id] = dec.[most_recent_session_id]
        cross apply sys.dm_exec_sql_text(dec.[most_recent_sql_handle]) as dest_blocking
        cross apply sys.dm_exec_sql_text(der.sql_handle) as dest_blocked
where   dtl.[resource_database_id] = db_id()

识别在行级的锁定和阻塞:

select  '[' + db_name(ddios.[database_id]) + '].[' + su.[name] + '].['
        + o.[name] + ']' as [statement] ,
        i.[name] as 'index_name' ,
        ddios.[partition_number] ,
        ddios.[row_lock_count] ,
        ddios.[row_lock_wait_count] ,
        cast (100.0 * ddios.[row_lock_wait_count] / ( ddios.[row_lock_count] ) as decimal(5,
                                                              2)) as [%_times_blocked] ,
        ddios.[row_lock_wait_in_ms] ,
        cast (1.0 * ddios.[row_lock_wait_in_ms] / ddios.[row_lock_wait_count] as decimal(15,
                                                              2)) as [avg_row_lock_wait_in_ms]
from    sys.dm_db_index_operational_stats(db_id(), null, null, null) ddios
        inner join sys.indexes i on ddios.[object_id] = i.[object_id]
                                    and i.[index_id] = ddios.[index_id]
        inner join sys.objects o on ddios.[object_id] = o.[object_id]
        inner join sys.sysusers su on o.[schema_id] = su.[uid]
where   ddios.row_lock_wait_count > 0
        and objectproperty(ddios.[object_id], 'isusertable') = 1
        and i.[index_id] > 0
order by ddios.[row_lock_wait_count] desc ,
        su.[name] ,
        o.[name] ,
        i.[name]

识别闩锁等待:

select  '[' + db_name() + '].[' + object_schema_name(ddios.[object_id])
        + '].[' + object_name(ddios.[object_id]) + ']' as [object_name] ,
        i.[name] as index_name ,
        ddios.page_io_latch_wait_count ,
        ddios.page_io_latch_wait_in_ms ,
        ( ddios.page_io_latch_wait_in_ms / ddios.page_io_latch_wait_count ) as avg_page_io_latch_wait_in_ms
from    sys.dm_db_index_operational_stats(db_id(), null, null, null) ddios
        inner join sys.indexes i on ddios.[object_id] = i.[object_id]
                                    and i.index_id = ddios.index_id
where   ddios.page_io_latch_wait_count > 0
        and objectproperty(i.object_id, 'isusertable') = 1
order by ddios.page_io_latch_wait_count desc ,
        avg_page_io_latch_wait_in_ms desc

识别锁升级:

select  object_name(ddios.[object_id], ddios.database_id) as [object_name] ,
        i.name as index_name ,
        ddios.index_id ,
        ddios.partition_number ,
        ddios.index_lock_promotion_attempt_count ,
        ddios.index_lock_promotion_count ,
        ( ddios.index_lock_promotion_attempt_count
          / ddios.index_lock_promotion_count ) as percent_success
from    sys.dm_db_index_operational_stats(db_id(), null, null, null) ddios
        inner join sys.indexes i on ddios.object_id = i.object_id
                                    and ddios.index_id = i.index_id
where   ddios.index_lock_promotion_count > 0
order by index_lock_promotion_count desc;

与锁争用有关的索引:

select  object_name(ddios.object_id, ddios.database_id) as object_name ,
        i.name as index_name ,
        ddios.index_id ,
        ddios.partition_number ,
        ddios.page_lock_wait_count ,
        ddios.page_lock_wait_in_ms ,
        case when ddmid.database_id is null then 'n'
             else 'y'
        end as missing_index_identified
from    sys.dm_db_index_operational_stats(db_id(), null, null, null) ddios
        inner join sys.indexes i on ddios.object_id = i.object_id
                                    and ddios.index_id = i.index_id
        left outer join ( select distinct
                                    database_id ,
                                    object_id
                          from      sys.dm_db_missing_index_details
                        ) as ddmid on ddmid.database_id = ddios.database_id
                                      and ddmid.object_id = ddios.object_id
where   ddios.page_lock_wait_in_ms > 0
order by ddios.page_lock_wait_count desc;

 

2、索引监控

未被使用的索引:

select  object_name(i.[object_id]) as [table name] ,
        i.name
from    sys.indexes as i
        inner join sys.objects as o on i.[object_id] = o.[object_id]
where   i.index_id not in ( select  ddius.index_id
                            from    sys.dm_db_index_usage_stats as ddius
                            where   ddius.[object_id] = i.[object_id]
                                    and i.index_id = ddius.index_id
                                    and database_id = db_id() )
        and o.[type] = 'u'
order by object_name(i.[object_id]) asc;

需要维护但是未被用过的索引:

select  '[' + db_name() + '].[' + su.[name] + '].[' + o.[name] + ']' as [statement] ,
        i.[name] as [index_name] ,
        ddius.[user_seeks] + ddius.[user_scans] + ddius.[user_lookups] as [user_reads] ,
        ddius.[user_updates] as [user_writes] ,
        sum(sp.rows) as [total_rows]
from    sys.dm_db_index_usage_stats ddius
        inner join sys.indexes i on ddius.[object_id] = i.[object_id]
                                    and i.[index_id] = ddius.[index_id]
        inner join sys.partitions sp on ddius.[object_id] = sp.[object_id]
                                        and sp.[index_id] = ddius.[index_id]
        inner join sys.objects o on ddius.[object_id] = o.[object_id]
        inner join sys.sysusers su on o.[schema_id] = su.[uid]
where   ddius.[database_id] = db_id() -- current database only
        and objectproperty(ddius.[object_id], 'isusertable') = 1
        and ddius.[index_id] > 0
group by su.[name] ,
        o.[name] ,
        i.[name] ,
        ddius.[user_seeks] + ddius.[user_scans] + ddius.[user_lookups] ,
        ddius.[user_updates]
having  ddius.[user_seeks] + ddius.[user_scans] + ddius.[user_lookups] = 0
order by ddius.[user_updates] desc ,
        su.[name] ,
        o.[name] ,
        i.[name]

可能不高效的非聚集索引 (writes > reads):

select  object_name(ddius.[object_id]) as [table name] ,
        i.name as [index name] ,
        i.index_id ,
        user_updates as [total writes] ,
        user_seeks + user_scans + user_lookups as [total reads] ,
        user_updates - ( user_seeks + user_scans + user_lookups ) as [difference]
from    sys.dm_db_index_usage_stats as ddius with ( nolock )
        inner join sys.indexes as i with ( nolock ) on ddius.[object_id] = i.[object_id]
                                                       and i.index_id = ddius.index_id
where   objectproperty(ddius.[object_id], 'isusertable') = 1
        and ddius.database_id = db_id()
        and user_updates > ( user_seeks + user_scans + user_lookups )
        and i.index_id > 1
order by [difference] desc ,
        [total writes] desc ,
        [total reads] asc;

没有用于用户查询的索引:

select  '[' + db_name() + '].[' + su.[name] + '].[' + o.[name] + ']' as [statement] ,
        i.[name] as [index_name] ,
        ddius.[user_seeks] + ddius.[user_scans] + ddius.[user_lookups] as [user_reads] ,
        ddius.[user_updates] as [user_writes] ,
        ddios.[leaf_insert_count] ,
        ddios.[leaf_delete_count] ,
        ddios.[leaf_update_count] ,
        ddios.[nonleaf_insert_count] ,
        ddios.[nonleaf_delete_count] ,
        ddios.[nonleaf_update_count]
from    sys.dm_db_index_usage_stats ddius
        inner join sys.indexes i on ddius.[object_id] = i.[object_id]
                                    and i.[index_id] = ddius.[index_id]
        inner join sys.partitions sp on ddius.[object_id] = sp.[object_id]
                                        and sp.[index_id] = ddius.[index_id]
        inner join sys.objects o on ddius.[object_id] = o.[object_id]
        inner join sys.sysusers su on o.[schema_id] = su.[uid]
        inner join sys.[dm_db_index_operational_stats](db_id(), null, null,
                                                       null) as ddios on ddius.[index_id] = ddios.[index_id]
                                                              and ddius.[object_id] = ddios.[object_id]
                                                              and sp.[partition_number] = ddios.[partition_number]
                                                              and ddius.[database_id] = ddios.[database_id]
where   objectproperty(ddius.[object_id], 'isusertable') = 1
        and ddius.[index_id] > 0
        and ddius.[user_seeks] + ddius.[user_scans] + ddius.[user_lookups] = 0
order by ddius.[user_updates] desc ,
        su.[name] ,
        o.[name] ,
        i.[name]

查找丢失索引:

select  user_seeks * avg_total_user_cost * ( avg_user_impact * 0.01 ) as [index_advantage] ,
        dbmigs.last_user_seek ,
        dbmid.[statement] as [database.schema.table] ,
        dbmid.equality_columns ,
        dbmid.inequality_columns ,
        dbmid.included_columns ,
        dbmigs.unique_compiles ,
        dbmigs.user_seeks ,
        dbmigs.avg_total_user_cost ,
        dbmigs.avg_user_impact
from    sys.dm_db_missing_index_group_stats as dbmigs with ( nolock )
        inner join sys.dm_db_missing_index_groups as dbmig with ( nolock ) on dbmigs.group_handle = dbmig.index_group_handle
        inner join sys.dm_db_missing_index_details as dbmid with ( nolock ) on dbmig.index_handle = dbmid.index_handle
where   dbmid.[database_id] = db_id()
order by index_advantage desc;

索引上的碎片超过15%并且索引体积较大(超过500页)的索引:

select  '[' + db_name() + '].[' + object_schema_name(ddips.[object_id],
                                                     db_id()) + '].['
        + object_name(ddips.[object_id], db_id()) + ']' as [statement] ,
        i.[name] as [index_name] ,
        ddips.[index_type_desc] ,
        ddips.[partition_number] ,
        ddips.[alloc_unit_type_desc] ,
        ddips.[index_depth] ,
        ddips.[index_level] ,
        cast(ddips.[avg_fragmentation_in_percent] as smallint) as [avg_frag_%] ,
        cast(ddips.[avg_fragment_size_in_pages] as smallint) as [avg_frag_size_in_pages] ,
        ddips.[fragment_count] ,
        ddips.[page_count]
from    sys.dm_db_index_physical_stats(db_id(), null, null, null, 'limited') ddips
        inner join sys.[indexes] i on ddips.[object_id] = i.[object_id]
                                      and ddips.[index_id] = i.[index_id]
where   ddips.[avg_fragmentation_in_percent] > 15
        and ddips.[page_count] > 500
order by ddips.[avg_fragmentation_in_percent] ,
        object_name(ddips.[object_id], db_id()) ,
        i.[name]

缺失索引:

select migs.group_handle, mid.* 
from sys.dm_db_missing_index_group_stats as migs 
inner join sys.dm_db_missing_index_groups as mig 
on (migs.group_handle = mig.index_group_handle) 
inner join sys.dm_db_missing_index_details as mid 
on (mig.index_handle = mid.index_handle) 
where migs.group_handle = 2

无用索引:

set transaction isolation level read uncommitted 
select 
db_name() as datbasename 
, schema_name(o.schema_id) as schemaname 
, object_name(i.object_id) as tablename 
, i.name as indexname 
into #tempneverusedindexes 
from sys.indexes i inner join sys.objects o on i.object_id = o.object_id 
where 1=2 
exec sp_msforeachdb 'use [?]; insert into #tempneverusedindexes 
select 
db_name() as datbasename 
, schema_name(o.schema_id) as schemaname 
, object_name(i.object_id) as tablename 
, i.name as indexname 
from sys.indexes i inner join sys.objects o on i.object_id = o.object_id 
left outer join sys.dm_db_index_usage_stats s on s.object_id = i.object_id 
and i.index_id = s.index_id 
and database_id = db_id() 
where objectproperty(o.object_id,''ismsshipped'') = 0 
and i.name is not null 
and s.object_id is null' 
select * from #tempneverusedindexes 
order by datbasename, schemaname, tablename, indexname 
drop table #tempneverusedindexes

经常被大量更新,但是却基本不适用的索引:

set transaction isolation level read uncommitted 
select 
db_name() as databasename 
, schema_name(o.schema_id) as schemaname 
, object_name(s.[object_id]) as tablename 
, i.name as indexname 
, s.user_updates 
, s.system_seeks + s.system_scans + s.system_lookups 
as [system usage] 
into #tempunusedindexes 
from sys.dm_db_index_usage_stats s 
inner join sys.indexes i on s.[object_id] = i.[object_id] 
and s.index_id = i.index_id 
inner join sys.objects o on i.object_id = o.object_id 
where 1=2 
exec sp_msforeachdb 'use [?]; insert into #tempunusedindexes 
select top 20 
db_name() as databasename 
, schema_name(o.schema_id) as schemaname 
, object_name(s.[object_id]) as tablename 
, i.name as indexname 
, s.user_updates 
, s.system_seeks + s.system_scans + s.system_lookups 
as [system usage] 
from sys.dm_db_index_usage_stats s 
inner join sys.indexes i on s.[object_id] = i.[object_id] 
and s.index_id = i.index_id 
inner join sys.objects o on i.object_id = o.object_id 
where s.database_id = db_id() 
and objectproperty(s.[object_id], ''ismsshipped'') = 0 
and s.user_seeks = 0 
and s.user_scans = 0 
and s.user_lookups = 0 
and i.name is not null 
order by s.user_updates desc' 
select top 20 * from #tempunusedindexes order by [user_updates] desc 
drop table #tempunusedindexes

 

3、数据库环境监控

查询当前数据库的配置信息:

select configuration_id configurationid,
name name,
description description,
cast(value as int) value,
cast(minimum as int) minimum,
cast(maximum as int) maximum,
cast(value_in_use as int) valueinuse,
is_dynamic isdynamic,
is_advanced isadvanced
from sys.configurations
order by is_advanced, name

检查sql server 当前已创建的线程数:

select count(*) from sys.dm_os_workers

查询当前连接到数据库的用户信息:

select s.login_name loginname,
s.host_name hostname,
s.transaction_isolation_level transactionisolationlevel,
max(c.connect_time) lastconnecttime,
count(*) connectioncount,
sum(cast(c.num_reads as bigint)) totalreads,
sum(cast(c.num_writes as bigint)) totalwrites
from sys.dm_exec_connections c
join sys.dm_exec_sessions s
on c.most_recent_session_id = s.session_id
group by s.login_name, s.host_name, s.transaction_isolation_level

查询cpu和内存利用率:

select dateadd(s, (timestamp - (osi.cpu_ticks / convert(float, (osi.cpu_ticks / osi.ms_ticks)))) / 1000, getdate()) as eventtime,
record.value('(./record/schedulermonitorevent/systemhealth/systemidle)[1]', 'int') as systemidle,
record.value('(./record/schedulermonitorevent/systemhealth/processutilization)[1]', 'int') as processutilization,
record.value('(./record/schedulermonitorevent/systemhealth/memoryutilization)[1]', 'int') as memoryutilization
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 '%<systemhealth>%') x
cross join sys.dm_os_sys_info osi
order by timestamp

查看每个数据库缓存大小:

select  count(*) * 8 / 1024 as 'cached size (mb)' ,
        case database_id
          when 32767 then 'resourcedb'
          else db_name(database_id)
        end as 'database'
from    sys.dm_os_buffer_descriptors
group by db_name(database_id) ,
        database_id
order by 'cached size (mb)' desc

统计io活动信息:

set statistics io on
select top 10* from table
set statistics io off

清除缓存sql语句:

checkpoint;
go
dbcc  freeproccache      ---清空执行计划缓存
dbcc dropcleanbuffers;   --清空数据缓存
go

查看当前进程的信息:

dbcc inputbuffer(51)

查看当前数据是否启用了快照隔离:

dbcc useroptions;

查看摸个数据库数据表中的数据页类型:

--in_row_data: 分别为存储行内数据的
    --lob_data: 存储lob对象,lob对象用于存储存在数据库的二进制文件
              --当这个类型的列出现时,原有的列会存储一个24字节的指针,而将具体的二进制数据存在lob页中
    --row_overflow_data:存储溢出数据的,使用varchar,nvarchar等数据类型时,当行的大小不超过8060字节时,全部存在行内in-row data
                    --当varchar中存储的数据过多使得整行超过8060字节时,会将额外的部分存于row-overflow data页中,
                    --如果update这列使得行大小减少到小于8060字节,则这行又会全部回到in-row data页
                    --text,ntext和image类型来说,每一列只要不为null,即使占用很小的数据,也需要额外分配一个lob页
dbcc ind ( lawyer, [dbo.tb_contract], -1)

 

4、sql执行次数和性能监控

查询cpu最高的10条sql:

select top 10 text as 'sql statement'
    ,last_execution_time as 'last execution time'
    ,(total_logical_reads + total_physical_reads + total_logical_writes) / execution_count as [average io]
    ,(total_worker_time / execution_count) / 1000000.0 as [average cpu time (sec)]
    ,(total_elapsed_time / execution_count) / 1000000.0 as [average elapsed time (sec)]
    ,execution_count as "execution count",qs.total_physical_reads,qs.total_logical_writes
    ,qp.query_plan as "query plan"
from sys.dm_exec_query_stats qs
cross apply sys.dm_exec_sql_text(qs.plan_handle) st
cross apply sys.dm_exec_query_plan(qs.plan_handle) qp
order by total_elapsed_time / execution_count desc

找出执行频繁的语句的sql语句:

with aa as (
select  
--执行次数 
qs.execution_count, 
--查询语句 
substring(st.text,(qs.statement_start_offset/2)+1, 
((case qs.statement_end_offset when -1 then datalength(st.text) 
else qs.statement_end_offset end - qs.statement_start_offset)/2) + 1 
) as statement_text, 
--执行文本 
st.text, 
--执行计划 
qs.last_elapsed_time,
qs.min_elapsed_time,
qs.max_elapsed_time,
qs.total_worker_time, 
qs.last_worker_time, 
qs.max_worker_time, 
qs.min_worker_time 
from 
sys.dm_exec_query_stats qs 
--关键字 
cross apply 
sys.dm_exec_sql_text(qs.sql_handle) st 
where 
qs.last_execution_time > '2016-02-14 00:00:00' and  execution_count > 500

-- and st.text like '%%' 
--order by 
--qs.execution_count desc

)
select text,max(execution_count) execution_count --,last_elapsed_time,min_elapsed_time,max_elapsed_time 
from aa
where [text] not  like '%sp_msupd_%' and  [text] not like '%sp_msins_%' and  [text] not like '%sp_msdel_%' 
group by text
order by 2  desc

查找逻辑读取最高的查询(存储过程):

select top ( 25 )
        p.name as [sp name] ,
        deps.total_logical_reads as [totallogicalreads] ,
        deps.total_logical_reads / deps.execution_count as [avglogicalreads] ,
        deps.execution_count ,
        isnull(deps.execution_count / datediff(second, deps.cached_time,
                                               getdate()), 0) as [calls/second] ,
        deps.total_elapsed_time ,
        deps.total_elapsed_time / deps.execution_count as [avg_elapsed_time] ,
        deps.cached_time
from    sys.procedures as p
        inner join sys.dm_exec_procedure_stats as deps on p.[object_id] = deps.[object_id]
where   deps.database_id = db_id()
order by deps.total_logical_reads desc;

查看某个sql的执行计划:

set statistics profile on 
select * from demo
set statistics profile off

查询某个sql的执行时间:

set statistics time on 
select * from demo
set statistics time off

查询某个sql的io信息:

set statistics io on 
select * from demo
set statistics io off

 

5、开源监控脚本,监控数据库锁定情况

use master
go
if not exists (select * from information_schema.routines where routine_name = 'sp_whoisactive')
exec ('create proc dbo.sp_whoisactive as select ''stub version, to be replaced''')
go
/*********************************************************************************************
who is active? v11.17 (2016-10-18)
(c) 2007-2016, adam machanic
feedback: mailto:amachanic@gmail.com
updates: http://whoisactive.com
license: 
who is active? is free to download and use for personal, educational, and internal 
corporate purposes, provided that this header is preserved. redistribution or sale 
of who is active?, in whole or in part, is prohibited without the author's express 
written consent.
*********************************************************************************************/
alter proc dbo.sp_whoisactive
(
--~
--filters--both inclusive and exclusive
--set either filter to '' to disable
--valid filter types are: session, program, database, login, and host
--session is a session id, and either 0 or '' can be used to indicate "all" sessions
--all other filter types support % or _ as wildcards
@filter sysname = '',
@filter_type varchar(10) = 'session',
@not_filter sysname = '',
@not_filter_type varchar(10) = 'session',
--retrieve data about the calling session?
@show_own_spid bit = 0,
--retrieve data about system sessions?
@show_system_spids bit = 0,
--controls how sleeping spids are handled, based on the idea of levels of interest
--0 does not pull any sleeping spids
--1 pulls only those sleeping spids that also have an open transaction
--2 pulls all sleeping spids
@show_sleeping_spids tinyint = 1,
--if 1, gets the full stored procedure or running batch, when available
--if 0, gets only the actual statement that is currently running in the batch or procedure
@get_full_inner_text bit = 0,
--get associated query plans for running tasks, if available
--if @get_plans = 1, gets the plan based on the request's statement offset
--if @get_plans = 2, gets the entire plan based on the request's plan_handle
@get_plans tinyint = 0,
--get the associated outer ad hoc query or stored procedure call, if available
@get_outer_command bit = 0,
--enables pulling transaction log write info and transaction duration
@get_transaction_info bit = 0,
--get information on active tasks, based on three interest levels
--level 0 does not pull any task-related information
--level 1 is a lightweight mode that pulls the top non-cxpacket wait, giving preference to blockers
--level 2 pulls all available task-based metrics, including: 
--number of active tasks, current wait stats, physical i/o, context switches, and blocker information
@get_task_info tinyint = 1,
--gets associated locks for each request, aggregated in an xml format
@get_locks bit = 0,
--get average time for past runs of an active query
--(based on the combination of plan handle, sql handle, and offset)
@get_avg_time bit = 0,
--get additional non-performance-related information about the session or request
--text_size, language, date_format, date_first, quoted_identifier, arithabort, ansi_null_dflt_on, 
--ansi_defaults, ansi_warnings, ansi_padding, ansi_nulls, concat_null_yields_null, 
--transaction_isolation_level, lock_timeout, deadlock_priority, row_count, command_type
--
--if a sql agent job is running, an subnode called agent_info will be populated with some or all of
--the following: job_id, job_name, step_id, step_name, msdb_query_error (in the event of an error)
--
--if @get_task_info is set to 2 and a lock wait is detected, a subnode called block_info will be
--populated with some or all of the following: lock_type, database_name, object_id, file_id, hobt_id, 
--applock_hash, metadata_resource, metadata_class_id, object_name, schema_name
@get_additional_info bit = 0,
--walk the blocking chain and count the number of 
--total spids blocked all the way down by a given session
--also enables task_info level 1, if @get_task_info is set to 0
@find_block_leaders bit = 0,
--pull deltas on various metrics
--interval in seconds to wait before doing the second data pull
@delta_interval tinyint = 0,
--list of desired output columns, in desired order
--note that the final output will be the intersection of all enabled features and all 
--columns in the list. therefore, only columns associated with enabled features will 
--actually appear in the output. likewise, removing columns from this list may effectively
--disable features, even if they are turned on
--
--each element in this list must be one of the valid output column names. names must be
--delimited by square brackets. white space, formatting, and additional characters are
--allowed, as long as the list contains exact matches of delimited valid column names.
@output_column_list varchar(8000) = '[dd%][session_id][sql_text][sql_command][login_name][wait_info][tasks][tran_log%][cpu%][temp%][block%][reads%][writes%][context%][physical%][query_plan][locks][%]',
--column(s) by which to sort output, optionally with sort directions. 
--valid column choices:
--session_id, physical_io, reads, physical_reads, writes, tempdb_allocations,
--tempdb_current, cpu, context_switches, used_memory, physical_io_delta, 
--reads_delta, physical_reads_delta, writes_delta, tempdb_allocations_delta, 
--tempdb_current_delta, cpu_delta, context_switches_delta, used_memory_delta, 
--tasks, tran_start_time, open_tran_count, blocking_session_id, blocked_session_count,
--percent_complete, host_name, login_name, database_name, start_time, login_time
--
--note that column names in the list must be bracket-delimited. commas and/or white
--space are not required. 
@sort_order varchar(500) = '[start_time] asc',
--formats some of the output columns in a more "human readable" form
--0 disables outfput format
--1 formats the output for variable-width fonts
--2 formats the output for fixed-width fonts
@format_output tinyint = 1,
--if set to a non-blank value, the script will attempt to insert into the specified 
--destination table. please note that the script will not verify that the table exists, 
--or that it has the correct schema, before doing the insert.
--table can be specified in one, two, or three-part format
@destination_table varchar(4000) = '',
--if set to 1, no data collection will happen and no result set will be returned; instead,
--a create table statement will be returned via the @schema parameter, which will match 
--the schema of the result set that would be returned by using the same collection of the
--rest of the parameters. the create table statement will have a placeholder token of 
--<table_name> in place of an actual table name.
@return_schema bit = 0,
@schema varchar(max) = null output,
--help! what do i do?
@help bit = 0
--~
)
/*
output columns
--------------
formatted/non:    [session_id] [smallint] not null
session id (a.k.a. spid)
formatted:        [dd hh:mm:ss.mss] [varchar](15) null
non-formatted:    <not returned>
for an active request, time the query has been running
for a sleeping session, time since the last batch completed
formatted:        [dd hh:mm:ss.mss (avg)] [varchar](15) null
non-formatted:    [avg_elapsed_time] [int] null
(requires @get_avg_time option)
how much time has the active portion of the query taken in the past, on average?
formatted:        [physical_io] [varchar](30) null
non-formatted:    [physical_io] [bigint] null
shows the number of physical i/os, for active requests
formatted:        [reads] [varchar](30) null
non-formatted:    [reads] [bigint] null
for an active request, number of reads done for the current query
for a sleeping session, total number of reads done over the lifetime of the session
formatted:        [physical_reads] [varchar](30) null
non-formatted:    [physical_reads] [bigint] null
for an active request, number of physical reads done for the current query
for a sleeping session, total number of physical reads done over the lifetime of the session
formatted:        [writes] [varchar](30) null
non-formatted:    [writes] [bigint] null
for an active request, number of writes done for the current query
for a sleeping session, total number of writes done over the lifetime of the session
formatted:        [tempdb_allocations] [varchar](30) null
non-formatted:    [tempdb_allocations] [bigint] null
for an active request, number of tempdb writes done for the current query
for a sleeping session, total number of tempdb writes done over the lifetime of the session
formatted:        [tempdb_current] [varchar](30) null
non-formatted:    [tempdb_current] [bigint] null
for an active request, number of tempdb pages currently allocated for the query
for a sleeping session, number of tempdb pages currently allocated for the session
formatted:        [cpu] [varchar](30) null
non-formatted:    [cpu] [int] null
for an active request, total cpu time consumed by the current query
for a sleeping session, total cpu time consumed over the lifetime of the session
formatted:        [context_switches] [varchar](30) null
non-formatted:    [context_switches] [bigint] null
shows the number of context switches, for active requests
formatted:        [used_memory] [varchar](30) not null
non-formatted:    [used_memory] [bigint] not null
for an active request, total memory consumption for the current query
for a sleeping session, total current memory consumption
formatted:        [physical_io_delta] [varchar](30) null
non-formatted:    [physical_io_delta] [bigint] null
(requires @delta_interval option)
difference between the number of physical i/os reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [reads_delta] [varchar](30) null
non-formatted:    [reads_delta] [bigint] null
(requires @delta_interval option)
difference between the number of reads reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [physical_reads_delta] [varchar](30) null
non-formatted:    [physical_reads_delta] [bigint] null
(requires @delta_interval option)
difference between the number of physical reads reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [writes_delta] [varchar](30) null
non-formatted:    [writes_delta] [bigint] null
(requires @delta_interval option)
difference between the number of writes reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [tempdb_allocations_delta] [varchar](30) null
non-formatted:    [tempdb_allocations_delta] [bigint] null
(requires @delta_interval option)
difference between the number of tempdb writes reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [tempdb_current_delta] [varchar](30) null
non-formatted:    [tempdb_current_delta] [bigint] null
(requires @delta_interval option)
difference between the number of allocated tempdb pages reported on the first and second 
collections. if the request started after the first collection, the value will be null
formatted:        [cpu_delta] [varchar](30) null
non-formatted:    [cpu_delta] [int] null
(requires @delta_interval option)
difference between the cpu time reported on the first and second collections. 
if the request started after the first collection, the value will be null
formatted:        [context_switches_delta] [varchar](30) null
non-formatted:    [context_switches_delta] [bigint] null
(requires @delta_interval option)
difference between the context switches count reported on the first and second collections
if the request started after the first collection, the value will be null
formatted:        [used_memory_delta] [varchar](30) null
non-formatted:    [used_memory_delta] [bigint] null
difference between the memory usage reported on the first and second collections
if the request started after the first collection, the value will be null
formatted:        [tasks] [varchar](30) null
non-formatted:    [tasks] [smallint] null
number of worker tasks currently allocated, for active requests
formatted/non:    [status] [varchar](30) not null
activity status for the session (running, sleeping, etc)
formatted/non:    [wait_info] [nvarchar](4000) null
aggregates wait information, in the following format:
(ax: bms/cms/dms)e
a is the number of waiting tasks currently waiting on resource type e. b/c/d are wait
times, in milliseconds. if only one thread is waiting, its wait time will be shown as b.
if two tasks are waiting, each of their wait times will be shown (b/c). if three or more 
tasks are waiting, the minimum, average, and maximum wait times will be shown (b/c/d).
if wait type e is a page latch wait and the page is of a "special" type (e.g. pfs, gam, sgam), 
the page type will be identified.
if wait type e is cxpacket, the nodeid from the query plan will be identified
formatted/non:    [locks] [xml] null
(requires @get_locks option)
aggregates lock information, in xml format.
the lock xml includes the lock mode, locked object, and aggregates the number of requests. 
attempts are made to identify locked objects by name
formatted/non:    [tran_start_time] [datetime] null
(requires @get_transaction_info option)
date and time that the first transaction opened by a session caused a transaction log 
write to occur.
formatted/non:    [tran_log_writes] [nvarchar](4000) null
(requires @get_transaction_info option)
aggregates transaction log write information, in the following format:
a:wb (c kb)
a is a database that has been touched by an active transaction
b is the number of log writes that have been made in the database as a result of the transaction
c is the number of log kilobytes consumed by the log records
formatted:        [open_tran_count] [varchar](30) null
non-formatted:    [open_tran_count] [smallint] null
shows the number of open transactions the session has open
formatted:        [sql_command] [xml] null
non-formatted:    [sql_command] [nvarchar](max) null
(requires @get_outer_command option)
shows the "outer" sql command, i.e. the text of the batch or rpc sent to the server, 
if available
formatted:        [sql_text] [xml] null
non-formatted:    [sql_text] [nvarchar](max) null
shows the sql text for active requests or the last statement executed
for sleeping sessions, if available in either case.
if @get_full_inner_text option is set, shows the full text of the batch.
otherwise, shows only the active statement within the batch.
if the query text is locked, a special timeout message will be sent, in the following format:
<timeout_exceeded />
if an error occurs, an error message will be sent, in the following format:
<error message="message" />
formatted/non:    [query_plan] [xml] null
(requires @get_plans option)
shows the query plan for the request, if available.
if the plan is locked, a special timeout message will be sent, in the following format:
<timeout_exceeded />
if an error occurs, an error message will be sent, in the following format:
<error message="message" />
formatted/non:    [blocking_session_id] [smallint] null
when applicable, shows the blocking spid
formatted:        [blocked_session_count] [varchar](30) null
non-formatted:    [blocked_session_count] [smallint] null
(requires @find_block_leaders option)
the total number of spids blocked by this session,
all the way down the blocking chain.
formatted:        [percent_complete] [varchar](30) null
non-formatted:    [percent_complete] [real] null
when applicable, shows the percent complete (e.g. for backups, restores, and some rollbacks)
formatted/non:    [host_name] [sysname] not null
shows the host name for the connection
formatted/non:    [login_name] [sysname] not null
shows the login name for the connection
formatted/non:    [database_name] [sysname] null
shows the connected database
formatted/non:    [program_name] [sysname] null
shows the reported program/application name
formatted/non:    [additional_info] [xml] null
(requires @get_additional_info option)
returns additional non-performance-related session/request information
if the script finds a sql agent job running, the name of the job and job step will be reported
if @get_task_info = 2 and the script finds a lock wait, the locked object will be reported
formatted/non:    [start_time] [datetime] not null
for active requests, shows the time the request started
for sleeping sessions, shows the time the last batch completed
formatted/non:    [login_time] [datetime] not null
shows the time that the session connected
formatted/non:    [request_id] [int] null
for active requests, shows the request_id
should be 0 unless mars is being used
formatted/non:    [collection_time] [datetime] not null
time that this script's final select ran
*/
as
begin;
set nocount on; 
set transaction isolation level read uncommitted;
set quoted_identifier on;
set ansi_padding on;
set concat_null_yields_null on;
set ansi_warnings on;
set numeric_roundabort off;
set arithabort on;
if
@filter is null
or @filter_type is null
or @not_filter is null
or @not_filter_type is null
or @show_own_spid is null
or @show_system_spids is null
or @show_sleeping_spids is null
or @get_full_inner_text is null
or @get_plans is null
or @get_outer_command is null
or @get_transaction_info is null
or @get_task_info is null
or @get_locks is null
or @get_avg_time is null
or @get_additional_info is null
or @find_block_leaders is null
or @delta_interval is null
or @format_output is null
or @output_column_list is null
or @sort_order is null
or @return_schema is null
or @destination_table is null
or @help is null
begin;
raiserror('input parameters cannot be null', 16, 1);
return;
end;
if @filter_type not in ('session', 'program', 'database', 'login', 'host')
begin;
raiserror('valid filter types are: session, program, database, login, host', 16, 1);
return;
end;
if @filter_type = 'session' and @filter like '%[^0123456789]%'
begin;
raiserror('session filters must be valid integers', 16, 1);
return;
end;
if @not_filter_type not in ('session', 'program', 'database', 'login', 'host')
begin;
raiserror('valid filter types are: session, program, database, login, host', 16, 1);
return;
end;
if @not_filter_type = 'session' and @not_filter like '%[^0123456789]%'
begin;
raiserror('session filters must be valid integers', 16, 1);
return;
end;
if @show_sleeping_spids not in (0, 1, 2)
begin;
raiserror('valid values for @show_sleeping_spids are: 0, 1, or 2', 16, 1);
return;
end;
if @get_plans not in (0, 1, 2)
begin;
raiserror('valid values for @get_plans are: 0, 1, or 2', 16, 1);
return;
end;
if @get_task_info not in (0, 1, 2)
begin;
raiserror('valid values for @get_task_info are: 0, 1, or 2', 16, 1);
return;
end;
if @format_output not in (0, 1, 2)
begin;
raiserror('valid values for @format_output are: 0, 1, or 2', 16, 1);
return;
end;
if @help = 1
begin;
declare 
@header varchar(max),
@params varchar(max),
@outputs varchar(max);
select 
@header =
replace
(
replace
(
convert
(
varchar(max),
substring
(
t.text, 
charindex('/' + replicate('*', 93), t.text) + 94,
charindex(replicate('*', 93) + '/', t.text) - (charindex('/' + replicate('*', 93), t.text) + 94)
)
),
char(13)+char(10),
char(13)
),
'    ',
''
),
@params =
char(13) +
replace
(
replace
(
convert
(
varchar(max),
substring
(
t.text, 
charindex('--~', t.text) + 5, 
charindex('--~', t.text, charindex('--~', t.text) + 5) - (charindex('--~', t.text) + 5)
)
),
char(13)+char(10),
char(13)
),
'    ',
''
),
@outputs = 
char(13) +
replace
(
replace
(
replace
(
convert
(
varchar(max),
substring
(
t.text, 
charindex('output columns'+char(13)+char(10)+'--------------', t.text) + 32,
charindex('*/', t.text, charindex('output columns'+char(13)+char(10)+'--------------', t.text) + 32) - (charindex('output columns'+char(13)+char(10)+'--------------', t.text) + 32)
)
),
char(9),
char(255)
),
char(13)+char(10),
char(13)
),
'    ',
''
) +
char(13)
from sys.dm_exec_requests as r
cross apply sys.dm_exec_sql_text(r.sql_handle) as t
where
r.session_id = @@spid;
with
a0 as
(select 1 as n union all select 1),
a1 as
(select 1 as n from a0 as a, a0 as b),
a2 as
(select 1 as n from a1 as a, a1 as b),
a3 as
(select 1 as n from a2 as a, a2 as b),
a4 as
(select 1 as n from a3 as a, a3 as b),
numbers as
(
select top(len(@header) - 1)
row_number() over
(
order by (select null)
) as number
from a4
order by
number
)
select
rtrim(ltrim(
substring
(
@header,
number + 1,
charindex(char(13), @header, number + 1) - number - 1
)
)) as [------header---------------------------------------------------------------------------------------------------------------]
from numbers
where
substring(@header, number, 1) = char(13);
with
a0 as
(select 1 as n union all select 1),
a1 as
(select 1 as n from a0 as a, a0 as b),
a2 as
(select 1 as n from a1 as a, a1 as b),
a3 as
(select 1 as n from a2 as a, a2 as b),
a4 as
(select 1 as n from a3 as a, a3 as b),
numbers as
(
select top(len(@params) - 1)
row_number() over
(
order by (select null)
) as number
from a4
order by
number
),
tokens as
(
select 
rtrim(ltrim(
substring
(
@params,
number + 1,
charindex(char(13), @params, number + 1) - number - 1
)
)) as token,
number,
case
when substring(@params, number + 1, 1) = char(13) then number
else coalesce(nullif(charindex(',' + char(13) + char(13), @params, number), 0), len(@params)) 
end as param_group,
row_number() over
(
partition by
charindex(',' + char(13) + char(13), @params, number),
substring(@params, number+1, 1)
order by 
number
) as group_order
from numbers
where
substring(@params, number, 1) = char(13)
),
parsed_tokens as
(
select
min
(
case
when token like '@%' then token
else null
end
) as parameter,
min
(
case
when token like '--%' then right(token, len(token) - 2)
else null
end
) as description,
param_group,
group_order
from tokens
where
not 
(
token = '' 
and group_order > 1
)
group by
param_group,
group_order
)
select
case
when description is null and parameter is null then '-------------------------------------------------------------------------'
when param_group = max(param_group) over() then parameter
else coalesce(left(parameter, len(parameter) - 1), '')
end as [------parameter----------------------------------------------------------],
case
when description is null and parameter is null then '----------------------------------------------------------------------------------------------------------------------'
else coalesce(description, '')
end as [------description-----------------------------------------------------------------------------------------------------]
from parsed_tokens
order by
param_group, 
group_order;
with
a0 as
(select 1 as n union all select 1),
a1 as
(select 1 as n from a0 as a, a0 as b),
a2 as
(select 1 as n from a1 as a, a1 as b),
a3 as
(select 1 as n from a2 as a, a2 as b),
a4 as
(select 1 as n from a3 as a, a3 as b),
numbers as
(
select top(len(@outputs) - 1)
row_number() over
(
order by (select null)
) as number
from a4
order by
number
),
tokens as
(
select 
rtrim(ltrim(
substring
(
@outputs,
number + 1,
case
when 
coalesce(nullif(charindex(char(13) + 'formatted', @outputs, number + 1), 0), len(@outputs)) < 
coalesce(nullif(charindex(char(13) + char(255) collate latin1_general_bin2, @outputs, number + 1), 0), len(@outputs))
then coalesce(nullif(charindex(char(13) + 'formatted', @outputs, number + 1), 0), len(@outputs)) - number - 1
else
coalesce(nullif(charindex(char(13) + char(255) collate latin1_general_bin2, @outputs, number + 1), 0), len(@outputs)) - number - 1
end
)
)) as token,
number,
coalesce(nullif(charindex(char(13) + 'formatted', @outputs, number + 1), 0), len(@outputs)) as output_group,
row_number() over
(
partition by 
coalesce(nullif(charindex(char(13) + 'formatted', @outputs, number + 1), 0), len(@outputs))
order by
number
) as output_group_order
from numbers
where
substring(@outputs, number, 10) = char(13) + 'formatted'
or substring(@outputs, number, 2) = char(13) + char(255) collate latin1_general_bin2
),
output_tokens as
(
select 
*,
case output_group_order
when 2 then max(case output_group_order when 1 then token else null end) over (partition by output_group)
else ''
end collate latin1_general_bin2 as column_info
from tokens
)
select
case output_group_order
when 1 then '-----------------------------------'
when 2 then 
case
when charindex('formatted/non:', column_info) = 1 then
substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info)+1, charindex(']', column_info, charindex(char(255) collate latin1_general_bin2, column_info)+2) - charindex(char(255) collate latin1_general_bin2, column_info))
else
substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info)+2, charindex(']', column_info, charindex(char(255) collate latin1_general_bin2, column_info)+2) - charindex(char(255) collate latin1_general_bin2, column_info)-1)
end
else ''
end as formatted_column_name,
case output_group_order
when 1 then '-----------------------------------'
when 2 then 
case
when charindex('formatted/non:', column_info) = 1 then
substring(column_info, charindex(']', column_info)+2, len(column_info))
else
substring(column_info, charindex(']', column_info)+2, charindex('non-formatted:', column_info, charindex(']', column_info)+2) - charindex(']', column_info)-3)
end
else ''
end as formatted_column_type,
case output_group_order
when 1 then '---------------------------------------'
when 2 then 
case
when charindex('formatted/non:', column_info) = 1 then ''
else
case
when substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1, 1) = '<' then
substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1, charindex('>', column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1) - charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info)))
else
substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1, charindex(']', column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1) - charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info)))
end
end
else ''
end as unformatted_column_name,
case output_group_order
when 1 then '---------------------------------------'
when 2 then 
case
when charindex('formatted/non:', column_info) = 1 then ''
else
case
when substring(column_info, charindex(char(255) collate latin1_general_bin2, column_info, charindex('non-formatted:', column_info))+1, 1) = '<' then ''
else
substring(column_info, charindex(']', column_info, charindex('non-formatted:', column_info))+2, charindex('non-formatted:', column_info, charindex(']', column_info)+2) - charindex(']', column_info)-3)
end
end
else ''
end as unformatted_column_type,
case output_group_order
when 1 then '----------------------------------------------------------------------------------------------------------------------'
else replace(token, char(255) collate latin1_general_bin2, '')
end as [------description-----------------------------------------------------------------------------------------------------]
from output_tokens
where
not 
(
output_group_order = 1 
and output_group = len(@outputs)
)
order by
output_group,
case output_group_order
when 1 then 99
else output_group_order
end;
return;
end;
with
a0 as
(select 1 as n union all select 1),
a1 as
(select 1 as n from a0 as a, a0 as b),
a2 as
(select 1 as n from a1 as a, a1 as b),
a3 as
(select 1 as n from a2 as a, a2 as b),
a4 as
(select 1 as n from a3 as a, a3 as b),
numbers as
(
select top(len(@output_column_list))
row_number() over
(
order by (select null)
) as number
from a4
order by
number
),
tokens as
(
select 
'|[' +
substring
(
@output_column_list,
number + 1,
charindex(']', @output_column_list, number) - number - 1
) + '|]' as token,
number
from numbers
where
substring(@output_column_list, number, 1) = '['
),
ordered_columns as
(
select
x.column_name,
row_number() over
(
partition by
x.column_name
order by
tokens.number,
x.default_order
) as r,
row_number() over
(
order by
tokens.number,
x.default_order
) as s
from tokens
join
(
select '[session_id]' as column_name, 1 as default_order
union all
select '[dd hh:mm:ss.mss]', 2
where
@format_output in (1, 2)
union all
select '[dd hh:mm:ss.mss (avg)]', 3
where
@format_output in (1, 2)
and @get_avg_time = 1
union all
select '[avg_elapsed_time]', 4
where
@format_output = 0
and @get_avg_time = 1
union all
select '[physical_io]', 5
where
@get_task_info = 2
union all
select '[reads]', 6
union all
select '[physical_reads]', 7
union all
select '[writes]', 8
union all
select '[tempdb_allocations]', 9
union all
select '[tempdb_current]', 10
union all
select '[cpu]', 11
union all
select '[context_switches]', 12
where
@get_task_info = 2
union all
select '[used_memory]', 13
union all
select '[physical_io_delta]', 14
where
@delta_interval > 0    
and @get_task_info = 2
union all
select '[reads_delta]', 15
where
@delta_interval > 0
union all
select '[physical_reads_delta]', 16
where
@delta_interval > 0
union all
select '[writes_delta]', 17
where
@delta_interval > 0
union all
select '[tempdb_allocations_delta]', 18
where
@delta_interval > 0
union all
select '[tempdb_current_delta]', 19
where
@delta_interval > 0
union all
select '[cpu_delta]', 20
where
@delta_interval > 0
union all
select '[context_switches_delta]', 21
where
@delta_interval > 0
and @get_task_info = 2
union all
select '[used_memory_delta]', 22
where
@delta_interval > 0
union all
select '[tasks]', 23
where
@get_task_info = 2
union all
select '[status]', 24
union all
select '[wait_info]', 25
where
@get_task_info > 0
or @find_block_leaders = 1
union all
select '[locks]', 26
where
@get_locks = 1
union all
select '[tran_start_time]', 27
where
@get_transaction_info = 1
union all
select '[tran_log_writes]', 28
where
@get_transaction_info = 1
union all
select '[open_tran_count]', 29
union all
select '[sql_command]', 30
where
@get_outer_command = 1
union all
select '[sql_text]', 31
union all
select '[query_plan]', 32
where
@get_plans >= 1
union all
select '[blocking_session_id]', 33
where
@get_task_info > 0
or @find_block_leaders = 1
union all
select '[blocked_session_count]', 34
where
@find_block_leaders = 1
union all
select '[percent_complete]', 35
union all
select '[host_name]', 36
union all
select '[login_name]', 37
union all
select '[database_name]', 38
union all
select '[program_name]', 39
union all
select '[additional_info]', 40
where
@get_additional_info = 1
union all
select '[start_time]', 41
union all
select '[login_time]', 42
union all
select '[request_id]', 43
union all
select '[collection_time]', 44
) as x on 
x.column_name like token escape '|'
)
select
@output_column_list =
stuff
(
(
select
',' + column_name as [text()]
from ordered_columns
where
r = 1
order by
s
for xml
path('')
),
1,
1,
''
);
if coalesce(rtrim(@output_column_list), '') = ''
begin;
raiserror('no valid column matches found in @output_column_list or no columns remain due to selected options.', 16, 1);
return;
end;
if @destination_table <> ''
begin;
set @destination_table = 
--database
coalesce(quotename(parsename(@destination_table, 3)) + '.', '') +
--schema
coalesce(quotename(parsename(@destination_table, 2)) + '.', '') +
--table
coalesce(quotename(parsename(@destination_table, 1)), '');
if coalesce(rtrim(@destination_table), '') = ''
begin;
raiserror('destination table not properly formatted.', 16, 1);
return;
end;
end;
with
a0 as
(select 1 as n union all select 1),
a1 as
(select 1 as n from a0 as a, a0 as b),
a2 as
(select 1 as n from a1 as a, a1 as b),
a3 as
(select 1 as n from a2 as a, a2 as b),
a4 as
(select 1 as n from a3 as a, a3 as b),
numbers as
(
select top(len(@sort_order))
row_number() over
(
order by (select null)
) as number
from a4
order by
number
),
tokens as
(
select 
'|[' +
substring
(
@sort_order,
number + 1,
charindex(']', @sort_order, number) - number - 1
) + '|]' as token,
substring
(
@sort_order,
charindex(']', @sort_order, number) + 1,
coalesce(nullif(charindex('[', @sort_order, charindex(']', @sort_order, number)), 0), len(@sort_order)) - charindex(']', @sort_order, number)
) as next_chunk,
number
from numbers
where
substring(@sort_order, number, 1) = '['
),
ordered_columns as
(
select
x.column_name +
case
when tokens.next_chunk like '%asc%' then ' asc'
when tokens.next_chunk like '%desc%' then ' desc'
else ''
end as column_name,
row_number() over
(
partition by
x.column_name
order by
tokens.number
) as r,
tokens.number
from tokens
join
(
select '[session_id]' as column_name
union all
select '[physical_io]'
union all
select '[reads]'
union all
select '[physical_reads]'
union all
select '[writes]'
union all
select '[tempdb_allocations]'
union all
select '[tempdb_current]'
union all
select '[cpu]'
union all
select '[context_switches]'
union all
select '[used_memory]'
union all
select '[physical_io_delta]'
union all
select '[reads_delta]'
union all
select '[physical_reads_delta]'
union all
select '[writes_delta]'
union all
select '[tempdb_allocations_delta]'
union all
select '[tempdb_current_delta]'
union all
select '[cpu_delta]'
union all
select '[context_switches_delta]'
union all
select '[used_memory_delta]'
union all
select '[tasks]'
union all
select '[tran_start_time]'
union all
select '[open_tran_count]'
union all
select '[blocking_session_id]'
union all
select '[blocked_session_count]'
union all
select '[percent_complete]'
union all
select '[host_name]'
union all
select '[login_name]'
union all
select '[database_name]'
union all
select '[start_time]'
union all
select '[login_time]'
) as x on 
x.column_name like token escape '|'
)
select
@sort_order = coalesce(z.sort_order, '')
from
(
select
stuff
(
(
select
',' + column_name as [text()]
from ordered_columns
where
r = 1
order by
number
for xml
path('')
),
1,
1,
''
) as sort_order
) as z;
create table #sessions
(
recursion smallint not null,
session_id smallint not null,
request_id int not null,
session_number int not null,
elapsed_time int not null,
avg_elapsed_time int null,
physical_io bigint null,
reads bigint null,
physical_reads bigint null,
writes bigint null,
tempdb_allocations bigint null,
tempdb_current bigint null,
cpu int null,
thread_cpu_snapshot bigint null,
context_switches bigint null,
used_memory bigint not null, 
tasks smallint null,
status varchar(30) not null,
wait_info nvarchar(4000) null,
locks xml null,
transaction_id bigint null,
tran_start_time datetime null,
tran_log_writes nvarchar(4000) null,
open_tran_count smallint null,
sql_command xml null,
sql_handle varbinary(64) null,
statement_start_offset int null,
statement_end_offset int null,
sql_text xml null,
plan_handle varbinary(64) null,
query_plan xml null,
blocking_session_id smallint null,
blocked_session_count smallint null,
percent_complete real null,
host_name sysname null,
login_name sysname not null,
database_name sysname null,
program_name sysname null,
additional_info xml null,
start_time datetime not null,
login_time datetime null,
last_request_start_time datetime null,
primary key clustered (session_id, request_id, recursion) with (ignore_dup_key = on),
unique nonclustered (transaction_id, session_id, request_id, recursion) with (ignore_dup_key = on)
);
if @return_schema = 0
begin;
--disable unnecessary autostats on the table
create statistics s_session_id on #sessions (session_id)
with sample 0 rows, norecompute;
create statistics s_request_id on #sessions (request_id)
with sample 0 rows, norecompute;
create statistics s_transaction_id on #sessions (transaction_id)
with sample 0 rows, norecompute;
create statistics s_session_number on #sessions (session_number)
with sample 0 rows, norecompute;
create statistics s_status on #sessions (status)
with sample 0 rows, norecompute;
create statistics s_start_time on #sessions (start_time)
with sample 0 rows, norecompute;
create statistics s_last_request_start_time on #sessions (last_request_start_time)
with sample 0 rows, norecompute;
create statistics s_recursion on #sessions (recursion)
with sample 0 rows, norecompute;
declare @recursion smallint;
set @recursion = 
case @delta_interval
when 0 then 1
else -1
end;
declare @first_collection_ms_ticks bigint;
declare @last_collection_start datetime;
--used for the delta pull
redo:;
if 
@get_locks = 1 
and @recursion = 1
and @output_column_list like '%|[locks|]%' escape '|'
begin;
select
y.resource_type,
y.database_name,
y.object_id,
y.file_id,
y.page_type,
y.hobt_id,
y.allocation_unit_id,
y.index_id,
y.schema_id,
y.principal_id,
y.request_mode,
y.request_status,
y.session_id,
y.resource_description,
y.request_count,
s.request_id,
s.start_time,
convert(sysname, null) as object_name,
convert(sysname, null) as index_name,
convert(sysname, null) as schema_name,
convert(sysname, null) as principal_name,
convert(nvarchar(2048), null) as query_error
into #locks
from
(
select
sp.spid as session_id,
case sp.status
when 'sleeping' then convert(int, 0)
else sp.request_id
end as request_id,
case sp.status
when 'sleeping' then sp.last_batch
else coalesce(req.start_time, sp.last_batch)
end as start_time,
sp.dbid
from sys.sysprocesses as sp
outer apply
(
select top(1)
case
when 
(
sp.hostprocess > ''
or r.total_elapsed_time < 0
) then
r.start_time
else
dateadd
(
ms, 
1000 * (datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())) / 500) - datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())), 
dateadd(second, -(r.total_elapsed_time / 1000), getdate())
)
end as start_time
from sys.dm_exec_requests as r
where
r.session_id = sp.spid
and r.request_id = sp.request_id
) as req
where
--process inclusive filter
1 =
case
when @filter <> '' then
case @filter_type
when 'session' then
case
when
convert(smallint, @filter) = 0
or sp.spid = convert(smallint, @filter)
then 1
else 0
end
when 'program' then
case
when sp.program_name like @filter then 1
else 0
end
when 'login' then
case
when sp.loginame like @filter then 1
else 0
end
when 'host' then
case
when sp.hostname like @filter then 1
else 0
end
when 'database' then
case
when db_name(sp.dbid) like @filter then 1
else 0
end
else 0
end
else 1
end
--process exclusive filter
and 0 =
case
when @not_filter <> '' then
case @not_filter_type
when 'session' then
case
when sp.spid = convert(smallint, @not_filter) then 1
else 0
end
when 'program' then
case
when sp.program_name like @not_filter then 1
else 0
end
when 'login' then
case
when sp.loginame like @not_filter then 1
else 0
end
when 'host' then
case
when sp.hostname like @not_filter then 1
else 0
end
when 'database' then
case
when db_name(sp.dbid) like @not_filter then 1
else 0
end
else 0
end
else 0
end
and 
(
@show_own_spid = 1
or sp.spid <> @@spid
)
and 
(
@show_system_spids = 1
or sp.hostprocess > ''
)
and sp.ecid = 0
) as s
inner hash join
(
select
x.resource_type,
x.database_name,
x.object_id,
x.file_id,
case
when x.page_no = 1 or x.page_no % 8088 = 0 then 'pfs'
when x.page_no = 2 or x.page_no % 511232 = 0 then 'gam'
when x.page_no = 3 or (x.page_no - 1) % 511232 = 0 then 'sgam'
when x.page_no = 6 or (x.page_no - 6) % 511232 = 0 then 'dcm'
when x.page_no = 7 or (x.page_no - 7) % 511232 = 0 then 'bcm'
when x.page_no is not null then '*'
else null
end as page_type,
x.hobt_id,
x.allocation_unit_id,
x.index_id,
x.schema_id,
x.principal_id,
x.request_mode,
x.request_status,
x.session_id,
x.request_id,
case
when coalesce(x.object_id, x.file_id, x.hobt_id, x.allocation_unit_id, x.index_id, x.schema_id, x.principal_id) is null then nullif(resource_description, '')
else null
end as resource_description,
count(*) as request_count
from
(
select
tl.resource_type +
case
when tl.resource_subtype = '' then ''
else '.' + tl.resource_subtype
end as resource_type,
coalesce(db_name(tl.resource_database_id), n'(null)') as database_name,
convert
(
int,
case
when tl.resource_type = 'object' then tl.resource_associated_entity_id
when tl.resource_description like '%object_id = %' then
(
substring
(
tl.resource_description, 
(charindex('object_id = ', tl.resource_description) + 12), 
coalesce
(
nullif
(
charindex(',', tl.resource_description, charindex('object_id = ', tl.resource_description) + 12),
0
), 
datalength(tl.resource_description)+1
) - (charindex('object_id = ', tl.resource_description) + 12)
)
)
else null
end
) as object_id,
convert
(
int,
case 
when tl.resource_type = 'file' then convert(int, tl.resource_description)
when tl.resource_type in ('page', 'extent', 'rid') then left(tl.resource_description, charindex(':', tl.resource_description)-1)
else null
end
) as file_id,
convert
(
int,
case
when tl.resource_type in ('page', 'extent', 'rid') then 
substring
(
tl.resource_description, 
charindex(':', tl.resource_description) + 1, 
coalesce
(
nullif
(
charindex(':', tl.resource_description, charindex(':', tl.resource_description) + 1), 
0
), 
datalength(tl.resource_description)+1
) - (charindex(':', tl.resource_description) + 1)
)
else null
end
) as page_no,
case
when tl.resource_type in ('page', 'key', 'rid', 'hobt') then tl.resource_associated_entity_id
else null
end as hobt_id,
case
when tl.resource_type = 'allocation_unit' then tl.resource_associated_entity_id
else null
end as allocation_unit_id,
convert
(
int,
case
when
/*todo: deal with server principals*/ 
tl.resource_subtype <> 'server_principal' 
and tl.resource_description like '%index_id or stats_id = %' then
(
substring
(
tl.resource_description, 
(charindex('index_id or stats_id = ', tl.resource_description) + 23), 
coalesce
(
nullif
(
charindex(',', tl.resource_description, charindex('index_id or stats_id = ', tl.resource_description) + 23), 
0
), 
datalength(tl.resource_description)+1
) - (charindex('index_id or stats_id = ', tl.resource_description) + 23)
)
)
else null
end 
) as index_id,
convert
(
int,
case
when tl.resource_description like '%schema_id = %' then
(
substring
(
tl.resource_description, 
(charindex('schema_id = ', tl.resource_description) + 12), 
coalesce
(
nullif
(
charindex(',', tl.resource_description, charindex('schema_id = ', tl.resource_description) + 12), 
0
), 
datalength(tl.resource_description)+1
) - (charindex('schema_id = ', tl.resource_description) + 12)
)
)
else null
end 
) as schema_id,
convert
(
int,
case
when tl.resource_description like '%principal_id = %' then
(
substring
(
tl.resource_description, 
(charindex('principal_id = ', tl.resource_description) + 15), 
coalesce
(
nullif
(
charindex(',', tl.resource_description, charindex('principal_id = ', tl.resource_description) + 15), 
0
), 
datalength(tl.resource_description)+1
) - (charindex('principal_id = ', tl.resource_description) + 15)
)
)
else null
end
) as principal_id,
tl.request_mode,
tl.request_status,
tl.request_session_id as session_id,
tl.request_request_id as request_id,
/*todo: applocks, other resource_descriptions*/
rtrim(tl.resource_description) as resource_description,
tl.resource_associated_entity_id
/*********************************************/
from 
(
select 
request_session_id,
convert(varchar(120), resource_type) collate latin1_general_bin2 as resource_type,
convert(varchar(120), resource_subtype) collate latin1_general_bin2 as resource_subtype,
resource_database_id,
convert(varchar(512), resource_description) collate latin1_general_bin2 as resource_description,
resource_associated_entity_id,
convert(varchar(120), request_mode) collate latin1_general_bin2 as request_mode,
convert(varchar(120), request_status) collate latin1_general_bin2 as request_status,
request_request_id
from sys.dm_tran_locks
) as tl
) as x
group by
x.resource_type,
x.database_name,
x.object_id,
x.file_id,
case
when x.page_no = 1 or x.page_no % 8088 = 0 then 'pfs'
when x.page_no = 2 or x.page_no % 511232 = 0 then 'gam'
when x.page_no = 3 or (x.page_no - 1) % 511232 = 0 then 'sgam'
when x.page_no = 6 or (x.page_no - 6) % 511232 = 0 then 'dcm'
when x.page_no = 7 or (x.page_no - 7) % 511232 = 0 then 'bcm'
when x.page_no is not null then '*'
else null
end,
x.hobt_id,
x.allocation_unit_id,
x.index_id,
x.schema_id,
x.principal_id,
x.request_mode,
x.request_status,
x.session_id,
x.request_id,
case
when coalesce(x.object_id, x.file_id, x.hobt_id, x.allocation_unit_id, x.index_id, x.schema_id, x.principal_id) is null then nullif(resource_description, '')
else null
end
) as y on
y.session_id = s.session_id
and y.request_id = s.request_id
option (hash group);
--disable unnecessary autostats on the table
create statistics s_database_name on #locks (database_name)
with sample 0 rows, norecompute;
create statistics s_object_id on #locks (object_id)
with sample 0 rows, norecompute;
create statistics s_hobt_id on #locks (hobt_id)
with sample 0 rows, norecompute;
create statistics s_allocation_unit_id on #locks (allocation_unit_id)
with sample 0 rows, norecompute;
create statistics s_index_id on #locks (index_id)
with sample 0 rows, norecompute;
create statistics s_schema_id on #locks (schema_id)
with sample 0 rows, norecompute;
create statistics s_principal_id on #locks (principal_id)
with sample 0 rows, norecompute;
create statistics s_request_id on #locks (request_id)
with sample 0 rows, norecompute;
create statistics s_start_time on #locks (start_time)
with sample 0 rows, norecompute;
create statistics s_resource_type on #locks (resource_type)
with sample 0 rows, norecompute;
create statistics s_object_name on #locks (object_name)
with sample 0 rows, norecompute;
create statistics s_schema_name on #locks (schema_name)
with sample 0 rows, norecompute;
create statistics s_page_type on #locks (page_type)
with sample 0 rows, norecompute;
create statistics s_request_mode on #locks (request_mode)
with sample 0 rows, norecompute;
create statistics s_request_status on #locks (request_status)
with sample 0 rows, norecompute;
create statistics s_resource_description on #locks (resource_description)
with sample 0 rows, norecompute;
create statistics s_index_name on #locks (index_name)
with sample 0 rows, norecompute;
create statistics s_principal_name on #locks (principal_name)
with sample 0 rows, norecompute;
end;
declare 
@sql varchar(max), 
@sql_n nvarchar(max);
set @sql = 
convert(varchar(max), '') +
'declare @blocker bit;
set @blocker = 0;
declare @i int;
set @i = 2147483647;
declare @sessions table
(
session_id smallint not null,
request_id int not null,
login_time datetime,
last_request_end_time datetime,
status varchar(30),
statement_start_offset int,
statement_end_offset int,
sql_handle binary(20),
host_name nvarchar(128),
login_name nvarchar(128),
program_name nvarchar(128),
database_id smallint,
memory_usage int,
open_tran_count smallint, 
' +
case
when 
(
@get_task_info <> 0 
or @find_block_leaders = 1 
) then
'wait_type nvarchar(32),
wait_resource nvarchar(256),
wait_time bigint, 
'
else 
''
end +
'blocked smallint,
is_user_process bit,
cmd varchar(32),
primary key clustered (session_id, request_id) with (ignore_dup_key = on)
);
declare @blockers table
(
session_id int not null primary key with (ignore_dup_key = on)
);
blockers:;
insert @sessions
(
session_id,
request_id,
login_time,
last_request_end_time,
status,
statement_start_offset,
statement_end_offset,
sql_handle,
host_name,
login_name,
program_name,
database_id,
memory_usage,
open_tran_count, 
' +
case
when 
(
@get_task_info <> 0
or @find_block_leaders = 1 
) then
'wait_type,
wait_resource,
wait_time, 
'
else
''
end +
'blocked,
is_user_process,
cmd 
)
select top(@i)
spy.session_id,
spy.request_id,
spy.login_time,
spy.last_request_end_time,
spy.status,
spy.statement_start_offset,
spy.statement_end_offset,
spy.sql_handle,
spy.host_name,
spy.login_name,
spy.program_name,
spy.database_id,
spy.memory_usage,
spy.open_tran_count,
' +
case
when 
(
@get_task_info <> 0  
or @find_block_leaders = 1 
) then
'spy.wait_type,
case
when
spy.wait_type like n''page%latch_%''
or spy.wait_type = n''cxpacket''
or spy.wait_type like n''latch[_]%''
or spy.wait_type = n''oledb'' then
spy.wait_resource
else
null
end as wait_resource,
spy.wait_time, 
'
else
''
end +
'spy.blocked,
spy.is_user_process,
spy.cmd
from
(
select top(@i)
spx.*, 
' +
case
when 
(
@get_task_info <> 0 
or @find_block_leaders = 1 
) then
'row_number() over
(
partition by
spx.session_id,
spx.request_id
order by
case
when spx.wait_type like n''lck[_]%'' then 
1
else
99
end,
spx.wait_time desc,
spx.blocked desc
) as r 
'
else 
'1 as r 
'
end +
'from
(
select top(@i)
sp0.session_id,
sp0.request_id,
sp0.login_time,
sp0.last_request_end_time,
lower(sp0.status) as status,
case
when sp0.cmd = ''create index'' then
0
else
sp0.stmt_start
end as statement_start_offset,
case
when sp0.cmd = n''create index'' then
-1
else
coalesce(nullif(sp0.stmt_end, 0), -1)
end as statement_end_offset,
sp0.sql_handle,
sp0.host_name,
sp0.login_name,
sp0.program_name,
sp0.database_id,
sp0.memory_usage,
sp0.open_tran_count, 
' +
case
when 
(
@get_task_info <> 0 
or @find_block_leaders = 1 
) then
'case
when sp0.wait_time > 0 and sp0.wait_type <> n''cxpacket'' then
sp0.wait_type
else
null
end as wait_type,
case
when sp0.wait_time > 0 and sp0.wait_type <> n''cxpacket'' then 
sp0.wait_resource
else
null
end as wait_resource,
case
when sp0.wait_type <> n''cxpacket'' then
sp0.wait_time
else
0
end as wait_time, 
'
else
''
end +
'sp0.blocked,
sp0.is_user_process,
sp0.cmd
from
(
select top(@i)
sp1.session_id,
sp1.request_id,
sp1.login_time,
sp1.last_request_end_time,
sp1.status,
sp1.cmd,
sp1.stmt_start,
sp1.stmt_end,
max(nullif(sp1.sql_handle, 0x00)) over (partition by sp1.session_id, sp1.request_id) as sql_handle,
sp1.host_name,
max(sp1.login_name) over (partition by sp1.session_id, sp1.request_id) as login_name,
sp1.program_name,
sp1.database_id,
max(sp1.memory_usage)  over (partition by sp1.session_id, sp1.request_id) as memory_usage,
max(sp1.open_tran_count)  over (partition by sp1.session_id, sp1.request_id) as open_tran_count,
sp1.wait_type,
sp1.wait_resource,
sp1.wait_time,
sp1.blocked,
sp1.hostprocess,
sp1.is_user_process
from
(
select top(@i)
sp2.spid as session_id,
case sp2.status
when ''sleeping'' then
convert(int, 0)
else
sp2.request_id
end as request_id,
max(sp2.login_time) as login_time,
max(sp2.last_batch) as last_request_end_time,
max(convert(varchar(30), rtrim(sp2.status)) collate latin1_general_bin2) as status,
max(convert(varchar(32), rtrim(sp2.cmd)) collate latin1_general_bin2) as cmd,
max(sp2.stmt_start) as stmt_start,
max(sp2.stmt_end) as stmt_end,
max(sp2.sql_handle) as sql_handle,
max(convert(sysname, rtrim(sp2.hostname)) collate sql_latin1_general_cp1_ci_as) as host_name,
max(convert(sysname, rtrim(sp2.loginame)) collate sql_latin1_general_cp1_ci_as) as login_name,
max
(
case
when blk.queue_id is not null then
n''service broker
database_id: '' + convert(nvarchar, blk.database_id) +
n'' queue_id: '' + convert(nvarchar, blk.queue_id)
else
convert
(
sysname,
rtrim(sp2.program_name)
)
end collate sql_latin1_general_cp1_ci_as
) as program_name,
max(sp2.dbid) as database_id,
max(sp2.memusage) as memory_usage,
max(sp2.open_tran) as open_tran_count,
rtrim(sp2.lastwaittype) as wait_type,
rtrim(sp2.waitresource) as wait_resource,
max(sp2.waittime) as wait_time,
coalesce(nullif(sp2.blocked, sp2.spid), 0) as blocked,
max
(
case
when blk.session_id = sp2.spid then
''blocker''
else
rtrim(sp2.hostprocess)
end
) as hostprocess,
convert
(
bit,
max
(
case
when sp2.hostprocess > '''' then
1
else
0
end
)
) as is_user_process
from
(
select top(@i)
session_id,
convert(int, null) as queue_id,
convert(int, null) as database_id
from @blockers
union all
select top(@i)
convert(smallint, 0),
convert(int, null) as queue_id,
convert(int, null) as database_id
where
@blocker = 0
union all
select top(@i)
convert(smallint, spid),
queue_id,
database_id
from sys.dm_broker_activated_tasks
where
@blocker = 0
) as blk
inner join sys.sysprocesses as sp2 on
sp2.spid = blk.session_id
or
(
blk.session_id = 0
and @blocker = 0
)
' +
case 
when 
(
@get_task_info = 0 
and @find_block_leaders = 0
) then
'where
sp2.ecid = 0 
' 
else
''
end +
'group by
sp2.spid,
case sp2.status
when ''sleeping'' then
convert(int, 0)
else
sp2.request_id
end,
rtrim(sp2.lastwaittype),
rtrim(sp2.waitresource),
coalesce(nullif(sp2.blocked, sp2.spid), 0)
) as sp1
) as sp0
where
@blocker = 1
or
(1=1 
' +
--inclusive filter
case
when @filter <> '' then
case @filter_type
when 'session' then
case
when convert(smallint, @filter) <> 0 then
'and sp0.session_id = convert(smallint, @filter) 
'
else
''
end
when 'program' then
'and sp0.program_name like @filter 
'
when 'login' then
'and sp0.login_name like @filter 
'
when 'host' then
'and sp0.host_name like @filter 
'
when 'database' then
'and db_name(sp0.database_id) like @filter 
'
else
''
end
else
''
end +
--exclusive filter
case
when @not_filter <> '' then
case @not_filter_type
when 'session' then
case
when convert(smallint, @not_filter) <> 0 then
'and sp0.session_id <> convert(smallint, @not_filter) 
'
else
''
end
when 'program' then
'and sp0.program_name not like @not_filter 
'
when 'login' then
'and sp0.login_name not like @not_filter 
'
when 'host' then
'and sp0.host_name not like @not_filter 
'
when 'database' then
'and db_name(sp0.database_id) not like @not_filter 
'
else
''
end
else
''
end +
case @show_own_spid
when 1 then
''
else
'and sp0.session_id <> @@spid 
'
end +
case 
when @show_system_spids = 0 then
'and sp0.hostprocess > '''' 
' 
else
''
end +
case @show_sleeping_spids
when 0 then
'and sp0.status <> ''sleeping'' 
'
when 1 then
'and
(
sp0.status <> ''sleeping''
or sp0.open_tran_count > 0
)
'
else
''
end +
')
) as spx
) as spy
where
spy.r = 1; 
' + 
case @recursion
when 1 then 
'if @@rowcount > 0
begin;
insert @blockers
(
session_id
)
select top(@i)
blocked
from @sessions
where
nullif(blocked, 0) is not null
except
select top(@i)
session_id
from @sessions; 
' +
case
when
(
@get_task_info > 0
or @find_block_leaders = 1
) then
'if @@rowcount > 0
begin;
set @blocker = 1;
goto blockers;
end; 
'
else 
''
end +
'end; 
'
else 
''
end +
'select top(@i)
@recursion as recursion,
x.session_id,
x.request_id,
dense_rank() over
(
order by
x.session_id
) as session_number,
' +
case
when @output_column_list like '%|[dd hh:mm:ss.mss|]%' escape '|' then 
'x.elapsed_time '
else 
'0 '
end + 
'as elapsed_time, 
' +
case
when
(
@output_column_list like '%|[dd hh:mm:ss.mss (avg)|]%' escape '|' or 
@output_column_list like '%|[avg_elapsed_time|]%' escape '|'
)
and @recursion = 1
then 
'x.avg_elapsed_time / 1000 '
else 
'null '
end + 
'as avg_elapsed_time, 
' +
case
when 
@output_column_list like '%|[physical_io|]%' escape '|'
or @output_column_list like '%|[physical_io_delta|]%' escape '|'
then 
'x.physical_io '
else 
'null '
end + 
'as physical_io, 
' +
case
when 
@output_column_list like '%|[reads|]%' escape '|'
or @output_column_list like '%|[reads_delta|]%' escape '|'
then 
'x.reads '
else 
'0 '
end + 
'as reads, 
' +
case
when 
@output_column_list like '%|[physical_reads|]%' escape '|'
or @output_column_list like '%|[physical_reads_delta|]%' escape '|'
then 
'x.physical_reads '
else 
'0 '
end + 
'as physical_reads, 
' +
case
when 
@output_column_list like '%|[writes|]%' escape '|'
or @output_column_list like '%|[writes_delta|]%' escape '|'
then 
'x.writes '
else 
'0 '
end + 
'as writes, 
' +
case
when 
@output_column_list like '%|[tempdb_allocations|]%' escape '|'
or @output_column_list like '%|[tempdb_allocations_delta|]%' escape '|'
then 
'x.tempdb_allocations '
else 
'0 '
end + 
'as tempdb_allocations, 
' +
case
when 
@output_column_list like '%|[tempdb_current|]%' escape '|'
or @output_column_list like '%|[tempdb_current_delta|]%' escape '|'
then 
'x.tempdb_current '
else 
'0 '
end + 
'as tempdb_current, 
' +
case
when 
@output_column_list like '%|[cpu|]%' escape '|'
or @output_column_list like '%|[cpu_delta|]%' escape '|'
then
'x.cpu '
else
'0 '
end + 
'as cpu, 
' +
case
when 
@output_column_list like '%|[cpu_delta|]%' escape '|'
and @get_task_info = 2
then 
'x.thread_cpu_snapshot '
else 
'0 '
end + 
'as thread_cpu_snapshot, 
' +
case
when 
@output_column_list like '%|[context_switches|]%' escape '|'
or @output_column_list like '%|[context_switches_delta|]%' escape '|'
then 
'x.context_switches '
else 
'null '
end + 
'as context_switches, 
' +
case
when 
@output_column_list like '%|[used_memory|]%' escape '|'
or @output_column_list like '%|[used_memory_delta|]%' escape '|'
then 
'x.used_memory '
else 
'0 '
end + 
'as used_memory, 
' +
case
when 
@output_column_list like '%|[tasks|]%' escape '|'
and @recursion = 1
then 
'x.tasks '
else 
'null '
end + 
'as tasks, 
' +
case
when 
(
@output_column_list like '%|[status|]%' escape '|' 
or @output_column_list like '%|[sql_command|]%' escape '|'
)
and @recursion = 1
then 
'x.status '
else 
''''' '
end + 
'as status, 
' +
case
when 
@output_column_list like '%|[wait_info|]%' escape '|' 
and @recursion = 1
then 
case @get_task_info
when 2 then
'coalesce(x.task_wait_info, x.sys_wait_info) '
else
'x.sys_wait_info '
end
else 
'null '
end + 
'as wait_info, 
' +
case
when 
(
@output_column_list like '%|[tran_start_time|]%' escape '|' 
or @output_column_list like '%|[tran_log_writes|]%' escape '|' 
)
and @recursion = 1
then 
'x.transaction_id '
else 
'null '
end + 
'as transaction_id, 
' +
case
when 
@output_column_list like '%|[open_tran_count|]%' escape '|' 
and @recursion = 1
then 
'x.open_tran_count '
else 
'null '
end + 
'as open_tran_count, 
' +
case
when 
@output_column_list like '%|[sql_text|]%' escape '|' 
and @recursion = 1
then 
'x.sql_handle '
else 
'null '
end + 
'as sql_handle, 
' +
case
when 
(
@output_column_list like '%|[sql_text|]%' escape '|' 
or @output_column_list like '%|[query_plan|]%' escape '|' 
)
and @recursion = 1
then 
'x.statement_start_offset '
else 
'null '
end + 
'as statement_start_offset, 
' +
case
when 
(
@output_column_list like '%|[sql_text|]%' escape '|' 
or @output_column_list like '%|[query_plan|]%' escape '|' 
)
and @recursion = 1
then 
'x.statement_end_offset '
else 
'null '
end + 
'as statement_end_offset, 
' +
'null as sql_text, 
' +
case
when 
@output_column_list like '%|[query_plan|]%' escape '|' 
and @recursion = 1
then 
'x.plan_handle '
else 
'null '
end + 
'as plan_handle, 
' +
case
when 
@output_column_list like '%|[blocking_session_id|]%' escape '|' 
and @recursion = 1
then 
'nullif(x.blocking_session_id, 0) '
else 
'null '
end + 
'as blocking_session_id, 
' +
case
when 
@output_column_list like '%|[percent_complete|]%' escape '|'
and @recursion = 1
then 
'x.percent_complete '
else 
'null '
end + 
'as percent_complete, 
' +
case
when 
@output_column_list like '%|[host_name|]%' escape '|' 
and @recursion = 1
then 
'x.host_name '
else 
''''' '
end + 
'as host_name, 
' +
case
when 
@output_column_list like '%|[login_name|]%' escape '|' 
and @recursion = 1
then 
'x.login_name '
else 
''''' '
end + 
'as login_name, 
' +
case
when 
@output_column_list like '%|[database_name|]%' escape '|' 
and @recursion = 1
then 
'db_name(x.database_id) '
else 
'null '
end + 
'as database_name, 
' +
case
when 
@output_column_list like '%|[program_name|]%' escape '|' 
and @recursion = 1
then 
'x.program_name '
else 
''''' '
end + 
'as program_name, 
' +
case
when
@output_column_list like '%|[additional_info|]%' escape '|'
and @recursion = 1
then
'(
select top(@i)
x.text_size,
x.language,
x.date_format,
x.date_first,
case x.quoted_identifier
when 0 then ''off''
when 1 then ''on''
end as quoted_identifier,
case x.arithabort
when 0 then ''off''
when 1 then ''on''
end as arithabort,
case x.ansi_null_dflt_on
when 0 then ''off''
when 1 then ''on''
end as ansi_null_dflt_on,
case x.ansi_defaults
when 0 then ''off''
when 1 then ''on''
end as ansi_defaults,
case x.ansi_warnings
when 0 then ''off''
when 1 then ''on''
end as ansi_warnings,
case x.ansi_padding
when 0 then ''off''
when 1 then ''on''
end as ansi_padding,
case ansi_nulls
when 0 then ''off''
when 1 then ''on''
end as ansi_nulls,
case x.concat_null_yields_null
when 0 then ''off''
when 1 then ''on''
end as concat_null_yields_null,
case x.transaction_isolation_level
when 0 then ''unspecified''
when 1 then ''readuncomitted''
when 2 then ''readcommitted''
when 3 then ''repeatable''
when 4 then ''serializable''
when 5 then ''snapshot''
end as transaction_isolation_level,
x.lock_timeout,
x.deadlock_priority,
x.row_count,
x.command_type, 
master.dbo.fn_varbintohexstr(x.sql_handle) as sql_handle,
master.dbo.fn_varbintohexstr(x.plan_handle) as plan_handle,
' +
case
when @output_column_list like '%|[program_name|]%' escape '|' then
'(
select top(1)
convert(uniqueidentifier, convert(xml, '''').value(''xs:hexbinary( substring(sql:column("agent_info.job_id_string"), 0) )'', ''binary(16)'')) as job_id,
agent_info.step_id,
(
select top(1)
null
for xml
path(''job_name''),
type
),
(
select top(1)
null
for xml
path(''step_name''),
type
)
from
(
select top(1)
substring(x.program_name, charindex(''0x'', x.program_name) + 2, 32) as job_id_string,
substring(x.program_name, charindex('': step '', x.program_name) + 7, charindex('')'', x.program_name, charindex('': step '', x.program_name)) - (charindex('': step '', x.program_name) + 7)) as step_id
where
x.program_name like n''sqlagent - tsql jobstep (job 0x%''
) as agent_info
for xml
path(''agent_job_info''),
type
),
'
else ''
end +
case
when @get_task_info = 2 then
'convert(xml, x.block_info) as block_info, 
'
else
''
end +
'x.host_process_id 
for xml
path(''additional_info''),
type
) '
else
'null '
end + 
'as additional_info, 
x.start_time, 
' +
case
when
@output_column_list like '%|[login_time|]%' escape '|'
and @recursion = 1
then
'x.login_time '
else 
'null '
end + 
'as login_time, 
x.last_request_start_time
from
(
select top(@i)
y.*,
case
when datediff(hour, y.start_time, getdate()) > 576 then
datediff(second, getdate(), y.start_time)
else datediff(ms, y.start_time, getdate())
end as elapsed_time,
coalesce(tempdb_info.tempdb_allocations, 0) as tempdb_allocations,
coalesce
(
case
when tempdb_info.tempdb_current < 0 then 0
else tempdb_info.tempdb_current
end,
0
) as tempdb_current, 
' +
case
when 
(
@get_task_info <> 0
or @find_block_leaders = 1
) then
'n''('' + convert(nvarchar, y.wait_duration_ms) + n''ms)'' +
y.wait_type +
case
when y.wait_type like n''page%latch_%'' then
n'':'' +
coalesce(db_name(convert(int, left(y.resource_description, charindex(n'':'', y.resource_description) - 1))), n''(null)'') +
n'':'' +
substring(y.resource_description, charindex(n'':'', y.resource_description) + 1, len(y.resource_description) - charindex(n'':'', reverse(y.resource_description)) - charindex(n'':'', y.resource_description)) +
n''('' +
case
when
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) = 1 or
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) % 8088 = 0
then 
n''pfs''
when
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) = 2 or
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) % 511232 = 0
then 
n''gam''
when
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) = 3 or
(convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) - 1) % 511232 = 0
then
n''sgam''
when
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) = 6 or
(convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) - 6) % 511232 = 0 
then 
n''dcm''
when
convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) = 7 or
(convert(int, right(y.resource_description, charindex(n'':'', reverse(y.resource_description)) - 1)) - 7) % 511232 = 0 
then 
n''bcm''
else 
n''*''
end +
n'')''
when y.wait_type = n''cxpacket'' then
n'':'' + substring(y.resource_description, charindex(n''nodeid'', y.resource_description) + 7, 4)
when y.wait_type like n''latch[_]%'' then
n'' ['' + left(y.resource_description, coalesce(nullif(charindex(n'' '', y.resource_description), 0), len(y.resource_description) + 1) - 1) + n'']''
when
y.wait_type = n''oledb''
and y.resource_description like n''%(spid=%)'' then
n''['' + left(y.resource_description, charindex(n''(spid='', y.resource_description) - 2) +
n'':'' + substring(y.resource_description, charindex(n''(spid='', y.resource_description) + 6, charindex(n'')'', y.resource_description, (charindex(n''(spid='', y.resource_description) + 6)) - (charindex(n''(spid='', y.resource_description) + 6)) + '']''
else
n''''
end collate latin1_general_bin2 as sys_wait_info, 
'
else
''
end +
case
when @get_task_info = 2 then
'tasks.physical_io,
tasks.context_switches,
tasks.tasks,
tasks.block_info,
tasks.wait_info as task_wait_info,
tasks.thread_cpu_snapshot,
'
else
'' 
end +
case 
when not (@get_avg_time = 1 and @recursion = 1) then
'convert(int, null) '
else 
'qs.total_elapsed_time / qs.execution_count '
end + 
'as avg_elapsed_time 
from
(
select top(@i)
sp.session_id,
sp.request_id,
coalesce(r.logical_reads, s.logical_reads) as reads,
coalesce(r.reads, s.reads) as physical_reads,
coalesce(r.writes, s.writes) as writes,
coalesce(r.cpu_time, s.cpu_time) as cpu,
sp.memory_usage + coalesce(r.granted_query_memory, 0) as used_memory,
lower(sp.status) as status,
coalesce(r.sql_handle, sp.sql_handle) as sql_handle,
coalesce(r.statement_start_offset, sp.statement_start_offset) as statement_start_offset,
coalesce(r.statement_end_offset, sp.statement_end_offset) as statement_end_offset,
' +
case
when 
(
@get_task_info <> 0
or @find_block_leaders = 1 
) then
'sp.wait_type collate latin1_general_bin2 as wait_type,
sp.wait_resource collate latin1_general_bin2 as resource_description,
sp.wait_time as wait_duration_ms, 
'
else
''
end +
'nullif(sp.blocked, 0) as blocking_session_id,
r.plan_handle,
nullif(r.percent_complete, 0) as percent_complete,
sp.host_name,
sp.login_name,
sp.program_name,
s.host_process_id,
coalesce(r.text_size, s.text_size) as text_size,
coalesce(r.language, s.language) as language,
coalesce(r.date_format, s.date_format) as date_format,
coalesce(r.date_first, s.date_first) as date_first,
coalesce(r.quoted_identifier, s.quoted_identifier) as quoted_identifier,
coalesce(r.arithabort, s.arithabort) as arithabort,
coalesce(r.ansi_null_dflt_on, s.ansi_null_dflt_on) as ansi_null_dflt_on,
coalesce(r.ansi_defaults, s.ansi_defaults) as ansi_defaults,
coalesce(r.ansi_warnings, s.ansi_warnings) as ansi_warnings,
coalesce(r.ansi_padding, s.ansi_padding) as ansi_padding,
coalesce(r.ansi_nulls, s.ansi_nulls) as ansi_nulls,
coalesce(r.concat_null_yields_null, s.concat_null_yields_null) as concat_null_yields_null,
coalesce(r.transaction_isolation_level, s.transaction_isolation_level) as transaction_isolation_level,
coalesce(r.lock_timeout, s.lock_timeout) as lock_timeout,
coalesce(r.deadlock_priority, s.deadlock_priority) as deadlock_priority,
coalesce(r.row_count, s.row_count) as row_count,
coalesce(r.command, sp.cmd) as command_type,
coalesce
(
case
when
(
s.is_user_process = 0
and r.total_elapsed_time >= 0
) then
dateadd
(
ms,
1000 * (datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())) / 500) - datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())),
dateadd(second, -(r.total_elapsed_time / 1000), getdate())
)
end,
nullif(coalesce(r.start_time, sp.last_request_end_time), convert(datetime, ''19000101'', 112)),
(
select top(1)
dateadd(second, -(ms_ticks / 1000), getdate())
from sys.dm_os_sys_info
)
) as start_time,
sp.login_time,
case
when s.is_user_process = 1 then
s.last_request_start_time
else
coalesce
(
dateadd
(
ms,
1000 * (datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())) / 500) - datepart(ms, dateadd(second, -(r.total_elapsed_time / 1000), getdate())),
dateadd(second, -(r.total_elapsed_time / 1000), getdate())
),
s.last_request_start_time
)
end as last_request_start_time,
r.transaction_id,
sp.database_id,
sp.open_tran_count
from @sessions as sp
left outer loop join sys.dm_exec_sessions as s on
s.session_id = sp.session_id
and s.login_time = sp.login_time
left outer loop join sys.dm_exec_requests as r on
sp.status <> ''sleeping''
and r.session_id = sp.session_id
and r.request_id = sp.request_id
and
(
(
s.is_user_process = 0
and sp.is_user_process = 0
)
or
(
r.start_time = s.last_request_start_time
and s.last_request_end_time <= sp.last_request_end_time
)
)
) as y
' + 
case 
when @get_task_info = 2 then
convert(varchar(max), '') +
'left outer hash join
(
select top(@i)
task_nodes.task_node.value(''(session_id/text())[1]'', ''smallint'') as session_id,
task_nodes.task_node.value(''(request_id/text())[1]'', ''int'') as request_id,
task_nodes.task_node.value(''(physical_io/text())[1]'', ''bigint'') as physical_io,
task_nodes.task_node.value(''(context_switches/text())[1]'', ''bigint'') as context_switches,
task_nodes.task_node.value(''(tasks/text())[1]'', ''int'') as tasks,
task_nodes.task_node.value(''(block_info/text())[1]'', ''nvarchar(4000)'') as block_info,
task_nodes.task_node.value(''(waits/text())[1]'', ''nvarchar(4000)'') as wait_info,
task_nodes.task_node.value(''(thread_cpu_snapshot/text())[1]'', ''bigint'') as thread_cpu_snapshot
from
(
select top(@i)
convert
(
xml,
replace
(
convert(nvarchar(max), tasks_raw.task_xml_raw) collate latin1_general_bin2,
n''</waits></tasks><tasks><waits>'',
n'', ''
)
) as task_xml
from
(
select top(@i)
case waits.r
when 1 then
waits.session_id
else
null
end as [session_id],
case waits.r
when 1 then
waits.request_id
else
null
end as [request_id],                                            
case waits.r
when 1 then
waits.physical_io
else
null
end as [physical_io],
case waits.r
when 1 then
waits.context_switches
else
null
end as [context_switches],
case waits.r
when 1 then
waits.thread_cpu_snapshot
else
null
end as [thread_cpu_snapshot],
case waits.r
when 1 then
waits.tasks
else
null
end as [tasks],
case waits.r
when 1 then
waits.block_info
else
null
end as [block_info],
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert
(
nvarchar(max),
n''('' +
convert(nvarchar, num_waits) + n''x: '' +
case num_waits
when 1 then
convert(nvarchar, min_wait_time) + n''ms''
when 2 then
case
when min_wait_time <> max_wait_time then
convert(nvarchar, min_wait_time) + n''/'' + convert(nvarchar, max_wait_time) + n''ms''
else
convert(nvarchar, max_wait_time) + n''ms''
end
else
case
when min_wait_time <> max_wait_time then
convert(nvarchar, min_wait_time) + n''/'' + convert(nvarchar, avg_wait_time) + n''/'' + convert(nvarchar, max_wait_time) + n''ms''
else 
convert(nvarchar, max_wait_time) + n''ms''
end
end +
n'')'' + wait_type collate latin1_general_bin2
),
nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''),
nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''),
nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''),
nchar(0),
n''''
) as [waits]
from
(
select top(@i)
w1.*,
row_number() over
(
partition by
w1.session_id,
w1.request_id
order by
w1.block_info desc,
w1.num_waits desc,
w1.wait_type
) as r
from
(
select top(@i)
task_info.session_id,
task_info.request_id,
task_info.physical_io,
task_info.context_switches,
task_info.thread_cpu_snapshot,
task_info.num_tasks as tasks,
case
when task_info.runnable_time is not null then
''runnable''
else
wt2.wait_type
end as wait_type,
nullif(count(coalesce(task_info.runnable_time, wt2.waiting_task_address)), 0) as num_waits,
min(coalesce(task_info.runnable_time, wt2.wait_duration_ms)) as min_wait_time,
avg(coalesce(task_info.runnable_time, wt2.wait_duration_ms)) as avg_wait_time,
max(coalesce(task_info.runnable_time, wt2.wait_duration_ms)) as max_wait_time,
max(wt2.block_info) as block_info
from
(
select top(@i)
t.session_id,
t.request_id,
sum(convert(bigint, t.pending_io_count)) over (partition by t.session_id, t.request_id) as physical_io,
sum(convert(bigint, t.context_switches_count)) over (partition by t.session_id, t.request_id) as context_switches, 
' +
case
when @output_column_list like '%|[cpu_delta|]%' escape '|'
then
'sum(tr.usermode_time + tr.kernel_time) over (partition by t.session_id, t.request_id) '
else
'convert(bigint, null) '
end + 
' as thread_cpu_snapshot, 
count(*) over (partition by t.session_id, t.request_id) as num_tasks,
t.task_address,
t.task_state,
case
when
t.task_state = ''runnable''
and w.runnable_time > 0 then
w.runnable_time
else
null
end as runnable_time
from sys.dm_os_tasks as t
cross apply
(
select top(1)
sp2.session_id
from @sessions as sp2
where
sp2.session_id = t.session_id
and sp2.request_id = t.request_id
and sp2.status <> ''sleeping''
) as sp20
left outer hash join
(
select top(@i)
(
select top(@i)
ms_ticks
from sys.dm_os_sys_info
) -
w0.wait_resumed_ms_ticks as runnable_time,
w0.worker_address,
w0.thread_address,
w0.task_bound_ms_ticks
from sys.dm_os_workers as w0
where
w0.state = ''runnable''
or @first_collection_ms_ticks >= w0.task_bound_ms_ticks
) as w on
w.worker_address = t.worker_address 
' +
case
when @output_column_list like '%|[cpu_delta|]%' escape '|'
then
'left outer hash join sys.dm_os_threads as tr on
tr.thread_address = w.thread_address
and @first_collection_ms_ticks >= w.task_bound_ms_ticks
'
else
''
end +
') as task_info
left outer hash join
(
select top(@i)
wt1.wait_type,
wt1.waiting_task_address,
max(wt1.wait_duration_ms) as wait_duration_ms,
max(wt1.block_info) as block_info
from
(
select distinct top(@i)
wt.wait_type +
case
when wt.wait_type like n''page%latch_%'' then
'':'' +
coalesce(db_name(convert(int, left(wt.resource_description, charindex(n'':'', wt.resource_description) - 1))), n''(null)'') +
n'':'' +
substring(wt.resource_description, charindex(n'':'', wt.resource_description) + 1, len(wt.resource_description) - charindex(n'':'', reverse(wt.resource_description)) - charindex(n'':'', wt.resource_description)) +
n''('' +
case
when
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) = 1 or
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) % 8088 = 0
then 
n''pfs''
when
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) = 2 or
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) % 511232 = 0 
then 
n''gam''
when
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) = 3 or
(convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) - 1) % 511232 = 0 
then 
n''sgam''
when
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) = 6 or
(convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) - 6) % 511232 = 0 
then 
n''dcm''
when
convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) = 7 or
(convert(int, right(wt.resource_description, charindex(n'':'', reverse(wt.resource_description)) - 1)) - 7) % 511232 = 0
then 
n''bcm''
else
n''*''
end +
n'')''
when wt.wait_type = n''cxpacket'' then
n'':'' + substring(wt.resource_description, charindex(n''nodeid'', wt.resource_description) + 7, 4)
when wt.wait_type like n''latch[_]%'' then
n'' ['' + left(wt.resource_description, coalesce(nullif(charindex(n'' '', wt.resource_description), 0), len(wt.resource_description) + 1) - 1) + n'']''
else 
n''''
end collate latin1_general_bin2 as wait_type,
case
when
(
wt.blocking_session_id is not null
and wt.wait_type like n''lck[_]%''
) then
(
select top(@i)
x.lock_type,
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
db_name
(
convert
(
int,
substring(wt.resource_description, nullif(charindex(n''dbid='', wt.resource_description), 0) + 5, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''dbid='', wt.resource_description) + 5), 0), len(wt.resource_description) + 1) - charindex(n''dbid='', wt.resource_description) - 5)
)
),
nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''),
nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''),
nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''),
nchar(0),
n''''
) as database_name,
case x.lock_type
when n''objectlock'' then
substring(wt.resource_description, nullif(charindex(n''objid='', wt.resource_description), 0) + 6, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''objid='', wt.resource_description) + 6), 0), len(wt.resource_description) + 1) - charindex(n''objid='', wt.resource_description) - 6)
else
null
end as object_id,
case x.lock_type
when n''filelock'' then
substring(wt.resource_description, nullif(charindex(n''fileid='', wt.resource_description), 0) + 7, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''fileid='', wt.resource_description) + 7), 0), len(wt.resource_description) + 1) - charindex(n''fileid='', wt.resource_description) - 7)
else
null
end as file_id,
case
when x.lock_type in (n''pagelock'', n''extentlock'', n''ridlock'') then
substring(wt.resource_description, nullif(charindex(n''associatedobjectid='', wt.resource_description), 0) + 19, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''associatedobjectid='', wt.resource_description) + 19), 0), len(wt.resource_description) + 1) - charindex(n''associatedobjectid='', wt.resource_description) - 19)
when x.lock_type in (n''keylock'', n''hobtlock'', n''allocunitlock'') then
substring(wt.resource_description, nullif(charindex(n''hobtid='', wt.resource_description), 0) + 7, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''hobtid='', wt.resource_description) + 7), 0), len(wt.resource_description) + 1) - charindex(n''hobtid='', wt.resource_description) - 7)
else
null
end as hobt_id,
case x.lock_type
when n''applicationlock'' then
substring(wt.resource_description, nullif(charindex(n''hash='', wt.resource_description), 0) + 5, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''hash='', wt.resource_description) + 5), 0), len(wt.resource_description) + 1) - charindex(n''hash='', wt.resource_description) - 5)
else
null
end as applock_hash,
case x.lock_type
when n''metadatalock'' then
substring(wt.resource_description, nullif(charindex(n''subresource='', wt.resource_description), 0) + 12, coalesce(nullif(charindex(n'' '', wt.resource_description, charindex(n''subresource='', wt.resource_description) + 12), 0), len(wt.resource_description) + 1) - charindex(n''subresource='', wt.resource_description) - 12)
else
null
end as metadata_resource,
case x.lock_type
when n''metadatalock'' then
substring(wt.resource_description, nullif(charindex(n''classid='', wt.resource_description), 0) + 8, coalesce(nullif(charindex(n'' dbid='', wt.resource_description) - charindex(n''classid='', wt.resource_description), 0), len(wt.resource_description) + 1) - 8)
else
null
end as metadata_class_id
from
(
select top(1)
left(wt.resource_description, charindex(n'' '', wt.resource_description) - 1) collate latin1_general_bin2 as lock_type
) as x
for xml
path('''')
)
else null
end as block_info,
wt.wait_duration_ms,
wt.waiting_task_address
from
(
select top(@i)
wt0.wait_type collate latin1_general_bin2 as wait_type,
wt0.resource_description collate latin1_general_bin2 as resource_description,
wt0.wait_duration_ms,
wt0.waiting_task_address,
case
when wt0.blocking_session_id = p.blocked then
wt0.blocking_session_id
else
null
end as blocking_session_id
from sys.dm_os_waiting_tasks as wt0
cross apply
(
select top(1)
s0.blocked
from @sessions as s0
where
s0.session_id = wt0.session_id
and coalesce(s0.wait_type, n'''') <> n''oledb''
and wt0.wait_type <> n''oledb''
) as p
) as wt
) as wt1
group by
wt1.wait_type,
wt1.waiting_task_address
) as wt2 on
wt2.waiting_task_address = task_info.task_address
and wt2.wait_duration_ms > 0
and task_info.runnable_time is null
group by
task_info.session_id,
task_info.request_id,
task_info.physical_io,
task_info.context_switches,
task_info.thread_cpu_snapshot,
task_info.num_tasks,
case
when task_info.runnable_time is not null then
''runnable''
else
wt2.wait_type
end
) as w1
) as waits
order by
waits.session_id,
waits.request_id,
waits.r
for xml
path(n''tasks''),
type
) as tasks_raw (task_xml_raw)
) as tasks_final
cross apply tasks_final.task_xml.nodes(n''/tasks'') as task_nodes (task_node)
where
task_nodes.task_node.exist(n''session_id'') = 1
) as tasks on
tasks.session_id = y.session_id
and tasks.request_id = y.request_id 
'
else
''
end +
'left outer hash join
(
select top(@i)
t_info.session_id,
coalesce(t_info.request_id, -1) as request_id,
sum(t_info.tempdb_allocations) as tempdb_allocations,
sum(t_info.tempdb_current) as tempdb_current
from
(
select top(@i)
tsu.session_id,
tsu.request_id,
tsu.user_objects_alloc_page_count +
tsu.internal_objects_alloc_page_count as tempdb_allocations,
tsu.user_objects_alloc_page_count +
tsu.internal_objects_alloc_page_count -
tsu.user_objects_dealloc_page_count -
tsu.internal_objects_dealloc_page_count as tempdb_current
from sys.dm_db_task_space_usage as tsu
cross apply
(
select top(1)
s0.session_id
from @sessions as s0
where
s0.session_id = tsu.session_id
) as p
union all
select top(@i)
ssu.session_id,
null as request_id,
ssu.user_objects_alloc_page_count +
ssu.internal_objects_alloc_page_count as tempdb_allocations,
ssu.user_objects_alloc_page_count +
ssu.internal_objects_alloc_page_count -
ssu.user_objects_dealloc_page_count -
ssu.internal_objects_dealloc_page_count as tempdb_current
from sys.dm_db_session_space_usage as ssu
cross apply
(
select top(1)
s0.session_id
from @sessions as s0
where
s0.session_id = ssu.session_id
) as p
) as t_info
group by
t_info.session_id,
coalesce(t_info.request_id, -1)
) as tempdb_info on
tempdb_info.session_id = y.session_id
and tempdb_info.request_id =
case
when y.status = n''sleeping'' then
-1
else
y.request_id
end
' +
case 
when 
not 
(
@get_avg_time = 1 
and @recursion = 1
) then 
''
else
'left outer hash join
(
select top(@i)
*
from sys.dm_exec_query_stats
) as qs on
qs.sql_handle = y.sql_handle
and qs.plan_handle = y.plan_handle
and qs.statement_start_offset = y.statement_start_offset
and qs.statement_end_offset = y.statement_end_offset
'
end + 
') as x
option (keepfixed plan, optimize for (@i = 1)); ';
set @sql_n = convert(nvarchar(max), @sql);
set @last_collection_start = getdate();
if @recursion = -1
begin;
select
@first_collection_ms_ticks = ms_ticks
from sys.dm_os_sys_info;
end;
insert #sessions
(
recursion,
session_id,
request_id,
session_number,
elapsed_time,
avg_elapsed_time,
physical_io,
reads,
physical_reads,
writes,
tempdb_allocations,
tempdb_current,
cpu,
thread_cpu_snapshot,
context_switches,
used_memory,
tasks,
status,
wait_info,
transaction_id,
open_tran_count,
sql_handle,
statement_start_offset,
statement_end_offset,        
sql_text,
plan_handle,
blocking_session_id,
percent_complete,
host_name,
login_name,
database_name,
program_name,
additional_info,
start_time,
login_time,
last_request_start_time
)
exec sp_executesql 
@sql_n,
n'@recursion smallint, @filter sysname, @not_filter sysname, @first_collection_ms_ticks bigint',
@recursion, @filter, @not_filter, @first_collection_ms_ticks;
--collect transaction information?
if
@recursion = 1
and
(
@output_column_list like '%|[tran_start_time|]%' escape '|'
or @output_column_list like '%|[tran_log_writes|]%' escape '|' 
)
begin;    
declare @i int;
set @i = 2147483647;
update s
set
tran_start_time =
convert
(
datetime,
left
(
x.trans_info,
nullif(charindex(nchar(254) collate latin1_general_bin2, x.trans_info) - 1, -1)
),
121
),
tran_log_writes =
right
(
x.trans_info,
len(x.trans_info) - charindex(nchar(254) collate latin1_general_bin2, x.trans_info)
)
from
(
select top(@i)
trans_nodes.trans_node.value('(session_id/text())[1]', 'smallint') as session_id,
coalesce(trans_nodes.trans_node.value('(request_id/text())[1]', 'int'), 0) as request_id,
trans_nodes.trans_node.value('(trans_info/text())[1]', 'nvarchar(4000)') as trans_info                
from
(
select top(@i)
convert
(
xml,
replace
(
convert(nvarchar(max), trans_raw.trans_xml_raw) collate latin1_general_bin2, 
n'</trans_info></trans><trans><trans_info>', n''
)
)
from
(
select top(@i)
case u_trans.r
when 1 then u_trans.session_id
else null
end as [session_id],
case u_trans.r
when 1 then u_trans.request_id
else null
end as [request_id],
convert
(
nvarchar(max),
case
when u_trans.database_id is not null then
case u_trans.r
when 1 then coalesce(convert(nvarchar, u_trans.transaction_start_time, 121) + nchar(254), n'')
else n''
end + 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert(varchar(128), coalesce(db_name(u_trans.database_id), n'(null)')),
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n'?'
) +
n': ' +
convert(nvarchar, u_trans.log_record_count) + n' (' + convert(nvarchar, u_trans.log_kb_used) + n' kb)' +
n','
else
n'n/a,'
end collate latin1_general_bin2
) as [trans_info]
from
(
select top(@i)
trans.*,
row_number() over
(
partition by
trans.session_id,
trans.request_id
order by
trans.transaction_start_time desc
) as r
from
(
select top(@i)
session_tran_map.session_id,
session_tran_map.request_id,
s_tran.database_id,
coalesce(sum(s_tran.database_transaction_log_record_count), 0) as log_record_count,
coalesce(sum(s_tran.database_transaction_log_bytes_used), 0) / 1024 as log_kb_used,
min(s_tran.database_transaction_begin_time) as transaction_start_time
from
(
select top(@i)
*
from sys.dm_tran_active_transactions
where
transaction_begin_time <= @last_collection_start
) as a_tran
inner hash join
(
select top(@i)
*
from sys.dm_tran_database_transactions
where
database_id < 32767
) as s_tran on
s_tran.transaction_id = a_tran.transaction_id
left outer hash join
(
select top(@i)
*
from sys.dm_tran_session_transactions
) as tst on
s_tran.transaction_id = tst.transaction_id
cross apply
(
select top(1)
s3.session_id,
s3.request_id
from
(
select top(1)
s1.session_id,
s1.request_id
from #sessions as s1
where
s1.transaction_id = s_tran.transaction_id
and s1.recursion = 1
union all
select top(1)
s2.session_id,
s2.request_id
from #sessions as s2
where
s2.session_id = tst.session_id
and s2.recursion = 1
) as s3
order by
s3.request_id
) as session_tran_map
group by
session_tran_map.session_id,
session_tran_map.request_id,
s_tran.database_id
) as trans
) as u_trans
for xml
path('trans'),
type
) as trans_raw (trans_xml_raw)
) as trans_final (trans_xml)
cross apply trans_final.trans_xml.nodes('/trans') as trans_nodes (trans_node)
) as x
inner hash join #sessions as s on
s.session_id = x.session_id
and s.request_id = x.request_id
option (optimize for (@i = 1));
end;
--variables for text and plan collection
declare    
@session_id smallint,
@request_id int,
@sql_handle varbinary(64),
@plan_handle varbinary(64),
@statement_start_offset int,
@statement_end_offset int,
@start_time datetime,
@database_name sysname;
if 
@recursion = 1
and @output_column_list like '%|[sql_text|]%' escape '|'
begin;
declare sql_cursor
cursor local fast_forward
for 
select 
session_id,
request_id,
sql_handle,
statement_start_offset,
statement_end_offset
from #sessions
where
recursion = 1
and sql_handle is not null
option (keepfixed plan);
open sql_cursor;
fetch next from sql_cursor
into 
@session_id,
@request_id,
@sql_handle,
@statement_start_offset,
@statement_end_offset;
--wait up to 5 ms for the sql text, then give up
set lock_timeout 5;
while @@fetch_status = 0
begin;
begin try;
update s
set
s.sql_text =
(
select
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
n'--' + nchar(13) + nchar(10) +
case 
when @get_full_inner_text = 1 then est.text
when len(est.text) < (@statement_end_offset / 2) + 1 then est.text
when substring(est.text, (@statement_start_offset/2), 2) like n'[a-za-z0-9][a-za-z0-9]' then est.text
else
case
when @statement_start_offset > 0 then
substring
(
est.text,
((@statement_start_offset/2) + 1),
(
case
when @statement_end_offset = -1 then 2147483647
else ((@statement_end_offset - @statement_start_offset)/2) + 1
end
)
)
else rtrim(ltrim(est.text))
end
end +
nchar(13) + nchar(10) + n'--' collate latin1_general_bin2,
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n''
) as [processing-instruction(query)]
for xml
path(''),
type
),
s.statement_start_offset = 
case 
when len(est.text) < (@statement_end_offset / 2) + 1 then 0
when substring(convert(varchar(max), est.text), (@statement_start_offset/2), 2) like '[a-za-z0-9][a-za-z0-9]' then 0
else @statement_start_offset
end,
s.statement_end_offset = 
case 
when len(est.text) < (@statement_end_offset / 2) + 1 then -1
when substring(convert(varchar(max), est.text), (@statement_start_offset/2), 2) like '[a-za-z0-9][a-za-z0-9]' then -1
else @statement_end_offset
end
from 
#sessions as s,
(
select top(1)
text
from
(
select 
text, 
0 as row_num
from sys.dm_exec_sql_text(@sql_handle)
union all
select 
null,
1 as row_num
) as est0
order by
row_num
) as est
where 
s.session_id = @session_id
and s.request_id = @request_id
and s.recursion = 1
option (keepfixed plan);
end try
begin catch;
update s
set
s.sql_text = 
case error_number() 
when 1222 then '<timeout_exceeded />'
else '<error message="' + error_message() + '" />'
end
from #sessions as s
where 
s.session_id = @session_id
and s.request_id = @request_id
and s.recursion = 1
option (keepfixed plan);
end catch;
fetch next from sql_cursor
into
@session_id,
@request_id,
@sql_handle,
@statement_start_offset,
@statement_end_offset;
end;
--return this to the default
set lock_timeout -1;
close sql_cursor;
deallocate sql_cursor;
end;
if 
@get_outer_command = 1 
and @recursion = 1
and @output_column_list like '%|[sql_command|]%' escape '|'
begin;
declare @buffer_results table
(
eventtype varchar(30),
parameters int,
eventinfo nvarchar(4000),
start_time datetime,
session_number int identity(1,1) not null primary key
);
declare buffer_cursor
cursor local fast_forward
for 
select 
session_id,
max(start_time) as start_time
from #sessions
where
recursion = 1
group by
session_id
order by
session_id
option (keepfixed plan);
open buffer_cursor;
fetch next from buffer_cursor
into 
@session_id,
@start_time;
while @@fetch_status = 0
begin;
begin try;
--in sql server 2008, dbcc inputbuffer will throw 
--an exception if the session no longer exists
insert @buffer_results
(
eventtype,
parameters,
eventinfo
)
exec sp_executesql
n'dbcc inputbuffer(@session_id) with no_infomsgs;',
n'@session_id smallint',
@session_id;
update br
set
br.start_time = @start_time
from @buffer_results as br
where
br.session_number = 
(
select max(br2.session_number)
from @buffer_results br2
);
end try
begin catch
end catch;
fetch next from buffer_cursor
into 
@session_id,
@start_time;
end;
update s
set
sql_command = 
(
select 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert
(
nvarchar(max),
n'--' + nchar(13) + nchar(10) + br.eventinfo + nchar(13) + nchar(10) + n'--' collate latin1_general_bin2
),
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n''
) as [processing-instruction(query)]
from @buffer_results as br
where 
br.session_number = s.session_number
and br.start_time = s.start_time
and 
(
(
s.start_time = s.last_request_start_time
and exists
(
select *
from sys.dm_exec_requests r2
where
r2.session_id = s.session_id
and r2.request_id = s.request_id
and r2.start_time = s.start_time
)
)
or 
(
s.request_id = 0
and exists
(
select *
from sys.dm_exec_sessions s2
where
s2.session_id = s.session_id
and s2.last_request_start_time = s.last_request_start_time
)
)
)
for xml
path(''),
type
)
from #sessions as s
where
recursion = 1
option (keepfixed plan);
close buffer_cursor;
deallocate buffer_cursor;
end;
if 
@get_plans >= 1 
and @recursion = 1
and @output_column_list like '%|[query_plan|]%' escape '|'
begin;
declare plan_cursor
cursor local fast_forward
for 
select
session_id,
request_id,
plan_handle,
statement_start_offset,
statement_end_offset
from #sessions
where
recursion = 1
and plan_handle is not null
option (keepfixed plan);
open plan_cursor;
fetch next from plan_cursor
into 
@session_id,
@request_id,
@plan_handle,
@statement_start_offset,
@statement_end_offset;
--wait up to 5 ms for a query plan, then give up
set lock_timeout 5;
while @@fetch_status = 0
begin;
begin try;
update s
set
s.query_plan =
(
select
convert(xml, query_plan)
from sys.dm_exec_text_query_plan
(
@plan_handle, 
case @get_plans
when 1 then
@statement_start_offset
else
0
end, 
case @get_plans
when 1 then
@statement_end_offset
else
-1
end
)
)
from #sessions as s
where 
s.session_id = @session_id
and s.request_id = @request_id
and s.recursion = 1
option (keepfixed plan);
end try
begin catch;
if error_number() = 6335
begin;
update s
set
s.query_plan =
(
select
n'--' + nchar(13) + nchar(10) + 
n'-- could not render showplan due to xml data type limitations. ' + nchar(13) + nchar(10) + 
n'-- to see the graphical plan save the xml below as a .sqlplan file and re-open in ssms.' + nchar(13) + nchar(10) +
n'--' + nchar(13) + nchar(10) +
replace(qp.query_plan, n'<relop', nchar(13)+nchar(10)+n'<relop') + 
nchar(13) + nchar(10) + n'--' collate latin1_general_bin2 as [processing-instruction(query_plan)]
from sys.dm_exec_text_query_plan
(
@plan_handle, 
case @get_plans
when 1 then
@statement_start_offset
else
0
end, 
case @get_plans
when 1 then
@statement_end_offset
else
-1
end
) as qp
for xml
path(''),
type
)
from #sessions as s
where 
s.session_id = @session_id
and s.request_id = @request_id
and s.recursion = 1
option (keepfixed plan);
end;
else
begin;
update s
set
s.query_plan = 
case error_number() 
when 1222 then '<timeout_exceeded />'
else '<error message="' + error_message() + '" />'
end
from #sessions as s
where 
s.session_id = @session_id
and s.request_id = @request_id
and s.recursion = 1
option (keepfixed plan);
end;
end catch;
fetch next from plan_cursor
into
@session_id,
@request_id,
@plan_handle,
@statement_start_offset,
@statement_end_offset;
end;
--return this to the default
set lock_timeout -1;
close plan_cursor;
deallocate plan_cursor;
end;
if 
@get_locks = 1 
and @recursion = 1
and @output_column_list like '%|[locks|]%' escape '|'
begin;
declare locks_cursor
cursor local fast_forward
for 
select distinct
database_name
from #locks
where
exists
(
select *
from #sessions as s
where
s.session_id = #locks.session_id
and recursion = 1
)
and database_name <> '(null)'
option (keepfixed plan);
open locks_cursor;
fetch next from locks_cursor
into 
@database_name;
while @@fetch_status = 0
begin;
begin try;
set @sql_n = convert(nvarchar(max), '') +
'update l ' +
'set ' +
'object_name = ' +
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'o.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
'), ' +
'index_name = ' +
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'i.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
'), ' +
'schema_name = ' +
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
's.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
'), ' +
'principal_name = ' + 
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'dp.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
') ' +
'from #locks as l ' +
'left outer join ' + quotename(@database_name) + '.sys.allocation_units as au on ' +
'au.allocation_unit_id = l.allocation_unit_id ' +
'left outer join ' + quotename(@database_name) + '.sys.partitions as p on ' +
'p.hobt_id = ' +
'coalesce ' +
'( ' +
'l.hobt_id, ' +
'case ' +
'when au.type in (1, 3) then au.container_id ' +
'else null ' +
'end ' +
') ' +
'left outer join ' + quotename(@database_name) + '.sys.partitions as p1 on ' +
'l.hobt_id is null ' +
'and au.type = 2 ' +
'and p1.partition_id = au.container_id ' +
'left outer join ' + quotename(@database_name) + '.sys.objects as o on ' +
'o.object_id = coalesce(l.object_id, p.object_id, p1.object_id) ' +
'left outer join ' + quotename(@database_name) + '.sys.indexes as i on ' +
'i.object_id = coalesce(l.object_id, p.object_id, p1.object_id) ' +
'and i.index_id = coalesce(l.index_id, p.index_id, p1.index_id) ' +
'left outer join ' + quotename(@database_name) + '.sys.schemas as s on ' +
's.schema_id = coalesce(l.schema_id, o.schema_id) ' +
'left outer join ' + quotename(@database_name) + '.sys.database_principals as dp on ' +
'dp.principal_id = l.principal_id ' +
'where ' +
'l.database_name = @database_name ' +
'option (keepfixed plan); ';
exec sp_executesql
@sql_n,
n'@database_name sysname',
@database_name;
end try
begin catch;
update #locks
set
query_error = 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert
(
nvarchar(max), 
error_message() collate latin1_general_bin2
),
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n''
)
where 
database_name = @database_name
option (keepfixed plan);
end catch;
fetch next from locks_cursor
into
@database_name;
end;
close locks_cursor;
deallocate locks_cursor;
create clustered index ix_srd on #locks (session_id, request_id, database_name);
update s
set 
s.locks =
(
select 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert
(
nvarchar(max), 
l1.database_name collate latin1_general_bin2
),
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n''
) as [database/@name],
min(l1.query_error) as [database/@query_error],
(
select 
l2.request_mode as [lock/@request_mode],
l2.request_status as [lock/@request_status],
count(*) as [lock/@request_count]
from #locks as l2
where 
l1.session_id = l2.session_id
and l1.request_id = l2.request_id
and l2.database_name = l1.database_name
and l2.resource_type = 'database'
group by
l2.request_mode,
l2.request_status
for xml
path(''),
type
) as [database/locks],
(
select
coalesce(l3.object_name, '(null)') as [object/@name],
l3.schema_name as [object/@schema_name],
(
select
l4.resource_type as [lock/@resource_type],
l4.page_type as [lock/@page_type],
l4.index_name as [lock/@index_name],
case 
when l4.object_name is null then l4.schema_name
else null
end as [lock/@schema_name],
l4.principal_name as [lock/@principal_name],
l4.resource_description as [lock/@resource_description],
l4.request_mode as [lock/@request_mode],
l4.request_status as [lock/@request_status],
sum(l4.request_count) as [lock/@request_count]
from #locks as l4
where 
l4.session_id = l3.session_id
and l4.request_id = l3.request_id
and l3.database_name = l4.database_name
and coalesce(l3.object_name, '(null)') = coalesce(l4.object_name, '(null)')
and coalesce(l3.schema_name, '') = coalesce(l4.schema_name, '')
and l4.resource_type <> 'database'
group by
l4.resource_type,
l4.page_type,
l4.index_name,
case 
when l4.object_name is null then l4.schema_name
else null
end,
l4.principal_name,
l4.resource_description,
l4.request_mode,
l4.request_status
for xml
path(''),
type
) as [object/locks]
from #locks as l3
where 
l3.session_id = l1.session_id
and l3.request_id = l1.request_id
and l3.database_name = l1.database_name
and l3.resource_type <> 'database'
group by 
l3.session_id,
l3.request_id,
l3.database_name,
coalesce(l3.object_name, '(null)'),
l3.schema_name
for xml
path(''),
type
) as [database/objects]
from #locks as l1
where
l1.session_id = s.session_id
and l1.request_id = s.request_id
and l1.start_time in (s.start_time, s.last_request_start_time)
and s.recursion = 1
group by 
l1.session_id,
l1.request_id,
l1.database_name
for xml
path(''),
type
)
from #sessions s
option (keepfixed plan);
end;
if 
@find_block_leaders = 1
and @recursion = 1
and @output_column_list like '%|[blocked_session_count|]%' escape '|'
begin;
with
blockers as
(
select
session_id,
session_id as top_level_session_id,
convert(varchar(8000), '.' + convert(varchar(8000), session_id) + '.') as the_path
from #sessions
where
recursion = 1
union all
select
s.session_id,
b.top_level_session_id,
convert(varchar(8000), b.the_path + convert(varchar(8000), s.session_id) + '.') as the_path
from blockers as b
join #sessions as s on
s.blocking_session_id = b.session_id
and s.recursion = 1
and b.the_path not like '%.' + convert(varchar(8000), s.session_id) + '.%' collate latin1_general_bin2
)
update s
set
s.blocked_session_count = x.blocked_session_count
from #sessions as s
join
(
select
b.top_level_session_id as session_id,
count(*) - 1 as blocked_session_count
from blockers as b
group by
b.top_level_session_id
) x on
s.session_id = x.session_id
where
s.recursion = 1;
end;
if
@get_task_info = 2
and @output_column_list like '%|[additional_info|]%' escape '|'
and @recursion = 1
begin;
create table #blocked_requests
(
session_id smallint not null,
request_id int not null,
database_name sysname not null,
object_id int,
hobt_id bigint,
schema_id int,
schema_name sysname null,
object_name sysname null,
query_error nvarchar(2048),
primary key (database_name, session_id, request_id)
);
create statistics s_database_name on #blocked_requests (database_name)
with sample 0 rows, norecompute;
create statistics s_schema_name on #blocked_requests (schema_name)
with sample 0 rows, norecompute;
create statistics s_object_name on #blocked_requests (object_name)
with sample 0 rows, norecompute;
create statistics s_query_error on #blocked_requests (query_error)
with sample 0 rows, norecompute;
insert #blocked_requests
(
session_id,
request_id,
database_name,
object_id,
hobt_id,
schema_id
)
select
session_id,
request_id,
database_name,
object_id,
hobt_id,
convert(int, substring(schema_node, charindex(' = ', schema_node) + 3, len(schema_node))) as schema_id
from
(
select
session_id,
request_id,
agent_nodes.agent_node.value('(database_name/text())[1]', 'sysname') as database_name,
agent_nodes.agent_node.value('(object_id/text())[1]', 'int') as object_id,
agent_nodes.agent_node.value('(hobt_id/text())[1]', 'bigint') as hobt_id,
agent_nodes.agent_node.value('(metadata_resource/text()[.="schema"]/../../metadata_class_id/text())[1]', 'varchar(100)') as schema_node
from #sessions as s
cross apply s.additional_info.nodes('//block_info') as agent_nodes (agent_node)
where
s.recursion = 1
) as t
where
t.database_name is not null
and
(
t.object_id is not null
or t.hobt_id is not null
or t.schema_node is not null
);
declare blocks_cursor
cursor local fast_forward
for
select distinct
database_name
from #blocked_requests;
open blocks_cursor;
fetch next from blocks_cursor
into 
@database_name;
while @@fetch_status = 0
begin;
begin try;
set @sql_n = 
convert(nvarchar(max), '') +
'update b ' +
'set ' +
'b.schema_name = ' +
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
's.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
'), ' +
'b.object_name = ' +
'replace ' +
'( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'replace(replace(replace(replace(replace(replace(replace(replace(replace(replace( ' +
'o.name collate latin1_general_bin2, ' +
'nchar(31),n''?''),nchar(30),n''?''),nchar(29),n''?''),nchar(28),n''?''),nchar(27),n''?''),nchar(26),n''?''),nchar(25),n''?''),nchar(24),n''?''),nchar(23),n''?''),nchar(22),n''?''), ' +
'nchar(21),n''?''),nchar(20),n''?''),nchar(19),n''?''),nchar(18),n''?''),nchar(17),n''?''),nchar(16),n''?''),nchar(15),n''?''),nchar(14),n''?''),nchar(12),n''?''), ' +
'nchar(11),n''?''),nchar(8),n''?''),nchar(7),n''?''),nchar(6),n''?''),nchar(5),n''?''),nchar(4),n''?''),nchar(3),n''?''),nchar(2),n''?''),nchar(1),n''?''), ' +
'nchar(0), ' +
n''''' ' +
') ' +
'from #blocked_requests as b ' +
'left outer join ' + quotename(@database_name) + '.sys.partitions as p on ' +
'p.hobt_id = b.hobt_id ' +
'left outer join ' + quotename(@database_name) + '.sys.objects as o on ' +
'o.object_id = coalesce(p.object_id, b.object_id) ' +
'left outer join ' + quotename(@database_name) + '.sys.schemas as s on ' +
's.schema_id = coalesce(o.schema_id, b.schema_id) ' +
'where ' +
'b.database_name = @database_name; ';
exec sp_executesql
@sql_n,
n'@database_name sysname',
@database_name;
end try
begin catch;
update #blocked_requests
set
query_error = 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
convert
(
nvarchar(max), 
error_message() collate latin1_general_bin2
),
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n''
)
where
database_name = @database_name;
end catch;
fetch next from blocks_cursor
into
@database_name;
end;
close blocks_cursor;
deallocate blocks_cursor;
update s
set
additional_info.modify
('
insert <schema_name>{sql:column("b.schema_name")}</schema_name>
as last
into (/additional_info/block_info)[1]
')
from #sessions as s
inner join #blocked_requests as b on
b.session_id = s.session_id
and b.request_id = s.request_id
and s.recursion = 1
where
b.schema_name is not null;
update s
set
additional_info.modify
('
insert <object_name>{sql:column("b.object_name")}</object_name>
as last
into (/additional_info/block_info)[1]
')
from #sessions as s
inner join #blocked_requests as b on
b.session_id = s.session_id
and b.request_id = s.request_id
and s.recursion = 1
where
b.object_name is not null;
update s
set
additional_info.modify
('
insert <query_error>{sql:column("b.query_error")}</query_error>
as last
into (/additional_info/block_info)[1]
')
from #sessions as s
inner join #blocked_requests as b on
b.session_id = s.session_id
and b.request_id = s.request_id
and s.recursion = 1
where
b.query_error is not null;
end;
if
@output_column_list like '%|[program_name|]%' escape '|'
and @output_column_list like '%|[additional_info|]%' escape '|'
and @recursion = 1
begin;
declare @job_id uniqueidentifier;
declare @step_id int;
declare agent_cursor
cursor local fast_forward
for 
select
s.session_id,
agent_nodes.agent_node.value('(job_id/text())[1]', 'uniqueidentifier') as job_id,
agent_nodes.agent_node.value('(step_id/text())[1]', 'int') as step_id
from #sessions as s
cross apply s.additional_info.nodes('//agent_job_info') as agent_nodes (agent_node)
where
s.recursion = 1
option (keepfixed plan);
open agent_cursor;
fetch next from agent_cursor
into 
@session_id,
@job_id,
@step_id;
while @@fetch_status = 0
begin;
begin try;
declare @job_name sysname;
set @job_name = null;
declare @step_name sysname;
set @step_name = null;
select
@job_name = 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
j.name,
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n'?'
),
@step_name = 
replace
(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(
replace(replace(replace(replace(replace(replace(replace(replace(replace(replace(
s.step_name,
nchar(31),n'?'),nchar(30),n'?'),nchar(29),n'?'),nchar(28),n'?'),nchar(27),n'?'),nchar(26),n'?'),nchar(25),n'?'),nchar(24),n'?'),nchar(23),n'?'),nchar(22),n'?'),
nchar(21),n'?'),nchar(20),n'?'),nchar(19),n'?'),nchar(18),n'?'),nchar(17),n'?'),nchar(16),n'?'),nchar(15),n'?'),nchar(14),n'?'),nchar(12),n'?'),
nchar(11),n'?'),nchar(8),n'?'),nchar(7),n'?'),nchar(6),n'?'),nchar(5),n'?'),nchar(4),n'?'),nchar(3),n'?'),nchar(2),n'?'),nchar(1),n'?'),
nchar(0),
n'?'
)
from msdb.dbo.sysjobs as j
inner join msdb..sysjobsteps as s on
j.job_id = s.job_id
where
j.job_id = @job_id
and s.step_id = @step_id;
if @job_name is not null
begin;
update s
set
additional_info.modify
('
insert text{sql:variable("@job_name")}
into (/additional_info/agent_job_info/job_name)[1]
')
from #sessions as s
where 
s.session_id = @session_id
option (keepfixed plan);
update s
set
additional_info.modify
('
insert text{sql:variable("@step_name")}
into (/additional_info/agent_job_info/step_name)[1]
')
from #sessions as s
where 
s.session_id = @session_id
option (keepfixed plan);
end;
end try
begin catch;
declare @msdb_error_message nvarchar(256);
set @msdb_error_message = error_message();
update s
set
additional_info.modify
('
insert <msdb_query_error>{sql:variable("@msdb_error_message")}</msdb_query_error>
as last
into (/additional_info/agent_job_info)[1]
')
from #sessions as s
where 
s.session_id = @session_id
and s.recursion = 1
option (keepfixed plan);
end catch;
fetch next from agent_cursor
into 
@session_id,
@job_id,
@step_id;
end;
close agent_cursor;
deallocate agent_cursor;
end; 
if 
@delta_interval > 0 
and @recursion <> 1
begin;
set @recursion = 1;
declare @delay_time char(12);
set @delay_time = convert(varchar, dateadd(second, @delta_interval, 0), 114);
waitfor delay @delay_time;
goto redo;
end;
end;
set @sql = 
--outer column list
convert
(
varchar(max),
case
when 
@destination_table <> '' 
and @return_schema = 0 
then 'insert ' + @destination_table + ' '
else ''
end +
'select ' +
@output_column_list + ' ' +
case @return_schema
when 1 then 'into #session_schema '
else ''
end
--end outer column list
) + 
--inner column list
convert
(
varchar(max),
'from ' +
'( ' +
'select ' +
'session_id, ' +
--[dd hh:mm:ss.mss]
case
when @format_output in (1, 2) then
'case ' +
'when elapsed_time < 0 then ' +
'right ' +
'( ' +
'replicate(''0'', max_elapsed_length) + convert(varchar, (-1 * elapsed_time) / 86400), ' +
'max_elapsed_length ' +
') + ' +
'right ' +
'( ' +
'convert(varchar, dateadd(second, (-1 * elapsed_time), 0), 120), ' +
'9 ' +
') + ' +
'''.000'' ' +
'else ' +
'right ' +
'( ' +
'replicate(''0'', max_elapsed_length) + convert(varchar, elapsed_time / 86400000), ' +
'max_elapsed_length ' +
') + ' +
'right ' +
'( ' +
'convert(varchar, dateadd(second, elapsed_time / 1000, 0), 120), ' +
'9 ' +
') + ' +
'''.'' + ' + 
'right(''000'' + convert(varchar, elapsed_time % 1000), 3) ' +
'end as [dd hh:mm:ss.mss], '
else
''
end +
--[dd hh:mm:ss.mss (avg)] / avg_elapsed_time
case 
when  @format_output in (1, 2) then 
'right ' +
'( ' +
'''00'' + convert(varchar, avg_elapsed_time / 86400000), ' +
'2 ' +
') + ' +
'right ' +
'( ' +
'convert(varchar, dateadd(second, avg_elapsed_time / 1000, 0), 120), ' +
'9 ' +
') + ' +
'''.'' + ' +
'right(''000'' + convert(varchar, avg_elapsed_time % 1000), 3) as [dd hh:mm:ss.mss (avg)], '
else
'avg_elapsed_time, '
end +
--physical_io
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, physical_io))) over() - len(convert(varchar, physical_io))) + left(convert(char(22), convert(money, physical_io), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, physical_io), 1), 19)) as '
else ''
end + 'physical_io, ' +
--reads
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, reads))) over() - len(convert(varchar, reads))) + left(convert(char(22), convert(money, reads), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, reads), 1), 19)) as '
else ''
end + 'reads, ' +
--physical_reads
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, physical_reads))) over() - len(convert(varchar, physical_reads))) + left(convert(char(22), convert(money, physical_reads), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, physical_reads), 1), 19)) as '
else ''
end + 'physical_reads, ' +
--writes
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, writes))) over() - len(convert(varchar, writes))) + left(convert(char(22), convert(money, writes), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, writes), 1), 19)) as '
else ''
end + 'writes, ' +
--tempdb_allocations
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, tempdb_allocations))) over() - len(convert(varchar, tempdb_allocations))) + left(convert(char(22), convert(money, tempdb_allocations), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, tempdb_allocations), 1), 19)) as '
else ''
end + 'tempdb_allocations, ' +
--tempdb_current
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, tempdb_current))) over() - len(convert(varchar, tempdb_current))) + left(convert(char(22), convert(money, tempdb_current), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, tempdb_current), 1), 19)) as '
else ''
end + 'tempdb_current, ' +
--cpu
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, cpu))) over() - len(convert(varchar, cpu))) + left(convert(char(22), convert(money, cpu), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, cpu), 1), 19)) as '
else ''
end + 'cpu, ' +
--context_switches
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, context_switches))) over() - len(convert(varchar, context_switches))) + left(convert(char(22), convert(money, context_switches), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, context_switches), 1), 19)) as '
else ''
end + 'context_switches, ' +
--used_memory
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, used_memory))) over() - len(convert(varchar, used_memory))) + left(convert(char(22), convert(money, used_memory), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, used_memory), 1), 19)) as '
else ''
end + 'used_memory, ' +
case
when @output_column_list like '%|_delta|]%' escape '|' then
--physical_io_delta            
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and physical_io_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, physical_io_delta))) over() - len(convert(varchar, physical_io_delta))) + left(convert(char(22), convert(money, physical_io_delta), 1), 19)) ' 
when 2 then 'convert(varchar, left(convert(char(22), convert(money, physical_io_delta), 1), 19)) '
else 'physical_io_delta '
end +
'else null ' +
'end as physical_io_delta, ' +
--reads_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and reads_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, reads_delta))) over() - len(convert(varchar, reads_delta))) + left(convert(char(22), convert(money, reads_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, reads_delta), 1), 19)) '
else 'reads_delta '
end +
'else null ' +
'end as reads_delta, ' +
--physical_reads_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and physical_reads_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, physical_reads_delta))) over() - len(convert(varchar, physical_reads_delta))) + left(convert(char(22), convert(money, physical_reads_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, physical_reads_delta), 1), 19)) '
else 'physical_reads_delta '
end + 
'else null ' +
'end as physical_reads_delta, ' +
--writes_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and writes_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, writes_delta))) over() - len(convert(varchar, writes_delta))) + left(convert(char(22), convert(money, writes_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, writes_delta), 1), 19)) '
else 'writes_delta '
end + 
'else null ' +
'end as writes_delta, ' +
--tempdb_allocations_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and tempdb_allocations_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, tempdb_allocations_delta))) over() - len(convert(varchar, tempdb_allocations_delta))) + left(convert(char(22), convert(money, tempdb_allocations_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, tempdb_allocations_delta), 1), 19)) '
else 'tempdb_allocations_delta '
end + 
'else null ' +
'end as tempdb_allocations_delta, ' +
--tempdb_current_delta
--this is the only one that can (legitimately) go negative 
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, tempdb_current_delta))) over() - len(convert(varchar, tempdb_current_delta))) + left(convert(char(22), convert(money, tempdb_current_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, tempdb_current_delta), 1), 19)) '
else 'tempdb_current_delta '
end + 
'else null ' +
'end as tempdb_current_delta, ' +
--cpu_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'then ' +
'case ' +
'when ' +
'thread_cpu_delta > cpu_delta ' +
'and thread_cpu_delta > 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, thread_cpu_delta + cpu_delta))) over() - len(convert(varchar, thread_cpu_delta))) + left(convert(char(22), convert(money, thread_cpu_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, thread_cpu_delta), 1), 19)) '
else 'thread_cpu_delta '
end + 
'when cpu_delta >= 0 then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, thread_cpu_delta + cpu_delta))) over() - len(convert(varchar, cpu_delta))) + left(convert(char(22), convert(money, cpu_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, cpu_delta), 1), 19)) '
else 'cpu_delta '
end + 
'else null ' +
'end ' +
'else ' +
'null ' +
'end as cpu_delta, ' +
--context_switches_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and context_switches_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, context_switches_delta))) over() - len(convert(varchar, context_switches_delta))) + left(convert(char(22), convert(money, context_switches_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, context_switches_delta), 1), 19)) '
else 'context_switches_delta '
end + 
'else null ' +
'end as context_switches_delta, ' +
--used_memory_delta
'case ' +
'when ' +
'first_request_start_time = last_request_start_time ' + 
'and num_events = 2 ' +
'and used_memory_delta >= 0 ' +
'then ' +
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, used_memory_delta))) over() - len(convert(varchar, used_memory_delta))) + left(convert(char(22), convert(money, used_memory_delta), 1), 19)) '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, used_memory_delta), 1), 19)) '
else 'used_memory_delta '
end + 
'else null ' +
'end as used_memory_delta, '
else ''
end +
--tasks
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, tasks))) over() - len(convert(varchar, tasks))) + left(convert(char(22), convert(money, tasks), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, tasks), 1), 19)) '
else ''
end + 'tasks, ' +
'status, ' +
'wait_info, ' +
'locks, ' +
'tran_start_time, ' +
'left(tran_log_writes, len(tran_log_writes) - 1) as tran_log_writes, ' +
--open_tran_count
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, open_tran_count))) over() - len(convert(varchar, open_tran_count))) + left(convert(char(22), convert(money, open_tran_count), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, open_tran_count), 1), 19)) as '
else ''
end + 'open_tran_count, ' +
--sql_command
case @format_output 
when 0 then 'replace(replace(convert(nvarchar(max), sql_command), ''<?query --''+char(13)+char(10), ''''), char(13)+char(10)+''--?>'', '''') as '
else ''
end + 'sql_command, ' +
--sql_text
case @format_output 
when 0 then 'replace(replace(convert(nvarchar(max), sql_text), ''<?query --''+char(13)+char(10), ''''), char(13)+char(10)+''--?>'', '''') as '
else ''
end + 'sql_text, ' +
'query_plan, ' +
'blocking_session_id, ' +
--blocked_session_count
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, blocked_session_count))) over() - len(convert(varchar, blocked_session_count))) + left(convert(char(22), convert(money, blocked_session_count), 1), 19)) as '
when 2 then 'convert(varchar, left(convert(char(22), convert(money, blocked_session_count), 1), 19)) as '
else ''
end + 'blocked_session_count, ' +
--percent_complete
case @format_output
when 1 then 'convert(varchar, space(max(len(convert(varchar, convert(money, percent_complete), 2))) over() - len(convert(varchar, convert(money, percent_complete), 2))) + convert(char(22), convert(money, percent_complete), 2)) as '
when 2 then 'convert(varchar, convert(char(22), convert(money, blocked_session_count), 1)) as '
else ''
end + 'percent_complete, ' +
'host_name, ' +
'login_name, ' +
'database_name, ' +
'program_name, ' +
'additional_info, ' +
'start_time, ' +
'login_time, ' +
'case ' +
'when status = n''sleeping'' then null ' +
'else request_id ' +
'end as request_id, ' +
'getdate() as collection_time '
--end inner column list
) +
--derived table and insert specification
convert
(
varchar(max),
'from ' +
'( ' +
'select top(2147483647) ' +
'*, ' +
'case ' +
'max ' +
'( ' +
'len ' +
'( ' +
'convert ' +
'( ' +
'varchar, ' +
'case ' +
'when elapsed_time < 0 then ' +
'(-1 * elapsed_time) / 86400 ' +
'else ' +
'elapsed_time / 86400000 ' +
'end ' +
') ' +
') ' +
') over () ' +
'when 1 then 2 ' +
'else ' +
'max ' +
'( ' +
'len ' +
'( ' +
'convert ' +
'( ' +
'varchar, ' +
'case ' +
'when elapsed_time < 0 then ' +
'(-1 * elapsed_time) / 86400 ' +
'else ' +
'elapsed_time / 86400000 ' +
'end ' +
') ' +
') ' +
') over () ' +
'end as max_elapsed_length, ' +
case
when @output_column_list like '%|_delta|]%' escape '|' then
'max(physical_io * recursion) over (partition by session_id, request_id) + ' +
'min(physical_io * recursion) over (partition by session_id, request_id) as physical_io_delta, ' +
'max(reads * recursion) over (partition by session_id, request_id) + ' +
'min(reads * recursion) over (partition by session_id, request_id) as reads_delta, ' +
'max(physical_reads * recursion) over (partition by session_id, request_id) + ' +
'min(physical_reads * recursion) over (partition by session_id, request_id) as physical_reads_delta, ' +
'max(writes * recursion) over (partition by session_id, request_id) + ' +
'min(writes * recursion) over (partition by session_id, request_id) as writes_delta, ' +
'max(tempdb_allocations * recursion) over (partition by session_id, request_id) + ' +
'min(tempdb_allocations * recursion) over (partition by session_id, request_id) as tempdb_allocations_delta, ' +
'max(tempdb_current * recursion) over (partition by session_id, request_id) + ' +
'min(tempdb_current * recursion) over (partition by session_id, request_id) as tempdb_current_delta, ' +
'max(cpu * recursion) over (partition by session_id, request_id) + ' +
'min(cpu * recursion) over (partition by session_id, request_id) as cpu_delta, ' +
'max(thread_cpu_snapshot * recursion) over (partition by session_id, request_id) + ' +
'min(thread_cpu_snapshot * recursion) over (partition by session_id, request_id) as thread_cpu_delta, ' +
'max(context_switches * recursion) over (partition by session_id, request_id) + ' +
'min(context_switches * recursion) over (partition by session_id, request_id) as context_switches_delta, ' +
'max(used_memory * recursion) over (partition by session_id, request_id) + ' +
'min(used_memory * recursion) over (partition by session_id, request_id) as used_memory_delta, ' +
'min(last_request_start_time) over (partition by session_id, request_id) as first_request_start_time, '
else ''
end +
'count(*) over (partition by session_id, request_id) as num_events ' +
'from #sessions as s1 ' +
case 
when @sort_order = '' then ''
else
'order by ' +
@sort_order
end +
') as s ' +
'where ' +
's.recursion = 1 ' +
') x ' +
'option (keepfixed plan); ' +
'' +
case @return_schema
when 1 then
'set @schema = ' +
'''create table <table_name> ( '' + ' +
'stuff ' +
'( ' +
'( ' +
'select ' +
''','' + ' +
'quotename(column_name) + '' '' + ' +
'data_type + ' + 
'case ' +
'when data_type like ''%char'' then ''('' + coalesce(nullif(convert(varchar, character_maximum_length), ''-1''), ''max'') + '') '' ' +
'else '' '' ' +
'end + ' +
'case is_nullable ' +
'when ''no'' then ''not '' ' +
'else '''' ' +
'end + ''null'' as [text()] ' +
'from tempdb.information_schema.columns ' +
'where ' +
'table_name = (select name from tempdb.sys.objects where object_id = object_id(''tempdb..#session_schema'')) ' +
'order by ' +
'ordinal_position ' +
'for xml ' +
'path('''') ' +
'), + ' +
'1, ' +
'1, ' +
''''' ' +
') + ' +
''')''; ' 
else ''
end
--end derived table and insert specification
);
set @sql_n = convert(nvarchar(max), @sql);
exec sp_executesql
@sql_n,
n'@schema varchar(max) output',
@schema output;
end;
go

 

(0)
上一篇 2022年3月21日
下一篇 2022年3月21日

相关推荐