forked from MasayukiOzawa/SQLServer-Util
-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
統計情報の更新と、In-Memory OLTP のファイルを UTF-8 で保存
- Loading branch information
1 parent
5c363d9
commit aa8fb10
Showing
6 changed files
with
93 additions
and
15 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,6 +1,6 @@ | ||
SELECT * FROM sys.dm_db_xtp_gc_cycle_stats | ||
SELECT * FROM sys.dm_db_xtp_gc_cycle_stats | ||
SELECT * FROM sys.dm_xtp_gc_queue_stats | ||
SELECT * FROM sys.dm_xtp_gc_stats | ||
|
||
-- Žè“®‚Ì GC ŽÀs | ||
-- 手動の GC 実行 | ||
EXEC sys.sp_xtp_checkpoint_force_garbage_collection |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,78 @@ | ||
SET NOCOUNT ON | ||
GO | ||
|
||
DECLARE @stats TABLE( | ||
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 | ||
) | ||
DECLARE @object_name sysname, @stats_name sysname | ||
|
||
DECLARE stats_cursor CURSOR FOR | ||
SELECT | ||
OBJECT_SCHEMA_NAME(s.object_id) + '.' + OBJECT_NAME(s.object_id), s.name | ||
FROM | ||
sys.stats AS s | ||
INNER JOIN | ||
sys.all_objects o | ||
ON | ||
s.object_id = o.object_id | ||
AND | ||
o.is_ms_shipped = 0 | ||
WHERE | ||
OBJECTPROPERTY(s.object_id, 'IsSystemTable') =0 | ||
|
||
OPEN stats_cursor | ||
|
||
FETCH NEXT FROM stats_cursor | ||
INTO @object_name, @stats_name | ||
|
||
WHILE @@FETCH_STATUS = 0 | ||
BEGIN | ||
|
||
INSERT INTO @stats EXEC ('DBCC SHOW_STATISTICS(''' + @object_name + ''', ''' + @stats_name + ''') WITH HISTOGRAM, NO_INFOMSGS') | ||
INSERT INTO @results SELECT @object_name, @stats_name,* FROM @stats | ||
DELETE FROM @stats | ||
FETCH NEXT FROM stats_cursor | ||
INTO @object_name, @stats_name | ||
END | ||
|
||
CLOSE stats_cursor | ||
DEALLOCATE stats_cursor | ||
|
||
SELECT * FROM @results | ||
|
||
|
||
-- SQL Server v.Next 向けの統計情報のヒストグラム確認 | ||
SELECT | ||
OBJECT_SCHEMA_NAME(s.object_id) AS schema_name, | ||
object_name(s.object_id) AS object_name, | ||
s.name, | ||
sh.step_number, | ||
sh.range_high_key, | ||
sh.range_rows, | ||
sh.equal_rows, | ||
sh.distinct_range_rows, | ||
sh.average_range_rows | ||
FROM | ||
sys.stats s | ||
cross apply | ||
sys.dm_db_stats_histogram(object_id, stats_id) AS sh | ||
WHERE | ||
OBJECTPROPERTY(s.object_id, 'IsSystemTable') =0 | ||
ORDER BY | ||
object_name(s.object_id), | ||
name, | ||
step_number, | ||
range_high_key |