├── .github └── ISSUE_TEMPLATE │ ├── bug_report.md │ └── feature_request.md ├── CONTRIBUTING.md ├── LICENSE ├── README.md ├── SECURITY.md └── sqldb-tips ├── get-sqldb-tips-compat-level-100-only.sql └── get-sqldb-tips.sql /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Create a report to help us improve 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | 8 | --- 9 | 10 | **Describe the bug** 11 | A clear and concise description of what the bug is. 12 | 13 | **To Reproduce** 14 | Steps to reproduce the behavior: 15 | 1. Go to '...' 16 | 2. Click on '....' 17 | 3. Scroll down to '....' 18 | 4. See error 19 | 20 | **Expected behavior** 21 | A clear and concise description of what you expected to happen. 22 | 23 | **Screenshots** 24 | If applicable, add screenshots to help explain your problem. 25 | 26 | **Database info** 27 | Please provide the service objective (SLO) of the database, and whether it is a single database or a database in an elastic pool. For example, P1, S12, HS_Gen5_8, GP_S_Gen5_2, etc. 28 | 29 | **Additional context** 30 | Add any other context about the problem here. 31 | -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/feature_request.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Feature request 3 | about: Suggest an idea for this project 4 | title: '' 5 | labels: '' 6 | assignees: '' 7 | 8 | --- 9 | 10 | **Is your feature request related to a problem? Please describe.** 11 | A clear and concise description of what the problem is. Ex. I'm always frustrated when [...] 12 | 13 | **Describe the solution you'd like** 14 | A clear and concise description of what you want to happen. 15 | 16 | **Describe alternatives you've considered** 17 | A clear and concise description of any alternative solutions or features you've considered. 18 | 19 | **Additional context** 20 | Add any other context or screenshots about the feature request here. 21 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributions 2 | 3 | We welcome and encourage contributions to this project. You can open [issues](../../issues) to report bugs and suggest improvements or new tips, or send [pull requests](../../pulls) to contribute code. 4 | 5 | We request that you keep the following guidelines in mind: 6 | 7 | 1. A new tip or a change to an existing tip must be implementable in T-SQL using the current surface area of Azure SQL Database; 8 | 2. A new tip or a change to an existing tip must be useful to a significant portion of Azure SQL Database customers; 9 | 3. The implementation must be lightweight, i.e. it should not cause high resource utilization or contention that may impact running workloads, and should not cause the script to run for an excessively long time. 10 | 11 | The last two guidelines are clearly subjective; we will use community input and our best judgement when considering contributions. 12 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2021 Microsoft 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Readme 2 | 3 | Execute the [`get-sqldb-tips.sql`](../../releases/latest) script to get tips for improving database design, health, and performance in [Azure SQL Database](https://azure.microsoft.com/services/sql-database/). 4 | 5 | ## Quickstart 6 | 7 | 1. Read wiki first: [Azure SQL Database tips](../../wiki/Azure-SQL-Database-tips). 8 | 2. See [FAQ](../../wiki/FAQ) for answers to common questions. 9 | 3. Download the [latest release](../../releases/latest) (zip file is under Assets) and execute. 10 | 11 | This script is maintained by the Azure SQL PM team. Feedback and contributions from the community are welcome and encouraged. 12 | 13 | ## Code of Conduct 14 | This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments. 15 | -------------------------------------------------------------------------------- /SECURITY.md: -------------------------------------------------------------------------------- 1 | 2 | 3 | ## Security 4 | 5 | Microsoft takes the security of our software products and services seriously, which includes all source code repositories managed through our GitHub organizations, which include [Microsoft](https://github.com/Microsoft), [Azure](https://github.com/Azure), [DotNet](https://github.com/dotnet), [AspNet](https://github.com/aspnet), [Xamarin](https://github.com/xamarin), and [our GitHub organizations](https://opensource.microsoft.com/). 6 | 7 | If you believe you have found a security vulnerability in any Microsoft-owned repository that meets [Microsoft's definition of a security vulnerability](https://aka.ms/opensource/security/definition), please report it to us as described below. 8 | 9 | ## Reporting Security Issues 10 | 11 | **Please do not report security vulnerabilities through public GitHub issues.** 12 | 13 | Instead, please report them to the Microsoft Security Response Center (MSRC) at [https://msrc.microsoft.com/create-report](https://aka.ms/opensource/security/create-report). 14 | 15 | If you prefer to submit without logging in, send email to [secure@microsoft.com](mailto:secure@microsoft.com). If possible, encrypt your message with our PGP key; please download it from the [Microsoft Security Response Center PGP Key page](https://aka.ms/opensource/security/pgpkey). 16 | 17 | You should receive a response within 24 hours. If for some reason you do not, please follow up via email to ensure we received your original message. Additional information can be found at [microsoft.com/msrc](https://aka.ms/opensource/security/msrc). 18 | 19 | Please include the requested information listed below (as much as you can provide) to help us better understand the nature and scope of the possible issue: 20 | 21 | * Type of issue (e.g. buffer overflow, SQL injection, cross-site scripting, etc.) 22 | * Full paths of source file(s) related to the manifestation of the issue 23 | * The location of the affected source code (tag/branch/commit or direct URL) 24 | * Any special configuration required to reproduce the issue 25 | * Step-by-step instructions to reproduce the issue 26 | * Proof-of-concept or exploit code (if possible) 27 | * Impact of the issue, including how an attacker might exploit the issue 28 | 29 | This information will help us triage your report more quickly. 30 | 31 | If you are reporting for a bug bounty, more complete reports can contribute to a higher bounty award. Please visit our [Microsoft Bug Bounty Program](https://aka.ms/opensource/security/bounty) page for more details about our active programs. 32 | 33 | ## Preferred Languages 34 | 35 | We prefer all communications to be in English. 36 | 37 | ## Policy 38 | 39 | Microsoft follows the principle of [Coordinated Vulnerability Disclosure](https://aka.ms/opensource/security/cvd). 40 | 41 | 42 | -------------------------------------------------------------------------------- /sqldb-tips/get-sqldb-tips-compat-level-100-only.sql: -------------------------------------------------------------------------------- 1 | /* 2 | ATTENTION: Only use this script if your database is using compatibility level 100. 3 | For all newer compatibility levels, use get-sqldb-tips.sql at https://aka.ms/sqldbtips 4 | 5 | Returns a set of tips to improve database design, health, and performance in Azure SQL Database. 6 | For the latest version of the script, see https://aka.ms/sqldbtips 7 | For a detailed description, see https://aka.ms/sqldbtipswiki 8 | */ 9 | 10 | -- Set to 1 to output tips as a JSON value 11 | DECLARE @JSONOutput bit = 0; 12 | 13 | -- Debug flag to return all tips regardless of database state 14 | DECLARE @ReturnAllTips bit = 0; 15 | 16 | -- Next three variables apply to "Top queries" (1320) hint, adjust if needed 17 | 18 | -- The length of recent time interval to use when determining top queries. Default is last 1 hour. 19 | -- Setting this to NULL disables the "Top queries" hint 20 | DECLARE @QueryStoreIntervalMinutes int = 60; 21 | /* 22 | 1 hour = 60 minutes 23 | 3 hours = 180 minutes 24 | 6 hours = 360 minutes 25 | 12 hours = 720 minutes 26 | 1 day = 1440 minutes 27 | 3 days = 4320 minutes 28 | 1 week = 10080 minutes 29 | 2 weeks = 20160 minutes 30 | 4 weeks = 40320 minutes 31 | */ 32 | 33 | -- To get top queries for a custom time interval, specify the start and end time here, in UTC 34 | DECLARE @QueryStoreCustomTimeStart datetimeoffset -- = '2021-01-01 00:01 +00:00'; 35 | DECLARE @QueryStoreCustomTimeEnd datetimeoffset -- = '2021-12-31 23:59 +00:00'; 36 | 37 | -- Configurable thresholds 38 | DECLARE 39 | 40 | -- 1100: Minimum table size to be considered 41 | @GuidLeadingColumnObjectMinSizeMB int = 1024, 42 | 43 | -- 1120: The ratio of used space to database MAXSIZE that is considered as being too high 44 | @UsedToMaxsizeSpaceThresholdRatio decimal(3,2) = 0.8, 45 | 46 | -- 1130: The ratio of allocated space to database MAXSIZE that is considered as being too high 47 | @AllocatedToMaxsizeSpaceThresholdRatio decimal(3,2) = 0.8, 48 | 49 | -- 1140: The ratio of used space to allocated space that is considered as being too low 50 | @UsedToAllocatedSpaceThresholdRatio decimal(3,2) = 0.3, 51 | 52 | -- 1140: Minimum database size to be considered 53 | @UsedToAllocatedSpaceDbMinSizeMB int = 10240, 54 | 55 | -- 1150: Minimum percentage of CPU RG delay to be considered as significant CPU throttling 56 | @CPUThrottlingDelayThresholdPercent decimal(5,2) = 20, 57 | 58 | -- 1170: The ratio of all index reads to index writes that is considered as being too low 59 | @IndexReadWriteThresholdRatio decimal(3,2) = 0.1, 60 | 61 | -- 1180: The maximum ratio of updates to all operations to define "infrequent updates" 62 | @CompressionPartitionUpdateRatioThreshold1 decimal(3,2) = 0.2, 63 | 64 | -- 1180: The maximum ratio of updates to all operations to define "more frequent but not frequent enough updates" 65 | @CompressionPartitionUpdateRatioThreshold2 decimal(3,2) = 0.5, 66 | 67 | -- 1180: The minimum ratio of scans to all operations to define "frequent enough scans" 68 | @CompressionPartitionScanRatioThreshold1 decimal(3,2) = 0.5, 69 | 70 | -- 1180: Maximum CPU usage percentage to be considered as sufficient CPU headroom 71 | @CompressionCPUHeadroomThreshold1 decimal(5,2) = 60, 72 | 73 | -- 1180: Minimum CPU usage percentage to be considered as insufficient CPU headroom 74 | @CompressionCPUHeadroomThreshold2 decimal(5,2) = 80, 75 | 76 | -- 1180: Minimum required number of resource stats sampling intervals 77 | @CompressionMinResourceStatSamples smallint = 30, 78 | 79 | -- 1180: Minimum ratio of compressible to not compressible allocations for compression to be worthwhile 80 | @CompressionMinEligibleRatio decimal(3,2) = 0.3, 81 | 82 | -- 1190: Minimum log rate as percentage of SLO limit that is considered as being too high 83 | @HighLogRateThresholdPercent decimal(5,2) = 80, 84 | 85 | -- 1200: Minimum required per-db size of single-use plans to be considered as significant 86 | @SingleUsePlanSizeThresholdMB int = 512, 87 | 88 | -- 1200: The minimum ratio of single-use plans size to total plan size per database to be considered as significant 89 | @SingleUseTotalPlanSizeRatioThreshold decimal(3,2) = 0.3, 90 | 91 | -- 1210: The minimum user impact for a missing index to be considered as significant 92 | @MissingIndexAvgUserImpactThreshold decimal(5,2) = 80, 93 | 94 | -- 1220: The minimum size of redo queue on secondaries to be considered as significant 95 | @RedoQueueSizeThresholdMB int = 1024, 96 | 97 | -- 1230: The minimum ratio of governed IOPS issued to workload group IOPS limit that is considered significant 98 | @GroupIORGAtLimitThresholdRatio decimal(3,2) = 0.9, 99 | 100 | -- 1240: The minimum ratio of IO RG delay time to total IO stall time that is considered significant 101 | @GroupIORGImpactRatio decimal(3,2) = 0.8, 102 | 103 | -- 1250: The minimum ratio of governed IOPS issued to resource pool IOPS limit that is considered significant 104 | @PoolIORGAtLimitThresholdRatio decimal(3,2) = 0.9, 105 | 106 | -- 1260: The minimum ratio of IO RG delay time to total IO stall time that is considered significant 107 | @PoolIORGImpactRatio decimal(3,2) = 0.8, 108 | 109 | -- 1270: The minimum size of persistent version store (PVS) to be considered significant 110 | @PVSMinimumSizeThresholdGB int = 100, 111 | 112 | -- 1270: The minimum ratio of PVS size to database maxsize to be considered significant 113 | @PVSToMaxSizeMinThresholdRatio decimal(3,2) = 0.3, 114 | 115 | -- 1290: The minimum table size to be considered 116 | @CCICandidateMinSizeGB int = 10, 117 | 118 | -- 1300: The minimum geo-replication lag to be considered significant 119 | @HighGeoReplLagMinThresholdSeconds int = 10, 120 | 121 | -- 1300: The length of time window that defines recent geo-replicated transactions 122 | @RecentGeoReplTranTimeWindowLengthSeconds int = 300, 123 | 124 | -- 1310: The number of empty partitions at head end considered required 125 | @MinEmptyPartitionCount tinyint = 2, 126 | 127 | -- 1320: The number of top queries along each dimension (duration, CPU time, etc.) to consider 128 | @QueryStoreTopQueryCount tinyint = 2, 129 | 130 | -- 1330: The ratio of tempdb allocated data space to data MAXSIZE that is considered as being too high 131 | @TempdbDataAllocatedToMaxsizeThresholdRatio decimal(3,2) = 0.8, 132 | 133 | -- 1340: The ratio of tempdb used space to MAXSIZE that is considered as being too high 134 | @TempdbDataUsedToMaxsizeThresholdRatio decimal(3,2) = 0.8, 135 | 136 | -- 1350: The ratio of tempdb allocated log space to log MAXSIZE that is considered as being too high 137 | @TempdbLogAllocatedToMaxsizeThresholdRatio decimal(3,2) = 0.6, 138 | 139 | -- 1360: The minimum ratio of workload group workers used to maximum workers per workload group considered as being too high 140 | @HighGroupWorkerUtilizationThresholdRatio decimal(3,2) = 0.8, 141 | 142 | -- 1370: The minimum ratio of resource pool workers used to maximum workers per resource pool considered as being too high 143 | @HighPoolWorkerUtilizationThresholdRatio decimal(3,2) = 0.7, 144 | 145 | -- 1380: The length of recent time interval to use when filtering network connectivity ring buffer events 146 | @NotableNetworkEventsIntervalMinutes int = 120, 147 | 148 | -- 1380: Minimum duration of login considered too long 149 | @NotableNetworkEventsSlowLoginThresholdMs int = 5000, 150 | 151 | -- 1390: Minimum instance CPU percentage considered too high 152 | @HighInstanceCPUThresholdPercent decimal(5,2) = 90, 153 | 154 | -- 1390: Minimum duration of a high instance CPU period considered significant 155 | @HighInstanceCPUMinThresholdSeconds int = 300, 156 | 157 | -- 1400: Minimum change in object cardinality to be considered significant, expressed as a ratio of cardinality at last stats update to current cardinality 158 | @StaleStatsCardinalityChangeMinDifference decimal(3,2) = 0.5, 159 | 160 | -- 1400: The min ratio of mod count to object cardinality to be considered significant 161 | @StaleStatsMinModificationCountRatio decimal(3,2) = 0.1, 162 | 163 | -- 1400: The minimum number of days since last stats update to be considered significant 164 | @StaleStatsMinAgeThresholdDays smallint = 30, 165 | 166 | -- 1410: The minimum number of rows in a table for the lack of indexes to be considered significant 167 | @NoIndexTablesMinRowCountThreshold int = 500, 168 | 169 | -- 1410: The minimum ratio of the number of no-index tables to the total number of tables to be considered significant 170 | @NoIndexMinTableCountRatio decimal(3,2) = 0.2, 171 | 172 | -- 1420: The minimum ratio of total time spend waiting on locks during the interval to the interval duration to be considered significant 173 | @LockBlockingTimeThresholdRatio decimal(3,2) = 0.1, 174 | 175 | -- 1420: The minumum number of blocked tasks observed at the time of each 20-second snapshot to be considered significant 176 | @LockBlockingBlockedTaskThreshold int = 1, 177 | 178 | -- 1430: The minimum number of requests in an interval to start considering if query optimizations are high 179 | @QueryOptimizationRequestCountThreshold smallint = 100, 180 | 181 | -- 1430: The minimum ratio of query optimizations to the number of requests to be considered significant 182 | @QueryOptimizationRequestThresholdRatio decimal(3,2) = 0.15, 183 | 184 | -- 1450: The minimum local storage usage ratio to be considered significant 185 | @MinLocalStorageQuotaUsageRatio decimal(3,2) = 0.85, 186 | 187 | -- 1490: Values below this fill factor are considered too low 188 | @FillFactorThreshold tinyint = 90, 189 | 190 | -- 1510: The ratio of the remaining identity/sequence range to initial identity range (or maximum sequence range) that is considered too low 191 | @IdentitySequenceRangeExhaustionThresholdRatio decimal(3,2) = 0.2, 192 | 193 | -- 1540: The minimum number of total page compression attempts per partition of an index to consider it in this tip 194 | @PageCompressionAttemptsThreshold int = 100, 195 | 196 | -- 1540: The ratio of successful page compression attempts to total page compression attempts that is considered too low 197 | @MinPageCompressionSuccessRatio decimal(3,2) = 0.5 198 | ; 199 | 200 | DECLARE @ExecStartTime datetimeoffset = SYSDATETIMEOFFSET(); 201 | 202 | DECLARE @TipDefinition table ( 203 | tip_id smallint NOT NULL PRIMARY KEY, 204 | tip_name nvarchar(60) NOT NULL UNIQUE, 205 | confidence_percent decimal(3,0) NOT NULL CHECK (confidence_percent BETWEEN 0 AND 100), 206 | tip_url nvarchar(200) NOT NULL, 207 | required_permission varchar(50) NOT NULL, 208 | execute_indicator bit NOT NULL 209 | ); 210 | DECLARE @DetectedTip table ( 211 | tip_id smallint NOT NULL PRIMARY KEY, 212 | details nvarchar(max) NULL 213 | ); 214 | DECLARE @SkippedTip table ( 215 | tip_id smallint NOT NULL PRIMARY KEY, 216 | reason nvarchar(30) NOT NULL DEFAULT ('lock timeout') 217 | ); 218 | 219 | DECLARE @CRLF char(2) = CONCAT(CHAR(13), CHAR(10)), 220 | @NbspCRLF nchar(3) = CONCAT(NCHAR(160), NCHAR(13), NCHAR(10)); 221 | 222 | DECLARE @ViewServerStateIndicator bit = 1; 223 | 224 | SET NOCOUNT ON; 225 | SET LOCK_TIMEOUT 3000; -- abort if another request holds a lock on metadata for too long 226 | 227 | BEGIN TRY 228 | 229 | DECLARE @EngineEdition int = CAST(SERVERPROPERTY('EngineEdition') AS int); 230 | 231 | IF @EngineEdition NOT IN (5,8) 232 | THROW 50005, 'This script is for Azure SQL Database and Azure SQL Managed Instance only.', 1; 233 | 234 | -- Bail out if current CPU utilization is very high, to avoid impacting workloads 235 | IF EXISTS ( 236 | SELECT 1 237 | FROM ( 238 | SELECT avg_cpu_percent, 239 | avg_instance_cpu_percent, 240 | LEAD(end_time) OVER (ORDER BY end_time) AS next_end_time 241 | FROM sys.dm_db_resource_stats 242 | ) AS rs 243 | WHERE next_end_time IS NULL 244 | AND 245 | ( 246 | rs.avg_cpu_percent > 95 247 | OR 248 | rs.avg_instance_cpu_percent > 97 249 | ) 250 | ) 251 | THROW 50010, 'CPU utilization is too high. Execute the script at a later time.', 1; 252 | 253 | IF DB_NAME() = 'master' AND @EngineEdition = 5 254 | THROW 50015, 'Execute this script in a user database, not in the ''master'' database.', 1; 255 | 256 | IF EXISTS ( 257 | SELECT 1 258 | FROM sys.databases 259 | WHERE database_id = DB_ID() 260 | AND 261 | compatibility_level > 100 262 | ) 263 | THROW 50020, 'This script is intended only for databases using compatibility level 100. For all newer compatibility levels, use get-sqldb-tips.sql at https://aka.ms/sqldbtips.', 1; 264 | 265 | -- Define all tips 266 | INSERT INTO @TipDefinition (execute_indicator, tip_id, tip_name, confidence_percent, tip_url, required_permission) 267 | VALUES 268 | (1, 1000, 'Reduce MAXDOP on all replicas', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1000', 'VIEW DATABASE STATE'), 269 | (1, 1010, 'Reduce MAXDOP on primary', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1010', 'VIEW DATABASE STATE'), 270 | (1, 1020, 'Reduce MAXDOP on secondaries', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1020', 'VIEW DATABASE STATE'), 271 | (1, 1030, 'Database compatibility level is not the latest', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1030', 'VIEW DATABASE STATE'), 272 | (1, 1040, 'Enable auto-create statistics', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1040', 'VIEW DATABASE STATE'), 273 | (1, 1050, 'Enable auto-update statistics', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1050', 'VIEW DATABASE STATE'), 274 | (1, 1060, 'Enable Read Committed Snapshot Isolation (RCSI)', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1060', 'VIEW DATABASE STATE'), 275 | (1, 1070, 'Enable Query Store', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1070', 'VIEW DATABASE STATE'), 276 | (1, 1071, 'Change Query Store operation mode to read-write', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1071', 'VIEW DATABASE STATE'), 277 | (1, 1072, 'Change Query Store capture mode from NONE to AUTO/ALL', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1072', 'VIEW DATABASE STATE'), 278 | (1, 1080, 'Disable AUTO_SHRINK', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1080', 'VIEW DATABASE STATE'), 279 | (1, 1100, 'Avoid GUID leading columns in btree indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1100', 'VIEW DATABASE STATE'), 280 | (1, 1110, 'Enable FLGP auto-tuning', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1110', 'VIEW DATABASE STATE'), 281 | (1, 1120, 'Used data size is close to MAXSIZE', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1120', 'VIEW DATABASE STATE'), 282 | (1, 1130, 'Allocated data size is close to MAXSIZE', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1130', 'VIEW DATABASE STATE'), 283 | (1, 1140, 'Allocated data size is much larger than used data size', 50, 'https://aka.ms/sqldbtipswiki#tip_id-1140', 'VIEW DATABASE STATE'), 284 | (1, 1150, 'Recent CPU throttling found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1150', 'VIEW SERVER STATE'), 285 | (1, 1160, 'Recent out of memory errors found', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1160', 'VIEW SERVER STATE'), 286 | (1, 1165, 'Recent memory grant waits and timeouts found', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1165', 'VIEW SERVER STATE'), 287 | (1, 1170, 'Nonclustered indexes with low reads found', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1170', 'VIEW SERVER STATE'), 288 | (1, 1180, 'ROW or PAGE compression opportunities may exist', 65, 'https://aka.ms/sqldbtipswiki#tip_id-1180', 'VIEW SERVER STATE'), 289 | (1, 1190, 'Transaction log IO is close to limit', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1190', 'VIEW DATABASE STATE'), 290 | (1, 1200, 'Plan cache is bloated by single-use plans', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1200', 'VIEW DATABASE STATE'), 291 | (1, 1210, 'Missing indexes may be impacting performance', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1210', 'VIEW SERVER STATE'), 292 | (1, 1220, 'Redo queue on a secondary replica is large', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1220', 'VIEW DATABASE STATE'), 293 | (1, 1230, 'Data IOPS are close to workload group limit', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1230', 'VIEW SERVER STATE'), 294 | (1, 1240, 'Workload group IO governance impact is significant', 40, 'https://aka.ms/sqldbtipswiki#tip_id-1240', 'VIEW SERVER STATE'), 295 | (1, 1250, 'Data IOPS are close to resource pool limit', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1250', 'VIEW SERVER STATE'), 296 | (1, 1260, 'Resource pool IO governance impact is significant', 40, 'https://aka.ms/sqldbtipswiki#tip_id-1260', 'VIEW SERVER STATE'), 297 | (1, 1270, 'Persistent Version Store size is large', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1270', 'VIEW SERVER STATE'), 298 | (1, 1280, 'Paused resumable index operations found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1280', 'VIEW DATABASE STATE'), 299 | (1, 1290, 'Clustered columnstore candidates found', 50, 'https://aka.ms/sqldbtipswiki#tip_id-1290', 'VIEW SERVER STATE'), 300 | (1, 1300, 'Geo-replication state may be unhealthy', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1300', 'VIEW DATABASE STATE'), 301 | (1, 1310, 'Last partitions are not empty', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1310', 'VIEW DATABASE STATE'), 302 | (1, 1320, 'Top queries should be investigated and tuned', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1320', 'VIEW DATABASE STATE'), 303 | (1, 1330, 'Tempdb data allocated size is close to MAXSIZE', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1330', 'tempdb.VIEW DATABASE STATE'), 304 | (1, 1340, 'Tempdb data used size is close to MAXSIZE', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1340', 'tempdb.VIEW DATABASE STATE'), 305 | (1, 1350, 'Tempdb log allocated size is close to MAXSIZE', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1350', 'tempdb.VIEW DATABASE STATE'), 306 | (1, 1360, 'Worker utilization is close to workload group limit', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1360', 'VIEW SERVER STATE'), 307 | (1, 1370, 'Worker utilization is close to resource pool limit', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1370', 'VIEW SERVER STATE'), 308 | (1, 1380, 'Notable network connectivity events found', 30, 'https://aka.ms/sqldbtipswiki#tip_id-1380', 'VIEW SERVER STATE'), 309 | (1, 1390, 'Instance CPU utilization is high', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1390', 'VIEW DATABASE STATE'), 310 | (1, 1400, 'Some statistics may be out of date', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1400', 'VIEW DATABASE STATE'), 311 | (1, 1410, 'Many tables do not have any indexes', 60, 'https://aka.ms/sqldbtipswiki#tip_id-1410', 'VIEW DATABASE STATE'), 312 | (1, 1420, 'Significant lock blocking has recently occurred', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1420', 'VIEW SERVER STATE'), 313 | (1, 1430, 'The number of recent query optimizations is high', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1430', 'VIEW SERVER STATE'), 314 | (1, 1440, 'Row locks or page locks are disabled for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1440', 'VIEW DATABASE STATE'), 315 | (1, 1450, 'Allocated local storage is close to maximum local storage', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1450', 'VIEW SERVER STATE'), 316 | (1, 1460, 'Column collation does not match database collation', 70, 'https://aka.ms/sqldbtipswiki#tip_id-1460', 'VIEW DATABASE STATE'), 317 | (1, 1470, 'Indexes with excessively large keys found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1470', 'VIEW DATABASE STATE'), 318 | (1, 1480, 'Disabled indexes found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1480', 'VIEW DATABASE STATE'), 319 | (1, 1490, 'Indexes with low fill factor found', 80, 'https://aka.ms/sqldbtipswiki#tip_id-1490', 'VIEW DATABASE STATE'), 320 | (1, 1500, 'Non-unique clustered indexes found', 65, 'https://aka.ms/sqldbtipswiki#tip_id-1500', 'VIEW DATABASE STATE'), 321 | (1, 1510, 'Most of the IDENTITY range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1510', 'VIEW DATABASE STATE'), 322 | (1, 1520, 'Most of the sequence range is used', 95, 'https://aka.ms/sqldbtipswiki#tip_id-1520', 'VIEW DATABASE STATE'), 323 | (1, 1530, 'Disabled or not trusted constraints found', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1530', 'VIEW DATABASE STATE'), 324 | (1, 1540, 'Page compression is ineffective for some indexes', 90, 'https://aka.ms/sqldbtipswiki#tip_id-1540', 'VIEW SERVER STATE') 325 | ; 326 | 327 | -- Top queries 328 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1320) AND execute_indicator = 1) 329 | BEGIN 330 | 331 | BEGIN TRY 332 | 333 | DROP TABLE IF EXISTS #query_wait_stats_summary; 334 | 335 | CREATE TABLE #query_wait_stats_summary 336 | ( 337 | query_hash binary(8) PRIMARY KEY, 338 | ranked_wait_categories varchar(max) NOT NULL 339 | ); 340 | 341 | DECLARE @QueryStoreTimeFrom datetimeoffset = IIF( 342 | (@QueryStoreCustomTimeStart IS NULL OR @QueryStoreCustomTimeEnd IS NULL) AND @QueryStoreIntervalMinutes IS NOT NULL, 343 | DATEADD(minute, -@QueryStoreIntervalMinutes, SYSDATETIMEOFFSET()), 344 | @QueryStoreCustomTimeStart 345 | ), 346 | @QueryStoreTimeThru datetimeoffset = IIF( 347 | (@QueryStoreCustomTimeStart IS NULL OR @QueryStoreCustomTimeEnd IS NULL) AND @QueryStoreIntervalMinutes IS NOT NULL, 348 | SYSDATETIMEOFFSET(), 349 | @QueryStoreCustomTimeEnd 350 | ); 351 | 352 | -- Opportunistically update statistics on Query Store internal tables 353 | BEGIN TRY 354 | 355 | UPDATE STATISTICS sys.plan_persist_context_settings; 356 | UPDATE STATISTICS sys.plan_persist_plan; 357 | UPDATE STATISTICS sys.plan_persist_plan_feedback; 358 | UPDATE STATISTICS sys.plan_persist_query; 359 | UPDATE STATISTICS sys.plan_persist_query_hints; 360 | UPDATE STATISTICS sys.plan_persist_query_template_parameterization; 361 | UPDATE STATISTICS sys.plan_persist_query_text; 362 | UPDATE STATISTICS sys.plan_persist_runtime_stats; 363 | UPDATE STATISTICS sys.plan_persist_runtime_stats_interval; 364 | UPDATE STATISTICS sys.plan_persist_wait_stats; 365 | 366 | END TRY 367 | BEGIN CATCH 368 | RAISERROR('Query Store statistics not updated, possibly due to insufficient permissions', 10, 1); 369 | END CATCH; 370 | 371 | -- query wait stats aggregated by query hash and wait category 372 | WITH 373 | query_wait_stats AS 374 | ( 375 | SELECT q.query_hash, 376 | ws.wait_category_desc, 377 | SUM(ws.total_query_wait_time_ms) AS total_query_wait_time_ms 378 | FROM sys.query_store_query AS q 379 | INNER JOIN sys.query_store_plan AS p 380 | ON q.query_id = p.query_id 381 | INNER JOIN sys.query_store_wait_stats AS ws 382 | ON p.plan_id = ws.plan_id 383 | INNER JOIN sys.query_store_runtime_stats_interval AS rsi 384 | ON ws.runtime_stats_interval_id = rsi.runtime_stats_interval_id 385 | WHERE q.is_internal_query = 0 386 | AND 387 | q.is_clouddb_internal_query = 0 388 | AND 389 | rsi.start_time >= @QueryStoreTimeFrom 390 | AND 391 | rsi.start_time <= @QueryStoreTimeThru 392 | GROUP BY q.query_hash, 393 | ws.wait_category_desc 394 | ), 395 | query_wait_stats_ratio AS 396 | ( 397 | SELECT query_hash, 398 | total_query_wait_time_ms, 399 | CONCAT( 400 | wait_category_desc, 401 | ' (', 402 | CAST(CAST(total_query_wait_time_ms * 1. / SUM(total_query_wait_time_ms) OVER (PARTITION BY query_hash) AS decimal(4,3)) AS varchar(5)), 403 | ')' 404 | ) AS wait_category_desc -- append relative wait weight to category name 405 | FROM query_wait_stats 406 | ), 407 | -- query wait stats aggregated by query hash, with concatenated list of wait categories ranked with longest first 408 | query_wait_stats_summary AS 409 | ( 410 | SELECT query_hash, 411 | STRING_AGG(wait_category_desc, ' | ') 412 | AS ranked_wait_categories 413 | FROM query_wait_stats_ratio 414 | GROUP BY query_hash 415 | ) 416 | INSERT INTO #query_wait_stats_summary (query_hash, ranked_wait_categories) -- persist into a temp table for perf reasons 417 | SELECT query_hash, ranked_wait_categories 418 | FROM query_wait_stats_summary 419 | OPTION (RECOMPILE); 420 | 421 | UPDATE STATISTICS #query_wait_stats_summary; 422 | 423 | -- query runtime stats aggregated by query hash 424 | WITH 425 | query_runtime_stats AS 426 | ( 427 | SELECT q.query_hash, 428 | COUNT(DISTINCT(q.query_id)) AS count_queries, 429 | MAX(q.query_id) AS query_id, 430 | COUNT(DISTINCT(p.plan_id)) AS count_plans, 431 | MAX(p.plan_id) AS plan_id, 432 | SUM(IIF(rs.execution_type_desc = 'Regular', rs.count_executions, 0)) AS count_regular_executions, 433 | SUM(IIF(rs.execution_type_desc = 'Aborted', rs.count_executions, 0)) AS count_aborted_executions, 434 | SUM(IIF(rs.execution_type_desc = 'Exception', rs.count_executions, 0)) AS count_exception_executions, 435 | SUM(rs.count_executions) AS count_executions, 436 | SUM(rs.avg_cpu_time * rs.count_executions) AS total_cpu_time, 437 | SUM(rs.avg_duration * rs.count_executions) AS total_duration, 438 | SUM(rs.avg_logical_io_reads * rs.count_executions) AS total_logical_io_reads, 439 | SUM(rs.avg_physical_io_reads * rs.count_executions) AS total_physical_io_reads, 440 | SUM(rs.avg_query_max_used_memory * rs.count_executions) AS total_query_max_used_memory, 441 | SUM(rs.avg_log_bytes_used * rs.count_executions) AS total_log_bytes_used, 442 | SUM(rs.avg_tempdb_space_used * rs.count_executions) AS total_tempdb_space_used, 443 | SUM(rs.avg_dop * rs.count_executions) AS total_dop 444 | FROM sys.query_store_query AS q 445 | INNER JOIN sys.query_store_plan AS p 446 | ON q.query_id = p.query_id 447 | INNER JOIN sys.query_store_runtime_stats AS rs 448 | ON p.plan_id = rs.plan_id 449 | INNER JOIN sys.query_store_runtime_stats_interval AS rsi 450 | ON rs.runtime_stats_interval_id = rsi.runtime_stats_interval_id 451 | WHERE q.is_internal_query = 0 452 | AND 453 | q.is_clouddb_internal_query = 0 454 | AND 455 | rsi.start_time >= @QueryStoreTimeFrom 456 | AND 457 | rsi.start_time <= @QueryStoreTimeThru 458 | GROUP BY q.query_hash 459 | ), 460 | -- rank queries along multiple dimensions (cpu, duration, etc.), without ties 461 | query_rank AS 462 | ( 463 | SELECT rs.query_hash, 464 | rs.count_queries, 465 | rs.query_id, 466 | rs.count_plans, 467 | rs.plan_id, 468 | rs.count_regular_executions, 469 | rs.count_aborted_executions, 470 | rs.count_exception_executions, 471 | ROW_NUMBER() OVER (ORDER BY rs.total_cpu_time DESC) AS cpu_time_rank, 472 | ROW_NUMBER() OVER (ORDER BY rs.total_duration DESC) AS duration_rank, 473 | ROW_NUMBER() OVER (ORDER BY rs.total_logical_io_reads DESC) AS logical_io_reads_rank, 474 | ROW_NUMBER() OVER (ORDER BY rs.total_physical_io_reads DESC) AS physical_io_reads_rank, 475 | ROW_NUMBER() OVER (ORDER BY rs.count_executions DESC) AS executions_rank, 476 | ROW_NUMBER() OVER (ORDER BY rs.total_query_max_used_memory DESC) AS total_query_max_used_memory_rank, 477 | ROW_NUMBER() OVER (ORDER BY rs.total_log_bytes_used DESC) AS total_log_bytes_used_rank, 478 | ROW_NUMBER() OVER (ORDER BY rs.total_tempdb_space_used DESC) AS total_tempdb_space_used_rank, 479 | ROW_NUMBER() OVER (ORDER BY rs.total_dop DESC) AS total_dop_rank, 480 | -- if total_cpu_time for a query is 2 times less than for the immediately higher query in the rank order, do not consider it a top query 481 | -- top_cpu_cutoff_indicator = 0 signifies a top query; the query where top_cpu_cutoff_indicator is 1 and any query with lower rank will be filtered out 482 | IIF(rs.total_cpu_time * 1. / NULLIF(LEAD(rs.total_cpu_time) OVER (ORDER BY rs.total_cpu_time), 0) < 0.5, 1, 0) AS top_cpu_cutoff_indicator, 483 | IIF(rs.total_duration * 1. / NULLIF(LEAD(rs.total_duration) OVER (ORDER BY rs.total_duration), 0) < 0.5, 1, 0) AS top_duration_cutoff_indicator, 484 | IIF(rs.total_logical_io_reads * 1. / NULLIF(LEAD(rs.total_logical_io_reads) OVER (ORDER BY rs.total_logical_io_reads), 0) < 0.5, 1, 0) AS top_logical_io_reads_cutoff_indicator, 485 | IIF(rs.total_physical_io_reads * 1. / NULLIF(LEAD(rs.total_physical_io_reads) OVER (ORDER BY rs.total_physical_io_reads), 0) < 0.5, 1, 0) AS top_physical_io_reads_cutoff_indicator, 486 | IIF(rs.count_executions * 1. / NULLIF(LEAD(rs.count_executions) OVER (ORDER BY rs.count_executions), 0) < 0.5, 1, 0) AS top_executions_cutoff_indicator, 487 | IIF(rs.total_query_max_used_memory * 1. / NULLIF(LEAD(rs.total_query_max_used_memory) OVER (ORDER BY rs.total_query_max_used_memory), 0) < 0.5, 1, 0) AS top_memory_cutoff_indicator, 488 | IIF(rs.total_log_bytes_used * 1. / NULLIF(LEAD(rs.total_log_bytes_used) OVER (ORDER BY rs.total_log_bytes_used), 0) < 0.5, 1, 0) AS top_log_bytes_cutoff_indicator, 489 | IIF(rs.total_tempdb_space_used * 1. / NULLIF(LEAD(rs.total_tempdb_space_used) OVER (ORDER BY rs.total_tempdb_space_used), 0) < 0.5, 1, 0) AS top_tempdb_cutoff_indicator, 490 | IIF(rs.total_dop * 1. / NULLIF(LEAD(rs.total_dop) OVER (ORDER BY rs.total_dop), 0) < 0.5, 1, 0) AS top_dop_cutoff_indicator, 491 | ws.ranked_wait_categories 492 | FROM query_runtime_stats AS rs 493 | LEFT JOIN #query_wait_stats_summary AS ws -- outer join in case wait stats collection is not enabled or waits are not available otherwise 494 | ON rs.query_hash = ws.query_hash 495 | ), 496 | -- add running sums of cut off indicators along rank order; indicators will remain 0 for top queries, and >0 otherwise 497 | top_query_rank AS 498 | ( 499 | SELECT *, 500 | SUM(top_cpu_cutoff_indicator) OVER (ORDER BY cpu_time_rank ROWS UNBOUNDED PRECEDING) AS top_cpu_indicator, 501 | SUM(top_duration_cutoff_indicator) OVER (ORDER BY duration_rank ROWS UNBOUNDED PRECEDING) AS top_duration_indicator, 502 | SUM(top_logical_io_reads_cutoff_indicator) OVER (ORDER BY logical_io_reads_rank ROWS UNBOUNDED PRECEDING) AS top_logical_io_indicator, 503 | SUM(top_physical_io_reads_cutoff_indicator) OVER (ORDER BY physical_io_reads_rank ROWS UNBOUNDED PRECEDING) AS top_physical_io_indicator, 504 | SUM(top_executions_cutoff_indicator) OVER (ORDER BY executions_rank ROWS UNBOUNDED PRECEDING) AS top_executions_indicator, 505 | SUM(top_memory_cutoff_indicator) OVER (ORDER BY total_query_max_used_memory_rank ROWS UNBOUNDED PRECEDING) AS top_memory_indicator, 506 | SUM(top_log_bytes_cutoff_indicator) OVER (ORDER BY total_log_bytes_used_rank ROWS UNBOUNDED PRECEDING) AS top_log_bytes_indicator, 507 | SUM(top_tempdb_cutoff_indicator) OVER (ORDER BY total_tempdb_space_used_rank ROWS UNBOUNDED PRECEDING) AS top_tempdb_indicator, 508 | SUM(top_dop_cutoff_indicator) OVER (ORDER BY total_dop_rank ROWS UNBOUNDED PRECEDING) AS top_dop_indicator 509 | FROM query_rank 510 | ), 511 | -- restrict to a union of queries that are top queries on some dimension; then, restrict further to top-within-top N queries along any dimension 512 | top_query AS 513 | ( 514 | SELECT query_hash, 515 | count_queries, 516 | query_id, 517 | count_plans, 518 | plan_id, 519 | count_regular_executions, 520 | count_aborted_executions, 521 | count_exception_executions, 522 | cpu_time_rank, 523 | duration_rank, 524 | logical_io_reads_rank, 525 | physical_io_reads_rank, 526 | executions_rank, 527 | total_query_max_used_memory_rank, 528 | total_log_bytes_used_rank, 529 | total_tempdb_space_used_rank, 530 | total_dop_rank, 531 | ranked_wait_categories 532 | FROM top_query_rank 533 | WHERE ( 534 | top_cpu_indicator = 0 535 | OR 536 | top_duration_indicator = 0 537 | OR 538 | top_executions_indicator = 0 539 | OR 540 | top_logical_io_indicator = 0 541 | OR 542 | top_physical_io_indicator = 0 543 | OR 544 | top_memory_indicator = 0 545 | OR 546 | top_log_bytes_indicator = 0 547 | OR 548 | top_tempdb_indicator = 0 549 | OR 550 | top_dop_indicator = 0 551 | ) 552 | AND 553 | ( 554 | cpu_time_rank <= @QueryStoreTopQueryCount 555 | OR 556 | duration_rank <= @QueryStoreTopQueryCount 557 | OR 558 | executions_rank <= @QueryStoreTopQueryCount 559 | OR 560 | logical_io_reads_rank <= @QueryStoreTopQueryCount 561 | OR 562 | physical_io_reads_rank <= @QueryStoreTopQueryCount 563 | OR 564 | total_query_max_used_memory_rank <= @QueryStoreTopQueryCount 565 | OR 566 | total_log_bytes_used_rank <= @QueryStoreTopQueryCount 567 | OR 568 | total_tempdb_space_used_rank <= @QueryStoreTopQueryCount 569 | OR 570 | total_dop_rank <= @QueryStoreTopQueryCount 571 | ) 572 | ) 573 | INSERT INTO @DetectedTip (tip_id, details) 574 | SELECT 1320 AS tip_id, 575 | CONCAT( 576 | @NbspCRLF, 577 | 'server: ', @@SERVERNAME, 578 | ', database: ', DB_NAME(), 579 | ', SLO: ', rg.slo_name, 580 | ', updateability: ', CAST(DATABASEPROPERTYEX(DB_NAME(), 'Updateability') AS nvarchar(10)), 581 | ', logical database GUID: ', rg.logical_database_guid, 582 | ', physical database GUID: ', rg.physical_database_guid, 583 | ', script execution timestamp (UTC): ', CONVERT(varchar(20), SYSUTCDATETIME(), 120), 584 | @CRLF, @CRLF, 585 | STRING_AGG( 586 | CAST(CONCAT( 587 | 'query hash: ', CONVERT(varchar(30), query_hash, 1), 588 | ', query_id: ', CAST(query_id AS varchar(11)), IIF(count_queries > 1, CONCAT(' (+', CAST(count_queries - 1 AS varchar(11)), ')'), ''), 589 | ', plan_id: ', CAST(plan_id AS varchar(11)), IIF(count_plans > 1, CONCAT(' (+', CAST(count_plans - 1 AS varchar(11)), ')'), ''), 590 | ', executions: (regular: ', CAST(count_regular_executions AS varchar(11)), ', aborted: ', CAST(count_aborted_executions AS varchar(11)), ', exception: ', CAST(count_exception_executions AS varchar(11)), ')', 591 | ', CPU time rank: ', CAST(cpu_time_rank AS varchar(11)), 592 | ', duration rank: ', CAST(duration_rank AS varchar(11)), 593 | ', executions rank: ', CAST(executions_rank AS varchar(11)), 594 | ', logical IO reads rank: ', CAST(logical_io_reads_rank AS varchar(11)), 595 | ', physical IO reads rank: ', CAST(physical_io_reads_rank AS varchar(11)), 596 | ', max used memory rank: ', CAST(total_query_max_used_memory_rank AS varchar(11)), 597 | ', log bytes used rank: ', CAST(total_log_bytes_used_rank AS varchar(11)), 598 | ', tempdb used rank: ', CAST(total_tempdb_space_used_rank AS varchar(11)), 599 | ', parallelism rank: ', CAST(total_dop_rank AS varchar(11)), 600 | ', weighted wait categories: ', ISNULL(ranked_wait_categories, '-') 601 | ) AS nvarchar(max)), @CRLF 602 | ), 603 | @CRLF 604 | ) 605 | AS details 606 | FROM top_query 607 | CROSS JOIN sys.dm_user_db_resource_governance AS rg 608 | WHERE rg.database_id = DB_ID() 609 | GROUP BY rg.slo_name, 610 | rg.logical_database_guid, 611 | rg.physical_database_guid 612 | HAVING COUNT(1) > 0 613 | OPTION (RECOMPILE); 614 | 615 | END TRY 616 | BEGIN CATCH 617 | IF ERROR_NUMBER() = 1222 618 | INSERT INTO @SkippedTip (tip_id) 619 | VALUES (1320); 620 | ELSE 621 | THROW; 622 | END CATCH; 623 | 624 | END; 625 | 626 | -- MAXDOP 627 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1000,1010,1020) AND execute_indicator = 1) 628 | 629 | WITH maxdop_config AS 630 | ( 631 | SELECT c.value, 632 | c.value_for_secondary 633 | FROM sys.database_scoped_configurations AS c 634 | CROSS JOIN sys.dm_user_db_resource_governance AS g 635 | WHERE 636 | @EngineEdition = 5 637 | AND 638 | c.name = N'MAXDOP' 639 | AND 640 | g.database_id = DB_ID() 641 | AND 642 | g.cpu_limit > 8 643 | ) 644 | INSERT INTO @DetectedTip (tip_id, details) 645 | SELECT t.tip_id, 646 | CONCAT( 647 | @NbspCRLF, 648 | 'MAXDOP for primary: ', CAST(mc.value AS varchar(2)), @CRLF, 649 | 'MAXDOP for secondary: ', ISNULL(CAST(mc.value_for_secondary AS varchar(4)), 'NULL'), @CRLF 650 | ) 651 | AS details 652 | FROM maxdop_config AS mc 653 | INNER JOIN ( 654 | VALUES (1000),(1010),(1020) 655 | ) AS t (tip_id) 656 | ON (t.tip_id = 1000 AND mc.value NOT BETWEEN 1 AND 8 AND (mc.value_for_secondary IS NULL OR mc.value_for_secondary NOT BETWEEN 1 AND 8)) 657 | OR 658 | (t.tip_id = 1010 AND mc.value NOT BETWEEN 1 AND 8 AND mc.value_for_secondary BETWEEN 1 AND 8) 659 | OR 660 | (t.tip_id = 1020 AND mc.value BETWEEN 1 AND 8 AND mc.value_for_secondary NOT BETWEEN 1 AND 8) 661 | INNER JOIN @TipDefinition AS td 662 | ON t.tip_id = td.tip_id 663 | WHERE td.execute_indicator = 1 664 | ; 665 | 666 | -- Compatibility level 667 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1030) AND execute_indicator = 1) 668 | 669 | BEGIN TRY 670 | 671 | INSERT INTO @DetectedTip (tip_id, details) 672 | SELECT 1030 AS tip_id, 673 | CONCAT(@NbspCRLF, 'Present database compatibility level: ', CAST(d.compatibility_level AS varchar(3)), @CRLF) AS details 674 | FROM sys.dm_exec_valid_use_hints AS h 675 | CROSS JOIN sys.databases AS d 676 | WHERE h.name LIKE 'QUERY[_]OPTIMIZER[_]COMPATIBILITY[_]LEVEL[_]%' 677 | AND 678 | d.name = DB_NAME() 679 | AND 680 | TRY_CAST(RIGHT(h.name, CHARINDEX('_', REVERSE(h.name)) - 1) AS smallint) > d.compatibility_level 681 | GROUP BY d.compatibility_level 682 | HAVING COUNT(1) > 1 -- Consider the last two compat levels (including the one possibly in preview) as current 683 | ; 684 | 685 | END TRY 686 | BEGIN CATCH 687 | IF ERROR_NUMBER() = 1222 688 | INSERT INTO @SkippedTip (tip_id) 689 | VALUES (1030); 690 | ELSE 691 | THROW; 692 | END CATCH; 693 | 694 | -- Auto-stats 695 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1040,1050) AND execute_indicator = 1) 696 | 697 | BEGIN TRY 698 | 699 | WITH autostats AS 700 | ( 701 | SELECT t.tip_id 702 | FROM sys.databases AS d 703 | INNER JOIN ( 704 | VALUES (1040),(1050) 705 | ) AS t (tip_id) 706 | ON (t.tip_id = 1040 AND d.is_auto_create_stats_on = 0) 707 | OR 708 | (t.tip_id = 1050 AND d.is_auto_update_stats_on = 0) 709 | INNER JOIN @TipDefinition AS td 710 | ON t.tip_id = td.tip_id 711 | WHERE d.name = DB_NAME() 712 | AND 713 | ( 714 | d.is_auto_create_stats_on = 0 715 | OR 716 | d.is_auto_update_stats_on = 0 717 | ) 718 | AND 719 | td.execute_indicator = 1 720 | ) 721 | INSERT INTO @DetectedTip (tip_id) 722 | SELECT tip_id 723 | FROM autostats; 724 | 725 | END TRY 726 | BEGIN CATCH 727 | IF ERROR_NUMBER() = 1222 728 | INSERT INTO @SkippedTip (tip_id) 729 | VALUES (1040),(1050); 730 | ELSE 731 | THROW; 732 | END CATCH; 733 | 734 | -- RCSI 735 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1060) AND execute_indicator = 1) 736 | 737 | BEGIN TRY 738 | 739 | INSERT INTO @DetectedTip (tip_id) 740 | SELECT 1060 AS tip_id 741 | FROM sys.databases 742 | WHERE name = DB_NAME() 743 | AND 744 | is_read_committed_snapshot_on = 0; 745 | 746 | END TRY 747 | BEGIN CATCH 748 | IF ERROR_NUMBER() = 1222 749 | INSERT INTO @SkippedTip (tip_id) 750 | VALUES (1060); 751 | ELSE 752 | THROW; 753 | END CATCH; 754 | 755 | -- Query Store state 756 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1070,1071,1072) AND execute_indicator = 1) 757 | 758 | BEGIN TRY 759 | 760 | INSERT INTO @DetectedTip (tip_id, details) 761 | SELECT t.tip_id, 762 | IIF( 763 | t.tip_id = 1071 AND qso.desired_state_desc = 'READ_WRITE', 764 | CONCAT( 765 | @NbspCRLF, 766 | CASE qso.readonly_reason 767 | WHEN 1 THEN 'Database is in read-only mode.' 768 | WHEN 2 THEN 'Database is in single-user mode.' 769 | WHEN 4 THEN 'Database in in emergency mode.' 770 | WHEN 8 THEN 'Database is a read-only replica.' 771 | WHEN 65536 THEN 'The size of Query Store has reached the limit set by MAX_STORAGE_SIZE_MB option.' 772 | WHEN 131072 THEN 'The number of queries in Query Store has reached the limit for the service objective. Remove unneeded queries or scale up to a higher service objective.' 773 | WHEN 262144 THEN 'The size of in-memory Query Store data has reached maximum limit. Query Store will be in read-only state while this data is being persisted in the database.' 774 | WHEN 524288 THEN 'Database has reached its maximum size limit.' 775 | END, 776 | @CRLF 777 | ), 778 | NULL 779 | ) 780 | AS details 781 | FROM sys.database_query_store_options AS qso 782 | INNER JOIN ( 783 | VALUES (1070),(1071),(1072) 784 | ) AS t (tip_id) 785 | ON (t.tip_id = 1070 AND qso.actual_state_desc = 'OFF') 786 | OR 787 | (t.tip_id = 1071 AND qso.actual_state_desc = 'READ_ONLY') 788 | OR 789 | (t.tip_id = 1072 AND qso.query_capture_mode_desc = 'NONE') 790 | INNER JOIN @TipDefinition AS td 791 | ON t.tip_id = td.tip_id 792 | WHERE DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 793 | AND 794 | td.execute_indicator = 1 795 | ; 796 | 797 | END TRY 798 | BEGIN CATCH 799 | IF ERROR_NUMBER() = 1222 800 | INSERT INTO @SkippedTip (tip_id) 801 | VALUES (1070),(1071),(1072); 802 | ELSE 803 | THROW; 804 | END CATCH; 805 | 806 | -- Auto-shrink 807 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1080) AND execute_indicator = 1) 808 | 809 | BEGIN TRY 810 | 811 | INSERT INTO @DetectedTip (tip_id) 812 | SELECT 1080 AS tip_id 813 | FROM sys.databases 814 | WHERE name = DB_NAME() 815 | AND 816 | is_auto_shrink_on = 1; 817 | 818 | END TRY 819 | BEGIN CATCH 820 | IF ERROR_NUMBER() = 1222 821 | INSERT INTO @SkippedTip (tip_id) 822 | VALUES (1080); 823 | ELSE 824 | THROW; 825 | END CATCH; 826 | 827 | -- Btree indexes with uniqueidentifier leading column 828 | -- This and all other tips querying sys.dm_db_partition_stats may be silently skipped 829 | -- when running with limited permissions and not holding both VIEW DATABASE STATE and VIEW DEFINITION. 830 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1100) AND execute_indicator = 1) 831 | 832 | BEGIN TRY 833 | 834 | WITH 835 | partition_size AS 836 | ( 837 | SELECT object_id, 838 | used_page_count, 839 | row_count 840 | FROM sys.dm_db_partition_stats 841 | WHERE index_id IN (0,1) 842 | UNION 843 | -- special index types 844 | SELECT it.parent_object_id, 845 | ps.used_page_count, 846 | 0 AS row_count 847 | FROM sys.dm_db_partition_stats AS ps 848 | INNER JOIN sys.internal_tables AS it 849 | ON ps.object_id = it.object_id 850 | WHERE it.internal_type_desc IN ( 851 | 'XML_INDEX_NODES','SELECTIVE_XML_INDEX_NODE_TABLE', -- XML indexes 852 | 'EXTENDED_INDEXES', -- spatial indexes 853 | 'FULLTEXT_INDEX_MAP','FULLTEXT_AVDL','FULLTEXT_COMP_FRAGMENT','FULLTEXT_DOCID_STATUS','FULLTEXT_INDEXED_DOCID','FULLTEXT_DOCID_FILTER','FULLTEXT_DOCID_MAP', -- fulltext indexes 854 | 'SEMPLAT_DOCUMENT_INDEX_TABLE','SEMPLAT_TAG_INDEX_TABLE' -- semantic search indexes 855 | ) 856 | ), 857 | object_size AS 858 | ( 859 | SELECT object_id, 860 | SUM(used_page_count) * 8 / 1024. AS object_size_mb, 861 | SUM(row_count) AS object_row_count 862 | FROM partition_size 863 | GROUP BY object_id 864 | ), 865 | guid_index AS 866 | ( 867 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 868 | QUOTENAME(o.name) COLLATE DATABASE_DEFAULT AS object_name, 869 | QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name, 870 | i.type_desc COLLATE DATABASE_DEFAULT AS index_type, 871 | o.object_id, 872 | i.index_id, 873 | os.object_size_mb, 874 | os.object_row_count 875 | FROM sys.objects AS o 876 | INNER JOIN sys.indexes AS i 877 | ON o.object_id = i.object_id 878 | INNER JOIN sys.index_columns AS ic 879 | ON i.object_id = ic.object_id 880 | AND 881 | i.index_id = ic.index_id 882 | INNER JOIN sys.columns AS c 883 | ON i.object_id = c.object_id 884 | AND 885 | ic.object_id = c.object_id 886 | AND 887 | ic.column_id = c.column_id 888 | INNER JOIN sys.types AS t 889 | ON c.system_type_id = t.system_type_id 890 | INNER JOIN object_size AS os 891 | ON o.object_id = os.object_id 892 | WHERE i.type_desc IN ('CLUSTERED','NONCLUSTERED') -- Btree indexes 893 | AND 894 | ic.key_ordinal = 1 -- leading column 895 | AND 896 | t.name = 'uniqueidentifier' 897 | AND 898 | i.is_hypothetical = 0 899 | AND 900 | i.is_disabled = 0 901 | AND 902 | o.is_ms_shipped = 0 903 | AND 904 | os.object_size_mb > @GuidLeadingColumnObjectMinSizeMB -- consider larger tables only 905 | AND 906 | -- data type is uniqueidentifier or an alias data type derived from uniqueidentifier 907 | EXISTS ( 908 | SELECT 1 909 | FROM sys.types AS t1 910 | LEFT JOIN sys.types AS t2 911 | ON t1.system_type_id = t2.system_type_id 912 | WHERE t1.name = 'uniqueidentifier' 913 | AND 914 | c.user_type_id = t2.user_type_id 915 | ) 916 | ) 917 | INSERT INTO @DetectedTip (tip_id, details) 918 | SELECT 1100 AS tip_id, 919 | CONCAT( 920 | @NbspCRLF, 921 | 'Total indexes: ', FORMAT(COUNT(1), '#,0'), 922 | @CRLF, @CRLF, 923 | STRING_AGG( 924 | CAST(CONCAT( 925 | 'schema: ', schema_name, 926 | ', object: ', object_name, 927 | ', object size (MB): ', FORMAT(object_size_mb, '#,0.00'), 928 | ', object row count: ', FORMAT(object_row_count, '#,0'), 929 | ', index: ', index_name, 930 | ', type: ', index_type 931 | ) AS nvarchar(max)), @CRLF 932 | ), 933 | @CRLF 934 | ) 935 | AS details 936 | FROM guid_index 937 | HAVING COUNT(1) > 0; 938 | 939 | END TRY 940 | BEGIN CATCH 941 | IF ERROR_NUMBER() = 1222 942 | INSERT INTO @SkippedTip (tip_id) 943 | VALUES (1100); 944 | ELSE 945 | THROW; 946 | END CATCH; 947 | 948 | -- FLGP auto-tuning 949 | INSERT INTO @DetectedTip (tip_id, details) 950 | SELECT 1110 AS tip_id, 951 | CONCAT(@NbspCRLF, 'Reason: ' + NULLIF(reason_desc, ''), @CRLF) AS details 952 | FROM sys.database_automatic_tuning_options 953 | WHERE name = 'FORCE_LAST_GOOD_PLAN' 954 | AND 955 | actual_state_desc <> 'ON' 956 | AND 957 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 958 | ; 959 | 960 | -- Used space close to maxsize 961 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1120) AND execute_indicator = 1) 962 | 963 | WITH space_used AS 964 | ( 965 | SELECT SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint) * 8 / 1024.) AS space_used_mb, 966 | CAST(DATABASEPROPERTYEX(DB_NAME(), 'MaxSizeInBytes') AS bigint) / 1024. / 1024 AS max_size_mb 967 | FROM sys.database_files 968 | WHERE @EngineEdition = 5 969 | AND 970 | type_desc = 'ROWS' 971 | AND 972 | CAST(DATABASEPROPERTYEX(DB_NAME(), 'MaxSizeInBytes') AS bigint) <> -1 -- not applicable to Hyperscale 973 | HAVING COUNT(1) > 0 974 | ) 975 | INSERT INTO @DetectedTip (tip_id, details) 976 | SELECT 1120 AS tip_id, 977 | CONCAT( 978 | @NbspCRLF, 979 | 'Used data size (MB): ', FORMAT(space_used_mb, '#,0.00'), 980 | ', maximum data size (MB): ', FORMAT(max_size_mb, '#,0.00'), 981 | @CRLF 982 | ) 983 | FROM space_used 984 | WHERE space_used_mb > @UsedToMaxsizeSpaceThresholdRatio * max_size_mb -- used space > n% of db maxsize 985 | ; 986 | 987 | -- Allocated space close to maxsize 988 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1130) AND execute_indicator = 1) 989 | 990 | WITH space_allocated AS 991 | ( 992 | SELECT SUM(CAST(size AS bigint) * 8 / 1024.) AS space_allocated_mb, 993 | CAST(DATABASEPROPERTYEX(DB_NAME(), 'MaxSizeInBytes') AS bigint) / 1024. / 1024 AS max_size_mb 994 | FROM sys.database_files 995 | WHERE @EngineEdition = 5 996 | AND 997 | type_desc = 'ROWS' 998 | AND 999 | CAST(DATABASEPROPERTYEX(DB_NAME(), 'MaxSizeInBytes') AS bigint) <> -1 -- not applicable to Hyperscale 1000 | AND 1001 | DATABASEPROPERTYEX(DB_NAME(), 'Edition') IN ('Premium','BusinessCritical') -- not relevant for remote storage SLOs 1002 | HAVING COUNT(1) > 0 1003 | ) 1004 | INSERT INTO @DetectedTip (tip_id, details) 1005 | SELECT 1130 AS tip_id, 1006 | CONCAT( 1007 | @NbspCRLF, 1008 | 'Allocated data size (MB): ', FORMAT(space_allocated_mb, '#,0.00'), 1009 | ', maximum data size (MB): ', FORMAT(max_size_mb, '#,0.00'), 1010 | @CRLF 1011 | ) 1012 | FROM space_allocated 1013 | WHERE space_allocated_mb > @AllocatedToMaxsizeSpaceThresholdRatio * max_size_mb -- allocated space > n% of db maxsize 1014 | ; 1015 | 1016 | -- Allocated space >> used space 1017 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1140) AND execute_indicator = 1) 1018 | 1019 | WITH allocated_used_space AS 1020 | ( 1021 | SELECT SUM(CAST(size AS bigint) * 8 / 1024.) AS space_allocated_mb, 1022 | SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint)) * 8 / 1024. AS space_used_mb 1023 | FROM sys.database_files 1024 | WHERE type_desc = 'ROWS' 1025 | ) 1026 | INSERT INTO @DetectedTip (tip_id, details) 1027 | SELECT 1140 AS tip_id, 1028 | CONCAT( 1029 | @NbspCRLF, 1030 | 'Used data size (MB): ', FORMAT(space_used_mb, '#,0.00'), 1031 | ', allocated data size (MB): ', FORMAT(space_allocated_mb, '#,0.00'), 1032 | @CRLF 1033 | ) 1034 | FROM allocated_used_space 1035 | WHERE space_used_mb > @UsedToAllocatedSpaceDbMinSizeMB -- not relevant for small databases 1036 | AND 1037 | @UsedToAllocatedSpaceThresholdRatio * space_allocated_mb > space_used_mb -- allocated space is more than N times used space 1038 | AND 1039 | DATABASEPROPERTYEX(DB_NAME(), 'Edition') IN ('Premium','BusinessCritical') -- not relevant for remote storage SLOs 1040 | ; 1041 | 1042 | -- High log rate 1043 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1190) AND execute_indicator = 1) 1044 | 1045 | WITH 1046 | log_rate_snapshot AS 1047 | ( 1048 | SELECT end_time, 1049 | avg_log_write_percent, 1050 | IIF(avg_log_write_percent > @HighLogRateThresholdPercent, 1, 0) AS high_log_rate_indicator 1051 | FROM sys.dm_db_resource_stats 1052 | WHERE @EngineEdition = 5 1053 | AND 1054 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 1055 | ), 1056 | pre_packed_log_rate_snapshot AS 1057 | ( 1058 | SELECT end_time, 1059 | avg_log_write_percent, 1060 | high_log_rate_indicator, 1061 | ROW_NUMBER() OVER (ORDER BY end_time) -- row number across all readings, in increasing chronological order 1062 | - 1063 | SUM(high_log_rate_indicator) OVER (ORDER BY end_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where log rate exceeded the threshold 1064 | AS grouping_helper -- this difference remains constant while log rate is above the threshold, and can be used to collapse/pack an interval using aggregation 1065 | FROM log_rate_snapshot 1066 | ), 1067 | packed_log_rate_snapshot AS 1068 | ( 1069 | SELECT MIN(end_time) AS min_end_time, 1070 | MAX(end_time) AS max_end_time, 1071 | MAX(avg_log_write_percent) AS max_log_write_percent 1072 | FROM pre_packed_log_rate_snapshot 1073 | WHERE high_log_rate_indicator = 1 1074 | GROUP BY grouping_helper 1075 | ), 1076 | log_rate_top_stat AS 1077 | ( 1078 | SELECT MAX(DATEDIFF(second, min_end_time, max_end_time)) AS top_log_rate_duration_seconds, 1079 | MAX(max_log_write_percent) AS top_log_write_percent, 1080 | COUNT(1) AS count_high_log_write_intervals 1081 | FROM packed_log_rate_snapshot 1082 | ) 1083 | INSERT INTO @DetectedTip (tip_id, details) 1084 | SELECT 1190 AS tip_id, 1085 | CONCAT( 1086 | @NbspCRLF, 1087 | 'In the last hour, there were ', count_high_log_write_intervals, 1088 | ' interval(s) with transaction log IO staying above ', @HighLogRateThresholdPercent, 1089 | '% of the service objective limit. The longest such interval lasted ', FORMAT(top_log_rate_duration_seconds, '#,0'), 1090 | ' seconds, and the maximum log IO was ', FORMAT(top_log_write_percent, '#,0.00'), 1091 | '%.', 1092 | @CRLF 1093 | ) AS details 1094 | FROM log_rate_top_stat 1095 | WHERE count_high_log_write_intervals > 0 1096 | ; 1097 | 1098 | -- Plan cache bloat from single-use plans 1099 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1200) AND execute_indicator = 1) 1100 | 1101 | WITH plan_cache_db_summary AS 1102 | ( 1103 | SELECT t.dbid AS database_id, -- In an elastic pool, return data for all databases 1104 | DB_NAME(t.dbid) AS database_name, 1105 | SUM(IIF(cp.usecounts = 1, cp.size_in_bytes / 1024. / 1024, 0)) AS single_use_db_plan_cache_size_mb, 1106 | SUM(cp.size_in_bytes / 1024. / 1024) AS total_db_plan_cache_size_mb 1107 | FROM sys.dm_exec_cached_plans AS cp 1108 | CROSS APPLY sys.dm_exec_sql_text(cp.plan_handle) AS t 1109 | WHERE cp.objtype IN ('Adhoc','Prepared') 1110 | AND 1111 | cp.cacheobjtype = 'Compiled Plan' 1112 | AND 1113 | t.dbid BETWEEN 5 AND 32700 -- exclude system databases 1114 | GROUP BY t.dbid 1115 | ) 1116 | INSERT INTO @DetectedTip (tip_id, details) 1117 | SELECT 1200 AS tip_id, 1118 | CONCAT( 1119 | @NbspCRLF, 1120 | STRING_AGG( 1121 | CAST(CONCAT( 1122 | 'database (id: ', database_id, 1123 | ', name: ' + QUOTENAME(database_name), -- database name is only available for current database, include for usability if available 1124 | '), single use plans take ', FORMAT(single_use_db_plan_cache_size_mb, 'N'), 1125 | ' MB, or ', FORMAT(single_use_db_plan_cache_size_mb / total_db_plan_cache_size_mb, 'P'), 1126 | ' of total cached plans for this database.' 1127 | ) AS nvarchar(max)), @CRLF 1128 | ), 1129 | @CRLF 1130 | ) 1131 | AS details 1132 | FROM plan_cache_db_summary 1133 | WHERE single_use_db_plan_cache_size_mb >= @SingleUsePlanSizeThresholdMB -- sufficiently large total size of single-use plans for a database 1134 | AND 1135 | single_use_db_plan_cache_size_mb * 1. / total_db_plan_cache_size_mb > @SingleUseTotalPlanSizeRatioThreshold -- single-use plans take more than n% of total plan cache size 1136 | HAVING COUNT(1) > 0 1137 | ; 1138 | 1139 | -- Redo queue is large 1140 | -- Applicable to Premium/Business Critical read scale-out replicas and all non-Hyperscale geo-replicas 1141 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1220) AND execute_indicator = 1) 1142 | 1143 | INSERT INTO @DetectedTip (tip_id, details) 1144 | SELECT 1220 AS tip_id, 1145 | CONCAT( 1146 | @NbspCRLF, 1147 | 'Current redo queue size: ', 1148 | FORMAT(redo_queue_size / 1024., 'N'), 1149 | ' MB. Most recent sampling of redo rate: ', 1150 | FORMAT(redo_rate / 1024., 'N'), 1151 | ' MB/s.', 1152 | @CRLF 1153 | ) 1154 | AS details 1155 | FROM sys.dm_database_replica_states 1156 | WHERE is_primary_replica = 0 -- redo details only available on secondary 1157 | AND 1158 | is_local = 1 1159 | AND 1160 | redo_queue_size / 1024. > @RedoQueueSizeThresholdMB 1161 | ; 1162 | 1163 | -- Paused resumable index DDL 1164 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1280) AND execute_indicator = 1) 1165 | 1166 | BEGIN TRY 1167 | 1168 | WITH resumable_index_op AS 1169 | ( 1170 | SELECT OBJECT_SCHEMA_NAME(iro.object_id) AS schema_name, 1171 | OBJECT_NAME(iro.object_id) AS object_name, 1172 | iro.name AS index_name, 1173 | i.type_desc AS index_type, 1174 | iro.percent_complete, 1175 | iro.start_time, 1176 | iro.last_pause_time, 1177 | iro.total_execution_time AS total_execution_time_minutes, 1178 | iro.page_count * 8 / 1024. AS index_operation_allocated_space_mb, 1179 | IIF(CAST(dsc.value AS int) = 0, NULL, DATEDIFF(minute, CURRENT_TIMESTAMP, DATEADD(minute, CAST(dsc.value AS int), iro.last_pause_time))) AS time_to_auto_abort_minutes, 1180 | iro.sql_text 1181 | FROM sys.index_resumable_operations AS iro 1182 | LEFT JOIN sys.indexes AS i -- new index being created will not be present, thus using outer join 1183 | ON iro.object_id = i.object_id 1184 | AND 1185 | iro.index_id = i.index_id 1186 | CROSS JOIN sys.database_scoped_configurations AS dsc 1187 | WHERE iro.state_desc = 'PAUSED' 1188 | AND 1189 | dsc.name = 'PAUSED_RESUMABLE_INDEX_ABORT_DURATION_MINUTES' 1190 | AND 1191 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 1192 | ) 1193 | INSERT INTO @DetectedTip (tip_id, details) 1194 | SELECT 1280 AS tip_id, 1195 | CONCAT( 1196 | @NbspCRLF, 1197 | 'Total resumable index operations: ', FORMAT(COUNT(1), '#,0'), 1198 | @CRLF, @CRLF, 1199 | STRING_AGG( 1200 | CAST(CONCAT( 1201 | 'schema name: ', QUOTENAME(schema_name) COLLATE DATABASE_DEFAULT, @CRLF, 1202 | 'object name: ', QUOTENAME(object_name) COLLATE DATABASE_DEFAULT, @CRLF, 1203 | 'index name: ', QUOTENAME(index_name) COLLATE DATABASE_DEFAULT, @CRLF, 1204 | 'index type: ' + index_type COLLATE DATABASE_DEFAULT + CHAR(13) + CHAR(10), 1205 | 'percent complete: ', FORMAT(percent_complete, '#,0.00'), '%', @CRLF, 1206 | 'start time: ', CONVERT(varchar(20), start_time, 120), @CRLF, 1207 | 'last pause time: ', CONVERT(varchar(20), last_pause_time, 120), @CRLF, 1208 | 'total execution time (minutes): ', FORMAT(total_execution_time_minutes, '#,0'), @CRLF, 1209 | 'space allocated by resumable index operation (MB): ', FORMAT(index_operation_allocated_space_mb, '#,0.00'), @CRLF, 1210 | 'time remaining to auto-abort (minutes): ' + FORMAT(time_to_auto_abort_minutes, '#,0') + CHAR(13) + CHAR(10), 1211 | 'index operation SQL statement: ', sql_text COLLATE DATABASE_DEFAULT, @CRLF 1212 | ) AS nvarchar(max)), @CRLF 1213 | ), 1214 | @CRLF 1215 | ) 1216 | FROM resumable_index_op 1217 | HAVING COUNT(1) > 0; 1218 | 1219 | END TRY 1220 | BEGIN CATCH 1221 | IF ERROR_NUMBER() = 1222 1222 | INSERT INTO @SkippedTip (tip_id) 1223 | VALUES (1280); 1224 | ELSE 1225 | THROW; 1226 | END CATCH; 1227 | 1228 | -- Geo-replication health 1229 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1300) AND execute_indicator = 1) 1230 | 1231 | BEGIN TRY 1232 | 1233 | WITH 1234 | geo_replication_link_details AS 1235 | ( 1236 | SELECT STRING_AGG( 1237 | CAST(CONCAT( 1238 | 'link GUID: ', link_guid, ', ', 1239 | 'local server: ' + QUOTENAME(@@SERVERNAME) + ', ', 1240 | 'local database: ' + QUOTENAME(DB_NAME()) + ', ', 1241 | 'partner server: ' + QUOTENAME(partner_server) + ', ', 1242 | 'partner database: ' + QUOTENAME(partner_database) + ', ', 1243 | 'geo-replication role: ' + role_desc + ', ', 1244 | 'last replication time: ' + CAST(last_replication AS varchar(40)) + ', ', 1245 | 'geo-replication lag (seconds): ' + FORMAT(replication_lag_sec, '#,0') + ', ', 1246 | 'geo-replication state: ' + replication_state_desc 1247 | ) AS nvarchar(max)), @CRLF 1248 | ) 1249 | AS details 1250 | FROM sys.dm_geo_replication_link_status 1251 | WHERE (replication_state_desc <> 'CATCH_UP' OR replication_state_desc IS NULL) 1252 | OR 1253 | -- high replication lag for recent transactions 1254 | ( 1255 | replication_state_desc = 'CATCH_UP' 1256 | AND 1257 | replication_lag_sec > @HighGeoReplLagMinThresholdSeconds 1258 | AND 1259 | last_replication > DATEADD(second, -@RecentGeoReplTranTimeWindowLengthSeconds, SYSDATETIMEOFFSET()) 1260 | ) 1261 | HAVING COUNT(1) > 0 1262 | ) 1263 | INSERT INTO @DetectedTip (tip_id, details) 1264 | SELECT 1300 AS tip_id, 1265 | CONCAT( 1266 | @NbspCRLF, 1267 | details, 1268 | @CRLF 1269 | ) 1270 | FROM geo_replication_link_details; 1271 | 1272 | END TRY 1273 | BEGIN CATCH 1274 | IF ERROR_NUMBER() = 1222 1275 | INSERT INTO @SkippedTip (tip_id) 1276 | VALUES (1300); 1277 | ELSE 1278 | THROW; 1279 | END CATCH; 1280 | 1281 | -- Last partitions are not empty 1282 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1310) AND execute_indicator = 1) 1283 | 1284 | BEGIN TRY 1285 | 1286 | WITH 1287 | partition_stat AS 1288 | ( 1289 | SELECT object_id, 1290 | partition_number, 1291 | reserved_page_count * 8 / 1024. AS size_mb, 1292 | row_count, 1293 | COUNT(1) OVER (PARTITION BY object_id) AS partition_count 1294 | FROM sys.dm_db_partition_stats 1295 | WHERE index_id IN (0,1) 1296 | ), 1297 | object_last_partition AS 1298 | ( 1299 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(ps.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1300 | QUOTENAME(OBJECT_NAME(ps.object_id)) COLLATE DATABASE_DEFAULT AS object_name, 1301 | ps.partition_count, 1302 | ps.partition_number, 1303 | SUM(ps.row_count) AS partition_rows, 1304 | SUM(ps.size_mb) AS partition_size_mb 1305 | FROM partition_stat AS ps 1306 | INNER JOIN sys.objects AS o 1307 | ON ps.object_id = o.object_id 1308 | WHERE ps.partition_count > 1 1309 | AND 1310 | ps.partition_count - ps.partition_number < @MinEmptyPartitionCount -- Consider last n partitions 1311 | AND 1312 | o.is_ms_shipped = 0 1313 | GROUP BY ps.object_id, 1314 | ps.partition_count, 1315 | ps.partition_number 1316 | HAVING SUM(ps.row_count) > 0 1317 | ) 1318 | INSERT INTO @DetectedTip (tip_id, details) 1319 | SELECT 1310 AS tip_id, 1320 | CONCAT( 1321 | @NbspCRLF, 1322 | 'Total partitions: ', FORMAT(COUNT(1), '#,0'), 1323 | @CRLF, @CRLF, 1324 | STRING_AGG( 1325 | CAST(CONCAT( 1326 | 'schema: ', schema_name, ', ', 1327 | 'object: ', object_name, ', ', 1328 | 'partition number: ', FORMAT(partition_number, '#,0'), 1329 | ' out of ', FORMAT(partition_count, '#,0'), ', ', 1330 | 'partition rows: ', FORMAT(partition_rows, '#,0'), ', ', 1331 | 'partition size (MB): ', FORMAT(partition_size_mb, '#,0.00') 1332 | ) AS nvarchar(max)), @CRLF 1333 | ), 1334 | @CRLF 1335 | ) 1336 | AS details 1337 | FROM object_last_partition 1338 | HAVING COUNT(1) > 0; 1339 | 1340 | END TRY 1341 | BEGIN CATCH 1342 | IF ERROR_NUMBER() = 1222 1343 | INSERT INTO @SkippedTip (tip_id) 1344 | VALUES (1310); 1345 | ELSE 1346 | THROW; 1347 | END CATCH; 1348 | 1349 | -- High instance CPU 1350 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1390) AND execute_indicator = 1) 1351 | 1352 | WITH 1353 | instance_cpu_snapshot AS 1354 | ( 1355 | SELECT end_time, 1356 | avg_instance_cpu_percent, 1357 | IIF(avg_instance_cpu_percent > @HighInstanceCPUThresholdPercent, 1, 0) AS high_instance_cpu_indicator 1358 | FROM sys.dm_db_resource_stats 1359 | WHERE @EngineEdition = 5 1360 | ), 1361 | pre_packed_instance_cpu_snapshot AS 1362 | ( 1363 | SELECT end_time, 1364 | avg_instance_cpu_percent, 1365 | high_instance_cpu_indicator, 1366 | ROW_NUMBER() OVER (ORDER BY end_time) -- row number across all readings, in increasing chronological order 1367 | - 1368 | SUM(high_instance_cpu_indicator) OVER (ORDER BY end_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where log rate exceeded the threshold 1369 | AS grouping_helper -- this difference remains constant while log rate is above the threshold, and can be used to collapse/pack an interval using aggregation 1370 | FROM instance_cpu_snapshot 1371 | ), 1372 | packed_instance_cpu_snapshot AS 1373 | ( 1374 | SELECT MIN(end_time) AS min_end_time, 1375 | MAX(end_time) AS max_end_time, 1376 | MAX(avg_instance_cpu_percent) AS max_instance_cpu_percent 1377 | FROM pre_packed_instance_cpu_snapshot 1378 | WHERE high_instance_cpu_indicator = 1 1379 | GROUP BY grouping_helper 1380 | HAVING DATEDIFF(second, MIN(end_time), MAX(end_time)) > @HighInstanceCPUMinThresholdSeconds 1381 | ), 1382 | instance_cpu_top_stat AS 1383 | ( 1384 | SELECT MAX(DATEDIFF(second, min_end_time, max_end_time)) AS top_instance_cpu_duration_seconds, 1385 | MAX(max_instance_cpu_percent) AS top_instance_cpu_percent, 1386 | COUNT(1) AS count_high_instance_cpu_intervals 1387 | FROM packed_instance_cpu_snapshot 1388 | ) 1389 | INSERT INTO @DetectedTip (tip_id, details) 1390 | SELECT 1390 AS tip_id, 1391 | CONCAT( 1392 | @NbspCRLF, 1393 | 'In the last hour, there were ', count_high_instance_cpu_intervals, 1394 | ' interval(s) with instance CPU utilization staying above ', @HighInstanceCPUThresholdPercent, 1395 | '% for at least ' , FORMAT(@HighInstanceCPUMinThresholdSeconds, '#,0'), 1396 | ' seconds. The longest such interval lasted ', FORMAT(top_instance_cpu_duration_seconds, '#,0'), 1397 | ' seconds, and the maximum instance CPU utilization was ', FORMAT(top_instance_cpu_percent, '#,0.00'), 1398 | '%.', 1399 | @CRLF 1400 | ) AS details 1401 | FROM instance_cpu_top_stat 1402 | WHERE count_high_instance_cpu_intervals > 0 1403 | ; 1404 | 1405 | -- Stale stats 1406 | -- This may be silently skipped if running with limited permissions. 1407 | -- VIEW SERVER STATE is insufficient to query sys.dm_db_stats_properties(), 1408 | -- sysadmin or db_owner or SELECT on columns is required. 1409 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1400) AND execute_indicator = 1) 1410 | 1411 | BEGIN TRY 1412 | 1413 | WITH 1414 | object_row_count AS 1415 | ( 1416 | SELECT object_id, 1417 | SUM(row_count) AS object_row_count 1418 | FROM sys.dm_db_partition_stats 1419 | WHERE index_id IN (0,1) -- clustered index or heap 1420 | GROUP BY object_id 1421 | ), 1422 | stale_stats AS 1423 | ( 1424 | SELECT OBJECT_SCHEMA_NAME(s.object_id) COLLATE DATABASE_DEFAULT AS schema_name, 1425 | OBJECT_NAME(s.object_id) COLLATE DATABASE_DEFAULT AS object_name, 1426 | s.name COLLATE DATABASE_DEFAULT AS statistics_name, 1427 | s.auto_created, 1428 | s.user_created, 1429 | s.no_recompute, 1430 | s.is_temporary, 1431 | s.is_incremental, 1432 | s.has_persisted_sample, 1433 | s.has_filter, 1434 | sp.last_updated, 1435 | sp.unfiltered_rows, 1436 | sp.rows_sampled, 1437 | orc.object_row_count, 1438 | sp.modification_counter 1439 | FROM sys.stats AS s 1440 | INNER JOIN sys.objects AS o 1441 | ON s.object_id = o.object_id 1442 | INNER JOIN object_row_count AS orc 1443 | ON o.object_id = orc.object_id 1444 | CROSS APPLY sys.dm_db_stats_properties(s.object_id, s.stats_id) AS sp 1445 | WHERE ( 1446 | o.is_ms_shipped = 0 1447 | OR 1448 | (OBJECT_SCHEMA_NAME(s.object_id) = 'sys' AND o.name LIKE 'plan[_]persist[_]%') -- include Query Store system tables 1449 | ) 1450 | AND 1451 | ( 1452 | -- object cardinality has changed substantially since last stats update 1453 | ABS(ISNULL(sp.unfiltered_rows, 0) - orc.object_row_count) / NULLIF(((ISNULL(sp.unfiltered_rows, 0) + orc.object_row_count) / 2), 0) > @StaleStatsCardinalityChangeMinDifference 1454 | OR 1455 | -- no stats blob created 1456 | (sp.last_updated IS NULL AND orc.object_row_count > 0) 1457 | OR 1458 | -- naive: stats for an object with many modifications not updated for a substantial time interval 1459 | (sp.modification_counter > @StaleStatsMinModificationCountRatio * orc.object_row_count AND DATEDIFF(day, sp.last_updated, SYSDATETIME()) > @StaleStatsMinAgeThresholdDays) 1460 | ) 1461 | ) 1462 | INSERT INTO @DetectedTip (tip_id, details) 1463 | SELECT 1400 AS tip_id, 1464 | CONCAT( 1465 | @NbspCRLF, 1466 | 'Total potentially out of date statistics: ', FORMAT(COUNT(1), '#,0'), 1467 | @CRLF, @CRLF, 1468 | STRING_AGG( 1469 | CAST(CONCAT( 1470 | schema_name, '.', 1471 | object_name, '.', 1472 | statistics_name, 1473 | ', last updated: ', ISNULL(FORMAT(last_updated, 's'), '-'), 1474 | ', last update rows: ', ISNULL(FORMAT(unfiltered_rows, '#,0'), '-'), 1475 | ', last update sampled rows: ', ISNULL(FORMAT(rows_sampled, '#,0'), '-'), 1476 | ', current rows: ', FORMAT(object_row_count, '#,0'), 1477 | ', modifications: ', ISNULL(FORMAT(modification_counter, '#,0'), '-'), 1478 | ', attributes: ' 1479 | + 1480 | NULLIF( 1481 | CONCAT_WS( 1482 | ',', 1483 | IIF(auto_created = 1, 'auto-created', NULL), 1484 | IIF(user_created = 1, 'user-created', NULL), 1485 | IIF(no_recompute = 1, 'no_recompute', NULL), 1486 | IIF(is_temporary = 1, 'temporary', NULL), 1487 | IIF(is_incremental = 1, 'incremental', NULL), 1488 | IIF(has_filter = 1, 'filtered', NULL), 1489 | IIF(has_persisted_sample = 1, 'persisted sample', NULL) 1490 | ) 1491 | , '') 1492 | ) AS nvarchar(max)), @CRLF 1493 | ), 1494 | @CRLF 1495 | ) 1496 | AS details 1497 | FROM stale_stats 1498 | HAVING COUNT(1) > 0; 1499 | 1500 | END TRY 1501 | BEGIN CATCH 1502 | IF ERROR_NUMBER() = 1222 1503 | INSERT INTO @SkippedTip (tip_id) 1504 | VALUES (1400); 1505 | ELSE 1506 | THROW; 1507 | END CATCH; 1508 | 1509 | -- Many tables with no indexes 1510 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1410) AND execute_indicator = 1) 1511 | 1512 | BEGIN TRY 1513 | 1514 | WITH 1515 | object_row_count AS 1516 | ( 1517 | SELECT object_id, 1518 | SUM(row_count) AS object_row_count 1519 | FROM sys.dm_db_partition_stats 1520 | WHERE index_id IN (0,1) -- clustered index or heap 1521 | GROUP BY object_id 1522 | ), 1523 | indexed_table AS 1524 | ( 1525 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1526 | QUOTENAME(t.name) COLLATE DATABASE_DEFAULT AS table_name, 1527 | IIF( 1528 | ISNULL(i.no_index_indicator, 0) = 1 1529 | AND 1530 | -- exclude small tables 1531 | orc.object_row_count > @NoIndexTablesMinRowCountThreshold, 1532 | 1, 1533 | 0 1534 | ) 1535 | AS no_index_indicator 1536 | FROM sys.tables AS t 1537 | INNER JOIN object_row_count AS orc 1538 | ON t.object_id = orc.object_id 1539 | OUTER APPLY ( 1540 | SELECT TOP (1) 1 AS no_index_indicator 1541 | FROM sys.indexes AS i 1542 | WHERE i.object_id = t.object_id 1543 | AND 1544 | i.type_desc = 'HEAP' 1545 | AND 1546 | NOT EXISTS ( 1547 | SELECT 1 1548 | FROM sys.indexes AS ni 1549 | WHERE ni.object_id = i.object_id 1550 | AND 1551 | ni.type_desc IN ('NONCLUSTERED','XML','SPATIAL','NONCLUSTERED COLUMNSTORE','NONCLUSTERED HASH') 1552 | ) 1553 | ) AS i 1554 | WHERE t.is_ms_shipped = 0 1555 | ) 1556 | INSERT INTO @DetectedTip (tip_id, details) 1557 | SELECT 1410 AS tip_id, 1558 | CONCAT( 1559 | @NbspCRLF, 1560 | 'Total tables: ', FORMAT(COUNT(1), '#,0'), 1561 | @CRLF, @CRLF, 1562 | 'Tables with ', FORMAT(@NoIndexTablesMinRowCountThreshold, '#,0'), 1563 | ' or more rows and no indexes: ', FORMAT(SUM(no_index_indicator), '#,0'), 1564 | @CRLF, @CRLF, 1565 | STRING_AGG(CAST( 1566 | IIF( 1567 | no_index_indicator = 1, 1568 | CONCAT(schema_name, '.', table_name), 1569 | NULL 1570 | ) 1571 | AS nvarchar(max) 1572 | ), 1573 | @CRLF 1574 | ), 1575 | @CRLF 1576 | ) 1577 | AS details 1578 | FROM indexed_table 1579 | HAVING SUM(no_index_indicator) > @NoIndexMinTableCountRatio * COUNT(1); 1580 | 1581 | END TRY 1582 | BEGIN CATCH 1583 | IF ERROR_NUMBER() = 1222 1584 | INSERT INTO @SkippedTip (tip_id) 1585 | VALUES (1410); 1586 | ELSE 1587 | THROW; 1588 | END CATCH; 1589 | 1590 | -- Disabled page or row locks 1591 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1440) AND execute_indicator = 1) 1592 | 1593 | BEGIN TRY 1594 | 1595 | WITH lock_index AS 1596 | ( 1597 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1598 | QUOTENAME(o.name) COLLATE DATABASE_DEFAULT AS object_name, 1599 | QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name, 1600 | i.allow_row_locks, 1601 | i.allow_page_locks 1602 | FROM sys.indexes AS i 1603 | INNER JOIN sys.objects AS o 1604 | ON i.object_id = o.object_id 1605 | WHERE o.is_ms_shipped = 0 1606 | AND 1607 | i.is_hypothetical = 0 1608 | AND 1609 | i.type_desc NOT IN ('CLUSTERED COLUMNSTORE','NONCLUSTERED COLUMNSTORE') 1610 | AND 1611 | NOT EXISTS ( 1612 | SELECT 1 1613 | FROM sys.tables AS t 1614 | WHERE t.object_id = o.object_id 1615 | AND 1616 | t.is_memory_optimized = 1 1617 | ) 1618 | AND 1619 | ( 1620 | i.allow_row_locks = 0 1621 | OR 1622 | i.allow_page_locks = 0 1623 | ) 1624 | ), 1625 | index_agg AS 1626 | ( 1627 | SELECT STRING_AGG( 1628 | CAST(CONCAT( 1629 | schema_name, '.', 1630 | object_name, '.', 1631 | index_name, 1632 | ': ', 1633 | CONCAT_WS( 1634 | ', ', 1635 | IIF(allow_row_locks = 0, 'row locks disabled', NULL), 1636 | IIF(allow_page_locks = 0, 'page locks disabled', NULL) 1637 | ) 1638 | ) AS nvarchar(max)), @CRLF 1639 | ) 1640 | AS details, 1641 | COUNT(1) AS index_count 1642 | FROM lock_index 1643 | HAVING COUNT(1) > 0 1644 | ) 1645 | INSERT INTO @DetectedTip (tip_id, details) 1646 | SELECT 1440 AS tip_id, 1647 | CONCAT( 1648 | @NbspCRLF, 1649 | 'Total indexes: ', FORMAT(index_count, '#,0'), 1650 | @CRLF, @CRLF, 1651 | ia.details, 1652 | @CRLF 1653 | ) AS details 1654 | FROM index_agg AS ia 1655 | WHERE ia.details IS NOT NULL; 1656 | 1657 | END TRY 1658 | BEGIN CATCH 1659 | IF ERROR_NUMBER() = 1222 1660 | INSERT INTO @SkippedTip (tip_id) 1661 | VALUES (1440); 1662 | ELSE 1663 | THROW; 1664 | END CATCH; 1665 | 1666 | -- Database-column collation mismatches 1667 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1460) AND execute_indicator = 1) 1668 | 1669 | BEGIN TRY 1670 | 1671 | WITH 1672 | table_column AS 1673 | ( 1674 | SELECT o.object_id, 1675 | c.column_id, 1676 | c.name COLLATE DATABASE_DEFAULT AS column_name, 1677 | c.collation_name COLLATE DATABASE_DEFAULT AS column_collation, 1678 | CAST(DATABASEPROPERTYEX(DB_NAME(), 'Collation') AS sysname) COLLATE DATABASE_DEFAULT AS database_collation 1679 | FROM sys.objects AS o 1680 | INNER JOIN sys.columns AS c 1681 | ON o.object_id = c.object_id 1682 | WHERE o.is_ms_shipped = 0 1683 | AND 1684 | o.type_desc IN ('USER_TABLE','VIEW') 1685 | ), 1686 | collation_mismatch_table AS 1687 | ( 1688 | SELECT object_id, 1689 | QUOTENAME(OBJECT_SCHEMA_NAME(object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1690 | QUOTENAME(OBJECT_NAME(object_id)) COLLATE DATABASE_DEFAULT AS object_name, 1691 | column_collation, 1692 | MIN(database_collation) AS database_collation, 1693 | STRING_AGG(CAST(QUOTENAME(column_name) AS nvarchar(max)), ',') AS column_list 1694 | FROM table_column 1695 | WHERE column_collation <> database_collation 1696 | GROUP BY object_id, 1697 | column_collation 1698 | ) 1699 | INSERT INTO @DetectedTip (tip_id, details) 1700 | SELECT 1460 AS tip_id, 1701 | CONCAT( 1702 | @NbspCRLF, 1703 | 'Database collation: ', MIN(database_collation), @CRLF, 1704 | 'Total objects with mismatched collation columns: ', FORMAT(COUNT(DISTINCT(object_id)), '#,0'), 1705 | @CRLF, @CRLF, 1706 | STRING_AGG(CAST( 1707 | CONCAT(schema_name, '.', object_name, ': ', column_list, ' (', column_collation, ')') 1708 | AS nvarchar(max) 1709 | ), 1710 | @CRLF 1711 | ), 1712 | @CRLF 1713 | ) 1714 | AS details 1715 | FROM collation_mismatch_table 1716 | HAVING COUNT(1) > 0; 1717 | 1718 | END TRY 1719 | BEGIN CATCH 1720 | IF ERROR_NUMBER() = 1222 1721 | INSERT INTO @SkippedTip (tip_id) 1722 | VALUES (1460); 1723 | ELSE 1724 | THROW; 1725 | END CATCH; 1726 | 1727 | -- Excessively large index keys 1728 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1470) AND execute_indicator = 1) 1729 | 1730 | BEGIN TRY 1731 | 1732 | WITH 1733 | large_key_index AS 1734 | ( 1735 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1736 | QUOTENAME(OBJECT_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS object_name, 1737 | QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name, 1738 | i.type_desc COLLATE DATABASE_DEFAULT AS index_type, 1739 | SUM(c.max_length) AS index_key_length_bytes, 1740 | STRING_AGG(CAST(QUOTENAME(c.name) COLLATE DATABASE_DEFAULT AS nvarchar(max)), ',') AS column_list 1741 | FROM sys.objects AS o 1742 | INNER JOIN sys.indexes AS i 1743 | ON o.object_id = i.object_id 1744 | INNER JOIN sys.index_columns AS ic 1745 | ON i.object_id = ic.object_id 1746 | AND 1747 | i.index_id = ic.index_id 1748 | INNER JOIN sys.columns AS c 1749 | ON o.object_id = c.object_id 1750 | AND 1751 | ic.column_id = c.column_id 1752 | WHERE o.is_ms_shipped = 0 1753 | AND 1754 | o.type_desc IN ('USER_TABLE','VIEW') 1755 | AND 1756 | i.type_desc IN ('CLUSTERED','NONCLUSTERED') 1757 | AND 1758 | ic.key_ordinal > 0 1759 | GROUP BY o.object_id, 1760 | i.index_id, 1761 | i.name, 1762 | i.type_desc 1763 | HAVING SUM(c.max_length) > IIF(i.type_desc = 'CLUSTERED', 900, 1700) 1764 | ) 1765 | INSERT INTO @DetectedTip (tip_id, details) 1766 | SELECT 1470 AS tip_id, 1767 | CONCAT( 1768 | @NbspCRLF, 1769 | 'Total indexes with excessively large keys: ', FORMAT(COUNT(1), '#,0'), 1770 | @CRLF, @CRLF, 1771 | STRING_AGG(CAST( 1772 | CONCAT( 1773 | 'schema: ', schema_name, 1774 | ', object: ', object_name, 1775 | ', index: ' + index_name, 1776 | ', index type: ', index_type, 1777 | ', index key columns: ', column_list, 1778 | ', index key length (bytes): ', FORMAT(index_key_length_bytes, '#,0') 1779 | ) 1780 | AS nvarchar(max) 1781 | ), 1782 | @CRLF 1783 | ), 1784 | @CRLF 1785 | ) 1786 | AS details 1787 | FROM large_key_index 1788 | HAVING COUNT(1) > 0; 1789 | 1790 | END TRY 1791 | BEGIN CATCH 1792 | IF ERROR_NUMBER() = 1222 1793 | INSERT INTO @SkippedTip (tip_id) 1794 | VALUES (1470); 1795 | ELSE 1796 | THROW; 1797 | END CATCH; 1798 | 1799 | -- Indexes: disabled, low fill factor, and non-unique clustered 1800 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1480,1490,1500) AND execute_indicator = 1) 1801 | 1802 | BEGIN TRY 1803 | 1804 | WITH 1805 | index_size AS 1806 | ( 1807 | SELECT p.object_id, 1808 | p.index_id, 1809 | SUM(ps.used_page_count) * 8 / 1024. AS total_index_size_mb 1810 | FROM sys.partitions AS p 1811 | INNER JOIN sys.dm_db_partition_stats AS ps 1812 | ON p.partition_id = ps.partition_id 1813 | AND 1814 | p.object_id = ps.object_id 1815 | AND 1816 | p.index_id = ps.index_id 1817 | GROUP BY p.object_id, 1818 | p.index_id 1819 | ), 1820 | candidate_index AS 1821 | ( 1822 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1823 | QUOTENAME(OBJECT_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS object_name, 1824 | QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name, 1825 | i.type_desc COLLATE DATABASE_DEFAULT AS index_type, 1826 | i.is_disabled, 1827 | i.fill_factor, 1828 | IIF(i.fill_factor > 0 AND i.fill_factor < @FillFactorThreshold, 1, 0) AS is_low_fill_factor, 1829 | IIF(i.type_desc = 'CLUSTERED' AND i.is_unique = 0, 1, 0) AS is_non_unique_clustered, 1830 | ins.total_index_size_mb 1831 | FROM sys.objects AS o 1832 | INNER JOIN sys.indexes AS i 1833 | ON o.object_id = i.object_id 1834 | INNER JOIN index_size AS ins 1835 | ON o.object_id = ins.object_id 1836 | AND 1837 | i.index_id = ins.index_id 1838 | WHERE o.is_ms_shipped = 0 1839 | AND 1840 | o.type_desc IN ('USER_TABLE','VIEW') 1841 | ) 1842 | INSERT INTO @DetectedTip (tip_id, details) 1843 | SELECT td.tip_id, 1844 | CONCAT( 1845 | @NbspCRLF, 1846 | 'Total indexes: ', FORMAT(COUNT(1), '#,0'), 1847 | @CRLF, @CRLF, 1848 | STRING_AGG(CAST( 1849 | CONCAT( 1850 | 'schema: ', schema_name, 1851 | ', object: ', object_name, 1852 | ', index: ' + index_name, 1853 | IIF(ci.is_non_unique_clustered = 1 AND td.tip_id = 1500, '', CONCAT(', index type: ', index_type)), 1854 | ', index size (MB): ', FORMAT(total_index_size_mb, '#,0.00'), 1855 | IIF(ci.is_low_fill_factor = 1 AND td.tip_id = 1490, CONCAT(', fill_factor: ', ci.fill_factor), '') 1856 | ) 1857 | AS nvarchar(max) 1858 | ), 1859 | @CRLF 1860 | ), 1861 | @CRLF 1862 | ) 1863 | AS details 1864 | FROM candidate_index AS ci 1865 | CROSS JOIN @TipDefinition AS td 1866 | WHERE td.execute_indicator = 1 1867 | AND 1868 | ( 1869 | (td.tip_id = 1480 AND ci.is_disabled = 1) 1870 | OR 1871 | (td.tip_id = 1490 AND ci.is_low_fill_factor = 1) 1872 | OR 1873 | (td.tip_id = 1500 AND ci.is_non_unique_clustered = 1) 1874 | ) 1875 | GROUP BY td.tip_id 1876 | HAVING COUNT(1) > 0; 1877 | 1878 | END TRY 1879 | BEGIN CATCH 1880 | IF ERROR_NUMBER() = 1222 1881 | INSERT INTO @SkippedTip (tip_id) 1882 | VALUES (1480),(1490),(1500); 1883 | ELSE 1884 | THROW; 1885 | END CATCH; 1886 | 1887 | -- IDENTITY columns close to running out of numbers 1888 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1510) AND execute_indicator = 1) 1889 | 1890 | BEGIN TRY 1891 | 1892 | WITH 1893 | data_type_range AS 1894 | ( 1895 | SELECT * 1896 | FROM ( 1897 | VALUES (48, 0, 255), -- tinyint 1898 | (52, -32768, 32767), -- smallint 1899 | (56, -2147483648, 2147483647), -- int 1900 | (127, -9223372036854775808, 9223372036854775807), -- bigint 1901 | (106, -99999999999999999999999999999999999999, 99999999999999999999999999999999999999), -- decimal 1902 | (108, -99999999999999999999999999999999999999, 99999999999999999999999999999999999999) -- numeric 1903 | ) AS dt (system_type_id, range_min, range_max) 1904 | ), 1905 | identity_column AS 1906 | ( 1907 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1908 | QUOTENAME(OBJECT_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS table_name, 1909 | QUOTENAME(c.name) AS column_name, 1910 | tp.name AS system_type_name, 1911 | IDENT_CURRENT(CONCAT(OBJECT_SCHEMA_NAME(t.object_id),'.',t.name)) AS current_identity_value, 1912 | IDENT_INCR(CONCAT(OBJECT_SCHEMA_NAME(t.object_id),'.',t.name)) AS identity_increment, 1913 | IDENT_SEED(CONCAT(OBJECT_SCHEMA_NAME(t.object_id),'.',t.name)) AS identity_seed, 1914 | dtr.range_min, 1915 | dtr.range_max, 1916 | CAST(dtr.range_min AS float) AS range_min_float, 1917 | CAST(dtr.range_max AS float) AS range_max_float 1918 | FROM sys.tables AS t 1919 | INNER JOIN sys.columns AS c 1920 | ON t.object_id = c.object_id 1921 | INNER JOIN sys.types AS tp 1922 | ON c.system_type_id = tp.system_type_id 1923 | INNER JOIN data_type_range AS dtr 1924 | ON c.system_type_id = dtr.system_type_id 1925 | WHERE c.is_identity = 1 1926 | AND 1927 | t.is_ms_shipped = 0 1928 | ) 1929 | INSERT INTO @DetectedTip (tip_id, details) 1930 | SELECT 1510 AS tip_id, 1931 | CONCAT( 1932 | @NbspCRLF, 1933 | STRING_AGG(CAST( 1934 | CONCAT( 1935 | 'schema: ', schema_name, 1936 | ', table: ', table_name, 1937 | ', column: ', column_name, 1938 | ', data type: ' , system_type_name, 1939 | ', initial identity value: ', FORMAT(identity_seed, '#,0'), 1940 | ', current identity value: ', FORMAT(current_identity_value, '#,0'), 1941 | ', identity increment: ', FORMAT(identity_increment, '#,0'), 1942 | ', data type range: ', FORMAT(range_min, '#,0'), ' to ', FORMAT(range_max, '#,0'), 1943 | ', remaining contiguous range: ', FORMAT(IIF(identity_increment > 0, range_max_float - current_identity_value, range_min_float - current_identity_value), '#,0') 1944 | ) 1945 | AS nvarchar(max) 1946 | ), 1947 | @CRLF 1948 | ), 1949 | @CRLF 1950 | ) 1951 | AS details 1952 | FROM identity_column 1953 | WHERE -- less than x% of the initial identity range remains 1954 | CASE WHEN identity_increment > 0 THEN (range_max_float - current_identity_value) / IIF((range_max_float - identity_seed) = 0, range_max_float - 1, range_max_float - identity_seed) 1955 | WHEN identity_increment < 0 THEN (range_min_float - current_identity_value) / IIF((range_min_float - identity_seed) = 0, range_min_float + 1, range_min_float - identity_seed) 1956 | END < @IdentitySequenceRangeExhaustionThresholdRatio 1957 | HAVING COUNT(1) > 0; 1958 | 1959 | END TRY 1960 | BEGIN CATCH 1961 | IF ERROR_NUMBER() = 1222 1962 | INSERT INTO @SkippedTip (tip_id) 1963 | VALUES (1510); 1964 | ELSE 1965 | THROW; 1966 | END CATCH; 1967 | 1968 | -- Sequences close to running out of numbers 1969 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1520) AND execute_indicator = 1) 1970 | 1971 | BEGIN TRY 1972 | 1973 | WITH 1974 | sequence_object AS 1975 | ( 1976 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(s.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 1977 | QUOTENAME(OBJECT_NAME(s.object_id)) COLLATE DATABASE_DEFAULT AS sequence_name, 1978 | tp.name AS system_type_name, 1979 | -- use float to work around sql_variant not supporting arithmetic expressions 1980 | CAST(s.current_value AS float) AS current_value, 1981 | CAST(s.start_value AS float) AS start_value, 1982 | CAST(s.minimum_value AS float) AS minimum_value, 1983 | CAST(s.maximum_value AS float) AS maximum_value, 1984 | CAST(s.increment AS float) AS increment, 1985 | s.is_exhausted 1986 | FROM sys.sequences AS s 1987 | INNER JOIN sys.types AS tp 1988 | ON s.system_type_id = tp.system_type_id 1989 | WHERE s.is_ms_shipped = 0 1990 | ) 1991 | INSERT INTO @DetectedTip (tip_id, details) 1992 | SELECT 1520 AS tip_id, 1993 | CONCAT( 1994 | @NbspCRLF, 1995 | STRING_AGG(CAST( 1996 | CONCAT( 1997 | 'schema: ', schema_name, 1998 | ', sequence: ', sequence_name, 1999 | ', data type: ' , system_type_name, 2000 | ', start value: ', FORMAT(start_value, '#,0'), 2001 | ', current value: ', FORMAT(current_value, '#,0'), 2002 | ', increment: ', FORMAT(increment, '#,0'), 2003 | ', full range: ', FORMAT(minimum_value, '#,0'), ' to ', FORMAT(maximum_value, '#,0'), 2004 | ', remaining contiguous range: ', FORMAT(IIF(increment > 0, maximum_value - current_value, minimum_value - current_value), '#,0'), 2005 | ', exhausted: ', IIF(is_exhausted = 1, 'Yes', 'No') 2006 | ) 2007 | AS nvarchar(max) 2008 | ), 2009 | @CRLF 2010 | ), 2011 | @CRLF 2012 | ) 2013 | AS details 2014 | FROM sequence_object 2015 | WHERE -- less than x% of the maximum sequence range remains 2016 | CASE WHEN increment > 0 THEN (maximum_value - current_value) / (maximum_value - start_value) 2017 | WHEN increment < 0 THEN (minimum_value - current_value) / (minimum_value - start_value) 2018 | END < @IdentitySequenceRangeExhaustionThresholdRatio 2019 | HAVING COUNT(1) > 0; 2020 | 2021 | END TRY 2022 | BEGIN CATCH 2023 | IF ERROR_NUMBER() = 1222 2024 | INSERT INTO @SkippedTip (tip_id) 2025 | VALUES (1520); 2026 | ELSE 2027 | THROW; 2028 | END CATCH; 2029 | 2030 | -- Disabled or untrusted constraints 2031 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1530) AND execute_indicator = 1) 2032 | 2033 | BEGIN TRY 2034 | 2035 | WITH 2036 | fk_check_constraint AS 2037 | ( 2038 | SELECT parent_object_id, 2039 | name, 2040 | type_desc, 2041 | is_disabled, 2042 | is_not_trusted, 2043 | is_ms_shipped 2044 | FROM sys.foreign_keys 2045 | UNION 2046 | SELECT parent_object_id, 2047 | name, 2048 | type_desc, 2049 | is_disabled, 2050 | is_not_trusted, 2051 | is_ms_shipped 2052 | FROM sys.check_constraints 2053 | ), 2054 | eligible_constraint AS 2055 | ( 2056 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 2057 | QUOTENAME(OBJECT_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS table_name, 2058 | QUOTENAME(fcc.name) COLLATE DATABASE_DEFAULT AS constraint_name, 2059 | fcc.type_desc AS constraint_type, 2060 | fcc.is_disabled, 2061 | fcc.is_not_trusted 2062 | FROM sys.tables AS t 2063 | INNER JOIN fk_check_constraint AS fcc 2064 | ON t.object_id = fcc.parent_object_id 2065 | WHERE t.is_ms_shipped = 0 2066 | AND 2067 | fcc.is_ms_shipped = 0 2068 | AND 2069 | ( 2070 | fcc.is_disabled = 1 2071 | OR 2072 | fcc.is_not_trusted = 1 2073 | ) 2074 | ) 2075 | INSERT INTO @DetectedTip (tip_id, details) 2076 | SELECT 1530 AS tip_id, 2077 | CONCAT( 2078 | @NbspCRLF, 2079 | STRING_AGG(CAST( 2080 | CONCAT( 2081 | 'schema: ', schema_name, 2082 | ', table: ', table_name, 2083 | ', constraint name: ', constraint_name, 2084 | ', constraint type: ', constraint_type, 2085 | ', attributes: ', 2086 | CONCAT_WS( 2087 | ', ', 2088 | IIF(is_disabled = 1, 'disabled', NULL), 2089 | IIF(is_not_trusted = 1, 'not trusted', NULL) 2090 | ) 2091 | ) 2092 | AS nvarchar(max) 2093 | ), 2094 | @CRLF 2095 | ), 2096 | @CRLF 2097 | ) 2098 | AS details 2099 | FROM eligible_constraint 2100 | HAVING COUNT(1) > 0; 2101 | 2102 | END TRY 2103 | BEGIN CATCH 2104 | IF ERROR_NUMBER() = 1222 2105 | INSERT INTO @SkippedTip (tip_id) 2106 | VALUES (1530); 2107 | ELSE 2108 | THROW; 2109 | END CATCH; 2110 | 2111 | -- When not running as server admin and without membership in ##MS_ServerStateReader## we do not have 2112 | -- VIEW DATABASE STATE on tempdb, which is required to execute tempdb.sys.sp_spaceused 2113 | -- and query tempdb.sys.dm_db_log_space_usage to determine tempdb used data and log space. 2114 | -- Evaluate these tempdb tips only if the required permission is held. 2115 | IF EXISTS ( 2116 | SELECT 1 2117 | FROM tempdb.sys.fn_my_permissions(default, 'DATABASE') 2118 | WHERE entity_name = 'database' 2119 | AND 2120 | permission_name = 'VIEW DATABASE STATE' 2121 | ) 2122 | BEGIN 2123 | 2124 | -- tempdb data and log size close to maxsize 2125 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1330,1340,1350) AND execute_indicator = 1) 2126 | BEGIN 2127 | 2128 | BEGIN TRY 2129 | 2130 | -- get tempdb used (aka reserved) size 2131 | DROP TABLE IF EXISTS #tempdb_space_used; 2132 | 2133 | CREATE TABLE #tempdb_space_used 2134 | ( 2135 | database_name sysname NULL, 2136 | database_size varchar(18) NULL, 2137 | unallocated_space varchar(18) NULL, 2138 | reserved varchar(18) NULL, 2139 | data varchar(18) NULL, 2140 | index_size varchar(18) NULL, 2141 | unused varchar(18) NULL 2142 | ); 2143 | 2144 | INSERT INTO #tempdb_space_used 2145 | EXEC tempdb.sys.sp_spaceused @oneresultset = 1; 2146 | 2147 | IF @@ROWCOUNT <> 1 2148 | THROW 50020, 'tempdb.sys.sp_spaceused returned the number of rows other than 1.', 1; 2149 | 2150 | WITH tempdb_file_size AS 2151 | ( 2152 | SELECT type_desc AS file_type, 2153 | SUM(CAST(size AS bigint) * 8 / 1024.) AS allocated_size_mb, 2154 | SUM(CAST(max_size AS bigint) * 8 / 1024.) AS max_size_mb, 2155 | SUM(IIF(type_desc = 'ROWS', 1, NULL)) AS count_files 2156 | FROM tempdb.sys.database_files 2157 | WHERE type_desc IN ('ROWS','LOG') 2158 | GROUP BY type_desc 2159 | ), 2160 | tempdb_tip AS 2161 | ( 2162 | SELECT tfs.file_type, 2163 | tt.space_type, 2164 | tfs.allocated_size_mb, 2165 | CASE tt.file_type WHEN 'ROWS' 2166 | THEN TRY_CAST(LEFT(tsu.reserved, LEN(tsu.reserved) - 3) AS decimal) / 1024. 2167 | WHEN 'LOG' 2168 | THEN lsu.used_log_space_in_bytes / 1024. / 1024 2169 | END 2170 | AS used_size_mb, 2171 | tfs.max_size_mb, 2172 | tfs.count_files 2173 | FROM tempdb_file_size AS tfs 2174 | INNER JOIN ( 2175 | VALUES ('ROWS', 'allocated'), 2176 | ('ROWS', 'used'), 2177 | ('LOG', 'allocated') 2178 | ) AS tt (file_type, space_type) 2179 | ON tfs.file_type = tt.file_type 2180 | LEFT JOIN #tempdb_space_used AS tsu 2181 | ON tfs.file_type = 'ROWS' 2182 | LEFT JOIN tempdb.sys.dm_db_log_space_usage AS lsu 2183 | ON tt.file_type = 'LOG' 2184 | ) 2185 | INSERT INTO @DetectedTip (tip_id, details) 2186 | SELECT td.tip_id, 2187 | CONCAT( 2188 | @NbspCRLF, 2189 | 'tempdb ', CASE tt.file_type WHEN 'ROWS' THEN 'data' WHEN 'LOG' THEN 'log' END , ' used size (MB): ', FORMAT(tt.used_size_mb, '#,0.00'), 2190 | ', tempdb ', CASE tt.file_type WHEN 'ROWS' THEN 'data' WHEN 'LOG' THEN 'log' END , ' allocated size (MB): ', FORMAT(tt.allocated_size_mb, '#,0.00'), 2191 | ', tempdb ', CASE tt.file_type WHEN 'ROWS' THEN 'data' WHEN 'LOG' THEN 'log' END, ' MAXSIZE (MB): ', FORMAT(tt.max_size_mb, '#,0.00'), 2192 | ', tempdb data files: ' + CAST(tt.count_files AS varchar(11)), 2193 | @CRLF 2194 | ) 2195 | AS details 2196 | FROM tempdb_tip AS tt 2197 | INNER JOIN @TipDefinition AS td 2198 | ON CASE WHEN tt.file_type = 'ROWS' AND tt.space_type = 'allocated' THEN 1330 2199 | WHEN tt.file_type = 'ROWS' AND tt.space_type = 'used' THEN 1340 2200 | WHEN tt.file_type = 'LOG' THEN 1350 2201 | END = td.tip_id 2202 | WHERE ( 2203 | (tt.file_type = 'ROWS' AND tt.space_type = 'allocated' AND tt.allocated_size_mb / NULLIF(tt.max_size_mb, 0) > @TempdbDataAllocatedToMaxsizeThresholdRatio) 2204 | OR 2205 | (tt.file_type = 'ROWS' AND tt.space_type = 'used' AND tt.used_size_mb / NULLIF(tt.max_size_mb, 0) > @TempdbDataUsedToMaxsizeThresholdRatio) 2206 | OR 2207 | (tt.file_type = 'LOG' AND tt.space_type = 'allocated' AND tt.allocated_size_mb / NULLIF(tt.max_size_mb, 0) > @TempdbLogAllocatedToMaxsizeThresholdRatio) 2208 | ) 2209 | AND 2210 | td.execute_indicator = 1; 2211 | 2212 | END TRY 2213 | BEGIN CATCH 2214 | IF ERROR_NUMBER() = 1222 2215 | INSERT INTO @SkippedTip (tip_id) 2216 | VALUES (1330),(1340),(1350); 2217 | ELSE 2218 | THROW; 2219 | END CATCH; 2220 | 2221 | END; 2222 | 2223 | END 2224 | ELSE 2225 | INSERT INTO @SkippedTip (tip_id, reason) 2226 | VALUES (1330,'insufficient permissions'), 2227 | (1340,'insufficient permissions'), 2228 | (1350,'insufficient permissions'); 2229 | 2230 | -- For tips that follow, VIEW DATABASE STATE is insufficient. 2231 | -- Determine if we have VIEW SERVER STATE empirically, given the absense of metadata to determine that otherwise. 2232 | BEGIN TRY 2233 | DECLARE @a int = (SELECT 1 FROM sys.dm_os_sys_info); 2234 | END TRY 2235 | BEGIN CATCH 2236 | IF ERROR_NUMBER() <> 0 2237 | SELECT @ViewServerStateIndicator = 0; 2238 | END CATCH; 2239 | 2240 | -- Proceed with the rest of the tips only if required permission is held 2241 | 2242 | IF @ViewServerStateIndicator = 1 2243 | BEGIN -- begin tips requiring VIEW SERVER STATE 2244 | 2245 | -- Recent CPU throttling 2246 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1150) AND execute_indicator = 1) 2247 | 2248 | WITH cpu_throttling AS 2249 | ( 2250 | SELECT SUM(duration_ms) / 60000 AS recent_history_duration_minutes, 2251 | SUM(IIF(delta_cpu_active_ms > 0 AND delta_cpu_delayed_ms > 0, 1, 0)) AS count_cpu_delayed_intervals, 2252 | CAST(AVG(IIF(delta_cpu_active_ms > 0 AND delta_cpu_delayed_ms > 0, CAST(delta_cpu_delayed_ms AS decimal(12,0)) / delta_cpu_active_ms, NULL)) * 100 AS decimal(5,2)) AS avg_cpu_delay_percent 2253 | FROM sys.dm_resource_governor_workload_groups_history_ex 2254 | WHERE @EngineEdition = 5 2255 | AND 2256 | name like 'UserPrimaryGroup.DB%' 2257 | AND 2258 | TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID() 2259 | ) 2260 | INSERT INTO @DetectedTip (tip_id, details) 2261 | SELECT 1150 AS tip_id, 2262 | CONCAT( 2263 | @NbspCRLF, 2264 | 'In the last ', recent_history_duration_minutes, 2265 | ' minutes, there were ', count_cpu_delayed_intervals, 2266 | ' occurrence(s) of CPU throttling. On average, CPU was throttled by ', FORMAT(avg_cpu_delay_percent, '#,0.00'), '%.', 2267 | @CRLF 2268 | ) AS details 2269 | FROM cpu_throttling 2270 | WHERE avg_cpu_delay_percent > @CPUThrottlingDelayThresholdPercent 2271 | ; 2272 | 2273 | -- Recent out of memory errors 2274 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1160) AND execute_indicator = 1) 2275 | 2276 | WITH oom AS 2277 | ( 2278 | SELECT SUM(duration_ms) / 60000 AS recent_history_duration_minutes, 2279 | SUM(IIF(delta_out_of_memory_count >= 0, delta_out_of_memory_count, 0)) AS count_oom 2280 | FROM sys.dm_resource_governor_resource_pools_history_ex 2281 | WHERE @EngineEdition = 5 2282 | AND 2283 | -- Consider user resource pool only 2284 | ( 2285 | name LIKE 'SloSharedPool%' 2286 | OR 2287 | name LIKE 'UserPool%' 2288 | ) 2289 | ) 2290 | INSERT INTO @DetectedTip (tip_id, details) 2291 | SELECT 1160 AS tip_id, 2292 | CONCAT( 2293 | @NbspCRLF, 2294 | 'In the last ', recent_history_duration_minutes, 2295 | ' minutes, there were ', count_oom, 2296 | ' out of memory errors in the ', 2297 | IIF(dso.service_objective = 'ElasticPool', CONCAT(QUOTENAME(dso.elastic_pool_name), ' elastic pool.'), CONCAT(QUOTENAME(DB_NAME(dso.database_id)), ' database.')), 2298 | @CRLF 2299 | ) AS details 2300 | FROM oom 2301 | CROSS JOIN sys.database_service_objectives AS dso 2302 | WHERE count_oom > 0 2303 | AND 2304 | dso.database_id = DB_ID() 2305 | ; 2306 | 2307 | -- Recent memory grant waits and timeouts 2308 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1165) AND execute_indicator = 1) 2309 | 2310 | WITH memgrant AS 2311 | ( 2312 | SELECT SUM(duration_ms) / 60000 AS recent_history_duration_minutes, 2313 | SUM(IIF(delta_memgrant_waiter_count >= 0, delta_memgrant_waiter_count, 0)) AS count_memgrant_waiter, 2314 | SUM(IIF(delta_memgrant_timeout_count >= 0, delta_memgrant_timeout_count, 0)) AS count_memgrant_timeout 2315 | FROM sys.dm_resource_governor_resource_pools_history_ex 2316 | WHERE @EngineEdition = 5 2317 | AND 2318 | -- Consider user resource pool only 2319 | ( 2320 | name LIKE 'SloSharedPool%' 2321 | OR 2322 | name LIKE 'UserPool%' 2323 | ) 2324 | ) 2325 | INSERT INTO @DetectedTip (tip_id, details) 2326 | SELECT 1165 AS tip_id, 2327 | CONCAT( 2328 | @NbspCRLF, 2329 | 'In the last ', recent_history_duration_minutes, 2330 | ' minutes, there were ', count_memgrant_waiter, 2331 | ' requests waiting for a memory grant, and ', count_memgrant_timeout, 2332 | ' memory grant timeouts in the ', 2333 | IIF(dso.service_objective = 'ElasticPool', CONCAT(QUOTENAME(dso.elastic_pool_name), ' elastic pool.'), CONCAT(QUOTENAME(DB_NAME(dso.database_id)), ' database.')), 2334 | @CRLF 2335 | ) AS details 2336 | FROM memgrant 2337 | CROSS JOIN sys.database_service_objectives AS dso 2338 | WHERE (count_memgrant_waiter > 0 OR count_memgrant_timeout > 0) 2339 | AND 2340 | dso.database_id = DB_ID() 2341 | ; 2342 | 2343 | -- Little used nonclustered indexes 2344 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1170) AND execute_indicator = 1) 2345 | 2346 | BEGIN TRY 2347 | 2348 | WITH index_size AS 2349 | ( 2350 | SELECT p.object_id, 2351 | p.index_id, 2352 | SUM(ps.used_page_count) * 8 / 1024. AS total_index_size_mb 2353 | FROM sys.partitions AS p 2354 | INNER JOIN sys.dm_db_partition_stats AS ps 2355 | ON p.partition_id = ps.partition_id 2356 | AND 2357 | p.object_id = ps.object_id 2358 | AND 2359 | p.index_id = ps.index_id 2360 | GROUP BY p.object_id, 2361 | p.index_id 2362 | ), 2363 | index_usage AS 2364 | ( 2365 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(o.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 2366 | QUOTENAME(o.name) COLLATE DATABASE_DEFAULT AS object_name, 2367 | QUOTENAME(i.name) COLLATE DATABASE_DEFAULT AS index_name, 2368 | ius.user_seeks, 2369 | ius.user_scans, 2370 | ius.user_lookups, 2371 | ius.user_updates, 2372 | ins.total_index_size_mb 2373 | FROM sys.dm_db_index_usage_stats AS ius 2374 | INNER JOIN sys.indexes AS i 2375 | ON ius.object_id = i.object_id 2376 | AND 2377 | ius.index_id = i.index_id 2378 | INNER JOIN index_size AS ins 2379 | ON i.object_id = ins.object_id 2380 | AND 2381 | i.index_id = ins.index_id 2382 | INNER JOIN sys.objects AS o 2383 | ON i.object_id = o.object_id 2384 | AND 2385 | ius.object_id = o.object_id 2386 | WHERE ius.database_id = DB_ID() 2387 | AND 2388 | i.type_desc = 'NONCLUSTERED' 2389 | AND 2390 | i.is_primary_key = 0 2391 | AND 2392 | i.is_unique_constraint = 0 2393 | AND 2394 | i.is_unique = 0 2395 | AND 2396 | o.is_ms_shipped = 0 2397 | AND 2398 | (ius.user_seeks + ius.user_scans + ius.user_lookups) * 1. / NULLIF(ius.user_updates, 0) < @IndexReadWriteThresholdRatio 2399 | ), 2400 | index_usage_agg AS 2401 | ( 2402 | SELECT STRING_AGG( 2403 | CAST(CONCAT( 2404 | schema_name, '.', 2405 | object_name, '.', 2406 | index_name, 2407 | ' (reads: ', FORMAT(user_seeks + user_scans + user_lookups, '#,0'), ' | writes: ', FORMAT(user_updates, '#,0'), ' | size (MB): ', FORMAT(total_index_size_mb, '#,0.00'), ')' 2408 | ) AS nvarchar(max)), @CRLF 2409 | ) 2410 | AS details, 2411 | COUNT(1) AS index_count 2412 | FROM index_usage 2413 | HAVING COUNT(1) > 0 2414 | ) 2415 | INSERT INTO @DetectedTip (tip_id, details) 2416 | SELECT 1170 AS tip_id, 2417 | CONCAT( 2418 | @NbspCRLF, 2419 | 'Since database engine startup at ', CONVERT(varchar(20), si.sqlserver_start_time, 120), 2420 | ' UTC:', 2421 | REPLICATE(@CRLF, 2), 2422 | 'Total indexes: ', FORMAT(index_count, '#,0'), 2423 | @CRLF, @CRLF, 2424 | iua.details, 2425 | @CRLF 2426 | ) AS details 2427 | FROM index_usage_agg AS iua 2428 | CROSS JOIN sys.dm_os_sys_info AS si 2429 | WHERE iua.details IS NOT NULL; 2430 | 2431 | END TRY 2432 | BEGIN CATCH 2433 | IF ERROR_NUMBER() = 1222 2434 | INSERT INTO @SkippedTip (tip_id) 2435 | VALUES (1170); 2436 | ELSE 2437 | THROW; 2438 | END CATCH; 2439 | 2440 | -- Compression candidates 2441 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1180) AND execute_indicator = 1) 2442 | 2443 | BEGIN TRY 2444 | 2445 | WITH 2446 | recent_cpu_usage AS 2447 | ( 2448 | SELECT AVG(avg_cpu_percent) AS avg_cpu_percent, 2449 | DATEDIFF(minute, MIN(end_time), MAX(end_time)) AS recent_cpu_minutes 2450 | FROM sys.dm_db_resource_stats 2451 | ), 2452 | partition_size AS 2453 | ( 2454 | SELECT p.object_id, 2455 | p.index_id, 2456 | p.partition_number, 2457 | p.data_compression_desc, 2458 | SUM(ps.used_page_count) * 8 / 1024. AS total_partition_size_mb, 2459 | SUM(ps.in_row_used_page_count) * 8 / 1024. AS in_row_partition_size_mb, 2460 | SUM(ps.row_overflow_used_page_count) * 8 / 1024. AS row_overflow_partition_size_mb, 2461 | SUM(ps.lob_used_page_count) * 8 / 1024. AS lob_partition_size_mb 2462 | FROM sys.partitions AS p 2463 | INNER JOIN sys.dm_db_partition_stats AS ps 2464 | ON p.partition_id = ps.partition_id 2465 | AND 2466 | p.object_id = ps.object_id 2467 | AND 2468 | p.index_id = ps.index_id 2469 | GROUP BY p.object_id, 2470 | p.index_id, 2471 | p.partition_number, 2472 | p.data_compression_desc 2473 | ), 2474 | -- Look at index stats for each partition of an index 2475 | partition_stats AS 2476 | ( 2477 | SELECT o.object_id, 2478 | i.name AS index_name, 2479 | i.type_desc AS index_type, 2480 | p.partition_number, 2481 | p.total_partition_size_mb, 2482 | p.in_row_partition_size_mb, 2483 | p.row_overflow_partition_size_mb, 2484 | p.lob_partition_size_mb, 2485 | p.in_row_partition_size_mb / NULLIF(p.total_partition_size_mb, 0) AS compression_eligible_ratio, -- overflow and LOB allocations are not compressible 2486 | p.data_compression_desc, 2487 | ios.leaf_update_count * 1. / NULLIF((ios.range_scan_count + ios.leaf_insert_count + ios.leaf_delete_count + ios.leaf_update_count + ios.leaf_page_merge_count + ios.singleton_lookup_count), 0) AS update_ratio, 2488 | ios.range_scan_count * 1. / NULLIF((ios.range_scan_count + ios.leaf_insert_count + ios.leaf_delete_count + ios.leaf_update_count + ios.leaf_page_merge_count + ios.singleton_lookup_count), 0) AS scan_ratio 2489 | FROM sys.objects AS o 2490 | INNER JOIN sys.indexes AS i 2491 | ON o.object_id = i.object_id 2492 | INNER JOIN partition_size AS p 2493 | ON i.object_id = p.object_id 2494 | AND 2495 | i.index_id = p.index_id 2496 | CROSS APPLY sys.dm_db_index_operational_stats(DB_ID(), o.object_id, i.index_id, p.partition_number) AS ios -- assumption: a representative workload has populated index operational stats 2497 | WHERE i.type_desc IN ('CLUSTERED','NONCLUSTERED','HEAP') 2498 | AND 2499 | p.data_compression_desc IN ('NONE','ROW') -- partitions already PAGE compressed are out of scope 2500 | AND 2501 | o.is_ms_shipped = 0 2502 | AND 2503 | i.is_hypothetical = 0 2504 | AND 2505 | i.is_disabled = 0 2506 | AND 2507 | NOT EXISTS ( 2508 | SELECT 1 2509 | FROM sys.tables AS t 2510 | WHERE t.object_id = o.object_id 2511 | AND 2512 | ( 2513 | t.is_external = 1 2514 | OR 2515 | t.is_memory_optimized = 1 2516 | ) 2517 | ) 2518 | AND 2519 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 2520 | ), 2521 | partition_compression AS 2522 | ( 2523 | SELECT ps.object_id, 2524 | ps.index_name, 2525 | ps.index_type, 2526 | ps.partition_number, 2527 | ps.total_partition_size_mb, 2528 | ps.in_row_partition_size_mb, 2529 | ps.row_overflow_partition_size_mb, 2530 | ps.lob_partition_size_mb, 2531 | SUM(ps.total_partition_size_mb) OVER (PARTITION BY object_id) AS object_size_mb, 2532 | ps.data_compression_desc AS present_compression_type, 2533 | CASE WHEN -- do not choose page compression when no index stats are available and update_ratio and scan_ratio are NULL, due to low confidence 2534 | ( 2535 | ps.update_ratio < @CompressionPartitionUpdateRatioThreshold1 -- infrequently updated 2536 | OR 2537 | ( 2538 | ps.update_ratio BETWEEN @CompressionPartitionUpdateRatioThreshold1 AND @CompressionPartitionUpdateRatioThreshold2 2539 | AND 2540 | ps.scan_ratio > @CompressionPartitionScanRatioThreshold1 2541 | ) -- more frequently updated but also more frequently scanned 2542 | ) 2543 | AND 2544 | rcu.avg_cpu_percent < @CompressionCPUHeadroomThreshold1 -- there is ample CPU headroom 2545 | AND 2546 | rcu.recent_cpu_minutes > @CompressionMinResourceStatSamples -- there is a sufficient number of CPU usage stats 2547 | AND 2548 | ps.compression_eligible_ratio >= @CompressionMinEligibleRatio 2549 | THEN 'PAGE' 2550 | WHEN rcu.avg_cpu_percent < @CompressionCPUHeadroomThreshold2 -- there is some CPU headroom 2551 | AND 2552 | rcu.recent_cpu_minutes > @CompressionMinResourceStatSamples -- there is a sufficient number of CPU usage stats 2553 | AND 2554 | ps.compression_eligible_ratio >= @CompressionMinEligibleRatio 2555 | THEN 'ROW' 2556 | WHEN rcu.avg_cpu_percent > @CompressionCPUHeadroomThreshold2 -- there is no CPU headroom, can't use compression 2557 | AND 2558 | rcu.recent_cpu_minutes > @CompressionMinResourceStatSamples -- there is a sufficient number of CPU usage stats 2559 | THEN 'NONE' 2560 | ELSE NULL -- not enough CPU usage stats to decide 2561 | END 2562 | AS new_compression_type 2563 | FROM partition_stats AS ps 2564 | CROSS JOIN recent_cpu_usage AS rcu 2565 | ), 2566 | partition_compression_interval 2567 | AS 2568 | ( 2569 | SELECT object_id, 2570 | index_name, 2571 | index_type, 2572 | present_compression_type, 2573 | new_compression_type, 2574 | partition_number, 2575 | total_partition_size_mb, 2576 | in_row_partition_size_mb, 2577 | row_overflow_partition_size_mb, 2578 | lob_partition_size_mb, 2579 | object_size_mb, 2580 | partition_number - ROW_NUMBER() OVER ( 2581 | PARTITION BY object_id, index_name, new_compression_type 2582 | ORDER BY partition_number 2583 | ) 2584 | AS interval_group -- used to pack contiguous partition intervals for the same object, index, compression type 2585 | FROM partition_compression 2586 | WHERE new_compression_type IS NOT NULL 2587 | ), 2588 | packed_partition_group AS 2589 | ( 2590 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 2591 | QUOTENAME(OBJECT_NAME(object_id)) COLLATE DATABASE_DEFAULT AS object_name, 2592 | QUOTENAME(index_name) COLLATE DATABASE_DEFAULT AS index_name, 2593 | index_type COLLATE DATABASE_DEFAULT AS index_type, 2594 | present_compression_type, 2595 | new_compression_type, 2596 | SUM(total_partition_size_mb) AS partition_range_total_size_mb, 2597 | SUM(in_row_partition_size_mb) AS partition_range_in_row_size_mb, 2598 | SUM(row_overflow_partition_size_mb) AS partition_range_row_overflow_size_mb, 2599 | SUM(lob_partition_size_mb) AS partition_range_lob_size_mb, 2600 | CONCAT(MIN(partition_number), '-', MAX(partition_number)) AS partition_range, 2601 | MIN(object_size_mb) AS object_size_mb 2602 | FROM partition_compression_interval 2603 | GROUP BY object_id, 2604 | index_name, 2605 | index_type, 2606 | present_compression_type, 2607 | new_compression_type, 2608 | interval_group 2609 | HAVING COUNT(1) > 0 2610 | ), 2611 | packed_partition_group_agg AS 2612 | ( 2613 | SELECT STRING_AGG( 2614 | CAST(CONCAT( 2615 | 'schema: ', schema_name, 2616 | ', object: ', object_name, 2617 | ', index: ' + index_name, 2618 | ', index type: ', index_type, 2619 | ', object size (MB): ', FORMAT(object_size_mb, 'N'), 2620 | ', partition range: ', partition_range, 2621 | ', partition range total size (MB): ', FORMAT(partition_range_total_size_mb, 'N'), 2622 | ' (in-row: ', FORMAT(partition_range_in_row_size_mb, 'N'), 2623 | ', row overflow: ', FORMAT(partition_range_row_overflow_size_mb, 'N'), 2624 | ', LOB: ', FORMAT(partition_range_lob_size_mb, 'N'), 2625 | '), present compression type: ', present_compression_type, 2626 | ', suggested compression type: ', new_compression_type, 2627 | ', index rebuild statement: ', CONCAT( 2628 | 'ALTER INDEX ', index_name, ' ON ', schema_name, '.', object_name, 2629 | ' REBUILD', IIF(partition_range = '1-1', '', CONCAT(' PARTITION = <', partition_range, '>')), 2630 | ' WITH (', 'DATA_COMPRESSION = ', new_compression_type, ',', 2631 | ' ONLINE = ON (WAIT_AT_LOW_PRIORITY (MAX_DURATION = 15 MINUTES, ABORT_AFTER_WAIT = SELF)), RESUMABLE = ON);' 2632 | ) 2633 | ) AS nvarchar(max)), @CRLF 2634 | ) 2635 | AS details 2636 | FROM packed_partition_group 2637 | HAVING COUNT(1) > 0 2638 | ) 2639 | INSERT INTO @DetectedTip (tip_id, details) 2640 | SELECT 1180 AS tip_id, 2641 | CONCAT( 2642 | @NbspCRLF, 2643 | 'Since database engine startup at ', CONVERT(varchar(20), si.sqlserver_start_time, 120), 2644 | ' UTC:', 2645 | @CRLF, 2646 | ppga.details, 2647 | @CRLF 2648 | ) AS details 2649 | FROM packed_partition_group_agg AS ppga 2650 | CROSS JOIN sys.dm_os_sys_info AS si 2651 | WHERE ppga.details IS NOT NULL 2652 | ; 2653 | 2654 | END TRY 2655 | BEGIN CATCH 2656 | IF ERROR_NUMBER() = 1222 2657 | INSERT INTO @SkippedTip (tip_id) 2658 | VALUES (1180); 2659 | ELSE 2660 | THROW; 2661 | END CATCH; 2662 | 2663 | -- Page compression wasting CPU 2664 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1540) AND execute_indicator = 1) 2665 | 2666 | BEGIN TRY 2667 | 2668 | WITH 2669 | partition_size AS 2670 | ( 2671 | SELECT p.object_id, 2672 | p.index_id, 2673 | p.partition_number, 2674 | p.data_compression_desc, 2675 | SUM(ps.used_page_count) * 8 / 1024. AS total_partition_size_mb, 2676 | SUM(ps.in_row_used_page_count) * 8 / 1024. AS in_row_partition_size_mb, 2677 | SUM(ps.row_overflow_used_page_count) * 8 / 1024. AS row_overflow_partition_size_mb, 2678 | SUM(ps.lob_used_page_count) * 8 / 1024. AS lob_partition_size_mb 2679 | FROM sys.partitions AS p 2680 | INNER JOIN sys.dm_db_partition_stats AS ps 2681 | ON p.partition_id = ps.partition_id 2682 | AND 2683 | p.object_id = ps.object_id 2684 | AND 2685 | p.index_id = ps.index_id 2686 | GROUP BY p.object_id, 2687 | p.index_id, 2688 | p.partition_number, 2689 | p.data_compression_desc 2690 | ), 2691 | -- Look at index stats for each partition of an index 2692 | partition_stats AS 2693 | ( 2694 | SELECT o.object_id, 2695 | i.name AS index_name, 2696 | i.type_desc AS index_type, 2697 | p.partition_number, 2698 | p.total_partition_size_mb, 2699 | p.in_row_partition_size_mb, 2700 | p.row_overflow_partition_size_mb, 2701 | p.lob_partition_size_mb, 2702 | SUM(p.total_partition_size_mb) OVER (PARTITION BY o.object_id) AS object_size_mb, 2703 | p.partition_number - ROW_NUMBER() OVER ( 2704 | PARTITION BY o.object_id, i.name 2705 | ORDER BY p.partition_number 2706 | ) 2707 | AS interval_group, -- used to pack contiguous partition intervals for the same object and index 2708 | ios.page_compression_attempt_count, 2709 | ios.page_compression_success_count 2710 | FROM sys.objects AS o 2711 | INNER JOIN sys.indexes AS i 2712 | ON o.object_id = i.object_id 2713 | INNER JOIN partition_size AS p 2714 | ON i.object_id = p.object_id 2715 | AND 2716 | i.index_id = p.index_id 2717 | CROSS APPLY sys.dm_db_index_operational_stats(DB_ID(), o.object_id, i.index_id, p.partition_number) AS ios -- assumption: a representative workload has populated index operational stats 2718 | WHERE i.type_desc IN ('CLUSTERED','NONCLUSTERED','HEAP') 2719 | AND 2720 | p.data_compression_desc = 'PAGE' 2721 | AND 2722 | o.is_ms_shipped = 0 2723 | AND 2724 | i.is_hypothetical = 0 2725 | AND 2726 | i.is_disabled = 0 2727 | AND 2728 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 2729 | AND 2730 | ios.page_compression_attempt_count > @PageCompressionAttemptsThreshold 2731 | AND 2732 | ios.page_compression_success_count * 1.0 < @MinPageCompressionSuccessRatio * ios.page_compression_attempt_count 2733 | ), 2734 | packed_partition_group AS 2735 | ( 2736 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 2737 | QUOTENAME(OBJECT_NAME(object_id)) COLLATE DATABASE_DEFAULT AS object_name, 2738 | QUOTENAME(index_name) COLLATE DATABASE_DEFAULT AS index_name, 2739 | index_type COLLATE DATABASE_DEFAULT AS index_type, 2740 | SUM(total_partition_size_mb) AS partition_range_total_size_mb, 2741 | SUM(in_row_partition_size_mb) AS partition_range_in_row_size_mb, 2742 | SUM(row_overflow_partition_size_mb) AS partition_range_row_overflow_size_mb, 2743 | SUM(lob_partition_size_mb) AS partition_range_lob_size_mb, 2744 | SUM(page_compression_attempt_count) AS page_compression_attempt_count, 2745 | SUM(page_compression_success_count) AS page_compression_success_count, 2746 | CONCAT(MIN(partition_number), '-', MAX(partition_number)) AS partition_range, 2747 | MIN(object_size_mb) AS object_size_mb 2748 | FROM partition_stats 2749 | GROUP BY object_id, 2750 | index_name, 2751 | index_type, 2752 | interval_group 2753 | HAVING COUNT(1) > 0 2754 | ), 2755 | packed_partition_group_agg AS 2756 | ( 2757 | SELECT STRING_AGG( 2758 | CAST(CONCAT( 2759 | 'schema: ', schema_name, 2760 | ', object: ', object_name, 2761 | ', index: ' + index_name, 2762 | ', index type: ', index_type, 2763 | ', object size (MB): ', FORMAT(object_size_mb, 'N'), 2764 | ', partition range: ', partition_range, 2765 | ', partition range total size (MB): ', FORMAT(partition_range_total_size_mb, 'N'), 2766 | ' (in-row: ', FORMAT(partition_range_in_row_size_mb, 'N'), 2767 | ', row overflow: ', FORMAT(partition_range_row_overflow_size_mb, 'N'), 2768 | ', LOB: ', FORMAT(partition_range_lob_size_mb, 'N'), 2769 | '), page compression total attempts: ', FORMAT(page_compression_attempt_count, '#,0'), 2770 | ', page compression successful attempts: ', FORMAT(page_compression_success_count, '#,0') 2771 | ) AS nvarchar(max)), @CRLF 2772 | ) 2773 | AS details 2774 | FROM packed_partition_group 2775 | HAVING COUNT(1) > 0 2776 | ) 2777 | INSERT INTO @DetectedTip (tip_id, details) 2778 | SELECT 1540 AS tip_id, 2779 | CONCAT( 2780 | @NbspCRLF, 2781 | 'Since database engine startup at ', CONVERT(varchar(20), si.sqlserver_start_time, 120), 2782 | ' UTC:', 2783 | @CRLF, 2784 | ppga.details, 2785 | @CRLF 2786 | ) AS details 2787 | FROM packed_partition_group_agg AS ppga 2788 | CROSS JOIN sys.dm_os_sys_info AS si 2789 | WHERE ppga.details IS NOT NULL 2790 | ; 2791 | 2792 | END TRY 2793 | BEGIN CATCH 2794 | IF ERROR_NUMBER() = 1222 2795 | INSERT INTO @SkippedTip (tip_id) 2796 | VALUES (1540); 2797 | ELSE 2798 | THROW; 2799 | END CATCH; 2800 | 2801 | -- Missing indexes 2802 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1210) AND execute_indicator = 1) 2803 | 2804 | BEGIN TRY 2805 | 2806 | WITH missing_index_agg AS 2807 | ( 2808 | SELECT STRING_AGG( 2809 | CAST(CONCAT( 2810 | 'object_name: ', 2811 | d.statement, 2812 | ', equality columns: ' + d.equality_columns, 2813 | ', inequality columns: ' + d.inequality_columns, 2814 | ', included columns: ' + d.included_columns, 2815 | ', unique compiles: ', FORMAT(gs.unique_compiles, '#,0'), 2816 | ', user seeks: ', FORMAT(gs.user_seeks, '#,0'), 2817 | ', user scans: ', FORMAT(gs.user_scans, '#,0'), 2818 | ', avg user impact: ', gs.avg_user_impact, '%.' 2819 | ) AS nvarchar(max)), @CRLF 2820 | ) 2821 | AS details, 2822 | COUNT(1) AS index_count 2823 | FROM sys.dm_db_missing_index_group_stats AS gs 2824 | INNER JOIN sys.dm_db_missing_index_groups AS g 2825 | ON gs.group_handle = g.index_group_handle 2826 | INNER JOIN sys.dm_db_missing_index_details AS d 2827 | ON g.index_handle = d.index_handle 2828 | WHERE gs.avg_user_impact > @MissingIndexAvgUserImpactThreshold 2829 | HAVING COUNT(1) > 0 2830 | ) 2831 | INSERT INTO @DetectedTip (tip_id, details) 2832 | SELECT 1210 AS tip_id, 2833 | CONCAT( 2834 | @NbspCRLF, 2835 | 'Since database engine startup at ', CONVERT(varchar(20), si.sqlserver_start_time, 120), 2836 | ' UTC:', 2837 | REPLICATE(@CRLF, 2), 2838 | 'Total indexes: ', FORMAT(index_count, '#,0'), 2839 | @CRLF, @CRLF, 2840 | mia.details, 2841 | @CRLF 2842 | ) AS details 2843 | FROM missing_index_agg AS mia 2844 | CROSS JOIN sys.dm_os_sys_info AS si 2845 | WHERE mia.details IS NOT NULL; 2846 | 2847 | END TRY 2848 | BEGIN CATCH 2849 | IF ERROR_NUMBER() = 1222 2850 | INSERT INTO @SkippedTip (tip_id) 2851 | VALUES (1210); 2852 | ELSE 2853 | THROW; 2854 | END CATCH; 2855 | 2856 | -- Data IO reaching user workload group SLO limit, or significant IO RG impact at user workload group level 2857 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1230,1240) AND execute_indicator = 1) 2858 | 2859 | WITH 2860 | io_rg_snapshot AS 2861 | ( 2862 | SELECT wgh.snapshot_time, 2863 | wgh.duration_ms, 2864 | wgh.delta_reads_issued / (wgh.duration_ms / 1000.) AS read_iops, 2865 | wgh.delta_writes_issued / (wgh.duration_ms / 1000.) AS write_iops, -- this is commonly zero, most writes are background writes to data files 2866 | (wgh.delta_read_bytes / (wgh.duration_ms / 1000.)) / 1024. / 1024 AS read_throughput_mbps, 2867 | wgh.delta_background_writes / (wgh.duration_ms / 1000.) AS background_write_iops, -- checkpoint, lazy writer, PVS 2868 | (wgh.delta_background_write_bytes / (wgh.duration_ms / 1000.)) / 1024. / 1024 AS background_write_throughput_mbps, 2869 | wgh.delta_read_stall_queued_ms, -- time spent in SQL IO RG 2870 | wgh.delta_read_stall_ms, -- total time spent completing the IO, including SQL IO RG time 2871 | rg.primary_group_max_io, -- workload group IOPS limit 2872 | IIF( 2873 | wgh.delta_reads_issued 2874 | + 2875 | IIF(rg.govern_background_io = 0, wgh.delta_background_writes, 0) -- depending on SLO, background write IO may or may not be accounted toward workload group IOPS limit 2876 | > 2877 | CAST(rg.primary_group_max_io AS bigint) * wgh.duration_ms / 1000 * @GroupIORGAtLimitThresholdRatio, -- over n% of IOPS budget for this interval 2878 | 1, 2879 | 0 2880 | ) AS reached_iops_limit_indicator, 2881 | IIF( 2882 | wgh.delta_read_stall_queued_ms * 1. / NULLIF(wgh.delta_read_stall_ms, 0) 2883 | > 2884 | @GroupIORGImpactRatio, 2885 | 1, 2886 | 0 2887 | ) AS significant_io_rg_impact_indicator -- over n% of IO stall is spent in SQL IO RG 2888 | FROM sys.dm_resource_governor_workload_groups_history_ex AS wgh 2889 | CROSS JOIN sys.dm_user_db_resource_governance AS rg 2890 | WHERE @EngineEdition = 5 2891 | AND 2892 | rg.database_id = DB_ID() 2893 | AND 2894 | wgh.name like 'UserPrimaryGroup.DB%' 2895 | AND 2896 | TRY_CAST(RIGHT(wgh.name, LEN(wgh.name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID() 2897 | ), 2898 | pre_packed_io_rg_snapshot AS 2899 | ( 2900 | SELECT SUM(duration_ms) OVER (ORDER BY (SELECT 'no order')) / 60000 AS recent_history_duration_minutes, 2901 | duration_ms, 2902 | snapshot_time, 2903 | read_iops, 2904 | write_iops, 2905 | background_write_iops, 2906 | delta_read_stall_queued_ms, 2907 | delta_read_stall_ms, 2908 | read_throughput_mbps, 2909 | background_write_throughput_mbps, 2910 | primary_group_max_io, 2911 | reached_iops_limit_indicator, 2912 | significant_io_rg_impact_indicator, 2913 | ROW_NUMBER() OVER (ORDER BY snapshot_time) -- row number across all readings, in increasing chronological order 2914 | - 2915 | SUM(reached_iops_limit_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where the threshold was exceeded 2916 | AS limit_grouping_helper, -- this difference remains constant while the threshold is exceeded, and can be used to collapse/pack an interval using aggregation 2917 | ROW_NUMBER() OVER (ORDER BY snapshot_time) 2918 | - 2919 | SUM(significant_io_rg_impact_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) 2920 | AS impact_grouping_helper 2921 | FROM io_rg_snapshot 2922 | ), 2923 | -- each row is an interval where IOPS was continuously at limit, with aggregated IO stats 2924 | packed_io_rg_snapshot_limit AS 2925 | ( 2926 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 2927 | MIN(snapshot_time) AS min_snapshot_time, 2928 | MAX(snapshot_time) AS max_snapshot_time, 2929 | AVG(duration_ms) AS avg_snapshot_duration_ms, 2930 | SUM(delta_read_stall_queued_ms) AS total_read_queued_time_ms, 2931 | SUM(delta_read_stall_ms) AS total_read_time_ms, 2932 | AVG(read_iops) AS avg_read_iops, 2933 | MAX(read_iops) AS max_read_iops, 2934 | AVG(write_iops) AS avg_write_iops, 2935 | MAX(write_iops) AS max_write_iops, 2936 | AVG(background_write_iops) AS avg_background_write_iops, 2937 | MAX(background_write_iops) AS max_background_write_iops, 2938 | AVG(read_throughput_mbps) AS avg_read_throughput_mbps, 2939 | MAX(read_throughput_mbps) AS max_read_throughput_mbps, 2940 | AVG(background_write_throughput_mbps) AS avg_background_write_throughput_mbps, 2941 | MAX(background_write_throughput_mbps) AS max_background_write_throughput_mbps, 2942 | MIN(primary_group_max_io) AS primary_group_max_io 2943 | FROM pre_packed_io_rg_snapshot 2944 | WHERE reached_iops_limit_indicator = 1 2945 | GROUP BY limit_grouping_helper 2946 | ), 2947 | -- each row is an interval where IO RG impact remained over the significance threshold, with aggregated IO stats 2948 | packed_io_rg_snapshot_impact AS 2949 | ( 2950 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 2951 | MIN(snapshot_time) AS min_snapshot_time, 2952 | MAX(snapshot_time) AS max_snapshot_time, 2953 | AVG(duration_ms) AS avg_snapshot_duration_ms, 2954 | SUM(delta_read_stall_queued_ms) AS total_read_queued_time_ms, 2955 | SUM(delta_read_stall_ms) AS total_read_time_ms, 2956 | AVG(read_iops) AS avg_read_iops, 2957 | MAX(read_iops) AS max_read_iops, 2958 | AVG(write_iops) AS avg_write_iops, 2959 | MAX(write_iops) AS max_write_iops, 2960 | AVG(background_write_iops) AS avg_background_write_iops, 2961 | MAX(background_write_iops) AS max_background_write_iops, 2962 | AVG(read_throughput_mbps) AS avg_read_throughput_mbps, 2963 | MAX(read_throughput_mbps) AS max_read_throughput_mbps, 2964 | AVG(background_write_throughput_mbps) AS avg_background_write_throughput_mbps, 2965 | MAX(background_write_throughput_mbps) AS max_background_write_throughput_mbps, 2966 | MIN(primary_group_max_io) AS primary_group_max_io 2967 | FROM pre_packed_io_rg_snapshot 2968 | WHERE significant_io_rg_impact_indicator = 1 2969 | GROUP BY impact_grouping_helper 2970 | ), 2971 | -- one row, a summary across all intervals where IOPS was continuously at limit 2972 | packed_io_rg_snapshot_limit_agg AS 2973 | ( 2974 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 2975 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time) + avg_snapshot_duration_ms / 1000.) AS longest_io_rg_at_limit_duration_seconds, 2976 | COUNT(1) AS count_io_rg_at_limit_intervals, 2977 | SUM(total_read_time_ms) AS total_read_time_ms, 2978 | SUM(total_read_queued_time_ms) AS total_read_queued_time_ms, 2979 | AVG(avg_read_iops) AS avg_read_iops, 2980 | MAX(max_read_iops) AS max_read_iops, 2981 | AVG(avg_write_iops) AS avg_write_iops, 2982 | MAX(max_write_iops) AS max_write_iops, 2983 | AVG(avg_background_write_iops) AS avg_background_write_iops, 2984 | MAX(max_background_write_iops) AS max_background_write_iops, 2985 | AVG(avg_read_throughput_mbps) AS avg_read_throughput_mbps, 2986 | MAX(max_read_throughput_mbps) AS max_read_throughput_mbps, 2987 | AVG(avg_background_write_throughput_mbps) AS avg_background_write_throughput_mbps, 2988 | MAX(max_background_write_throughput_mbps) AS max_background_write_throughput_mbps, 2989 | MIN(primary_group_max_io) AS primary_group_max_io 2990 | FROM packed_io_rg_snapshot_limit 2991 | ), 2992 | -- one row, a summary across all intervals where IO RG impact remained over the significance threshold 2993 | packed_io_rg_snapshot_impact_agg AS 2994 | ( 2995 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 2996 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time) + avg_snapshot_duration_ms / 1000.) AS longest_io_rg_impact_duration_seconds, 2997 | COUNT(1) AS count_io_rg_impact_intervals, 2998 | SUM(total_read_time_ms) AS total_read_time_ms, 2999 | SUM(total_read_queued_time_ms) AS total_read_queued_time_ms, 3000 | AVG(avg_read_iops) AS avg_read_iops, 3001 | MAX(max_read_iops) AS max_read_iops, 3002 | AVG(avg_write_iops) AS avg_write_iops, 3003 | MAX(max_write_iops) AS max_write_iops, 3004 | AVG(avg_background_write_iops) AS avg_background_write_iops, 3005 | MAX(max_background_write_iops) AS max_background_write_iops, 3006 | AVG(avg_read_throughput_mbps) AS avg_read_throughput_mbps, 3007 | MAX(max_read_throughput_mbps) AS max_read_throughput_mbps, 3008 | AVG(avg_background_write_throughput_mbps) AS avg_background_write_throughput_mbps, 3009 | MAX(max_background_write_throughput_mbps) AS max_background_write_throughput_mbps 3010 | FROM packed_io_rg_snapshot_impact 3011 | ) 3012 | INSERT INTO @DetectedTip (tip_id, details) 3013 | SELECT td.tip_id, 3014 | CONCAT( 3015 | @NbspCRLF, 3016 | 'In the last ', l.recent_history_duration_minutes, 3017 | ' minutes, there were ', l.count_io_rg_at_limit_intervals, 3018 | ' time interval(s) when total data IO approached the workload group (database-level) IOPS limit of the service objective, ', FORMAT(l.primary_group_max_io, '#,0'), ' IOPS.', @CRLF, @CRLF, 3019 | 'Aggregated across these intervals, IO statistics were: ', @CRLF, @CRLF, 3020 | 'longest interval duration: ', FORMAT(l.longest_io_rg_at_limit_duration_seconds, '#,0'), ' seconds; ', @CRLF, 3021 | 'total read IO time: ', FORMAT(l.total_read_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3022 | 'total queued read IO time: ', FORMAT(l.total_read_queued_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3023 | 'average read IOPS: ', FORMAT(l.avg_read_iops, '#,0'), '; ', @CRLF, 3024 | 'maximum read IOPS: ', FORMAT(l.max_read_iops, '#,0'), '; ', @CRLF, 3025 | 'average write IOPS: ', FORMAT(l.avg_write_iops, '#,0'), '; ', @CRLF, 3026 | 'maximum write IOPS: ', FORMAT(l.max_write_iops, '#,0'), '; ', @CRLF, 3027 | 'average background write IOPS: ', FORMAT(l.avg_background_write_iops, '#,0'), '; ', @CRLF, 3028 | 'maximum background write IOPS: ', FORMAT(l.max_background_write_iops, '#,0'), '; ', @CRLF, 3029 | 'average read IO throughput: ', FORMAT(l.avg_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3030 | 'maximum read IO throughput: ', FORMAT(l.max_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3031 | 'average background write IO throughput: ', FORMAT(l.avg_background_write_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3032 | 'maximum background write IO throughput: ', FORMAT(l.max_background_write_throughput_mbps, '#,0.00'), ' MBps.', 3033 | @CRLF 3034 | ) 3035 | AS details 3036 | FROM packed_io_rg_snapshot_limit_agg AS l 3037 | INNER JOIN @TipDefinition AS td 3038 | ON td.tip_id = 1230 3039 | WHERE l.count_io_rg_at_limit_intervals > 0 3040 | AND 3041 | td.execute_indicator = 1 3042 | UNION 3043 | SELECT td.tip_id, 3044 | CONCAT( 3045 | @NbspCRLF, 3046 | 'In the last ', i.recent_history_duration_minutes, 3047 | ' minutes, there were ', i.count_io_rg_impact_intervals, 3048 | ' time interval(s) when workload group (database-level) resource governance for the selected service objective was significantly delaying IO requests.', @CRLF, @CRLF, 3049 | 'Aggregated across these intervals, IO statistics were: ', @CRLF, @CRLF, 3050 | 'longest interval duration: ', FORMAT(i.longest_io_rg_impact_duration_seconds, '#,0'), ' seconds; ', @CRLF, 3051 | 'total read IO time: ', FORMAT(i.total_read_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3052 | 'total queued read IO time: ', FORMAT(i.total_read_queued_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3053 | 'average read IOPS: ', FORMAT(i.avg_read_iops, '#,0'), '; ', @CRLF, 3054 | 'maximum read IOPS: ', FORMAT(i.max_read_iops, '#,0'), '; ', @CRLF, 3055 | 'average write IOPS: ', FORMAT(i.avg_write_iops, '#,0'), '; ', @CRLF, 3056 | 'maximum write IOPS: ', FORMAT(i.max_write_iops, '#,0'), '; ', @CRLF, 3057 | 'average background write IOPS: ', FORMAT(i.avg_background_write_iops, '#,0'), '; ', @CRLF, 3058 | 'maximum background write IOPS: ', FORMAT(i.max_background_write_iops, '#,0'), '; ', @CRLF, 3059 | 'average read IO throughput: ', FORMAT(i.avg_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3060 | 'maximum read IO throughput: ', FORMAT(i.max_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3061 | 'average background write IO throughput: ', FORMAT(i.avg_background_write_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3062 | 'maximum background write IO throughput: ', FORMAT(i.max_background_write_throughput_mbps, '#,0.00'), ' MBps.', 3063 | @CRLF 3064 | ) 3065 | AS details 3066 | FROM packed_io_rg_snapshot_impact_agg AS i 3067 | INNER JOIN @TipDefinition AS td 3068 | ON td.tip_id = 1240 3069 | WHERE i.count_io_rg_impact_intervals > 0 3070 | AND 3071 | td.execute_indicator = 1 3072 | ; 3073 | 3074 | -- Data IO reaching user resource pool SLO limit, or significant IO RG impact at user resource pool level 3075 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1250,1260) AND execute_indicator = 1) 3076 | 3077 | WITH 3078 | io_rg_snapshot AS 3079 | ( 3080 | SELECT rph.snapshot_time, 3081 | rph.duration_ms, 3082 | rph.delta_read_io_issued / (rph.duration_ms / 1000.) AS read_iops, 3083 | rph.delta_write_io_issued / (rph.duration_ms / 1000.) AS write_iops, -- this is commonly zero, most writes are background writes to data files 3084 | (rph.delta_read_bytes / (rph.duration_ms / 1000.)) / 1024. / 1024 AS read_throughput_mbps, 3085 | rph.delta_read_io_stall_queued_ms, -- time spent in SQL IO RG 3086 | rph.delta_read_io_stall_ms, -- total time spent completing the IO, including SQL IO RG time 3087 | rg.pool_max_io, -- resource pool IOPS limit 3088 | IIF( 3089 | rph.delta_read_io_issued 3090 | > 3091 | CAST(rg.pool_max_io AS bigint) * rph.duration_ms / 1000 * @PoolIORGAtLimitThresholdRatio, -- over n% of IOPS budget for this interval 3092 | 1, 3093 | 0 3094 | ) AS reached_iops_limit_indicator, 3095 | IIF( 3096 | rph.delta_read_io_stall_queued_ms * 1. / NULLIF(rph.delta_read_io_stall_ms, 0) 3097 | > 3098 | @PoolIORGImpactRatio, 3099 | 1, 3100 | 0 3101 | ) AS significant_io_rg_impact_indicator -- over n% of IO stall is spent in SQL IO RG 3102 | FROM sys.dm_resource_governor_resource_pools_history_ex AS rph 3103 | CROSS JOIN sys.dm_user_db_resource_governance AS rg 3104 | WHERE @EngineEdition = 5 3105 | AND 3106 | rg.database_id = DB_ID() 3107 | AND 3108 | -- Consider user resource pool only 3109 | ( 3110 | rph.name LIKE 'SloSharedPool%' 3111 | OR 3112 | rph.name LIKE 'UserPool%' 3113 | ) 3114 | AND 3115 | rg.pool_max_io > 0 -- resource pool IO is governed 3116 | ), 3117 | pre_packed_io_rg_snapshot AS 3118 | ( 3119 | SELECT SUM(duration_ms) OVER (ORDER BY (SELECT 'no order')) / 60000 AS recent_history_duration_minutes, 3120 | duration_ms, 3121 | snapshot_time, 3122 | read_iops, 3123 | write_iops, 3124 | delta_read_io_stall_queued_ms, 3125 | delta_read_io_stall_ms, 3126 | read_throughput_mbps, 3127 | pool_max_io, 3128 | reached_iops_limit_indicator, 3129 | significant_io_rg_impact_indicator, 3130 | ROW_NUMBER() OVER (ORDER BY snapshot_time) -- row number across all readings, in increasing chronological order 3131 | - 3132 | SUM(reached_iops_limit_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where the threshold was exceeded 3133 | AS limit_grouping_helper, -- this difference remains constant while the threshold is exceeded, and can be used to collapse/pack an interval using aggregation 3134 | ROW_NUMBER() OVER (ORDER BY snapshot_time) 3135 | - 3136 | SUM(significant_io_rg_impact_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) 3137 | AS impact_grouping_helper 3138 | FROM io_rg_snapshot 3139 | ), 3140 | -- each row is an interval where IOPS was continuously at limit, with aggregated IO stats 3141 | packed_io_rg_snapshot_limit AS 3142 | ( 3143 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3144 | MIN(snapshot_time) AS min_snapshot_time, 3145 | MAX(snapshot_time) AS max_snapshot_time, 3146 | AVG(duration_ms) AS avg_snapshot_duration_ms, 3147 | SUM(delta_read_io_stall_queued_ms) AS total_read_queued_time_ms, 3148 | SUM(delta_read_io_stall_ms) AS total_read_time_ms, 3149 | AVG(read_iops) AS avg_read_iops, 3150 | MAX(read_iops) AS max_read_iops, 3151 | AVG(write_iops) AS avg_write_iops, 3152 | MAX(write_iops) AS max_write_iops, 3153 | AVG(read_throughput_mbps) AS avg_read_throughput_mbps, 3154 | MAX(read_throughput_mbps) AS max_read_throughput_mbps, 3155 | MIN(pool_max_io) AS pool_max_io 3156 | FROM pre_packed_io_rg_snapshot 3157 | WHERE reached_iops_limit_indicator = 1 3158 | GROUP BY limit_grouping_helper 3159 | ), 3160 | -- each row is an interval where IO RG impact remained over the significance threshold, with aggregated IO stats 3161 | packed_io_rg_snapshot_impact AS 3162 | ( 3163 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3164 | MIN(snapshot_time) AS min_snapshot_time, 3165 | MAX(snapshot_time) AS max_snapshot_time, 3166 | AVG(duration_ms) AS avg_snapshot_duration_ms, 3167 | SUM(delta_read_io_stall_queued_ms) AS total_read_queued_time_ms, 3168 | SUM(delta_read_io_stall_ms) AS total_read_time_ms, 3169 | AVG(read_iops) AS avg_read_iops, 3170 | MAX(read_iops) AS max_read_iops, 3171 | AVG(write_iops) AS avg_write_iops, 3172 | MAX(write_iops) AS max_write_iops, 3173 | AVG(read_throughput_mbps) AS avg_read_throughput_mbps, 3174 | MAX(read_throughput_mbps) AS max_read_throughput_mbps, 3175 | MIN(pool_max_io) AS pool_max_io 3176 | FROM pre_packed_io_rg_snapshot 3177 | WHERE significant_io_rg_impact_indicator = 1 3178 | GROUP BY impact_grouping_helper 3179 | ), 3180 | -- one row, a summary across all intervals where IOPS was continuously at limit 3181 | packed_io_rg_snapshot_limit_agg AS 3182 | ( 3183 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3184 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time) + avg_snapshot_duration_ms / 1000.) AS longest_io_rg_at_limit_duration_seconds, 3185 | COUNT(1) AS count_io_rg_at_limit_intervals, 3186 | SUM(total_read_time_ms) AS total_read_time_ms, 3187 | SUM(total_read_queued_time_ms) AS total_read_queued_time_ms, 3188 | AVG(avg_read_iops) AS avg_read_iops, 3189 | MAX(max_read_iops) AS max_read_iops, 3190 | AVG(avg_write_iops) AS avg_write_iops, 3191 | MAX(max_write_iops) AS max_write_iops, 3192 | AVG(avg_read_throughput_mbps) AS avg_read_throughput_mbps, 3193 | MAX(max_read_throughput_mbps) AS max_read_throughput_mbps, 3194 | MIN(pool_max_io) AS pool_max_io 3195 | FROM packed_io_rg_snapshot_limit 3196 | ), 3197 | -- one row, a summary across all intervals where IO RG impact remained over the significance threshold 3198 | packed_io_rg_snapshot_impact_agg AS 3199 | ( 3200 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3201 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time) + avg_snapshot_duration_ms / 1000.) AS longest_io_rg_impact_duration_seconds, 3202 | COUNT(1) AS count_io_rg_impact_intervals, 3203 | SUM(total_read_time_ms) AS total_read_time_ms, 3204 | SUM(total_read_queued_time_ms) AS total_read_queued_time_ms, 3205 | AVG(avg_read_iops) AS avg_read_iops, 3206 | MAX(max_read_iops) AS max_read_iops, 3207 | AVG(avg_write_iops) AS avg_write_iops, 3208 | MAX(max_write_iops) AS max_write_iops, 3209 | AVG(avg_read_throughput_mbps) AS avg_read_throughput_mbps, 3210 | MAX(max_read_throughput_mbps) AS max_read_throughput_mbps 3211 | FROM packed_io_rg_snapshot_impact 3212 | ) 3213 | INSERT INTO @DetectedTip (tip_id, details) 3214 | SELECT td.tip_id, 3215 | CONCAT( 3216 | @NbspCRLF, 3217 | 'In the last ', l.recent_history_duration_minutes, 3218 | ' minutes, there were ', l.count_io_rg_at_limit_intervals, 3219 | ' time interval(s) when total data IO approached the resource pool IOPS limit of the service objective ', IIF(dso.service_objective = 'ElasticPool', CONCAT('for elastic pool ', QUOTENAME(dso.elastic_pool_name)), ''), ', ', FORMAT(l.pool_max_io, '#,0'), ' IOPS.', @CRLF, @CRLF, 3220 | 'Aggregated across these intervals, IO statistics were: ', @CRLF, @CRLF, 3221 | 'longest interval duration: ', FORMAT(l.longest_io_rg_at_limit_duration_seconds, '#,0'), ' seconds; ', @CRLF, 3222 | 'total read IO time: ', FORMAT(l.total_read_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3223 | 'total queued read IO time: ', FORMAT(l.total_read_queued_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3224 | 'average read IOPS: ', FORMAT(l.avg_read_iops, '#,0'), '; ', @CRLF, 3225 | 'maximum read IOPS: ', FORMAT(l.max_read_iops, '#,0'), '; ', @CRLF, 3226 | 'average write IOPS: ', FORMAT(l.avg_write_iops, '#,0'), '; ', @CRLF, 3227 | 'maximum write IOPS: ', FORMAT(l.max_write_iops, '#,0'), '; ', @CRLF, 3228 | 'average read IO throughput: ', FORMAT(l.avg_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3229 | 'maximum read IO throughput: ', FORMAT(l.max_read_throughput_mbps, '#,0.00'), ' MBps.', 3230 | @CRLF 3231 | ) 3232 | AS details 3233 | FROM packed_io_rg_snapshot_limit_agg AS l 3234 | INNER JOIN @TipDefinition AS td 3235 | ON td.tip_id = 1250 3236 | CROSS JOIN sys.database_service_objectives AS dso 3237 | WHERE l.count_io_rg_at_limit_intervals > 0 3238 | AND 3239 | dso.database_id = DB_ID() 3240 | AND 3241 | td.execute_indicator = 1 3242 | UNION 3243 | SELECT td.tip_id, 3244 | CONCAT( 3245 | @NbspCRLF, 3246 | 'In the last ', i.recent_history_duration_minutes, 3247 | ' minutes, there were ', i.count_io_rg_impact_intervals, 3248 | ' time interval(s) when resource pool resource governance for the selected service objective was significantly delaying IO requests', IIF(dso.service_objective = 'ElasticPool', CONCAT(' for elastic pool ', QUOTENAME(dso.elastic_pool_name)), ''), '.', @CRLF, @CRLF, 3249 | 'Aggregated across these intervals, IO statistics were: ', @CRLF, @CRLF, 3250 | 'longest interval duration: ', FORMAT(i.longest_io_rg_impact_duration_seconds, '#,0'), ' seconds; ', @CRLF, 3251 | 'total read IO time: ', FORMAT(i.total_read_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3252 | 'total queued read IO time: ', FORMAT(i.total_read_queued_time_ms, '#,0'), ' milliseconds; ', @CRLF, 3253 | 'average read IOPS: ', FORMAT(i.avg_read_iops, '#,0'), '; ', @CRLF, 3254 | 'maximum read IOPS: ', FORMAT(i.max_read_iops, '#,0'), '; ', @CRLF, 3255 | 'average write IOPS: ', FORMAT(i.avg_write_iops, '#,0'), '; ', @CRLF, 3256 | 'maximum write IOPS: ', FORMAT(i.max_write_iops, '#,0'), '; ', @CRLF, 3257 | 'average read IO throughput: ', FORMAT(i.avg_read_throughput_mbps, '#,0.00'), ' MBps; ', @CRLF, 3258 | 'maximum read IO throughput: ', FORMAT(i.max_read_throughput_mbps, '#,0.00'), ' MBps.', 3259 | @CRLF 3260 | ) 3261 | AS details 3262 | FROM packed_io_rg_snapshot_impact_agg AS i 3263 | INNER JOIN @TipDefinition AS td 3264 | ON td.tip_id = 1260 3265 | CROSS JOIN sys.database_service_objectives AS dso 3266 | WHERE i.count_io_rg_impact_intervals > 0 3267 | AND 3268 | dso.database_id = DB_ID() 3269 | AND 3270 | td.execute_indicator = 1 3271 | ; 3272 | 3273 | -- Large PVS 3274 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1270) AND execute_indicator = 1) 3275 | 3276 | BEGIN TRY 3277 | 3278 | WITH 3279 | db_size AS 3280 | ( 3281 | SELECT SUM(CAST(FILEPROPERTY(name, 'SpaceUsed') AS bigint) * 8 / 1024. / 1024) AS space_used_gb, 3282 | SUM(CAST(size AS bigint) * 8 / 1024. / 1024) AS space_allocated_gb, 3283 | NULLIF(CAST(DATABASEPROPERTYEX(DB_NAME(), 'MaxSizeInBytes') AS bigint), -1) / 1024. / 1024 / 1024 AS max_size_gb 3284 | FROM sys.database_files 3285 | WHERE type_desc = 'ROWS' 3286 | ), 3287 | pvs_db_stats AS 3288 | ( 3289 | SELECT pvss.persistent_version_store_size_kb / 1024. / 1024 AS persistent_version_store_size_gb, 3290 | pvss.online_index_version_store_size_kb / 1024. / 1024 AS online_index_version_store_size_gb, 3291 | ds.space_used_gb, 3292 | ds.space_allocated_gb, 3293 | ds.max_size_gb, 3294 | pvss.current_aborted_transaction_count, 3295 | pvss.aborted_version_cleaner_start_time, 3296 | pvss.aborted_version_cleaner_end_time, 3297 | dt.database_transaction_begin_time AS oldest_transaction_begin_time, 3298 | asdt.session_id AS active_transaction_session_id, 3299 | asdt.elapsed_time_seconds AS active_transaction_elapsed_time_seconds 3300 | FROM sys.dm_tran_persistent_version_store_stats AS pvss 3301 | CROSS JOIN db_size AS ds 3302 | LEFT JOIN sys.dm_tran_database_transactions AS dt 3303 | ON pvss.oldest_active_transaction_id = dt.transaction_id 3304 | AND 3305 | pvss.database_id = dt.database_id 3306 | LEFT JOIN sys.dm_tran_active_snapshot_database_transactions AS asdt 3307 | ON pvss.min_transaction_timestamp = asdt.transaction_sequence_num 3308 | OR 3309 | pvss.online_index_min_transaction_timestamp = asdt.transaction_sequence_num 3310 | WHERE pvss.database_id = DB_ID() 3311 | AND 3312 | ( 3313 | pvss.persistent_version_store_size_kb > @PVSMinimumSizeThresholdGB * 1024 * 1024 -- PVS is larger than n GB 3314 | OR 3315 | ( 3316 | -- compare PVS size to database MAXSIZE, or to allocated size when MAXSIZE is not defined (Hyperscale, Managed Instance) 3317 | pvss.persistent_version_store_size_kb >= @PVSToMaxSizeMinThresholdRatio * COALESCE(ds.max_size_gb, ds.space_allocated_gb) * 1024 * 1024 -- PVS is larger than n% of database max/allocated size 3318 | AND 3319 | pvss.persistent_version_store_size_kb > 1048576 -- don't consider PVS smaller than 1 GB as large 3320 | ) 3321 | ) 3322 | ) 3323 | INSERT INTO @DetectedTip (tip_id, details) 3324 | SELECT 1270 AS tip_id, 3325 | CONCAT( 3326 | @NbspCRLF, 3327 | 'PVS size (GB): ', FORMAT(persistent_version_store_size_gb, 'N'), @CRLF, 3328 | 'online index version store size (GB): ', FORMAT(online_index_version_store_size_gb, 'N'), @CRLF, 3329 | 'used data size (GB): ', FORMAT(space_used_gb, 'N'), @CRLF, 3330 | 'allocated data size (GB): ', FORMAT(space_allocated_gb, 'N'), @CRLF, 3331 | 'maximum database size (GB): ' + FORMAT(max_size_gb, 'N') + @CRLF, -- omit for Hyperscale and MI as not applicable 3332 | 'current aborted transaction count: ', FORMAT(current_aborted_transaction_count, '#,0'), @CRLF, 3333 | 'aborted transaction version cleaner start time (UTC): ', ISNULL(CONVERT(varchar(20), aborted_version_cleaner_start_time, 120), '-'), @CRLF, 3334 | 'aborted transaction version cleaner end time (UTC): ', ISNULL(CONVERT(varchar(20), aborted_version_cleaner_end_time, 120), '-'), @CRLF, 3335 | 'oldest transaction begin time (UTC): ', ISNULL(CONVERT(varchar(30), oldest_transaction_begin_time, 121), '-'), @CRLF, 3336 | 'active transaction session_id: ', ISNULL(CAST(active_transaction_session_id AS varchar(11)), '-'), @CRLF, 3337 | 'active transaction elapsed time (seconds): ', ISNULL(CAST(active_transaction_elapsed_time_seconds AS varchar(11)), '-'), 3338 | @CRLF 3339 | ) 3340 | AS details 3341 | FROM pvs_db_stats; 3342 | 3343 | END TRY 3344 | BEGIN CATCH 3345 | IF ERROR_NUMBER() = 1222 3346 | INSERT INTO @SkippedTip (tip_id) 3347 | VALUES (1270); 3348 | ELSE 3349 | THROW; 3350 | END CATCH; 3351 | 3352 | -- CCI candidates 3353 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1290) AND execute_indicator = 1) 3354 | 3355 | BEGIN TRY 3356 | 3357 | WITH 3358 | any_partition AS 3359 | ( 3360 | SELECT p.object_id, 3361 | p.index_id, 3362 | p.partition_number, 3363 | p.rows, 3364 | p.data_compression_desc, 3365 | ps.used_page_count * 8 / 1024. AS partition_size_mb, 3366 | MAX(IIF(p.data_compression_desc IN ('COLUMNSTORE','COLUMNSTORE_ARCHIVE'), 1, 0)) OVER (PARTITION BY p.object_id) AS object_has_columnstore_indexes, 3367 | MAX(IIF(p.rows >= 102400, 1, 0)) OVER (PARTITION BY p.object_id) AS object_has_columnstore_compressible_partitions 3368 | FROM sys.partitions AS p 3369 | INNER JOIN sys.dm_db_partition_stats AS ps 3370 | ON p.partition_id = ps.partition_id 3371 | AND 3372 | p.object_id = ps.object_id 3373 | AND 3374 | p.index_id = ps.index_id 3375 | WHERE -- restrict to objects that do not have column data types not supported for CCI 3376 | NOT EXISTS ( 3377 | SELECT 1 3378 | FROM sys.columns AS c 3379 | INNER JOIN sys.types AS t 3380 | ON c.system_type_id = t.system_type_id 3381 | WHERE c.object_id = p.object_id 3382 | AND 3383 | t.name IN ('text','ntext','image','timestamp','sql_variant','hierarchyid','geometry','geography','xml') 3384 | ) 3385 | ), 3386 | candidate_partition AS 3387 | ( 3388 | SELECT object_id, 3389 | index_id, 3390 | partition_number, 3391 | rows, 3392 | partition_size_mb 3393 | FROM any_partition 3394 | WHERE data_compression_desc IN ('NONE','ROW','PAGE') 3395 | AND 3396 | -- an object with any kind of columnstore is not a candidate 3397 | object_has_columnstore_indexes = 0 3398 | AND 3399 | object_has_columnstore_compressible_partitions = 1 3400 | AND 3401 | DATABASEPROPERTYEX(DB_NAME(), 'Updateability') = 'READ_WRITE' -- only produce this on primary 3402 | ), 3403 | table_operational_stats AS -- summarize operational stats for heap, CI, and NCI 3404 | ( 3405 | SELECT cp.object_id, 3406 | SUM(IIF(cp.index_id IN (0,1), partition_size_mb, 0)) AS table_size_mb, -- exclude NCI size 3407 | SUM(IIF(cp.index_id IN (0,1), 1, 0)) AS partition_count, 3408 | SUM(ios.leaf_insert_count) AS lead_insert_count, 3409 | SUM(ios.leaf_update_count) AS leaf_update_count, 3410 | SUM(ios.leaf_delete_count + ios.leaf_ghost_count) AS leaf_delete_count, 3411 | SUM(ios.range_scan_count) AS range_scan_count, 3412 | SUM(ios.singleton_lookup_count) AS singleton_lookup_count 3413 | FROM candidate_partition AS cp 3414 | CROSS APPLY sys.dm_db_index_operational_stats(DB_ID(), cp.object_id, cp.index_id, cp.partition_number) AS ios -- assumption: a representative workload has populated index operational stats for relevant tables 3415 | GROUP BY cp.object_id 3416 | ), 3417 | cci_candidate_table AS 3418 | ( 3419 | SELECT QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS schema_name, 3420 | QUOTENAME(t.name) COLLATE DATABASE_DEFAULT AS table_name, 3421 | tos.table_size_mb, 3422 | tos.partition_count, 3423 | tos.lead_insert_count AS insert_count, 3424 | tos.leaf_update_count AS update_count, 3425 | tos.leaf_delete_count AS delete_count, 3426 | tos.singleton_lookup_count AS singleton_lookup_count, 3427 | tos.range_scan_count AS range_scan_count, 3428 | ius.user_seeks AS seek_count, 3429 | ius.user_scans AS full_scan_count, 3430 | ius.user_lookups AS lookup_count 3431 | FROM sys.tables AS t 3432 | INNER JOIN sys.indexes AS i 3433 | ON t.object_id = i.object_id 3434 | INNER JOIN table_operational_stats AS tos 3435 | ON t.object_id = tos.object_id 3436 | INNER JOIN sys.dm_db_index_usage_stats AS ius 3437 | ON t.object_id = ius.object_id 3438 | AND 3439 | i.index_id = ius.index_id 3440 | WHERE i.type IN (0,1) -- clustered index or heap 3441 | AND 3442 | tos.table_size_mb > @CCICandidateMinSizeGB * 1024. -- consider sufficiently large tables only 3443 | AND 3444 | t.is_ms_shipped = 0 3445 | AND 3446 | -- conservatively require a CCI candidate to have no updates, seeks, or lookups 3447 | tos.leaf_update_count = 0 3448 | AND 3449 | tos.singleton_lookup_count = 0 3450 | AND 3451 | ius.user_lookups = 0 3452 | AND 3453 | ius.user_seeks = 0 3454 | AND 3455 | ius.user_scans > 0 -- require a CCI candidate to have some full scans 3456 | ), 3457 | cci_candidate_details AS 3458 | ( 3459 | SELECT STRING_AGG( 3460 | CAST(CONCAT( 3461 | 'schema: ', schema_name, ', ', 3462 | 'table: ', table_name, ', ', 3463 | 'table size (MB): ', FORMAT(table_size_mb, '#,0.00'), ', ', 3464 | 'partition count: ', FORMAT(partition_count, '#,0'), ', ', 3465 | 'inserts: ', FORMAT(insert_count, '#,0'), ', ', 3466 | 'updates: ', FORMAT(update_count, '#,0'), ', ', 3467 | 'deletes: ', FORMAT(delete_count, '#,0'), ', ', 3468 | 'singleton lookups: ', FORMAT(singleton_lookup_count, '#,0'), ', ', 3469 | 'range scans: ', FORMAT(range_scan_count, '#,0'), ', ', 3470 | 'seeks: ', FORMAT(seek_count, '#,0'), ', ', 3471 | 'full scans: ', FORMAT(full_scan_count, '#,0'), ', ', 3472 | 'lookups: ', FORMAT(lookup_count, '#,0') 3473 | ) AS nvarchar(max)), @CRLF 3474 | ) 3475 | AS details, 3476 | COUNT(1) AS cci_candidate_count 3477 | FROM cci_candidate_table 3478 | ) 3479 | INSERT INTO @DetectedTip (tip_id, details) 3480 | SELECT 1290 AS tip_id, 3481 | CONCAT( 3482 | @NbspCRLF, 3483 | 'Since database engine startup at ', CONVERT(varchar(20), si.sqlserver_start_time, 120), 3484 | ' UTC:', 3485 | REPLICATE(@CRLF, 2), 3486 | 'Total CCI candidates: ', FORMAT(cci_candidate_count, '#,0'), 3487 | @CRLF, @CRLF, 3488 | ccd.details, 3489 | @CRLF 3490 | ) AS details 3491 | FROM cci_candidate_details AS ccd 3492 | CROSS JOIN sys.dm_os_sys_info AS si 3493 | WHERE ccd.details IS NOT NULL; 3494 | 3495 | END TRY 3496 | BEGIN CATCH 3497 | IF ERROR_NUMBER() = 1222 3498 | INSERT INTO @SkippedTip (tip_id) 3499 | VALUES (1290); 3500 | ELSE 3501 | THROW; 3502 | END CATCH; 3503 | 3504 | -- Workload group workers close to limit 3505 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1360) AND execute_indicator = 1) 3506 | 3507 | WITH 3508 | worker_snapshot AS 3509 | ( 3510 | SELECT snapshot_time, 3511 | duration_ms, 3512 | active_worker_count, 3513 | max_worker, 3514 | IIF(active_worker_count * 1. / NULLIF(max_worker, 0) > @HighGroupWorkerUtilizationThresholdRatio, 1, 0) AS high_worker_utilization_indicator 3515 | FROM sys.dm_resource_governor_workload_groups_history_ex 3516 | WHERE @EngineEdition = 5 3517 | AND 3518 | name like 'UserPrimaryGroup.DB%' 3519 | AND 3520 | TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID() 3521 | ), 3522 | pre_packed_worker_snapshot AS 3523 | ( 3524 | SELECT SUM(duration_ms) OVER (ORDER BY (SELECT 'no order')) / 60000 AS recent_history_duration_minutes, 3525 | snapshot_time, 3526 | active_worker_count, 3527 | max_worker, 3528 | high_worker_utilization_indicator, 3529 | ROW_NUMBER() OVER (ORDER BY snapshot_time) -- row number across all readings, in increasing chronological order 3530 | - 3531 | SUM(high_worker_utilization_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where worker utilization exceeded the threshold 3532 | AS grouping_helper -- this difference remains constant while worker utilization is above the threshold, and can be used to collapse/pack an interval using aggregation 3533 | FROM worker_snapshot 3534 | ), 3535 | packed_worker_snapshot AS 3536 | ( 3537 | SELECT MIN(snapshot_time) AS min_snapshot_time, 3538 | MAX(snapshot_time) AS max_snapshot_time, 3539 | AVG(active_worker_count) AS avg_worker_count, 3540 | MAX(active_worker_count) AS max_worker_count, 3541 | MIN(max_worker) AS worker_limit, 3542 | MIN(recent_history_duration_minutes) AS recent_history_duration_minutes 3543 | FROM pre_packed_worker_snapshot 3544 | WHERE high_worker_utilization_indicator = 1 3545 | GROUP BY grouping_helper 3546 | ), 3547 | worker_top_stat AS 3548 | ( 3549 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3550 | MIN(worker_limit) AS worker_limit, 3551 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time)) AS longest_high_worker_duration_seconds, 3552 | AVG(avg_worker_count) AS avg_worker_count, 3553 | MAX(max_worker_count) AS max_worker_count, 3554 | COUNT(1) AS count_high_worker_intervals 3555 | FROM packed_worker_snapshot 3556 | ) 3557 | INSERT INTO @DetectedTip (tip_id, details) 3558 | SELECT 1360 AS tip_id, 3559 | CONCAT( 3560 | @NbspCRLF, 3561 | 'In the last ', recent_history_duration_minutes, 3562 | ' minutes, there were ', count_high_worker_intervals, 3563 | ' interval(s) with worker utilization staying above ', FORMAT(@HighGroupWorkerUtilizationThresholdRatio, 'P'), 3564 | ' of the workload group worker limit of ', FORMAT(worker_limit, '#,0'), 3565 | ' workers. The longest such interval lasted ', FORMAT(longest_high_worker_duration_seconds, '#,0'), 3566 | ' seconds. Across all such intervals, the average number of workers used was ', FORMAT(avg_worker_count, '#,0.00'), 3567 | ' and the maximum number of workers used was ', FORMAT(max_worker_count, '#,0'), 3568 | '.', 3569 | @CRLF 3570 | ) AS details 3571 | FROM worker_top_stat 3572 | WHERE count_high_worker_intervals > 0 3573 | ; 3574 | 3575 | -- Resource pool workers close to limit 3576 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1370) AND execute_indicator = 1) 3577 | 3578 | WITH 3579 | worker_snapshot AS 3580 | ( 3581 | SELECT snapshot_time, 3582 | duration_ms, 3583 | active_worker_count, 3584 | active_worker_count * 100. / NULLIF(max_worker_percent, 0) AS max_worker, 3585 | IIF(max_worker_percent > @HighPoolWorkerUtilizationThresholdRatio * 100., 1, 0) AS high_worker_utilization_indicator 3586 | FROM sys.dm_resource_governor_resource_pools_history_ex 3587 | WHERE @EngineEdition = 5 3588 | AND 3589 | -- Consider user resource pool only 3590 | ( 3591 | name LIKE 'SloSharedPool%' 3592 | OR 3593 | name LIKE 'UserPool%' 3594 | ) 3595 | ), 3596 | pre_packed_worker_snapshot AS 3597 | ( 3598 | SELECT SUM(duration_ms) OVER (ORDER BY (SELECT 'no order')) / 60000 AS recent_history_duration_minutes, 3599 | snapshot_time, 3600 | active_worker_count, 3601 | max_worker, 3602 | high_worker_utilization_indicator, 3603 | ROW_NUMBER() OVER (ORDER BY snapshot_time) -- row number across all readings, in increasing chronological order 3604 | - 3605 | SUM(high_worker_utilization_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) -- running count of all intervals where worker utilization exceeded the threshold 3606 | AS grouping_helper -- this difference remains constant while worker utilization is above the threshold, and can be used to collapse/pack an interval using aggregation 3607 | FROM worker_snapshot 3608 | ), 3609 | packed_worker_snapshot AS 3610 | ( 3611 | SELECT MIN(snapshot_time) AS min_snapshot_time, 3612 | MAX(snapshot_time) AS max_snapshot_time, 3613 | AVG(active_worker_count) AS avg_worker_count, 3614 | MAX(active_worker_count) AS max_worker_count, 3615 | MIN(max_worker) AS worker_limit, 3616 | MIN(recent_history_duration_minutes) AS recent_history_duration_minutes 3617 | FROM pre_packed_worker_snapshot 3618 | WHERE high_worker_utilization_indicator = 1 3619 | GROUP BY grouping_helper 3620 | ), 3621 | worker_top_stat AS 3622 | ( 3623 | SELECT MIN(recent_history_duration_minutes) AS recent_history_duration_minutes, 3624 | MIN(worker_limit) AS worker_limit, 3625 | MAX(DATEDIFF(second, min_snapshot_time, max_snapshot_time)) AS longest_high_worker_duration_seconds, 3626 | AVG(avg_worker_count) AS avg_worker_count, 3627 | MAX(max_worker_count) AS max_worker_count, 3628 | COUNT(1) AS count_high_worker_intervals 3629 | FROM packed_worker_snapshot 3630 | ) 3631 | INSERT INTO @DetectedTip (tip_id, details) 3632 | SELECT 1370 AS tip_id, 3633 | CONCAT( 3634 | @NbspCRLF, 3635 | 'In the last ', recent_history_duration_minutes, 3636 | ' minutes, there were ', count_high_worker_intervals, 3637 | ' interval(s) with worker utilization staying above ', FORMAT(@HighPoolWorkerUtilizationThresholdRatio, 'P'), 3638 | ' of the resource pool worker limit of approximately ', FORMAT(worker_limit, '#,0'), 3639 | ' workers. The longest such interval lasted ', FORMAT(longest_high_worker_duration_seconds, '#,0'), 3640 | ' seconds. Across all such intervals, the average number of workers used was ', FORMAT(avg_worker_count, '#,0.00'), 3641 | ' and the maximum number of workers used was ', FORMAT(max_worker_count, '#,0'), 3642 | '.', 3643 | @CRLF 3644 | ) AS details 3645 | FROM worker_top_stat 3646 | WHERE count_high_worker_intervals > 0 3647 | ; 3648 | 3649 | -- Notable connectivity events 3650 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1380) AND execute_indicator = 1) 3651 | BEGIN 3652 | 3653 | BEGIN TRY 3654 | 3655 | DECLARE @crb TABLE ( 3656 | event_time datetime NOT NULL, 3657 | record xml NOT NULL 3658 | ); 3659 | 3660 | -- stage XML in a table variable to enable parallelism when processing XQuery expressions 3661 | WITH crb AS 3662 | ( 3663 | SELECT DATEADD(second, -0.001 * (si.cpu_ticks/(si.cpu_ticks/si.ms_ticks) - rb.timestamp), CURRENT_TIMESTAMP) AS event_time, 3664 | TRY_CAST(rb.record AS XML) AS record 3665 | FROM sys.dm_os_ring_buffers AS rb 3666 | CROSS JOIN sys.dm_os_sys_info AS si 3667 | WHERE rb.ring_buffer_type = 'RING_BUFFER_CONNECTIVITY' 3668 | ) 3669 | INSERT INTO @crb (event_time, record) 3670 | SELECT event_time, record 3671 | FROM crb 3672 | WHERE event_time > DATEADD(minute, -@NotableNetworkEventsIntervalMinutes, CURRENT_TIMESTAMP) -- ignore older events 3673 | ; 3674 | 3675 | DROP TABLE IF EXISTS ##tips_connectivity_event; 3676 | 3677 | WITH connectivity_event AS 3678 | ( 3679 | SELECT event_time, 3680 | record 3681 | FROM @crb 3682 | WHERE record IS NOT NULL 3683 | ), 3684 | shredded_connectivity_event AS 3685 | ( 3686 | SELECT event_time, 3687 | record.value('(./Record/ConnectivityTraceRecord/RemoteHost/text())[1]','varchar(30)') AS remote_host, 3688 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TotalTime/text())[1]','int') AS login_total_time_ms, 3689 | record.value('(./Record/ConnectivityTraceRecord/RecordType/text())[1]','varchar(50)') AS record_type, 3690 | record.value('(./Record/ConnectivityTraceRecord/RecordSource/text())[1]','varchar(50)') AS record_source, 3691 | record.value('(./Record/ConnectivityTraceRecord/TdsDisconnectFlags/PhysicalConnectionIsKilled/text())[1]','bit') AS physical_connection_is_killed, 3692 | record.value('(./Record/ConnectivityTraceRecord/TdsDisconnectFlags/DisconnectDueToReadError/text())[1]','bit') AS disconnect_due_to_read_error, 3693 | record.value('(./Record/ConnectivityTraceRecord/TdsDisconnectFlags/NetworkErrorFoundInInputStream/text())[1]','bit') AS network_error_found_in_input_stream, 3694 | record.value('(./Record/ConnectivityTraceRecord/TdsDisconnectFlags/ErrorFoundBeforeLogin/text())[1]','bit') AS error_found_before_login, 3695 | record.value('(./Record/ConnectivityTraceRecord/TdsDisconnectFlags/SessionIsKilled/text())[1]','bit') AS session_is_killed, 3696 | record.value('(./Record/ConnectivityTraceRecord/Spid/text())[1]','int') AS spid, 3697 | record.value('(./Record/ConnectivityTraceRecord/OSError/text())[1]','int') AS os_error, 3698 | record.value('(./Record/ConnectivityTraceRecord/SniConsumerError/text())[1]','int') AS sni_consumer_error, 3699 | record.value('(./Record/ConnectivityTraceRecord/State/text())[1]','int') AS state, 3700 | record.value('(./Record/ConnectivityTraceRecord/RemotePort/text())[1]','int') AS remote_port, 3701 | record.value('(./Record/ConnectivityTraceRecord/LocalHost/text())[1]','varchar(30)') AS local_host, 3702 | record.value('(./Record/ConnectivityTraceRecord/LocalPort/text())[1]','int') AS local_port, 3703 | record.value('(./Record/ConnectivityTraceRecord/TdsBufInfo/InputBufError/text())[1]','int') AS input_buf_error, 3704 | record.value('(./Record/ConnectivityTraceRecord/TdsBufInfo/OutputBufError/text())[1]','int') AS output_buf_error, 3705 | record.value('(./Record/ConnectivityTraceRecord/TdsBuffersInformation/TdsInputBufferError/text())[1]','int') AS tds_input_buffer_error, 3706 | record.value('(./Record/ConnectivityTraceRecord/TdsBuffersInformation/TdsOutputBufferError/text())[1]','int') AS tds_output_buffer_error, 3707 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/EnqueueTime/text())[1]','int') AS login_enqueue_time_ms, 3708 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/NetWritesTime/text())[1]','int') AS login_net_writes_time_ms, 3709 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/NetReadsTime/text())[1]','int') AS login_net_reads_time_ms, 3710 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/Ssl/TotalTime/text())[1]','int') AS login_ssl_total_time_ms, 3711 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime/TotalTime/text())[1]','int') AS login_trigger_rg_total_time_ms, 3712 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime/FindLogin/text())[1]','int') AS login_trigger_rg_find_login_time_ms, 3713 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime/LogonTriggers/text())[1]','int') AS login_trigger_rg_logon_triggers_time_ms, 3714 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime/ExecClassifier/text())[1]','int') AS login_trigger_rg_exec_classifier_time_ms, 3715 | record.value('(./Record/ConnectivityTraceRecord/LoginTimersInMilliseconds/TriggerAndResGovTime/SessionRecover/text())[1]','int') AS login_trigger_rg_session_recover_time_ms 3716 | FROM connectivity_event 3717 | ) 3718 | SELECT sce.event_time, 3719 | sce.record_type, 3720 | sce.record_source, 3721 | sce.spid, 3722 | sce.os_error, 3723 | sce.sni_consumer_error, 3724 | m.text AS sni_consumer_error_message, 3725 | sce.state AS sni_consumer_error_state, 3726 | sce.remote_host, 3727 | sce.remote_port, 3728 | sce.local_host, 3729 | sce.local_port, 3730 | COALESCE(sce.tds_input_buffer_error, sce.input_buf_error) AS tds_input_buffer_error, 3731 | COALESCE(sce.tds_output_buffer_error, sce.output_buf_error) AS tds_output_buffer_error, 3732 | sce.physical_connection_is_killed, 3733 | sce.disconnect_due_to_read_error, 3734 | sce.network_error_found_in_input_stream, 3735 | sce.error_found_before_login, 3736 | sce.session_is_killed, 3737 | sce.login_total_time_ms, 3738 | sce.login_enqueue_time_ms, 3739 | sce.login_net_writes_time_ms, 3740 | sce.login_net_reads_time_ms, 3741 | sce.login_ssl_total_time_ms, 3742 | sce.login_trigger_rg_total_time_ms, 3743 | sce.login_trigger_rg_find_login_time_ms, 3744 | sce.login_trigger_rg_logon_triggers_time_ms, 3745 | sce.login_trigger_rg_exec_classifier_time_ms, 3746 | sce.login_trigger_rg_session_recover_time_ms 3747 | INTO ##tips_connectivity_event 3748 | FROM shredded_connectivity_event AS sce 3749 | LEFT JOIN sys.messages AS m 3750 | ON sce.sni_consumer_error = m.message_id 3751 | AND 3752 | m.language_id = 1033 3753 | WHERE sce.remote_host <> '' -- ignore SQL DB internal connections 3754 | AND 3755 | ( 3756 | ( 3757 | sce.record_type = 'Error' 3758 | AND 3759 | NOT (sce.sni_consumer_error = 18456 AND sce.state = 123) -- SSMS noise 3760 | ) 3761 | OR 3762 | ( 3763 | sce.record_type = 'LoginTimers' 3764 | AND 3765 | sce.login_total_time_ms > @NotableNetworkEventsSlowLoginThresholdMs 3766 | ) 3767 | OR 3768 | ( 3769 | sce.record_type = 'ConnectionClose' 3770 | AND 3771 | (sce.physical_connection_is_killed = 1 OR sce.disconnect_due_to_read_error = 1 OR sce.network_error_found_in_input_stream = 1 OR sce.error_found_before_login = 1 OR sce.session_is_killed = 1) 3772 | ) 3773 | ) 3774 | ; 3775 | 3776 | IF @@ROWCOUNT > 0 3777 | BEGIN 3778 | INSERT INTO @DetectedTip (tip_id, details) 3779 | SELECT 1380 AS tip_id, 3780 | CONCAT( 3781 | @NbspCRLF, 3782 | 'In the last ', FORMAT(@NotableNetworkEventsIntervalMinutes, '#,0'), 3783 | ' minutes, notable network connectivity events have occurred. For details, execute this query in the same database:', @CRLF, 3784 | 'SELECT event_age, * FROM ##tips_connectivity_event ORDER BY event_time DESC;', 3785 | @CRLF 3786 | ) AS details; 3787 | 3788 | ALTER TABLE ##tips_connectivity_event 3789 | ADD event_age AS CONCAT( 3790 | DATEDIFF(second, event_time, CURRENT_TIMESTAMP) / 3600, ' h, ', 3791 | (DATEDIFF(second, event_time, CURRENT_TIMESTAMP) % 3600) / 60, ' m, ', 3792 | DATEDIFF(second, event_time, CURRENT_TIMESTAMP) % 60, ' s' 3793 | ); 3794 | END; 3795 | 3796 | END TRY 3797 | BEGIN CATCH 3798 | IF ERROR_NUMBER() = 1222 3799 | INSERT INTO @SkippedTip (tip_id) 3800 | VALUES (1380); 3801 | ELSE 3802 | THROW; 3803 | END CATCH; 3804 | 3805 | END; 3806 | 3807 | -- Significant recent blocking 3808 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1420) AND execute_indicator = 1) 3809 | 3810 | WITH 3811 | blocking_snapshot AS 3812 | ( 3813 | SELECT snapshot_time, 3814 | duration_ms, 3815 | blocked_task_count, 3816 | delta_lock_wait_count, 3817 | delta_lock_wait_time_ms, 3818 | IIF(delta_lock_wait_time_ms > @LockBlockingTimeThresholdRatio * duration_ms OR blocked_task_count >= @LockBlockingBlockedTaskThreshold, 1, 0) AS blocking_indicator 3819 | FROM sys.dm_resource_governor_workload_groups_history_ex 3820 | WHERE @EngineEdition = 5 3821 | AND 3822 | name like 'UserPrimaryGroup.DB%' 3823 | AND 3824 | TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID() 3825 | ), 3826 | pre_packed_blocking_snapshot AS 3827 | ( 3828 | SELECT snapshot_time, 3829 | duration_ms, 3830 | blocked_task_count, 3831 | delta_lock_wait_count, 3832 | delta_lock_wait_time_ms, 3833 | blocking_indicator, 3834 | ROW_NUMBER() OVER (ORDER BY snapshot_time) 3835 | - 3836 | SUM(blocking_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) 3837 | AS grouping_helper 3838 | FROM blocking_snapshot 3839 | ), 3840 | packed_blocking_snapshot AS 3841 | ( 3842 | SELECT MIN(snapshot_time) AS min_snapshot_time, 3843 | MAX(snapshot_time) AS max_snapshot_time, 3844 | AVG(duration_ms) AS avg_snapshot_interval_duration_ms, 3845 | MIN(blocked_task_count) AS min_blocked_task_count, 3846 | MAX(blocked_task_count) AS max_blocked_task_count, 3847 | SUM(delta_lock_wait_count) AS total_lock_waits, 3848 | SUM(delta_lock_wait_time_ms) AS total_lock_wait_time_milliseconds 3849 | FROM pre_packed_blocking_snapshot 3850 | WHERE blocking_indicator = 1 3851 | GROUP BY grouping_helper 3852 | ) 3853 | INSERT INTO @DetectedTip (tip_id, details) 3854 | SELECT 1420 AS tip_id, 3855 | CONCAT( 3856 | @NbspCRLF, 3857 | 'Significant lock blocking has occurred during the following time intervals (UTC):', 3858 | @CRLF, @CRLF, 3859 | STRING_AGG( 3860 | CAST(CONCAT( 3861 | 'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'), 3862 | ', end time: ', FORMAT(max_snapshot_time, 's'), 3863 | ', duration: ', DATEADD(second, DATEDIFF(second, DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), max_snapshot_time), CAST('00:00:00' AS time(0))), 3864 | ', total lock wait time: ', DATEADD(millisecond, total_lock_wait_time_milliseconds, CAST('00:00:00' AS time(3))), 3865 | ', minimum observed blocked tasks: ', FORMAT(min_blocked_task_count, '#,0'), 3866 | ', maximum observed blocked tasks: ', FORMAT(max_blocked_task_count, '#,0'), 3867 | ', total lock waits: ', FORMAT(total_lock_waits, '#,0') 3868 | ) AS nvarchar(max)), @CRLF 3869 | ), 3870 | @CRLF 3871 | ) 3872 | AS details 3873 | FROM packed_blocking_snapshot 3874 | HAVING COUNT(1) > 0 3875 | ; 3876 | 3877 | -- High query optimizations 3878 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1430) AND execute_indicator = 1) 3879 | 3880 | WITH 3881 | high_optimizations_snapshot AS 3882 | ( 3883 | SELECT snapshot_time, 3884 | duration_ms, 3885 | delta_request_count, 3886 | delta_query_optimizations, 3887 | IIF(delta_query_optimizations > @QueryOptimizationRequestThresholdRatio * delta_request_count AND delta_request_count >= @QueryOptimizationRequestCountThreshold, 1, 0) AS high_optimizations_indicator 3888 | FROM sys.dm_resource_governor_workload_groups_history_ex 3889 | WHERE @EngineEdition = 5 3890 | AND 3891 | name like 'UserPrimaryGroup.DB%' 3892 | AND 3893 | TRY_CAST(RIGHT(name, LEN(name) - LEN('UserPrimaryGroup.DB') - 2) AS int) = DB_ID() 3894 | ), 3895 | pre_packed_high_optimizations_snapshot AS 3896 | ( 3897 | SELECT snapshot_time, 3898 | duration_ms, 3899 | delta_request_count, 3900 | delta_query_optimizations, 3901 | high_optimizations_indicator, 3902 | ROW_NUMBER() OVER (ORDER BY snapshot_time) 3903 | - 3904 | SUM(high_optimizations_indicator) OVER (ORDER BY snapshot_time ROWS UNBOUNDED PRECEDING) 3905 | AS grouping_helper 3906 | FROM high_optimizations_snapshot 3907 | ), 3908 | packed_high_optimization_snapshot AS 3909 | ( 3910 | SELECT MIN(snapshot_time) AS min_snapshot_time, 3911 | MAX(snapshot_time) AS max_snapshot_time, 3912 | AVG(duration_ms) AS avg_snapshot_interval_duration_ms, 3913 | SUM(delta_request_count) AS total_requests, 3914 | SUM(delta_query_optimizations) AS total_optimizations 3915 | FROM pre_packed_high_optimizations_snapshot 3916 | WHERE high_optimizations_indicator = 1 3917 | GROUP BY grouping_helper 3918 | ) 3919 | INSERT INTO @DetectedTip (tip_id, details) 3920 | SELECT 1430 AS tip_id, 3921 | CONCAT( 3922 | @NbspCRLF, 3923 | 'Time intervals with a high number of query optimizations (UTC):', 3924 | @CRLF, @CRLF, 3925 | STRING_AGG( 3926 | CAST(CONCAT( 3927 | 'Interval start time: ', FORMAT(DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), 's'), 3928 | ', end time: ', FORMAT(max_snapshot_time, 's'), 3929 | ', duration: ', DATEADD(second, DATEDIFF(second, DATEADD(millisecond, -avg_snapshot_interval_duration_ms, min_snapshot_time), max_snapshot_time), CAST('00:00:00' AS time(0))), 3930 | ', total requests: ', FORMAT(total_requests, '#,0'), 3931 | ', total optimizations: ', FORMAT(total_optimizations, '#,0'), 3932 | ', query optimization rate: ', FORMAT(LEAST(total_optimizations * 1.0 / total_requests, 1), 'P') 3933 | ) AS nvarchar(max)), @CRLF 3934 | ), 3935 | @CRLF 3936 | ) 3937 | AS details 3938 | FROM packed_high_optimization_snapshot 3939 | HAVING COUNT(1) > 0 3940 | ; 3941 | 3942 | -- Local storage quota 3943 | IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1450) AND execute_indicator = 1) 3944 | 3945 | WITH 3946 | local_storage AS 3947 | ( 3948 | SELECT database_id, 3949 | DB_NAME(database_id) AS database_name, 3950 | SUM(IIF(file_id <> 2, size_on_disk_bytes, 0)) / 1024. / 1024 AS data_size_on_disk_mb, 3951 | SUM(IIF(file_id = 2, size_on_disk_bytes, 0)) / 1024. / 1024 AS log_size_on_disk_mb 3952 | FROM sys.dm_io_virtual_file_stats(default, default) 3953 | GROUP BY database_id 3954 | ), 3955 | local_storage_agg AS 3956 | ( 3957 | SELECT STRING_AGG( 3958 | CAST(CONCAT( 3959 | 'database (id: ', database_id, 3960 | ', name: ' + QUOTENAME(database_name), -- database name is only available for current database and system databases, include for usability if available 3961 | '), DATA: ', FORMAT(data_size_on_disk_mb, '#,0.00'), 3962 | ', LOG: ', FORMAT(log_size_on_disk_mb, '#,0.00') 3963 | ) AS nvarchar(max)), @CRLF 3964 | ) 3965 | AS storage_summary 3966 | FROM local_storage 3967 | ), 3968 | local_storage_quota AS 3969 | ( 3970 | SELECT rg.user_data_directory_space_quota_mb, 3971 | rg.user_data_directory_space_usage_mb, 3972 | rg.user_data_directory_space_usage_mb * 1. / rg.user_data_directory_space_quota_mb AS quota_usage, 3973 | lsa.storage_summary 3974 | FROM local_storage_agg AS lsa 3975 | CROSS JOIN sys.dm_user_db_resource_governance AS rg 3976 | WHERE rg.database_id = DB_ID() 3977 | AND 3978 | DATABASEPROPERTYEX(DB_NAME(), 'Edition') IN ('Premium','BusinessCritical') -- not relevant for remote storage SLOs 3979 | ) 3980 | INSERT INTO @DetectedTip (tip_id, details) 3981 | SELECT 1450 AS tip_id, 3982 | CONCAT( 3983 | @NbspCRLF, 3984 | 'Maximum local storage (MB): ', FORMAT(user_data_directory_space_quota_mb, '#,0.00'), @CRLF, 3985 | 'Allocated local storage (MB): ', FORMAT(user_data_directory_space_usage_mb, '#,0.00'), @CRLF, 3986 | 'Local storage usage (%): ', FORMAT(quota_usage, 'P'), 3987 | @CRLF, @CRLF, 3988 | 'Allocated local storage per database (MB):', @CRLF, 3989 | storage_summary, @CRLF 3990 | ) 3991 | AS details 3992 | FROM local_storage_quota 3993 | WHERE quota_usage > @MinLocalStorageQuotaUsageRatio; 3994 | 3995 | END; -- end tips requiring VIEW SERVER STATE 3996 | 3997 | -- Return detected tips 3998 | 3999 | IF @JSONOutput = 0 4000 | SELECT td.tip_id, 4001 | td.tip_name AS description, 4002 | td.confidence_percent, 4003 | td.tip_url AS additional_info_url, 4004 | d.details 4005 | FROM @TipDefinition AS td 4006 | LEFT JOIN @DetectedTip AS dt 4007 | ON dt.tip_id = td.tip_id 4008 | OUTER APPLY ( 4009 | SELECT dt.details AS [processing-instruction(_)] 4010 | WHERE dt.details IS NOT NULL 4011 | FOR XML PATH (''), TYPE 4012 | ) d (details) 4013 | WHERE dt.tip_id IS NOT NULL 4014 | OR 4015 | @ReturnAllTips = 1 4016 | ORDER BY description; 4017 | ELSE IF @JSONOutput = 1 4018 | WITH tips AS -- flatten for JSON output 4019 | ( 4020 | SELECT td.tip_id, 4021 | td.tip_name AS description, 4022 | td.confidence_percent, 4023 | td.tip_url AS additional_info_url, 4024 | REPLACE(REPLACE(dt.details, CHAR(13), ''), NCHAR(160), '') AS details -- strip unnecessary formatting 4025 | FROM @TipDefinition AS td 4026 | LEFT JOIN @DetectedTip AS dt 4027 | ON dt.tip_id = td.tip_id 4028 | WHERE dt.tip_id IS NOT NULL 4029 | OR 4030 | @ReturnAllTips = 1 4031 | ) 4032 | SELECT * 4033 | FROM tips 4034 | ORDER BY description 4035 | FOR JSON AUTO; 4036 | 4037 | -- Output skipped tips, if any 4038 | IF @ViewServerStateIndicator = 0 4039 | OR 4040 | EXISTS (SELECT 1 FROM @TipDefinition WHERE execute_indicator = 0) 4041 | OR 4042 | EXISTS (SELECT 1 FROM @SkippedTip) 4043 | BEGIN 4044 | WITH tip AS 4045 | ( 4046 | SELECT td.tip_id, 4047 | td.tip_name, 4048 | CASE WHEN @ViewServerStateIndicator = 0 AND td.required_permission = 'VIEW SERVER STATE' THEN 'insufficient permissions' 4049 | WHEN td.execute_indicator = 0 THEN 'user-specified exclusions' 4050 | WHEN st.tip_id IS NOT NULL THEN st.reason 4051 | ELSE NULL 4052 | END 4053 | AS skipped_reason 4054 | FROM @TipDefinition AS td 4055 | LEFT JOIN @SkippedTip AS st 4056 | ON td.tip_id = st.tip_id 4057 | ), 4058 | skipped_tip AS 4059 | ( 4060 | SELECT CONCAT( 4061 | COUNT(1), 4062 | ' tip(s) were skipped because of ', 4063 | skipped_reason 4064 | ) AS warning, 4065 | CASE skipped_reason WHEN 'insufficient permissions' THEN 'https://aka.ms/sqldbtipswiki#permissions' 4066 | WHEN 'user-specified exclusions' THEN 'https://aka.ms/sqldbtipswiki#tip-exclusions' 4067 | WHEN 'lock timeout' THEN 'https://aka.ms/sqldbtipswiki#how-it-works' 4068 | END 4069 | AS additional_info_url, 4070 | CONCAT( 4071 | @NbspCRLF, 4072 | STRING_AGG( 4073 | CONCAT( 4074 | 'tip_id: ', tip_id, 4075 | ', ', tip_name 4076 | ), 4077 | @CRLF 4078 | ), 4079 | @CRLF 4080 | ) 4081 | AS skipped_tips 4082 | FROM tip 4083 | WHERE skipped_reason IS NOT NULL 4084 | GROUP BY skipped_reason 4085 | HAVING COUNT(1) > 0 4086 | ) 4087 | SELECT st.warning, 4088 | st.additional_info_url, 4089 | tl.skipped_tips 4090 | FROM skipped_tip AS st 4091 | OUTER APPLY ( 4092 | SELECT st.skipped_tips AS [processing-instruction(_)] 4093 | WHERE st.skipped_tips IS NOT NULL 4094 | FOR XML PATH (''), TYPE 4095 | ) tl (skipped_tips) 4096 | END; 4097 | 4098 | PRINT CONCAT( 4099 | 'Execution start time: ', @ExecStartTime, 4100 | ', duration: ', FORMAT(DATEDIFF(second, @ExecStartTime, SYSDATETIMEOFFSET()), '#,0'), 4101 | ' seconds' 4102 | ); 4103 | 4104 | END TRY 4105 | BEGIN CATCH 4106 | SET LOCK_TIMEOUT -1; -- revert to default 4107 | 4108 | THROW; 4109 | END CATCH; 4110 | --------------------------------------------------------------------------------