diff --git a/docs/en/assets/Rewrite-view-based.png b/docs/en/assets/Rewrite-view-based.png new file mode 100644 index 0000000000000..aeb26acc4bff4 Binary files /dev/null and b/docs/en/assets/Rewrite-view-based.png differ diff --git a/docs/en/using_starrocks/query_rewrite_with_materialized_views.md b/docs/en/using_starrocks/query_rewrite_with_materialized_views.md index c390b89243857..31b1532230d24 100644 --- a/docs/en/using_starrocks/query_rewrite_with_materialized_views.md +++ b/docs/en/using_starrocks/query_rewrite_with_materialized_views.md @@ -710,34 +710,280 @@ As shown above, `agg_mv5` contains the data from partitions `p1` to `p7`, and th ## View-based materialized view rewrite -StarRocks supports creating materialized views based on views. Subsequent queries against the views can be transparently rewritten. +From v3.1.0 onwards, StarRocks supports creating materialized views based on views. Subsequent queries against the views can be rewritten if they are of the SPJG pattern. By default, queries against views are automatically transcribed into queries against the base tables of the views and then transparently matched and rewritten. -For example, create the following views: +However, in real-world scenarios, data analysts may perform data modeling upon complex, nested views, which cannot be directly transcribed. As a result, materialized views created based on such views cannot rewrite queries. To improve its capability in the preceding scenario, StarRocks optimizes the view-based materialized view query rewrite logic from v3.3.0 onwards. + +### Fundamentals + +In the previous query rewrite logic, StarRocks will transcribe queries against a view into queries against the base tables of the view. Query rewrite will encounter failures if the execution plan of the transcribed query mismatches the SPJG pattern. + +To solve this problem, StarRocks introduces a new operator - LogicalViewScanOperator, to simplify the structure of the execution plan tree without transcribing the query. This operator seeks to match the execution plan tree with the SPJG pattern, therefore facilitating query rewrite. + +The following example lists a query with an AGGREGATE sub-query, a view built upon the sub-query, the transcribed query based on the view, and the materialized view built upon the view: ```SQL -CREATE VIEW customer_view1 +-- Original query: +SELECT + v1.a, + t2.b, + v1.total +FROM( + SELECT + a, + sum(c) AS total + FROM t1 + GROUP BY a +) v1 +INNER JOIN t2 ON v1.a = t2.a; + +-- View: +CREATE VIEW view_1 AS +SELECT + t1.a, + sum(t1.c) AS total +FROM t1 +GROUP BY t1.a; + +-- Transcribed query: +SELECT + v1.a, + t2.b, + v1.total +FROM view_1 v1 +JOIN t2 ON v1.a = t2.a; + +-- Materialized view: +CREATE MATERIALIZED VIEW mv1 +DISTRIBUTED BY hash(a) +REFRESH MANUAL AS -SELECT c_custkey, c_name, c_address -FROM customer; +SELECT + v1.a, + t2.b, + v1.total +FROM view_1 v1 +JOIN t2 ON v1.a = t2.a; +``` -CREATE VIEW lineorder_view1 -AS -SELECT lo_orderkey, lo_linenumber, lo_custkey, lo_revenue -FROM lineorder; +The execution plan of the original query, as shown on the left of the following diagram, mismatches the SPJG pattern due to the LogicalAggregateOperator within the JOIN. StarRocks does not support query rewrite for such cases. However, by defining a view based on the sub-query, the original query can be transcribed into a query against the view. With the LogicalViewScanOperator, StarRocks can transfer the mismatched part into the SPJG pattern, therefore allowing query rewrite under this circumstance. + +![img](../assets/Rewrite-view-based.png) + +### Usage + +View-based materialized view query rewrite is disabled by default. + +To enable this feature, you must set the following variable: + +```SQL +SET enable_view_based_mv_rewrite = true; ``` -Then, create the following materialized view based on the views: +### Use cases + +#### Rewrite queries using single-view-based materialized views + +StarRocks supports rewriting queries with a materialized view built upon a single view, including queries with aggregations. + +For example, you can build the following view and materialized view for the TPC-H Query 18: ```SQL -CREATE MATERIALIZED VIEW join_mv1 -DISTRIBUTED BY hash(lo_orderkey) +CREATE VIEW q18_view AS -SELECT lo_orderkey, lo_linenumber, lo_revenue, c_name -FROM lineorder_view1 INNER JOIN customer_view1 -ON lo_custkey = c_custkey; +SELECT + c_name, + c_custkey, + o_orderkey, + o_orderdate, + o_totalprice, + sum(l_quantity) +FROM + customer, + orders, + lineitem +WHERE + o_orderkey IN ( + SELECT + l_orderkey + FROM + lineitem + GROUP BY + l_orderkey having + sum(l_quantity) > 315 + ) + AND c_custkey = o_custkey + AND o_orderkey = l_orderkey +GROUP BY + c_name, + c_custkey, + o_orderkey, + o_orderdate, + o_totalprice; + +CREATE MATERIALIZED VIEW q18_mv +DISTRIBUTED BY hash(c_custkey, o_orderkey) +REFRESH MANUAL +AS +SELECT * FROM q18_view; ``` -During query rewrite, queries against `customer_view1` and `lineorder_view1` are automatically expanded to the base tables and then transparently matched and rewritten. +The materialized view can rewrite both the following queries: + +```Plain +mysql> EXPLAIN LOGICAL SELECT * FROM q18_view; ++-------------------------------------------------------------------------------------------------------+ +| Explain String | ++-------------------------------------------------------------------------------------------------------+ +| - Output => [2:c_name, 1:c_custkey, 9:o_orderkey, 10:o_orderdate, 13:o_totalprice, 52:sum] | +| - SCAN [q18_mv] => [1:c_custkey, 2:c_name, 52:sum, 9:o_orderkey, 10:o_orderdate, 13:o_totalprice] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 9, cpu: 486.00, memory: 0.00, network: 0.00, cost: 243.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 1:c_custkey := 60:c_custkey | +| 2:c_name := 59:c_name | +| 52:sum := 64:sum(l_quantity) | +| 9:o_orderkey := 61:o_orderkey | +| 10:o_orderdate := 62:o_orderdate | +| 13:o_totalprice := 63:o_totalprice | ++-------------------------------------------------------------------------------------------------------+ +``` + +```Plain +mysql> EXPLAIN LOGICAL SELECT c_name, sum(`sum(l_quantity)`) FROM q18_view GROUP BY c_name; ++-----------------------------------------------------------------------------------------------------+ +| Explain String | ++-----------------------------------------------------------------------------------------------------+ +| - Output => [2:c_name, 59:sum] | +| - AGGREGATE(GLOBAL) [2:c_name] | +| Estimates: {row: 9, cpu: 306.00, memory: 306.00, network: 0.00, cost: 1071.00} | +| 59:sum := sum(59:sum) | +| - EXCHANGE(SHUFFLE) [2] | +| Estimates: {row: 9, cpu: 30.60, memory: 0.00, network: 30.60, cost: 306.00} | +| - AGGREGATE(LOCAL) [2:c_name] | +| Estimates: {row: 9, cpu: 61.20, memory: 30.60, network: 0.00, cost: 244.80} | +| 59:sum := sum(52:sum) | +| - SCAN [q18_mv] => [2:c_name, 52:sum] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 9, cpu: 306.00, memory: 0.00, network: 0.00, cost: 153.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 2:c_name := 60:c_name | +| 52:sum := 65:sum(l_quantity) | ++-----------------------------------------------------------------------------------------------------+ +``` + +#### Rewrite queries with JOIN using view-based materialized views + +StarRocks supports rewriting queries with JOINs between views or between views and tables, including aggregations upon JOINs. + +For example, you can create the following views and materialized view: + +```SQL +CREATE VIEW view_1 AS +SELECT + l_partkey, + l_suppkey, + sum(l_quantity) AS total_quantity +FROM lineitem +GROUP BY + l_partkey, + l_suppkey; + + +CREATE VIEW view_2 AS +SELECT + l_partkey, + l_suppkey, + sum(l_tax) AS total_tax +FROM lineitem +GROUP BY + l_partkey, + l_suppkey; + + +CREATE MATERIALIZED VIEW mv_1 +DISTRIBUTED BY hash(l_partkey, l_suppkey) +REFRESH MANUAL AS +SELECT + v1.l_partkey, + v2.l_suppkey, + total_quantity, + total_tax +FROM view_1 v1 +JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey +AND v1.l_suppkey = v2.l_suppkey; +``` + +The materialized view can rewrite both the following queries: + +```Plain +mysql> EXPLAIN LOGICAL + -> SELECT v1.l_partkey, + -> v2.l_suppkey, + -> total_quantity, + -> total_tax + -> FROM view_1 v1 + -> JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey + -> AND v1.l_suppkey = v2.l_suppkey; ++--------------------------------------------------------------------------------------------------------+ +| Explain String | ++--------------------------------------------------------------------------------------------------------+ +| - Output => [4:l_partkey, 25:l_suppkey, 17:sum, 37:sum] | +| - SCAN [mv_1] => [17:sum, 4:l_partkey, 37:sum, 25:l_suppkey] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 799541, cpu: 31981640.00, memory: 0.00, network: 0.00, cost: 15990820.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 17:sum := 43:total_quantity | +| 4:l_partkey := 41:l_partkey | +| 37:sum := 44:total_tax | +| 25:l_suppkey := 42:l_suppkey | ++--------------------------------------------------------------------------------------------------------+ +``` + +```Plain +mysql> EXPLAIN LOGICAL + -> SELECT v1.l_partkey, + -> sum(total_quantity), + -> sum(total_tax) + -> FROM view_1 v1 + -> JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey + -> AND v1.l_suppkey = v2.l_suppkey + -> group by v1.l_partkey; ++--------------------------------------------------------------------------------------------------------------------+ +| Explain String | ++--------------------------------------------------------------------------------------------------------------------+ +| - Output => [4:l_partkey, 41:sum, 42:sum] | +| - AGGREGATE(GLOBAL) [4:l_partkey] | +| Estimates: {row: 196099, cpu: 4896864.00, memory: 3921980.00, network: 0.00, cost: 29521223.20} | +| 41:sum := sum(41:sum) | +| 42:sum := sum(42:sum) | +| - EXCHANGE(SHUFFLE) [4] | +| Estimates: {row: 136024, cpu: 489686.40, memory: 0.00, network: 489686.40, cost: 19228831.20} | +| - AGGREGATE(LOCAL) [4:l_partkey] | +| Estimates: {row: 136024, cpu: 5756695.20, memory: 489686.40, network: 0.00, cost: 18249458.40} | +| 41:sum := sum(17:sum) | +| 42:sum := sum(37:sum) | +| - SCAN [mv_1] => [17:sum, 4:l_partkey, 37:sum] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 799541, cpu: 28783476.00, memory: 0.00, network: 0.00, cost: 14391738.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 17:sum := 45:total_quantity | +| 4:l_partkey := 43:l_partkey | +| 37:sum := 46:total_tax | ++--------------------------------------------------------------------------------------------------------------------+ +``` + +#### Rewrite queries using materialized views built upon external table-based views + +You can build views upon tables in external catalogs and then materialized views upon the views to rewrite queries. The usage is similar to that for internal tables. ## External catalog-based materialized view rewrite @@ -802,10 +1048,24 @@ For asynchronous materialized views created based on an external catalog, you ca ## Limitations -In terms of materialized view-based query rewrite, StarRocks currently has the following limitations: +In terms of materialized view query rewrite, StarRocks currently has the following limitations: - StarRocks does not support rewriting queries with non-deterministic functions, including rand, random, uuid, and sleep. - StarRocks does not support rewriting queries with window functions. - Materialized views defined with statements containing LIMIT, ORDER BY, UNION, EXCEPT, INTERSECT, MINUS, GROUPING SETS, WITH CUBE, or WITH ROLLUP cannot be used for query rewrite. - Strong consistency of query results is not guaranteed between base tables and materialized views built on external catalogs. - Asynchronous materialized views created on base tables in a JDBC catalog do not support query rewrite. + +In terms of view-based materialized view query rewrite, StarRocks currently has the following limitations: + +- Currently, StarRocks does not support Partition Union rewrite. +- Query rewrite is not supported if the view contains random functions, including rand(), random(), uuid(), and sleep(). +- Query rewrite is not supported if the view contains columns with same names. You must assign different aliases for columns with the same names. +- Views that are used to create a materialized view must contain at least one column of the following data types: integer types, date types, and string types. For example, you cannot create a materialized that queries the view, because `total_cost` is a DOUBLE-type column. + + ```SQL + CREATE VIEW v1 + AS + SELECT sum(cost) AS total_cost + FROM t1; + ``` diff --git a/docs/zh/assets/Rewrite-view-based.png b/docs/zh/assets/Rewrite-view-based.png new file mode 100644 index 0000000000000..0992a87c580c2 Binary files /dev/null and b/docs/zh/assets/Rewrite-view-based.png differ diff --git a/docs/zh/using_starrocks/query_rewrite_with_materialized_views.md b/docs/zh/using_starrocks/query_rewrite_with_materialized_views.md index 84cee9038eacc..5a861c3d0ff63 100644 --- a/docs/zh/using_starrocks/query_rewrite_with_materialized_views.md +++ b/docs/zh/using_starrocks/query_rewrite_with_materialized_views.md @@ -529,7 +529,7 @@ GROUP BY lo_orderkey, c_name; | hll_raw_agg, hll_union_agg, ndv, approx_count_distinct | hll_union | | percentile_approx, percentile_union | percentile_union | -没有相应 GROUP BY 列的 DISTINCT 聚合无法使用聚合上卷查询改写。但是,从 StarRocks v3.1 开始,如果聚合上卷对应 DISTINCT 聚合函数的查询没有 GROUP BY 列,但有等价的谓词,该查询也可以被相关物化视图重写,因为 StarRocks 可以将等价谓词转换为 GROUP BY 常量表达式。 +没有相应 GROUP BY 列的 DISTINCT 聚合无法使用聚合上卷查询改写。但是,从 StarRocks v3.1 开始,如果聚合上卷对应 DISTINCT 聚合函数的查询没有 GROUP BY 列,但有等价的谓词,该查询也可以被相关物化视图改写,因为 StarRocks 可以将等价谓词转换为 GROUP BY 常量表达式。 在以下示例中,StarRocks 可以使用物化视图 `order_agg_mv1` 改写对应查询 Query: @@ -706,36 +706,282 @@ GROUP BY lo_orderkey; 如上所示,`agg_mv5` 包含来自分区 `p1` 到 `p7` 的数据,而分区 `p8` 的数据来源于 `lineorder`。最后,这两组数据使用 UNION 操作合并。 -## 基于视图构建物化视图 +## 基于视图的物化视图查询改写 -StarRocks 支持基于视图创建物化视图。后续针对视图的查询可以被透明改写。 +自 v3.1.0 起,StarRocks 支持基于视图创建物化视图。如果基于视图的查询为 SPJG 类型,StarRocks 将会内联展开查询,然后进行改写。默认情况下,对视图的查询会自动展开为对视图的基表的查询,然后进行透明匹配和改写。 -例如,创建以下视图: +然而,在实际场景中,数据分析师可能会基于复杂的嵌套视图进行数据建模,这些视图无法直接展开。因此,基于这些视图创建的物化视图无法改写查询。为了改进在上述情况下的能力,从 v3.3.0 开始,StarRock 优化了基于视图的物化视图查询改写逻辑。 + +### 基本原理 + +在先前的查询改写逻辑中,StarRocks 会将基于视图的查询展开为针对视图基表的查询。如果展开后查询的执行计划与 SPJG 模式不匹配,物化视图将无法改写查询。 + +为了解决这个问题,StarRocks 引入了一个新的算子 - LogicalViewScanOperator,该算子用于简化执行计划树的结构,且无需展开查询,使查询执行计划树尽量满足 SPJG 模式,从而优化查询改写。 + +以下示例展示了一个包含聚合子查询的查询,一个建立在子查询之上的视图,基于视图展开之后的查询,以及建立在视图之上的物化视图: ```SQL -CREATE VIEW customer_view1 +-- 原始查询: +SELECT + v1.a, + t2.b, + v1.total +FROM( + SELECT + a, + sum(c) AS total + FROM t1 + GROUP BY a +) v1 +INNER JOIN t2 ON v1.a = t2.a; + +-- 视图: +CREATE VIEW view_1 AS +SELECT + t1.a, + sum(t1.c) AS total +FROM t1 +GROUP BY t1.a; + +-- 展开后的查询 +SELECT + v1.a, + t2.b, + v1.total +FROM view_1 v1 +JOIN t2 ON v1.a = t2.a; + +-- 物化视图: +CREATE MATERIALIZED VIEW mv1 +DISTRIBUTED BY hash(a) +REFRESH MANUAL AS -SELECT c_custkey, c_name, c_address -FROM customer; +SELECT + v1.a, + t2.b, + v1.total +FROM view_1 v1 +JOIN t2 ON v1.a = t2.a; +``` -CREATE VIEW lineorder_view1 -AS -SELECT lo_orderkey, lo_linenumber, lo_custkey, lo_revenue -FROM lineorder; +原始查询的执行计划如下图左侧所示。由于 JOIN 内的 LogicalAggregateOperator 与 SPJG 模式不匹配,StarRocks 不支持这种情况下的查询改写。然而,如果将子查询定义为一个视图,原始查询可以展开为针对该视图的查询。通过 LogicalViewScanOperator,StarRocks 可以将不匹配的部分转换为 SPJG 模式,从而允许改写查询。 + +![img](../assets/Rewrite-view-based.png) + +### 使用 + +StarRocks 默认禁用基于视图的物化视图查询改写。 + +要启用此功能,您必须设置以下变量: + +```SQL +SET enable_view_based_mv_rewrite = true; ``` -根据以上视图创建物化视图: +### 使用场景 + +#### 基于单个视图的物化视图查询改写 + +StarRocks 支持通过基于单个视图的物化视图进行查询改写,包括聚合查询。 + +例如,您可以为 TPC-H Query 18 构建以下视图和物化视图: ```SQL -CREATE MATERIALIZED VIEW join_mv1 -DISTRIBUTED BY hash(lo_orderkey) +CREATE VIEW q18_view AS -SELECT lo_orderkey, lo_linenumber, lo_revenue, c_name -FROM lineorder_view1 INNER JOIN customer_view1 -ON lo_custkey = c_custkey; +SELECT + c_name, + c_custkey, + o_orderkey, + o_orderdate, + o_totalprice, + sum(l_quantity) +FROM + customer, + orders, + lineitem +WHERE + o_orderkey IN ( + SELECT + l_orderkey + FROM + lineitem + GROUP BY + l_orderkey having + sum(l_quantity) > 315 + ) + AND c_custkey = o_custkey + AND o_orderkey = l_orderkey +GROUP BY + c_name, + c_custkey, + o_orderkey, + o_orderdate, + o_totalprice; + +CREATE MATERIALIZED VIEW q18_mv +DISTRIBUTED BY hash(c_custkey, o_orderkey) +REFRESH MANUAL +AS +SELECT * FROM q18_view; ``` -查询改写过程中,针对 `customer_view1` 和 `lineorder_view1` 的查询会自动展开到基表,然后进行透明匹配改写。 +物化视图可以改写以下两个查询: + +```Plain +mysql> EXPLAIN LOGICAL SELECT * FROM q18_view; ++-------------------------------------------------------------------------------------------------------+ +| Explain String | ++-------------------------------------------------------------------------------------------------------+ +| - Output => [2:c_name, 1:c_custkey, 9:o_orderkey, 10:o_orderdate, 13:o_totalprice, 52:sum] | +| - SCAN [q18_mv] => [1:c_custkey, 2:c_name, 52:sum, 9:o_orderkey, 10:o_orderdate, 13:o_totalprice] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 9, cpu: 486.00, memory: 0.00, network: 0.00, cost: 243.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 1:c_custkey := 60:c_custkey | +| 2:c_name := 59:c_name | +| 52:sum := 64:sum(l_quantity) | +| 9:o_orderkey := 61:o_orderkey | +| 10:o_orderdate := 62:o_orderdate | +| 13:o_totalprice := 63:o_totalprice | ++-------------------------------------------------------------------------------------------------------+ +``` + +```Plain +mysql> EXPLAIN LOGICAL SELECT c_name, sum(`sum(l_quantity)`) FROM q18_view GROUP BY c_name; ++-----------------------------------------------------------------------------------------------------+ +| Explain String | ++-----------------------------------------------------------------------------------------------------+ +| - Output => [2:c_name, 59:sum] | +| - AGGREGATE(GLOBAL) [2:c_name] | +| Estimates: {row: 9, cpu: 306.00, memory: 306.00, network: 0.00, cost: 1071.00} | +| 59:sum := sum(59:sum) | +| - EXCHANGE(SHUFFLE) [2] | +| Estimates: {row: 9, cpu: 30.60, memory: 0.00, network: 30.60, cost: 306.00} | +| - AGGREGATE(LOCAL) [2:c_name] | +| Estimates: {row: 9, cpu: 61.20, memory: 30.60, network: 0.00, cost: 244.80} | +| 59:sum := sum(52:sum) | +| - SCAN [q18_mv] => [2:c_name, 52:sum] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 9, cpu: 306.00, memory: 0.00, network: 0.00, cost: 153.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 2:c_name := 60:c_name | +| 52:sum := 65:sum(l_quantity) | ++-----------------------------------------------------------------------------------------------------+ +``` + +#### 基于视图的物化视图改写 JOIN 查询 + +StarRocks 支持对包含视图之间或视图与表之间的 JOIN 的查询进行改写,包括在 JOIN 上进行聚合。 + +例如,您可以创建以下视图和物化视图: + +```SQL +CREATE VIEW view_1 AS +SELECT + l_partkey, + l_suppkey, + sum(l_quantity) AS total_quantity +FROM lineitem +GROUP BY + l_partkey, + l_suppkey; + + +CREATE VIEW view_2 AS +SELECT + l_partkey, + l_suppkey, + sum(l_tax) AS total_tax +FROM lineitem +GROUP BY + l_partkey, + l_suppkey; + + +CREATE MATERIALIZED VIEW mv_1 +DISTRIBUTED BY hash(l_partkey, l_suppkey) +REFRESH MANUAL AS +SELECT + v1.l_partkey, + v2.l_suppkey, + total_quantity, + total_tax +FROM view_1 v1 +JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey +AND v1.l_suppkey = v2.l_suppkey; +``` + +物化视图可以改写以下两个查询: + +```Plain +mysql> EXPLAIN LOGICAL + -> SELECT v1.l_partkey, + -> v2.l_suppkey, + -> total_quantity, + -> total_tax + -> FROM view_1 v1 + -> JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey + -> AND v1.l_suppkey = v2.l_suppkey; ++--------------------------------------------------------------------------------------------------------+ +| Explain String | ++--------------------------------------------------------------------------------------------------------+ +| - Output => [4:l_partkey, 25:l_suppkey, 17:sum, 37:sum] | +| - SCAN [mv_1] => [17:sum, 4:l_partkey, 37:sum, 25:l_suppkey] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 799541, cpu: 31981640.00, memory: 0.00, network: 0.00, cost: 15990820.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 17:sum := 43:total_quantity | +| 4:l_partkey := 41:l_partkey | +| 37:sum := 44:total_tax | +| 25:l_suppkey := 42:l_suppkey | ++--------------------------------------------------------------------------------------------------------+ +``` + +```Plain +mysql> EXPLAIN LOGICAL + -> SELECT v1.l_partkey, + -> sum(total_quantity), + -> sum(total_tax) + -> FROM view_1 v1 + -> JOIN view_2 v2 ON v1.l_partkey = v2.l_partkey + -> AND v1.l_suppkey = v2.l_suppkey + -> group by v1.l_partkey; ++--------------------------------------------------------------------------------------------------------------------+ +| Explain String | ++--------------------------------------------------------------------------------------------------------------------+ +| - Output => [4:l_partkey, 41:sum, 42:sum] | +| - AGGREGATE(GLOBAL) [4:l_partkey] | +| Estimates: {row: 196099, cpu: 4896864.00, memory: 3921980.00, network: 0.00, cost: 29521223.20} | +| 41:sum := sum(41:sum) | +| 42:sum := sum(42:sum) | +| - EXCHANGE(SHUFFLE) [4] | +| Estimates: {row: 136024, cpu: 489686.40, memory: 0.00, network: 489686.40, cost: 19228831.20} | +| - AGGREGATE(LOCAL) [4:l_partkey] | +| Estimates: {row: 136024, cpu: 5756695.20, memory: 489686.40, network: 0.00, cost: 18249458.40} | +| 41:sum := sum(17:sum) | +| 42:sum := sum(37:sum) | +| - SCAN [mv_1] => [17:sum, 4:l_partkey, 37:sum] | + # highlight-start +| MaterializedView: true | + # highlight-end +| Estimates: {row: 799541, cpu: 28783476.00, memory: 0.00, network: 0.00, cost: 14391738.00} | +| partitionRatio: 1/1, tabletRatio: 96/96 | +| 17:sum := 45:total_quantity | +| 4:l_partkey := 43:l_partkey | +| 37:sum := 46:total_tax | ++--------------------------------------------------------------------------------------------------------------------+ +``` + +#### 基于视图的物化视图改写外表查询 + +您可以在 External Catalog 中的外表上构建视图,然后基于这些视图构建物化视图来改写查询。其使用方式类似于内部表。 ## 基于 External Catalog 构建物化视图 @@ -807,3 +1053,17 @@ StarRocks 默认开启基于 Default Catalog 创建的异步物化视图查询 - 如果物化视图定义语句中包含 LIMIT、ORDER BY、UNION、EXCEPT、INTERSECT、MINUS、GROUPING SETS、WITH CUBE 或 WITH ROLLUP,则无法用于改写。 - 基于 External Catalog 的物化视图不保证查询结果强一致。 - 基于 JDBC Catalog 表构建的异步物化视图暂不支持查询改写。 + +针对基于视图的物化视图查询改写,StarRocks 目前存在以下限制: + +- 目前,StarRocks 不支持分区 Union 改写。 +- 如果视图包含随机函数,则不支持查询改写,包括 rand()、random()、uuid() 和 sleep()。 +- 如果视图包含具有相同名称的列,则不支持查询改写。您必须为具有相同名称的列设置不同的别名。 +- 用于创建物化视图的视图必须至少包含以下数据类型之一的列:整数类型、日期类型和字符串类型。以下示例中,因为 `total_cost` 为 DOUBLE 类型的列,所以无法创建查询该视图的物化视图。 + + ```SQL + CREATE VIEW v1 + AS + SELECT sum(cost) AS total_cost + FROM t1; + ```