Fixed all cost metrics to be base 10 in Log analytics queries and in serverless workbook. Also added query perf page.
This commit is contained in:
Nick Salch 2023-01-17 11:26:03 -08:00
Родитель a684d88057
Коммит 97b9d4f568
8 изменённых файлов: 2132 добавлений и 37 удалений

Просмотреть файл

@ -7,13 +7,15 @@ SynapseBuiltinSqlPoolRequestsEnded
QueryHash=tostring(Properties.queryHash),
QueryText=tostring(Properties.queryText),
_ResourceId
| extend MbProcessed = case (BytesProcessed < 10000000,10000000,
BytesProcessed)/1000/1000
| summarize
MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024),
TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),
MaxSingleQueryMBProcessed=max(toint(MbProcessed)),
TotalMBProcessed=sum(toint(MbProcessed)),
QueryCount=count(),
QueryHash=any(QueryHash) ,
Resource=any(_ResourceId)
by QueryText //using queryText because queryHash doesnt change if only literals are different
| extend Approx_Accumulated_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)
| extend Approx_Cost_Per_Execution=((TotalMBProcessed)*0.000476837158203125)/100/QueryCount
| order by TotalMBProcessed
| extend Approx_Accumulated_Cost=((TotalMBProcessed)*5.0/100000.0)/100
| extend Approx_Cost_Per_Execution=((TotalMBProcessed)*5.0/100000.0)/100/QueryCount
| order by TotalMBProcessed

Просмотреть файл

@ -0,0 +1,19 @@
//Cost per query
SynapseBuiltinSqlPoolRequestsEnded
//| where _ResourceId has 'contosoprod'
| project
BytesProcessed=Properties.dataProcessedBytes,
tostring(Identity),
QueryHash=tostring(Properties.queryHash),
QueryText=tostring(Properties.queryText),
_ResourceId
| summarize
MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024),
TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),
QueryCount=count(),
QueryHash=any(QueryHash) ,
Resource=any(_ResourceId)
by QueryText //using queryText because queryHash doesnt change if only literals are different
| extend Approx_Accumulated_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)
| extend Approx_Cost_Per_Execution=((TotalMBProcessed)*0.000476837158203125)/100/QueryCount
| order by TotalMBProcessed

Просмотреть файл

@ -1,7 +1,14 @@
//Query cost by User
SynapseBuiltinSqlPoolRequestsEnded
//| where _ResourceId has 'contosoprod'
| project BytesProcessed=Properties.dataProcessedBytes,tostring(Identity),_ResourceId
| summarize TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),QueryCount=count(),MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024),Resource=any(_ResourceId) by Identity
| extend Approx_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)
| order by TotalMBProcessed
| project BytesProcessed=Properties.dataProcessedBytes
, tostring(Identity)
| extend MbProcessed = case (BytesProcessed < 10000000,10000000,
BytesProcessed)/1000/1000
| summarize
TotalMBProcessed=sum(toint(MbProcessed)),
QueryCount=count(),
MaxSingleQueryMBProcessed=max(toint(MbProcessed) )
by Identity
| extend Approx_Cost=((TotalMBProcessed) *5.0/100000.0) / 100
| order by TotalMBProcessed

Просмотреть файл

@ -0,0 +1,7 @@
//Query cost by User
SynapseBuiltinSqlPoolRequestsEnded
//| where _ResourceId has 'contosoprod'
| project BytesProcessed=Properties.dataProcessedBytes,tostring(Identity),_ResourceId
| summarize TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),QueryCount=count(),MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024),Resource=any(_ResourceId) by Identity
| extend Approx_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)
| order by TotalMBProcessed

Просмотреть файл

