Last active
June 30, 2017 01:07
-
-
Save yang-qu/68be29f0a3dd46ea1ba2 to your computer and use it in GitHub Desktop.
get tables size in sql server 2008 ~ 2014
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
| --size in KB | |
| SELECT | |
| s.Name AS SchemaName, | |
| t.NAME AS TableName, | |
| 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.schemas s ON s.schema_id = t.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 | |
| WHERE | |
| t.NAME NOT LIKE 'dt%' | |
| AND t.is_ms_shipped = 0 | |
| AND i.OBJECT_ID > 255 | |
| GROUP BY | |
| t.Name, s.Name, p.Rows | |
| ORDER BY | |
| s.Name, t.Name | |
| -- size in MB | |
| SELECT | |
| t.NAME AS TableName, | |
| s.Name AS SchemaName, | |
| p.rows AS RowCounts, | |
| CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS TotalSpaceMB, | |
| CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS UsedSpaceMB, | |
| CAST(ROUND(((SUM(a.total_pages) - SUM(a.used_pages)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSpaceMB | |
| 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.NAME NOT LIKE 'dt%' | |
| AND t.is_ms_shipped = 0 | |
| AND i.OBJECT_ID > 255 | |
| GROUP BY | |
| t.Name, s.Name, p.Rows | |
| ORDER BY | |
| TotalSpaceMB desc |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment