Skip to content

Commit

Permalink
プランキャッシュ操作用の XQuery のサンプルを追加
Browse files Browse the repository at this point in the history
  • Loading branch information
MasayukiOzawa committed Nov 4, 2018
1 parent f8c34a0 commit 975ecc4
Show file tree
Hide file tree
Showing 2 changed files with 61 additions and 2 deletions.
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
-- 実行プランを XML インデックスで検索するため、物理テーブルに格納
-- 実行プランを XML インデックスで検索するため、物理テーブルに格納
-- 検索性能が遅くてもよいのであれば、検索クエリの FROM 句に指定することも可能
DROP TABLE IF EXISTS #tmp
GO
Expand All @@ -14,9 +14,14 @@ OUTER APPLY
sys.dm_exec_query_plan(plan_handle)
OUTER APPLY
sys.dm_exec_sql_text(sql_handle)
GO

ALTER TABLE #tmp ALTER COLUMN No int NOT NULL
ALTER TABLE #tmp ADD CONSTRAINT PK_Tmp PRIMARY KEY CLUSTERED(No)
GO
ALTER TABLE #tmp ADD CONSTRAINT PK_Tmp_Query PRIMARY KEY CLUSTERED(No)
GO
CREATE PRIMARY XML INDEX PIdx_Tmp_Query ON #tmp(query_plan)
GO

-- 実行プランから特定のテーブルの全件検索を実施しているクエリを取得
DECLARE @TableName sysname = QUOTENAME('LINEITEM')
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,54 @@
-- ����̃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,
T2.Stmt.value('fn:local-name(.)', 'varchar(200)') AS local_name,
T2.Stmt.query('data(./@StatementText)') AS StatementText,
T2.Stmt.query('data(./QueryPlan/@CachedPlanSize)') AS CachedPlanSize,
T2.Stmt.query('data(./QueryPlan/@CompileTime)') AS CompileTime,
T.query_plan.value('(/ShowPlanXML/@Build)[1]', 'varchar(18)') AS Build,
T.query_hash,
T.query_plan_hash
FROM
(
SELECT TOP 1
query_hash,
query_plan_hash,
text,
query_plan
FROM sys.dm_exec_query_stats
OUTER APPLY
sys.dm_exec_query_plan(plan_handle)
OUTER APPLY
sys.dm_exec_sql_text(sql_handle)
) AS T
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,
T2.Stmt.value('fn:local-name(.)', 'varchar(200)') AS local_name,
T2.Stmt.query('data(./@PhysicalOp)') AS PhysicalOp,
T2.Stmt.query('data(./@LogicalOp)') AS LogicalOp,
T2.Stmt.query('data(./child::*/Object/@Table)') AS Table_Name,
T2.Stmt.query('data(./child::*/Object/@Index)') AS Index_Name,
T2.Stmt.query('data(./@EstimatedTotalSubtreeCost)') AS EstimatedTotalSubtreeCost,
T2.Stmt.query('.')
FROM
(
SELECT TOP 1
query_hash,
query_plan_hash,
text,
query_plan
FROM sys.dm_exec_query_stats
OUTER APPLY
sys.dm_exec_query_plan(plan_handle)
OUTER APPLY
sys.dm_exec_sql_text(sql_handle)
) AS T
CROSS APPLY query_plan.nodes('//RelOp') AS T2(Stmt);
GO

0 comments on commit 975ecc4

Please sign in to comment.