Skip to content

Commit

Permalink
SQL Operations Studio 用のファイルを追加
Browse files Browse the repository at this point in the history
  • Loading branch information
MasayukiOzawa committed Nov 19, 2017
1 parent c519e5b commit 63780b9
Show file tree
Hide file tree
Showing 10 changed files with 275 additions and 0 deletions.
14 changes: 14 additions & 0 deletions SQL Operations Studio/Snippets/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
%USERPROFILE%\AppData\Roaming\sqlops\User\snippets 内に「sql.json」を配置することで、ユーザースニペット登録されます。

追加方法の詳細については、次の情報を参照して下さい。
- [Create and use code snippets to quickly create Transact-SQL (T-SQL) scripts in SQL Operations Studio (preview)](https://docs.microsoft.com/en-us/sql/sql-operations-studio/code-snippets)

レポジトリ内のスニペットは「usersql」をプレフィックスとして設定していますので、必要に応じて JSON を変更してください。

スニペットを追加すると、クエリウィンドウにプレフィックスを入力することで、スニペットに登録したクエリを使用することが可能になります。
![イメージ](./img/img01.png)



本リポジトリのスニペットでは、次のクエリが登録されています。
- 利用状況モニター
Binary file added SQL Operations Studio/Snippets/img/img01.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
80 changes: 80 additions & 0 deletions SQL Operations Studio/Snippets/sql.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
{

"利用状況モニター": {
"prefix": "usersqlActivityMonitor",
"body": [
"SELECT",
" es.session_id,",
" er.request_id,",
" er.start_time,",
" es.last_request_start_time,",
" es.last_request_end_time,",
" CASE WHEN er.sql_handle IS NULL",
" THEN ec_text.text",
" ELSE er_text.text",
" END AS text,",
" er.command,",
" es.status,",
" er.wait_type,",
" er.last_wait_type,",
" er.wait_resource,",
" er.database_id,",
" DB_NAME(DB_ID()) AS database_name,",
" er.user_id,",
" er.wait_time,",
" es.cpu_time,",
" er.cpu_time AS exec_requests_cpu_time,",
" er.open_resultset_count,",
" er.open_resultset_count,",
" er.percent_complete,",
" er.estimated_completion_time,",
" es.total_elapsed_time,",
" er.total_elapsed_time AS exec_requests_total_elapsed_time,",
" es.memory_usage,",
" es.total_scheduled_time,",
" es.reads,",
" er.reads AS exec_requests_reads,",
" es.writes,",
" er.writes AS exec_requests_writes,",
" es.logical_reads,",
" er.logical_reads AS exec_requests_logical_reads,",
" es.row_count,",
" er.row_count AS exec_requests_row_count,",
" er.granted_query_memory,",
" er.scheduler_id,",
" er.transaction_isolation_level,",
" er.executing_managed_code,",
" es.lock_timeout,",
" er.lock_timeout as exec_requests_lock_timeout,",
" es.deadlock_priority,",
" er.deadlock_priority AS exec_requests_deadlock_priority,",
" es.host_name,",
" es.program_name,",
" es.login_time,",
" es.login_name,",
" es.client_version,",
" es.client_interface_name,",
" er.query_hash,",
" er.query_plan_hash",
"FROM",
" sys.dm_exec_sessions es",
" LEFT JOIN",
" sys.dm_exec_requests er",
" ON",
" es.session_id = er.session_id",
" LEFT JOIN",
" (SELECT * FROM sys.dm_exec_connections WHERE most_recent_sql_handle <> 0x0) AS ec",
" ON",
" es.session_id = ec.session_id",
" OUTER APPLY",
" sys.dm_exec_sql_text(er.sql_handle) AS er_text",
" OUTER APPLY",
" sys.dm_exec_sql_text(ec.most_recent_sql_handle) AS ec_text",
"WHERE",
" es.session_id <> @@SPID",
"ORDER BY",
" session_id ASC"
],
"description": "利用状況モニターの情報を表示"
}
}
10 changes: 10 additions & 0 deletions SQL Operations Studio/Widgets/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
ウィジェットで利用する SQL のファイルを「sqlops.exe」の配下に「sql」ディレクトリを作成し、その配下にウィジェットで使用している SQL を配置します。
ウィジェットは、SQL Operations Studio のユーザー定義内に設定しているため、「ファイル -> 基本設定 -> 設定」でユーザー定義を作成し、本リポジトリ内の Setting.json の定義を追加して下さい。

追加方法の詳細については、次の情報を参照して下さい。
- [Tutorial: Enable the table space usage sample insight widget using SQL Operations Studio (preview)](https://docs.microsoft.com/en-us/sql/sql-operations-studio/tutorial-qds-sql-server)
- [Tutorial: Add the five slowest queries sample widget to the database dashboard](https://docs.microsoft.com/en-us/sql/sql-operations-studio/tutorial-qds-sql-server)
- [Manage servers and databases with Insight widgets in SQL Operations Studio (preview)](https://docs.microsoft.com/en-us/sql/sql-operations-studio/insight-widgets)

ウィジェットを追加することで、自分で定義した情報をダッシュボードに表示することができます。
![イメージ](./img/img01.png)
63 changes: 63 additions & 0 deletions SQL Operations Studio/Widgets/Setting.json
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
{
"name": "Buffer Cache",
"gridItemConfig": {
"sizex": 2,
"sizey": 1
},
"widget": {
"insights-widget": {
"type": {
"horizontalBar": {
"dataDirection": "vertical",
"dataType": "number",
"legendPosition": "right",
"labelFirstColumn": false,
"columnsAsLabels": true
}
},
"queryFile": "./sql/BufferCache.sql"
}
}
},
{
"name": "Plan Cache",
"gridItemConfig": {
"sizex": 2,
"sizey": 1
},
"widget": {
"insights-widget": {
"type": {
"horizontalBar": {
"dataDirection": "vertical",
"dataType": "number",
"legendPosition": "right",
"labelFirstColumn": false,
"columnsAsLabels": true
}
},
"queryFile": "./sql/PlanCache.sql"
}
}
},
{
"name": "OS Info",
"gridItemConfig": {
"sizex": 1,
"sizey": 1
},
"widget": {
"insights-widget": {
"type": {
"count": {
"dataDirection": "vertical",
"dataType": "number",
"legendPosition": "none",
"labelFirstColumn": false,
"columnsAsLabels": false
}
},
"queryFile": "./sql/OSInfo.sql"
}
}
}
Binary file added SQL Operations Studio/Widgets/img/img01.png
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
73 changes: 73 additions & 0 deletions SQL Operations Studio/Widgets/sql/ActivityMonitor.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
SELECT
es.session_id,
er.request_id,
er.start_time,
es.last_request_start_time,
es.last_request_end_time,
CASE WHEN er.sql_handle IS NULL
THEN ec_text.text
ELSE er_text.text
END AS text,
er.command,
es.status,
er.wait_type,
er.last_wait_type,
er.wait_resource,
er.database_id,
DB_NAME(DB_ID()) AS database_name,
er.user_id,
er.wait_time,
es.cpu_time,
er.cpu_time AS exec_requests_cpu_time,
er.open_resultset_count,
er.open_resultset_count,
er.percent_complete,
er.estimated_completion_time,
es.total_elapsed_time,
er.total_elapsed_time AS exec_requests_total_elapsed_time,
es.memory_usage,
es.total_scheduled_time,
es.reads,
er.reads AS exec_requests_reads,
es.writes,
er.writes AS exec_requests_writes,
es.logical_reads,
er.logical_reads AS exec_requests_logical_reads,
es.row_count,
er.row_count AS exec_requests_row_count,
er.granted_query_memory,
er.scheduler_id,
er.transaction_isolation_level,
er.executing_managed_code,
es.lock_timeout,
er.lock_timeout as exec_requests_lock_timeout,
es.deadlock_priority,
er.deadlock_priority AS exec_requests_deadlock_priority,
es.host_name,
es.program_name,
es.login_time,
es.login_name,
es.client_version,
es.client_interface_name,
er.query_hash,
er.query_plan_hash
FROM
sys.dm_exec_sessions es
LEFT JOIN
sys.dm_exec_requests er
ON
es.session_id = er.session_id
LEFT JOIN
(SELECT * FROM sys.dm_exec_connections WHERE most_recent_sql_handle <> 0x0) AS ec
ON
es.session_id = ec.session_id
OUTER APPLY
sys.dm_exec_sql_text(er.sql_handle) AS er_text
OUTER APPLY
sys.dm_exec_sql_text(ec.most_recent_sql_handle) AS ec_text
WHERE
es.session_id <> @@SPID
ORDER BY
session_id ASC


16 changes: 16 additions & 0 deletions SQL Operations Studio/Widgets/sql/BufferCache.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
SELECT
CASE database_id
WHEN 32767 THEN 'ResourceDb'
ELSE db_name(database_id)
END AS [Database_name],
count(*) * 8.0 AS [Page Size (KB)]
FROM
[sys].[dm_os_buffer_descriptors] WITH (NOLOCK)
GROUP BY
db_name(database_id),
[database_id],
[is_in_bpool_extension]
ORDER BY
[database_id] ASC,
[is_in_bpool_extension] ASC
OPTION (RECOMPILE)
9 changes: 9 additions & 0 deletions SQL Operations Studio/Widgets/sql/OSInfo.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
SELECT
cpu_count,
hyperthread_ratio,
cores_per_socket,
physical_memory_kb,
max_workers_count
FROM
sys.dm_os_sys_info
GO
10 changes: 10 additions & 0 deletions SQL Operations Studio/Widgets/sql/PlanCache.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
SELECT
[cacheobjtype] + ':' + [objtype] AS [Type],
SUM(CONVERT(bigint, [size_in_bytes])) / 1024.0 AS [size_in_bytes (KB)]
FROM
[sys].[dm_exec_cached_plans] WITH (NOLOCK)
GROUP BY
[cacheobjtype],
[objtype]
OPTION (RECOMPILE)

0 comments on commit 63780b9

Please sign in to comment.