├── .gitignore ├── .vscode └── launch.json ├── .vscodeignore ├── Build.ps1 ├── CHANGELOG.md ├── LICENSE ├── README.md ├── extension-definition.json ├── src ├── README.md ├── images │ ├── icon.pdn │ ├── icon.png │ ├── mssql-instance-insights-tab.png │ ├── mssql-instance-vlfs-detail.png │ ├── mssql-instance-vlfs.png │ ├── mssql-instance-waits-details.png │ ├── mssql-instance-waits.png │ ├── mssql-instance-xelio-details.png │ ├── mssql-instance-xelio.png │ ├── mssql-instance-xelio2.png │ ├── mssql-instance-xelmemory-details.png │ ├── mssql-instance-xelmemory.png │ ├── mssql-instance-xelsystem-details.png │ ├── mssql-instance-xelsystem.png │ └── show-detail.png ├── package.json └── sql │ ├── mssql-instance-vlfs-detail.sql │ ├── mssql-instance-vlfs.sql │ ├── mssql-instance-waits-detail.sql │ ├── mssql-instance-waits.sql │ ├── mssql-instance-xelio.sql │ ├── mssql-instance-xelmemory.sql │ └── mssql-instance-xelsystem.sql └── vsc-extension-quickstart.md /.gitignore: -------------------------------------------------------------------------------- 1 | node_modules 2 | *.vsix 3 | -------------------------------------------------------------------------------- /.vscode/launch.json: -------------------------------------------------------------------------------- 1 | // A launch configuration that launches the extension inside a new window 2 | // Use IntelliSense to learn about possible attributes. 3 | // Hover to view descriptions of existing attributes. 4 | // For more information, visit: https://go.microsoft.com/fwlink/?linkid=830387 5 | 6 | // To debug the extension: 7 | // 1. please install the "SQL Operations Studio Debug" extension into VSCode 8 | // 2. Ensure sqlops is added to your path: 9 | // - open SQL Operations Studio 10 | // - run the command "Install 'sqlops' command in PATH" 11 | { 12 | "version": "0.2.0", 13 | "configurations": [ 14 | { 15 | "name": "Extension", 16 | "type": "sqlopsExtensionHost", 17 | "request": "launch", 18 | "runtimeExecutable": "sqlops", 19 | "args": [ 20 | "--extensionDevelopmentPath=${workspaceFolder}\\src" 21 | ] 22 | } 23 | ] 24 | } -------------------------------------------------------------------------------- /.vscodeignore: -------------------------------------------------------------------------------- 1 | .vscode/** 2 | .vscode-test/** 3 | .gitignore 4 | vsc-extension-quickstart.md 5 | -------------------------------------------------------------------------------- /Build.ps1: -------------------------------------------------------------------------------- 1 | [CmdLetBinding()] 2 | Param ( 3 | [Parameter()] 4 | [string]$BuildDir 5 | ) 6 | 7 | [string]$scriptPath = $PSScriptRoot; 8 | 9 | # set the location history 10 | Push-Location; 11 | 12 | # make sure the releases folder exists 13 | if ($null -eq $BuildDir -or $BuildDir.Length -eq 0) 14 | { 15 | $BuildDir = Join-Path -Path $scriptPath -ChildPath 'build'; 16 | } 17 | if (-not(Test-Path -Path $BuildDir)) 18 | { 19 | New-Item -Path $BuildDir -ItemType Directory -Force | Out-Null; 20 | } 21 | 22 | # Get the packages to build in this repo 23 | $packageFiles = Get-ChildItem -Path $scriptPath -Recurse -Filter 'package.json' 24 | 25 | if ($packageFiles.Count -eq 0) 26 | { 27 | Write-Error -Message 'No Extensions found to package' 28 | Exit 29 | } 30 | 31 | # set our working location to the build folder 32 | Set-Location -Path $BuildDir; 33 | 34 | # process each package found 35 | foreach ($package in $packageFiles) 36 | { 37 | Write-Verbose -Message "Processing $($package.fullname)"; 38 | 39 | # try 40 | # { 41 | Set-Location -Path $package.DirectoryName; 42 | vsce.cmd package; 43 | Get-ChildItem -Path $package.DirectoryName -Filter '*.vsix' | Move-Item -Destination $BuildDir -Force; 44 | # } 45 | # catch 46 | # { 47 | 48 | # } 49 | 50 | Write-Verbose -Message ('Finished processing package {0}' -f $packageJson.name); 51 | 52 | } 53 | 54 | # return to the previous user location 55 | Pop-Location; 56 | 57 | Write-Verbose -Message 'Extension Packaging Complete'; -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | # Change Log 2 | 3 | All notable changes to the "mssql-instance-insights" extension will be documented in this file. Check [Keep a Changelog](http://keepachangelog.com/) for recommendations on how to structure this file. 4 | 5 | ## [Unreleased] 6 | 7 | - None 8 | 9 | ## [0.2.0] 10 | 11 | ### Added 12 | 13 | - VLFs widget 14 | 15 | ### Changed 16 | 17 | - Minor documentation fixes for marketplace support 18 | 19 | ## [0.2.0-beta1] 20 | 21 | ### Added 22 | 23 | - Migration of code from [https://github.com/Matticusau/sqlops-widgets](https://github.com/Matticusau/sqlops-widgets) -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2018 Matt 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 | # MSSQL Instance Insights - SQLOps Extension 2 | 3 | This collection of widgets are designed to provide insights into MSSQL Instance to further extend the built-in default widgets. 4 | 5 | Where possible all of these widgets will include more detail when you click *_Show Details_* from the widget menu. 6 | 7 | See the [package README](./src/README.md) for more information. 8 | 9 | ## Installation 10 | 11 | The current release will be available through the Extensions Marketplace in Sql Ops Studio. 12 | 13 | Current and Pre-releases will be available from the [Releases](https://github.com/Matticusau/sqlops-mssql-instance-insights/releases) tab of the projects repository. Simply download the VSIX of the release you want, and use the ***Install Extension from VSIX Package*** option in Sql Ops Studio. 14 | 15 | ## Change Log 16 | 17 | See the [Change Log](./CHANGELOG.md) for the full changes. 18 | 19 | ## License 20 | 21 | This project is released under the [MIT License](./LICENSE) 22 | 23 | ## Contributors 24 | 25 | * Matticusau [GitHub](https://github.com/Matticusau) | [twitter](https://twitter.com/matticusau) 26 | -------------------------------------------------------------------------------- /extension-definition.json: -------------------------------------------------------------------------------- 1 | { 2 | "extensionId": "", 3 | "extensionName": "mssql-instance-insights", 4 | "displayName": "MSSQL Instance Insights", 5 | "shortDescription": "Sql Server Instance insights", 6 | "publisher": { 7 | "displayName":"matticusau", 8 | "publisherId": "matticusau", 9 | "publisherName":"matticusau" 10 | }, 11 | "versions": [ 12 | { 13 | "version": "0.2.1", 14 | "lastUpdated": "04/21/2018", 15 | "assetUri": "", 16 | "fallbackAssetUri": "fallbackAssetUri", 17 | "files": [ 18 | { 19 | "assetType": "Microsoft.SQLOps.DownloadPage", 20 | "source": "https://github.com/Matticusau/sqlops-mssql-instance-insights/releases/tag/0.2.1" 21 | }, 22 | { 23 | "assetType": "Microsoft.VisualStudio.Services.Links.Source", 24 | "source": "https://github.com/Matticusau/sqlops-mssql-instance-insights" 25 | }, 26 | { 27 | "assetType": "Microsoft.VisualStudio.Services.Icons.Default", 28 | "source": "https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/master/src/images/icon.png" 29 | }, 30 | { 31 | "assetType": "Microsoft.VisualStudio.Services.Content.Details", 32 | "source": "https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/master/src/README.md" 33 | }, 34 | { 35 | "assetType": "Microsoft.VisualStudio.Code.Manifest", 36 | "source": "https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/master/src/package.json" 37 | }, 38 | { 39 | "assetType": "Microsoft.VisualStudio.Services.Content.License", 40 | "source": "https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/master/LICENSE" 41 | } 42 | ], 43 | "properties": [ 44 | { "key": "Microsoft.VisualStudio.Code.ExtensionDependencies", "value":""}, 45 | { "key": "Microsoft.VisualStudio.Code.Engine", "value":"*"} 46 | ] 47 | } 48 | ], 49 | "statistics": [], 50 | "flags": "preview" 51 | } -------------------------------------------------------------------------------- /src/README.md: -------------------------------------------------------------------------------- 1 | # MSSQL-Instance-Insights widget 2 | 3 | This collection of widgets are designed to provide insights into MSSQL Instance to further extend the built-in default widgets. 4 | 5 | Where possible all of these widgets will include more detail when you click *_Show Details_* from the widget menu. 6 | 7 | Show Details 8 | 9 | ## Installation 10 | 11 | The current release will be available through the Extensions Marketplace in Sql Ops Studio. 12 | 13 | Current and Pre-releases will be available from the [Releases](https://github.com/Matticusau/sqlops-mssql-instance-insights/releases) tab of the projects repository. Simply download the VSIX of the release you want, and use the ***Install Extension from VSIX Package*** option in Sql Ops Studio. 14 | 15 | ## Supported SQL Server Versions 16 | 17 | These widgets have been tested against the following SQL Server versions: 18 | 19 | * SQL Server 2016 20 | * SQL Server 2017 (Windows & linux) 21 | 22 | If you find any issues using these widgets on these supported SQL Server versions, or any other versions please create an issue as we would like to make these available for as many releases as possible. 23 | 24 | ***We are looking for testers to confirm other environments.*** So if you find they do work on other releases let me know, and credit will be given. 25 | 26 | ## Dashboard Tab 27 | 28 | When the extension is loaded it will add a Dashboard tab. You can edit your workspace settings in the *dashboard.server.tabs* section to include this on your specific projects. 29 | 30 | mssql-instance-insights-tab.png 31 | 32 | ## mssql-instance-waits 33 | 34 | This Server Dashboard widget includes information on the top 10 waits for the SQL Instance. Information will be shown in the form of a bar chart. 35 | 36 | mssql-instance-waits.png 37 | 38 | You can access more information about the waits in the detailed fly-out displayed when you select "..." on the widget. 39 | 40 | mssql-instance-waits-details.png 41 | 42 | Credit for the query this widget is based on goes to [Paul Randal - Tell me where it hurts](https://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/) 43 | 44 | To enable this widget add the following json to either your user or workspace settings in the *dashboard.server.widgets* section. 45 | 46 | ```json 47 | { 48 | "widget": { 49 | "mssql-instance-waits.insight": { 50 | "cacheId": "1d7cba8b-c87a-4bcc-ae54-2f40a5503a90" 51 | } 52 | } 53 | } 54 | ``` 55 | 56 | ## mssql-instance-vlfs 57 | 58 | This Server Dashboard widget includes information on the number of VLfs per database in the SQL Instance. Information will be shown in the form of a bar chart. 59 | 60 | This insight is ***not*** supported on Azure SQL Db. 61 | 62 | mssql-instance-vlfs.png 63 | 64 | You can access more information about the vlfs in the detailed fly-out displayed when you select "..." on the widget. 65 | 66 | mssql-instance-vlfs-details.png 67 | 68 | To enable this widget add the following json to either your user or workspace settings in the *dashboard.server.widgets* section. 69 | 70 | ```json 71 | { 72 | "widget": { 73 | "mssql-instance-vlfs.insight": { 74 | "cacheId": "1d7cba8b-c87a-4bcc-ae54-2f40a5503a90" 75 | } 76 | } 77 | } 78 | ``` 79 | 80 | ## mssql-instance-xelsystem 81 | 82 | This Server Dashboard widget includes information on the general system performance captured by the Extended Events System Health Session for the SQL Instance. Information will be shown in the form of a line chart. If the System Health Session is stopped or the instance has been restarted will affect the amount of data available for this widget. 83 | 84 | mssql-instance-xelsystem.png 85 | 86 | You can access more information in the detailed fly-out displayed when you select "..." on the widget. 87 | 88 | mssql-instance-xelsystem-details.png 89 | 90 | Credit for the query this widget is based on goes to [troubleshootingsql.com](https://troubleshootingsql.com/2013/08/02/powerview-and-system-health-session-system/) 91 | 92 | > This widget is not currently supported on *_Azure SQL DB_* due to lack of support for Extended Events. 93 | 94 | To enable this widget add the following json to either your user or workspace settings in the *dashboard.server.widgets* section. 95 | 96 | ```json 97 | { 98 | "widget": { 99 | "mssql-instance-xelsystem.insight": { 100 | "cacheId": "1d7cba8b-c87a-4bcc-ae54-2f40a5503a90" 101 | } 102 | } 103 | } 104 | ``` 105 | 106 | ## mssql-instance-xelio 107 | 108 | This Server Dashboard widget includes information on the IO performance captured by the Extended Events System Health Session for the SQL Instance. Information will be shown in the form of a line chart. If the System Health Session is stopped or the instance has been restarted will affect the amount of data available for this widget. 109 | 110 | mssql-instance-xelio2.png 111 | 112 | You can access more information in the detailed fly-out displayed when you select "..." on the widget. 113 | 114 | mssql-instance-xelio-details.png 115 | 116 | Credit for the query this widget is based on goes to [troubleshootingsql.com](https://troubleshootingsql.com/2013/07/25/powerview-and-system-health-session-io-health/) 117 | 118 | > This widget is not currently supported on *_Azure SQL DB_* due to lack of support for Extended Events. 119 | 120 | To enable this widget add the following json to either your user or workspace settings in the *dashboard.server.widgets* section. 121 | 122 | ```json 123 | { 124 | "widget": { 125 | "mssql-instance-xelio.insight": { 126 | "cacheId": "1d7cba8b-c87a-4bcc-ae54-2f40a5503a90" 127 | } 128 | } 129 | } 130 | ``` 131 | 132 | ## mssql-instance-xelmemory 133 | 134 | This Server Dashboard widget includes information on the Memory performance captured by the Extended Events System Health Session for the SQL Instance. Information will be shown in the form of a line chart. If the System Health Session is stopped or the instance has been restarted will affect the amount of data available for this widget. 135 | 136 | mssql-instance-xelmemory.png 137 | 138 | You can access more information in the detailed fly-out displayed when you select "..." on the widget. 139 | 140 | mssql-instance-xelmemory-details.png 141 | 142 | Credit for the query this widget is based on goes to [troubleshootingsql.com](https://troubleshootingsql.com/2013/07/19/powerview-and-system-health-sessionsql-memory-health/) 143 | 144 | > This widget is not currently supported on *_Azure SQL DB_* due to lack of support for Extended Events. 145 | 146 | To enable this widget add the following json to either your user or workspace settings in the *dashboard.server.widgets* section. 147 | 148 | ```json 149 | { 150 | "widget": { 151 | "mssql-instance-xelmemory.insight": { 152 | "cacheId": "1d7cba8b-c87a-4bcc-ae54-2f40a5503a90" 153 | } 154 | } 155 | } 156 | ``` -------------------------------------------------------------------------------- /src/images/icon.pdn: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/icon.pdn -------------------------------------------------------------------------------- /src/images/icon.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/icon.png -------------------------------------------------------------------------------- /src/images/mssql-instance-insights-tab.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-insights-tab.png -------------------------------------------------------------------------------- /src/images/mssql-instance-vlfs-detail.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-vlfs-detail.png -------------------------------------------------------------------------------- /src/images/mssql-instance-vlfs.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-vlfs.png -------------------------------------------------------------------------------- /src/images/mssql-instance-waits-details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-waits-details.png -------------------------------------------------------------------------------- /src/images/mssql-instance-waits.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-waits.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelio-details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelio-details.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelio.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelio.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelio2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelio2.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelmemory-details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelmemory-details.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelmemory.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelmemory.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelsystem-details.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelsystem-details.png -------------------------------------------------------------------------------- /src/images/mssql-instance-xelsystem.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/mssql-instance-xelsystem.png -------------------------------------------------------------------------------- /src/images/show-detail.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Matticusau/sqlops-mssql-instance-insights/454324a25f38bbcf1be81884be5fd0029e5ac01f/src/images/show-detail.png -------------------------------------------------------------------------------- /src/package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "mssql-instance-insights", 3 | "displayName": "MSSQL Instance Insights", 4 | "description": "Sql Server Instance insights", 5 | "version": "0.2.1", 6 | "publisher": "matticusau", 7 | "license": "MIT", 8 | "icon": "images/icon.png", 9 | "author": { 10 | "email": "matt.lavery@outlook.com", 11 | "name": "Matt Lavery", 12 | "url": "http://www.matticus.net" 13 | }, 14 | "repository": { 15 | "type": "git", 16 | "url": "https://github.com/matticusau/sqlops-mssql-instance-insights" 17 | }, 18 | "bugs": { 19 | "url": "https://github.com/matticusau/sqlops-mssql-instance-insights/issues" 20 | }, 21 | "engines": { 22 | "vscode": "^1.22.0", 23 | "sqlops": "*" 24 | }, 25 | "categories": [ 26 | "Other" 27 | ], 28 | "homepage": "https://github.com/matticusau/sqlops-mssql-instance-insights", 29 | "contributes": { 30 | "dashboard.insights": [ 31 | { 32 | "id": "mssql-instance-waits.insight", 33 | "contrib": { 34 | "queryFile": "./sql/mssql-instance-waits.sql", 35 | "type": { 36 | "horizontalBar": { 37 | "dataDirection": "vertical", 38 | "dataType": "number", 39 | "legendPosition": "none", 40 | "labelFirstColumn": false, 41 | "columnsAsLabels": false 42 | } 43 | }, 44 | "details": { 45 | "queryFile": "./sql/mssql-instance-waits-detail.sql", 46 | "label": { 47 | "icon": "database", 48 | "column": "WaitType", 49 | "state": [ 50 | { 51 | "condition": { 52 | "if": "greaterthan", 53 | "greaterthan": "80" 54 | }, 55 | "color": "red" 56 | }, 57 | { 58 | "condition": { 59 | "if": "greaterthan", 60 | "greaterthan": "40" 61 | }, 62 | "color": "orange" 63 | }, 64 | { 65 | "condition": { 66 | "if": "lessthan", 67 | "lessthan": "41" 68 | }, 69 | "color": "green" 70 | } 71 | ] 72 | }, 73 | "value": "Percentage", 74 | "actions": null 75 | } 76 | } 77 | }, 78 | { 79 | "id": "mssql-instance-xelsystem.insight", 80 | "contrib": { 81 | "queryFile": "./sql/mssql-instance-xelsystem.sql", 82 | "type": { 83 | "line": { 84 | "dataDirection": "vertical", 85 | "dataType": "number", 86 | "legendPosition": "bottom", 87 | "labelFirstColumn": false, 88 | "columnsAsLabels": true 89 | } 90 | }, 91 | "details": { 92 | "queryFile": "./sql/mssql-instance-xelsystem.sql", 93 | "label": { 94 | "icon": "database", 95 | "column": "Event Time", 96 | "state": [ 97 | { 98 | "condition": { 99 | "if": "greaterthan", 100 | "greaterthan": "0" 101 | }, 102 | "color": "red" 103 | }, 104 | { 105 | "condition": { 106 | "if": "equals", 107 | "equals": "0" 108 | }, 109 | "color": "green" 110 | } 111 | ] 112 | }, 113 | "value": "Non Yields Reported", 114 | "actions": null 115 | } 116 | } 117 | }, 118 | { 119 | "id": "mssql-instance-xelio.insight", 120 | "contrib": { 121 | "queryFile": "./sql/mssql-instance-xelio.sql", 122 | "type": { 123 | "line": { 124 | "dataDirection": "vertical", 125 | "dataType": "number", 126 | "legendPosition": "bottom", 127 | "labelFirstColumn": false, 128 | "columnsAsLabels": true 129 | } 130 | }, 131 | "details": { 132 | "queryFile": "./sql/mssql-instance-xelio.sql", 133 | "label": { 134 | "icon": "database", 135 | "column": "Event Time", 136 | "state": [ 137 | { 138 | "condition": { 139 | "if": "greaterthan", 140 | "greaterthan": "0" 141 | }, 142 | "color": "red" 143 | }, 144 | { 145 | "condition": { 146 | "if": "equals", 147 | "equals": "0" 148 | }, 149 | "color": "green" 150 | } 151 | ] 152 | }, 153 | "value": "Total Long IOs", 154 | "actions": null 155 | } 156 | } 157 | }, 158 | { 159 | "id": "mssql-instance-xelmemory.insight", 160 | "contrib": { 161 | "queryFile": "./sql/mssql-instance-xelmemory.sql", 162 | "type": { 163 | "line": { 164 | "dataDirection": "vertical", 165 | "dataType": "number", 166 | "legendPosition": "bottom", 167 | "labelFirstColumn": false, 168 | "columnsAsLabels": true 169 | } 170 | }, 171 | "details": { 172 | "queryFile": "./sql/mssql-instance-xelmemory.sql", 173 | "label": { 174 | "icon": "database", 175 | "column": "Event Time", 176 | "state": [ 177 | { 178 | "condition": { 179 | "if": "lessthan", 180 | "lessthan": "4" 181 | }, 182 | "color": "orange" 183 | }, 184 | { 185 | "condition": { 186 | "if": "greaterthan", 187 | "greaterthan": "4" 188 | }, 189 | "color": "green" 190 | } 191 | ] 192 | }, 193 | "value": "Available Physical Memory (GB)", 194 | "actions": null 195 | } 196 | } 197 | }, 198 | { 199 | "id": "mssql-instance-vlfs.insight", 200 | "contrib": { 201 | "queryFile": "./sql/mssql-instance-vlfs.sql", 202 | "type": { 203 | "bar": { 204 | "dataDirection": "vertical", 205 | "dataType": "number", 206 | "legendPosition": "none", 207 | "labelFirstColumn": false, 208 | "columnsAsLabels": false 209 | } 210 | }, 211 | "details": { 212 | "queryFile": "./sql/mssql-instance-vlfs-detail.sql", 213 | "label": { 214 | "icon": "database", 215 | "column": "DBName", 216 | "state": [ 217 | { 218 | "condition": { 219 | "if": "greaterthan", 220 | "greaterthan": "10000" 221 | }, 222 | "color": "red" 223 | }, 224 | { 225 | "condition": { 226 | "if": "greaterthan", 227 | "greaterthan": "1000" 228 | }, 229 | "color": "orange" 230 | }, 231 | { 232 | "condition": { 233 | "if": "lessthan", 234 | "lessthan": "999" 235 | }, 236 | "color": "green" 237 | } 238 | ] 239 | }, 240 | "value": "TotalVLFs", 241 | "actions": null 242 | } 243 | } 244 | } 245 | ] 246 | , 247 | "dashboard.tabs": [ 248 | { 249 | "id": "mssql-instance-insights.tab", 250 | "title": "MSSQL Instance Insights", 251 | "description": "SQL Server Instance insights and widgets", 252 | "container": { 253 | "widgets-container": [ 254 | { 255 | "name": "Top 10 Waits", 256 | "gridItemConfig": { 257 | "sizex": 2, 258 | "sizey": 1 259 | }, 260 | "widget": { 261 | "mssql-instance-waits.insight": {} 262 | } 263 | }, 264 | { 265 | "name": "Virtual Log Files (VLFs)", 266 | "gridItemConfig": { 267 | "sizex": 2, 268 | "sizey": 1 269 | }, 270 | "widget": { 271 | "mssql-instance-vlfs.insight": {} 272 | } 273 | }, 274 | { 275 | "name": "XEL System Stats", 276 | "gridItemConfig": { 277 | "sizex": 2, 278 | "sizey": 2 279 | }, 280 | "widget": { 281 | "mssql-instance-xelsystem.insight": {} 282 | } 283 | }, 284 | { 285 | "name": "XEL IO Stats", 286 | "gridItemConfig": { 287 | "sizex": 2, 288 | "sizey": 2 289 | }, 290 | "widget": { 291 | "mssql-instance-xelio.insight": {} 292 | } 293 | }, 294 | { 295 | "name": "XEL Memory Stats", 296 | "gridItemConfig": { 297 | "sizex": 2, 298 | "sizey": 2 299 | }, 300 | "widget": { 301 | "mssql-instance-xelmemory.insight": {} 302 | } 303 | } 304 | ] 305 | } 306 | } 307 | ] 308 | } 309 | } -------------------------------------------------------------------------------- /src/sql/mssql-instance-vlfs-detail.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Author: Matticusau 3 | -- Purpose: Provides insights into all VLFs 4 | -- License: https://github.com/Matticusau/sqlops-mssql-instance-insights/blob/master/LICENSE 5 | -- Original script: https://github.com/Microsoft/DataInsightsAsia/blob/Dev/Scripts/VLFs/VLFsReport.sql 6 | -- 7 | 8 | -- check if we are running on Azure PaaS 9 | DECLARE @isAzurePaaS BIT; 10 | IF ((SELECT @@Version) LIKE 'Microsoft SQL Azure%') 11 | SET @isAzurePaaS = 1; 12 | ELSE 13 | SET @isAzurePaaS = 0; 14 | 15 | 16 | IF (@isAzurePaaS = 0) 17 | BEGIN 18 | 19 | SET NOCOUNT ON; 20 | 21 | -- declare variables required 22 | DECLARE @majorVer SMALLINT, @minorVer SMALLINT, @build SMALLINT 23 | DECLARE @DatabaseId INT; 24 | DECLARE @TSQL varchar(MAX); 25 | DECLARE cur_DBs CURSOR FOR 26 | SELECT database_id 27 | FROM sys.databases 28 | WHERE name NOT IN (N'master',N'model',N'msdb',N'tempdb'); 29 | OPEN cur_DBs; 30 | FETCH NEXT FROM cur_DBs INTO @DatabaseId 31 | 32 | -- Get the version 33 | SELECT @majorVer = (@@microsoftversion / 0x1000000) & 0xff, @minorVer = (@@microsoftversion / 0x10000) & 0xff, @build = @@microsoftversion & 0xffff 34 | 35 | -- These table variables will be used to store the data 36 | DECLARE @tblAllDBs Table (DBName sysname 37 | , FileId INT 38 | , FileSize BIGINT 39 | , StartOffset BIGINT 40 | , FSeqNo INT 41 | , Status TinyInt 42 | , Parity INT 43 | , CreateLSN NUMERIC(25,0) 44 | ) 45 | IF ( @majorVer >= 11 ) 46 | BEGIN 47 | DECLARE @tblVLFs2012 Table (RecoveryUnitId BIGINT 48 | , FileId INT 49 | , FileSize BIGINT 50 | , StartOffset BIGINT 51 | , FSeqNo INT 52 | , Status TinyInt 53 | , Parity INT 54 | , CreateLSN NUMERIC(25,0) 55 | ); 56 | END 57 | ELSE 58 | BEGIN 59 | DECLARE @tblVLFs Table ( 60 | FileId INT 61 | , FileSize BIGINT 62 | , StartOffset BIGINT 63 | , FSeqNo INT 64 | , Status TinyInt 65 | , Parity INT 66 | , CreateLSN NUMERIC(25,0) 67 | ); 68 | END 69 | 70 | --loop through each database and get the info 71 | WHILE @@FETCH_STATUS = 0 72 | BEGIN 73 | 74 | PRINT 'DB: ' + CONVERT(varchar(200), DB_NAME(@DatabaseId)); 75 | SET @TSQL = 'dbcc loginfo('+CONVERT(varchar(12), @DatabaseId)+');'; 76 | 77 | IF ( @majorVer >= 11 ) 78 | BEGIN 79 | DELETE FROM @tblVLFs2012; 80 | INSERT INTO @tblVLFs2012 81 | EXEC(@TSQL); 82 | INSERT INTO @tblAllDBs 83 | SELECT DB_NAME(@DatabaseId) 84 | , FileId 85 | , FileSize 86 | , StartOffset 87 | , FSeqNo 88 | , Status 89 | , Parity 90 | , CreateLSN 91 | FROM @tblVLFs2012; 92 | END 93 | ELSE 94 | BEGIN 95 | DELETE FROM @tblVLFs; 96 | INSERT INTO @tblVLFs 97 | EXEC(@TSQL); 98 | INSERT INTO @tblAllDBs 99 | SELECT DB_NAME(@DatabaseId) 100 | , FileId 101 | , FileSize 102 | , StartOffset 103 | , FSeqNo 104 | , Status 105 | , Parity 106 | , CreateLSN 107 | FROM @tblVLFs; 108 | END 109 | 110 | FETCH NEXT FROM cur_DBs INTO @DatabaseId 111 | END 112 | CLOSE cur_DBs; 113 | DEALLOCATE cur_DBs; 114 | 115 | --just for formating if output to Text 116 | PRINT ''; 117 | PRINT ''; 118 | PRINT ''; 119 | 120 | --Return the data based on what we have found 121 | SELECT a.DBName 122 | , COUNT(a.FileId) AS [TotalVLFs] 123 | , MAX(b.[ActiveVLFs]) AS [ActiveVLFs] 124 | , (SUM(a.FileSize) / COUNT(a.FileId) / 1024) AS [AvgFileSizeKb] 125 | FROM @tblAllDBs a 126 | INNER JOIN ( 127 | SELECT DBName 128 | , COUNT(FileId) [ActiveVLFs] 129 | FROM @tblAllDBs 130 | WHERE Status = 2 131 | GROUP BY DBName 132 | ) b 133 | ON b.DBName = a.DBName 134 | GROUP BY a.DBName 135 | ORDER BY TotalVLFs DESC; 136 | 137 | 138 | SET NOCOUNT OFF; 139 | 140 | END 141 | ELSE 142 | BEGIN 143 | -- not supported on Azure so return an empty recordset 144 | SELECT 'NotSupportedOnAzure' AS [DBName] 145 | , 0 AS [TotalVLFs] 146 | , 0 AS [ActiveVLFs] 147 | , 0 AS [AvgFileSizeKb] 148 | END -------------------------------------------------------------------------------- /src/sql/mssql-instance-vlfs.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Author: Matticusau 3 | -- Purpose: Provides insights into all VLFs 4 | -- License: https://github.com/Matticusau/sqlops-mssql-instance-insights/blob/master/LICENSE 5 | -- Original script: https://github.com/Microsoft/DataInsightsAsia/blob/Dev/Scripts/VLFs/VLFsReport.sql 6 | -- 7 | 8 | -- check if we are running on Azure PaaS 9 | DECLARE @isAzurePaaS BIT; 10 | IF ((SELECT @@Version) LIKE 'Microsoft SQL Azure%') 11 | SET @isAzurePaaS = 1; 12 | ELSE 13 | SET @isAzurePaaS = 0; 14 | 15 | 16 | IF (@isAzurePaaS = 0) 17 | BEGIN 18 | 19 | SET NOCOUNT ON; 20 | 21 | -- declare variables required 22 | DECLARE @majorVer SMALLINT, @minorVer SMALLINT, @build SMALLINT 23 | DECLARE @DatabaseId INT; 24 | DECLARE @TSQL varchar(MAX); 25 | DECLARE cur_DBs CURSOR FOR 26 | SELECT database_id 27 | FROM sys.databases 28 | WHERE name NOT IN (N'master',N'model',N'msdb',N'tempdb'); 29 | OPEN cur_DBs; 30 | FETCH NEXT FROM cur_DBs INTO @DatabaseId 31 | 32 | -- Get the version 33 | SELECT @majorVer = (@@microsoftversion / 0x1000000) & 0xff, @minorVer = (@@microsoftversion / 0x10000) & 0xff, @build = @@microsoftversion & 0xffff 34 | 35 | -- These table variables will be used to store the data 36 | DECLARE @tblAllDBs Table (DBName sysname 37 | , FileId INT 38 | , FileSize BIGINT 39 | , StartOffset BIGINT 40 | , FSeqNo INT 41 | , Status TinyInt 42 | , Parity INT 43 | , CreateLSN NUMERIC(25,0) 44 | ) 45 | IF ( @majorVer >= 11 ) 46 | BEGIN 47 | DECLARE @tblVLFs2012 Table (RecoveryUnitId BIGINT 48 | , FileId INT 49 | , FileSize BIGINT 50 | , StartOffset BIGINT 51 | , FSeqNo INT 52 | , Status TinyInt 53 | , Parity INT 54 | , CreateLSN NUMERIC(25,0) 55 | ); 56 | END 57 | ELSE 58 | BEGIN 59 | DECLARE @tblVLFs Table ( 60 | FileId INT 61 | , FileSize BIGINT 62 | , StartOffset BIGINT 63 | , FSeqNo INT 64 | , Status TinyInt 65 | , Parity INT 66 | , CreateLSN NUMERIC(25,0) 67 | ); 68 | END 69 | 70 | --loop through each database and get the info 71 | WHILE @@FETCH_STATUS = 0 72 | BEGIN 73 | 74 | PRINT 'DB: ' + CONVERT(varchar(200), DB_NAME(@DatabaseId)); 75 | SET @TSQL = 'dbcc loginfo('+CONVERT(varchar(12), @DatabaseId)+');'; 76 | 77 | IF ( @majorVer >= 11 ) 78 | BEGIN 79 | DELETE FROM @tblVLFs2012; 80 | INSERT INTO @tblVLFs2012 81 | EXEC(@TSQL); 82 | INSERT INTO @tblAllDBs 83 | SELECT DB_NAME(@DatabaseId) 84 | , FileId 85 | , FileSize 86 | , StartOffset 87 | , FSeqNo 88 | , Status 89 | , Parity 90 | , CreateLSN 91 | FROM @tblVLFs2012; 92 | END 93 | ELSE 94 | BEGIN 95 | DELETE FROM @tblVLFs; 96 | INSERT INTO @tblVLFs 97 | EXEC(@TSQL); 98 | INSERT INTO @tblAllDBs 99 | SELECT DB_NAME(@DatabaseId) 100 | , FileId 101 | , FileSize 102 | , StartOffset 103 | , FSeqNo 104 | , Status 105 | , Parity 106 | , CreateLSN 107 | FROM @tblVLFs; 108 | END 109 | 110 | FETCH NEXT FROM cur_DBs INTO @DatabaseId 111 | END 112 | CLOSE cur_DBs; 113 | DEALLOCATE cur_DBs; 114 | 115 | --just for formating if output to Text 116 | PRINT ''; 117 | PRINT ''; 118 | PRINT ''; 119 | 120 | --Return the data based on what we have found 121 | SELECT a.DBName 122 | , COUNT(a.FileId) AS [TotalVLFs] 123 | -- , MAX(b.[ActiveVLFs]) AS [ActiveVLFs] 124 | -- , (SUM(a.FileSize) / COUNT(a.FileId) / 1024) AS [AvgFileSizeKb] 125 | FROM @tblAllDBs a 126 | INNER JOIN ( 127 | SELECT DBName 128 | , COUNT(FileId) [ActiveVLFs] 129 | FROM @tblAllDBs 130 | WHERE Status = 2 131 | GROUP BY DBName 132 | ) b 133 | ON b.DBName = a.DBName 134 | GROUP BY a.DBName 135 | ORDER BY TotalVLFs DESC; 136 | 137 | 138 | SET NOCOUNT OFF; 139 | 140 | END 141 | ELSE 142 | BEGIN 143 | -- not supported on Azure so return an empty recordset 144 | SELECT 'NotSupportedOnAzure' AS [DBName] 145 | , 0 AS [TotalVLFs] 146 | -- , 0 AS [ActiveVLFs] 147 | -- , 0 AS [AvgFileSizeKb] 148 | END -------------------------------------------------------------------------------- /src/sql/mssql-instance-waits-detail.sql: -------------------------------------------------------------------------------- 1 | -- Reference: https://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/ 2 | 3 | WITH [Waits] AS 4 | (SELECT 5 | [wait_type], 6 | [wait_time_ms] / 1000.0 AS [WaitS], 7 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS], 8 | [signal_wait_time_ms] / 1000.0 AS [SignalS], 9 | [waiting_tasks_count] AS [WaitCount], 10 | 100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage], 11 | ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum] 12 | FROM sys.dm_os_wait_stats 13 | WHERE [wait_type] NOT IN ( 14 | N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', 15 | N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', 16 | N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', 17 | N'CHKPT', N'CLR_AUTO_EVENT', 18 | N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', 19 | 20 | -- Maybe comment these four out if you have mirroring issues 21 | N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', 22 | N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', 23 | 24 | N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', 25 | N'EXECSYNC', N'FSAGENT', 26 | N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', 27 | 28 | -- Maybe comment these six out if you have AG issues 29 | N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 30 | N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', 31 | N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', 32 | 33 | N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', 34 | N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT', 35 | N'ONDEMAND_TASK_QUEUE', 36 | N'PREEMPTIVE_XE_GETTARGETSTATE', 37 | N'PWAIT_ALL_COMPONENTS_INITIALIZED', 38 | N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', 39 | N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE', 40 | N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', 41 | N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK', 42 | N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', 43 | N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', 44 | N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', 45 | N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', 46 | N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', 47 | N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', 48 | N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', 49 | N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', 50 | N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 51 | N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', 52 | N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', 53 | N'WAIT_XTP_RECOVERY', 54 | N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', 55 | N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN', 56 | N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT') 57 | AND [waiting_tasks_count] > 0 58 | ) 59 | SELECT 60 | MAX ([W1].[wait_type]) AS [WaitType], 61 | CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S], 62 | CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S], 63 | CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S], 64 | MAX ([W1].[WaitCount]) AS [WaitCount], 65 | CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage], 66 | CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S], 67 | CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S], 68 | CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S] 69 | --, 70 | --CAST ('https://www.sqlskills.com/help/waits/' + MAX ([W1].[wait_type]) as XML) AS [Help/Info URL] 71 | FROM [Waits] AS [W1] 72 | INNER JOIN [Waits] AS [W2] 73 | ON [W2].[RowNum] <= [W1].[RowNum] 74 | GROUP BY [W1].[RowNum] 75 | HAVING SUM ([W2].[Percentage]) - MAX( [W1].[Percentage] ) < 95; -- percentage threshold 76 | GO -------------------------------------------------------------------------------- /src/sql/mssql-instance-waits.sql: -------------------------------------------------------------------------------- 1 | -- Reference: https://www.sqlskills.com/blogs/paul/wait-statistics-or-please-tell-me-where-it-hurts/ 2 | 3 | WITH [Waits] AS 4 | (SELECT 5 | [wait_type], 6 | [wait_time_ms] / 1000.0 AS [WaitS], 7 | ([wait_time_ms] - [signal_wait_time_ms]) / 1000.0 AS [ResourceS], 8 | [signal_wait_time_ms] / 1000.0 AS [SignalS], 9 | [waiting_tasks_count] AS [WaitCount], 10 | 100.0 * [wait_time_ms] / SUM ([wait_time_ms]) OVER() AS [Percentage], 11 | ROW_NUMBER() OVER(ORDER BY [wait_time_ms] DESC) AS [RowNum] 12 | FROM sys.dm_os_wait_stats 13 | WHERE [wait_type] NOT IN ( 14 | N'BROKER_EVENTHANDLER', N'BROKER_RECEIVE_WAITFOR', 15 | N'BROKER_TASK_STOP', N'BROKER_TO_FLUSH', 16 | N'BROKER_TRANSMITTER', N'CHECKPOINT_QUEUE', 17 | N'CHKPT', N'CLR_AUTO_EVENT', 18 | N'CLR_MANUAL_EVENT', N'CLR_SEMAPHORE', 19 | 20 | -- Maybe comment these four out if you have mirroring issues 21 | N'DBMIRROR_DBM_EVENT', N'DBMIRROR_EVENTS_QUEUE', 22 | N'DBMIRROR_WORKER_QUEUE', N'DBMIRRORING_CMD', 23 | 24 | N'DIRTY_PAGE_POLL', N'DISPATCHER_QUEUE_SEMAPHORE', 25 | N'EXECSYNC', N'FSAGENT', 26 | N'FT_IFTS_SCHEDULER_IDLE_WAIT', N'FT_IFTSHC_MUTEX', 27 | 28 | -- Maybe comment these six out if you have AG issues 29 | N'HADR_CLUSAPI_CALL', N'HADR_FILESTREAM_IOMGR_IOCOMPLETION', 30 | N'HADR_LOGCAPTURE_WAIT', N'HADR_NOTIFICATION_DEQUEUE', 31 | N'HADR_TIMER_TASK', N'HADR_WORK_QUEUE', 32 | 33 | N'KSOURCE_WAKEUP', N'LAZYWRITER_SLEEP', 34 | N'LOGMGR_QUEUE', N'MEMORY_ALLOCATION_EXT', 35 | N'ONDEMAND_TASK_QUEUE', 36 | N'PREEMPTIVE_XE_GETTARGETSTATE', 37 | N'PWAIT_ALL_COMPONENTS_INITIALIZED', 38 | N'PWAIT_DIRECTLOGCONSUMER_GETNEXT', 39 | N'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP', N'QDS_ASYNC_QUEUE', 40 | N'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP', 41 | N'QDS_SHUTDOWN_QUEUE', N'REDO_THREAD_PENDING_WORK', 42 | N'REQUEST_FOR_DEADLOCK_SEARCH', N'RESOURCE_QUEUE', 43 | N'SERVER_IDLE_CHECK', N'SLEEP_BPOOL_FLUSH', 44 | N'SLEEP_DBSTARTUP', N'SLEEP_DCOMSTARTUP', 45 | N'SLEEP_MASTERDBREADY', N'SLEEP_MASTERMDREADY', 46 | N'SLEEP_MASTERUPGRADED', N'SLEEP_MSDBSTARTUP', 47 | N'SLEEP_SYSTEMTASK', N'SLEEP_TASK', 48 | N'SLEEP_TEMPDBSTARTUP', N'SNI_HTTP_ACCEPT', 49 | N'SP_SERVER_DIAGNOSTICS_SLEEP', N'SQLTRACE_BUFFER_FLUSH', 50 | N'SQLTRACE_INCREMENTAL_FLUSH_SLEEP', 51 | N'SQLTRACE_WAIT_ENTRIES', N'WAIT_FOR_RESULTS', 52 | N'WAITFOR', N'WAITFOR_TASKSHUTDOWN', 53 | N'WAIT_XTP_RECOVERY', 54 | N'WAIT_XTP_HOST_WAIT', N'WAIT_XTP_OFFLINE_CKPT_NEW_LOG', 55 | N'WAIT_XTP_CKPT_CLOSE', N'XE_DISPATCHER_JOIN', 56 | N'XE_DISPATCHER_WAIT', N'XE_TIMER_EVENT') 57 | AND [waiting_tasks_count] > 0 58 | ) 59 | SELECT TOP 10 60 | MAX ([W1].[wait_type]) AS [WaitType], 61 | --CAST (MAX ([W1].[WaitS]) AS DECIMAL (16,2)) AS [Wait_S], 62 | CAST (MAX ([W1].[ResourceS]) AS DECIMAL (16,2)) AS [Resource_S] 63 | --, 64 | -- CAST (MAX ([W1].[SignalS]) AS DECIMAL (16,2)) AS [Signal_S], 65 | -- MAX ([W1].[WaitCount]) AS [WaitCount], 66 | -- CAST (MAX ([W1].[Percentage]) AS DECIMAL (5,2)) AS [Percentage], 67 | -- CAST ((MAX ([W1].[WaitS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgWait_S], 68 | -- CAST ((MAX ([W1].[ResourceS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgRes_S], 69 | -- CAST ((MAX ([W1].[SignalS]) / MAX ([W1].[WaitCount])) AS DECIMAL (16,4)) AS [AvgSig_S], 70 | -- CAST ('https://www.sqlskills.com/help/waits/' + MAX ([W1].[wait_type]) as XML) AS [Help/Info URL] 71 | FROM [Waits] AS [W1] 72 | INNER JOIN [Waits] AS [W2] 73 | ON [W2].[RowNum] <= [W1].[RowNum] 74 | GROUP BY [W1].[RowNum] 75 | HAVING SUM ([W2].[Percentage]) - MAX( [W1].[Percentage] ) < 95; -- percentage threshold 76 | GO -------------------------------------------------------------------------------- /src/sql/mssql-instance-xelio.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Author: Matticusau 3 | -- Purpose: Provides IO performance data from Extended Events System Health Session 4 | -- License: https://github.com/Matticusau/sqlops-widgets/blob/master/LICENSE 5 | -- Credit to: https://troubleshootingsql.com/2013/07/25/powerview-and-system-health-session-io-health/ 6 | -- 7 | SET NOCOUNT ON 8 | -- Fetch data only if SQL 2012 or higher (Extended Events schema changed between 2008 R2 and 2012) 9 | IF (SUBSTRING(CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)),1,CHARINDEX('.',CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)))-1) >= 11) 10 | BEGIN 11 | -- Get UTC time difference for reporting event times local to server time 12 | DECLARE @UTCDateDiff int = DATEDIFF(mi,GETUTCDATE(),GETDATE()); 13 | 14 | -- Store XML data retrieved in temp table 15 | SELECT TOP 1 CAST(xet.target_data AS XML) AS XMLDATA 16 | INTO #SystemHealthSessionData 17 | FROM sys.dm_xe_session_targets xet 18 | JOIN sys.dm_xe_sessions xe ON (xe.address = xet.event_session_address) 19 | WHERE xe.name = 'system_health' 20 | AND xet.target_name = 'ring_buffer'; 21 | 22 | -- Parse XML data and provide required values in the form of a table 23 | ;WITH CTE_HealthSession (EventXML) AS 24 | ( 25 | SELECT C.query('.') EventXML 26 | FROM #SystemHealthSessionData a 27 | CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C) 28 | ) 29 | SELECT 30 | DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) as [Event Time], 31 | EventXML.value('(/event/data/text)[1]','varchar(255)') as Component, 32 | EventXML.value('(/event/data/value/ioSubsystem/@ioLatchTimeouts)[1]','bigint') as [IO Latch Timeouts], 33 | EventXML.value('(/event/data/value/ioSubsystem/@totalLongIos)[1]','bigint') as [Total Long IOs], 34 | ISNULL(EventXML.value('(/event/data/value/ioSubsystem/longestPendingRequests/pendingRequest/@filePath)[1]','varchar(8000)'),'') as [Longest Pending Request File], 35 | ISNULL(EventXML.value('(/event/data/value/ioSubsystem/longestPendingRequests/pendingRequest/@duration)[1]','bigint'),0) as [Longest Pending IO Duration] 36 | FROM CTE_HealthSession 37 | WHERE EventXML.value('(/event/@name)[1]', 'varchar(255)') = 'sp_server_diagnostics_component_result' 38 | AND EventXML.value('(/event/data/text)[1]','varchar(255)') = 'IO_SUBSYSTEM' 39 | AND DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) >= DATEADD(mi, -240, GETUTCDATE()) 40 | ORDER BY [Event Time]; 41 | 42 | -- Clean up 43 | DROP TABLE #SystemHealthSessionData 44 | 45 | END -------------------------------------------------------------------------------- /src/sql/mssql-instance-xelmemory.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Author: Matticusau 3 | -- Purpose: Provides Memory performance data from Extended Events System Health Session 4 | -- License: https://github.com/Matticusau/sqlops-widgets/blob/master/LICENSE 5 | -- Credit to: https://troubleshootingsql.com/2013/07/19/powerview-and-system-health-sessionsql-memory-health/ 6 | -- 7 | SET NOCOUNT ON 8 | -- Fetch data only if SQL 2012 or higher (Extended Events schema changed between 2008 R2 and 2012) 9 | IF (SUBSTRING(CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)),1,CHARINDEX('.',CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)))-1) >= 11) 10 | BEGIN 11 | -- Get UTC time difference for reporting event times local to server time 12 | DECLARE @UTCDateDiff int = DATEDIFF(mi,GETUTCDATE(),GETDATE()); 13 | 14 | -- Store XML data retrieved in temp table 15 | SELECT TOP 1 CAST(xet.target_data AS XML) AS XMLDATA 16 | INTO #SystemHealthSessionData 17 | FROM sys.dm_xe_session_targets xet 18 | JOIN sys.dm_xe_sessions xe ON (xe.address = xet.event_session_address) 19 | WHERE xe.name = 'system_health' 20 | AND xet.target_name = 'ring_buffer'; 21 | 22 | -- Parse XML data and provide required values in the form of a table 23 | ;WITH CTE_HealthSession (EventXML) AS 24 | ( 25 | SELECT C.query('.') EventXML 26 | FROM #SystemHealthSessionData a 27 | CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C) 28 | ) 29 | SELECT 30 | DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) as [Event Time], 31 | EventXML.value('(/event/data/text)[1]','varchar(255)') as Component, 32 | EventXML.value('(/event/data/value/resource/@outOfMemoryExceptions)[1]','bigint') as [OOM Exceptions], 33 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[1]','bigint')/(1024*1024*1024) as [Available Physical Memory (GB)], 34 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[3]','bigint')/(1024*1024*1024) as [Available Paging File (GB)], 35 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[5]','int') as [Percent of Committed Memory in WS], 36 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[6]','bigint') as [Page Faults], 37 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[12]','bigint')/1024 as [VM Committed (MB)], 38 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[13]','bigint')/(1024*1024) as [Locked Pages Allocated (GB)], 39 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[14]','bigint')/(1024*1024) as [Large Pages Allocated (GB)], 40 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[17]','bigint')/(1024*1024) as [Target Committed (GB)], 41 | EventXML.value('(/event/data/value/resource/memoryReport/entry/@value)[18]','bigint')/(1024*1024) as [Current Committed (GB)] 42 | FROM CTE_HealthSession 43 | WHERE EventXML.value('(/event/@name)[1]', 'varchar(255)') = 'sp_server_diagnostics_component_result' 44 | AND EventXML.value('(/event/data/text)[1]','varchar(255)') = 'RESOURCE' 45 | AND DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) >= DATEADD(mi, -240, GETUTCDATE()) 46 | ORDER BY [Event Time] desc; 47 | 48 | -- Clean Up 49 | DROP TABLE #SystemHealthSessionData 50 | 51 | END -------------------------------------------------------------------------------- /src/sql/mssql-instance-xelsystem.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Author: Matticusau 3 | -- Purpose: Provides general System performance data from Extended Events System Health Session 4 | -- License: https://github.com/Matticusau/sqlops-widgets/blob/master/LICENSE 5 | -- Credit to: https://troubleshootingsql.com/2013/08/02/powerview-and-system-health-session-system/ 6 | -- 7 | SET NOCOUNT ON 8 | -- Fetch data only if SQL 2012 or higher (Extended Events schema changed between 2008 R2 and 2012) 9 | IF (SUBSTRING(CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)),1,CHARINDEX('.',CAST(SERVERPROPERTY ('ProductVersion') AS varchar(50)))-1) >= 11) 10 | BEGIN 11 | -- Get UTC time difference for reporting event times local to server time 12 | DECLARE @UTCDateDiff int = DATEDIFF(mi,GETUTCDATE(),GETDATE()); 13 | 14 | -- Store XML data retrieved in temp table 15 | SELECT TOP 1 CAST(xet.target_data AS XML) AS XMLDATA 16 | INTO #SystemHealthSessionData 17 | FROM sys.dm_xe_session_targets xet 18 | JOIN sys.dm_xe_sessions xe ON (xe.address = xet.event_session_address) 19 | WHERE xe.name = 'system_health' 20 | AND xet.target_name = 'ring_buffer'; 21 | 22 | -- Parse XML data and provide required values in the form of a table 23 | ;WITH CTE_HealthSession (EventXML) AS 24 | ( 25 | SELECT C.query('.') EventXML 26 | FROM #SystemHealthSessionData a 27 | CROSS APPLY a.XMLDATA.nodes('/RingBufferTarget/event') as T(C) 28 | ) 29 | SELECT 30 | DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) as [Event Time], 31 | EventXML.value('(/event/data/text)[1]','varchar(255)') as Component, 32 | EventXML.value('(/event/data/value/system/@latchWarnings)[1]','bigint') as [Latch Warnings], 33 | EventXML.value('(/event/data/value/system/@isAccessViolationOccurred)[1]','bigint') as [Access Violations], 34 | EventXML.value('(/event/data/value/system/@nonYieldingTasksReported)[1]','bigint') as [Non Yields Reported], 35 | EventXML.value('(/event/data/value/system/@BadPagesDetected)[1]','bigint') as [Bad Pages Detected], 36 | EventXML.value('(/event/data/value/system/@BadPagesFixed)[1]','bigint') as [Bad Pages Fixed] 37 | FROM CTE_HealthSession 38 | WHERE EventXML.value('(/event/@name)[1]', 'varchar(255)') = 'sp_server_diagnostics_component_result' 39 | AND EventXML.value('(/event/data/text)[1]','varchar(255)') = 'SYSTEM' 40 | AND DATEADD(mi,@UTCDateDiff,EventXML.value('(/event/@timestamp)[1]','datetime')) >= DATEADD(mi, -240, GETUTCDATE()) 41 | ORDER BY [Event Time]; 42 | 43 | -- Clean Up 44 | DROP TABLE #SystemHealthSessionData 45 | 46 | END -------------------------------------------------------------------------------- /vsc-extension-quickstart.md: -------------------------------------------------------------------------------- 1 | # Welcome to your SQL Operations Studio Extension 2 | 3 | ## What's in the folder 4 | * This folder contains all of the files necessary for your dashboard insight extension. 5 | * `package.json` - this is the manifest file that defines the list of insights and new dashboard tabs for the extension. Open this in SQL Operations Studio and edit the `contributes` section to add new features. 6 | * `dashboard.insights` section is where your insight definition is added. This is a bar chart insight by default. You can add additional insights here 7 | * `dashboard.tabs` section is where you register a new "tab" or area in the dashboard for your extension, and include your new insight. If you select `No` for the `Add a full dashboard tab?` question this will not be added, and instead you can use the insight in other tabs / in the home tab. 8 | * `sql/query.sql` - this is the file your first insight widget query should be added to. 9 | 10 | 11 | ## Get up and running straight away 12 | * Press `F5` to open a new window with your extension loaded. 13 | * Press `Ctrl + .` instead of `Ctrl + Shift + P` 14 | * Verify that it will launch the Command Palette listing all available commands. The `Ctrl + .` keyboard shortcut was added as an example to you. 15 | 16 | ## Make changes 17 | * You can relaunch the extension from the debug toolbar after making changes to the files listed above. 18 | * You can also reload (`Ctrl+R` or `Cmd+R` on Mac) the SQL Operations Studio window with your extension to load your changes. 19 | 20 | ## Install your extension 21 | * To start using your extension with SQL Operations Studio copy it into the `/.sqlops/extensions` folder and restart SqlOps. 22 | * To share your extension with the world, read on https://github.com/microsoft/sqlopsstudio/wiki/Getting-started-with-Extensibility about publishing an extension. 23 | --------------------------------------------------------------------------------