Skip to content

Commit

Permalink
統計情報用のクエリを追加
Browse files Browse the repository at this point in the history
  • Loading branch information
MasayukiOzawa committed Mar 18, 2018
1 parent b7479cd commit d4513ca
Show file tree
Hide file tree
Showing 2 changed files with 69 additions and 14 deletions.
36 changes: 22 additions & 14 deletions Statistics/統計情報のヒストグラムの確認.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,20 +2,20 @@
GO

DECLARE @stats TABLE(
RANGE_HI_KEY sql_variant,
RANGE_ROWS real,
EQ_ROWS real,
DISTINCT_RANGE_ROWS bigint,
AVG_RANGE_ROWS real
RANGE_HI_KEY sql_variant,
RANGE_ROWS real,
EQ_ROWS real,
DISTINCT_RANGE_ROWS bigint,
AVG_RANGE_ROWS real
)
DECLARE @results TABLE(
object_name sysname,
stats_name sysname,
RANGE_HI_KEY sql_variant,
RANGE_ROWS real,
EQ_ROWS real,
DISTINCT_RANGE_ROWS bigint,
AVG_RANGE_ROWS real
object_name sysname,
stats_name sysname,
RANGE_HI_KEY sql_variant,
RANGE_ROWS real,
EQ_ROWS real,
DISTINCT_RANGE_ROWS bigint,
AVG_RANGE_ROWS real
)
DECLARE @object_name sysname, @stats_name sysname

Expand Down Expand Up @@ -54,7 +54,7 @@ DEALLOCATE stats_cursor
SELECT * FROM @results


-- SQL Server v.Next 向けの統計情報のヒストグラム確認
-- SQL Server 2016 SP1 CU2 以降の統計情報のヒストグラム確認
SELECT
OBJECT_SCHEMA_NAME(s.object_id) AS schema_name,
object_name(s.object_id) AS object_name,
Expand All @@ -64,7 +64,15 @@ SELECT
sh.range_rows,
sh.equal_rows,
sh.distinct_range_rows,
sh.average_range_rows
sh.average_range_rows,
s.auto_created,
s.user_created,
s.no_recompute,
s.has_filter,
s.filter_definition,
s.is_temporary,
s.is_incremental,
STATS_DATE(s.object_id, s.stats_id) AS stats_date
FROM
sys.stats s
cross apply
Expand Down
47 changes: 47 additions & 0 deletions Statistics/統計情報情報の確認.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,47 @@
SELECT
OBJECT_NAME(s.object_id) AS object_name,
s.*,
SUBSTRING(sc.column_name, 1, LEN(sc.column_name) -1) AS column_name,
sp.*,
CASE sp.rows
WHEN 0 THEN 0
ELSE
CAST(CAST(sp.rows_sampled AS float) / sp.rows * 100 AS numeric(5,2))
END AS sampling_percent,
CASE sp.rows
WHEN 0 THEN 0
ELSE
CAST(CAST(sp.modification_counter AS float) / sp.rows * 100 AS numeric(5,2))
END AS modification_percent,
isp.*
FROM
sys.stats AS s
CROSS APPLY
sys.dm_db_stats_properties(s.object_id, s.stats_id) AS sp
OUTER APPLY
sys.dm_db_incremental_stats_properties(s.object_id, s.stats_id) AS isp
LEFT JOIN
sys.objects AS o
ON
o.object_id = s.object_id
CROSS APPLY
(
(SELECT
CAST(c.name AS varchar(255)) + ','
FROM
sys.stats_columns AS sc
LEFT JOIN
sys.columns AS c
ON
sc.object_id = c.object_id
AND
sc.column_id = c.column_id
WHERE
sc.object_id = s.object_id
AND
sc.stats_id = s.stats_id
FOR XML PATH ('')
)
) AS sc(column_name)
WHERE
o.is_ms_shipped = 0

0 comments on commit d4513ca

Please sign in to comment.