Need help finding out the space used by the table

  • I need to find out the size of the data in the table as well as the total table size. I need to do it programatically. Is there any sys SP or any other thing through whic I can get these results?

    Ragrds,

    Nawaz.

  • How about http://msdn.microsoft.com/en-us/library/ms188776.aspx

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Thank u Very Much

  • I've not tried this in 2008, yet, but it did a dandy job in SQL Server 2005. A lot of the tables I referenced are legacy tables that are on their way out but I never bothered to change them from when I wrote this for SQL Server 2000.

    --_______________________________________________________________________________________________________________________

    /**********************************************************************************************************************

    Purpose:

    Returns a single result set similar to sp_Space used for all user tables at once.

    Notes:

    1. May be used as a view, stored procedure, or table-valued funtion.

    2. Must comment out 1 "Schema" in the SELECT list below prior to use. See the adjacent comments for more info.

    Revision History:

    Rev 00 - 22 Jan 2007 - Jeff Moden

    - Initital creation for SQL Server 2000

    Rev 01 - 11 Mar 2007 - Jeff Moden

    - Add automatic page size determination for future compliance

    Rev 02 - 05 Jan 2008 - Jeff Moden

    - Change "Owner" to "Schema" in output. Add optional code per Note 2 to find correct schema name

    **********************************************************************************************************************/

    --===== Ensure that all row counts, etc is up to snuff

    -- Obviously, this will not work in a view or UDF and should be removed if in a view or UDF. External code should

    -- execute the command below prior to retrieving from the view or UDF.

    DBCC UPDATEUSAGE(0) WITH COUNT_ROWS, NO_INFOMSGS

    --===== Return the single result set similar to what sp_SpaceUsed returns for a table, but more

    SELECT DBName = DB_NAME(),

    SchemaName = SCHEMA_NAME(so.UID), --Comment out if for SQL Server 2000

    --SchemaName = USER_NAME(so.UID), --Comment out if for SQL Server 2005

    TableName = so.Name,

    TableID = so.ID,

    MinRowSize = MIN(si.MinLen),

    MaxRowSize = MAX(si.XMaxLen),

    ReservedKB = SUM(CASE WHEN si.IndID IN (0,1,255) THEN si.Reserved ELSE 0 END) * pkb.PageKB,

    DataKB = SUM(CASE WHEN si.IndID IN (0,1 ) THEN si.DPages ELSE 0 END) * pkb.PageKB

    + SUM(CASE WHEN si.IndID IN ( 255) THEN ISNULL(si.Used,0) ELSE 0 END) * pkb.PageKB,

    IndexKB = SUM(CASE WHEN si.IndID IN (0,1,255) THEN si.Used ELSE 0 END) * pkb.PageKB

    - SUM(CASE WHEN si.IndID IN (0,1 ) THEN si.DPages ELSE 0 END) * pkb.PageKB

    - SUM(CASE WHEN si.IndID IN ( 255) THEN ISNULL(si.Used,0) ELSE 0 END) * pkb.PageKB,

    UnusedKB = SUM(CASE WHEN si.IndID IN (0,1,255) THEN si.Reserved ELSE 0 END) * pkb.PageKB

    - SUM(CASE WHEN si.IndID IN (0,1,255) THEN si.Used ELSE 0 END) * pkb.PageKB,

    Rows = SUM(CASE WHEN si.IndID IN (0,1 ) THEN si.Rows ELSE 0 END),

    RowModCtr = MIN(si.RowModCtr),

    HasTextImage = MAX(CASE WHEN si.IndID IN ( 255) THEN 1 ELSE 0 END),

    HasClustered = MAX(CASE WHEN si.IndID IN ( 1 ) THEN 1 ELSE 0 END)

    FROM dbo.SysObjects so,

    dbo.SysIndexes si,

    (--Derived table finds page size in KB according to system type

    SELECT Low/1024 AS PageKB --1024 is a binary Kilo-byte

    FROM Master.dbo.spt_Values

    WHERE Number = 1 --Identifies the primary row for the given type

    AND Type = 'E' --Identifies row for system type

    ) pkb

    WHERE si.ID = so.ID

    AND si.IndID IN (0, --Table w/o Text or Image Data

    1, --Table with clustered index

    255) --Table w/ Text or Image Data

    AND so.XType = 'U' --User Tables

    AND PERMISSIONS(so.ID) <> 0

    GROUP BY so.Name,

    so.UID,

    so.ID,

    pkb.PageKB

    ORDER BY ReservedKB DESC

    ;

    --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)

  • You Can these scripts to find the table spaces on the server

    SELECT OBJECT_NAME(OBJECT_ID) TableName, st.row_count

    FROM sys.dm_db_partition_stats st

    WHERE index_id < 2

    ORDER BY st.row_count DESC

    GO

    SELECT * FROM THOURS

    SELECT OBJECT_NAME(OBJECT_ID) AS DatabaseName, last_user_update,*

    FROM sys.dm_db_index_usage_stats

    WHERE database_id = DB_ID( 'Opus_db')

    AND OBJECT_ID=OBJECT_ID('TDF_BEFLOW_INVENTORY_IMPORT_PREVIOUS')

  • exec sp_spaceused 'tablename'

  • By Using these scripts we can know the large space tables on the database.

    Thanks SQLDBA Arjun for providing this

  • SQLDBA ARJUN (2/29/2012)


    You Can these scripts to find the table spaces on the server

    SELECT OBJECT_NAME(OBJECT_ID) TableName, st.row_count

    FROM sys.dm_db_partition_stats st

    WHERE index_id < 2

    ORDER BY st.row_count DESC

    GO

    SELECT * FROM THOURS

    SELECT OBJECT_NAME(OBJECT_ID) AS DatabaseName, last_user_update,*

    FROM sys.dm_db_index_usage_stats

    WHERE database_id = DB_ID( 'Opus_db')

    AND OBJECT_ID=OBJECT_ID('TDF_BEFLOW_INVENTORY_IMPORT_PREVIOUS')

    --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)

  • Post withdrawn. I posted to the wrong thread.

    --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 9 posts - 1 through 8 (of 8 total)

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