@ -15,7 +15,7 @@
"name": "TimeRange",
"type": 4,
"value": {
"durationMs": 259200000
"durationMs": 43200000
},
"typeSettings": {
"selectableValues": [
@ -87,7 +87,10 @@
"includeAll": false,
"showDefault": false
},
"defaultValue": "value::all"
"defaultValue": "value::all",
"value": [
"value::all"
]
},
{
"id": "3dbc1029-1a17-4a4d-a133-2d47c1e7844e",
@ -113,7 +116,10 @@
},
"defaultValue": "value::all",
"queryType": 1,
"resourceType": "microsoft.resourcegraph/resources"
"resourceType": "microsoft.resourcegraph/resources",
"value": [
"value::all"
]
},
{
"id": "4d1459db-354e-4019-8e86-015d946ce892",
@ -151,7 +157,7 @@
{
"type": 1,
"content": {
"json": "All costs listed in this workbook are approximate based on $5/TB. The cost listed here has not yet been extensively validated.",
"json": "All costs listed in this workbook are approximate based on $5/TB and data processed is set to a minimum of 10MB. All calculations in the query results are using the charged data processed as opposed to the actual data processed. ",
"style": "warning"
},
"name": "text - 4"
@ -177,6 +183,14 @@
"linkLabel": "Data Processed",
"subTarget": "DataProcessed",
"style": "link"
},
{
"id": "7c0e9efd-a60a-40d7-a290-12133a09a440",
"cellValue": "GroupSelection",
"linkTarget": "parameter",
"linkLabel": "Query Performance",
"subTarget": "QueryPerformance",
"style": "link"
}
]
},
@ -203,7 +217,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -259,7 +273,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -317,7 +331,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -374,7 +388,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -411,7 +425,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -447,7 +461,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 604800000
"durationMs": 86400000
},
"metrics": [
{
@ -541,7 +555,7 @@
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Most Recent Query Runs\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| order by TimeGenerated\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n StartTime=Properties.startTime,\r\n EndTime=Properties.endTime, \r\n Identity,\r\n CommandType=Properties.command,\r\n Result=ResultType,\r\n MbProcessed=(Properties.dataProcessedBytes/1024/1024),\r\n QueryText=Properties.queryText,\r\n _ResourceId\r\n| extend elapsedTime_sec =(todatetime(EndTime) - StartTime)/1s\r\n| extend Approx_Cost=((MbProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)\r\n| project-reorder StartTime,EndTime,elapsedTime_sec,Identity,CommandType,Result,MbProcessed,Approx_Cost\r\n",
"query": "//Most Recent Query Runs\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| order by TimeGenerated\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n StartTime=Properties.startTime,\r\n EndTime=Properties.endTime, \r\n Identity,\r\n CommandType=Properties.command,\r\n Result=ResultType,\r\n MbProcessed=(Properties.dataProcessedBytes/1000/1000),\r\n QueryText=Properties.queryText,\r\n _ResourceId\r\n| extend elapsedTime_sec =(todatetime(EndTime) - StartTime)/1s\r\n| extend Approx_Cost=((MbProcessed)*5.0/100000.0)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)\r\n| project-reorder StartTime,EndTime,elapsedTime_sec,Identity,CommandType,Result,MbProcessed,Approx_Cost\r\n",
"size": 2,
"showAnalytics": true,
"title": "Recent Queries",
@ -626,6 +640,101 @@
},
"showPin": true,
"name": "Recent Queries"
},
{
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Overall concurrency\r\nlet snapshotTelemetryInterval = 1m;//1m;//1h;//30m;//Do not change\r\nlet minTelemetryDate = toscalar(SynapseSqlPoolExecRequests | summarize min(StartTime));\r\nlet maxTelemetryDate = toscalar(SynapseSqlPoolExecRequests | summarize max(EndTime));\r\nlet timeIntervals = range SnapshotTimeStamp from bin(minTelemetryDate, snapshotTelemetryInterval) to bin(maxTelemetryDate, snapshotTelemetryInterval) step snapshotTelemetryInterval;\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| order by TimeGenerated\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n StartTime=todatetime(Properties.startTime),\r\n EndTime=todatetime(Properties.endTime), \r\n MbProcessed=(Properties.dataProcessedBytes/1000/1000)\r\n| extend elapsedTime_sec =(EndTime - StartTime)/1s\r\n| mv-expand TimeInterval=range(bin(StartTime, snapshotTelemetryInterval), bin(EndTime, snapshotTelemetryInterval) , snapshotTelemetryInterval) limit 100000\r\n| summarize ActiveQueryCount=count(),sum(MbProcessed),avg(elapsedTime_sec) by todatetime(TimeInterval)\r\n",
"size": 2,
"showAnalytics": true,
"title": "Concurrency",
"timeContextFromParameter": "TimeRange",
"timeBrushParameterName": "TimeRange",
"queryType": 0,
"resourceType": "microsoft.operationalinsights/workspaces",
"crossComponentResources": [
"{LogAnalyticsWorkspace}"
],
"visualization": "linechart",
"gridSettings": {
"formatters": [
{
"columnMatch": "StartTime",
"formatter": 6
},
{
"columnMatch": "EndTime",
"formatter": 6
},
{
"columnMatch": "elapsedTime_sec",
"formatter": 8,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Result",
"formatter": 18,
"formatOptions": {
"thresholdsOptions": "icons",
"thresholdsGrid": [
{
"operator": "Default",
"thresholdValue": null,
"representation": "success",
"text": "{0}{1}"
}
]
}
},
{
"columnMatch": "MbProcessed",
"formatter": 3,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Approx_Cost",
"formatter": 8,
"formatOptions": {
"palette": "yellow"
},
"numberFormat": {
"unit": 0,
"options": {
"style": "decimal",
"minimumFractionDigits": 2,
"maximumFractionDigits": 6
}
}
},
{
"columnMatch": "QueryText",
"formatter": 7,
"formatOptions": {
"linkTarget": "CellDetails",
"linkIsContextBlade": true,
"customColumnWidthSetting": "100ch"
}
},
{
"columnMatch": "BytesProcessed",
"formatter": 8,
"formatOptions": {
"palette": "red"
}
}
]
},
"graphSettings": {
"type": 0
}
},
"showPin": true,
"name": "Concurrency"
}
]
},
@ -713,7 +822,7 @@
],
"timeContextFromParameter": "TimeRange",
"timeContext": {
"durationMs": 0
"durationMs": 86400000
},
"metrics": [
{
@ -738,13 +847,10 @@
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Queries by completion type\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n BytesProcessed=Properties.dataProcessedBytes,\r\n tostring(Identity),\r\n QueryHash=tostring(Properties.queryHash),\r\n QueryText=tostring(Properties.queryText)\r\n| summarize \r\n MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024),\r\n TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),\r\n QueryCount=count(),\r\n QueryHash=any(QueryHash) \r\n by QueryText //using queryText because queryHash doesn't seem to be different between queries\r\n| extend Approx_Accumulated_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)\r\n| extend Approx_Cost_Per_Execution=((TotalMBProcessed)*0.000476837158203125)/100/QueryCount\r\n| order by TotalMBProcessed\r\n",
"query": "//Queries by completion type\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n BytesProcessed=Properties.dataProcessedBytes,\r\n tostring(Identity),\r\n QueryHash=tostring(Properties.queryHash),\r\n QueryText=tostring(Properties.queryText),\r\n _ResourceId\r\n| extend MbProcessed = case (BytesProcessed < 10000000,10000000,\r\n\t\t\t\t\t\t\tBytesProcessed)/1000/1000\r\n| summarize \r\n MaxSingleQueryMBProcessed=max(toint(MbProcessed)),\r\n TotalMBProcessed=sum(toint(MbProcessed)),\r\n QueryCount=count(),\r\n QueryHash=any(QueryHash) ,\r\n Resource=any(_ResourceId)\r\n by QueryText //using queryText because queryHash doesnt change if only literals are different\r\n| extend Approx_Accumulated_Cost=((TotalMBProcessed)*5.0/100000.0)/100 \r\n| extend Approx_Cost_Per_Execution=((TotalMBProcessed)*5.0/100000.0)/100/QueryCount\r\n| order by TotalMBProcessed\r\n",
"size": 0,
"showAnalytics": true,
"title": "Data Processed By Query",
"timeContext": {
"durationMs": 0
},
"timeContextFromParameter": "TimeRange",
"queryType": 0,
"resourceType": "microsoft.operationalinsights/workspaces",
@ -859,13 +965,10 @@
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Queries by completion type\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| where _ResourceId in~ ({Synapse})\r\n| project BytesProcessed=Properties.dataProcessedBytes,tostring(Identity)\r\n| summarize TotalMBProcessed=sum(toint(BytesProcessed)/1024/1024),QueryCount=count(),MaxSingleQueryMBProcessed=max(toint(BytesProcessed)/1024/1024) by Identity\r\n| extend Approx_Cost=((TotalMBProcessed)*0.000476837158203125)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)\r\n| order by TotalMBProcessed\r\n",
"query": "//Queries by completion type\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| where _ResourceId in~ ({Synapse})\r\n| project BytesProcessed=Properties.dataProcessedBytes\r\n\t\t, tostring(Identity)\r\n| extend MbProcessed = case (BytesProcessed < 10000000,10000000,\r\n BytesProcessed)/1000/1000\r\n| summarize\r\n TotalMBProcessed=sum(toint(MbProcessed)),\r\n QueryCount=count(),\r\n MaxSingleQueryMBProcessed=max(toint(MbProcessed) )\r\n by Identity\r\n| extend Approx_Cost=((TotalMBProcessed) *5.0/100000.0) / 100 \r\n| order by TotalMBProcessed",
"size": 0,
"showAnalytics": true,
"title": "Data Processed By User with $5 per TB cost",
"timeContext": {
"durationMs": 0
},
"timeContextFromParameter": "TimeRange",
"exportFieldName": "Identity",
"exportParameterName": "Identity",
@ -950,9 +1053,6 @@
"size": 2,
"title": "Query Summary for User by Data Processed",
"noDataMessage": "Select a user to see their query history",
"timeContext": {
"durationMs": 1209600000
},
"timeContextFromParameter": "TimeRange",
"queryType": 0,
"resourceType": "microsoft.operationalinsights/workspaces",
@ -1018,6 +1118,224 @@
"value": "DataProcessed"
},
"name": "DataProcessed"
},
{
"type": 12,
"content": {
"version": "NotebookGroup/1.0",
"groupType": "editable",
"title": "Query Performance",
"items": [
{
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Most Recent Query Runs\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| order by TimeGenerated\r\n| where _ResourceId in~ ({Synapse})\r\n| project \r\n StartTime=Properties.startTime,\r\n EndTime=Properties.endTime, \r\n Identity,\r\n CommandType=Properties.command,\r\n Result=ResultType,\r\n MbProcessed=(Properties.dataProcessedBytes/1000/1000),\r\n QueryText=Properties.queryText,\r\n QueryHash=Properties.queryHash,\r\n _ResourceId\r\n| extend elapsedTime_sec =(todatetime(EndTime) - StartTime)/1s\r\n| extend Approx_Cost=((MbProcessed)*5.0/100000.0)/100 //multiply by price per mb ($5 per TB from Microsoft Docs: https://azure.microsoft.com/en-us/pricing/details/synapse-analytics/)\r\n| project-reorder StartTime,EndTime,elapsedTime_sec,Identity,CommandType,Result,MbProcessed,Approx_Cost\r\n",
"size": 2,
"showAnalytics": true,
"title": "Recent Queries",
"exportFieldName": "QueryHash",
"exportParameterName": "QueryHash",
"queryType": 0,
"resourceType": "microsoft.operationalinsights/workspaces",
"crossComponentResources": [
"{LogAnalyticsWorkspace}"
],
"gridSettings": {
"formatters": [
{
"columnMatch": "StartTime",
"formatter": 6
},
{
"columnMatch": "EndTime",
"formatter": 6
},
{
"columnMatch": "elapsedTime_sec",
"formatter": 8,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Result",
"formatter": 18,
"formatOptions": {
"thresholdsOptions": "icons",
"thresholdsGrid": [
{
"operator": "Default",
"thresholdValue": null,
"representation": "success",
"text": "{0}{1}"
}
]
}
},
{
"columnMatch": "MbProcessed",
"formatter": 3,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Approx_Cost",
"formatter": 8,
"formatOptions": {
"palette": "yellow"
},
"numberFormat": {
"unit": 0,
"options": {
"style": "decimal",
"minimumFractionDigits": 2,
"maximumFractionDigits": 6
}
}
},
{
"columnMatch": "QueryText",
"formatter": 7,
"formatOptions": {
"linkTarget": "CellDetails",
"linkIsContextBlade": true,
"customColumnWidthSetting": "100ch"
}
},
{
"columnMatch": "BytesProcessed",
"formatter": 8,
"formatOptions": {
"palette": "red"
}
}
]
}
},
"showPin": true,
"name": "Recent Queries - Copy"
},
{
"type": 1,
"content": {
"json": "Select a query to view graphical history of each run"
},
"name": "text - 2"
},
{
"type": 3,
"content": {
"version": "KqlItem/1.0",
"query": "//Most Recent Query Runs\r\nSynapseBuiltinSqlPoolRequestsEnded\r\n| order by TimeGenerated\r\n| where _ResourceId in~ ({Synapse})\r\n| where Properties.queryHash == {QueryHash}\r\n| project \r\n StartTime=Properties.startTime,\r\n EndTime=Properties.endTime, \r\n Identity,\r\n RequestId=Properties.clientRequestId,\r\n StatementId = Properties.distributedStatementId,\r\n CommandType=Properties.command,\r\n Result=ResultType,\r\n MbProcessed=(Properties.dataProcessedBytes/1000/1000),\r\n QueryText=Properties.queryText,\r\n QueryHash=Properties.queryHash,\r\n _ResourceId\r\n| extend elapsedTime_sec =(todatetime(EndTime) - StartTime)/1s\r\n| extend Approx_Cost=((MbProcessed)*5.0/100000.0)/100 \r\n| project-reorder StartTime,EndTime,elapsedTime_sec,Identity,RequestId,StatementId,CommandType,Result,MbProcessed,Approx_Cost\r\n",
"size": 2,
"showAnalytics": true,
"title": "Selected Query History",
"noDataMessage": "Please select a query to view run history",
"queryType": 0,
"resourceType": "microsoft.operationalinsights/workspaces",
"crossComponentResources": [
"{LogAnalyticsWorkspace}"
],
"visualization": "linechart",
"gridSettings": {
"formatters": [
{
"columnMatch": "StartTime",
"formatter": 6
},
{
"columnMatch": "EndTime",
"formatter": 6
},
{
"columnMatch": "elapsedTime_sec",
"formatter": 8,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Result",
"formatter": 18,
"formatOptions": {
"thresholdsOptions": "icons",
"thresholdsGrid": [
{
"operator": "Default",
"thresholdValue": null,
"representation": "success",
"text": "{0}{1}"
}
]
}
},
{
"columnMatch": "MbProcessed",
"formatter": 3,
"formatOptions": {
"palette": "blue"
}
},
{
"columnMatch": "Approx_Cost",
"formatter": 8,
"formatOptions": {
"palette": "yellow"
},
"numberFormat": {
"unit": 0,
"options": {
"style": "decimal",
"minimumFractionDigits": 2,
"maximumFractionDigits": 6
}
}
},
{
"columnMatch": "QueryText",
"formatter": 7,
"formatOptions": {
"linkTarget": "CellDetails",
"linkIsContextBlade": true,
"customColumnWidthSetting": "100ch"
}
},
{
"columnMatch": "BytesProcessed",
"formatter": 8,
"formatOptions": {
"palette": "red"
}
}
]
},
"chartSettings": {
"xAxis": "EndTime",
"yAxis": [
"elapsedTime_sec",
"MbProcessed"
],
"showDataPoints": true
}
},
"conditionalVisibility": {
"parameterName": "QueryHash",
"comparison": "isNotEqualTo",
"value": ""
},
"showPin": true,
"name": "SelectedQueryHistory"
}
]
},
"conditionalVisibility": {
"parameterName": "GroupSelection",
"comparison": "isEqualTo",
"value": "QueryPerformance"
},
"name": "QueryPerformance"
}
],
"fallbackResourceIds": [

Разница между файлами не показана из-за своего большого размера Загрузить разницу

Просмотреть файл

@ -1,5 +1,5 @@
/***************************************************************************
Synapse Toolkit v2.1_beta, 10/31/22
Synapse Toolkit
The Synapse Toolkit is a set of stored procedures that help investigate
current activity on your Synapse Dedicated SQL Pool. sp_status is the overall
@ -33,7 +33,7 @@ GO
ALTER PROC [dbo].[sp_status] AS
PRINT 'Synapse Toolkit v2.0_beta, 10/13/22'
PRINT 'Synapse Toolkit v2.1_beta, 11/15/22'
EXEC sp_concurrency;
EXEC sp_requests;
@ -77,7 +77,7 @@ SELECT
,sum(ner.cpu_time)/1000 AS 'step_cpu_time'
,sum(ner.reads) AS 'step_reads'
,sum(ner.writes) AS 'step_writes'
--,sum(ner.logical_reads) AS 'total_logical_reads'
--,sum(ner.logical_reads) AS 'total_logical_reads'ok, i'
,max(ner.granted_query_memory) AS 'step_total_granted_memory_pages'
,round(log(sum(g.query_cost)),2) AS 'step_cost'
,'EXEC sp_requests_detail @request_id=''' + r.request_id + '''' AS 'request_detail_command'
@ -181,6 +181,7 @@ SELECT
,dist.end_time
,dist.spid
,rs.command
,dist.source_info AS 'distribution_source_command'
,dist.error_id
FROM
(--dms
@ -201,6 +202,7 @@ SELECT
,bytes_processed
,rows_processed AS row_count
,command AS dist_text
,source_info
FROM sys.dm_pdw_dms_workers
WHERE request_id = @request_id
@ -217,7 +219,8 @@ SELECT
,start_time
,end_time
,total_elapsed_time
,command
,command
,-1 AS 'distribution_source_command'
,error_id
,spid
,-1 AS bytes_per_sec
@ -232,7 +235,7 @@ RIGHT JOIN sys.dm_pdw_request_steps rs
ON rs.request_id = dist.request_id
AND rs.step_index = dist.step_index
WHERE rs.request_id = @request_id
ORDER BY rs.step_index,dist.pdw_node_id,dist.distribution_id
ORDER BY rs.step_index,dist.pdw_node_id,dist.distribution_id,dist.type
OPTION(LABEL='SynapseToolkit')
GO

Просмотреть файл

@ -0,0 +1,712 @@
/***************************************************************************
Synapse Toolkit
The Synapse Toolkit is a set of stored procedures that help investigate
current activity on your Synapse Dedicated SQL Pool. sp_status is the overall
summary procedure that calls various other procedures to provide a picture
of current activity. Use the detail_command columns to deep dive into a
particular session, query, or wait.
List of SPs currently included:
sp_status
sp_concurrency
sp_requests
sp_reqeusts_detail
sp_sessions
sp_sessions_detail
sp_waits
sp_waits_detail
sp_datamovement
****************************************************************************/
/***************************************************************************
Procedure name: sp_status
Description:
Runs a few of the included SPs to give overall system utilization.
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_status')
EXEC ('CREATE PROC dbo.sp_status AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_status] AS
PRINT 'Synapse Toolkit v2.1_beta, 11/15/22'
EXEC sp_concurrency;
EXEC sp_requests;
EXEC sp_datamovement
GO
/***************************************************************************
Procedure name: sp_requests
Description:
Collects running requests and suspended requests in two separate result windows.
A running request provides a sp_requests_details query to see the plan for the
running query. A suspended request provides the sp_waits_detail query so you can
see why the query is in the suspended state.
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_requests')
EXEC ('CREATE PROC dbo.sp_requests AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_requests] AS
SELECT
'Running Request' AS 'Running Requests'
,s.session_id
,r.request_id
--,r.status
,r.command
,r.resource_allocation_percentage AS 'resource_grant'
,s.login_name
,r.submit_time
,r.end_compile_time
,r.total_elapsed_time
,r.[label]
,r.classifier_name
,r.group_name
,ISNULL(r.command2, r.command) AS 'query_text'
,r.result_cache_hit
--,psr.step_index
--,prs.operation_type
--,prs.status
,sum(ner.cpu_time)/1000 AS 'step_cpu_time'
,sum(ner.reads) AS 'step_reads'
,sum(ner.writes) AS 'step_writes'
--,sum(ner.logical_reads) AS 'total_logical_reads'ok, i'
,max(ner.granted_query_memory) AS 'step_total_granted_memory_pages'
,round(log(sum(g.query_cost)),2) AS 'step_cost'
,'EXEC sp_requests_detail @request_id=''' + r.request_id + '''' AS 'request_detail_command'
,'EXEC sp_sessions_detail @session_id=''' + s.session_id + '''' AS 'session_detail_command'
FROM sys.dm_pdw_exec_requests r
JOIN sys.dm_pdw_exec_sessions s
on r.session_id = s.session_id
LEFT JOIN sys.dm_pdw_request_steps rs
ON r.request_id = rs.request_id
LEFT JOIN sys.dm_pdw_sql_requests sr
ON rs.request_id = sr.request_id
AND rs.step_index = sr.step_index
LEFT JOIN sys.dm_pdw_nodes_exec_requests ner
ON sr.spid = ner.session_id
AND sr.pdw_node_id = ner.pdw_node_id
LEFT JOIN sys.dm_pdw_nodes_exec_query_memory_grants g
ON ner.session_id = g.session_id
AND ner.pdw_node_id = g.pdw_node_id
WHERE (r.group_name is not null OR r.result_cache_hit = 1)
AND rs.[status] = 'Running'
GROUP BY r.request_id
--,r.[status]
,r.request_id
,r.status
,r.command
,r.command2
,r.resource_allocation_percentage
,s.session_id
,s.login_name
,r.submit_time
,r.end_compile_time
,r.total_elapsed_time
,r.[label]
,r.classifier_name
,r.group_name
--,ISNULL(r.command2, r.command)
,r.result_cache_hit
OPTION(LABEL='SynapseToolkit')
SELECT 'Suspended Request' AS 'Suspended Requests'
,s.session_id
,r.request_id
,s.login_name
,r.submit_time
,r.total_elapsed_time AS 'wait_time'
,r.[label]
,r.classifier_name
,ISNULL(r.command2, r.command) AS 'query_text'
,w.resource_waits AS 'concurrency_waits'
,w.object_waits AS 'object_waits'
,'EXEC sp_waits_detail @request_id=''' + r.request_id + '''' AS 'waits_detail'
,'EXEC sp_sessions_detail @session_id=''' + r.session_id + '''' AS 'session_detail_command'
FROM sys.dm_pdw_exec_requests r
JOIN sys.dm_pdw_exec_sessions s
on r.session_id = s.session_id
LEFT JOIN (
SELECT
request_id
,SUM(CASE WHEN object_type = 'SYSTEM' THEN 1 ELSE 0 END) AS resource_waits
,SUM(CASE WHEN object_type != 'SYSTEM' THEN 1 ELSE 0 END) AS object_waits
FROM sys.dm_pdw_waits
WHERE state != 'Granted'
GROUP BY request_id
) w
ON r.request_id = w.request_id
WHERE r.[status] = 'Suspended'
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_requests_detail
Description:
Provides the detailed query plan for the specified requestID. This shows
a results at the distribution-level. Use Step_index to determine
which step you are looking at.
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_requests_detail')
EXEC ('CREATE PROC dbo.sp_requests_detail AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_requests_detail] @request_id [varchar](20) AS
--Query Step Data
SELECT
'Query Plan' AS 'Query Plan'
,rs.request_id
,rs.step_index
,rs.operation_type
,rs.[status] AS 'step_status'
,rs.estimated_rows AS 'step_estimated_rows'
,rs.row_count AS 'step_actual_rows'
,rs.total_elapsed_time AS 'step_elapsed_time'
,dist.pdw_node_id
,dist.distribution_id
,dist.[type] AS 'distribution_step_type'
,dist.[status] AS 'distribution_step_status'
,dist.total_elapsed_time AS 'distribution_elapsed_time'
,dist.bytes_per_sec
,dist.bytes_processed
,dist.row_count
,dist.start_time
,dist.end_time
,dist.spid
,rs.command
,dist.error_id
FROM
(--dms
SELECT
request_id
,step_index
,pdw_node_id
,distribution_id
,type
,status
,start_time
,end_time
,total_elapsed_time
,command
,error_id
,sql_spid AS spid
,bytes_per_sec
,bytes_processed
,rows_processed AS row_count
,command AS dist_text
FROM sys.dm_pdw_dms_workers
WHERE request_id = @request_id
UNION ALL
--sql
SELECT
request_id
,step_index
,pdw_node_id
,distribution_id
,'SQL' AS type
,[status]
,start_time
,end_time
,total_elapsed_time
,command
,error_id
,spid
,-1 AS bytes_per_sec
,-1 AS bytes_processed
,row_count
,command AS dist_text
FROM sys.dm_pdw_sql_requests
WHERE request_id = @request_id
AND command not like '%DISTRIBUTED_MOVE%'
) dist
RIGHT JOIN sys.dm_pdw_request_steps rs
ON rs.request_id = dist.request_id
AND rs.step_index = dist.step_index
WHERE rs.request_id = @request_id
ORDER BY rs.step_index,dist.pdw_node_id,dist.distribution_id,dist.type
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_waits
Description:
Collects information on granted and queued object and resource (concurrency)
waits. Provides statements for waits_detail queries to get more information on
what is blocking what.
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_waits')
EXEC ('CREATE PROC dbo.sp_waits AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_waits] AS
--Granted Object Locks
SELECT 'Granted Object Lock' AS 'Granted Object Locks'
,w.session_id
,w.request_id
,r.[status] AS 'request_status'
,w.[state] AS 'wait_state'
,w.[type]
,w.object_type
,w.[object_name]
,r.importance
,r.classifier_name
,r.group_name
,w.priority
,w.request_time
,w.acquire_time
,r.total_elapsed_time AS 'request_elapsed_time'
,r.[label]
,ISNULL(r.command2, r.command) AS 'query_text'
--,'EXEC sp_waits_detail @request_id=''' + w.request_id + '''' AS 'detail_command'
FROM sys.dm_pdw_waits w
JOIN sys.dm_pdw_exec_requests r
ON w.request_id = r.request_id
WHERE w.object_type != 'SYSTEM'
AND w.[state]='Granted'
AND r.[status] != 'Completed'
AND w.session_id != SESSION_ID()
ORDER BY r.[status],r.start_time,r.submit_time,w.priority asc
OPTION(LABEL='SynapseToolkit')
--Queued Locks
SELECT 'Queued Object Lock' AS 'Queued Object Locks'
,w.session_id
,w.request_id
,r.[status] AS 'request_status'
,w.[state] AS 'wait_state'
,w.[type]
,w.object_type
,w.[object_name]
,r.importance
,r.classifier_name
,r.group_name
,w.priority
,w.request_time
,w.acquire_time
,r.total_elapsed_time AS 'request_elapsed_time'
,r.[label]
,ISNULL(r.command2, r.command) AS 'query_text'
,'EXEC sp_waits_detail @request_id=''' + w.request_id + '''' AS 'detail_command'
FROM sys.dm_pdw_waits w
JOIN sys.dm_pdw_exec_requests r
ON w.request_id = r.request_id
WHERE w.object_type != 'SYSTEM'
AND w.[state]!='Granted'
AND r.[status] != 'Completed'
ORDER BY r.[status],r.start_time,r.submit_time,w.priority asc
OPTION(LABEL='SynapseToolkit')
--Granted concurrency waits
SELECT 'Granted Concurrency Wait' AS 'Granted Concurrency Waits'
,w.session_id
,w.request_id
,r.[status] AS 'request_status'
,w.[state] AS 'wait_state'
,r.resource_allocation_percentage
,r.importance
,r.classifier_name
,r.group_name
,w.priority
,w.request_time
,w.acquire_time
,r.total_elapsed_time AS 'request_elapsed_time'
,r.[label]
,ISNULL(r.command2, r.command) AS 'query_text'
FROM sys.dm_pdw_waits w
JOIN sys.dm_pdw_exec_requests r
on w.request_id = r.request_id
WHERE object_type = 'SYSTEM'
AND w.[state]='Granted'
AND w.[type] NOT IN ('ConcurrencyResourceType','LocalQueriesConcurrencyResourceType')
ORDER BY w.session_id,w.request_id,w.wait_id
OPTION(LABEL='SynapseToolkit')
--Queued concurrency waits
SELECT 'Queued Concurrency Wait' AS 'Queued Concurrency Waits'
,w.session_id
,w.request_id
,r.[status] AS 'request_status'
,w.[state] AS 'wait_state'
,r.resource_allocation_percentage
,r.importance
,r.classifier_name
,r.group_name
,w.priority
,w.request_time
,w.acquire_time
,r.total_elapsed_time AS 'request_elapsed_time'
,r.[label]
,ISNULL(r.command2, r.command) AS 'query_text'
FROM sys.dm_pdw_waits w
JOIN sys.dm_pdw_exec_requests r
on w.request_id = r.request_id
WHERE object_type = 'SYSTEM'
AND w.[state]!='Granted'
AND w.[type] NOT IN ('ConcurrencyResourceType','LocalQueriesConcurrencyResourceType')
ORDER BY w.session_id,w.request_id,w.wait_id
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_waits_detail
Description:
When providing a suspended requestID:
This sp will return all queries that have object locks on the same objects
the provided query is queued on
This query returns a message if a query with no waiting object locks is provided
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_waits_detail')
EXEC ('CREATE PROC dbo.sp_waits_detail AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_waits_detail] @request_id [varchar](20) AS
--If the provided statement is suspended, show what's blocking it
IF (SELECT [status] FROM sys.dm_pdw_exec_requests WHERE request_id = @request_id) = 'Suspended'
BEGIN
IF (SELECT TOP 1 [object_type] FROM sys.dm_pdw_waits WHERE request_id = @request_id AND STATE != 'GRANTED' ) != 'SYSTEM'
BEGIN
--Queued Object Locks for provided query
SELECT 'Blocked Object Lock' AS 'Blocked Object Locks'
,session_id
,request_id
,wait_id
,[state]
,[type]
,object_type
,[object_name]
,priority
,request_time
,acquire_time
FROM sys.dm_pdw_waits
WHERE object_type != 'SYSTEM'
AND [state]!='Granted'
AND request_id = @request_id
ORDER BY session_id,wait_id
OPTION(LABEL='SynapseToolkit')
--Granted Locks on the same objects as in query
SELECT 'Possible Blocker' AS 'Possible Blockers'
,w2.session_id
,w2.request_id
,w2.wait_id
,w2.[state]
,w2.[type]
,w2.object_type
,w2.[object_name]
,w2.priority
,w2.request_time
,w2.acquire_time
,'EXEC sp_requests_detail @request_id=''' + w2.request_id + '''' AS 'request_detail_command'
,'EXEC sp_sessions_detail @session_id=''' + w2.session_id + '''' AS 'session_detail_command'
FROM sys.dm_pdw_waits w1
JOIN sys.dm_pdw_waits w2
ON w1.[object_name] = w2.[object_name]
WHERE w1.request_id = @request_id
AND w2.[state] = 'Granted'
ORDER BY w2.session_id,w2.wait_id
OPTION(LABEL='SynapseToolkit')
END
END
ELSE
BEGIN
SELECT 'No queued object Locks found for ' + @request_id AS 'Message'
END
GO
/***************************************************************************
Procedure name: sp_tempdb
Description: lists various information about tempdb usage
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_tempDB')
EXEC ('CREATE PROC dbo.sp_tempDB AS SELECT ''TEMPORARY''')
GO
ALTER PROC sp_tempDB AS
--Total TempDB Usage
SELECT
'Total TempDB usage' AS 'Total TempDB usage'
,sum(pdw.rows_processed) as 'rows_written'
,sum(pdw.bytes_processed) as 'bytes_written'
,CAST(sum(pdw.bytes_processed)/1024.0/1024.0/1024.0 AS Decimal(10,1)) AS 'GB_written'
,total_tempdb.total_tempdb_gb as 'Total_tempDB_size_GB'
,CAST(((sum(pdw.bytes_processed)/1024.0/1024.0/1024.0)/total_tempdb.total_tempdb_gb)*100.0 AS Decimal(10,1)) AS 'approx_percent_used'
FROM Sys.dm_pdw_dms_workers pdw
JOIN sys.dm_pdw_exec_requests req
ON pdw.request_id = req.request_id
JOIN (SELECT (count(1) * 1995) AS total_tempdb_gb FROM sys.dm_pdw_nodes WHERE type='COMPUTE') AS total_tempdb
ON 1=1
WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY total_tempdb.total_tempdb_gb
--Tempdb usage per query
SELECT
'TempDB per query' AS 'TempDB per query'
,req.request_id
,sum(pdw.bytes_processed) as 'bytes_written'
,CAST(sum(pdw.bytes_processed)/1024.0/1024.0/1024.0 AS Decimal(10,1)) AS 'GB_written'
,sum(pdw.rows_processed) as 'rows_written'
,'EXEC sp_requests_detail @request_id=''' + req.request_id + '''' AS 'request_detail_command'
from Sys.dm_pdw_dms_workers pdw
JOIN sys.dm_pdw_exec_requests req
ON pdw.request_id = req.request_id
WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY req.request_id
ORDER BY bytes_written desc
--Tempdb usage per node
SELECT
'TempDB per node' AS 'TempDB per node'
,pdw.pdw_node_id
,n.type
,sum(pdw.bytes_processed) as 'bytes_written'
,CAST(sum(pdw.bytes_processed)/1024.0/1024.0/1024.0 AS Decimal(10,1)) AS 'GB_written'
,'1995' AS 'Total_tempDB_size_GB'
,CAST(((sum(pdw.bytes_processed)/1024.0/1024.0/1024.0)/1995.0)*100 AS Decimal(10,1)) AS 'percent_used'
,sum(pdw.rows_processed) as 'rows_written'
FROM sys.dm_pdw_nodes n
LEFT JOIN Sys.dm_pdw_dms_workers pdw
ON n.pdw_node_id = pdw.pdw_node_id
LEFT JOIN sys.dm_pdw_exec_requests req
ON pdw.request_id = req.request_id
WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY n.type,pdw.pdw_node_id
ORDER BY bytes_written desc
/***************************************************************************
Procedure name: sp_concurrency
Description:
Shows general information about how many queries are running/suspended
and how many queued object locks or resource (concurrency) locks. Also
shows the currentl percentage of resources allocated to running queries
by workload group assignment
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_concurrency')
EXEC ('CREATE PROC dbo.sp_concurrency AS SELECT ''TEMPORARY''')
GO
ALTER PROC [dbo].[sp_concurrency] AS
SELECT
sum(case when r.status = 'Running' then r.resource_allocation_percentage else 0 end) as 'total_resources_granted'
,tempdb_metrics.percent_used as 'approx_tempdb_used_percent'
--,sum(case when s.status = 'Active' then 1 else 0 end) as 'active_sessions'
--sum(case when s.status = 'Idle' then 1 else 0 end) as 'idle_sessions'
,(SELECT count(1) FROM sys.dm_pdw_exec_sessions where status = 'Active') AS 'active_sessions'
,(SELECT count(1) FROM sys.dm_pdw_exec_sessions where status = 'Idle') AS 'idle_sessions'
,sum(case when r.status = 'Running' AND (r.group_name is not null OR r.result_cache_hit = 1) then 1 else 0 end) as running_queries
,sum(case when r.status = 'suspended' then 1 else 0 end) as queued_queries
,sum(case when w.queued_resource_waits > 0 then 1 else 0 end) AS concurrency_waits
,sum(case when w.queued_object_locks > 0 then 1 else 0 end) AS object_waits
,'EXEC sp_tempdb' AS 'tempdb_usage_detail'
FROM
sys.dm_pdw_exec_requests r
JOIN sys.dm_pdw_exec_sessions s
ON r.session_id = s.session_id
LEFT JOIN (
SELECT
request_id
,count(request_id) AS queued_locks
,sum(case when object_type = 'system' then 1 else 0 end) as queued_resource_waits
,sum(case when object_type != 'system' then 1 else 0 end) as queued_object_locks
FROM sys.dm_pdw_waits
WHERE state != 'Granted'
GROUP BY request_id
) w
ON w.request_id = r.request_id
JOIN (
SELECT
sum(pdw.bytes_processed) as 'bytes_written'
,CAST(sum(pdw.bytes_processed)/1024.0/1024.0/1024.0 AS Decimal(10,1)) AS 'GB_written'
,sum(pdw.rows_processed) as 'rows_written'
,total_tempdb.total_tempdb_gb
,CAST(((sum(pdw.bytes_processed)/1024.0/1024.0/1024.0)/total_tempdb.total_tempdb_gb)*100.0 AS Decimal(10,1)) AS 'percent_used'
FROM Sys.dm_pdw_dms_workers pdw
JOIN sys.dm_pdw_exec_requests req
ON pdw.request_id = req.request_id
JOIN (SELECT (count(1) * 1995) AS total_tempdb_gb FROM sys.dm_pdw_nodes WHERE type='COMPUTE') AS total_tempdb
ON 1=1
WHERE pdw.type = 'Writer'
AND req.status = 'running'
GROUP BY total_tempdb.total_tempdb_gb
) AS tempdb_metrics
ON 1=1
GROUP BY tempdb_metrics.percent_used
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_datamovement
Description:
Shows all data movement currently happening in order from largest to
smallest. The items at the top of this list are likely the most resource-
intensive queries currently running.
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_datamovement')
EXEC ('CREATE PROC dbo.sp_datamovement AS SELECT ''TEMPORARY''')
GO
ALTER PROC sp_datamovement AS
WITH step_data AS
(
SELECT
SUM(rows_processed) AS Step_Rows_Processed
, SUM(Bytes_processed) AS Step_Bytes_Processed
, max(total_elapsed_time) AS Step_elapsed_time
, request_id
, step_index
, status
--, type
FROM sys.dm_pdw_dms_workers
WHERE status != 'StepComplete'
Group by
request_id
, step_index
, status
)
SELECT
'Data Movement' AS 'Data Movements'
,s.login_name
,step_data.request_id
, per.session_id
, rs.operation_type
, (step_data.Step_elapsed_time/1000/60) AS 'step_elapsed_time_(m)'
, step_data.Step_rows_processed
, step_data.step_bytes_processed
, (step_data.Step_Bytes_Processed/1024/1024/1024) AS Step_GB_Processed
, step_data.step_index
--, step_data.type
, step_data.status as Step_status
--, per.status AS QID_Status
, per.total_elapsed_time/1000/60 as 'QID_elapsed_time(m)'
, ISNULL(per.command2, per.command) AS 'QID_Command'
, per.resource_class
, per.importance
,'EXEC sp_requests_detail @request_id=''' + per.request_id + '''' AS 'request_detail_command'
FROM step_data
LEFT JOIN sys.dm_pdw_exec_requests per
ON step_data.request_id = per.request_id
JOIN sys.dm_pdw_exec_sessions s
ON per.session_id = s.session_id
JOIN sys.dm_pdw_request_steps rs
ON step_data.request_id = rs.request_id
AND step_data.step_index = rs.step_index
WHERE per.status = 'Running'
ORDER BY step_data.Step_rows_processed DESC
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_sessions
Description: status of all open sessions
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_sessions')
EXEC ('CREATE PROC dbo.sp_sessions AS SELECT ''TEMPORARY''')
GO
ALTER PROC sp_sessions AS
SELECT
'Active Session' AS 'Active Sessions'
,s.session_id
,s.request_id
,s.login_name
,s.login_time
,s.query_count
,s.client_id
,s.[app_name]
,'EXEC sp_sessions_detail @session_id=''' + s.session_id + '''' AS 'detail_command'
FROM sys.dm_pdw_exec_sessions s
WHERE s.[status] = 'active'
order by login_time asc
OPTION(LABEL='SynapseToolkit')
SELECT
'Idle Session' AS 'Idle Sessions'
,s.session_id
,s.request_id
,s.login_name
,s.login_time
,s.query_count
,s.client_id
,s.[app_name]
,'EXEC sp_sessions_detail @session_id=''' + s.session_id + '''' AS 'detail_command'
FROM sys.dm_pdw_exec_sessions s
WHERE s.[status] = 'idle'
order by login_time asc
OPTION(LABEL='SynapseToolkit')
GO
/***************************************************************************
Procedure name: sp_sessions_detail
Description:
****************************************************************************/
IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'sp_sessions_detail')
EXEC ('CREATE PROC dbo.sp_sessions_detail AS SELECT ''TEMPORARY''')
GO
ALTER PROC sp_sessions_detail @session_id [varchar](20) AS
SELECT
Session_id
,request_id
,[status]
,submit_time
,end_compile_time
,start_time
,end_time
,total_elapsed_time/1000 AS 'total_elapsed_time_s'
,[label]
,error_id
,command
,command2
,classifier_name
,group_name
,importance
,resource_allocation_percentage
,result_cache_hit
,'EXEC sp_requests_detail @request_id=''' + request_id + '''' AS 'detail_command'
FROM sys.dm_pdw_exec_requests
WHERE session_id = @session_id
ORDER BY submit_time ASC
OPTION(LABEL='SynapseToolkit')
/***************************************************************************
Procedure name:
Description:
****************************************************************************/
/*IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = '')
EXEC ('CREATE PROC dbo. AS SELECT ''TEMPORARY''')
GO
*/