これだけはやっておけ

これやってないシステムは万死に値するので、とにかくやっておけ

  1. MAX DOPの設定
    1/4 or 1/2×物理CPU数(物理コア数)
    NUMA構成なら、NUMA内の物理コア数
    ※HTとかの論理数ではない
  2. tempdbのデータファイルの分割
    CPUのコア数と同じにする
  3. SQL Serverアカウントにメモリ内のページロックの権限を付与
    • SQL Server 2008 R2 Stdでは、トレースフラグ845も付与

tempdbの移動

  1. tempdb の確認
    SELECT name, physical_name, state_desc
    FROM sys.master_files
    WHERE database_id = DB_ID(N'tempdb');
    GO
  2. パスの変更
    USE master;
    GO
    ALTER DATABASE tempdb 
    MODIFY FILE (NAME = tempdev, FILENAME = 'D:\SQLServer\tempdb\tempdb.mdf');
    GO
    ALTER DATABASE tempdb 
    MODIFY FILE (NAME = templog, FILENAME = 'D:\SQLServer\tempdb\templog.ldf');
    GO
  3. SQL Serverの再起動
  4. 確認
    SELECT name, physical_name, state_desc
    FROM sys.master_files
    WHERE database_id = DB_ID(N'tempdb');

リストア後のユーザ補正

  • レポート
    USE <database>
    EXEC sp_change_users_login 'Report'
  • 補正
    USE <database>
    EXEC sp_change_users_login 'Update_One', '不明なユーザー名', '新環境ユーザー名'

オブジェクト(テーブルとか)の所有者変更

sp_changeobjectowner OBJECT_NAME, OWNER_NAME

欠落インデックスのレポート

  • これで、ある程度不足しているインデックスがわかる
    SELECT 
    migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans) cost_impact
    ,migs.avg_total_user_cost
    ,migs.avg_user_impact
    ,migs.user_seeks
    ,migs.user_scans
    ,mid.statement
    ,mid.equality_columns
    ,mid.inequality_columns
    ,mid.included_columns
    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 in
    (
    SELECT TOP 50 group_handle
    FROM sys.dm_db_missing_index_group_stats
    ORDER BY avg_total_user_cost * avg_user_impact * (user_seeks + user_scans) DESC
    )
    ORDER BY migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans) DESC

インデックス一覧

select
i.name  as indes_name
, ob.name as table_name
, col.name as column_name
, ix.id
, ix.indid
, ix.keyno
from
sysindexkeys ix
, sysobjects ob
, syscolumns col
, sysindexes i
where
ix.id = ob.id
and ix.id = col.id
and ix.colid = col.colid
and i.id = ix.id
and i.indid = ix.indid
and ob.xtype in ('U','PK')
order by ob.name,ob.xtype,i.name,ix.id,ix.indid,ix.keyno

テーブル使用容量

BEGIN

  DECLARE @tablename VARCHAR(256)
  declare @id int
        declare @rows int, @datasizeused int, @indexsizeused int, @pagesize int

  DECLARE tablelist CURSOR FOR
        SELECT Name FROM Sys.Tables ORDER BY Name

  SET NOCOUNT ON

        CREATE TABLE #table_size (
                 TABLE_NAME VARCHAR(256)
                ,ROWS INT
                ,DATA_SIZE INT
                ,INDEX_SIZE INT
        )

        select @pagesize = v.low / 1024 from master..spt_values v where v.number=1 and v.type=N'E'

  OPEN tablelist

  FETCH NEXT FROM tablelist INTO @tablename
  WHILE @@FETCH_STATUS = 0
  BEGIN
        select @id = id from dbo.sysobjects where id = object_id(@tablename) and (OBJECTPROPERTY(id, N'IsTable') = 1)

        /* rows */
        SELECT @rows = convert(int, rowcnt)
                FROM dbo.sysindexes
                WHERE indid < 2 and id = @id

        /* data */
        SELECT @datasizeused =
                SUM(CASE WHEN a.type <> 1 THEN a.used_pages
                                WHEN p.index_id < 2 THEN a.data_pages
                                ELSE 0
                        END)
        FROM sys.indexes as i
        JOIN sys.partitions as p ON p.object_id = i.object_id and p.index_id = i.index_id
        JOIN sys.allocation_units as a ON a.container_id = p.partition_id
        where i.object_id = @id

        /* index */
        SELECT @indexsizeused =
                sum(isnull(sidx.used,0)-isnull(sidx.dpages,0))
                FROM dbo.sysindexes sidx
                WHERE sidx.indid < 2 and sidx.id = @id


        insert into #table_size
        values( @tablename, @rows, @datasizeused* @pagesize, @indexsizeused*@pagesize)

        FETCH NEXT FROM tablelist INTO @tablename
  END

        SELECT * FROM #table_size
