Skip to content

Commit

Permalink
Huge houskeeping
Browse files Browse the repository at this point in the history
  • Loading branch information
JocaPC committed Mar 8, 2020
1 parent 37423e1 commit 0f6c24e
Show file tree
Hide file tree
Showing 11 changed files with 99 additions and 17 deletions.
17 changes: 16 additions & 1 deletion package.json
Original file line number Diff line number Diff line change
Expand Up @@ -74,6 +74,21 @@
}
}
},
{
"id": "qpi.file-io-history",
"contrib": {
"type":{
"line":{
"dataDirection":"vertical",
"columnsAsLabels":true,
"labelFirstColumn":false,
"legendPosition":"top",
"dataType":"number"
}
},
"queryFile":"./sql/file-io-history.sql"
}
},
{
"id": "qpi.memory",
"contrib": {
Expand Down Expand Up @@ -446,7 +461,7 @@
"sizey": 1
},
"widget": {
"qpi.file-stats": {}
"qpi.file-io-history": {}
}
},
{
Expand Down
28 changes: 26 additions & 2 deletions snippets/snippets.json
Original file line number Diff line number Diff line change
Expand Up @@ -166,13 +166,37 @@
"description": "Return query plan wait statistics from the latest Query Store interval."
},
"QPI snapshot statistics": {
"prefix": "qpi:snapshot stats",
"prefix": "qpi:snapshot all stats",
"body": [
"-- Take the snapshot (baseline) of the following statistics:",
"exec qpi.snapshot_perf_counters;",
"exec qpi.snapshot_wait_stats;",
"exec qpi.snapshot_file_stats;"
],
"description": "Take a snapshot of file/wait statistics and perf counters"
},
"QPI snapshot wait stats": {
"prefix": "qpi:snapshot wait stats",
"body": [
"-- Take the snapshot (baseline) of the wait statistics:",
"exec qpi.snapshot_wait_stats;"
],
"description": "Take a snapshot of wait statistics"
},
"QPI snapshot perf counters stats": {
"prefix": "qpi:snapshot wait stats",
"body": [
"-- Take the snapshot (baseline) of the perf counters:",
"exec qpi.snapshot_perf_counters;",
],
"description": "Take a snapshot of wait statistics"
},
"QPI snapshot file statistics": {
"prefix": "qpi:snapshot file stats",
"body": [
"-- Take the snapshot (baseline) of the file statistics:",
"exec qpi.snapshot_file_stats;"
],
"description": "Take a snapshot of statistics"
},
"QPI file statistics": {
Expand All @@ -181,7 +205,7 @@
"-- Returns IO statistics for all database files:",
"SELECT * FROM qpi.file_stats;"
],
"description": "get file IO statistics"
"description": "Get file IO statistics"
},
"QPI db file statistics": {
"prefix": "qpi:db file stats",
Expand Down
11 changes: 7 additions & 4 deletions sql/db-data-file-stats-history.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,16 @@
-- Returns IO statistics for database data files (mdf/ndf):
select [time] = CONVERT(VARCHAR(5), CAST(start_time AS smalldatetime), 108),
[Write(MB/s)] = SUM(write_mbps),
[IO(MB/s)] = SUM(throughput_mbps),
[IO/sec] = SUM(iops),
[Read latency(ms)] = AVG(read_latency_ms),
[Write latency(ms)] = AVG(write_latency_ms),
[Total reads] = SUM(num_of_reads),
[Total writes] = SUM(num_of_writes)
[Write latency(ms)] = AVG(write_latency_ms)
from qpi.db_file_stats_history
where type <> 'log'
and start_time >= DATEADD(hh, -24, GETUTCDATE())
group by CAST(start_time AS smalldatetime)
order by CAST(start_time AS smalldatetime) asc
order by CAST(start_time AS smalldatetime) asc

-- Tips:
-- Add columns in SELECT [Total reads] = SUM(num_of_reads), [Total writes] = SUM(num_of_writes)
-- use qpi:snapshot to take more recent snapshot of file io statistics.
11 changes: 7 additions & 4 deletions sql/db-log-file-stats-history.sql
Original file line number Diff line number Diff line change
@@ -1,13 +1,16 @@
-- Returns IO statistics for database data files (mdf/ndf):
select [time] = CONVERT(VARCHAR(5), CAST(start_time AS smalldatetime), 108),
[Write(MB/s)] = SUM(write_mbps),
[IO(MB/s)] = SUM(throughput_mbps),
[IO/sec] = SUM(iops),
[Read latency(ms)] = AVG(read_latency_ms),
[Write latency(ms)] = AVG(write_latency_ms),
[Total reads] = SUM(num_of_reads),
[Total writes] = SUM(num_of_writes)
[Write latency(ms)] = AVG(write_latency_ms)
from qpi.db_file_stats_history
where type = 'log'
and start_time >= DATEADD(hh, -24, GETUTCDATE())
group by CAST(start_time AS smalldatetime)
order by CAST(start_time AS smalldatetime) asc
order by CAST(start_time AS smalldatetime) asc

-- Tips:
-- Add columns in SELECT [Total reads] = SUM(num_of_reads), [Total writes] = SUM(num_of_writes)
-- use qpi:snapshot to take more recent snapshot of file io statistics.
7 changes: 7 additions & 0 deletions sql/file-io-history.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
select cast(datepart(hour, start_time) as char(2)) +':'+ cast(datepart(mi, start_time) as char(2)),
[logwrite(mbps)] = sum(case when type = 'LOG' then write_mbps else 0 end),
[logwrite_latency(ms)] = max(case when type = 'LOG' then write_latency_ms else null end)
from qpi.file_stats_history
where DATEDIFF(hour, start_time, GETUTCDATE()) < 4
group by start_time
order by start_time asc
7 changes: 6 additions & 1 deletion sql/file-stats.sql
Original file line number Diff line number Diff line change
@@ -1 +1,6 @@
select * from qpi.file_stats;
-- Gets the file IO statistics for the current database since the last snapshot
select * from qpi.db_file_stats;

-- Tips:
-- use qpi:snapshot file stats to take more recent file snapshot
-- use qpi.file_stats to get the statistics of all database files (including other databases)
7 changes: 6 additions & 1 deletion sql/queries-blocked.sql
Original file line number Diff line number Diff line change
@@ -1,2 +1,7 @@
SELECT text, blocked_by_query, blocked_by_session_id, wait_time_s, wait_type
FROM qpi.blocked_queries;
FROM qpi.blocked_queries;

-- Tips:
-- You can unblock the query using KILL <blocked_by_session_id> if you are sure that blocking query is stuck.
-- You can find the locks that other queries are holding using:
-- SELECT * FROM qpi.query_locks;
7 changes: 6 additions & 1 deletion sql/queries-top-storage.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,12 @@
-- Returns queries that used more than 0.5 MB of storage IO:
SELECT query_id, [read(MB)] = physical_io_reads_kb/1024,
count_executions,
text,
[Duration(sec)] = CAST(duration_s AS NUMERIC(8,1)), [CPU(sec)] = CAST(cpu_time_ms AS NUMERIC(8,1))/1000
FROM qpi.db_query_exec_stats_history
WHERE physical_io_reads_kb > 512
order by physical_io_reads_kb desc
order by physical_io_reads_kb desc

-- Tip:
-- Use the following query to find the queries by id:
-- select * from qpi.db_queries where query_id = 38
7 changes: 6 additions & 1 deletion sql/queries-waiting-cpu.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,11 @@
-- Returns top 10 recent queries that waited for CPU longer than 50 ms in average:
SELECT TOP 10 query_id, [wait time(sec)] = CAST(wait_time_ms /1000 AS NUMERIC(8,1)),
start_time, end_time, query_text_id, execution_type_desc
FROM qpi.db_query_wait_stats_as_of(null)
WHERE category = 'CPU'
AND wait_time_ms > 50
ORDER BY wait_time_ms DESC
ORDER BY wait_time_ms DESC

-- Tip:
-- Use the following query to find the queries by id:
-- select * from qpi.db_queries where query_id = 38
7 changes: 6 additions & 1 deletion sql/queries-waiting-io.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,11 @@
-- Returns top 10 recent queries that waited for IO longer than 50 ms in average:
SELECT TOP 10 query_id, [wait time(sec)] = CAST(wait_time_ms /1000 AS NUMERIC(8,1)),
start_time, end_time, query_text_id, execution_type_desc
FROM qpi.db_query_wait_stats_as_of(null)
WHERE category = 'Buffer IO'
AND wait_time_ms > 50
ORDER BY wait_time_ms DESC
ORDER BY wait_time_ms DESC

-- Tip:
-- Use the following query to find the queries by id:
-- select * from qpi.db_queries where query_id = 38
7 changes: 6 additions & 1 deletion sql/queries-waiting-memory.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,11 @@
-- Returns top 10 recent queries that waited for memory longer than 50 ms in average:
SELECT TOP 10 query_id, [wait time(sec)] = CAST(wait_time_ms /1000 AS NUMERIC(8,1)),
start_time, end_time, query_text_id, execution_type_desc
FROM qpi.db_query_wait_stats_as_of(null)
WHERE category = 'Memory'
AND wait_time_ms > 50
ORDER BY wait_time_ms DESC
ORDER BY wait_time_ms DESC

-- Tip:
-- Use the following query to find the queries by id:
-- select * from qpi.db_queries where query_id = 38

0 comments on commit 0f6c24e

Please sign in to comment.