반응형
SQL Server 모든 테이블 크기를 조회하는 쿼리
테이블의 건수와, 테이블에 구성된 인덱스들의 합도 같이 확인할 수 있습니다.
SELECT
OBJECT_SCHEMA_NAME(a2.object_id) AS SchemaName,
a2.name AS TableName,
a1.rows as [RowCount],
CAST(ROUND(((a1.reserved + ISNULL(a4.reserved,0)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS ReservedSize_MB,
CAST(ROUND(a1.data * 8 / 1024.00, 2) AS NUMERIC(36, 2)) AS DataSize_MB,
CAST(ROUND((CASE WHEN (a1.used + ISNULL(a4.used,0)) > a1.data THEN (a1.used + ISNULL(a4.used,0)) - a1.data ELSE 0 END) * 8 / 1024.00, 2) AS NUMERIC(36, 2)) AS IndexSize_MB,
CAST(ROUND((CASE WHEN (a1.reserved + ISNULL(a4.reserved,0)) > a1.used THEN (a1.reserved + ISNULL(a4.reserved,0)) - a1.used ELSE 0 END) * 8 / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSize_MB
FROM
(SELECT
ps.object_id,
SUM (CASE WHEN (ps.index_id < 2) THEN row_count ELSE 0 END) AS [rows],
SUM (ps.reserved_page_count) AS reserved,
SUM (CASE
WHEN (ps.index_id < 2) THEN (ps.in_row_data_page_count + ps.lob_used_page_count + ps.row_overflow_used_page_count)
ELSE (ps.lob_used_page_count + ps.row_overflow_used_page_count)
END
) AS data,
SUM (ps.used_page_count) AS used
FROM sys.dm_db_partition_stats ps
GROUP BY ps.object_id) AS a1
LEFT OUTER JOIN
(SELECT
it.parent_id,
SUM(ps.reserved_page_count) AS reserved,
SUM(ps.used_page_count) AS used
FROM sys.dm_db_partition_stats ps
INNER JOIN sys.internal_tables it ON (it.object_id = ps.object_id)
WHERE it.internal_type IN (202,204)
GROUP BY it.parent_id) AS a4 ON (a4.parent_id = a1.object_id)
INNER JOIN sys.all_objects a2 ON ( a1.object_id = a2.object_id )
WHERE a2.type <> N'S' and a2.type <> N'IT'
ORDER BY ReservedSize_MB DESC
반응형
'프로그래밍 > DataBase' 카테고리의 다른 글
[MSSQL] STRING_SPLIT(Transact-SQL) 지정된 구분 기호 문자에 따라 문자열을 부분 문자열의 행으로 분할하는 테이블 반환 함수 (0) | 2023.01.17 |
---|---|
[Database] MSSQL 링크드서버, linked server (0) | 2022.11.02 |
[MSSQL] DB 복구모델 - 전체(Full) 로 변경 (0) | 2022.11.02 |
[MSSQL] Sub Query 서브쿼리에서 정렬하기 (0) | 2022.08.25 |
[MSSQL] SSMS(SQL Server Management Studio) 다운로드 (0) | 2022.07.15 |