├── docs
├── images
│ ├── grafana_dashboard_microsoft_sql_server_example.png
│ ├── grafana_dashboard_microsoft_sql_server_section_general.png
│ ├── grafana_dashboard_microsoft_sql_server_section_jobs_monitoring.png
│ ├── grafana_dashboard_microsoft_sql_server_section_query_performance.png
│ ├── grafana_dashboard_microsoft_sql_server_section_server_performance.png
│ ├── grafana_dashboard_microsoft_sql_server_section_database_space_usage.png
│ └── grafana_dashboard_microsoft_sql_server_section_buffer_and_index_management.png
└── metrics.md
├── quickstart
├── grafana
│ ├── dashboards.yml
│ ├── datasource.yml
│ └── Dockerfile
├── db
│ ├── Dockerfile
│ ├── init-db.sh
│ ├── insert_data.sql
│ └── create_db.sql
├── docker-compose.yml
└── README.md
├── .github
├── ISSUE_TEMPLATE
│ ├── help_wanted.yml
│ ├── documentation_request.yml
│ ├── feature_request.yml
│ └── bug_report.yml
├── workflows
│ ├── mssql-demo.yml
│ └── grafana-microsoft-sql-server-dashboard.yml
└── pull_request_template.md
├── README.md
└── dashboard.json
/docs/images/grafana_dashboard_microsoft_sql_server_example.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_example.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_general.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_general.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_jobs_monitoring.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_jobs_monitoring.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_query_performance.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_query_performance.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_server_performance.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_server_performance.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_database_space_usage.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_database_space_usage.png
--------------------------------------------------------------------------------
/docs/images/grafana_dashboard_microsoft_sql_server_section_buffer_and_index_management.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/czantoine/microsoft-sql-server-with-grafana/HEAD/docs/images/grafana_dashboard_microsoft_sql_server_section_buffer_and_index_management.png
--------------------------------------------------------------------------------
/quickstart/grafana/dashboards.yml:
--------------------------------------------------------------------------------
1 | apiVersion: 1
2 |
3 | providers:
4 | - name: 'Default'
5 | orgId: 1
6 | type: file
7 | disableDeletion: false
8 | updateIntervalSeconds: 10
9 | options:
10 | path: /var/lib/grafana/dashboards
11 |
--------------------------------------------------------------------------------
/quickstart/grafana/datasource.yml:
--------------------------------------------------------------------------------
1 | apiVersion: 1
2 |
3 | datasources:
4 | - name: 'mssql'
5 | type: 'mssql'
6 | access: proxy
7 | url: sqlserver:1433
8 | user: sa
9 | password: YourStrong@Passw0rd
10 | database: DemoDB
11 | isDefault: true
12 | jsonData:
13 | sslmode: disable
14 | secureJsonData:
15 | password: YourStrong@Passw0rd
--------------------------------------------------------------------------------
/quickstart/db/Dockerfile:
--------------------------------------------------------------------------------
1 | FROM mcr.microsoft.com/mssql/server:2019-latest
2 |
3 | WORKDIR /tmp
4 |
5 | USER root
6 |
7 | ENV ACCEPT_EULA=Y
8 | ENV SA_PASSWORD=YourStrong@Passw0rd
9 | ENV MSSQL_PID=Developer
10 |
11 | COPY ./quickstart/db/create_db.sql .
12 | COPY ./quickstart/db/insert_data.sql .
13 | COPY ./quickstart/db/init-db.sh .
14 |
15 | RUN chmod +x ./init-db.sh
16 |
17 | ENTRYPOINT ["./init-db.sh"]
18 |
--------------------------------------------------------------------------------
/quickstart/grafana/Dockerfile:
--------------------------------------------------------------------------------
1 | FROM grafana/grafana:latest
2 |
3 | USER root
4 |
5 | ENV GF_AUTH_ANONYMOUS_ENABLED=true
6 |
7 | RUN mkdir -p /var/lib/grafana/dashboards
8 |
9 | RUN curl -o /var/lib/grafana/dashboards/dashboard.json https://grafana.com/api/dashboards/21378/revisions/7/download
10 |
11 | RUN sed -i 's/"uid": *"\${DS_MSSQL}"/"uid": ""/g' /var/lib/grafana/dashboards/dashboard.json
12 |
13 | COPY ./quickstart/grafana/dashboards.yml /etc/grafana/provisioning/dashboards/default.yml
14 | COPY ./quickstart/grafana/datasource.yml /etc/grafana/provisioning/datasources/default.yml
15 |
--------------------------------------------------------------------------------
/quickstart/docker-compose.yml:
--------------------------------------------------------------------------------
1 | version: '3.7'
2 |
3 | services:
4 | sqlserver:
5 | image: czantoine/mssql-demo
6 | container_name: sqlserver-demo
7 | platform: linux/amd64
8 | ports:
9 | - "1433:1433"
10 | networks:
11 | - monitoring
12 |
13 | grafana:
14 | image: czantoine/grafana-microsoft-sql-server-dashboard
15 | container_name: grafana
16 | platform: linux/amd64
17 | environment:
18 | - GF_SECURITY_ADMIN_USER=admin
19 | - GF_SECURITY_ADMIN_PASSWORD=admin_password
20 | - GF_AUTH_ANONYMOUS_ENABLED=true
21 | ports:
22 | - "3009:3000"
23 | networks:
24 | - monitoring
25 |
26 | networks:
27 | monitoring:
28 | driver: bridge
29 |
--------------------------------------------------------------------------------
/quickstart/db/init-db.sh:
--------------------------------------------------------------------------------
1 | #!/bin/bash
2 |
3 | apt-get update
4 | apt-get install -y curl
5 | curl https://packages.microsoft.com/keys/microsoft.asc | apt-key add -
6 | curl https://packages.microsoft.com/config/debian/10/prod.list > /etc/apt/sources.list.d/mssql-release.list
7 | apt-get update
8 | ACCEPT_EULA=Y apt-get install -y msodbcsql17 mssql-tools
9 | echo 'export PATH="$PATH:/opt/mssql-tools/bin"' >> ~/.bashrc
10 |
11 | /opt/mssql/bin/sqlservr &
12 |
13 | sleep 30
14 |
15 | /opt/mssql-tools/bin/sqlcmd -S localhost -U SA -P "$SA_PASSWORD" -d master -i /tmp/create_db.sql
16 |
17 | while true; do
18 | /opt/mssql-tools/bin/sqlcmd -S localhost -U SA -P "$SA_PASSWORD" -d DemoDB -i /tmp/insert_data.sql
19 | sleep 20
20 | done
21 |
22 | wait
--------------------------------------------------------------------------------
/quickstart/db/insert_data.sql:
--------------------------------------------------------------------------------
1 | USE DemoDB;
2 |
3 | DECLARE @RandomId INT = ABS(CHECKSUM(NEWID())) % 10000;
4 | DECLARE @RandomName NVARCHAR(50) = 'Employee ' + CONVERT(NVARCHAR(10), @RandomId);
5 | DECLARE @RandomPosition NVARCHAR(50) = CASE
6 | WHEN (ABS(CHECKSUM(NEWID())) % 2) = 0 THEN 'Developer'
7 | ELSE 'Manager'
8 | END;
9 |
10 | INSERT INTO Employees (Name, Position, DepartmentId, HireDate, Salary) VALUES
11 | (@RandomName, @RandomPosition, 1, GETDATE(), (ABS(CHECKSUM(NEWID())) % 100000) + 30000.00);
12 |
13 | DECLARE @RandomProjectName NVARCHAR(100) = 'Project ' + CONVERT(NVARCHAR(10), @RandomId) + ' - ' + CAST(NEWID() AS NVARCHAR(36));
14 | INSERT INTO Projects (ProjectName, StartDate, Budget) VALUES
15 | (@RandomProjectName, GETDATE(), (ABS(CHECKSUM(NEWID())) % 50000) + 15000.00);
16 |
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE/help_wanted.yml:
--------------------------------------------------------------------------------
1 | name: "🙏 Help Wanted"
2 | description: Request help with a specific area or issue
3 | title: "[HELP] Describe the help needed"
4 | labels: ["help wanted"]
5 |
6 | body:
7 | - type: markdown
8 | attributes:
9 | value: |
10 | ### 🙏 Help Needed
11 | Describe the assistance you are seeking.
12 |
13 | - type: dropdown
14 | attributes:
15 | label: 🛠️ Area of Help
16 | description: Indicate which area you need help with.
17 | options:
18 | - Dashboard Panel
19 | - SQL Query
20 | - Data Source Connection
21 | - Quickstart Guide
22 | - Other
23 |
24 | - type: textarea
25 | attributes:
26 | label: 📋 Context
27 | description: Provide any relevant context or background information.
28 | validations:
29 | required: true
30 |
31 | - type: textarea
32 | attributes:
33 | label: 💬 Additional Information
34 | description: Add any additional details that could help others assist you.
35 |
--------------------------------------------------------------------------------
/.github/workflows/mssql-demo.yml:
--------------------------------------------------------------------------------
1 | name: mssql-demo-docker
2 |
3 | on:
4 | push:
5 | branches:
6 | - "main"
7 | paths-ignore:
8 | - "README.md"
9 | - "docs/**"
10 | - "LICENSE"
11 | - "CONTRIBUTING.md"
12 | release:
13 | types: [published]
14 |
15 | jobs:
16 | build:
17 | runs-on: ubuntu-latest
18 | steps:
19 | -
20 | name: Checkout
21 | uses: actions/checkout@v3
22 | -
23 | name: Login to Docker Hub
24 | uses: docker/login-action@v2
25 | with:
26 | username: ${{ secrets.DOCKERHUB_USERNAME }}
27 | password: ${{ secrets.DOCKERHUB_TOKEN }}
28 | -
29 | name: Set up Docker Buildx
30 | uses: docker/setup-buildx-action@v2
31 | -
32 | name: Build and push
33 | uses: docker/build-push-action@v4
34 | with:
35 | context: .
36 | file: ${{ github.workspace }}/quickstart/db/Dockerfile
37 | push: true
38 | tags: ${{ secrets.DOCKERHUB_USERNAME }}/mssql-demo:latest
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE/documentation_request.yml:
--------------------------------------------------------------------------------
1 | name: "📚 Documentation Request"
2 | description: Request an update or improvement to the documentation
3 | title: "[DOC] Documentation request description"
4 | labels: ["documentation"]
5 |
6 | body:
7 | - type: markdown
8 | attributes:
9 | value: |
10 | ### 📚 Documentation Subject
11 | Specify the section or topic of the documentation that needs updating.
12 |
13 | - type: dropdown
14 | attributes:
15 | label: 📝 Area to Document
16 | description: Which area needs documentation?
17 | options:
18 | - Dashboard Panel
19 | - SQL Query
20 | - Data Source Connection
21 | - Quickstart Guide
22 | - Other
23 |
24 | - type: textarea
25 | attributes:
26 | label: 📈 Improvements Needed
27 | description: Describe what could be added or improved in the documentation.
28 | validations:
29 | required: true
30 |
31 | - type: textarea
32 | attributes:
33 | label: ℹ️ Additional Information
34 | description: Add any other context that could help improve the documentation.
35 |
--------------------------------------------------------------------------------
/.github/workflows/grafana-microsoft-sql-server-dashboard.yml:
--------------------------------------------------------------------------------
1 | name: grafana-microsoft-sql-server-dashboard-docker
2 |
3 | on:
4 | push:
5 | branches:
6 | - "main"
7 | paths-ignore:
8 | - "README.md"
9 | - "docs/**"
10 | - "LICENSE"
11 | - "CONTRIBUTING.md"
12 | release:
13 | types: [published]
14 |
15 | jobs:
16 | build:
17 | runs-on: ubuntu-latest
18 | steps:
19 | -
20 | name: Checkout
21 | uses: actions/checkout@v3
22 | -
23 | name: Login to Docker Hub
24 | uses: docker/login-action@v2
25 | with:
26 | username: ${{ secrets.DOCKERHUB_USERNAME }}
27 | password: ${{ secrets.DOCKERHUB_TOKEN }}
28 | -
29 | name: Set up Docker Buildx
30 | uses: docker/setup-buildx-action@v2
31 | -
32 | name: Build and push
33 | uses: docker/build-push-action@v4
34 | with:
35 | context: .
36 | file: ${{ github.workspace }}/quickstart/grafana/Dockerfile
37 | push: true
38 | tags: ${{ secrets.DOCKERHUB_USERNAME }}/grafana-microsoft-sql-server-dashboard:latest
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE/feature_request.yml:
--------------------------------------------------------------------------------
1 | name: "✨ Feature Request"
2 | description: Suggest an idea to improve the monitoring dashboard
3 | title: "[FEATURE] Feature description"
4 | labels: ["enhancement"]
5 |
6 | body:
7 | - type: markdown
8 | attributes:
9 | value: |
10 | ### ✨ Feature Description
11 | A clear and concise description of the feature you want to add or improve.
12 |
13 | - type: textarea
14 | attributes:
15 | label: 💡 Justification
16 | description: Explain why this feature would be useful.
17 | validations:
18 | required: true
19 |
20 | - type: dropdown
21 | attributes:
22 | label: 🔍 Area of Improvement
23 | description: Which area should this feature target?
24 | options:
25 | - Dashboard Panel
26 | - SQL Query
27 | - Data Source Connection
28 | - Quickstart Guide
29 | - Other
30 |
31 | - type: textarea
32 | attributes:
33 | label: 🛠️ Proposed Solution
34 | description: Describe how you think this feature could be implemented.
35 |
36 | - type: textarea
37 | attributes:
38 | label: ℹ️ Additional Information
39 | description: Add any other context or resources here.
40 |
--------------------------------------------------------------------------------
/.github/pull_request_template.md:
--------------------------------------------------------------------------------
1 | # 📄 Pull Request
2 |
3 | ## 📋 Description
4 |
5 |
6 | ## 🔗 Related Issues
7 |
8 | - Closes #issue_number
9 |
10 | ## 📈 Changes Overview
11 | - [ ] SQL Queries:
12 | - [ ] Dashboard Panels:
13 | - [ ] Data Source Connection:
14 | - [ ] Quickstart Guide:
15 | - [ ] Other:
16 |
17 | ## ✅ Checklist
18 | - [ ] I have tested the changes locally
19 | - [ ] The code is well-documented
20 | - [ ] I have updated related documentation (if needed)
21 | - [ ] This PR has no breaking changes
22 |
23 | ## 📷 Screenshots (if applicable)
24 |
25 |
26 | ## 💬 Additional Comments
27 |
--------------------------------------------------------------------------------
/.github/ISSUE_TEMPLATE/bug_report.yml:
--------------------------------------------------------------------------------
1 | name: "🐞 Bug Report"
2 | description: Report a bug to help improve the monitoring dashboard
3 | title: "[BUG] Bug description"
4 | labels: ["bug"]
5 |
6 | body:
7 | - type: markdown
8 | attributes:
9 | value: |
10 | ### 🐞 Bug Description
11 | A clear and concise description of the bug encountered.
12 |
13 | - type: textarea
14 | attributes:
15 | label: 🔄 Steps to Reproduce
16 | description: Describe the steps to reproduce the bug.
17 | validations:
18 | required: true
19 |
20 | - type: textarea
21 | attributes:
22 | label: 🎯 Expected Behavior
23 | description: Describe what you expected to happen.
24 | validations:
25 | required: true
26 |
27 | - type: textarea
28 | attributes:
29 | label: ❗ Observed Behavior
30 | description: Describe what actually happened.
31 | validations:
32 | required: true
33 |
34 | - type: dropdown
35 | attributes:
36 | label: 📊 Affected Area
37 | description: Which area does this bug affect?
38 | options:
39 | - Dashboard Panel
40 | - SQL Query
41 | - Data Source Connection
42 | - Quickstart Guide
43 | - Other
44 |
45 | - type: textarea
46 | attributes:
47 | label: 🖼️ Screenshots
48 | description: Add screenshots if applicable.
49 |
50 | - type: textarea
51 | attributes:
52 | label: ℹ️ Additional Information
53 | description: Add any other context about the problem here.
54 |
55 |
--------------------------------------------------------------------------------
/quickstart/README.md:
--------------------------------------------------------------------------------
1 | # Example usage of Monitoring with Grafana and Microsoft SQL Server
2 |
3 | [](https://github.com/czantoine/microsoft-sql-server-with-grafana/actions/workflows/grafana-microsoft-sql-server-dashboard.yml)
4 | [](https://github.com/czantoine/microsoft-sql-server-with-grafana/actions/workflows/mssql-demo.yml)
5 |
6 | # Requirements
7 |
8 | - **~2 min of your time**
9 | - [git](https://git-scm.com/) & [docker-compose](https://docs.docker.com/compose/)
10 |
11 | ## Deploy
12 |
13 | ``` bash
14 | # Clone this repository
15 | git clone https://github.com/czantoine/microsoft-sql-server-with-grafana
16 | cd microsoft-sql-server-with-grafana/quickstart
17 |
18 | # Start Grafana and SQL Server containers !
19 | docker compose up -d
20 | ```
21 |
22 | You should now have a stack completely configured and accessible at these locations:
23 |
24 | It might take up to **1 minute** for the database to initialize and for metrics to start appearing in Grafana. During this time, the dashboard may not show any data.
25 |
26 | - `grafana-microsoft-sql-server-dashboard`: [http://localhost:3009](http://localhost:3009) (if you want/need to login, creds are `admin/admin_password`)
27 | - `mssql-demo`: localhost:1433 (if you want/need to login, creds are `sa/YourStrong@Passw0rd`)
28 |
29 | There are currently **no data available for the Jobs Monitoring** section of the dashboard.
30 |
31 | ## Use and troubleshoot
32 |
33 | ### Validate that containers are running
34 |
35 | ```bash
36 | docker ps
37 | CONTAINER ID IMAGE COMMAND CREATED STATUS PORTS NAMES
38 | d14c99a109c9 grafana-microsoft-sql-server-dashboard "/run.sh" 3 minutes ago Up 3 minutes 0.0.0.0:3009->3000/tcp grafana
39 | d50232cb287f mssql-demo "./init-db.sh" 3 minutes ago Up 3 minutes 0.0.0.0:1433->1433/tcp sqlserver-demo
40 | ```
41 |
42 | ### Checkout the grafana example dashboards
43 |
44 | Example dashboards should be available at these addresses:
45 |
46 | - **Monitoring dashboard** - [http://localhost:3009/d/microsoft-sql-server-dashboard](http://localhost:3009/d/bff36b75-3eae-44b8-994b-c7a87274d162/microsoft-sql-server-dashboard)
47 |
48 | 
49 |
50 | ## Cleanup
51 |
52 | ```bash
53 | docker compose down
54 | ```
--------------------------------------------------------------------------------
/quickstart/db/create_db.sql:
--------------------------------------------------------------------------------
1 | CREATE DATABASE DemoDB;
2 | GO
3 |
4 | USE DemoDB;
5 | GO
6 |
7 | CREATE TABLE Departments (
8 | DepartmentId INT PRIMARY KEY IDENTITY(1,1),
9 | DepartmentName NVARCHAR(50) NOT NULL,
10 | Location NVARCHAR(50) NOT NULL
11 | );
12 | GO
13 |
14 | INSERT INTO Departments (DepartmentName, Location) VALUES
15 | ('IT', 'Headquarters'),
16 | ('HR', 'Headquarters'),
17 | ('Finance', 'Headquarters'),
18 | ('Marketing', 'Regional Office'),
19 | ('Sales', 'Branch Office'),
20 | ('Research', 'Innovation Center'),
21 | ('Operations', 'Warehouse'),
22 | ('Customer Service', 'Headquarters');
23 | GO
24 |
25 | CREATE TABLE Employees (
26 | Id INT PRIMARY KEY IDENTITY(1,1),
27 | Name NVARCHAR(50) NOT NULL,
28 | Position NVARCHAR(50) NOT NULL,
29 | DepartmentId INT NOT NULL,
30 | HireDate DATE NOT NULL,
31 | Salary DECIMAL(10, 2) NOT NULL,
32 | FOREIGN KEY (DepartmentId) REFERENCES Departments(DepartmentId)
33 | );
34 | GO
35 |
36 | INSERT INTO Employees (Name, Position, DepartmentId, HireDate, Salary) VALUES
37 | ('John Doe', 'Developer', 1, '2022-01-15', 70000.00),
38 | ('Jane Smith', 'Manager', 2, '2021-03-22', 85000.00),
39 | ('Alice Johnson', 'Analyst', 3, '2023-07-10', 60000.00),
40 | ('Bob Brown', 'Designer', 4, '2020-11-05', 65000.00),
41 | ('Charlie Davis', 'Developer', 1, '2019-05-30', 72000.00),
42 | ('Eve White', 'Manager', 5, '2022-09-18', 90000.00),
43 | ('Frank Black', 'Intern', 1, '2024-01-01', 40000.00),
44 | ('Grace Green', 'HR Assistant', 2, '2021-05-15', 45000.00),
45 | ('Henry Hall', 'Finance Manager', 3, '2020-12-01', 95000.00),
46 | ('Ivy Lewis', 'Marketing Specialist', 4, '2023-03-01', 55000.00),
47 | ('Jack King', 'Sales Executive', 5, '2019-07-25', 60000.00),
48 | ('Karen Adams', 'Customer Support', 8, '2022-08-01', 48000.00),
49 | ('Larry Martin', 'Research Scientist', 6, '2021-06-15', 80000.00),
50 | ('Mona Clark', 'Operations Supervisor', 7, '2020-10-10', 70000.00),
51 | ('Nina Carter', 'Product Manager', 4, '2023-02-20', 72000.00);
52 | GO
53 |
54 | CREATE TABLE Projects (
55 | ProjectId INT PRIMARY KEY IDENTITY(1,1),
56 | ProjectName NVARCHAR(100) NOT NULL,
57 | StartDate DATE NOT NULL,
58 | EndDate DATE NULL,
59 | Budget DECIMAL(15, 2) NOT NULL
60 | );
61 | GO
62 |
63 | INSERT INTO Projects (ProjectName, StartDate, EndDate, Budget) VALUES
64 | ('Website Redesign', '2023-01-15', '2023-06-15', 50000.00),
65 | ('Mobile App Development', '2023-02-01', NULL, 75000.00),
66 | ('Market Research', '2023-03-01', '2023-12-01', 30000.00),
67 | ('Data Migration', '2023-05-01', NULL, 60000.00),
68 | ('Customer Feedback System', '2023-04-01', '2023-09-30', 25000.00),
69 | ('Inventory Management System', '2023-06-01', NULL, 40000.00),
70 | ('Sales Data Analysis', '2023-08-01', '2024-01-01', 35000.00),
71 | ('HR Portal Development', '2023-07-15', NULL, 45000.00),
72 | ('New Product Launch', '2023-09-01', '2024-03-01', 100000.00),
73 | ('Social Media Campaign', '2023-10-01', '2024-01-01', 30000.00);
74 | GO
75 |
76 | CREATE TABLE EmployeeProjects (
77 | EmployeeId INT NOT NULL,
78 | ProjectId INT NOT NULL,
79 | PRIMARY KEY (EmployeeId, ProjectId),
80 | FOREIGN KEY (EmployeeId) REFERENCES Employees(Id),
81 | FOREIGN KEY (ProjectId) REFERENCES Projects(ProjectId)
82 | );
83 | GO
84 |
85 | INSERT INTO EmployeeProjects (EmployeeId, ProjectId) VALUES
86 | (1, 1),
87 | (2, 3),
88 | (3, 2),
89 | (4, 1),
90 | (5, 4),
91 | (6, 2),
92 | (7, 5),
93 | (8, 6),
94 | (9, 7),
95 | (10, 8),
96 | (11, 9),
97 | (12, 10),
98 | (13, 1),
99 | (14, 3);
100 | GO
101 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 |
6 |
7 |
8 |
9 | If you enjoy my projects and want to support my work, consider buying me a coffee! ☕️
10 |
11 | [](https://ko-fi.com/V7V22V693)
12 |
13 | # Monitoring Microsoft SQL Server with Grafana
14 |
15 |
16 |
17 |
18 |
19 | Example of the metrics you should expect to retrieve; the detailed list of exported metrics is maintained [here](docs/metrics.md).
20 |
21 | A Docker Compose setup is available if you wish to test the dashboard. Available [here](quickstart/README.md).
22 |
23 | ## Features
24 |
25 | This is a comprehensive Grafana dashboard designed for monitoring Microsoft SQL Server. It provides real-time insights into your SQL Server environment, making it easy for both technical and non-technical users to understand the performance of their SQL Server instances.
26 |
27 | ## Data Source Setup
28 | The data source for this dashboard can directly be your SQL Server database instance. Ensure that the SQL Server instance is accessible to Grafana.
29 |
30 | ### General
31 | - **Database name**: Displays the database name.
32 | - **Uptime**: Displays the SQL Server start time.
33 | - **Active User Sessions**: Shows the count of active user sessions by login name.
34 |
35 | 
36 |
37 | ### Query Performance
38 | - **Top 10 Longest Running Queries**: Lists the top 10 queries with the longest average duration.
39 | - **Queries per Second**: Provides average duration and execution count of queries.
40 | - **Query Cache Hit Rate**: Visualizes the cache hit ratio for queries.
41 | - **Query Plan Cache Efficiency**: Shows the efficiency of cached query plans.
42 | - **Wait Stats Overview**: Displays an overview of wait statistics in SQL Server.
43 | - **Current Connections**: Indicates the current number of connections to the SQL Server.
44 | - **Query Latency**: Visualizes latency for recent queries.
45 | - **Execution Plans Performance**: Monitors performance metrics of executed plans.
46 |
47 | 
48 |
49 | ### Server Performance
50 | - **Query Latency**: Displays the top 10 longest running queries based on total elapsed time.
51 | - **Running Threads**: Displays the number of running threads in the SQL Server.
52 | - **Open Files Limit**: Shows the count of currently open files.
53 | - **Active Transactions**: Provides details on active transactions in the system.
54 | - **Temp Tables Created On Disk**: Monitors the number of temporary tables created on disk.
55 | - **Table Locks**: Displays information on current table locks.
56 | - **Waiting Times Monitoring**: Provides an overview of wait statistics in SQL Server.
57 |
58 | 
59 |
60 | ### Buffer and Index Management
61 | - **Buffer Pool Hit Rate**: Visualizes the hit rate of the buffer pool.
62 | - **Buffer Pool Usage**: Monitors the overall usage of the buffer pool.
63 | - **Index Usage**: Displays usage statistics for database indexes.
64 | - **Page Life Expectancy**: Shows the average time pages stay in the buffer pool.
65 |
66 | 
67 |
68 | ### Database Space Usage
69 | - **Total Space**: Displays the total space allocated to all tables in the database.
70 | - **Used Space**: Shows the space currently used by all tables.
71 | - **Unused Space**: Provides information on unused space in the database.
72 | - **Memory Grants Pending**: Indicates the count of pending memory grants.
73 | - **Transaction Log Space Usage**: Displays the usage of transaction log space.
74 | - **Database File Usage**: Shows details about database files and their sizes.
75 | - **Table Locks**: Provides information on current table locks.
76 | - **Backups Status**: Displays the status of recent database backups.
77 | - **Memory Usage**: Visualizes overall memory usage in SQL Server.
78 | - **TempDB Disk Monitoring**: Monitors I/O stalls for TempDB files.
79 | -
80 | 
81 |
82 | ### Jobs Monitoring
83 | - **Job Execution Frequency**: Displays the execution count of jobs over the last week.
84 | - **Job Execution History Duration**: Shows job execution history along with durations.
85 | - **Jobs in Progress**: Lists jobs that are currently running along with their durations.
86 | - **Failed Jobs Overview**: Provides an overview of recently failed jobs and their error messages.
87 | - **Scheduled and Running Jobs**: Displays the status of scheduled and currently running jobs.
88 |
89 | 
90 |
91 | You can directly find the [dashboard here](https://grafana.com/grafana/dashboards/21378-microsoft-sql-server-dashboard/) or use the ID: 21378.
92 |
93 | ---
94 |
95 | If you find this project useful, please give it a star ⭐️ ! Your support is greatly appreciated. Also, feel free to contribute to this project. All contributions, whether bug fixes, improvements, or new features, are welcome!
96 |
97 | ## Stargazers overt time
98 | [](https://starchart.cc/czantoine/microsoft-sql-server-with-grafana)
99 |
--------------------------------------------------------------------------------
/docs/metrics.md:
--------------------------------------------------------------------------------
1 | # Metrics Overview
2 |
3 | ## General
4 | | Metric | SQL Query |
5 | |----------------------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
6 | | Database Name | `SELECT DB_NAME() AS DatabaseName;` |
7 | | Uptime | `SELECT sqlserver_start_time AS 'SQL SERVER START TIME' FROM sys.dm_os_sys_info;` |
8 | | Active User Sessions | `SELECT login_name AS LoginName, COUNT(session_id) AS SessionCount FROM sys.dm_exec_sessions WHERE is_user_process = 1 GROUP BY login_name ORDER BY SessionCount DESC;` |
9 |
10 | ## Query Performance
11 | | Metric | SQL Query |
12 | |---------------------------------|-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
13 | | Top 10 Longest Running Queries | `SELECT TOP 10 qs.total_elapsed_time / qs.execution_count / 1000.0 AS avg_duration_ms, qs.execution_count, SUBSTRING(qt.text, qs.statement_start_offset/2, (CASE WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS query_text FROM sys.dm_exec_query_stats qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) qt ORDER BY avg_duration_ms DESC;` |
14 | | Queries per Second | `SELECT qs.total_elapsed_time / qs.execution_count / 1000.0 AS 'Avg Duration ms', qs.execution_count AS 'Exuction Count', SUBSTRING(qt.text, qs.statement_start_offset/2, (CASE WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2 ELSE qs.statement_end_offset END - qs.statement_start_offset)/2) AS query_text FROM sys.dm_exec_query_stats qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) qt ORDER BY 'Avg Duration ms' DESC;` |
15 | | Query Cache Hit Rate | `SELECT (CAST(SUM(CASE WHEN usecounts > 0 THEN 1 ELSE 0 END) AS FLOAT) / COUNT(*)) * 100 AS Cache_Hit_Ratio FROM sys.dm_exec_cached_plans WHERE objtype = 'Adhoc' OR objtype = 'Prepared';` |
16 | | Query Plan Cache Efficiency | `SELECT cacheobjtype AS CacheObjectType, objtype AS ObjectType, usecounts AS 'Use Count', size_in_bytes AS 'Cache Size' FROM sys.dm_exec_cached_plans WHERE usecounts < 10;` |
17 | | Wait Stats Overview | `DBCC SQLPERF (WAITSTATS);` |
18 | | Current Connections | `SELECT COUNT(session_id) AS Connections FROM sys.dm_exec_sessions WHERE is_user_process = 1;` |
19 | | Query Latency | `SELECT TOP 10 creation_time AS CreationTime, total_logical_reads AS LogicalReads FROM sys.dm_exec_query_stats ORDER BY total_elapsed_time DESC;` |
20 | | Execution Plans Performance | `SELECT TOP 10 st.text AS QueryText, qs.total_worker_time AS CPUTime, qs.total_elapsed_time AS TotalTime, qs.total_logical_reads AS LogicalReads FROM sys.dm_exec_query_stats qs CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) st ORDER BY qs.total_worker_time DESC;` |
21 |
22 | ## Server Performance
23 | | Metric | SQL Query |
24 | |----------------------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
25 | | Query Latency | `SELECT TOP 10 creation_time AS CreationTime, total_elapsed_time/1000 AS TotalElapsedTimeMS, execution_count AS ExecutionCount, total_worker_time/1000 AS CPUTimeMS FROM sys.dm_exec_query_stats ORDER BY total_elapsed_time DESC;` |
26 | | Running Threads | `SELECT COUNT(*) AS Running_Threads FROM sys.dm_exec_requests WHERE status = 'running';` |
27 | | Open Files Limit | `SELECT COUNT(*) AS OpenFiles FROM sys.dm_io_pending_io_requests;` |
28 | | Active Transactions | `SELECT transaction_id AS TransactionID, transaction_begin_time AS BeginTime, transaction_state AS State, transaction_type AS Type FROM sys.dm_tran_active_transactions;` |
29 | | Temp Tables Created On Disk | `SELECT SUM(user_objects_alloc_page_count) AS 'User Object Pages', SUM(internal_objects_alloc_page_count) AS 'Internal Object Pages' FROM sys.dm_db_session_space_usage;` |
30 | | Wait Times Monitoring | `SELECT wait_type, SUM(wait_time_ms) AS WaitTimeMS, SUM(waiting_tasks_count) AS TaskCount FROM sys.dm_os_wait_stats WHERE wait_type NOT IN ('SLEEP_TASK', 'BROKER_TASK_STOP', 'SQLTRACE_BUFFER_FLUSH') GROUP BY wait_type ORDER BY WaitTimeMS DESC;` |
31 | | Table Locks | `SELECT request_session_id AS SessionID, resource_database_id AS DatabaseID, resource_associated_entity_id AS EntityID, request_mode AS LockType, request_status AS Status FROM sys.dm_tran_locks;` |
32 |
33 | ## Buffer and Index Management
34 | | Metric | SQL Query |
35 | |----------------------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
36 | | Buffer Pool Hit Rate | `SELECT CAST(COUNT(*) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Buffer Pool Used MB', CAST(SUM(CASE WHEN is_modified = 1 THEN 1 ELSE 0 END) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Dirty Buffer MB', CAST(COUNT(*) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Buffer Pool Total MB', CAST(SUM(CASE WHEN is_modified = 1 THEN 1 ELSE 0 END) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Dirty Buffer Used MB' FROM sys.dm_os_buffer_descriptors WHERE database_id > 4;` |
37 | | Buffer Pool Usage | `SELECT (total_physical_memory_kb / 1024) AS 'Total Physical Memory MB', (available_physical_memory_kb / 1024) AS 'Available Physical Memory MB', (total_page_file_kb / 1024) AS 'Total Page File MB', (available_page_file_kb / 1024) AS 'Available Page File MB', (system_memory_state_desc) AS 'System Memory State Description' FROM sys.dm_os_sys_memory;` |
38 | | Index Usage | `SELECT OBJECT_NAME(s.object_id) AS TableName, i.name AS IndexName, s.user_seeks, s.user_scans, s.user_lookups, s.user_updates FROM sys.dm_db_index_usage_stats AS s INNER JOIN sys.indexes AS i ON i.object_id = s.object_id AND i.index_id = s.index_id WHERE s.database_id = DB_ID(DB_NAME()) ORDER BY s.user_seeks DESC;` |
39 | | Page Life Expectancy | `SELECT [object_name], [counter_name], [cntr_value] AS PageLifeExpectancy FROM sys.dm_os_performance_counters WHERE [object_name] LIKE '%Buffer Manager%' AND [counter_name] = 'Page life expectancy';` |
40 |
41 | ## Database Space Usage
42 | | Metric | SQL Query |
43 | |----------------------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
44 | | Total Space MB | `SELECT ISNULL(t.NAME, 'Total') AS TableName, ISNULL(s.NAME, '') AS SchemaName, CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.0), 2) AS DECIMAL(18, 2)) AS TotalSpaceMB FROM sys.tables t INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id INNER JOIN sys.schemas s ON t.schema_id = s.schema_id GROUP BY ROLLUP(t.Name, s.Name) ORDER BY CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END, TotalSpaceMB DESC;` |
45 | | Used Space MB | `SELECT ISNULL(t.NAME, 'Total') AS TableName, ISNULL(s.NAME, '') AS SchemaName, CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.0), 2) AS DECIMAL(18, 2)) AS UsedSpaceMB FROM sys.tables t INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id INNER JOIN sys.schemas s ON t.schema_id = s.schema_id GROUP BY ROLLUP(t.Name, s.Name) ORDER BY CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END, UsedSpaceMB DESC;` |
46 | | Unused Space MB | `SELECT ISNULL(t.NAME, 'Total') AS TableName, ISNULL(s.NAME, '') AS SchemaName, CAST(ROUND(((SUM(a.total_pages - a.used_pages) * 8) / 1024.0 * 100), 2) AS DECIMAL(18, 2)) AS UnusedSpaceMB FROM sys.tables t INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id INNER JOIN sys.allocation_units a ON p.partition_id = a.container_id INNER JOIN sys.schemas s ON t.schema_id = s.schema_id GROUP BY ROLLUP(t.Name, s.Name) ORDER BY CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END, UnusedSpaceMB DESC;` |
47 | | Memory Grants Pending | `SELECT COUNT(*) AS MemoryGrantsPending FROM sys.dm_exec_query_memory_grants WHERE grant_time IS NULL;` |
48 | | Transaction Log Space Usage | `DBCC SQLPERF (LOGSPACE);` |
49 | | Database File Usage | `SELECT name AS FileName, size/128 AS FileSizeMB, physical_name AS PhysicalName FROM sys.master_files WHERE database_id = DB_ID();` |
50 | | Backup Status | `SELECT database_name, backup_start_date, backup_finish_date, backup_size / 1024 / 1024 AS BackupSizeMB FROM msdb.dbo.backupset ORDER BY backup_start_date DESC;` |
51 | | Row Count | `SELECT ISNULL(t.NAME, 'Total') AS TableName, ISNULL(s.NAME, '') AS SchemaName, SUM(p.rows) AS RowCounts FROM sys.tables t INNER JOIN sys.indexes i ON t.OBJECT_ID = i.object_id INNER JOIN sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id INNER JOIN sys.schemas s ON t.schema_id = s.schema_id GROUP BY ROLLUP(t.Name, s.Name) ORDER BY CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END, RowCounts DESC;` |
52 | | Memory Usage| `SELECT total_physical_memory_kb, available_physical_memory_kb, total_page_file_kb, available_page_file_kb FROM sys.dm_os_sys_memory;` |
53 | | TempDB Disk Monitoring | `SELECT database_id, file_id, io_stall_read_ms AS DiskReadStall, io_stall_write_ms AS DiskWriteStall, num_of_reads, num_of_writes FROM sys.dm_io_virtual_file_stats (2, NULL);` |
54 |
55 | | Metric | SQL Query |
56 | |---------------------------|---------------------------------------------------------------------------------------------------------------------------------------------------------------------|
57 | | Job Execution Frequency | `SELECT job.name AS JobName, COUNT(run.run_date) AS ExecutionCount FROM msdb.dbo.sysjobs AS job INNER JOIN msdb.dbo.sysjobhistory AS run ON job.job_id = run.job_id WHERE run.run_date >= CONVERT(VARCHAR, GETDATE() - 7, 112) -- Last 7 days GROUP BY job.name ORDER BY ExecutionCount DESC` |
58 | | Jobs in progress | `SELECT DISTINCT job.name AS JobName, activity.run_requested_date AS StartTime, DATEDIFF(SECOND, activity.run_requested_date, GETDATE()) AS RunDurationSeconds FROM msdb.dbo.sysjobs AS job INNER JOIN msdb.dbo.sysjobactivity AS activity ON job.job_id = activity.job_id WHERE activity.run_requested_date IS NOT NULL AND activity.stop_execution_date IS NULL ORDER BY activity.run_requested_date DESC;`|
59 | | Scheduled and Running Jobs | `SELECT TOP 20 job.name AS JobName, CASE WHEN activity.run_requested_date IS NULL THEN 'Scheduled' ELSE 'Running' END AS JobStatus, schedule.next_run_date AS NextRunDate, schedule.next_run_time AS NextRunTime FROM msdb.dbo.sysjobs AS job LEFT JOIN msdb.dbo.sysjobactivity AS activity ON job.job_id = activity.job_id LEFT JOIN msdb.dbo.sysjobschedules AS schedule ON job.job_id = schedule.job_id WHERE activity.stop_execution_date IS NULL -- Running jobs OR schedule.next_run_date IS NOT NULL -- Scheduled jobs ORDER BY schedule.next_run_date, schedule.next_run_time;`|
60 | | Job Execution History Duration | `SELECT job.name AS JobName, run.run_date AS RunDate, run.run_duration AS RunDuration FROM msdb.dbo.sysjobs AS job INNER JOIN msdb.dbo.sysjobhistory AS run ON job.job_id = run.job_id WHERE run.step_id = 0 -- 0 indicates job level information ORDER BY run.run_date DESC`|
61 | | Failed Jobs Overview| `SELECT job.name AS JobName, run.run_date AS RunDate, run.run_time AS RunTime, run.run_duration AS RunDuration, run.message AS ErrorMessage FROM msdb.dbo.sysjobs AS job INNER JOIN msdb.dbo.sysjobhistory AS run ON job.job_id = run.job_id WHERE run.run_status = 0 -- 0 indicates failure ORDER BY run.run_date DESC`|
62 |
63 |
64 |
--------------------------------------------------------------------------------
/dashboard.json:
--------------------------------------------------------------------------------
1 | {
2 | "__inputs": [
3 | {
4 | "name": "DS_MSSQL",
5 | "label": "mssql",
6 | "description": "",
7 | "type": "datasource",
8 | "pluginId": "mssql",
9 | "pluginName": "Microsoft SQL Server"
10 | }
11 | ],
12 | "__elements": {},
13 | "__requires": [
14 | {
15 | "type": "panel",
16 | "id": "barchart",
17 | "name": "Bar chart",
18 | "version": ""
19 | },
20 | {
21 | "type": "panel",
22 | "id": "bargauge",
23 | "name": "Bar gauge",
24 | "version": ""
25 | },
26 | {
27 | "type": "panel",
28 | "id": "gauge",
29 | "name": "Gauge",
30 | "version": ""
31 | },
32 | {
33 | "type": "grafana",
34 | "id": "grafana",
35 | "name": "Grafana",
36 | "version": "11.2.0"
37 | },
38 | {
39 | "type": "datasource",
40 | "id": "mssql",
41 | "name": "Microsoft SQL Server",
42 | "version": "1.0.0"
43 | },
44 | {
45 | "type": "panel",
46 | "id": "piechart",
47 | "name": "Pie chart",
48 | "version": ""
49 | },
50 | {
51 | "type": "panel",
52 | "id": "stat",
53 | "name": "Stat",
54 | "version": ""
55 | },
56 | {
57 | "type": "panel",
58 | "id": "table",
59 | "name": "Table",
60 | "version": ""
61 | },
62 | {
63 | "type": "panel",
64 | "id": "text",
65 | "name": "Text",
66 | "version": ""
67 | },
68 | {
69 | "type": "panel",
70 | "id": "timeseries",
71 | "name": "Time series",
72 | "version": ""
73 | }
74 | ],
75 | "annotations": {
76 | "list": [
77 | {
78 | "builtIn": 1,
79 | "datasource": {
80 | "type": "grafana",
81 | "uid": "-- Grafana --"
82 | },
83 | "enable": true,
84 | "hide": true,
85 | "iconColor": "rgba(0, 211, 255, 1)",
86 | "name": "Annotations & Alerts",
87 | "type": "dashboard"
88 | }
89 | ]
90 | },
91 | "description": "This is a comprehensive Microsoft SQL Server Dashboard designed to monitor key performance indicators. It provides real-time insights into your SQL Server environment.",
92 | "editable": true,
93 | "fiscalYearStartMonth": 0,
94 | "gnetId": 21378,
95 | "graphTooltip": 0,
96 | "id": null,
97 | "links": [],
98 | "liveNow": false,
99 | "links": [
100 | {
101 | "asDropdown": false,
102 | "icon": "doc",
103 | "includeVars": false,
104 | "keepTime": false,
105 | "tags": [],
106 | "targetBlank": true,
107 | "title": "GitHub",
108 | "tooltip": "",
109 | "type": "link",
110 | "url": "https://github.com/czantoine/microsoft-sql-server-with-grafana/tree/main"
111 | }
112 | ],
113 | "panels": [
114 | {
115 | "collapsed": false,
116 | "gridPos": {
117 | "h": 1,
118 | "w": 24,
119 | "x": 0,
120 | "y": 0
121 | },
122 | "id": 49,
123 | "panels": [],
124 | "title": "General",
125 | "type": "row"
126 | },
127 | {
128 | "datasource": {
129 | "type": "mssql",
130 | "uid": "${DS_MSSQL}"
131 |
132 | },
133 | "gridPos": {
134 | "h": 6,
135 | "w": 4,
136 | "x": 0,
137 | "y": 1
138 | },
139 | "id": 48,
140 | "options": {
141 | "code": {
142 | "language": "plaintext",
143 | "showLineNumbers": false,
144 | "showMiniMap": false
145 | },
146 | "content": "\n\n

\n
",
147 | "mode": "html"
148 | },
149 | "pluginVersion": "11.2.0",
150 | "targets": [
151 | {
152 | "dataset": "DemoDB",
153 |
154 | "datasource": {
155 | "type": "mssql",
156 | "uid": "${DS_MSSQL}"
157 |
158 | },
159 | "editorMode": "code",
160 | "format": "table",
161 | "rawQuery": true,
162 | "rawSql": "SELECT DB_NAME() AS DatabaseName;\n",
163 | "refId": "A",
164 | "sql": {
165 | "columns": [
166 | {
167 | "parameters": [],
168 | "type": "function"
169 | }
170 | ],
171 | "groupBy": [
172 | {
173 | "property": {
174 | "type": "string"
175 | },
176 | "type": "groupBy"
177 | }
178 | ],
179 | "limit": 50
180 | }
181 | }
182 | ],
183 | "type": "text"
184 | },
185 | {
186 | "datasource": {
187 | "type": "mssql",
188 | "uid": "${DS_MSSQL}"
189 |
190 | },
191 | "fieldConfig": {
192 | "defaults": {
193 | "mappings": [],
194 | "thresholds": {
195 | "mode": "absolute",
196 | "steps": [
197 | {
198 | "color": "green",
199 | "value": null
200 | },
201 | {
202 | "color": "red",
203 | "value": 80
204 | }
205 | ]
206 | },
207 | "unit": "short"
208 |
209 | },
210 | "overrides": []
211 | },
212 | "gridPos": {
213 | "h": 3,
214 | "w": 4,
215 | "x": 4,
216 | "y": 1
217 | },
218 | "id": 47,
219 | "options": {
220 | "colorMode": "value",
221 | "graphMode": "area",
222 | "justifyMode": "auto",
223 | "orientation": "auto",
224 | "percentChangeColorMode": "standard",
225 | "reduceOptions": {
226 | "calcs": [],
227 | "fields": "/.*/",
228 | "values": true
229 | },
230 | "showPercentChange": false,
231 | "textMode": "value",
232 | "wideLayout": true
233 | },
234 | "pluginVersion": "11.2.0",
235 | "targets": [
236 | {
237 | "dataset": "DemoDB",
238 |
239 | "datasource": {
240 | "type": "mssql",
241 | "uid": "${DS_MSSQL}"
242 |
243 | },
244 | "editorMode": "code",
245 | "format": "table",
246 | "rawQuery": true,
247 | "rawSql": "SELECT DB_NAME() AS DatabaseName;\n",
248 | "refId": "A",
249 | "sql": {
250 | "columns": [
251 | {
252 | "parameters": [],
253 | "type": "function"
254 | }
255 | ],
256 | "groupBy": [
257 | {
258 | "property": {
259 | "type": "string"
260 | },
261 | "type": "groupBy"
262 | }
263 | ],
264 | "limit": 50
265 | }
266 | }
267 | ],
268 | "type": "stat"
269 | },
270 | {
271 | "datasource": {
272 | "type": "mssql",
273 | "uid": "${DS_MSSQL}"
274 |
275 | },
276 | "fieldConfig": {
277 | "defaults": {
278 | "color": {
279 | "mode": "palette-classic"
280 | },
281 | "mappings": [],
282 | "thresholds": {
283 | "mode": "absolute",
284 | "steps": [
285 | {
286 | "color": "green",
287 | "value": null
288 | },
289 | {
290 | "color": "red",
291 | "value": 80
292 | }
293 | ]
294 | }
295 |
296 |
297 | },
298 | "overrides": []
299 | },
300 | "gridPos": {
301 | "h": 6,
302 | "w": 16,
303 | "x": 8,
304 | "y": 1
305 | },
306 | "id": 31,
307 | "options": {
308 | "displayMode": "basic",
309 | "maxVizHeight": 135,
310 | "minVizHeight": 0,
311 | "minVizWidth": 0,
312 | "namePlacement": "auto",
313 | "orientation": "auto",
314 | "reduceOptions": {
315 | "calcs": [],
316 | "fields": "",
317 | "limit": 6,
318 | "values": true
319 | },
320 | "showUnfilled": true,
321 | "sizing": "manual",
322 | "text": {},
323 | "valueMode": "text"
324 | },
325 | "pluginVersion": "11.2.0",
326 | "targets": [
327 | {
328 | "dataset": "_DBA",
329 | "datasource": {
330 | "type": "mssql",
331 | "uid": "${DS_MSSQL}"
332 |
333 | },
334 | "editorMode": "code",
335 | "format": "table",
336 | "rawQuery": true,
337 | "rawSql": "SELECT login_name AS LoginName,\n COUNT(session_id) AS SessionCount\nFROM sys.dm_exec_sessions\nWHERE is_user_process = 1\nGROUP BY login_name\nORDER BY SessionCount DESC;\n",
338 | "refId": "A",
339 | "sql": {
340 | "columns": [
341 | {
342 | "parameters": [],
343 | "type": "function"
344 | }
345 | ],
346 | "groupBy": [
347 | {
348 | "property": {
349 | "type": "string"
350 | },
351 | "type": "groupBy"
352 | }
353 | ],
354 | "limit": 50
355 | }
356 | }
357 | ],
358 | "title": "Active User Sessions",
359 | "type": "bargauge"
360 | },
361 | {
362 | "datasource": {
363 | "type": "mssql",
364 | "uid": "${DS_MSSQL}"
365 |
366 | },
367 | "fieldConfig": {
368 | "defaults": {
369 | "color": {
370 | "fixedColor": "green",
371 | "mode": "fixed"
372 | },
373 | "custom": {
374 | "align": "center",
375 | "cellOptions": {
376 | "type": "color-text"
377 | },
378 | "filterable": false,
379 | "inspect": false
380 | },
381 | "mappings": [],
382 | "thresholds": {
383 | "mode": "absolute",
384 | "steps": [
385 | {
386 | "color": "green",
387 | "value": null
388 | },
389 | {
390 | "color": "red",
391 | "value": 80
392 | }
393 | ]
394 | },
395 | "unit": "date"
396 |
397 | },
398 | "overrides": []
399 | },
400 | "gridPos": {
401 | "h": 3,
402 | "w": 4,
403 | "x": 4,
404 | "y": 4
405 | },
406 | "id": 5,
407 | "options": {
408 | "cellHeight": "sm",
409 | "footer": {
410 | "countRows": false,
411 | "enablePagination": false,
412 | "fields": "",
413 | "reducer": [
414 | "lastNotNull"
415 | ],
416 | "show": false
417 | },
418 | "showHeader": false
419 | },
420 | "pluginVersion": "11.2.0",
421 | "targets": [
422 | {
423 | "dataset": "DemoDB",
424 |
425 | "datasource": {
426 | "type": "mssql",
427 | "uid": "${DS_MSSQL}"
428 |
429 | },
430 | "editorMode": "code",
431 | "format": "table",
432 | "rawQuery": true,
433 | "rawSql": "SELECT sqlserver_start_time as 'SQL SERVER START TIME'\nFROM sys.dm_os_sys_info;\n",
434 | "refId": "A",
435 | "sql": {
436 | "columns": [
437 | {
438 | "parameters": [],
439 | "type": "function"
440 | }
441 | ],
442 | "groupBy": [
443 | {
444 | "property": {
445 | "type": "string"
446 | },
447 | "type": "groupBy"
448 | }
449 | ],
450 | "limit": 50
451 | }
452 | }
453 | ],
454 | "title": "Uptime",
455 | "type": "table"
456 | },
457 | {
458 | "collapsed": false,
459 | "gridPos": {
460 | "h": 1,
461 | "w": 24,
462 | "x": 0,
463 | "y": 7
464 | },
465 | "id": 20,
466 | "panels": [],
467 | "title": "Query Performance",
468 | "type": "row"
469 | },
470 | {
471 | "datasource": {
472 | "type": "mssql",
473 | "uid": "${DS_MSSQL}"
474 |
475 | },
476 | "fieldConfig": {
477 | "defaults": {
478 | "color": {
479 | "mode": "continuous-GrYlRd"
480 | },
481 | "mappings": [],
482 | "thresholds": {
483 | "mode": "absolute",
484 | "steps": [
485 | {
486 | "color": "green",
487 | "value": null
488 | },
489 | {
490 | "color": "red",
491 | "value": 80
492 | }
493 | ]
494 | }
495 |
496 |
497 | },
498 | "overrides": []
499 | },
500 | "gridPos": {
501 | "h": 8,
502 | "w": 9,
503 | "x": 0,
504 | "y": 8
505 | },
506 | "id": 4,
507 | "options": {
508 | "displayMode": "gradient",
509 | "maxVizHeight": 300,
510 | "minVizHeight": 16,
511 | "minVizWidth": 8,
512 | "namePlacement": "auto",
513 | "orientation": "horizontal",
514 | "reduceOptions": {
515 | "calcs": [],
516 | "fields": "",
517 | "values": true
518 | },
519 | "showUnfilled": true,
520 | "sizing": "auto",
521 | "valueMode": "color"
522 | },
523 | "pluginVersion": "11.2.0",
524 | "targets": [
525 | {
526 | "dataset": "DemoDB",
527 |
528 | "datasource": {
529 | "type": "mssql",
530 | "uid": "${DS_MSSQL}"
531 |
532 | },
533 | "editorMode": "code",
534 | "format": "table",
535 | "rawQuery": true,
536 | "rawSql": "SELECT TOP 10\n qs.total_elapsed_time / qs.execution_count / 1000.0 AS avg_duration_ms,\n qs.execution_count,\n SUBSTRING(qt.text, qs.statement_start_offset/2,\n (CASE\n WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2\n ELSE qs.statement_end_offset\n END - qs.statement_start_offset)/2) AS query_text\nFROM sys.dm_exec_query_stats qs\nCROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) qt\nORDER BY avg_duration_ms DESC;\n",
537 | "refId": "A",
538 | "sql": {
539 | "columns": [
540 | {
541 | "parameters": [],
542 | "type": "function"
543 | }
544 | ],
545 | "groupBy": [
546 | {
547 | "property": {
548 | "type": "string"
549 | },
550 | "type": "groupBy"
551 | }
552 | ],
553 | "limit": 50
554 | }
555 | }
556 | ],
557 | "title": "Top 10 Longest Running Queries",
558 | "type": "bargauge"
559 | },
560 | {
561 | "datasource": {
562 | "type": "mssql",
563 | "uid": "${DS_MSSQL}"
564 |
565 | },
566 | "fieldConfig": {
567 | "defaults": {
568 | "mappings": [],
569 | "max": 10,
570 | "min": 0,
571 | "thresholds": {
572 | "mode": "percentage",
573 | "steps": [
574 | {
575 | "color": "green",
576 | "value": null
577 | },
578 | {
579 | "color": "orange",
580 | "value": 70
581 | },
582 | {
583 | "color": "red",
584 | "value": 85
585 | }
586 | ]
587 | }
588 |
589 |
590 | },
591 | "overrides": []
592 | },
593 | "gridPos": {
594 | "h": 6,
595 | "w": 10,
596 | "x": 9,
597 | "y": 8
598 | },
599 | "id": 3,
600 | "options": {
601 | "minVizHeight": 75,
602 | "minVizWidth": 75,
603 | "orientation": "auto",
604 | "reduceOptions": {
605 | "calcs": [
606 | "lastNotNull"
607 | ],
608 | "fields": "",
609 | "values": false
610 | },
611 | "showThresholdLabels": false,
612 | "showThresholdMarkers": true,
613 | "sizing": "auto"
614 | },
615 | "pluginVersion": "11.2.0",
616 | "targets": [
617 | {
618 | "dataset": "DemoDB",
619 |
620 | "datasource": {
621 | "type": "mssql",
622 | "uid": "${DS_MSSQL}"
623 |
624 | },
625 | "editorMode": "code",
626 | "format": "table",
627 | "rawQuery": true,
628 | "rawSql": "SELECT \n qs.total_elapsed_time / qs.execution_count / 1000.0 AS 'Avg Duration ms',\n qs.execution_count AS 'Execution Count',\n SUBSTRING(qt.text, qs.statement_start_offset/2,\n (CASE\n WHEN qs.statement_end_offset = -1 THEN LEN(CONVERT(NVARCHAR(MAX), qt.text)) * 2\n ELSE qs.statement_end_offset\n END - qs.statement_start_offset)/2) AS query_text\nFROM sys.dm_exec_query_stats qs\nCROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) qt\nORDER BY 'Avg Duration ms' DESC;\n",
629 | "refId": "A",
630 | "sql": {
631 | "columns": [
632 | {
633 | "parameters": [],
634 | "type": "function"
635 | }
636 | ],
637 | "groupBy": [
638 | {
639 | "property": {
640 | "type": "string"
641 | },
642 | "type": "groupBy"
643 | }
644 | ],
645 | "limit": 50
646 | }
647 | }
648 | ],
649 | "title": "Queries per Second",
650 | "type": "gauge"
651 | },
652 | {
653 | "datasource": {
654 | "type": "mssql",
655 | "uid": "${DS_MSSQL}"
656 |
657 | },
658 | "fieldConfig": {
659 | "defaults": {
660 | "color": {
661 | "mode": "continuous-GrYlRd"
662 | },
663 | "mappings": [],
664 | "max": 100,
665 | "min": 0,
666 | "thresholds": {
667 | "mode": "absolute",
668 | "steps": [
669 | {
670 | "color": "green",
671 | "value": null
672 | },
673 | {
674 | "color": "red",
675 | "value": 80
676 | }
677 | ]
678 | }
679 |
680 |
681 | },
682 | "overrides": []
683 | },
684 | "gridPos": {
685 | "h": 6,
686 | "w": 5,
687 | "x": 19,
688 | "y": 8
689 | },
690 | "id": 8,
691 | "options": {
692 | "displayMode": "lcd",
693 | "maxVizHeight": 300,
694 | "minVizHeight": 16,
695 | "minVizWidth": 8,
696 | "namePlacement": "auto",
697 | "orientation": "vertical",
698 | "reduceOptions": {
699 | "calcs": [
700 | "lastNotNull"
701 | ],
702 | "fields": "",
703 | "values": false
704 | },
705 | "showUnfilled": true,
706 | "sizing": "auto",
707 | "valueMode": "color"
708 | },
709 | "pluginVersion": "11.2.0",
710 | "targets": [
711 | {
712 | "dataset": "DemoDB",
713 |
714 | "datasource": {
715 | "type": "mssql",
716 | "uid": "${DS_MSSQL}"
717 |
718 | },
719 | "editorMode": "code",
720 | "format": "table",
721 | "rawQuery": true,
722 | "rawSql": "SELECT \n (CAST(SUM(CASE WHEN usecounts > 0 THEN 1 ELSE 0 END) AS FLOAT) / COUNT(*)) * 100 AS Cache_Hit_Ratio\nFROM sys.dm_exec_cached_plans\nWHERE objtype = 'Adhoc'\n OR objtype = 'Prepared';\n",
723 | "refId": "A",
724 | "sql": {
725 | "columns": [
726 | {
727 | "parameters": [],
728 | "type": "function"
729 | }
730 | ],
731 | "groupBy": [
732 | {
733 | "property": {
734 | "type": "string"
735 | },
736 | "type": "groupBy"
737 | }
738 | ],
739 | "limit": 50
740 | }
741 | }
742 | ],
743 | "title": "Query Cache Hit Rate",
744 | "type": "bargauge"
745 | },
746 | {
747 | "datasource": {
748 | "type": "mssql",
749 | "uid": "${DS_MSSQL}"
750 |
751 | },
752 | "fieldConfig": {
753 | "defaults": {
754 | "mappings": [],
755 | "max": 100000000000,
756 | "thresholds": {
757 | "mode": "percentage",
758 | "steps": [
759 | {
760 | "color": "green",
761 | "value": null
762 | },
763 | {
764 | "color": "orange",
765 | "value": 70
766 | },
767 | {
768 | "color": "red",
769 | "value": 85
770 | }
771 | ]
772 | }
773 |
774 |
775 | },
776 | "overrides": []
777 | },
778 | "gridPos": {
779 | "h": 6,
780 | "w": 10,
781 | "x": 9,
782 | "y": 14
783 | },
784 | "id": 26,
785 | "options": {
786 | "minVizHeight": 75,
787 | "minVizWidth": 75,
788 | "orientation": "auto",
789 | "reduceOptions": {
790 | "calcs": [
791 | "lastNotNull"
792 | ],
793 | "fields": "",
794 | "values": false
795 | },
796 | "showThresholdLabels": false,
797 | "showThresholdMarkers": true,
798 | "sizing": "auto"
799 | },
800 | "pluginVersion": "11.2.0",
801 | "targets": [
802 | {
803 | "dataset": "DemoDB",
804 |
805 | "datasource": {
806 | "type": "mssql",
807 | "uid": "${DS_MSSQL}"
808 |
809 | },
810 | "editorMode": "code",
811 | "format": "table",
812 | "rawQuery": true,
813 | "rawSql": "DBCC SQLPERF (WAITSTATS);\n",
814 | "refId": "A",
815 | "sql": {
816 | "columns": [
817 | {
818 | "parameters": [],
819 | "type": "function"
820 | }
821 | ],
822 | "groupBy": [
823 | {
824 | "property": {
825 | "type": "string"
826 | },
827 | "type": "groupBy"
828 | }
829 | ],
830 | "limit": 50
831 | }
832 | }
833 | ],
834 | "title": "Wait Stats Overview",
835 | "type": "gauge"
836 | },
837 | {
838 | "datasource": {
839 | "type": "mssql",
840 | "uid": "${DS_MSSQL}"
841 |
842 | },
843 | "fieldConfig": {
844 | "defaults": {
845 | "mappings": [],
846 | "max": 70,
847 | "min": 0,
848 | "thresholds": {
849 | "mode": "percentage",
850 | "steps": [
851 | {
852 | "color": "green",
853 | "value": null
854 | },
855 | {
856 | "color": "orange",
857 | "value": 70
858 | },
859 | {
860 | "color": "red",
861 | "value": 85
862 | }
863 | ]
864 | }
865 |
866 |
867 | },
868 | "overrides": []
869 | },
870 | "gridPos": {
871 | "h": 6,
872 | "w": 5,
873 | "x": 19,
874 | "y": 14
875 | },
876 | "id": 1,
877 | "options": {
878 | "minVizHeight": 75,
879 | "minVizWidth": 75,
880 | "orientation": "auto",
881 | "reduceOptions": {
882 | "calcs": [
883 | "lastNotNull"
884 | ],
885 | "fields": "",
886 | "values": false
887 | },
888 | "showThresholdLabels": false,
889 | "showThresholdMarkers": true,
890 | "sizing": "auto"
891 | },
892 | "pluginVersion": "11.2.0",
893 | "targets": [
894 | {
895 | "dataset": "DemoDB",
896 |
897 | "datasource": {
898 | "type": "mssql",
899 | "uid": "${DS_MSSQL}"
900 |
901 | },
902 | "editorMode": "code",
903 | "format": "table",
904 | "rawQuery": true,
905 | "rawSql": "SELECT COUNT(session_id) AS Connections\nFROM sys.dm_exec_sessions\nWHERE is_user_process = 1;\n",
906 | "refId": "A",
907 | "sql": {
908 | "columns": [
909 | {
910 | "parameters": [],
911 | "type": "function"
912 | }
913 | ],
914 | "groupBy": [
915 | {
916 | "property": {
917 | "type": "string"
918 | },
919 | "type": "groupBy"
920 | }
921 | ],
922 | "limit": 50
923 | }
924 | }
925 | ],
926 | "title": "Current Connections",
927 | "type": "gauge"
928 | },
929 | {
930 | "datasource": {
931 | "type": "mssql",
932 | "uid": "${DS_MSSQL}"
933 |
934 | },
935 | "fieldConfig": {
936 | "defaults": {
937 | "color": {
938 | "mode": "palette-classic"
939 | },
940 | "mappings": [],
941 | "max": 100000,
942 | "thresholds": {
943 | "mode": "absolute",
944 | "steps": [
945 | {
946 | "color": "green",
947 | "value": null
948 | },
949 | {
950 | "color": "red",
951 | "value": 80
952 | }
953 | ]
954 | }
955 |
956 |
957 | },
958 | "overrides": []
959 | },
960 | "gridPos": {
961 | "h": 4,
962 | "w": 9,
963 | "x": 0,
964 | "y": 16
965 | },
966 | "id": 32,
967 | "options": {
968 | "displayMode": "lcd",
969 | "maxVizHeight": 300,
970 | "minVizHeight": 16,
971 | "minVizWidth": 8,
972 | "namePlacement": "auto",
973 | "orientation": "horizontal",
974 | "reduceOptions": {
975 | "calcs": [
976 | "lastNotNull"
977 | ],
978 | "fields": "",
979 | "values": false
980 | },
981 | "showUnfilled": true,
982 | "sizing": "auto",
983 | "valueMode": "color"
984 | },
985 | "pluginVersion": "11.2.0",
986 | "targets": [
987 | {
988 | "dataset": "_DBA",
989 | "datasource": {
990 | "type": "mssql",
991 | "uid": "${DS_MSSQL}"
992 |
993 | },
994 | "editorMode": "code",
995 | "format": "table",
996 | "rawQuery": true,
997 | "rawSql": "SELECT cacheobjtype AS CacheObjectType,\n objtype AS ObjectType,\n usecounts AS 'Use Count',\n size_in_bytes AS 'Cache Size'\nFROM sys.dm_exec_cached_plans\nWHERE usecounts < 10;\n",
998 | "refId": "A",
999 | "sql": {
1000 | "columns": [
1001 | {
1002 | "parameters": [],
1003 | "type": "function"
1004 | }
1005 | ],
1006 | "groupBy": [
1007 | {
1008 | "property": {
1009 | "type": "string"
1010 | },
1011 | "type": "groupBy"
1012 | }
1013 | ],
1014 | "limit": 50
1015 | }
1016 | }
1017 | ],
1018 | "title": "Query Plan Cache Efficiency",
1019 | "type": "bargauge"
1020 | },
1021 | {
1022 | "datasource": {
1023 | "type": "mssql",
1024 | "uid": "${DS_MSSQL}"
1025 |
1026 | },
1027 | "fieldConfig": {
1028 | "defaults": {
1029 | "color": {
1030 | "mode": "continuous-GrYlRd"
1031 | },
1032 | "custom": {
1033 | "axisBorderShow": false,
1034 | "axisCenteredZero": false,
1035 | "axisColorMode": "text",
1036 | "axisLabel": "",
1037 | "axisPlacement": "auto",
1038 | "barAlignment": 0,
1039 | "barWidthFactor": 0.6,
1040 | "drawStyle": "line",
1041 | "fillOpacity": 20,
1042 | "gradientMode": "scheme",
1043 | "hideFrom": {
1044 | "legend": false,
1045 | "tooltip": false,
1046 | "viz": false
1047 | },
1048 | "insertNulls": false,
1049 | "lineInterpolation": "smooth",
1050 | "lineWidth": 3,
1051 | "pointSize": 5,
1052 | "scaleDistribution": {
1053 | "type": "linear"
1054 | },
1055 | "showPoints": "auto",
1056 | "spanNulls": false,
1057 | "stacking": {
1058 | "group": "A",
1059 | "mode": "none"
1060 | },
1061 | "thresholdsStyle": {
1062 | "mode": "off"
1063 | }
1064 | },
1065 | "mappings": [],
1066 | "thresholds": {
1067 | "mode": "absolute",
1068 | "steps": [
1069 | {
1070 | "color": "green",
1071 | "value": null
1072 | },
1073 | {
1074 | "color": "red",
1075 | "value": 80
1076 | }
1077 | ]
1078 | }
1079 |
1080 |
1081 | },
1082 | "overrides": []
1083 | },
1084 | "gridPos": {
1085 | "h": 8,
1086 | "w": 13,
1087 | "x": 0,
1088 | "y": 20
1089 | },
1090 | "id": 37,
1091 | "options": {
1092 | "legend": {
1093 | "calcs": [],
1094 | "displayMode": "hidden",
1095 | "placement": "right",
1096 | "showLegend": false
1097 | },
1098 | "tooltip": {
1099 | "mode": "single",
1100 | "sort": "none"
1101 | }
1102 | },
1103 | "targets": [
1104 | {
1105 | "dataset": "_DBA",
1106 | "datasource": {
1107 | "type": "mssql",
1108 | "uid": "${DS_MSSQL}"
1109 |
1110 | },
1111 | "editorMode": "code",
1112 | "format": "table",
1113 | "rawQuery": true,
1114 | "rawSql": "SELECT TOP 10\n creation_time AS CreationTime,\n total_logical_reads AS LogicalReads\nFROM sys.dm_exec_query_stats\nORDER BY total_elapsed_time DESC;\n",
1115 | "refId": "A",
1116 | "sql": {
1117 | "columns": [
1118 | {
1119 | "parameters": [],
1120 | "type": "function"
1121 | }
1122 | ],
1123 | "groupBy": [
1124 | {
1125 | "property": {
1126 | "type": "string"
1127 | },
1128 | "type": "groupBy"
1129 | }
1130 | ],
1131 | "limit": 50
1132 | }
1133 | }
1134 | ],
1135 | "title": "Query Latency",
1136 | "type": "timeseries"
1137 | },
1138 | {
1139 | "datasource": {
1140 | "type": "mssql",
1141 | "uid": "${DS_MSSQL}"
1142 |
1143 | },
1144 | "fieldConfig": {
1145 | "defaults": {
1146 | "color": {
1147 | "mode": "continuous-GrYlRd"
1148 | },
1149 | "mappings": [],
1150 | "thresholds": {
1151 | "mode": "absolute",
1152 | "steps": [
1153 | {
1154 | "color": "green",
1155 | "value": null
1156 | },
1157 | {
1158 | "color": "red",
1159 | "value": 80
1160 | }
1161 | ]
1162 | }
1163 |
1164 |
1165 | },
1166 | "overrides": []
1167 | },
1168 | "gridPos": {
1169 | "h": 8,
1170 | "w": 11,
1171 | "x": 13,
1172 | "y": 20
1173 | },
1174 | "id": 39,
1175 | "options": {
1176 | "displayMode": "gradient",
1177 | "maxVizHeight": 300,
1178 | "minVizHeight": 16,
1179 | "minVizWidth": 8,
1180 | "namePlacement": "auto",
1181 | "orientation": "horizontal",
1182 | "reduceOptions": {
1183 | "calcs": [],
1184 | "fields": "",
1185 | "values": true
1186 | },
1187 | "showUnfilled": true,
1188 | "sizing": "auto",
1189 | "valueMode": "color"
1190 | },
1191 | "pluginVersion": "11.2.0",
1192 | "targets": [
1193 | {
1194 | "dataset": "_DBA",
1195 | "datasource": {
1196 | "type": "mssql",
1197 | "uid": "${DS_MSSQL}"
1198 |
1199 | },
1200 | "editorMode": "code",
1201 | "format": "table",
1202 | "rawQuery": true,
1203 | "rawSql": "SELECT TOP 10\n st.text AS QueryText,\n qs.total_worker_time AS CPUTime,\n qs.total_elapsed_time AS TotalTime,\n qs.total_logical_reads AS LogicalReads\nFROM sys.dm_exec_query_stats qs\nCROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) st\nORDER BY qs.total_worker_time DESC;\n",
1204 | "refId": "A",
1205 | "sql": {
1206 | "columns": [
1207 | {
1208 | "parameters": [],
1209 | "type": "function"
1210 | }
1211 | ],
1212 | "groupBy": [
1213 | {
1214 | "property": {
1215 | "type": "string"
1216 | },
1217 | "type": "groupBy"
1218 | }
1219 | ],
1220 | "limit": 50
1221 | }
1222 | }
1223 | ],
1224 | "title": "Execution Plans Performance",
1225 | "type": "bargauge"
1226 | },
1227 | {
1228 | "collapsed": false,
1229 | "gridPos": {
1230 | "h": 1,
1231 | "w": 24,
1232 | "x": 0,
1233 | "y": 28
1234 | },
1235 | "id": 19,
1236 | "panels": [],
1237 | "title": "Server Performance",
1238 | "type": "row"
1239 | },
1240 | {
1241 | "datasource": {
1242 | "type": "mssql",
1243 | "uid": "${DS_MSSQL}"
1244 |
1245 | },
1246 | "fieldConfig": {
1247 | "defaults": {
1248 | "mappings": [],
1249 | "thresholds": {
1250 | "mode": "absolute",
1251 | "steps": [
1252 | {
1253 | "color": "green",
1254 | "value": null
1255 | },
1256 | {
1257 | "color": "red",
1258 | "value": 80
1259 | }
1260 | ]
1261 | },
1262 | "unit": "short"
1263 |
1264 | },
1265 | "overrides": []
1266 | },
1267 | "gridPos": {
1268 | "h": 4,
1269 | "w": 8,
1270 | "x": 0,
1271 | "y": 29
1272 | },
1273 | "id": 38,
1274 | "options": {
1275 | "colorMode": "background",
1276 | "graphMode": "none",
1277 | "justifyMode": "auto",
1278 | "orientation": "auto",
1279 | "percentChangeColorMode": "standard",
1280 | "reduceOptions": {
1281 | "calcs": [
1282 | "lastNotNull"
1283 | ],
1284 | "fields": "",
1285 | "values": false
1286 | },
1287 | "showPercentChange": false,
1288 | "textMode": "auto",
1289 | "wideLayout": true
1290 | },
1291 | "pluginVersion": "11.2.0",
1292 | "targets": [
1293 | {
1294 | "dataset": "_DBA",
1295 | "datasource": {
1296 | "type": "mssql",
1297 | "uid": "${DS_MSSQL}"
1298 |
1299 | },
1300 | "editorMode": "code",
1301 | "format": "table",
1302 | "rawQuery": true,
1303 | "rawSql": "SELECT TOP 10\n creation_time AS CreationTime,\n total_elapsed_time/1000 AS TotalElapsedTimeMS,\n execution_count AS ExecutionCount,\n total_worker_time/1000 AS CPUTimeMS\nFROM sys.dm_exec_query_stats\nORDER BY total_elapsed_time DESC;\n",
1304 | "refId": "A",
1305 | "sql": {
1306 | "columns": [
1307 | {
1308 | "parameters": [],
1309 | "type": "function"
1310 | }
1311 | ],
1312 | "groupBy": [
1313 | {
1314 | "property": {
1315 | "type": "string"
1316 | },
1317 | "type": "groupBy"
1318 | }
1319 | ],
1320 | "limit": 50
1321 | }
1322 | }
1323 | ],
1324 | "title": "Query Latency",
1325 | "type": "stat"
1326 | },
1327 | {
1328 | "datasource": {
1329 | "type": "mssql",
1330 | "uid": "${DS_MSSQL}"
1331 |
1332 | },
1333 | "fieldConfig": {
1334 | "defaults": {
1335 | "color": {
1336 | "mode": "continuous-BlYlRd"
1337 | },
1338 | "mappings": [],
1339 | "thresholds": {
1340 | "mode": "absolute",
1341 | "steps": [
1342 | {
1343 | "color": "green",
1344 | "value": null
1345 | },
1346 | {
1347 | "color": "red",
1348 | "value": 80.0002
1349 | }
1350 | ]
1351 | }
1352 |
1353 |
1354 | },
1355 | "overrides": []
1356 | },
1357 | "gridPos": {
1358 | "h": 2,
1359 | "w": 3,
1360 | "x": 8,
1361 | "y": 29
1362 | },
1363 | "id": 6,
1364 | "options": {
1365 | "displayMode": "lcd",
1366 | "maxVizHeight": 300,
1367 | "minVizHeight": 16,
1368 | "minVizWidth": 8,
1369 | "namePlacement": "auto",
1370 | "orientation": "horizontal",
1371 | "reduceOptions": {
1372 | "calcs": [
1373 | "lastNotNull"
1374 | ],
1375 | "fields": "",
1376 | "values": false
1377 | },
1378 | "showUnfilled": true,
1379 | "sizing": "auto",
1380 | "valueMode": "color"
1381 | },
1382 | "pluginVersion": "11.2.0",
1383 | "targets": [
1384 | {
1385 | "dataset": "DemoDB",
1386 |
1387 | "datasource": {
1388 | "type": "mssql",
1389 | "uid": "${DS_MSSQL}"
1390 |
1391 | },
1392 | "editorMode": "code",
1393 | "format": "table",
1394 | "rawQuery": true,
1395 | "rawSql": "SELECT COUNT(*) AS Running_Threads\nFROM sys.dm_exec_requests\nWHERE status = 'running';\n",
1396 | "refId": "A",
1397 | "sql": {
1398 | "columns": [
1399 | {
1400 | "parameters": [],
1401 | "type": "function"
1402 | }
1403 | ],
1404 | "groupBy": [
1405 | {
1406 | "property": {
1407 | "type": "string"
1408 | },
1409 | "type": "groupBy"
1410 | }
1411 | ],
1412 | "limit": 50
1413 | }
1414 | }
1415 | ],
1416 | "title": "Running Threads",
1417 | "type": "bargauge"
1418 | },
1419 | {
1420 | "datasource": {
1421 | "type": "mssql",
1422 | "uid": "${DS_MSSQL}"
1423 |
1424 | },
1425 | "fieldConfig": {
1426 | "defaults": {
1427 | "color": {
1428 | "mode": "palette-classic"
1429 | },
1430 | "custom": {
1431 | "axisBorderShow": false,
1432 | "axisCenteredZero": false,
1433 | "axisColorMode": "text",
1434 | "axisLabel": "",
1435 | "axisPlacement": "auto",
1436 | "fillOpacity": 49,
1437 | "gradientMode": "none",
1438 | "hideFrom": {
1439 | "legend": false,
1440 | "tooltip": false,
1441 | "viz": false
1442 | },
1443 | "lineWidth": 2,
1444 | "scaleDistribution": {
1445 | "type": "linear"
1446 | },
1447 | "thresholdsStyle": {
1448 | "mode": "off"
1449 | }
1450 | },
1451 | "mappings": [],
1452 | "thresholds": {
1453 | "mode": "absolute",
1454 | "steps": [
1455 | {
1456 | "color": "green",
1457 | "value": null
1458 | },
1459 | {
1460 | "color": "red",
1461 | "value": 80
1462 | }
1463 | ]
1464 | },
1465 | "unit": "short"
1466 |
1467 | },
1468 | "overrides": []
1469 | },
1470 | "gridPos": {
1471 | "h": 15,
1472 | "w": 13,
1473 | "x": 11,
1474 | "y": 29
1475 | },
1476 | "id": 9,
1477 | "options": {
1478 | "barRadius": 0,
1479 | "barWidth": 0.9,
1480 | "fullHighlight": false,
1481 | "groupWidth": 0.7,
1482 | "legend": {
1483 | "calcs": [],
1484 | "displayMode": "list",
1485 | "placement": "bottom",
1486 | "showLegend": true
1487 | },
1488 | "orientation": "horizontal",
1489 | "showValue": "auto",
1490 | "stacking": "normal",
1491 | "tooltip": {
1492 | "mode": "single",
1493 | "sort": "none"
1494 | },
1495 | "xTickLabelRotation": 0,
1496 | "xTickLabelSpacing": 100
1497 | },
1498 | "targets": [
1499 | {
1500 | "dataset": "DemoDB",
1501 |
1502 | "datasource": {
1503 | "type": "mssql",
1504 | "uid": "${DS_MSSQL}"
1505 |
1506 | },
1507 | "editorMode": "code",
1508 | "format": "table",
1509 | "rawQuery": true,
1510 | "rawSql": "SELECT \n request_session_id AS SessionID,\n resource_database_id AS DatabaseID,\n resource_associated_entity_id AS EntityID,\n request_mode AS LockType,\n request_status AS Status\nFROM sys.dm_tran_locks;\n",
1511 | "refId": "A",
1512 | "sql": {
1513 | "columns": [
1514 | {
1515 | "parameters": [],
1516 | "type": "function"
1517 | }
1518 | ],
1519 | "groupBy": [
1520 | {
1521 | "property": {
1522 | "type": "string"
1523 | },
1524 | "type": "groupBy"
1525 | }
1526 | ],
1527 | "limit": 50
1528 | }
1529 | }
1530 | ],
1531 | "title": "Table Locks",
1532 | "type": "barchart"
1533 | },
1534 | {
1535 | "datasource": {
1536 | "type": "mssql",
1537 | "uid": "${DS_MSSQL}"
1538 |
1539 | },
1540 | "fieldConfig": {
1541 | "defaults": {
1542 | "color": {
1543 | "mode": "continuous-BlYlRd"
1544 | },
1545 | "mappings": [],
1546 | "thresholds": {
1547 | "mode": "absolute",
1548 | "steps": [
1549 | {
1550 | "color": "green",
1551 | "value": null
1552 | },
1553 | {
1554 | "color": "red",
1555 | "value": 80
1556 | }
1557 | ]
1558 | }
1559 |
1560 |
1561 | },
1562 | "overrides": []
1563 | },
1564 | "gridPos": {
1565 | "h": 2,
1566 | "w": 3,
1567 | "x": 8,
1568 | "y": 31
1569 | },
1570 | "id": 12,
1571 | "options": {
1572 | "displayMode": "lcd",
1573 | "maxVizHeight": 300,
1574 | "minVizHeight": 16,
1575 | "minVizWidth": 8,
1576 | "namePlacement": "auto",
1577 | "orientation": "horizontal",
1578 | "reduceOptions": {
1579 | "calcs": [
1580 | "lastNotNull"
1581 | ],
1582 | "fields": "",
1583 | "values": false
1584 | },
1585 | "showUnfilled": true,
1586 | "sizing": "auto",
1587 | "valueMode": "color"
1588 | },
1589 | "pluginVersion": "11.2.0",
1590 | "targets": [
1591 | {
1592 | "dataset": "DemoDB",
1593 |
1594 | "datasource": {
1595 | "type": "mssql",
1596 | "uid": "${DS_MSSQL}"
1597 |
1598 | },
1599 | "editorMode": "code",
1600 | "format": "table",
1601 | "rawQuery": true,
1602 | "rawSql": "SELECT \n COUNT(*) AS OpenFiles\nFROM sys.dm_io_pending_io_requests;\n",
1603 | "refId": "A",
1604 | "sql": {
1605 | "columns": [
1606 | {
1607 | "parameters": [],
1608 | "type": "function"
1609 | }
1610 | ],
1611 | "groupBy": [
1612 | {
1613 | "property": {
1614 | "type": "string"
1615 | },
1616 | "type": "groupBy"
1617 | }
1618 | ],
1619 | "limit": 50
1620 | }
1621 | }
1622 | ],
1623 | "title": "Open Files Limit",
1624 | "type": "bargauge"
1625 | },
1626 | {
1627 | "datasource": {
1628 | "type": "mssql",
1629 | "uid": "${DS_MSSQL}"
1630 |
1631 | },
1632 | "fieldConfig": {
1633 | "defaults": {
1634 | "mappings": [],
1635 | "thresholds": {
1636 | "mode": "percentage",
1637 | "steps": [
1638 | {
1639 | "color": "green",
1640 | "value": null
1641 | },
1642 | {
1643 | "color": "orange",
1644 | "value": 70
1645 | },
1646 | {
1647 | "color": "red",
1648 | "value": 85
1649 | }
1650 | ]
1651 | }
1652 |
1653 |
1654 | },
1655 | "overrides": []
1656 | },
1657 | "gridPos": {
1658 | "h": 6,
1659 | "w": 7,
1660 | "x": 0,
1661 | "y": 33
1662 | },
1663 | "id": 33,
1664 | "options": {
1665 | "minVizHeight": 75,
1666 | "minVizWidth": 75,
1667 | "orientation": "auto",
1668 | "reduceOptions": {
1669 | "calcs": [
1670 | "lastNotNull"
1671 | ],
1672 | "fields": "",
1673 | "values": false
1674 | },
1675 | "showThresholdLabels": false,
1676 | "showThresholdMarkers": true,
1677 | "sizing": "auto"
1678 | },
1679 | "pluginVersion": "11.2.0",
1680 | "targets": [
1681 | {
1682 | "dataset": "_DBA",
1683 | "datasource": {
1684 | "type": "mssql",
1685 | "uid": "${DS_MSSQL}"
1686 |
1687 | },
1688 | "editorMode": "code",
1689 | "format": "table",
1690 | "rawQuery": true,
1691 | "rawSql": "SELECT transaction_id AS TransactionID,\n transaction_begin_time AS BeginTime,\n transaction_state AS State,\n transaction_type AS Type\nFROM sys.dm_tran_active_transactions;\n",
1692 | "refId": "A",
1693 | "sql": {
1694 | "columns": [
1695 | {
1696 | "parameters": [],
1697 | "type": "function"
1698 | }
1699 | ],
1700 | "groupBy": [
1701 | {
1702 | "property": {
1703 | "type": "string"
1704 | },
1705 | "type": "groupBy"
1706 | }
1707 | ],
1708 | "limit": 50
1709 | }
1710 | }
1711 | ],
1712 | "title": "Active Transactions",
1713 | "type": "gauge"
1714 | },
1715 | {
1716 | "datasource": {
1717 | "type": "mssql",
1718 | "uid": "${DS_MSSQL}"
1719 |
1720 | },
1721 | "fieldConfig": {
1722 | "defaults": {
1723 | "color": {
1724 | "mode": "palette-classic"
1725 | },
1726 | "custom": {
1727 | "hideFrom": {
1728 | "legend": false,
1729 | "tooltip": false,
1730 | "viz": false
1731 | }
1732 | },
1733 | "mappings": []
1734 |
1735 | },
1736 | "overrides": []
1737 | },
1738 | "gridPos": {
1739 | "h": 11,
1740 | "w": 4,
1741 | "x": 7,
1742 | "y": 33
1743 | },
1744 | "id": 11,
1745 | "options": {
1746 | "displayLabels": [
1747 | "percent",
1748 | "name"
1749 | ],
1750 | "legend": {
1751 | "calcs": [],
1752 | "displayMode": "hidden",
1753 | "placement": "right",
1754 | "showLegend": false,
1755 | "values": []
1756 | },
1757 | "pieType": "pie",
1758 | "reduceOptions": {
1759 | "calcs": [
1760 | "lastNotNull"
1761 | ],
1762 | "fields": "",
1763 | "values": false
1764 | },
1765 | "tooltip": {
1766 | "mode": "single",
1767 | "sort": "none"
1768 | }
1769 | },
1770 | "targets": [
1771 | {
1772 | "dataset": "DemoDB",
1773 |
1774 | "datasource": {
1775 | "type": "mssql",
1776 | "uid": "${DS_MSSQL}"
1777 |
1778 | },
1779 | "editorMode": "code",
1780 | "format": "table",
1781 | "rawQuery": true,
1782 | "rawSql": "SELECT \n SUM(user_objects_alloc_page_count) AS 'User Object Pages',\n SUM(internal_objects_alloc_page_count) AS 'Internal Object Pages'\nFROM sys.dm_db_session_space_usage;\n",
1783 | "refId": "A",
1784 | "sql": {
1785 | "columns": [
1786 | {
1787 | "parameters": [],
1788 | "type": "function"
1789 | }
1790 | ],
1791 | "groupBy": [
1792 | {
1793 | "property": {
1794 | "type": "string"
1795 | },
1796 | "type": "groupBy"
1797 | }
1798 | ],
1799 | "limit": 50
1800 | }
1801 | }
1802 | ],
1803 | "title": "Temp Tables Created On Disk",
1804 | "type": "piechart"
1805 | },
1806 | {
1807 | "datasource": {
1808 | "type": "mssql",
1809 | "uid": "${DS_MSSQL}"
1810 |
1811 | },
1812 | "fieldConfig": {
1813 | "defaults": {
1814 | "color": {
1815 | "mode": "continuous-GrYlRd"
1816 | },
1817 | "mappings": [],
1818 | "thresholds": {
1819 | "mode": "absolute",
1820 | "steps": [
1821 | {
1822 | "color": "green",
1823 | "value": null
1824 | },
1825 | {
1826 | "color": "red",
1827 | "value": 80
1828 | }
1829 | ]
1830 | }
1831 |
1832 |
1833 | },
1834 | "overrides": []
1835 | },
1836 | "gridPos": {
1837 | "h": 5,
1838 | "w": 7,
1839 | "x": 0,
1840 | "y": 39
1841 | },
1842 | "id": 40,
1843 | "options": {
1844 | "displayMode": "lcd",
1845 | "maxVizHeight": 300,
1846 | "minVizHeight": 16,
1847 | "minVizWidth": 8,
1848 | "namePlacement": "auto",
1849 | "orientation": "horizontal",
1850 | "reduceOptions": {
1851 | "calcs": [
1852 | "lastNotNull"
1853 | ],
1854 | "fields": "",
1855 | "values": false
1856 | },
1857 | "showUnfilled": true,
1858 | "sizing": "auto",
1859 | "valueMode": "color"
1860 | },
1861 | "pluginVersion": "11.2.0",
1862 | "targets": [
1863 | {
1864 | "dataset": "_DBA",
1865 | "datasource": {
1866 | "type": "mssql",
1867 | "uid": "${DS_MSSQL}"
1868 |
1869 | },
1870 | "editorMode": "code",
1871 | "format": "table",
1872 | "rawQuery": true,
1873 | "rawSql": "SELECT wait_type, \n SUM(wait_time_ms) AS WaitTimeMS, \n SUM(waiting_tasks_count) AS TaskCount\nFROM sys.dm_os_wait_stats\nWHERE wait_type NOT IN ('SLEEP_TASK', 'BROKER_TASK_STOP', 'SQLTRACE_BUFFER_FLUSH')\nGROUP BY wait_type\nORDER BY WaitTimeMS DESC;\n",
1874 | "refId": "A",
1875 | "sql": {
1876 | "columns": [
1877 | {
1878 | "parameters": [],
1879 | "type": "function"
1880 | }
1881 | ],
1882 | "groupBy": [
1883 | {
1884 | "property": {
1885 | "type": "string"
1886 | },
1887 | "type": "groupBy"
1888 | }
1889 | ],
1890 | "limit": 50
1891 | }
1892 | }
1893 | ],
1894 | "title": "Wait Times Monitoring",
1895 | "type": "bargauge"
1896 | },
1897 | {
1898 | "collapsed": false,
1899 | "gridPos": {
1900 | "h": 1,
1901 | "w": 24,
1902 | "x": 0,
1903 | "y": 44
1904 | },
1905 | "id": 22,
1906 | "panels": [],
1907 | "title": "Buffer and Index Management",
1908 | "type": "row"
1909 | },
1910 | {
1911 | "datasource": {
1912 | "type": "mssql",
1913 | "uid": "${DS_MSSQL}"
1914 |
1915 | },
1916 | "fieldConfig": {
1917 | "defaults": {
1918 | "color": {
1919 | "mode": "continuous-GrYlRd"
1920 | },
1921 | "mappings": [],
1922 | "thresholds": {
1923 | "mode": "absolute",
1924 | "steps": [
1925 | {
1926 | "color": "green",
1927 | "value": null
1928 | },
1929 | {
1930 | "color": "red",
1931 | "value": 80
1932 | }
1933 | ]
1934 | }
1935 |
1936 |
1937 | },
1938 | "overrides": []
1939 | },
1940 | "gridPos": {
1941 | "h": 10,
1942 | "w": 4,
1943 | "x": 0,
1944 | "y": 45
1945 | },
1946 | "id": 13,
1947 | "options": {
1948 | "displayMode": "gradient",
1949 | "maxVizHeight": 300,
1950 | "minVizHeight": 16,
1951 | "minVizWidth": 8,
1952 | "namePlacement": "auto",
1953 | "orientation": "horizontal",
1954 | "reduceOptions": {
1955 | "calcs": [
1956 | "lastNotNull"
1957 | ],
1958 | "fields": "",
1959 | "values": false
1960 | },
1961 | "showUnfilled": true,
1962 | "sizing": "auto",
1963 | "valueMode": "color"
1964 | },
1965 | "pluginVersion": "11.2.0",
1966 | "targets": [
1967 | {
1968 | "dataset": "DemoDB",
1969 |
1970 | "datasource": {
1971 | "type": "mssql",
1972 | "uid": "${DS_MSSQL}"
1973 |
1974 | },
1975 | "editorMode": "code",
1976 | "format": "table",
1977 | "rawQuery": true,
1978 | "rawSql": "SELECT \n CAST(COUNT(*) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Buffer Pool Used MB',\n CAST(SUM(CASE WHEN is_modified = 1 THEN 1 ELSE 0 END) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Dirty Buffer MB',\n CAST(COUNT(*) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Buffer Pool Total MB',\n CAST(SUM(CASE WHEN is_modified = 1 THEN 1 ELSE 0 END) * 8.0 / 1024 AS DECIMAL(10, 2)) AS 'Dirty Buffer Used MB'\nFROM sys.dm_os_buffer_descriptors\nWHERE database_id > 4;\n",
1979 | "refId": "A",
1980 | "sql": {
1981 | "columns": [
1982 | {
1983 | "parameters": [],
1984 | "type": "function"
1985 | }
1986 | ],
1987 | "groupBy": [
1988 | {
1989 | "property": {
1990 | "type": "string"
1991 | },
1992 | "type": "groupBy"
1993 | }
1994 | ],
1995 | "limit": 50
1996 | }
1997 | }
1998 | ],
1999 | "title": "Buffer Pool Hit Rate",
2000 | "type": "bargauge"
2001 | },
2002 | {
2003 | "datasource": {
2004 | "type": "mssql",
2005 | "uid": "${DS_MSSQL}"
2006 |
2007 | },
2008 | "fieldConfig": {
2009 | "defaults": {
2010 | "color": {
2011 | "mode": "palette-classic"
2012 | },
2013 | "custom": {
2014 | "axisBorderShow": false,
2015 | "axisCenteredZero": false,
2016 | "axisColorMode": "text",
2017 | "axisLabel": "",
2018 | "axisPlacement": "auto",
2019 | "fillOpacity": 80,
2020 | "gradientMode": "none",
2021 | "hideFrom": {
2022 | "legend": false,
2023 | "tooltip": false,
2024 | "viz": false
2025 | },
2026 | "lineWidth": 1,
2027 | "scaleDistribution": {
2028 | "type": "linear"
2029 | },
2030 | "thresholdsStyle": {
2031 | "mode": "off"
2032 | }
2033 | },
2034 | "mappings": [],
2035 | "thresholds": {
2036 | "mode": "absolute",
2037 | "steps": [
2038 | {
2039 | "color": "green",
2040 | "value": null
2041 | },
2042 | {
2043 | "color": "red",
2044 | "value": 80
2045 | }
2046 | ]
2047 | },
2048 | "unit": "short"
2049 |
2050 | },
2051 | "overrides": []
2052 | },
2053 | "gridPos": {
2054 | "h": 10,
2055 | "w": 4,
2056 | "x": 4,
2057 | "y": 45
2058 | },
2059 | "id": 7,
2060 | "options": {
2061 | "barRadius": 0,
2062 | "barWidth": 0.97,
2063 | "fullHighlight": false,
2064 | "groupWidth": 0.7,
2065 | "legend": {
2066 | "calcs": [],
2067 | "displayMode": "list",
2068 | "placement": "bottom",
2069 | "showLegend": true
2070 | },
2071 | "orientation": "auto",
2072 | "showValue": "never",
2073 | "stacking": "none",
2074 | "tooltip": {
2075 | "mode": "single",
2076 | "sort": "none"
2077 | },
2078 | "xTickLabelRotation": 0,
2079 | "xTickLabelSpacing": 0
2080 | },
2081 | "pluginVersion": "10.3.1",
2082 | "targets": [
2083 | {
2084 | "dataset": "DemoDB",
2085 |
2086 | "datasource": {
2087 | "type": "mssql",
2088 | "uid": "${DS_MSSQL}"
2089 |
2090 | },
2091 | "editorMode": "code",
2092 | "format": "table",
2093 | "rawQuery": true,
2094 | "rawSql": "SELECT \n (total_physical_memory_kb / 1024) AS 'Total Physical Memory MB',\n (available_physical_memory_kb / 1024) AS 'Available Physical Memory MB',\n (total_page_file_kb / 1024) AS 'Total Page File MB',\n (available_page_file_kb / 1024) AS 'Available Page File MB',\n (system_memory_state_desc) AS 'System Memory State Description'\nFROM sys.dm_os_sys_memory;\n",
2095 | "refId": "A",
2096 | "sql": {
2097 | "columns": [
2098 | {
2099 | "parameters": [],
2100 | "type": "function"
2101 | }
2102 | ],
2103 | "groupBy": [
2104 | {
2105 | "property": {
2106 | "type": "string"
2107 | },
2108 | "type": "groupBy"
2109 | }
2110 | ],
2111 | "limit": 50
2112 | }
2113 | }
2114 | ],
2115 | "title": "Buffer Pool Usage",
2116 | "type": "barchart"
2117 | },
2118 | {
2119 | "datasource": {
2120 | "type": "mssql",
2121 | "uid": "${DS_MSSQL}"
2122 |
2123 | },
2124 | "fieldConfig": {
2125 | "defaults": {
2126 | "color": {
2127 | "mode": "palette-classic"
2128 | },
2129 | "custom": {
2130 | "axisBorderShow": false,
2131 | "axisCenteredZero": false,
2132 | "axisColorMode": "text",
2133 | "axisLabel": "",
2134 | "axisPlacement": "auto",
2135 | "fillOpacity": 80,
2136 | "gradientMode": "none",
2137 | "hideFrom": {
2138 | "legend": false,
2139 | "tooltip": false,
2140 | "viz": false
2141 | },
2142 | "lineWidth": 1,
2143 | "scaleDistribution": {
2144 | "log": 2,
2145 | "type": "log"
2146 | },
2147 | "thresholdsStyle": {
2148 | "mode": "off"
2149 | }
2150 | },
2151 | "mappings": [],
2152 | "thresholds": {
2153 | "mode": "absolute",
2154 | "steps": [
2155 | {
2156 | "color": "green",
2157 | "value": null
2158 | },
2159 | {
2160 | "color": "red",
2161 | "value": 80
2162 | }
2163 | ]
2164 | },
2165 | "unit": "short"
2166 |
2167 | },
2168 | "overrides": []
2169 | },
2170 | "gridPos": {
2171 | "h": 10,
2172 | "w": 13,
2173 | "x": 8,
2174 | "y": 45
2175 | },
2176 | "id": 14,
2177 | "options": {
2178 | "barRadius": 0,
2179 | "barWidth": 1,
2180 | "fullHighlight": false,
2181 | "groupWidth": 0.36,
2182 | "legend": {
2183 | "calcs": [],
2184 | "displayMode": "list",
2185 | "placement": "right",
2186 | "showLegend": true
2187 | },
2188 | "orientation": "auto",
2189 | "showValue": "auto",
2190 | "stacking": "none",
2191 | "tooltip": {
2192 | "mode": "single",
2193 | "sort": "none"
2194 | },
2195 | "xTickLabelRotation": -45,
2196 | "xTickLabelSpacing": 0
2197 | },
2198 | "targets": [
2199 | {
2200 | "dataset": "DemoDB",
2201 |
2202 | "datasource": {
2203 | "type": "mssql",
2204 | "uid": "${DS_MSSQL}"
2205 |
2206 | },
2207 | "editorMode": "code",
2208 | "format": "table",
2209 | "rawQuery": true,
2210 | "rawSql": "SELECT \n OBJECT_NAME(s.object_id) AS TableName,\n i.name AS IndexName,\n s.user_seeks,\n s.user_scans,\n s.user_lookups,\n s.user_updates\nFROM sys.dm_db_index_usage_stats AS s\nINNER JOIN sys.indexes AS i ON i.object_id = s.object_id AND i.index_id = s.index_id\nWHERE s.database_id = DB_ID(DB_NAME())\nORDER BY s.user_seeks DESC;\n",
2211 | "refId": "A",
2212 | "sql": {
2213 | "columns": [
2214 | {
2215 | "parameters": [],
2216 | "type": "function"
2217 | }
2218 | ],
2219 | "groupBy": [
2220 | {
2221 | "property": {
2222 | "type": "string"
2223 | },
2224 | "type": "groupBy"
2225 | }
2226 | ],
2227 | "limit": 50
2228 | }
2229 | }
2230 | ],
2231 | "title": "Index Usage",
2232 | "type": "barchart"
2233 | },
2234 | {
2235 | "datasource": {
2236 | "type": "mssql",
2237 | "uid": "${DS_MSSQL}"
2238 |
2239 | },
2240 | "fieldConfig": {
2241 | "defaults": {
2242 | "fieldMinMax": true,
2243 | "mappings": [],
2244 | "max": 600,
2245 | "min": 0,
2246 | "thresholds": {
2247 | "mode": "percentage",
2248 | "steps": [
2249 | {
2250 | "color": "green",
2251 | "value": null
2252 | },
2253 | {
2254 | "color": "orange",
2255 | "value": 70
2256 | },
2257 | {
2258 | "color": "red",
2259 | "value": 85
2260 | }
2261 | ]
2262 | }
2263 |
2264 |
2265 | },
2266 | "overrides": []
2267 | },
2268 | "gridPos": {
2269 | "h": 10,
2270 | "w": 3,
2271 | "x": 21,
2272 | "y": 45
2273 | },
2274 | "id": 35,
2275 | "options": {
2276 | "minVizHeight": 75,
2277 | "minVizWidth": 75,
2278 | "orientation": "auto",
2279 | "reduceOptions": {
2280 | "calcs": [],
2281 | "fields": "",
2282 | "values": true
2283 | },
2284 | "showThresholdLabels": false,
2285 | "showThresholdMarkers": true,
2286 | "sizing": "auto",
2287 | "text": {
2288 | "titleSize": 1
2289 | }
2290 | },
2291 | "pluginVersion": "11.2.0",
2292 | "targets": [
2293 | {
2294 | "dataset": "_DBA",
2295 | "datasource": {
2296 | "type": "mssql",
2297 | "uid": "${DS_MSSQL}"
2298 |
2299 | },
2300 | "editorMode": "code",
2301 | "format": "table",
2302 | "rawQuery": true,
2303 | "rawSql": "SELECT [object_name], [counter_name], [cntr_value] AS PageLifeExpectancy\nFROM sys.dm_os_performance_counters\nWHERE [object_name] LIKE '%Buffer Manager%'\nAND [counter_name] = 'Page life expectancy';\n",
2304 | "refId": "A",
2305 | "sql": {
2306 | "columns": [
2307 | {
2308 | "parameters": [],
2309 | "type": "function"
2310 | }
2311 | ],
2312 | "groupBy": [
2313 | {
2314 | "property": {
2315 | "type": "string"
2316 | },
2317 | "type": "groupBy"
2318 | }
2319 | ],
2320 | "limit": 50
2321 | }
2322 | }
2323 | ],
2324 | "title": "Page Life Expectancy",
2325 | "type": "gauge"
2326 | },
2327 | {
2328 | "collapsed": false,
2329 | "gridPos": {
2330 | "h": 1,
2331 | "w": 24,
2332 | "x": 0,
2333 | "y": 55
2334 | },
2335 | "id": 21,
2336 | "panels": [],
2337 | "title": "Database Space Usage",
2338 | "type": "row"
2339 | },
2340 | {
2341 | "datasource": {
2342 | "type": "mssql",
2343 | "uid": "${DS_MSSQL}"
2344 |
2345 | },
2346 | "description": "modify the max with the size of your disk associated with the database",
2347 | "fieldConfig": {
2348 | "defaults": {
2349 | "color": {
2350 | "mode": "continuous-GrYlRd"
2351 | },
2352 | "mappings": [],
2353 | "max": 500000,
2354 | "min": 0,
2355 | "thresholds": {
2356 | "mode": "absolute",
2357 | "steps": [
2358 | {
2359 | "color": "green",
2360 | "value": null
2361 | },
2362 | {
2363 | "color": "red",
2364 | "value": 80
2365 | }
2366 | ]
2367 | },
2368 | "unit": "decmbytes"
2369 |
2370 | },
2371 | "overrides": []
2372 | },
2373 | "gridPos": {
2374 | "h": 5,
2375 | "w": 3,
2376 | "x": 0,
2377 | "y": 56
2378 | },
2379 | "id": 16,
2380 | "options": {
2381 | "displayMode": "lcd",
2382 | "maxVizHeight": 300,
2383 | "minVizHeight": 16,
2384 | "minVizWidth": 8,
2385 | "namePlacement": "auto",
2386 | "orientation": "vertical",
2387 | "reduceOptions": {
2388 | "calcs": [
2389 | "lastNotNull"
2390 | ],
2391 | "fields": "/^TotalSpaceMB$/",
2392 | "values": false
2393 | },
2394 | "showUnfilled": true,
2395 | "sizing": "auto",
2396 | "valueMode": "color"
2397 | },
2398 | "pluginVersion": "11.2.0",
2399 | "targets": [
2400 | {
2401 | "dataset": "DemoDB",
2402 |
2403 | "datasource": {
2404 | "type": "mssql",
2405 | "uid": "${DS_MSSQL}"
2406 |
2407 | },
2408 | "editorMode": "code",
2409 | "format": "table",
2410 | "rawQuery": true,
2411 | "rawSql": "SELECT \n ISNULL(t.NAME, 'Total') AS TableName,\n ISNULL(s.NAME, '') AS SchemaName,\n CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.0), 2) AS DECIMAL(18, 2)) AS TotalSpaceMB\nFROM \n sys.tables t\nINNER JOIN \n sys.indexes i ON t.OBJECT_ID = i.object_id\nINNER JOIN \n sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id\nINNER JOIN \n sys.allocation_units a ON p.partition_id = a.container_id\nINNER JOIN \n sys.schemas s ON t.schema_id = s.schema_id\nGROUP BY \n ROLLUP(t.Name, s.Name)\nORDER BY \n CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END,\n TotalSpaceMB DESC;\n",
2412 | "refId": "A",
2413 | "sql": {
2414 | "columns": [
2415 | {
2416 | "parameters": [],
2417 | "type": "function"
2418 | }
2419 | ],
2420 | "groupBy": [
2421 | {
2422 | "property": {
2423 | "type": "string"
2424 | },
2425 | "type": "groupBy"
2426 | }
2427 | ],
2428 | "limit": 50
2429 | }
2430 | }
2431 | ],
2432 | "title": "Total Space MB",
2433 | "type": "bargauge"
2434 | },
2435 | {
2436 | "datasource": {
2437 | "type": "mssql",
2438 | "uid": "${DS_MSSQL}"
2439 |
2440 | },
2441 | "description": "modify the max with the size of your disk associated with the database",
2442 | "fieldConfig": {
2443 | "defaults": {
2444 | "color": {
2445 | "mode": "continuous-GrYlRd"
2446 | },
2447 | "mappings": [],
2448 | "max": 500000,
2449 | "min": 0,
2450 | "thresholds": {
2451 | "mode": "absolute",
2452 | "steps": [
2453 | {
2454 | "color": "green",
2455 | "value": null
2456 | },
2457 | {
2458 | "color": "red",
2459 | "value": 80
2460 | }
2461 | ]
2462 | },
2463 | "unit": "decmbytes"
2464 |
2465 | },
2466 | "overrides": []
2467 | },
2468 | "gridPos": {
2469 | "h": 5,
2470 | "w": 3,
2471 | "x": 3,
2472 | "y": 56
2473 | },
2474 | "id": 17,
2475 | "options": {
2476 | "displayMode": "lcd",
2477 | "maxVizHeight": 300,
2478 | "minVizHeight": 16,
2479 | "minVizWidth": 8,
2480 | "namePlacement": "auto",
2481 | "orientation": "vertical",
2482 | "reduceOptions": {
2483 | "calcs": [
2484 | "lastNotNull"
2485 | ],
2486 | "fields": "",
2487 | "values": false
2488 | },
2489 | "showUnfilled": true,
2490 | "sizing": "auto",
2491 | "valueMode": "color"
2492 | },
2493 | "pluginVersion": "11.2.0",
2494 | "targets": [
2495 | {
2496 | "dataset": "DemoDB",
2497 |
2498 | "datasource": {
2499 | "type": "mssql",
2500 | "uid": "${DS_MSSQL}"
2501 |
2502 | },
2503 | "editorMode": "code",
2504 | "format": "table",
2505 | "rawQuery": true,
2506 | "rawSql": "SELECT \n ISNULL(t.NAME, 'Total') AS TableName,\n ISNULL(s.NAME, '') AS SchemaName,\n CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.0), 2) AS DECIMAL(18, 2)) AS UsedSpaceMB\nFROM \n sys.tables t\nINNER JOIN \n sys.indexes i ON t.OBJECT_ID = i.object_id\nINNER JOIN \n sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id\nINNER JOIN \n sys.allocation_units a ON p.partition_id = a.container_id\nINNER JOIN \n sys.schemas s ON t.schema_id = s.schema_id\nGROUP BY \n ROLLUP(t.Name, s.Name)\nORDER BY \n CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END,\n UsedSpaceMB DESC;\n",
2507 | "refId": "A",
2508 | "sql": {
2509 | "columns": [
2510 | {
2511 | "parameters": [],
2512 | "type": "function"
2513 | }
2514 | ],
2515 | "groupBy": [
2516 | {
2517 | "property": {
2518 | "type": "string"
2519 | },
2520 | "type": "groupBy"
2521 | }
2522 | ],
2523 | "limit": 50
2524 | }
2525 | }
2526 | ],
2527 | "title": "Used Space MB",
2528 | "type": "bargauge"
2529 | },
2530 | {
2531 | "datasource": {
2532 | "type": "mssql",
2533 | "uid": "${DS_MSSQL}"
2534 |
2535 | },
2536 | "fieldConfig": {
2537 | "defaults": {
2538 | "color": {
2539 | "mode": "palette-classic"
2540 | },
2541 | "custom": {
2542 | "axisBorderShow": false,
2543 | "axisCenteredZero": false,
2544 | "axisColorMode": "text",
2545 | "axisLabel": "",
2546 | "axisPlacement": "auto",
2547 | "fillOpacity": 80,
2548 | "gradientMode": "none",
2549 | "hideFrom": {
2550 | "legend": false,
2551 | "tooltip": false,
2552 | "viz": false
2553 | },
2554 | "lineWidth": 1,
2555 | "scaleDistribution": {
2556 | "type": "linear"
2557 | },
2558 | "thresholdsStyle": {
2559 | "mode": "off"
2560 | }
2561 | },
2562 | "fieldMinMax": false,
2563 | "mappings": [],
2564 | "thresholds": {
2565 | "mode": "absolute",
2566 | "steps": [
2567 | {
2568 | "color": "green",
2569 | "value": null
2570 | },
2571 | {
2572 | "color": "red",
2573 | "value": 80
2574 | }
2575 | ]
2576 | },
2577 | "unit": "decmbytes"
2578 |
2579 | },
2580 | "overrides": []
2581 | },
2582 | "gridPos": {
2583 | "h": 8,
2584 | "w": 18,
2585 | "x": 6,
2586 | "y": 56
2587 | },
2588 | "id": 24,
2589 | "options": {
2590 | "barRadius": 0,
2591 | "barWidth": 0.97,
2592 | "fullHighlight": false,
2593 | "groupWidth": 0.7,
2594 | "legend": {
2595 | "calcs": [],
2596 | "displayMode": "list",
2597 | "placement": "bottom",
2598 | "showLegend": true
2599 | },
2600 | "orientation": "horizontal",
2601 | "showValue": "never",
2602 | "stacking": "normal",
2603 | "tooltip": {
2604 | "mode": "single",
2605 | "sort": "none"
2606 | },
2607 | "xTickLabelRotation": 0,
2608 | "xTickLabelSpacing": 100
2609 | },
2610 | "targets": [
2611 | {
2612 | "datasource": {
2613 | "type": "mssql",
2614 | "uid": "${DS_MSSQL}"
2615 |
2616 | },
2617 | "editorMode": "code",
2618 | "format": "table",
2619 | "rawQuery": true,
2620 | "rawSql": "dbcc sqlperf (logspace)",
2621 | "refId": "A",
2622 | "sql": {
2623 | "columns": [
2624 | {
2625 | "parameters": [],
2626 | "type": "function"
2627 | }
2628 | ],
2629 | "groupBy": [
2630 | {
2631 | "property": {
2632 | "type": "string"
2633 | },
2634 | "type": "groupBy"
2635 | }
2636 | ],
2637 | "limit": 50
2638 | }
2639 | }
2640 | ],
2641 | "title": "Transaction Log Space Usage",
2642 | "type": "barchart"
2643 | },
2644 | {
2645 | "datasource": {
2646 | "type": "mssql",
2647 | "uid": "${DS_MSSQL}"
2648 |
2649 | },
2650 | "description": "modify the max with the size of your disk associated with the database",
2651 | "fieldConfig": {
2652 | "defaults": {
2653 | "color": {
2654 | "mode": "continuous-GrYlRd"
2655 | },
2656 | "mappings": [],
2657 | "max": 500000,
2658 | "min": 0,
2659 | "thresholds": {
2660 | "mode": "absolute",
2661 | "steps": [
2662 | {
2663 | "color": "green",
2664 | "value": null
2665 | },
2666 | {
2667 | "color": "yellow",
2668 | "value": 80
2669 | },
2670 | {
2671 | "color": "orange",
2672 | "value": 90
2673 | },
2674 | {
2675 | "color": "red",
2676 | "value": 100
2677 | }
2678 | ]
2679 | },
2680 | "unit": "decmbytes"
2681 |
2682 | },
2683 | "overrides": []
2684 | },
2685 | "gridPos": {
2686 | "h": 5,
2687 | "w": 3,
2688 | "x": 0,
2689 | "y": 61
2690 | },
2691 | "id": 18,
2692 | "options": {
2693 | "displayMode": "lcd",
2694 | "maxVizHeight": 300,
2695 | "minVizHeight": 16,
2696 | "minVizWidth": 8,
2697 | "namePlacement": "auto",
2698 | "orientation": "vertical",
2699 | "reduceOptions": {
2700 | "calcs": [
2701 | "lastNotNull"
2702 | ],
2703 | "fields": "",
2704 | "values": false
2705 | },
2706 | "showUnfilled": true,
2707 | "sizing": "auto",
2708 | "valueMode": "color"
2709 | },
2710 | "pluginVersion": "11.2.0",
2711 | "targets": [
2712 | {
2713 | "dataset": "DemoDB",
2714 |
2715 | "datasource": {
2716 | "type": "mssql",
2717 | "uid": "${DS_MSSQL}"
2718 |
2719 | },
2720 | "editorMode": "code",
2721 | "format": "table",
2722 | "rawQuery": true,
2723 | "rawSql": "SELECT \n ISNULL(t.NAME, 'Total') AS TableName,\n ISNULL(s.NAME, '') AS SchemaName,\n CAST(ROUND(((SUM(a.total_pages - a.used_pages) * 8) / 1024.0 * 100), 2) AS DECIMAL(18, 2)) AS UnusedSpaceMB\nFROM \n sys.tables t\nINNER JOIN \n sys.indexes i ON t.OBJECT_ID = i.object_id\nINNER JOIN \n sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id\nINNER JOIN \n sys.allocation_units a ON p.partition_id = a.container_id\nINNER JOIN \n sys.schemas s ON t.schema_id = s.schema_id\nGROUP BY \n ROLLUP(t.Name, s.Name)\nORDER BY \n CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END,\n UnusedSpaceMB DESC;\n",
2724 | "refId": "A",
2725 | "sql": {
2726 | "columns": [
2727 | {
2728 | "parameters": [],
2729 | "type": "function"
2730 | }
2731 | ],
2732 | "groupBy": [
2733 | {
2734 | "property": {
2735 | "type": "string"
2736 | },
2737 | "type": "groupBy"
2738 | }
2739 | ],
2740 | "limit": 50
2741 | }
2742 | }
2743 | ],
2744 | "title": "Unused Space MB",
2745 | "type": "bargauge"
2746 | },
2747 | {
2748 | "datasource": {
2749 | "type": "mssql",
2750 | "uid": "${DS_MSSQL}"
2751 |
2752 | },
2753 | "fieldConfig": {
2754 | "defaults": {
2755 | "mappings": [],
2756 | "thresholds": {
2757 | "mode": "percentage",
2758 | "steps": [
2759 | {
2760 | "color": "green",
2761 | "value": null
2762 | },
2763 | {
2764 | "color": "orange",
2765 | "value": 70
2766 | },
2767 | {
2768 | "color": "red",
2769 | "value": 85
2770 | }
2771 | ]
2772 | }
2773 |
2774 |
2775 | },
2776 | "overrides": []
2777 | },
2778 | "gridPos": {
2779 | "h": 5,
2780 | "w": 3,
2781 | "x": 3,
2782 | "y": 61
2783 | },
2784 | "id": 36,
2785 | "options": {
2786 | "minVizHeight": 75,
2787 | "minVizWidth": 75,
2788 | "orientation": "auto",
2789 | "reduceOptions": {
2790 | "calcs": [
2791 | "lastNotNull"
2792 | ],
2793 | "fields": "",
2794 | "values": false
2795 | },
2796 | "showThresholdLabels": false,
2797 | "showThresholdMarkers": true,
2798 | "sizing": "auto"
2799 | },
2800 | "pluginVersion": "11.2.0",
2801 | "targets": [
2802 | {
2803 | "dataset": "_DBA",
2804 | "datasource": {
2805 | "type": "mssql",
2806 | "uid": "${DS_MSSQL}"
2807 |
2808 | },
2809 | "editorMode": "code",
2810 | "format": "table",
2811 | "rawQuery": true,
2812 | "rawSql": "SELECT COUNT(*) AS MemoryGrantsPending\nFROM sys.dm_exec_query_memory_grants\nWHERE grant_time IS NULL;\n",
2813 | "refId": "A",
2814 | "sql": {
2815 | "columns": [
2816 | {
2817 | "parameters": [],
2818 | "type": "function"
2819 | }
2820 | ],
2821 | "groupBy": [
2822 | {
2823 | "property": {
2824 | "type": "string"
2825 | },
2826 | "type": "groupBy"
2827 | }
2828 | ],
2829 | "limit": 50
2830 | }
2831 | }
2832 | ],
2833 | "title": "Memory Grants Pending",
2834 | "type": "gauge"
2835 | },
2836 | {
2837 | "datasource": {
2838 | "type": "mssql",
2839 | "uid": "${DS_MSSQL}"
2840 |
2841 | },
2842 | "fieldConfig": {
2843 | "defaults": {
2844 | "color": {
2845 | "mode": "palette-classic"
2846 | },
2847 | "custom": {
2848 | "hideFrom": {
2849 | "legend": false,
2850 | "tooltip": false,
2851 | "viz": false
2852 | }
2853 | },
2854 | "fieldMinMax": false,
2855 | "mappings": []
2856 |
2857 | },
2858 | "overrides": []
2859 | },
2860 | "gridPos": {
2861 | "h": 7,
2862 | "w": 4,
2863 | "x": 6,
2864 | "y": 64
2865 | },
2866 | "id": 34,
2867 | "options": {
2868 | "displayLabels": [
2869 | "percent"
2870 | ],
2871 | "legend": {
2872 | "calcs": [],
2873 | "displayMode": "list",
2874 | "placement": "bottom",
2875 | "showLegend": true,
2876 | "values": []
2877 | },
2878 | "pieType": "pie",
2879 | "reduceOptions": {
2880 | "calcs": [
2881 | "lastNotNull"
2882 | ],
2883 | "fields": "",
2884 | "values": true
2885 | },
2886 | "tooltip": {
2887 | "mode": "single",
2888 | "sort": "desc"
2889 | }
2890 | },
2891 | "targets": [
2892 | {
2893 | "dataset": "_DBA",
2894 | "datasource": {
2895 | "type": "mssql",
2896 | "uid": "${DS_MSSQL}"
2897 |
2898 | },
2899 | "editorMode": "code",
2900 | "format": "table",
2901 | "rawQuery": true,
2902 | "rawSql": "SELECT name AS FileName,\n size/128 AS FileSizeMB,\n physical_name AS PhysicalName\nFROM sys.master_files;\n",
2903 | "refId": "A",
2904 | "sql": {
2905 | "columns": [
2906 | {
2907 | "parameters": [],
2908 | "type": "function"
2909 | }
2910 | ],
2911 | "groupBy": [
2912 | {
2913 | "property": {
2914 | "type": "string"
2915 | },
2916 | "type": "groupBy"
2917 | }
2918 | ],
2919 | "limit": 50
2920 | }
2921 | }
2922 | ],
2923 | "title": "Database File Usage",
2924 | "type": "piechart"
2925 | },
2926 | {
2927 | "datasource": {
2928 | "type": "mssql",
2929 | "uid": "${DS_MSSQL}"
2930 |
2931 | },
2932 | "fieldConfig": {
2933 | "defaults": {
2934 | "custom": {
2935 | "align": "center",
2936 | "cellOptions": {
2937 | "type": "auto"
2938 | },
2939 | "inspect": false
2940 | },
2941 | "mappings": [],
2942 | "thresholds": {
2943 | "mode": "absolute",
2944 | "steps": [
2945 | {
2946 | "color": "green",
2947 | "value": null
2948 | },
2949 | {
2950 | "color": "yellow",
2951 | "value": 40
2952 | },
2953 | {
2954 | "color": "orange",
2955 | "value": 70
2956 | },
2957 | {
2958 | "color": "red",
2959 | "value": 90
2960 | }
2961 | ]
2962 | }
2963 |
2964 |
2965 | },
2966 | "overrides": [
2967 | {
2968 | "matcher": {
2969 | "id": "byName",
2970 | "options": "database_name"
2971 | },
2972 | "properties": [
2973 | {
2974 | "id": "custom.align",
2975 | "value": "auto"
2976 | }
2977 | ]
2978 | },
2979 | {
2980 | "matcher": {
2981 | "id": "byName",
2982 | "options": "backup_start_date"
2983 | },
2984 | "properties": [
2985 | {
2986 | "id": "custom.width",
2987 | "value": 200
2988 | }
2989 | ]
2990 | },
2991 | {
2992 | "matcher": {
2993 | "id": "byName",
2994 | "options": "backup_finish_date"
2995 | },
2996 | "properties": [
2997 | {
2998 | "id": "custom.width",
2999 | "value": 203
3000 | }
3001 | ]
3002 | },
3003 | {
3004 | "matcher": {
3005 | "id": "byName",
3006 | "options": "BackupSizeMB"
3007 | },
3008 | "properties": [
3009 | {
3010 | "id": "custom.width",
3011 | "value": 150
3012 | },
3013 | {
3014 | "id": "custom.cellOptions",
3015 | "value": {
3016 | "type": "color-background"
3017 | }
3018 | }
3019 | ]
3020 | }
3021 | ]
3022 | },
3023 | "gridPos": {
3024 | "h": 7,
3025 | "w": 10,
3026 | "x": 10,
3027 | "y": 64
3028 | },
3029 | "id": 43,
3030 | "options": {
3031 | "cellHeight": "sm",
3032 | "footer": {
3033 | "countRows": false,
3034 | "fields": "",
3035 | "reducer": [
3036 | "sum"
3037 | ],
3038 | "show": false
3039 | },
3040 | "showHeader": true
3041 | },
3042 | "pluginVersion": "11.2.0",
3043 | "targets": [
3044 | {
3045 | "dataset": "_DBA",
3046 | "datasource": {
3047 | "type": "mssql",
3048 | "uid": "${DS_MSSQL}"
3049 |
3050 | },
3051 | "editorMode": "code",
3052 | "format": "table",
3053 | "rawQuery": true,
3054 | "rawSql": "SELECT database_name, \n backup_start_date, \n backup_finish_date, \n backup_size / 1024 / 1024 AS BackupSizeMB\nFROM msdb.dbo.backupset\nORDER BY backup_start_date DESC;\n",
3055 | "refId": "A",
3056 | "sql": {
3057 | "columns": [
3058 | {
3059 | "parameters": [],
3060 | "type": "function"
3061 | }
3062 | ],
3063 | "groupBy": [
3064 | {
3065 | "property": {
3066 | "type": "string"
3067 | },
3068 | "type": "groupBy"
3069 | }
3070 | ],
3071 | "limit": 50
3072 | }
3073 | }
3074 | ],
3075 | "title": "Backup Status",
3076 | "type": "table"
3077 | },
3078 | {
3079 | "datasource": {
3080 | "type": "mssql",
3081 | "uid": "${DS_MSSQL}"
3082 |
3083 | },
3084 | "fieldConfig": {
3085 | "defaults": {
3086 | "color": {
3087 | "mode": "thresholds"
3088 | },
3089 | "mappings": [],
3090 | "max": 5000000000,
3091 | "min": 0,
3092 | "thresholds": {
3093 | "mode": "percentage",
3094 | "steps": [
3095 | {
3096 | "color": "green",
3097 | "value": null
3098 | },
3099 | {
3100 | "color": "orange",
3101 | "value": 70
3102 | },
3103 | {
3104 | "color": "red",
3105 | "value": 85
3106 | }
3107 | ]
3108 | }
3109 |
3110 |
3111 | },
3112 | "overrides": []
3113 | },
3114 | "gridPos": {
3115 | "h": 7,
3116 | "w": 4,
3117 | "x": 20,
3118 | "y": 64
3119 | },
3120 | "id": 15,
3121 | "options": {
3122 | "minVizHeight": 75,
3123 | "minVizWidth": 75,
3124 | "orientation": "auto",
3125 | "reduceOptions": {
3126 | "calcs": [
3127 | "lastNotNull"
3128 | ],
3129 | "fields": "",
3130 | "values": false
3131 | },
3132 | "showThresholdLabels": false,
3133 | "showThresholdMarkers": true,
3134 | "sizing": "auto"
3135 | },
3136 | "pluginVersion": "11.2.0",
3137 | "targets": [
3138 | {
3139 | "dataset": "DemoDB",
3140 |
3141 | "datasource": {
3142 | "type": "mssql",
3143 | "uid": "${DS_MSSQL}"
3144 |
3145 | },
3146 | "editorMode": "code",
3147 | "format": "table",
3148 | "rawQuery": true,
3149 | "rawSql": "SELECT \n ISNULL(t.NAME, 'Total') AS TableName,\n ISNULL(s.NAME, '') AS SchemaName,\n SUM(p.rows) AS RowCounts\nFROM \n sys.tables t\nINNER JOIN \n sys.indexes i ON t.OBJECT_ID = i.object_id\nINNER JOIN \n sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id\nINNER JOIN \n sys.schemas s ON t.schema_id = s.schema_id\nGROUP BY \n ROLLUP(t.Name, s.Name)\nORDER BY \n CASE WHEN t.Name IS NULL THEN 1 ELSE 0 END,\n RowCounts DESC;\n",
3150 | "refId": "A",
3151 | "sql": {
3152 | "columns": [
3153 | {
3154 | "parameters": [],
3155 | "type": "function"
3156 | }
3157 | ],
3158 | "groupBy": [
3159 | {
3160 | "property": {
3161 | "type": "string"
3162 | },
3163 | "type": "groupBy"
3164 | }
3165 | ],
3166 | "limit": 50
3167 | }
3168 | }
3169 | ],
3170 | "title": "Row Count",
3171 | "type": "gauge"
3172 | },
3173 | {
3174 | "datasource": {
3175 | "type": "mssql",
3176 | "uid": "${DS_MSSQL}"
3177 |
3178 | },
3179 | "fieldConfig": {
3180 | "defaults": {
3181 | "mappings": [],
3182 | "thresholds": {
3183 | "mode": "percentage",
3184 | "steps": [
3185 | {
3186 | "color": "green",
3187 | "value": null
3188 | },
3189 | {
3190 | "color": "orange",
3191 | "value": 70
3192 | },
3193 | {
3194 | "color": "red",
3195 | "value": 85
3196 | }
3197 | ]
3198 | }
3199 |
3200 |
3201 | },
3202 | "overrides": []
3203 | },
3204 | "gridPos": {
3205 | "h": 5,
3206 | "w": 6,
3207 | "x": 0,
3208 | "y": 66
3209 | },
3210 | "id": 10,
3211 | "options": {
3212 | "minVizHeight": 75,
3213 | "minVizWidth": 75,
3214 | "orientation": "auto",
3215 | "reduceOptions": {
3216 | "calcs": [
3217 | "lastNotNull"
3218 | ],
3219 | "fields": "",
3220 | "values": false
3221 | },
3222 | "showThresholdLabels": false,
3223 | "showThresholdMarkers": true,
3224 | "sizing": "auto"
3225 | },
3226 | "pluginVersion": "11.2.0",
3227 | "targets": [
3228 | {
3229 | "dataset": "DemoDB",
3230 |
3231 | "datasource": {
3232 | "type": "mssql",
3233 | "uid": "${DS_MSSQL}"
3234 |
3235 | },
3236 | "editorMode": "code",
3237 | "format": "table",
3238 | "rawQuery": true,
3239 | "rawSql": "SELECT \n request_session_id AS 'Session ID',\n resource_database_id AS 'Database ID',\n resource_associated_entity_id AS 'Entity ID',\n request_mode AS LockType,\n request_status AS Status\nFROM sys.dm_tran_locks;\n",
3240 | "refId": "A",
3241 | "sql": {
3242 | "columns": [
3243 | {
3244 | "parameters": [],
3245 | "type": "function"
3246 | }
3247 | ],
3248 | "groupBy": [
3249 | {
3250 | "property": {
3251 | "type": "string"
3252 | },
3253 | "type": "groupBy"
3254 | }
3255 | ],
3256 | "limit": 50
3257 | }
3258 | }
3259 | ],
3260 | "title": "Table Locks",
3261 | "type": "gauge"
3262 | },
3263 | {
3264 | "datasource": {
3265 | "type": "mssql",
3266 | "uid": "${DS_MSSQL}"
3267 |
3268 | },
3269 | "fieldConfig": {
3270 | "defaults": {
3271 | "color": {
3272 | "mode": "continuous-GrYlRd"
3273 | },
3274 | "mappings": [],
3275 | "thresholds": {
3276 | "mode": "absolute",
3277 | "steps": [
3278 | {
3279 | "color": "green",
3280 | "value": null
3281 | },
3282 | {
3283 | "color": "red",
3284 | "value": 80
3285 | }
3286 | ]
3287 | }
3288 |
3289 |
3290 | },
3291 | "overrides": []
3292 | },
3293 | "gridPos": {
3294 | "h": 8,
3295 | "w": 11,
3296 | "x": 0,
3297 | "y": 71
3298 | },
3299 | "id": 44,
3300 | "options": {
3301 | "displayMode": "lcd",
3302 | "maxVizHeight": 300,
3303 | "minVizHeight": 16,
3304 | "minVizWidth": 8,
3305 | "namePlacement": "auto",
3306 | "orientation": "horizontal",
3307 | "reduceOptions": {
3308 | "calcs": [
3309 | "lastNotNull"
3310 | ],
3311 | "fields": "",
3312 | "values": false
3313 | },
3314 | "showUnfilled": true,
3315 | "sizing": "auto",
3316 | "valueMode": "color"
3317 | },
3318 | "pluginVersion": "11.2.0",
3319 | "targets": [
3320 | {
3321 | "dataset": "_DBA",
3322 | "datasource": {
3323 | "type": "mssql",
3324 | "uid": "${DS_MSSQL}"
3325 |
3326 | },
3327 | "editorMode": "code",
3328 | "format": "table",
3329 | "rawQuery": true,
3330 | "rawSql": "SELECT total_physical_memory_kb, \n available_physical_memory_kb, \n total_page_file_kb, \n available_page_file_kb\nFROM sys.dm_os_sys_memory;\n",
3331 | "refId": "A",
3332 | "sql": {
3333 | "columns": [
3334 | {
3335 | "parameters": [],
3336 | "type": "function"
3337 | }
3338 | ],
3339 | "groupBy": [
3340 | {
3341 | "property": {
3342 | "type": "string"
3343 | },
3344 | "type": "groupBy"
3345 | }
3346 | ],
3347 | "limit": 50
3348 | }
3349 | }
3350 | ],
3351 | "title": "Memory Usage",
3352 | "type": "bargauge"
3353 | },
3354 | {
3355 | "datasource": {
3356 | "type": "mssql",
3357 | "uid": "${DS_MSSQL}"
3358 |
3359 | },
3360 | "fieldConfig": {
3361 | "defaults": {
3362 | "color": {
3363 | "mode": "continuous-GrYlRd"
3364 | },
3365 | "mappings": [],
3366 | "thresholds": {
3367 | "mode": "absolute",
3368 | "steps": [
3369 | {
3370 | "color": "green",
3371 | "value": null
3372 | },
3373 | {
3374 | "color": "red",
3375 | "value": 80
3376 | }
3377 | ]
3378 | }
3379 |
3380 |
3381 | },
3382 | "overrides": []
3383 | },
3384 | "gridPos": {
3385 | "h": 8,
3386 | "w": 13,
3387 | "x": 11,
3388 | "y": 71
3389 | },
3390 | "id": 41,
3391 | "options": {
3392 | "displayMode": "lcd",
3393 | "maxVizHeight": 300,
3394 | "minVizHeight": 16,
3395 | "minVizWidth": 8,
3396 | "namePlacement": "auto",
3397 | "orientation": "horizontal",
3398 | "reduceOptions": {
3399 | "calcs": [
3400 | "lastNotNull"
3401 | ],
3402 | "fields": "",
3403 | "values": false
3404 | },
3405 | "showUnfilled": true,
3406 | "sizing": "auto",
3407 | "valueMode": "color"
3408 | },
3409 | "pluginVersion": "11.2.0",
3410 | "targets": [
3411 | {
3412 | "dataset": "_DBA",
3413 | "datasource": {
3414 | "type": "mssql",
3415 | "uid": "${DS_MSSQL}"
3416 |
3417 | },
3418 | "editorMode": "code",
3419 | "format": "table",
3420 | "rawQuery": true,
3421 | "rawSql": "SELECT database_id, \n file_id, \n io_stall_read_ms AS DiskReadStall, \n io_stall_write_ms AS DiskWriteStall, \n num_of_reads, \n num_of_writes\nFROM sys.dm_io_virtual_file_stats (2, NULL);\n",
3422 | "refId": "A",
3423 | "sql": {
3424 | "columns": [
3425 | {
3426 | "parameters": [],
3427 | "type": "function"
3428 | }
3429 | ],
3430 | "groupBy": [
3431 | {
3432 | "property": {
3433 | "type": "string"
3434 | },
3435 | "type": "groupBy"
3436 | }
3437 | ],
3438 | "limit": 50
3439 | }
3440 | }
3441 | ],
3442 | "title": "TempDB Disk Monitoring",
3443 | "type": "bargauge"
3444 | },
3445 | {
3446 | "collapsed": false,
3447 | "gridPos": {
3448 | "h": 1,
3449 | "w": 24,
3450 | "x": 0,
3451 | "y": 79
3452 | },
3453 | "id": 45,
3454 | "panels": [],
3455 | "title": "Jobs Monitoring",
3456 | "type": "row"
3457 | },
3458 | {
3459 | "datasource": {
3460 | "type": "mssql",
3461 | "uid": "${DS_MSSQL}"
3462 |
3463 | },
3464 | "description": "Last 7 days",
3465 | "fieldConfig": {
3466 | "defaults": {
3467 | "color": {
3468 | "mode": "continuous-GrYlRd"
3469 | },
3470 | "mappings": [],
3471 | "thresholds": {
3472 | "mode": "absolute",
3473 | "steps": [
3474 | {
3475 | "color": "green",
3476 | "value": null
3477 | },
3478 | {
3479 | "color": "red",
3480 | "value": 80
3481 | }
3482 | ]
3483 | }
3484 |
3485 |
3486 | },
3487 | "overrides": []
3488 | },
3489 | "gridPos": {
3490 | "h": 12,
3491 | "w": 4,
3492 | "x": 0,
3493 | "y": 80
3494 | },
3495 | "id": 30,
3496 | "options": {
3497 | "displayMode": "gradient",
3498 | "maxVizHeight": 63,
3499 | "minVizHeight": 1,
3500 | "minVizWidth": 8,
3501 | "namePlacement": "top",
3502 | "orientation": "horizontal",
3503 | "reduceOptions": {
3504 | "calcs": [],
3505 | "fields": "",
3506 | "values": true
3507 | },
3508 | "showUnfilled": true,
3509 | "sizing": "auto",
3510 | "text": {
3511 | "titleSize": 13,
3512 | "valueSize": 15
3513 | },
3514 | "valueMode": "color"
3515 | },
3516 | "pluginVersion": "11.2.0",
3517 | "targets": [
3518 | {
3519 | "dataset": "_DBA",
3520 | "datasource": {
3521 | "type": "mssql",
3522 | "uid": "${DS_MSSQL}"
3523 |
3524 | },
3525 | "editorMode": "code",
3526 | "format": "table",
3527 | "rawQuery": true,
3528 | "rawSql": "SELECT job.name AS JobName,\n COUNT(run.run_date) AS ExecutionCount\nFROM msdb.dbo.sysjobs AS job\nINNER JOIN msdb.dbo.sysjobhistory AS run\nON job.job_id = run.job_id\nWHERE run.run_date >= CONVERT(VARCHAR, GETDATE() - 7, 112) -- Last 7 days\nGROUP BY job.name\nORDER BY ExecutionCount DESC\n",
3529 | "refId": "A",
3530 | "sql": {
3531 | "columns": [
3532 | {
3533 | "parameters": [],
3534 | "type": "function"
3535 | }
3536 | ],
3537 | "groupBy": [
3538 | {
3539 | "property": {
3540 | "type": "string"
3541 | },
3542 | "type": "groupBy"
3543 | }
3544 | ],
3545 | "limit": 50
3546 | }
3547 | }
3548 | ],
3549 | "title": "Job Execution Frequency",
3550 | "type": "bargauge"
3551 | },
3552 | {
3553 | "datasource": {
3554 | "type": "mssql",
3555 | "uid": "${DS_MSSQL}"
3556 |
3557 | },
3558 | "fieldConfig": {
3559 | "defaults": {
3560 | "custom": {
3561 | "align": "center",
3562 | "cellOptions": {
3563 | "type": "auto"
3564 | },
3565 | "inspect": false
3566 | },
3567 | "mappings": [],
3568 | "noValue": "No Jobs running",
3569 | "thresholds": {
3570 | "mode": "absolute",
3571 | "steps": [
3572 | {
3573 | "color": "green",
3574 | "value": null
3575 | },
3576 | {
3577 | "color": "yellow",
3578 | "value": 20
3579 | },
3580 | {
3581 | "color": "orange",
3582 | "value": 45
3583 | },
3584 | {
3585 | "color": "red",
3586 | "value": 70
3587 | }
3588 | ]
3589 | }
3590 |
3591 |
3592 | },
3593 | "overrides": [
3594 | {
3595 | "matcher": {
3596 | "id": "byName",
3597 | "options": "RunDurationSeconds"
3598 | },
3599 | "properties": [
3600 | {
3601 | "id": "unit",
3602 | "value": "dtdurations"
3603 | },
3604 | {
3605 | "id": "custom.cellOptions",
3606 | "value": {
3607 | "type": "color-background"
3608 | }
3609 | }
3610 | ]
3611 | },
3612 | {
3613 | "matcher": {
3614 | "id": "byName",
3615 | "options": "RunDurationSeconds"
3616 | },
3617 | "properties": [
3618 | {
3619 | "id": "custom.width",
3620 | "value": 120
3621 | }
3622 | ]
3623 | },
3624 | {
3625 | "matcher": {
3626 | "id": "byName",
3627 | "options": "StartTime"
3628 | },
3629 | "properties": [
3630 | {
3631 | "id": "custom.width",
3632 | "value": 200
3633 | }
3634 | ]
3635 | },
3636 | {
3637 | "matcher": {
3638 | "id": "byName",
3639 | "options": "JobName"
3640 | },
3641 | "properties": [
3642 | {
3643 | "id": "custom.width",
3644 | "value": 250
3645 | }
3646 | ]
3647 | },
3648 | {
3649 | "matcher": {
3650 | "id": "byName",
3651 | "options": "JobName"
3652 | },
3653 | "properties": [
3654 | {
3655 | "id": "custom.align",
3656 | "value": "auto"
3657 | }
3658 | ]
3659 | }
3660 | ]
3661 | },
3662 | "gridPos": {
3663 | "h": 3,
3664 | "w": 8,
3665 | "x": 4,
3666 | "y": 80
3667 | },
3668 | "id": 46,
3669 | "options": {
3670 | "cellHeight": "sm",
3671 | "footer": {
3672 | "countRows": false,
3673 | "fields": "",
3674 | "reducer": [
3675 | "sum"
3676 | ],
3677 | "show": false
3678 | },
3679 | "showHeader": false
3680 | },
3681 | "pluginVersion": "11.2.0",
3682 | "targets": [
3683 | {
3684 | "dataset": "_DBA",
3685 | "datasource": {
3686 | "type": "mssql",
3687 | "uid": "${DS_MSSQL}"
3688 |
3689 | },
3690 | "editorMode": "code",
3691 | "format": "table",
3692 | "rawQuery": true,
3693 | "rawSql": "SELECT DISTINCT \n job.name AS JobName,\n activity.run_requested_date AS StartTime,\n DATEDIFF(SECOND, activity.run_requested_date, GETDATE()) AS RunDurationSeconds\nFROM msdb.dbo.sysjobs AS job\nINNER JOIN msdb.dbo.sysjobactivity AS activity\n ON job.job_id = activity.job_id\nWHERE activity.run_requested_date IS NOT NULL\n AND activity.stop_execution_date IS NULL\nORDER BY activity.run_requested_date DESC;\n",
3694 | "refId": "A",
3695 | "sql": {
3696 | "columns": [
3697 | {
3698 | "parameters": [],
3699 | "type": "function"
3700 | }
3701 | ],
3702 | "groupBy": [
3703 | {
3704 | "property": {
3705 | "type": "string"
3706 | },
3707 | "type": "groupBy"
3708 | }
3709 | ],
3710 | "limit": 50
3711 | }
3712 | }
3713 | ],
3714 | "title": "Jobs in progress",
3715 | "type": "table"
3716 | },
3717 | {
3718 | "datasource": {
3719 | "type": "mssql",
3720 | "uid": "${DS_MSSQL}"
3721 |
3722 | },
3723 | "fieldConfig": {
3724 | "defaults": {
3725 | "custom": {
3726 | "align": "center",
3727 | "cellOptions": {
3728 | "type": "auto"
3729 | },
3730 | "inspect": false
3731 | },
3732 | "mappings": [],
3733 | "max": 100,
3734 | "thresholds": {
3735 | "mode": "absolute",
3736 | "steps": [
3737 | {
3738 | "color": "green",
3739 | "value": null
3740 | },
3741 | {
3742 | "color": "red",
3743 | "value": 80
3744 | }
3745 | ]
3746 | }
3747 |
3748 |
3749 | },
3750 | "overrides": [
3751 | {
3752 | "matcher": {
3753 | "id": "byName",
3754 | "options": "NextRunDate"
3755 | },
3756 | "properties": [
3757 | {
3758 | "id": "custom.width",
3759 | "value": 120
3760 | }
3761 | ]
3762 | },
3763 | {
3764 | "matcher": {
3765 | "id": "byName",
3766 | "options": "NextRunTime"
3767 | },
3768 | "properties": [
3769 | {
3770 | "id": "custom.width",
3771 | "value": 120
3772 | }
3773 | ]
3774 | },
3775 | {
3776 | "matcher": {
3777 | "id": "byName",
3778 | "options": "JobStatus"
3779 | },
3780 | "properties": [
3781 | {
3782 | "id": "custom.width",
3783 | "value": 120
3784 | },
3785 | {
3786 | "id": "custom.cellOptions",
3787 | "value": {
3788 | "type": "color-text"
3789 | }
3790 | }
3791 | ]
3792 | },
3793 | {
3794 | "matcher": {
3795 | "id": "byName",
3796 | "options": "JobName"
3797 | },
3798 | "properties": [
3799 | {
3800 | "id": "custom.align",
3801 | "value": "auto"
3802 | }
3803 | ]
3804 | }
3805 | ]
3806 | },
3807 | "gridPos": {
3808 | "h": 6,
3809 | "w": 12,
3810 | "x": 12,
3811 | "y": 80
3812 | },
3813 | "id": 29,
3814 | "options": {
3815 | "cellHeight": "sm",
3816 | "footer": {
3817 | "countRows": false,
3818 | "fields": "",
3819 | "reducer": [
3820 | "sum"
3821 | ],
3822 | "show": false
3823 | },
3824 | "showHeader": true
3825 | },
3826 | "pluginVersion": "11.2.0",
3827 | "targets": [
3828 | {
3829 | "dataset": "_DBA",
3830 | "datasource": {
3831 | "type": "mssql",
3832 | "uid": "${DS_MSSQL}"
3833 |
3834 | },
3835 | "editorMode": "code",
3836 | "format": "table",
3837 | "rawQuery": true,
3838 | "rawSql": "SELECT TOP 20\n job.name AS JobName,\n CASE\n WHEN activity.run_requested_date IS NULL THEN 'Scheduled'\n ELSE 'Running'\n END AS JobStatus,\n schedule.next_run_date AS NextRunDate,\n schedule.next_run_time AS NextRunTime\nFROM msdb.dbo.sysjobs AS job\nLEFT JOIN msdb.dbo.sysjobactivity AS activity\n ON job.job_id = activity.job_id\nLEFT JOIN msdb.dbo.sysjobschedules AS schedule\n ON job.job_id = schedule.job_id\nWHERE activity.stop_execution_date IS NULL -- Running jobs\n OR schedule.next_run_date IS NOT NULL -- Scheduled jobs\nORDER BY schedule.next_run_date, schedule.next_run_time;\n",
3839 | "refId": "A",
3840 | "sql": {
3841 | "columns": [
3842 | {
3843 | "parameters": [],
3844 | "type": "function"
3845 | }
3846 | ],
3847 | "groupBy": [
3848 | {
3849 | "property": {
3850 | "type": "string"
3851 | },
3852 | "type": "groupBy"
3853 | }
3854 | ],
3855 | "limit": 50
3856 | }
3857 | }
3858 | ],
3859 | "title": "Scheduled and Running Jobs",
3860 | "type": "table"
3861 | },
3862 | {
3863 | "datasource": {
3864 | "type": "mssql",
3865 | "uid": "${DS_MSSQL}"
3866 |
3867 | },
3868 | "description": "",
3869 | "fieldConfig": {
3870 | "defaults": {
3871 | "custom": {
3872 | "align": "center",
3873 | "cellOptions": {
3874 | "type": "auto"
3875 | },
3876 | "inspect": false
3877 | },
3878 | "mappings": [],
3879 | "thresholds": {
3880 | "mode": "absolute",
3881 | "steps": [
3882 | {
3883 | "color": "purple",
3884 | "value": null
3885 | },
3886 | {
3887 | "color": "yellow",
3888 | "value": 20
3889 | },
3890 | {
3891 | "color": "orange",
3892 | "value": 45
3893 | },
3894 | {
3895 | "color": "red",
3896 | "value": 70
3897 | }
3898 | ]
3899 | }
3900 |
3901 |
3902 | },
3903 | "overrides": [
3904 | {
3905 | "matcher": {
3906 | "id": "byName",
3907 | "options": "RunDuration"
3908 | },
3909 | "properties": [
3910 | {
3911 | "id": "unit",
3912 | "value": "dtdurations"
3913 | },
3914 | {
3915 | "id": "custom.cellOptions",
3916 | "value": {
3917 | "mode": "gradient",
3918 | "type": "color-background"
3919 | }
3920 | },
3921 | {
3922 | "id": "custom.width",
3923 | "value": 120
3924 | }
3925 | ]
3926 | },
3927 | {
3928 | "matcher": {
3929 | "id": "byName",
3930 | "options": "RunDate"
3931 | },
3932 | "properties": [
3933 | {
3934 | "id": "custom.width",
3935 | "value": 90
3936 | }
3937 | ]
3938 | },
3939 | {
3940 | "matcher": {
3941 | "id": "byName",
3942 | "options": "JobName"
3943 | },
3944 | "properties": [
3945 | {
3946 | "id": "custom.align",
3947 | "value": "auto"
3948 | }
3949 | ]
3950 | }
3951 | ]
3952 | },
3953 | "gridPos": {
3954 | "h": 9,
3955 | "w": 8,
3956 | "x": 4,
3957 | "y": 83
3958 | },
3959 | "id": 27,
3960 | "options": {
3961 | "cellHeight": "sm",
3962 | "footer": {
3963 | "countRows": false,
3964 | "fields": "",
3965 | "reducer": [
3966 | "sum"
3967 | ],
3968 | "show": false
3969 | },
3970 | "showHeader": true
3971 | },
3972 | "pluginVersion": "11.2.0",
3973 | "targets": [
3974 | {
3975 | "dataset": "_DBA",
3976 | "datasource": {
3977 | "type": "mssql",
3978 | "uid": "${DS_MSSQL}"
3979 |
3980 | },
3981 | "editorMode": "code",
3982 | "format": "table",
3983 | "rawQuery": true,
3984 | "rawSql": "SELECT job.name AS JobName,\n run.run_date AS RunDate,\n run.run_duration AS RunDuration\nFROM msdb.dbo.sysjobs AS job\nINNER JOIN msdb.dbo.sysjobhistory AS run\nON job.job_id = run.job_id\nWHERE run.step_id = 0 -- 0 indicates job level information\nORDER BY run.run_date DESC\n",
3985 | "refId": "A",
3986 | "sql": {
3987 | "columns": [
3988 | {
3989 | "parameters": [],
3990 | "type": "function"
3991 | }
3992 | ],
3993 | "groupBy": [
3994 | {
3995 | "property": {
3996 | "type": "string"
3997 | },
3998 | "type": "groupBy"
3999 | }
4000 | ],
4001 | "limit": 50
4002 | }
4003 | }
4004 | ],
4005 | "title": "Job Execution History Duration",
4006 | "type": "table"
4007 | },
4008 | {
4009 | "datasource": {
4010 | "type": "mssql",
4011 | "uid": "${DS_MSSQL}"
4012 |
4013 | },
4014 | "fieldConfig": {
4015 | "defaults": {
4016 | "custom": {
4017 | "align": "center",
4018 | "cellOptions": {
4019 | "type": "auto"
4020 | },
4021 | "inspect": false
4022 | },
4023 | "mappings": [],
4024 | "thresholds": {
4025 | "mode": "absolute",
4026 | "steps": [
4027 | {
4028 | "color": "green",
4029 | "value": null
4030 | },
4031 | {
4032 | "color": "red",
4033 | "value": 80
4034 | }
4035 | ]
4036 | }
4037 |
4038 |
4039 | },
4040 | "overrides": [
4041 | {
4042 | "matcher": {
4043 | "id": "byName",
4044 | "options": "RunDate"
4045 | },
4046 | "properties": [
4047 | {
4048 | "id": "custom.width",
4049 | "value": 120
4050 | }
4051 | ]
4052 | },
4053 | {
4054 | "matcher": {
4055 | "id": "byName",
4056 | "options": "RunTime"
4057 | },
4058 | "properties": [
4059 | {
4060 | "id": "custom.width",
4061 | "value": 100
4062 | }
4063 | ]
4064 | },
4065 | {
4066 | "matcher": {
4067 | "id": "byName",
4068 | "options": "RunDuration"
4069 | },
4070 | "properties": [
4071 | {
4072 | "id": "custom.width",
4073 | "value": 100
4074 | }
4075 | ]
4076 | },
4077 | {
4078 | "matcher": {
4079 | "id": "byName",
4080 | "options": "JobName"
4081 | },
4082 | "properties": [
4083 | {
4084 | "id": "custom.align",
4085 | "value": "auto"
4086 | }
4087 | ]
4088 | }
4089 | ]
4090 | },
4091 | "gridPos": {
4092 | "h": 6,
4093 | "w": 12,
4094 | "x": 12,
4095 | "y": 86
4096 | },
4097 | "id": 28,
4098 | "options": {
4099 | "cellHeight": "sm",
4100 | "footer": {
4101 | "countRows": false,
4102 | "fields": "",
4103 | "reducer": [
4104 | "sum"
4105 | ],
4106 | "show": false
4107 | },
4108 | "showHeader": true
4109 | },
4110 | "pluginVersion": "11.2.0",
4111 | "targets": [
4112 | {
4113 | "dataset": "_DBA",
4114 | "datasource": {
4115 | "type": "mssql",
4116 | "uid": "${DS_MSSQL}"
4117 |
4118 | },
4119 | "editorMode": "code",
4120 | "format": "table",
4121 | "rawQuery": true,
4122 | "rawSql": "SELECT job.name AS JobName,\n run.run_date AS RunDate,\n run.run_time AS RunTime,\n run.run_duration AS RunDuration,\n run.message AS ErrorMessage\nFROM msdb.dbo.sysjobs AS job\nINNER JOIN msdb.dbo.sysjobhistory AS run\nON job.job_id = run.job_id\nWHERE run.run_status = 0 -- 0 indicates failure\nORDER BY run.run_date DESC\n",
4123 | "refId": "A",
4124 | "sql": {
4125 | "columns": [
4126 | {
4127 | "parameters": [],
4128 | "type": "function"
4129 | }
4130 | ],
4131 | "groupBy": [
4132 | {
4133 | "property": {
4134 | "type": "string"
4135 | },
4136 | "type": "groupBy"
4137 | }
4138 | ],
4139 | "limit": 50
4140 | }
4141 | }
4142 | ],
4143 | "title": "Failed Jobs Overview",
4144 | "type": "table"
4145 | }
4146 | ],
4147 | "refresh": "5s",
4148 | "schemaVersion": 39,
4149 | "tags": [],
4150 | "templating": {
4151 | "list": []
4152 | },
4153 | "time": {
4154 | "from": "now-3h",
4155 | "to": "now"
4156 | },
4157 | "timepicker": {},
4158 | "timezone": "",
4159 | "title": "Microsoft SQL Server Dashboard",
4160 | "uid": "bff36b75-3eae-44b8-994b-c7a87274d162",
4161 | "version": 1,
4162 | "weekStart": ""
4163 | }
4164 |
--------------------------------------------------------------------------------