drop table #table_size
  --(5)終了処理
  DEALLOCATE tablelist

END

Agent XPs の設定

  • SQL Server エージェントの拡張ストアド プロシージャを使用できるようにする
    sp_configure 'show advanced options', 1;
    GO
    RECONFIGURE;
    GO
    sp_configure 'Agent XPs', 1;
    GO
    RECONFIGURE
    GO

タブ区切りファイルのインポート

bcp database_name.dbo.table_name in filename.txt -Uuser -Ppass -Sserver -c

indesの再構築と再編成

use <databasename>
go


SET NOCOUNT ON;
DECLARE @objectid int;
DECLARE @indexid int;
DECLARE @partitioncount bigint;
DECLARE @schemaname nvarchar(130); 
DECLARE @objectname nvarchar(130); 
DECLARE @indexname nvarchar(130); 
DECLARE @partitionnum bigint;
DECLARE @partitions bigint;
DECLARE @frag float;
DECLARE @command nvarchar(4000); 

SELECT
    object_id AS objectid,
    index_id AS indexid,
    partition_number AS partitionnum,
    avg_fragmentation_in_percent AS frag
INTO #work_to_do
FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')
WHERE avg_fragmentation_in_percent > 10.0 AND index_id > 0;

DECLARE partitions CURSOR FOR SELECT * FROM #work_to_do;

OPEN partitions;

WHILE (1=1)
    BEGIN;
        FETCH NEXT
           FROM partitions
           INTO @objectid, @indexid, @partitionnum, @frag;
           
        IF @@FETCH_STATUS < 0 BREAK;
        
        SELECT @objectname = QUOTENAME(o.name), @schemaname = QUOTENAME(s.name)
        FROM sys.objects AS o
        JOIN sys.schemas as s ON s.schema_id = o.schema_id
        WHERE o.object_id = @objectid;
        
        SELECT @indexname = QUOTENAME(name)
        FROM sys.indexes
        WHERE  object_id = @objectid AND index_id = @indexid;
        
        SELECT @partitioncount = count (*)
        FROM sys.partitions
        WHERE object_id = @objectid AND index_id = @indexid;

        IF @frag < 30.0
            SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REORGANIZE';
        IF @frag >= 30.0
--            SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REBUILD WITH (ONLINE = ON)';  -- Enterprize
            SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REBUILD';  -- Standard
        IF @partitioncount > 1
            SET @command = @command + N' PARTITION=' + CAST(@partitionnum AS nvarchar(10));
        EXEC (@command);
        PRINT N'Executed(' + CAST (@frag as nvarchar) +'): ' + @command;
    END;

CLOSE partitions;
DEALLOCATE partitions;

DROP TABLE #work_to_do;
GO





トップ   編集 凍結 差分 バックアップ 添付 複製 名前変更 リロード   新規 一覧 単語検索 最終更新   ヘルプ   最終更新のRSS
Last-modified: Thu, 03 Apr 2014 10:36:55 JST (1300d)