EXPLAIN (Transact-SQL)
適用於:Azure Synapse Analytics (僅限專用 SQL 集區)
傳回 Azure Synapse Analytics SQL 的查詢計劃,而不會執行陳述式。 使用 EXPLAIN 預覽哪些作業需要移動資料,以及檢視查詢作業的估計成本。 WITH RECOMMENDATIONS
適用於 Azure Synapse Analytics。
Syntax
EXPLAIN [WITH_RECOMMENDATIONS] SQL_statement
[;]
注意
Azure Synapse Analytics 的無伺服器 SQL 集區不支援此語法。
引數
SQL_statement
將執行 EXPLAIN 的 SQL 陳述式。 SQL_statement 可以是以下任一個命令:SELECT
、INSERT
、UPDATE
、DELETE
、CREATE TABLE AS SELECT
、CREATE REMOTE TABLE
。
WITH_RECOMMENDATIONS
傳回含 SQL 陳述式效能最佳化建議的查詢計劃。
權限
需要 SHOWPLAN 權限,以及執行 SQL_statement 的權限。 請參閱權限:GRANT、DENY、REVOKE (Azure Synapse Analytics、平行處理資料倉儲)。
傳回值
從 EXPLAIN 命令的傳回值是 XML 文件。 此 XML 文件會列出指定查詢之查詢計劃中的所有作業,每個作業都以 <dsql_operation>
標記括住。 傳回值為 nvarchar(max) 類型。
傳回的查詢計劃描述循序 SQL 語句;當查詢執行時,它可能會牽涉到平行化作業,因此顯示的一些循序語句可能會同時執行。
傳回值 XML 的結構如下所示:
\<?xml version="1.0" encoding="utf-8"?>
<dsql_query>
<sql>. . .</sql>
<params />
<dsql_operations>
<dsql_operation>
. . .
</dsql_operation>
[ . . . n ]
<dsql_operations>
</dsql_query>
XML 標記包含這項資訊:
XML 標記 | 摘要、屬性和內容 |
---|---|
<dsql_query> | 最上層/文件元素。 |
<sql> | 回應 SQL_statement。 |
<params> | 目前不使用此標記。 |
<materialized_view_candidates> (預覽) | 包含建議具體化檢視的 CREATE 陳述式,可讓 SQL 陳述式有較好的效能。 |
<dsql_operations> | 摘要說明和包含查詢步驟,並包含查詢的成本資訊。 也包含所有 <dsql_operation> 區塊。 此標記包含整個查詢的計數資訊:<dsql_operations total_cost=total_cost total_number_operations=total_number_operations> total_cost 是查詢執行的預估時間總計,以毫秒為單位。 total_number_operations 是查詢的作業總數。 將平行處理並在多個節點上執行的作業都會計算為單一作業。 |
<dsql_operation> | 描述查詢計劃內的單一作業。 <dsql_operation> 標記包含作為屬性的作業類型:<dsql_operation operation_type=operation_type> operation_type 為可在 sys.dm_pdw_request_steps (Transact-SQL) 中找到的其中一個值。 \<dsql_operation> 區塊中的內容取決於作業類型。請參閱下表。 |
作業類型 | 內容 | 範例 |
---|---|---|
BROADCAST_MOVE、DISTRIBUTE_REPLICATED_TABLE_MOVE、MASTER_TABLE_MOVE、PARTITION_MOVE、SHUFFLE_MOVE 和 TRIM_MOVE | <operation_cost> 元素,具有這些屬性。 值只反映本機作業:- cost 是本機運算子成本,並顯示作業執行的預估時間,以毫秒為單位。 - accumulative_cost 是計劃中包括平行作業加總值的所有所見作業總和,以毫秒為單位。 - average_rowsize 是作業期間,擷取和傳遞之資料列的資料列預估平均大小 (以位元組為單位)。 - output_rows 是輸出 (節點) 基數,並顯示輸出資料列的數目。 <location> :作業發生所在的節點或散發。 選項包括:"Control"、"ComputeNode"、"AllComputeNodes"、"AllDistributions"、"SubsetDistributions"、"Distribution" 和 "SubsetNodes"。<source_statement> :隨機移動的來源資料。<destination_table> :資料將移入的內部暫存資料表。<shuffle_columns> :(只適用於 SHUFFLE_MOVE 作業)。 一或多個將用於暫存資料表之散發資料行的資料行。 |
<operation_cost cost="40" accumulative_cost="40" average_rowsize = "50" output_rows="100"/> <location distribution="AllDistributions" /> <source_statement type="statement">SELECT [TableAlias_3b77ee1d8ccf4a94ba644118b355db9d].[dist_date] FROM [qatest].[dbo].[flyers] [TableAlias_3b77ee1d8ccf4a94ba644118b355db9d] </source_statement> <destination_table>Q_[TEMP_ID_259]_[PARTITION_ID]</destination_table> <shuffle_columns>dist_date;</shuffle_columns> <shuffle_columns>Email;Date;</shuffle_columns> |
MetaDataCreate_Operation | <source_table> :作業的來源資料表。<destination_table> :作業的目的地資料表。 |
<source_table>databases</source_table> <destination_table>MetaDataCreateLandingTempTable</destination_table> |
開啟 | <location> :請參閱 <location> .。<sql_operation> :識別將在節點上執行的 SQL 命令。 |
<location permanent="false" distribution="AllDistributions">Compute</location> <sql_operation type="statement">CREATE TABLE [ tempdb].[dbo]. [Q_[TEMP_ID_259]]_ [PARTITION_ID]]]([dist_date] DATE) WITH (DISTRIBUTION = HASH([dist_date]),) </sql_operation> |
RemoteOnOperation | <DestinationCatalog> :目的地目錄。<DestinationSchema> :DestinationCatalog 中的目的地結構描述。<DestinationTableName> :目的地資料表或 "TableName" 的名稱。<DestinationDatasource> :目的地資料來源的名稱。<Username> 和 <Password> :這些欄位表示可能需要目的地的使用者名稱和密碼。<CreateStatement> :目的地資料庫的資料表建立陳述式。 |
<DestinationCatalog>master</DestinationCatalog> <DestinationSchema>dbo</DestinationSchema> <DestinationTableName>TableName</DestinationTableName> <DestinationDatasource>DestDataSource</DestinationDatasource> <Username>...</Username> <Password>...</Password> <CreateStatement>CREATE TABLE [master].[dbo].[TableName] ([col1] BIGINT) ON [PRIMARY] WITH(DATA_COMPRESSION=PAGE);</CreateStatement> |
RETURN | <resultset> :結果集的識別碼。 |
<resultset>RS_19</resultset> |
RND_ID | <identifier> :所建立物件的識別碼。 |
<identifier>TEMP_ID_260</identifier> |
限制
EXPLAIN 只能套用至可最佳化的查詢,也就是可根據 EXPLAIN 命令的結果改善或修改的查詢。 上一節有提供支援的 EXPLAIN 命令。 嘗試使用 EXPLAIN 搭配不支援的查詢類型,將會傳回錯誤或回應查詢。
使用者交易中不支援 EXPLAIN。
範例
下列範例顯示在 SELECT 陳述式執行 EXPLAIN 命令,以及 XML 結果。
提交 EXPLAIN 陳述式
此範例中提交的命令為:
-- Uses AdventureWorks
EXPLAIN
SELECT CAST (AVG(YearlyIncome) AS int) AS AverageIncome,
CAST(AVG(FIS.SalesAmount) AS int) AS AverageSales,
G.StateProvinceName, T.SalesTerritoryGroup
FROM dbo.DimGeography AS G
JOIN dbo.DimSalesTerritory AS T
ON G.SalesTerritoryKey = T.SalesTerritoryKey
JOIN dbo.DimCustomer AS C
ON G.GeographyKey = C.GeographyKey
JOIN dbo.FactInternetSales AS FIS
ON C.CustomerKey = FIS.CustomerKey
WHERE T.SalesTerritoryGroup IN ('North America', 'Pacific')
AND Gender = 'F'
GROUP BY G.StateProvinceName, T.SalesTerritoryGroup
ORDER BY AVG(YearlyIncome) DESC;
GO
使用 EXPLAIN 選項執行陳述式後,[訊息] 索引標籤會顯示一行標題 explain,並且以 XML 文字 \<?xml version="1.0" encoding="utf-8"?>
為開頭。選取 XML 可在 XML 視窗中開啟整段文字。 若要進一步了解下列註解,您應該在 SSDT 中開啟行號的顯示。
開啟行號
當 SSDT 的 [explain] 索引標籤出現輸出時,在 [工具] 功能表上,選取 [選項] 。
展開 [文字編輯器] 區段,展開 [XML],然後選取 [一般]。
在 [顯示] 區域中,核取 [行號] 。
選取 [確定]。
範例 EXPLAIN 輸出
EXPLAIN 命令開啟行號的 XML 結果為:
1 \<?xml version="1.0" encoding="utf-8"?>
2 <dsql_query>
3 <sql>SELECT CAST (AVG(YearlyIncome) AS int) AS AverageIncome,
4 CAST(AVG(FIS.SalesAmount) AS int) AS AverageSales,
5 G.StateProvinceName, T.SalesTerritoryGroup
6 FROM dbo.DimGeography AS G
7 JOIN dbo.DimSalesTerritory AS T
8 ON G.SalesTerritoryKey = T.SalesTerritoryKey
9 JOIN dbo.DimCustomer AS C
10 ON G.GeographyKey = C.GeographyKey
11 JOIN dbo.FactInternetSales AS FIS
12 ON C.CustomerKey = FIS.CustomerKey
13 WHERE T.SalesTerritoryGroup IN ('North America', 'Pacific')
14 AND Gender = 'F'
15 GROUP BY G.StateProvinceName, T.SalesTerritoryGroup
16 ORDER BY AVG(YearlyIncome) DESC</sql>
17 <dsql_operations total_cost="0.926237696" total_number_operations="9">
18 <dsql_operation operation_type="RND_ID">
19 <identifier>TEMP_ID_16893</identifier>
20 </dsql_operation>
21 <dsql_operation operation_type="ON">
22 <location permanent="false" distribution="AllComputeNodes" />
23 <sql_operations>
24 <sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_16893] ([CustomerKey] INT NOT NULL, [GeographyKey] INT, [YearlyIncome] MONEY ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
25 </sql_operations>
26 </dsql_operation>
27 <dsql_operation operation_type="BROADCAST_MOVE">
28 <operation_cost cost="0.121431552" accumulative_cost="0.121431552" average_rowsize="16" output_rows="31.6228" />
29 <source_statement>SELECT [T1_1].[CustomerKey] AS [CustomerKey],
30 [T1_1].[GeographyKey] AS [GeographyKey],
31 [T1_1].[YearlyIncome] AS [YearlyIncome]
32 FROM (SELECT [T2_1].[CustomerKey] AS [CustomerKey],
33 [T2_1].[GeographyKey] AS [GeographyKey],
34 [T2_1].[YearlyIncome] AS [YearlyIncome]
35 FROM [AdventureWorksPDW2012].[dbo].[DimCustomer] AS T2_1
36 WHERE ([T2_1].[Gender] = CAST (N'F' COLLATE Latin1_General_100_CI_AS_KS_WS AS NVARCHAR (1)) COLLATE Latin1_General_100_CI_AS_KS_WS)) AS T1_1</source_statement>
37 <destination_table>[TEMP_ID_16893]</destination_table>
38 </dsql_operation>
39 <dsql_operation operation_type="RND_ID">
40 <identifier>TEMP_ID_16894</identifier>
41 </dsql_operation>
42 <dsql_operation operation_type="ON">
43 <location permanent="false" distribution="AllDistributions" />
44 <sql_operations>
45 <sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_16894] ([StateProvinceName] NVARCHAR(50) COLLATE Latin1_General_100_CI_AS_KS_WS, [SalesTerritoryGroup] NVARCHAR(50) COLLATE Latin1_General_100_CI_AS_KS_WS NOT NULL, [col] BIGINT, [col1] MONEY NOT NULL, [col2] BIGINT, [col3] MONEY NOT NULL ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
46 </sql_operations>
47 </dsql_operation>
48 <dsql_operation operation_type="SHUFFLE_MOVE">
49 <operation_cost cost="0.804806144" accumulative_cost="0.926237696" average_rowsize="232" output_rows="108.406" />
50 <source_statement>SELECT [T1_1].[StateProvinceName] AS [StateProvinceName],
51 [T1_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup],
52 [T1_1].[col2] AS [col],
53 [T1_1].[col] AS [col1],
54 [T1_1].[col3] AS [col2],
55 [T1_1].[col1] AS [col3]
56 FROM (SELECT ISNULL([T2_1].[col1], CONVERT (MONEY, 0.00, 0)) AS [col],
57 ISNULL([T2_1].[col3], CONVERT (MONEY, 0.00, 0)) AS [col1],
58 [T2_1].[StateProvinceName] AS [StateProvinceName],
59 [T2_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup],
60 [T2_1].[col] AS [col2],
61 [T2_1].[col2] AS [col3]
62 FROM (SELECT COUNT_BIG([T3_2].[YearlyIncome]) AS [col],
63 SUM([T3_2].[YearlyIncome]) AS [col1],
64 COUNT_BIG(CAST ((0) AS INT)) AS [col2],
65 SUM([T3_2].[SalesAmount]) AS [col3],
66 [T3_2].[StateProvinceName] AS [StateProvinceName],
67 [T3_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup]
68 FROM (SELECT [T4_1].[SalesTerritoryKey] AS [SalesTerritoryKey],
69 [T4_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup]
70 FROM [AdventureWorksPDW2012].[dbo].[DimSalesTerritory] AS T4_1
71 WHERE (([T4_1].[SalesTerritoryGroup] = CAST (N'North America' COLLATE Latin1_General_100_CI_AS_KS_WS AS NVARCHAR (13)) COLLATE Latin1_General_100_CI_AS_KS_WS)
72 OR ([T4_1].[SalesTerritoryGroup] = CAST (N'Pacific' COLLATE Latin1_General_100_CI_AS_KS_WS AS NVARCHAR (7)) COLLATE Latin1_General_100_CI_AS_KS_WS))) AS T3_1
73 INNER JOIN
74 (SELECT [T4_1].[SalesTerritoryKey] AS [SalesTerritoryKey],
75 [T4_2].[YearlyIncome] AS [YearlyIncome],
76 [T4_2].[SalesAmount] AS [SalesAmount],
77 [T4_1].[StateProvinceName] AS [StateProvinceName]
78 FROM [AdventureWorksPDW2012].[dbo].[DimGeography] AS T4_1
79 INNER JOIN
80 (SELECT [T5_2].[GeographyKey] AS [GeographyKey],
81 [T5_2].[YearlyIncome] AS [YearlyIncome],
82 [T5_1].[SalesAmount] AS [SalesAmount]
83 FROM [AdventureWorksPDW2012].[dbo].[FactInternetSales] AS T5_1
84 INNER JOIN
85 [tempdb].[dbo].[TEMP_ID_16893] AS T5_2
86 ON ([T5_1].[CustomerKey] = [T5_2].[CustomerKey])) AS T4_2
87 ON ([T4_2].[GeographyKey] = [T4_1].[GeographyKey])) AS T3_2
88 ON ([T3_1].[SalesTerritoryKey] = [T3_2].[SalesTerritoryKey])
89 GROUP BY [T3_2].[StateProvinceName], [T3_1].[SalesTerritoryGroup]) AS T2_1) AS T1_1</source_statement>
90 <destination_table>[TEMP_ID_16894]</destination_table>
91 <shuffle_columns>StateProvinceName;</shuffle_columns>
92 </dsql_operation>
93 <dsql_operation operation_type="ON">
94 <location permanent="false" distribution="AllComputeNodes" />
95 <sql_operations>
96 <sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_16893]</sql_operation>
97 </sql_operations>
98 </dsql_operation>
99 <dsql_operation operation_type="RETURN">
100 <location distribution="AllDistributions" />
101 <select>SELECT [T1_1].[col] AS [col],
102 [T1_1].[col1] AS [col1],
103 [T1_1].[StateProvinceName] AS [StateProvinceName],
104 [T1_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup],
105 [T1_1].[col2] AS [col2]
106 FROM (SELECT CONVERT (INT, [T2_1].[col], 0) AS [col],
107 CONVERT (INT, [T2_1].[col1], 0) AS [col1],
108 [T2_1].[StateProvinceName] AS [StateProvinceName],
109 [T2_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup],
110 [T2_1].[col] AS [col2]
111 FROM (SELECT CASE
112 WHEN ([T3_1].[col] = CAST ((0) AS BIGINT)) THEN CAST (NULL AS MONEY)
113 ELSE ([T3_1].[col1] / CONVERT (MONEY, [T3_1].[col], 0))
114 END AS [col],
115 CASE
116 WHEN ([T3_1].[col2] = CAST ((0) AS BIGINT)) THEN CAST (NULL AS MONEY)
117 ELSE ([T3_1].[col3] / CONVERT (MONEY, [T3_1].[col2], 0))
118 END AS [col1],
119 [T3_1].[StateProvinceName] AS [StateProvinceName],
120 [T3_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup]
121 FROM (SELECT ISNULL([T4_1].[col], CONVERT (BIGINT, 0, 0)) AS [col],
122 ISNULL([T4_1].[col1], CONVERT (MONEY, 0.00, 0)) AS [col1],
123 ISNULL([T4_1].[col2], CONVERT (BIGINT, 0, 0)) AS [col2],
124 ISNULL([T4_1].[col3], CONVERT (MONEY, 0.00, 0)) AS [col3],
125 [T4_1].[StateProvinceName] AS [StateProvinceName],
126 [T4_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup]
127 FROM (SELECT SUM([T5_1].[col]) AS [col],
128 SUM([T5_1].[col1]) AS [col1],
129 SUM([T5_1].[col2]) AS [col2],
130 SUM([T5_1].[col3]) AS [col3],
131 [T5_1].[StateProvinceName] AS [StateProvinceName],
132 [T5_1].[SalesTerritoryGroup] AS [SalesTerritoryGroup]
133 FROM [tempdb].[dbo].[TEMP_ID_16894] AS T5_1
134 GROUP BY [T5_1].[StateProvinceName], [T5_1].[SalesTerritoryGroup]) AS T4_1) AS T3_1) AS T2_1) AS T1_1
135 ORDER BY [T1_1].[col2] DESC</select>
136 </dsql_operation>
137 <dsql_operation operation_type="ON">
138 <location permanent="false" distribution="AllDistributions" />
139 <sql_operations>
140 <sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_16894]</sql_operation>
141 </sql_operations>
142 </dsql_operation>
143 </dsql_operations>
144 </dsql_query>
EXPLAIN 輸出的意義
上一個程式碼區塊中的輸出包含 144 個有編號的行。 此查詢的輸出可能會稍有不同。 下列清單說明重要區段。
第 3 到 16 行提供正在分析之查詢的描述。
第 17 行指定作業的總數是 9。 您可以尋找單字 dsql_operation 找到每個作業的開始。
第 18 行啟動第 1 個作業。 第 18 行和第 19 行表示 RND_ID 作業會建立一個用於物件描述的隨機識別碼號碼。 範例輸出中描述的物件為 TEMP_ID_16893。 您的號碼將會不同。
第 20 行啟動第 2 個作業。 第 21 到 25 行:在所有計算節點上,建立名為
TEMP_ID_16893
的暫存資料表。第 26 行啟動第 3 個作業。 第 27 到 37 行:使用廣播移動將資料移動至
TEMP_ID_16893
。 提供傳送至每個計算節點的查詢。 第 37 行指定目的地資料表為TEMP_ID_16893
。第 38 行啟動第 4 個作業。 第 39 到 40 行:建立資料表的隨機識別碼。 TEMP_ID_16894 是範例中的識別碼號碼。 您的號碼將會不同。
第 41 行啟動第 5 個作業。 第 42 到 46 行:在所有節點上,建立名為
TEMP_ID_16894
的暫存資料表。第 47 行啟動第 6 個作業。 第 48 到 91 行:使用隨機移動作業,從各個資料表 (包括
TEMP_ID_16893
) 將資料移到資料表TEMP_ID_16893
。 提供傳送至每個計算節點的查詢。 第 90 行指定目的地資料表為TEMP_ID_16894
。 第 91 行指定資料行。第 92 行啟動第 7 個作業。 第 93 到 97 行:在所有計算節點上,卸除名為
TEMP_ID_16893
的暫存資料表。第 98 行啟動第 8 個作業。 第 99 到 135 行:將結果傳回至用戶端。 使用提供的查詢取得結果。
第 136 行啟動第 9 個作業。 第 137 到 140 行:在所有節點上,卸除名為
TEMP_ID_16894
的暫存資料表。
提交 EXPLAIN 陳述式 WITH_RECOMMENDATIONS
EXPLAIN WITH_RECOMMENDATIONS
select count(*)
from ((select distinct c_last_name, c_first_name, d_date
from store_sales, date_dim, customer
where store_sales.ss_sold_date_sk = date_dim.d_date_sk
and store_sales.ss_customer_sk = customer.c_customer_sk
and d_month_seq between 1194 and 1194+11)
except
(select distinct c_last_name, c_first_name, d_date
from catalog_sales, date_dim, customer
where catalog_sales.cs_sold_date_sk = date_dim.d_date_sk
and catalog_sales.cs_bill_customer_sk = customer.c_customer_sk
and d_month_seq between 1194 and 1194+11)
) top_customers
EXPLAIN WITH_RECOMMENDATIONS 的範例輸出
下列範例輸出包括建立名為 View1
的建議具體化檢視。
<?xml version="1.0" encoding="utf-8"?>
<dsql_query number_nodes="1" number_distributions="8" number_distributions_per_node="8">
<sql>select count(*)
from ((select distinct c_last_name, c_first_name, d_date
from store_sales, date_dim, customer
where store_sales.ss_sold_date_sk = date_dim.d_date_sk
and store_sales.ss_customer_sk = customer.c_customer_sk
and d_month_seq between 1194 and 1194+11)
except
(select distinct c_last_name, c_first_name, d_date
from catalog_sales, date_dim, customer
where catalog_sales.cs_sold_date_sk = date_dim.d_date_sk
and catalog_sales.cs_bill_customer_sk = customer.c_customer_sk
and d_month_seq between 1194 and 1194+11)
) top_customers</sql>
<materialized_view_candidates>
<materialized_view_candidates with_constants="False">CREATE MATERIALIZED VIEW View1 WITH (DISTRIBUTION = HASH([Expr0])) AS
SELECT [tpcds10].[dbo].[customer].[c_last_name] AS [Expr0],
[tpcds10].[dbo].[customer].[c_first_name] AS [Expr1],
[tpcds10].[dbo].[date_dim].[d_date] AS [Expr2],
[tpcds10].[dbo].[date_dim].[d_month_seq] AS [Expr3]
FROM [dbo].[store_sales],
[dbo].[date_dim],
[dbo].[customer]
WHERE ([tpcds10].[dbo].[store_sales].[ss_customer_sk]=[tpcds10].[dbo].[customer].[c_customer_sk])
AND ([tpcds10].[dbo].[store_sales].[ss_sold_date_sk]=[tpcds10].[dbo].[date_dim].[d_date_sk])
GROUP BY [tpcds10].[dbo].[customer].[c_last_name],
[tpcds10].[dbo].[customer].[c_first_name],
[tpcds10].[dbo].[date_dim].[d_date],
[tpcds10].[dbo].[date_dim].[d_month_seq]</materialized_view_candidates>
<materialized_view_candidates with_constants="False">CREATE MATERIALIZED VIEW View2 WITH (DISTRIBUTION = HASH([Expr0])) AS
SELECT [tpcds10].[dbo].[customer].[c_last_name] AS [Expr0],
[tpcds10].[dbo].[customer].[c_first_name] AS [Expr1],
[tpcds10].[dbo].[date_dim].[d_date] AS [Expr2],
[tpcds10].[dbo].[date_dim].[d_month_seq] AS [Expr3]
FROM [dbo].[catalog_sales],
[dbo].[date_dim],
[dbo].[customer]
WHERE ([tpcds10].[dbo].[catalog_sales].[cs_bill_customer_sk]=[tpcds10].[dbo].[customer].[c_customer_sk])
AND ([tpcds10].[dbo].[catalog_sales].[cs_sold_date_sk]=[tpcds10].[dbo].[date_dim].[d_date_sk])
GROUP BY [tpcds10].[dbo].[customer].[c_last_name],
[tpcds10].[dbo].[customer].[c_first_name],
[tpcds10].[dbo].[date_dim].[d_date],
[tpcds10].[dbo].[date_dim].[d_month_seq]</materialized_view_candidates>
<materialized_view_candidates with_constants="True">CREATE MATERIALIZED VIEW View3 WITH (DISTRIBUTION = HASH([Expr0])) AS
SELECT [tpcds10].[dbo].[customer].[c_last_name] AS [Expr0],
[tpcds10].[dbo].[customer].[c_first_name] AS [Expr1],
[tpcds10].[dbo].[date_dim].[d_date] AS [Expr2]
FROM [dbo].[store_sales],
[dbo].[date_dim],
[dbo].[customer]
WHERE ([tpcds10].[dbo].[store_sales].[ss_customer_sk]=[tpcds10].[dbo].[customer].[c_customer_sk])
AND ([tpcds10].[dbo].[store_sales].[ss_sold_date_sk]=[tpcds10].[dbo].[date_dim].[d_date_sk])
AND ([tpcds10].[dbo].[date_dim].[d_month_seq]>=(1194))
AND ([tpcds10].[dbo].[date_dim].[d_month_seq]<=(1205))
GROUP BY [tpcds10].[dbo].[customer].[c_last_name],
[tpcds10].[dbo].[customer].[c_first_name],
[tpcds10].[dbo].[date_dim].[d_date]</materialized_view_candidates>
<materialized_view_candidates with_constants="True">CREATE MATERIALIZED VIEW View4 WITH (DISTRIBUTION = HASH([Expr0])) AS
SELECT [tpcds10].[dbo].[customer].[c_last_name] AS [Expr0],
[tpcds10].[dbo].[customer].[c_first_name] AS [Expr1],
[tpcds10].[dbo].[date_dim].[d_date] AS [Expr2]
FROM [dbo].[catalog_sales],
[dbo].[date_dim],
[dbo].[customer]
WHERE ([tpcds10].[dbo].[catalog_sales].[cs_bill_customer_sk]=[tpcds10].[dbo].[customer].[c_customer_sk])
AND ([tpcds10].[dbo].[catalog_sales].[cs_sold_date_sk]=[tpcds10].[dbo].[date_dim].[d_date_sk])
AND ([tpcds10].[dbo].[date_dim].[d_month_seq]>=(1194))
AND ([tpcds10].[dbo].[date_dim].[d_month_seq]<=(1205))
GROUP BY [tpcds10].[dbo].[customer].[c_last_name],
[tpcds10].[dbo].[customer].[c_first_name],
[tpcds10].[dbo].[date_dim].[d_date]</materialized_view_candidates>
</materialized_view_candidates>
<dsql_operations total_cost="3472197.35650704" total_number_operations="28">
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_1</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_1] ([c_customer_sk] INT NOT NULL, [c_first_name] CHAR(20) COLLATE SQL_Latin1_General_CP1_CI_AS, [c_last_name] CHAR(30) COLLATE SQL_Latin1_General_CP1_CI_AS ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="BROADCAST_MOVE">
<operation_cost cost="842400" accumulative_cost="842400" average_rowsize="54" output_rows="65000000" GroupNumber="44" />
<source_statement>SELECT [T1_1].[c_customer_sk] AS [c_customer_sk],
[T1_1].[c_first_name] AS [c_first_name],
[T1_1].[c_last_name] AS [c_last_name]
FROM [tpcds10].[dbo].[customer] AS T1_1</source_statement>
<destination_table>[TEMP_ID_1]</destination_table>
</dsql_operation>
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_2</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_2] ([d_date_sk] INT NOT NULL, [d_date] DATE ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="BROADCAST_MOVE">
<operation_cost cost="0.62729352" accumulative_cost="842400.62729352" average_rowsize="7" output_rows="373.389" GroupNumber="43" />
<source_statement>SELECT [T1_1].[d_date_sk] AS [d_date_sk],
[T1_1].[d_date] AS [d_date]
FROM (SELECT [T2_1].[d_date_sk] AS [d_date_sk],
[T2_1].[d_date] AS [d_date]
FROM [tpcds10].[dbo].[date_dim] AS T2_1
WHERE (([T2_1].[d_month_seq] >= CAST ((1194) AS INT))
AND ([T2_1].[d_month_seq] <= CAST ((1205) AS INT)))) AS T1_1</source_statement>
<destination_table>[TEMP_ID_2]</destination_table>
</dsql_operation>
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_3</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllDistributions" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_3] ([cs_bill_customer_sk] INT, [d_date] DATE ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="SHUFFLE_MOVE">
<operation_cost cost="610362.9" accumulative_cost="1452763.52729352" average_rowsize="7" output_rows="2906490000" GroupNumber="57" />
<source_statement>SELECT [T1_1].[cs_bill_customer_sk] AS [cs_bill_customer_sk],
[T1_1].[d_date] AS [d_date]
FROM (SELECT [T2_2].[cs_bill_customer_sk] AS [cs_bill_customer_sk],
[T2_1].[d_date] AS [d_date]
FROM [tempdb].[dbo].[TEMP_ID_2] AS T2_1
INNER JOIN
[tpcds10].[dbo].[catalog_sales] AS T2_2
ON ([T2_2].[cs_sold_date_sk] = [T2_1].[d_date_sk])) AS T1_1</source_statement>
<destination_table>[TEMP_ID_3]</destination_table>
<shuffle_columns>d_date;</shuffle_columns>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_2]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_4</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_4] ([c_customer_sk] INT NOT NULL, [c_first_name] CHAR(20) COLLATE SQL_Latin1_General_CP1_CI_AS, [c_last_name] CHAR(30) COLLATE SQL_Latin1_General_CP1_CI_AS ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="BROADCAST_MOVE">
<operation_cost cost="842400" accumulative_cost="2295163.52729352" average_rowsize="54" output_rows="65000000" GroupNumber="36" />
<source_statement>SELECT [T1_1].[c_customer_sk] AS [c_customer_sk],
[T1_1].[c_first_name] AS [c_first_name],
[T1_1].[c_last_name] AS [c_last_name]
FROM [tpcds10].[dbo].[customer] AS T1_1</source_statement>
<destination_table>[TEMP_ID_4]</destination_table>
</dsql_operation>
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_5</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_5] ([d_date_sk] INT NOT NULL, [d_date] DATE ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="BROADCAST_MOVE">
<operation_cost cost="0.62729352" accumulative_cost="2295164.15458704" average_rowsize="7" output_rows="373.389" GroupNumber="35" />
<source_statement>SELECT [T1_1].[d_date_sk] AS [d_date_sk],
[T1_1].[d_date] AS [d_date]
FROM (SELECT [T2_1].[d_date_sk] AS [d_date_sk],
[T2_1].[d_date] AS [d_date]
FROM [tpcds10].[dbo].[date_dim] AS T2_1
WHERE (([T2_1].[d_month_seq] >= CAST ((1194) AS INT))
AND ([T2_1].[d_month_seq] <= CAST ((1205) AS INT)))) AS T1_1</source_statement>
<destination_table>[TEMP_ID_5]</destination_table>
</dsql_operation>
<dsql_operation operation_type="RND_ID">
<identifier>TEMP_ID_6</identifier>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllDistributions" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[dbo].[TEMP_ID_6] ([ss_customer_sk] INT, [d_date] DATE ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="SHUFFLE_MOVE">
<operation_cost cost="1177033.2" accumulative_cost="3472197.35458704" average_rowsize="7" output_rows="5604920000" GroupNumber="54" />
<source_statement>SELECT [T1_1].[ss_customer_sk] AS [ss_customer_sk],
[T1_1].[d_date] AS [d_date]
FROM (SELECT [T2_2].[ss_customer_sk] AS [ss_customer_sk],
[T2_1].[d_date] AS [d_date]
FROM [tempdb].[dbo].[TEMP_ID_5] AS T2_1
INNER JOIN
[tpcds10].[dbo].[store_sales] AS T2_2
ON ([T2_2].[ss_sold_date_sk] = [T2_1].[d_date_sk])) AS T1_1</source_statement>
<destination_table>[TEMP_ID_6]</destination_table>
<shuffle_columns>d_date;</shuffle_columns>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_5]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="Control" />
<sql_operations>
<sql_operation type="statement">CREATE TABLE [tempdb].[QTables].[QTable_87367172aa554f06b73cf3ed97e5b985] ([col] BIGINT ) WITH(DATA_COMPRESSION=PAGE);</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="PARTITION_MOVE">
<operation_cost cost="0.00192" accumulative_cost="3472197.35650704" average_rowsize="8" output_rows="1" GroupNumber="66" />
<location distribution="AllDistributions" />
<source_statement>SELECT [T1_1].[col] AS [col]
FROM (SELECT COUNT_BIG(CAST ((0) AS INT)) AS [col]
FROM (SELECT 0 AS [col]
FROM [tempdb].[dbo].[TEMP_ID_4] AS T3_1
INNER JOIN
[tempdb].[dbo].[TEMP_ID_6] AS T3_2
ON ([T3_2].[ss_customer_sk] = [T3_1].[c_customer_sk])
GROUP BY [T3_1].[c_last_name], [T3_1].[c_first_name], [T3_2].[d_date]
HAVING NOT EXISTS (SELECT 1 AS C1
FROM [tempdb].[dbo].[TEMP_ID_1] AS T4_1
INNER JOIN
[tempdb].[dbo].[TEMP_ID_3] AS T4_2
ON ([T4_2].[cs_bill_customer_sk] = [T4_1].[c_customer_sk])
GROUP BY [T4_1].[c_last_name], [T4_1].[c_first_name], [T4_2].[d_date]
HAVING (([T3_1].[c_last_name] = [T4_1].[c_last_name]
OR ([T3_1].[c_last_name] IS NULL
AND [T4_1].[c_last_name] IS NULL))
AND ([T3_1].[c_first_name] = [T4_1].[c_first_name]
OR ([T3_1].[c_first_name] IS NULL
AND [T4_1].[c_first_name] IS NULL))
AND ([T3_2].[d_date] = [T4_2].[d_date]
OR ([T3_2].[d_date] IS NULL
AND [T4_2].[d_date] IS NULL))))) AS T2_1
GROUP BY [T2_1].[col]) AS T1_1</source_statement>
<destination>Control</destination>
<destination_table>[QTable_87367172aa554f06b73cf3ed97e5b985]</destination_table>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllDistributions" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_6]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_4]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllDistributions" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_3]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="AllComputeNodes" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[dbo].[TEMP_ID_1]</sql_operation>
</sql_operations>
</dsql_operation>
<dsql_operation operation_type="RETURN">
<location distribution="Control" />
<select>SELECT [T1_1].[col] AS [col]
FROM (SELECT CONVERT (INT, [T2_1].[col], 0) AS [col]
FROM (SELECT ISNULL([T3_1].[col], CONVERT (BIGINT, 0, 0)) AS [col]
FROM (SELECT SUM([T4_1].[col]) AS [col]
FROM [tempdb].[QTables].[QTable_87367172aa554f06b73cf3ed97e5b985] AS T4_1) AS T3_1) AS T2_1) AS T1_1</select>
</dsql_operation>
<dsql_operation operation_type="ON">
<location permanent="false" distribution="Control" />
<sql_operations>
<sql_operation type="statement">DROP TABLE [tempdb].[QTables].[QTable_87367172aa554f06b73cf3ed97e5b985]</sql_operation>
</sql_operations>
</dsql_operation>
</dsql_operations>
</dsql_query>
相關內容
- sys.pdw_materialized_view_column_distribution_properties (Transact-SQL)
- sys.pdw_materialized_view_distribution_properties (Transact-SQL)
- sys.pdw_materialized_view_mappings (Transact-SQL)
- Azure Synapse Analytics 和分析平台系統 (PDW) 目錄檢視
- Azure Synapse Analytics 中支援的系統檢視
- Azure Synapse Analytics 中支援的 T-SQL 陳述式
- CREATE MATERIALIZED VIEW AS SELECT (Transact-SQL)
- ALTER MATERIALIZED VIEW (Transact-SQL)
- DBCC PDW_SHOWMATERIALIZEDVIEWOVERHEAD (Transact-SQL)
- 使用 DMV 監視 Azure Synapse Analytics 專用 SQL 集區工作負載
- 顯示估計的執行計畫