mirror of
https://dev.azure.com/effectory/Survey%20Software/_git/Cloud%20Engineering
synced 2026-02-27 18:52:18 +01:00
added documetation
This commit is contained in:
@@ -1,80 +1,156 @@
|
||||
/*
|
||||
================================================================================
|
||||
SQL SERVER DATABASE SIZE AND BACKUP ANALYSIS REPORT
|
||||
================================================================================
|
||||
|
||||
DESCRIPTION:
|
||||
Comprehensive analysis of SQL Server database sizes, space utilization,
|
||||
and backup information. This script provides detailed insights into:
|
||||
• Database file sizes (data and log files)
|
||||
• Actual space used vs. allocated space
|
||||
• Recovery model information
|
||||
• Latest backup information for both full and log backups
|
||||
• Backup size metrics including compression details
|
||||
|
||||
FEATURES:
|
||||
• Multi-database analysis across entire SQL Server instance
|
||||
• Real-time space usage calculation using dynamic SQL
|
||||
• Backup history analysis from msdb.backupset
|
||||
• Intelligent backup size reporting (compressed vs. uncompressed)
|
||||
• Results ordered by total database size (largest first)
|
||||
|
||||
OUTPUT COLUMNS:
|
||||
- database_id: SQL Server internal database identifier
|
||||
- name: Database name
|
||||
- state_desc: Database state (ONLINE, OFFLINE, etc.)
|
||||
- recovery_model_desc: Recovery model (FULL, SIMPLE, BULK_LOGGED)
|
||||
- total_size: Total allocated space (data + log files) in MB
|
||||
- data_size: Total allocated data file space in MB
|
||||
- data_used_size: Actual space used in data files in MB
|
||||
- log_size: Total allocated log file space in MB
|
||||
- log_used_size: Actual space used in log files in MB
|
||||
- full_last_date: Date/time of most recent full backup
|
||||
- full_size: Size of most recent full backup in MB
|
||||
- log_last_date: Date/time of most recent log backup
|
||||
- log_size: Size of most recent log backup in MB
|
||||
|
||||
USAGE SCENARIOS:
|
||||
• Database capacity planning and growth analysis
|
||||
• Storage optimization and space reclamation projects
|
||||
• Backup strategy review and optimization
|
||||
• Performance troubleshooting related to database size
|
||||
• Compliance reporting for backup procedures
|
||||
|
||||
TECHNICAL IMPLEMENTATION:
|
||||
• Uses temporary table to collect space usage across databases
|
||||
• Dynamic SQL generation to query each online database
|
||||
• Joins system catalog views (sys.databases, sys.master_files)
|
||||
• Integrates backup history from msdb.backupset
|
||||
• Handles compressed backup size calculations
|
||||
|
||||
PERMISSIONS REQUIRED:
|
||||
• VIEW SERVER STATE permission
|
||||
• Access to msdb database for backup history
|
||||
• Database access to calculate space usage (connects to each database)
|
||||
|
||||
COMPATIBILITY:
|
||||
• SQL Server 2008 R2 and later versions
|
||||
• Works with Azure SQL Database (with limited backup history)
|
||||
• Compatible with SQL Server on Linux
|
||||
|
||||
AUTHOR: Cloud Engineering Team
|
||||
CREATED: Database administration and monitoring toolkit
|
||||
UPDATED: Enhanced with comprehensive backup analysis and documentation
|
||||
|
||||
================================================================================
|
||||
*/
|
||||
|
||||
IF OBJECT_ID('tempdb.dbo.#space') IS NOT NULL
|
||||
DROP TABLE #space
|
||||
|
||||
-- Create temporary table to store actual space usage from each database
|
||||
CREATE TABLE #space (
|
||||
database_id INT PRIMARY KEY
|
||||
, data_used_size DECIMAL(18,2)
|
||||
, log_used_size DECIMAL(18,2)
|
||||
, data_used_size DECIMAL(18,2) -- Actual space used in data files (MB)
|
||||
, log_used_size DECIMAL(18,2) -- Actual space used in log files (MB)
|
||||
)
|
||||
|
||||
-- Variable to hold dynamically generated SQL for cross-database queries
|
||||
DECLARE @SQL NVARCHAR(MAX)
|
||||
|
||||
-- Generate dynamic SQL to collect actual space usage from each online database
|
||||
-- This approach is necessary because FILEPROPERTY() must be executed in the context of each database
|
||||
SELECT @SQL = STUFF((
|
||||
SELECT '
|
||||
USE [' + d.name + ']
|
||||
INSERT INTO #space (database_id, data_used_size, log_used_size)
|
||||
SELECT
|
||||
DB_ID()
|
||||
, SUM(CASE WHEN [type] = 0 THEN space_used END)
|
||||
, SUM(CASE WHEN [type] = 1 THEN space_used END)
|
||||
, SUM(CASE WHEN [type] = 0 THEN space_used END) -- Data files (type = 0)
|
||||
, SUM(CASE WHEN [type] = 1 THEN space_used END) -- Log files (type = 1)
|
||||
FROM (
|
||||
SELECT s.[type], space_used = SUM(FILEPROPERTY(s.name, ''SpaceUsed'') * 8. / 1024)
|
||||
SELECT s.[type], space_used = SUM(FILEPROPERTY(s.name, ''SpaceUsed'') * 8. / 1024) -- Convert pages to MB
|
||||
FROM sys.database_files s
|
||||
GROUP BY s.[type]
|
||||
) t;'
|
||||
FROM sys.databases d
|
||||
WHERE d.[state] = 0
|
||||
WHERE d.[state] = 0 -- Only include ONLINE databases
|
||||
FOR XML PATH(''), TYPE).value('.', 'NVARCHAR(MAX)'), 1, 2, '')
|
||||
|
||||
-- Execute the dynamic SQL to populate space usage data
|
||||
EXEC sys.sp_executesql @SQL
|
||||
|
||||
-- Main query: Combine database information, file sizes, space usage, and backup data
|
||||
SELECT
|
||||
d.database_id
|
||||
, d.name
|
||||
, d.state_desc
|
||||
, d.recovery_model_desc
|
||||
, t.total_size
|
||||
, t.data_size
|
||||
, s.data_used_size
|
||||
, t.log_size
|
||||
, s.log_used_size
|
||||
, bu.full_last_date
|
||||
, bu.full_size
|
||||
, bu.log_last_date
|
||||
, bu.log_size
|
||||
, d.state_desc -- Database state (ONLINE, OFFLINE, etc.)
|
||||
, d.recovery_model_desc -- Recovery model (FULL, SIMPLE, BULK_LOGGED)
|
||||
, t.total_size -- Total allocated space (data + log) in MB
|
||||
, t.data_size -- Allocated data file space in MB
|
||||
, s.data_used_size -- Actual space used in data files in MB
|
||||
, t.log_size -- Allocated log file space in MB
|
||||
, s.log_used_size -- Actual space used in log files in MB
|
||||
, bu.full_last_date -- Most recent full backup date
|
||||
, bu.full_size -- Most recent full backup size in MB
|
||||
, bu.log_last_date -- Most recent log backup date
|
||||
, bu.log_size -- Most recent log backup size in MB
|
||||
FROM (
|
||||
-- Calculate allocated file sizes from sys.master_files (covers all databases from master)
|
||||
SELECT
|
||||
database_id
|
||||
, log_size = CAST(SUM(CASE WHEN [type] = 1 THEN size END) * 8. / 1024 AS DECIMAL(18,2))
|
||||
, data_size = CAST(SUM(CASE WHEN [type] = 0 THEN size END) * 8. / 1024 AS DECIMAL(18,2))
|
||||
, total_size = CAST(SUM(size) * 8. / 1024 AS DECIMAL(18,2))
|
||||
FROM sys.master_files
|
||||
, log_size = CAST(SUM(CASE WHEN [type] = 1 THEN size END) * 8. / 1024 AS DECIMAL(18,2)) -- Log files
|
||||
, data_size = CAST(SUM(CASE WHEN [type] = 0 THEN size END) * 8. / 1024 AS DECIMAL(18,2)) -- Data files
|
||||
, total_size = CAST(SUM(size) * 8. / 1024 AS DECIMAL(18,2)) -- Total allocated
|
||||
FROM sys.master_files -- System view with all database files across instance
|
||||
GROUP BY database_id
|
||||
) t
|
||||
JOIN sys.databases d ON d.database_id = t.database_id
|
||||
LEFT JOIN #space s ON d.database_id = s.database_id
|
||||
JOIN sys.databases d ON d.database_id = t.database_id -- Join with database catalog
|
||||
LEFT JOIN #space s ON d.database_id = s.database_id -- Join with actual space usage data
|
||||
LEFT JOIN (
|
||||
-- Subquery to get latest backup information for each database
|
||||
SELECT
|
||||
database_name
|
||||
, full_last_date = MAX(CASE WHEN [type] = 'D' THEN backup_finish_date END)
|
||||
, full_size = MAX(CASE WHEN [type] = 'D' THEN backup_size END)
|
||||
, log_last_date = MAX(CASE WHEN [type] = 'L' THEN backup_finish_date END)
|
||||
, log_size = MAX(CASE WHEN [type] = 'L' THEN backup_size END)
|
||||
, full_last_date = MAX(CASE WHEN [type] = 'D' THEN backup_finish_date END) -- Latest full backup date
|
||||
, full_size = MAX(CASE WHEN [type] = 'D' THEN backup_size END) -- Latest full backup size
|
||||
, log_last_date = MAX(CASE WHEN [type] = 'L' THEN backup_finish_date END) -- Latest log backup date
|
||||
, log_size = MAX(CASE WHEN [type] = 'L' THEN backup_size END) -- Latest log backup size
|
||||
FROM (
|
||||
-- Inner query to get most recent backup of each type per database
|
||||
SELECT
|
||||
s.database_name
|
||||
, s.[type]
|
||||
, s.[type] -- 'D' = Full backup, 'L' = Log backup
|
||||
, s.backup_finish_date
|
||||
, backup_size =
|
||||
, backup_size = -- Smart backup size calculation
|
||||
CAST(CASE WHEN s.backup_size = s.compressed_backup_size
|
||||
THEN s.backup_size
|
||||
ELSE s.compressed_backup_size
|
||||
END / 1048576.0 AS DECIMAL(18,2))
|
||||
THEN s.backup_size -- No compression used
|
||||
ELSE s.compressed_backup_size -- Use compressed size
|
||||
END / 1048576.0 AS DECIMAL(18,2)) -- Convert bytes to MB
|
||||
, RowNum = ROW_NUMBER() OVER (PARTITION BY s.database_name, s.[type] ORDER BY s.backup_finish_date DESC)
|
||||
FROM msdb.dbo.backupset s
|
||||
WHERE s.[type] IN ('D', 'L')
|
||||
FROM msdb.dbo.backupset s -- SQL Server backup history
|
||||
WHERE s.[type] IN ('D', 'L') -- Full and Log backups only
|
||||
) f
|
||||
WHERE f.RowNum = 1
|
||||
WHERE f.RowNum = 1 -- Only most recent backup of each type
|
||||
GROUP BY f.database_name
|
||||
) bu ON d.name = bu.database_name
|
||||
ORDER BY t.total_size DESC
|
||||
) bu ON d.name = bu.database_name -- Join backup data with database info
|
||||
ORDER BY t.total_size DESC -- Order by largest databases first
|
||||
@@ -1,28 +1,119 @@
|
||||
/*
|
||||
================================================================================
|
||||
SQL SERVER TABLE SIZE AND SPACE UTILIZATION ANALYSIS
|
||||
================================================================================
|
||||
|
||||
DESCRIPTION:
|
||||
Comprehensive analysis of table sizes and space utilization within a SQL Server database.
|
||||
This script provides detailed insights into storage consumption, helping identify:
|
||||
• Tables consuming the most storage space
|
||||
• Space efficiency and potential optimization opportunities
|
||||
• Row counts and storage allocation patterns
|
||||
• Unused space that could be reclaimed through maintenance
|
||||
|
||||
FEATURES:
|
||||
• Per-table storage analysis with schema information
|
||||
• Detailed space breakdown (total, used, unused)
|
||||
• Multiple unit reporting (KB and MB for flexibility)
|
||||
• Row count correlation with storage size
|
||||
• Excludes system tables and diagnostic tables
|
||||
• Results ordered by storage consumption (largest first)
|
||||
|
||||
OUTPUT COLUMNS:
|
||||
- TableName: Name of the table
|
||||
- SchemaName: Schema containing the table
|
||||
- rows: Number of rows in the table (from partition statistics)
|
||||
- TotalSpaceKB: Total allocated space in kilobytes
|
||||
- TotalSpaceMB: Total allocated space in megabytes (rounded to 2 decimals)
|
||||
- UsedSpaceKB: Actually used space in kilobytes
|
||||
- UsedSpaceMB: Actually used space in megabytes (rounded to 2 decimals)
|
||||
- UnusedSpaceKB: Allocated but unused space in kilobytes
|
||||
- UnusedSpaceMB: Allocated but unused space in megabytes (rounded to 2 decimals)
|
||||
|
||||
USAGE SCENARIOS:
|
||||
• Database capacity planning and growth forecasting
|
||||
• Storage optimization and space reclamation projects
|
||||
• Performance troubleshooting (large table identification)
|
||||
• Archive and purging strategy development
|
||||
• Index maintenance priority assessment
|
||||
• Storage cost analysis and optimization
|
||||
|
||||
TECHNICAL IMPLEMENTATION:
|
||||
• Queries system catalog views for accurate space calculations
|
||||
• Aggregates data across all indexes and partitions for each table
|
||||
• Joins allocation units to get precise storage metrics
|
||||
• Filters out system tables and development artifacts
|
||||
• Uses 8KB page size for accurate space calculations
|
||||
|
||||
DATA SOURCES:
|
||||
• sys.tables: Table metadata and properties
|
||||
• sys.indexes: Index information for space aggregation
|
||||
• sys.partitions: Partition-level row counts and object relationships
|
||||
• sys.allocation_units: Physical storage allocation details
|
||||
• sys.schemas: Schema ownership and organization
|
||||
|
||||
FILTERS APPLIED:
|
||||
• Excludes tables with names starting with 'dt%' (development/diagnostic tables)
|
||||
• Excludes Microsoft shipped system tables (is_ms_shipped = 0)
|
||||
• Excludes system objects (object_id > 255)
|
||||
• Only includes user-created tables in user schemas
|
||||
|
||||
PERFORMANCE CONSIDERATIONS:
|
||||
• Efficient query using system catalog views
|
||||
• Minimal performance impact on production systems
|
||||
• Results cached by SQL Server's metadata caching
|
||||
• Suitable for regular monitoring and reporting
|
||||
|
||||
PERMISSIONS REQUIRED:
|
||||
• VIEW DEFINITION permission on target database
|
||||
• Membership in db_datareader role (recommended)
|
||||
• Access to system catalog views (granted by default to most users)
|
||||
|
||||
COMPATIBILITY:
|
||||
• SQL Server 2005 and later versions
|
||||
• Azure SQL Database compatible
|
||||
• SQL Server on Linux compatible
|
||||
• Works with all SQL Server editions
|
||||
|
||||
AUTHOR: Cloud Engineering Team
|
||||
CREATED: Database administration and monitoring toolkit
|
||||
UPDATED: Enhanced with comprehensive space analysis and documentation
|
||||
|
||||
================================================================================
|
||||
*/
|
||||
|
||||
SELECT
|
||||
t.name AS TableName,
|
||||
s.name AS SchemaName,
|
||||
p.rows,
|
||||
t.name AS TableName, -- Table name for identification
|
||||
s.name AS SchemaName, -- Schema name for organization context
|
||||
p.rows, -- Row count from partition statistics
|
||||
|
||||
-- Total allocated space calculations (pages * 8KB per page)
|
||||
SUM(a.total_pages) * 8 AS TotalSpaceKB,
|
||||
CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS TotalSpaceMB,
|
||||
|
||||
-- Actually used space calculations
|
||||
SUM(a.used_pages) * 8 AS UsedSpaceKB,
|
||||
CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS UsedSpaceMB,
|
||||
|
||||
-- Unused (allocated but not used) space calculations
|
||||
(SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB,
|
||||
CAST(ROUND(((SUM(a.total_pages) - SUM(a.used_pages)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSpaceMB
|
||||
FROM
|
||||
sys.tables t
|
||||
sys.tables t -- Base table metadata
|
||||
INNER JOIN
|
||||
sys.indexes i ON t.object_id = i.object_id
|
||||
sys.indexes i ON t.object_id = i.object_id -- All indexes on each table
|
||||
INNER JOIN
|
||||
sys.partitions p ON i.object_id = p.object_id AND i.index_id = p.index_id
|
||||
sys.partitions p ON i.object_id = p.object_id AND i.index_id = p.index_id -- Partition information and row counts
|
||||
INNER JOIN
|
||||
sys.allocation_units a ON p.partition_id = a.container_id
|
||||
sys.allocation_units a ON p.partition_id = a.container_id -- Physical storage allocation details
|
||||
LEFT OUTER JOIN
|
||||
sys.schemas s ON t.schema_id = s.schema_id
|
||||
sys.schemas s ON t.schema_id = s.schema_id -- Schema information (LEFT JOIN for safety)
|
||||
WHERE
|
||||
t.name NOT LIKE 'dt%'
|
||||
AND t.is_ms_shipped = 0
|
||||
AND i.object_id > 255
|
||||
t.name NOT LIKE 'dt%' -- Exclude diagnostic/development tables (common naming pattern)
|
||||
AND t.is_ms_shipped = 0 -- Exclude Microsoft system tables
|
||||
AND i.object_id > 255 -- Exclude system objects (object_id <= 255 are system objects)
|
||||
GROUP BY
|
||||
t.name, s.name, p.rows
|
||||
t.name, s.name, p.rows -- Group by table, schema, and row count for aggregation
|
||||
ORDER BY
|
||||
TotalSpaceMB DESC, t.name
|
||||
TotalSpaceMB DESC, -- Order by largest tables first
|
||||
t.name -- Secondary sort by table name for consistency
|
||||
@@ -1,32 +1,158 @@
|
||||
-- Query to list all objects in a database with their types
|
||||
/*
|
||||
================================================================================
|
||||
SQL SERVER DATABASE OBJECT INVENTORY AND CATALOG ANALYSIS
|
||||
================================================================================
|
||||
|
||||
DESCRIPTION:
|
||||
Comprehensive inventory of all user-created database objects within a SQL Server database.
|
||||
This script provides a complete catalog of database objects with type classification,
|
||||
helping database administrators and developers understand the database structure and
|
||||
identify objects for maintenance, documentation, or migration activities.
|
||||
|
||||
FEATURES:
|
||||
• Complete database object inventory with schema context
|
||||
• Human-readable object type descriptions
|
||||
• Modification date tracking for change management
|
||||
• Focused on user-created objects (excludes system objects)
|
||||
• Filtered results to show primary development objects
|
||||
• Organized output by schema, type, and name for easy navigation
|
||||
|
||||
OUTPUT COLUMNS:
|
||||
- ObjectName: Fully qualified object name (Schema.ObjectName format)
|
||||
- ObjectType: Human-readable description of the object type
|
||||
- ModifiedDate: Last modification timestamp for change tracking
|
||||
|
||||
OBJECT TYPES INCLUDED:
|
||||
• User Tables: Data storage tables created by users
|
||||
• Views: Virtual tables and data abstractions
|
||||
• Stored Procedures: Executable SQL code blocks
|
||||
• Scalar Functions: Functions returning single values
|
||||
• Inline Table Functions: Functions returning table results inline
|
||||
• Table Functions: Functions returning table structures
|
||||
• Extended Stored Procedures: System-level executable procedures
|
||||
• CLR Objects: .NET Common Language Runtime integrated objects
|
||||
- CLR Stored Procedures
|
||||
- CLR Scalar Functions
|
||||
- CLR Table Functions
|
||||
- CLR Aggregate Functions
|
||||
|
||||
OBJECT TYPES EXCLUDED:
|
||||
• Triggers (TR): Database triggers
|
||||
• Primary Keys (PK): Primary key constraints
|
||||
• Foreign Keys (F): Foreign key constraints
|
||||
• Check Constraints (C): Data validation constraints
|
||||
• Default Constraints (D): Default value constraints
|
||||
• Unique Constraints (UQ): Unique value constraints
|
||||
• System Tables (S): SQL Server system tables
|
||||
• Service Queues (SQ): Service Broker queues
|
||||
• Internal Tables (IT): SQL Server internal structures
|
||||
|
||||
USAGE SCENARIOS:
|
||||
• Database documentation and inventory management
|
||||
• Migration planning and object dependency analysis
|
||||
• Code review and development lifecycle management
|
||||
• Security auditing and permission analysis
|
||||
• Database schema comparison and synchronization
|
||||
• Object naming convention compliance checking
|
||||
• Development team onboarding and knowledge transfer
|
||||
|
||||
TECHNICAL IMPLEMENTATION:
|
||||
• Queries sys.objects catalog view for object metadata
|
||||
• Joins with sys.schemas for complete naming context
|
||||
• Uses CASE statement for user-friendly type descriptions
|
||||
• Filters system objects using is_ms_shipped flag
|
||||
• Additional filtering to focus on primary development objects
|
||||
• Results ordered for logical grouping and easy scanning
|
||||
|
||||
DATA SOURCES:
|
||||
• sys.objects: Core object metadata and properties
|
||||
• sys.schemas: Schema ownership and organization information
|
||||
|
||||
FILTERS APPLIED:
|
||||
• is_ms_shipped = 0: Excludes Microsoft system objects
|
||||
• Object type filtering: Excludes constraints, triggers, and internal objects
|
||||
• Focus on tables, views, procedures, and functions
|
||||
|
||||
PERFORMANCE CONSIDERATIONS:
|
||||
• Efficient query using system catalog views
|
||||
• Minimal performance impact (metadata-only query)
|
||||
• Results typically cached by SQL Server
|
||||
• Suitable for regular inventory and monitoring
|
||||
|
||||
PERMISSIONS REQUIRED:
|
||||
• VIEW DEFINITION permission on target database
|
||||
• Access to system catalog views (standard user access)
|
||||
• Membership in db_datareader role (recommended)
|
||||
|
||||
COMPATIBILITY:
|
||||
• SQL Server 2005 and later versions
|
||||
• Azure SQL Database compatible
|
||||
• SQL Server on Linux compatible
|
||||
• Works with all SQL Server editions
|
||||
|
||||
CUSTOMIZATION OPTIONS:
|
||||
• Modify object type filters to include/exclude specific types
|
||||
• Add additional object properties (create_date, principal_id, etc.)
|
||||
• Filter by specific schemas or naming patterns
|
||||
• Add object size or usage statistics
|
||||
|
||||
AUTHOR: Cloud Engineering Team
|
||||
CREATED: Database administration and development toolkit
|
||||
UPDATED: Enhanced with comprehensive object type mapping and documentation
|
||||
|
||||
================================================================================
|
||||
*/
|
||||
|
||||
-- Main query: Database object inventory with type classification and metadata
|
||||
SELECT
|
||||
s.name + '.' + o.name AS ObjectName,
|
||||
CASE o.type
|
||||
WHEN 'U' THEN 'User Table'
|
||||
WHEN 'V' THEN 'View'
|
||||
WHEN 'P' THEN 'Stored Procedure'
|
||||
WHEN 'FN' THEN 'Scalar Function'
|
||||
WHEN 'IF' THEN 'Inline Table Function'
|
||||
WHEN 'TF' THEN 'Table Function'
|
||||
WHEN 'TR' THEN 'Trigger'
|
||||
WHEN 'PK' THEN 'Primary Key'
|
||||
WHEN 'F' THEN 'Foreign Key'
|
||||
WHEN 'C' THEN 'Check Constraint'
|
||||
WHEN 'D' THEN 'Default Constraint'
|
||||
WHEN 'UQ' THEN 'Unique Constraint'
|
||||
WHEN 'S' THEN 'System Table'
|
||||
WHEN 'SQ' THEN 'Service Queue'
|
||||
WHEN 'IT' THEN 'Internal Table'
|
||||
WHEN 'X' THEN 'Extended Stored Procedure'
|
||||
WHEN 'PC' THEN 'CLR Stored Procedure'
|
||||
WHEN 'FS' THEN 'CLR Scalar Function'
|
||||
WHEN 'FT' THEN 'CLR Table Function'
|
||||
WHEN 'AF' THEN 'CLR Aggregate Function'
|
||||
ELSE 'Other'
|
||||
s.name + '.' + o.name AS ObjectName, -- Fully qualified name (Schema.Object)
|
||||
CASE o.type -- Convert system type codes to readable descriptions
|
||||
-- Primary database objects (included in results)
|
||||
WHEN 'U' THEN 'User Table' -- User-defined tables
|
||||
WHEN 'V' THEN 'View' -- Views and indexed views
|
||||
WHEN 'P' THEN 'Stored Procedure' -- T-SQL stored procedures
|
||||
WHEN 'FN' THEN 'Scalar Function' -- Scalar user-defined functions
|
||||
WHEN 'IF' THEN 'Inline Table Function' -- Inline table-valued functions
|
||||
WHEN 'TF' THEN 'Table Function' -- Multi-statement table-valued functions
|
||||
WHEN 'X' THEN 'Extended Stored Procedure' -- System extended procedures
|
||||
|
||||
-- CLR (Common Language Runtime) objects
|
||||
WHEN 'PC' THEN 'CLR Stored Procedure' -- .NET CLR stored procedures
|
||||
WHEN 'FS' THEN 'CLR Scalar Function' -- .NET CLR scalar functions
|
||||
WHEN 'FT' THEN 'CLR Table Function' -- .NET CLR table-valued functions
|
||||
WHEN 'AF' THEN 'CLR Aggregate Function' -- .NET CLR aggregate functions
|
||||
|
||||
-- Constraint and system objects (filtered out but documented)
|
||||
WHEN 'TR' THEN 'Trigger' -- Database triggers
|
||||
WHEN 'PK' THEN 'Primary Key' -- Primary key constraints
|
||||
WHEN 'F' THEN 'Foreign Key' -- Foreign key constraints
|
||||
WHEN 'C' THEN 'Check Constraint' -- Check constraints
|
||||
WHEN 'D' THEN 'Default Constraint' -- Default constraints
|
||||
WHEN 'UQ' THEN 'Unique Constraint' -- Unique constraints
|
||||
WHEN 'S' THEN 'System Table' -- System tables
|
||||
WHEN 'SQ' THEN 'Service Queue' -- Service Broker queues
|
||||
WHEN 'IT' THEN 'Internal Table' -- Internal system tables
|
||||
|
||||
ELSE 'Other' -- Catch-all for unrecognized types
|
||||
END AS ObjectType,
|
||||
o.modify_date AS ModifiedDate
|
||||
FROM sys.objects o
|
||||
INNER JOIN sys.schemas s ON o.schema_id = s.schema_id
|
||||
WHERE o.is_ms_shipped = 0 -- Exclude system objects
|
||||
and not (o.type in ('TR','PK','F','C','D','UQ','S','SQ','IT','',''))
|
||||
ORDER BY s.name, ObjectType, o.name;
|
||||
o.modify_date AS ModifiedDate -- Last modification timestamp
|
||||
FROM sys.objects o -- Core object metadata catalog
|
||||
INNER JOIN sys.schemas s ON o.schema_id = s.schema_id -- Schema information for full naming context
|
||||
WHERE
|
||||
o.is_ms_shipped = 0 -- Exclude Microsoft system objects
|
||||
AND NOT (o.type IN ( -- Filter out constraint and system object types
|
||||
'TR', -- Triggers
|
||||
'PK', -- Primary Keys
|
||||
'F', -- Foreign Keys
|
||||
'C', -- Check Constraints
|
||||
'D', -- Default Constraints
|
||||
'UQ', -- Unique Constraints
|
||||
'S', -- System Tables
|
||||
'SQ', -- Service Queues
|
||||
'IT', -- Internal Tables
|
||||
'' -- Empty/null types
|
||||
))
|
||||
ORDER BY
|
||||
s.name, -- Primary sort: Schema name
|
||||
ObjectType, -- Secondary sort: Object type for grouping
|
||||
o.name -- Tertiary sort: Object name alphabetically
|
||||
Reference in New Issue
Block a user