/* ================================================================================ 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, -- 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 -- 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