Skip to content

Commit

Permalink
no message
Browse files Browse the repository at this point in the history
  • Loading branch information
MasayukiOzawa committed Nov 14, 2018
1 parent 975ecc4 commit cbf5daf
Show file tree
Hide file tree
Showing 3 changed files with 160 additions and 2 deletions.
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
-- ����̃N�G���̃X�e�[�g�����g���擾
-- 特定のクエリのステートメントを取得
WITH XMLNAMESPACES (DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan' )
SELECT
T2.Stmt.query('data(./@StatementId)') AS StatementId,
Expand Down Expand Up @@ -26,7 +26,7 @@ CROSS APPLY query_plan.nodes('//StmtSimple') AS T2(Stmt);
GO


-- ����̃N�G���̑�����擾
-- 特定のクエリの操作を取得
WITH XMLNAMESPACES (DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan' )
SELECT
T2.Stmt.query('data(./@NodeId)') AS NodeId,
Expand Down
63 changes: 63 additions & 0 deletions Query/拡張イベントを使用したクエリトレース.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
/*
CREATE EVENT SESSION [LiveTrace] ON DATABASE
ADD EVENT sqlserver.rpc_starting(SET collect_statement=(1)
ACTION(sqlserver.client_app_name,sqlserver.client_hostname,sqlserver.database_id,sqlserver.database_name,sqlserver.session_id,sqlserver.sql_text,sqlserver.username)),
ADD EVENT sqlserver.sql_batch_starting(SET collect_batch_text=(1)
ACTION(sqlserver.client_app_name,sqlserver.client_hostname,sqlserver.database_id,sqlserver.database_name,sqlserver.session_id,sqlserver.sql_text,sqlserver.username))
ADD TARGET package0.ring_buffer(SET max_memory=(102400))
WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_MULTIPLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS,MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF)
GO
ALTER EVENT SESSION [LiveTrace] ON DATABASE STATE=START
ALTER EVENT SESSION [LiveTrace] ON DATABASE STATE=STOP
*/

DROP TABLE IF EXISTS #tmp
GO
SELECT
'1' AS No,
CAST(xt.target_data AS XML) AS target_data
INTO #tmp
FROM
sys.dm_xe_database_sessions AS xs
LEFT JOIN
sys.dm_xe_database_session_targets AS xt
ON
xs.address = xt.event_session_address
WHERE
xs.name = 'LiveTrace'


ALTER TABLE #tmp ALTER COLUMN No int NOT NULL
ALTER TABLE #tmp ADD CONSTRAINT PK_Tmp PRIMARY KEY CLUSTERED(No)
CREATE PRIMARY XML INDEX PIdx_Tmp_target_Data ON #tmp(target_data)

SELECT
TimeStamp,
name,
[session_id],
[client_hostname],
[client_app_name],
[sql_text]
FROM
(
SELECT
T2.val.value('parent::*/@timestamp', 'datetime2(3)') AS TimeStamp,
T2.val.value('parent::*/@name', 'varchar(255)') AS name,
T2.val.value('@name', 'varchar(255)') AS action_name,
T2.val.value('(./value)[1]', 'varchar(max)') AS text
-- ,T2.val.query('.') AS xml

FROM
#tmp
CROSS APPLY target_data.nodes('/RingBufferTarget/event/action') AS T2 (val)
) AS LiveTrace
PIVOT(
MAX(text)
FOR action_name IN([session_id], [sql_text], [client_hostname], [client_app_name])
) AS PV
WHERE
session_id <> @@SPID
ORDER BY
TimeStamp DESC
Original file line number Diff line number Diff line change
@@ -0,0 +1,95 @@
/*
SELECT * FROM sys.database_scoped_configurations
ALTER DATABASE SCOPED CONFIGURATION SET LIGHTWEIGHT_QUERY_PROFILING=OFF
ALTER DATABASE SCOPED CONFIGURATION SET LIGHTWEIGHT_QUERY_PROFILING=ON
*/

SELECT
T.session_id,
er.command,
er.status,
SUBSTRING(st.text, (qsx.statement_start_offset/2)+1,
((CASE qsx.statement_end_offset
WHEN -1 THEN DATALENGTH(st.text)
ELSE qsx.statement_end_offset
END - qsx.statement_start_offset)/2) + 1) AS statement_text,
st.text,
er.last_wait_type,
er.wait_resource,
qsx.query_plan AS qsx_query_plan,
qp.query_plan AS qp_query_plan
FROM
(
SELECT DISTINCT
session_id
FROM
sys.dm_exec_query_profiles
WHERE
session_id <> @@SPID
) AS T
LEFT JOIN sys.dm_exec_requests AS er ON er.session_id = T.session_id
OUTER APPLY sys.dm_exec_query_statistics_xml(T.session_id) AS qsx
OUTER APPLY sys.dm_exec_sql_text(qsx.sql_handle) AS st
OUTER APPLY sys.dm_exec_query_plan(qsx.plan_handle) AS qp
GO


SELECT
qp.session_id,
qp.request_id,
er.command,
er.status,
qp.physical_operator_name,
DB_NAME(qp.database_id) AS database_name,
OBJECT_NAME(qp.object_id) AS object_name,
ix.name AS index_name,
OBJECT_NAME(page_info.object_id) AS object_name,
ix.name,
page_info.partition_id,
page_info.alloc_unit_id,
page_info.slot_count,
page_info.free_bytes,
qp.node_id,
qp.thread_id,
qp.estimate_row_count,
qp.row_count,
qp.rewind_count,
qp.rebind_count,
qp.end_of_scan_count,
qp.first_active_time,
qp.last_active_time,
qp.open_time,
qp.first_row_time,
qp.last_row_time,
qp.close_time,
qp.elapsed_time_ms,
qp.cpu_time_ms,
qp.scan_count,
qp.logical_read_count,
qp.physical_read_count,
qp.read_ahead_count,
qp.actual_read_row_count,
qp.estimated_read_row_count,
qp.write_page_count,
qp.lob_logical_read_count,
qp.lob_physical_read_count,
qp.lob_read_ahead_count,
qp.segment_read_count,
qp.segment_skip_count,
page_info.database_id,
page_info.page_id,
page_info.page_type,
page_info.page_type_desc,
page_info.page_level
FROM
sys.dm_exec_query_profiles AS qp
LEFT JOIN sys.indexes AS ix ON ix.object_id = qp.object_id AND ix.index_id = qp.index_id
LEFT JOIN sys.dm_exec_requests AS er ON er.session_id = qp.session_id
OUTER APPLY sys.fn_PageResCracker (er.page_resource) AS r
OUTER APPLY sys.dm_db_page_info(COALESCE(r.db_id, 0), r.file_id, r.page_id, DEFAULT) AS page_info
WHERE
qp.session_id <> @@SPID
ORDER BY
qp.session_id ASC,
qp.node_id ASC
GO

0 comments on commit cbf5daf

Please sign in to comment.