Lesson Learned #227: How much data is using my database per table
Published Jul 19 2022 08:34 AM 2,041 Views

Today, we worked on a service request that our customer reported an unusual space used by their database. Checking the space we identified the main cause of this.

 

Normally, we used to run the following query to obtain how much data are using the tables in my database 

 

 

SELECT 
    t.NAME AS TableName,
    s.Name AS SchemaName,
    p.rows AS RowCounts,
    SUM(a.total_pages) * 8 AS TotalSpaceKB, 
    SUM(a.used_pages) * 8 AS UsedSpaceKB, 
    (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB
FROM 
    sys.tables t
INNER JOIN      
    sys.indexes i ON t.OBJECT_ID = i.object_id
INNER JOIN 
    sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
INNER JOIN 
    sys.allocation_units a ON p.partition_id = a.container_id
LEFT OUTER JOIN 
    sys.schemas s ON t.schema_id = s.schema_id
WHERE t.is_ms_shipped = 0
    AND i.OBJECT_ID > 255 
GROUP BY 
    t.Name, s.Name, p.Rows
ORDER BY 
    t.Name

 

 

Jose_Manuel_Jurado_0-1658244186763.png

 

But, we need to pay attention also, to other tables that are "shipped" with SQL Server/Azure SQL considered like system tables like persistent_version_table (PVS ), Query Data Store etc are not included in this filter. 

 

So, at this time, we found that specific tables for PVS are using too much space and was needed to run a cleanup process. So, in this situation, I would like to suggest running the following query to obtain an overview about the space used including user and system tables.

 

 

SELECT 
    t.NAME AS TableName,
    s.Name AS SchemaName,
    p.rows AS RowCounts,
    SUM(a.total_pages) * 8 AS TotalSpaceKB, 
    SUM(a.used_pages) * 8 AS UsedSpaceKB, 
    (SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB,
	CASE t.is_ms_shipped WHEN 0 then 'User' ELSE 'System' END AS TypeTable
FROM sys.schemas s
INNER JOIN sys.objects t ON t.schema_id = s.schema_id
INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id
INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id
GROUP BY 
    t.Name, s.Name, t.is_ms_shipped, p.Rows
ORDER BY 
    t.Name

 

 

Enjoy!

Version history
Last update:
‎Jul 19 2022 08:36 AM
Updated by: