Find out the size of database tables, row count, data size, index growth

  • I want to create table and all columns. column names are database name, current date, row count, data size, index size.

    in this table i want to insert about all the tables above information for one particular database.

    I want to use DMV for this

    let me know if you have any question.

  • sys.databases

    sys.tables

    sys.indexes

    sys.dm_db_partition_stats

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • do you have a script for this or can you send me the script please?

  • Not offhand, no. It's not hard though, most of the data you want is in sys.dm_db_partition_stats, you just need to join to the others to get the names.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • This might be a good start.

    use MyDB

    go

    DECLARE @names TABLE

    (

    id INT IDENTITY(1,1),

    name NVARCHAR(100) NULL

    )

    DECLARE @ROWCOUNT INT

    DECLARE @i INT = 1

    DECLARE @STR nvarchar(100)

    INSERT INTO @names(name) SELECT name FROM sys.Tables

    SET @ROWCOUNT = @@ROWCOUNT

    DECLARE @space TABLE

    (

    name NVARCHAR(100) NULL,

    rows CHAR(11),

    reserved NVARCHAR (15),

    data NVARCHAR (18),

    indexes NVARCHAR (18),

    unused NVARCHAR (18)

    )

    WHILE @i <= @ROWCOUNT

    BEGIN

    SELECT @STR = name FROM @names WHERE id = @i

    INSERT INTO @space

    EXEC sp_spaceused @STR

    SET @i += 1

    END

    SELECT * FROM @space

    ORDER BY CONVERT( BIGINT, rows ) DESC

    ;

  • Thanks for the reply.

    this is now working out.

    can you help me with the script using dmv

    It creates table and insert all the tables information about specified database

  • tinakothari (11/18/2012)


    Thanks for the reply.

    this is now working out.

    can you help me with the script using dmv

    It creates table and insert all the tables information about specified database

    All of the information you seek is in the system objects that Gail Shaw noted in her post above. If you need the information you state, then you should understand that information, as well. The only way you'll understand all of that information is to read about each of those objects in Books Online and figure this one out on your own. You won't be sorry that you did. Think of it as a "rite of passage" that every DBA should go through. 😉 If you have problems during your attempt, I'm sure that folks would be happy to help you with specific prroblems instead of writing the entire query for you.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • tinakothari (11/18/2012)


    I want to create table and all columns. column names are database name, current date, row count, data size, index size.

    in this table i want to insert about all the tables above information for one particular database.

    I want to use DMV for this

    let me know if you have any question.

    You could try this

    SELECTDB_NAME() AS DatabaseName

    , object_name(i.object_id) AS TableName

    , ISNULL(i.name, 'HEAP') AS IndexName

    , i.index_id AS IndexID

    , i.type_desc AS IndexType

    , p.partition_number AS PartitionNo

    , p.[rows] AS NumRows

    , au.type_desc AS InType

    , au.total_pages AS NumPages

    , au.total_pages * 8 AS TotKBs

    , au.used_pages * 8 AS UsedKBs

    , au.data_pages * 8 AS DataKBs

    FROM sys.indexes i INNER JOIN sys.partitions p

    ON i.object_id = p.object_id AND i.index_id = p.index_id

    INNER JOIN sys.allocation_units au ON

    CASE

    WHEN au.[type] in (1,3) THEN p.hobt_id

    WHEN au.type = 2 THEN p.partition_id

    end = au.container_id

    INNER JOIN sys.objects o ON i.object_id = o.object_id

    WHERE o.is_ms_shipped <> 1

    ORDER BY TableName, i.index_id

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

    "Ya can't make an omelette without breaking just a few eggs" 😉

  • This is a very handy script, Thank you very much for it. I updated the script to handle tables in different schema's. I was using this today and found I have issues when the tables had different schema's.

    --

    use YourDatabaseName

    go

    --SELECT * FROM sys.Tables

    --SELECT @@SERVERNAME;

    --SELECT DB_NAME() AS DataBaseName;

    DECLARE @names TABLE

    (

    id INT IDENTITY(1, 1)

    , name NVARCHAR(100) NULL

    );

    DECLARE @ROWCOUNT INT;

    DECLARE @i INT = 1;

    DECLARE @STR NVARCHAR(100);

    INSERT INTO @names

    ( name

    )

    SELECT SCHEMA_NAME(schema_id) + '.' + name

    FROM sys.tables;

    --INSERT INTO @names(name) SELECT name FROM sys.Tables RebuttalStatusHistory ReviewHistory

    SET @ROWCOUNT = @@ROWCOUNT;

    DECLARE @space TABLE

    (

    name NVARCHAR(100) NULL

    , rows CHAR(11)

    , reserved NVARCHAR(15)

    , data NVARCHAR(18)

    , indexes NVARCHAR(18)

    , unused NVARCHAR(18)

    );

    WHILE @i <= @ROWCOUNT

    BEGIN

    SELECT @STR = name

    FROM @names

    WHERE id = @i;

    INSERT INTO @space

    EXEC sp_spaceused @STR;

    SET @i += 1;

    END;

    SELECT *

    FROM @space

    ORDER BY CONVERT(BIGINT, rows) DESC;

  • mark.the.dba (6/1/2015)


    I updated the script to handle tables in different schema's. I was using this today and found I have issues when the tables had different schema's.

    I hope they were all good issues because, if they were bad, you haven't given us a clue as to what the issues were.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • mark.the.dba (6/1/2015)


    I updated the script to handle tables in different schema's. I was using this today and found I have issues when the tables had different schema's.

    /quote]

    I hope they were all good issues because, if they were bad, you haven't given us a clue as to what the issues were.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 11 posts - 1 through 10 (of 10 total)

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