check DB statistics status

  • Hi All.

    Can any one tell me where and how to check DB statistics status on a particular server.

    And is there any way to see that it was last updated and much more details about the db statistice.

    Atlast how to update the statistics of a DB

    Regards,

    Sandhya

  • For a over view of DB statistics please read

    ms-help://MS.SQLCC.v9/MS.SQLSVR.v9.en/tsqlref9/html/919158f2-38d0-4f68-82ab-e1633bd0d308.htm

    To determine the statistics for a particular table or view use:

    To display a report on the indexes of an object, execute sp_helpindex and specify the table or view name.

    If everything seems to be going well, you have obviously overlooked something.

    Ron

    Please help us, help you -before posting a question please read[/url]
    Before posting a performance problem please read[/url]

  • You can also query the sys.stats DMV to findout information about what statistics exist on particular tables. You can join it to the sys.stats_columns DMV to get column info.

    Jonathan Kehayias | Principal Consultant | MCM: SQL Server 2008
    My Blog | Twitter | MVP Profile
    Training | Consulting | Become a SQLskills Insider
    Troubleshooting SQL Server: A Guide for Accidental DBAs[/url]

  • sandhyarao49 (1/1/2009)


    Hi All.

    Can any one tell me where and how to check DB statistics status on a particular server.

    And is there any way to see that it was last updated and much more details about the db statistice.

    Atlast how to update the statistics of a DB

    Regards,

    Sandhya

    ----------------------------------------------------------------------------

    SELECT name AS index_name,

    STATS_DATE(OBJECT_ID, index_id) AS statistics_update_date

    FROM sys.indexes

    --------------------------------------------------------------------------------

    ALTER PROCEDURE [dbo].[usp_Detail_Index_Stats] @table_name sysname

    AS

    ----------------------------------------------------------------------------------

    -- ******VARIABLE DECLARATIONS******

    ----------------------------------------------------------------------------------

    DECLARE @IndexTable TABLE

    (

    [Database] sysname, [Table] sysname, [Index Name] sysname NULL, index_id smallint,

    [object_id] INT, [Index Type] VARCHAR(20), [Alloc Unit Type] VARCHAR(20),

    [Avg Frag %] decimal(5,2), [Row Ct] bigint, [Stats Update Dt] datetime

    )

    DECLARE @dbid smallint --Database id for current database

    DECLARE @objectid INT --Object id for table being analyzed

    DECLARE @indexid INT --Index id for the target index for the STATS_DATE() function

    ----------------------------------------------------------------------------------

    -- ******VARIABLE ASSIGNMENTS******

    ----------------------------------------------------------------------------------

    SELECT @dbid = DB_ID(DB_NAME())

    SELECT @objectid = OBJECT_ID(@table_name)

    ----------------------------------------------------------------------------------

    -- ******Load @IndexTable with Index Metadata******

    ----------------------------------------------------------------------------------

    INSERT INTO @IndexTable

    (

    [Database], [Table], [Index Name], index_id, [object_id],

    [Index Type], [Alloc Unit Type], [Avg Frag %], [Row Ct]

    )

    SELECT

    DB_NAME() AS "Database"

    @table_name AS "Table"

    SI.NAME AS "Index Name"

    IPS.index_id, IPS.OBJECT_ID, --These fields included for joins only

    IPS.index_type_desc, --Heap, Non-clustered, or Clustered

    IPS.alloc_unit_type_desc, --In-row data or BLOB data

    CAST(IPS.avg_fragmentation_in_percent AS decimal(5,2)),

    IPS.record_count

    FROM sys.dm_db_index_physical_stats (@dbid, @objectid, NULL, NULL, 'sampled') IPS

    LEFT JOIN sys.sysindexes SI ON IPS.OBJECT_ID = SI.id AND IPS.index_id = SI.indid

    WHERE IPS.index_id <> 0

    ----------------------------------------------------------------------------------

    -- ******ADD STATISTICS INFORMATION******

    ----------------------------------------------------------------------------------

    DECLARE curIndex_ID CURSOR FOR

    SELECT I.index_id

    FROM @IndexTable I

    ORDER BY I.index_id

    OPEN curIndex_ID

    FETCH NEXT FROM curIndex_ID INTO @indexid

    WHILE @@FETCH_STATUS = 0

    BEGIN

    UPDATE @IndexTable

    SET [Stats Update Dt] = STATS_DATE(@objectid, @indexid)

    WHERE [object_id] = @objectid AND [index_id] = @indexid

    FETCH NEXT FROM curIndex_ID INTO @indexid

    END

    CLOSE curIndex_ID

    DEALLOCATE curIndex_ID

    ----------------------------------------------------------------------------------

    -- ******RETURN RESULTS******

    ----------------------------------------------------------------------------------

    SELECT I.[Database], I.[Table], I.[Index Name], "Index Type"=

    CASE I.[Index Type]

    WHEN 'NONCLUSTERED INDEX' THEN 'NCLUST'

    WHEN 'CLUSTERED INDEX' THEN 'CLUST'

    ELSE 'HEAP'

    END,

    I.[Avg Frag %], I.[Row Ct],

    CONVERT(VARCHAR, I.[Stats Update Dt], 110) AS "Stats Dt"

    FROM @IndexTable I

    ORDER BY I.[Index Type], I.[index_id]

    -------

    --------------------------------------------------------------------------------

    Query 1

    In this first query we are just using sys.dm_db_index_usage_stats and sys.objects to get a list of the indexes that have been used and how they are being used.

    SELECT DB_NAME(DATABASE_ID) AS DATABASENAME,

    OBJECT_NAME(B.OBJECT_ID) AS TABLENAME,

    INDEX_NAME = (SELECT NAME

    FROM SYS.INDEXES A

    WHERE A.OBJECT_ID = B.OBJECT_ID

    AND A.INDEX_ID = B.INDEX_ID),

    USER_SEEKS,

    USER_SCANS,

    USER_LOOKUPS,

    USER_UPDATES

    FROM SYS.DM_DB_INDEX_USAGE_STATS B

    INNER JOIN SYS.OBJECTS C

    ON B.OBJECT_ID = C.OBJECT_ID

    WHERE DATABASE_ID = DB_ID(DB_NAME())

    AND C.TYPE <> 'S'

    --------------------------------------------------------------------------------

    Query 2

    In this query we are listing each user table and all of the tables indexes that have not been used by using a NOT EXISTS against sys.dm_db_index_usage_stats.

    SELECT DB_NAME() AS DATABASENAME,

    OBJECT_NAME(B.OBJECT_ID) AS TABLENAME,

    B.NAME AS INDEXNAME,

    B.INDEX_ID

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    WHERE NOT EXISTS (SELECT *

    FROM SYS.DM_DB_INDEX_USAGE_STATS C

    WHERE B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID)

    AND A.TYPE <> 'S'

    ORDER BY 1, 2, 3

    --------------------------------------------------------------------------------

    Query 3

    In this query we are listing each user table, all of its indexes and the columns that make up the index. The issue with this query is that you have a row for each column in the index which could get confusing if you have a lot of indexes.

    SELECT A.NAME,

    B.NAME,

    C.KEY_ORDINAL,

    D.NAME

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S'

    ORDER BY 1, 2, 3

    --------------------------------------------------------------------------------

    Query 4

    In this query we use most of Query 3, but we are doing a PIVOT so we can see the index and the index columns in one row. This only accounts for 7 index columns, but it could easily be increased to handle more in the PIVOT operation. Here is another tip related to the use of PIVOT, Crosstab queries using PIVOT in SQL Server 2005. if you would like to better understand how PIVOT works.

    SELECT TABLENAME, INDEXNAME, INDEXID, [1] AS COL1, [2] AS COL2, [3] AS COL3,

    [4] AS COL4, [5] AS COL5, [6] AS COL6, [7] AS COL7

    FROM (SELECT A.NAME AS TABLENAME,

    B.NAME AS INDEXNAME,

    B.INDEX_ID AS INDEXID,

    D.NAME AS COLUMNNAME,

    C.KEY_ORDINAL

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S') P

    PIVOT

    (MIN(COLUMNNAME)

    FOR KEY_ORDINAL IN ( [1],[2],[3],[4],[5],[6],[7] ) ) AS PVT

    ORDER BY TABLENAME, INDEXNAME;

    --------------------------------------------------------------------------------

    Query 5

    In this query we tie in our PIVOT query above with sys.dm_db_index_usage_stats so we can look at only the indexes that have been used since the last time the stats were reset.

    SELECT TABLENAME, INDEXNAME, INDEX_ID, [1] AS COL1, [2] AS COL2, [3] AS COL3,

    [4] AS COL4, [5] AS COL5, [6] AS COL6, [7] AS COL7

    FROM (SELECT A.NAME AS TABLENAME,

    A.OBJECT_ID,

    B.NAME AS INDEXNAME,

    B.INDEX_ID,

    D.NAME AS COLUMNNAME,

    C.KEY_ORDINAL

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S') P

    PIVOT

    (MIN(COLUMNNAME)

    FOR KEY_ORDINAL IN ( [1],[2],[3],[4],[5],[6],[7] ) ) AS PVT

    WHERE EXISTS (SELECT OBJECT_ID,

    INDEX_ID

    FROM SYS.DM_DB_INDEX_USAGE_STATS B

    WHERE DATABASE_ID = DB_ID(DB_NAME())

    AND PVT.OBJECT_ID = B.OBJECT_ID

    AND PVT.INDEX_ID = B.INDEX_ID)

    ORDER BY TABLENAME, INDEXNAME;

    --------------------------------------------------------------------------------

    Query 6

    This query also uses the PIVOT query along with sys.dm_db_index_usage_stats so we can also see the stats on the indexes that have been used.

    SELECT PVT.TABLENAME, PVT.INDEXNAME, [1] AS COL1, [2] AS COL2, [3] AS COL3,

    [4] AS COL4, [5] AS COL5, [6] AS COL6, [7] AS COL7, B.USER_SEEKS,

    B.USER_SCANS, B.USER_LOOKUPS

    FROM (SELECT A.NAME AS TABLENAME,

    A.OBJECT_ID,

    B.NAME AS INDEXNAME,

    B.INDEX_ID,

    D.NAME AS COLUMNNAME,

    C.KEY_ORDINAL

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S') P

    PIVOT

    (MIN(COLUMNNAME)

    FOR KEY_ORDINAL IN ( [1],[2],[3],[4],[5],[6],[7] ) ) AS PVT

    INNER JOIN SYS.DM_DB_INDEX_USAGE_STATS B

    ON PVT.OBJECT_ID = B.OBJECT_ID

    AND PVT.INDEX_ID = B.INDEX_ID

    AND B.DATABASE_ID = DB_ID()

    ORDER BY TABLENAME, INDEXNAME;

    --------------------------------------------------------------------------------

    Query 7

    This last query allow us to see both used and unused indexes. Since the DMV sys.dm_db_index_usage_stats only tracks when an index is used it is hard to compare the used and unused indexes. The query below allows you to see all indexes to compare both used and unused indexes since the stats were collected by using a UNION.

    SELECT PVT.TABLENAME, PVT.INDEXNAME, PVT.INDEX_ID, [1] AS COL1, [2] AS COL2, [3] AS COL3,

    [4] AS COL4, [5] AS COL5, [6] AS COL6, [7] AS COL7, B.USER_SEEKS,

    B.USER_SCANS, B.USER_LOOKUPS

    FROM (SELECT A.NAME AS TABLENAME,

    A.OBJECT_ID,

    B.NAME AS INDEXNAME,

    B.INDEX_ID,

    D.NAME AS COLUMNNAME,

    C.KEY_ORDINAL

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S') P

    PIVOT

    (MIN(COLUMNNAME)

    FOR KEY_ORDINAL IN ( [1],[2],[3],[4],[5],[6],[7] ) ) AS PVT

    INNER JOIN SYS.DM_DB_INDEX_USAGE_STATS B

    ON PVT.OBJECT_ID = B.OBJECT_ID

    AND PVT.INDEX_ID = B.INDEX_ID

    AND B.DATABASE_ID = DB_ID()

    UNION

    SELECT TABLENAME, INDEXNAME, INDEX_ID, [1] AS COL1, [2] AS COL2, [3] AS COL3,

    [4] AS COL4, [5] AS COL5, [6] AS COL6, [7] AS COL7, 0, 0, 0

    FROM (SELECT A.NAME AS TABLENAME,

    A.OBJECT_ID,

    B.NAME AS INDEXNAME,

    B.INDEX_ID,

    D.NAME AS COLUMNNAME,

    C.KEY_ORDINAL

    FROM SYS.OBJECTS A

    INNER JOIN SYS.INDEXES B

    ON A.OBJECT_ID = B.OBJECT_ID

    INNER JOIN SYS.INDEX_COLUMNS C

    ON B.OBJECT_ID = C.OBJECT_ID

    AND B.INDEX_ID = C.INDEX_ID

    INNER JOIN SYS.COLUMNS D

    ON C.OBJECT_ID = D.OBJECT_ID

    AND C.COLUMN_ID = D.COLUMN_ID

    WHERE A.TYPE <> 'S') P

    PIVOT

    (MIN(COLUMNNAME)

    FOR KEY_ORDINAL IN ( [1],[2],[3],[4],[5],[6],[7] ) ) AS PVT

    WHERE NOT EXISTS (SELECT OBJECT_ID,

    INDEX_ID

    FROM SYS.DM_DB_INDEX_USAGE_STATS B

    WHERE DATABASE_ID = DB_ID(DB_NAME())

    AND PVT.OBJECT_ID = B.OBJECT_ID

    AND PVT.INDEX_ID = B.INDEX_ID)

    ORDER BY TABLENAME, INDEX_ID;

    --------------------------------------------------------------------------------

    _____________________________________________________________________________________________________________
    Paresh Prajapati
    ➡ +919924626601
    http://paresh-sqldba.blogspot.com/[/url]
    LinkedIn | Tweet Me | FaceBook | Brijj

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply