`

《Pro Oracle SQL》CHAPTER 9 -- 9.10Performance Tuning with the Model Clause

阅读更多

Performance Tuning with the Model Clause  Model子句的性能调优    (page 293)
    As with all SQL, sometimes you need to tune statements using the Model clause. To that end, it helps to know how to read execution plans involving the clause. It also helps to know about some of the issues
you’ll encounter—such as predicate pushing and partitioning—when working with Model clause
queries. 
     如同所有SQL,有时你需要用Model子句调优语句。出于该的目的,知道如何读涉及该子句的执行计划是有帮助的。知道一些你会遇到的问题--如谓词推进和分区--当使用Model子句查询时,也是有帮助的。
Execution Plans     执行计划
    In the Model clause, rule evaluation is the critical step. Rule evaluation can use one of five algorithm
types:  ACYCLIC ,  ACYCLIC FAST, CYCLIC, ORDERED , and  ORDERED FAST. 
The algorithm chosen depends upon the complexity and dependency of the rules themselves. The algorithm chosen also affects the performance of the SQL statement. But details of these algorithms are not well documented.   
ACYCLIC FAST and  ORDERED FAST  algorithms are more optimized algorithms that allow cells to be
evaluated efficiently. However, the algorithm chosen depends upon the type of the rules that you
specify. For example, if there is a possibility  of a cycle in the rules, then the algorithm that can handle
cyclic rules is chosen.
    在Model子句中,规则求值是至关重要的步骤。规则求值会用到下列五种类型的算法:ACYCLIC ,  ACYCLIC FAST, CYCLIC, ORDERED , 和ORDERED FAST。 但是这些算法的细节并没有文档可循。ACYCLIC FAST 和ORDERED FAST 算法是比较优化的算法,能让单元格有效率的求值。然而,算法的选择依赖于你所指定规则的类型。例如,如果有可能在规则中有循环,则将选择能处理循环的算法。
    The algorithms of type  ACYCLIC  and  CYCLIC are used if the SQL statement specifies the rules
automatic order  clause. An ORDERED  type of the rule evaluation algorithm is used if the SQL statement
specifies rules sequential order. If a rule is accessing individual cells without any aggregation, then
either the  ACYCIC FAST  or  ORDERED FAST algorithm is used.
    如果SQL语句指定rules automatic order子句则ACYCLIC和CYCLIC类型的算法会被选择。如果SQL语句指定rules sequential order则ORDERED 类型的规则求值算法会被选择。如果规则只是访问单个单元格而没有任何聚合,则要么ACYCIC FAST要么ORDERED FAST将被选择。

ACYCLIC
    In Listing 9-23, a Model SQL statement and its execution plan is shown. Step 2 in the execution plan
shows that this SQL is using the  SQL MODEL ACYCLIC algorithm for rule evaluation. The keyword ACYCLIC  indicates that there are no possible  CYCLIC  dependencies between the rules. In this example, with the order by year, week clause you control the dependency between the rules, avoiding cycle
dependencies,
    在列表9-23中,展示了一Model SQL语句和它的执行计划。在执行计划的步骤2中展示该SQL使用了SQL MODEL ACYCLIC算法对规则求值。关键字ACYCLIC指出这里不可能在规则间CYCLIC(循环的)依赖。 在该例子中,用order by year, week 子句控制规则间的依赖性,避免循环依赖。
Listing 9-23.  Automatic order and ACYCLIC
  1    select product, country, year, week, inventory, sale, receipts
  2    from sales_fact
  3    where country in ('Australia') and product='Xtend Memory'
  4    model return updated rows
  5    partition by (product, country)
  6    dimension by (year, week)
  7    measures ( 0 inventory , sale, receipts)
  8    rules automatic order(
  9         inventory [year, week ] order by year, week   =
 10                                   nvl(inventory [cv(year), cv(week)-1 ] ,0)
 11                                    - sale[cv(year), cv(week) ] +
 12                                    + receipts [cv(year), cv(week) ]
 13     )
 14*    order by product, country,year, week
---------------------------------------------------
| Id  | Operation                   | Name          | E-Rows |
----------------------------------------------------
|   0 | SELECT STATEMENT    |                   |          |
|   1 |  SORT ORDER BY         |                   |    147 |
|   2 |   SQL MODEL ACYCLIC |                   |    147 |
|*  3 |    TABLE ACCESS FULL| SALES_FACT |    147 |
---------------------------------------------------

ACYCLIC FAST
    If a rule is a simple rule accessing just one cell, the  ACYCLIC FAST algorithm can be used. The execution plan in Listing 9-24 shows that the ACYCLIC FAST  algorithm is used to evaluate the rule in this example.
    如果某规则是简单的规则只是访问一个单元格,就能选择ACYCLIC FAST算法。 在列表9-24的执行计划显示在本例中ACYCLIC FAST算法用于规则求值。
Listing 9-24.  Automatic Order and ACYCLIC FAST
  1    select distinct product, country, year,week, sale_first_Week
  2    from sales_fact
  3    where country in ('Australia') and product='Xtend Memory'
  4    model return updated rows
  5    partition by (product, country)
  6    dimension by (year,week)
  7    measures ( 0 sale_first_week ,sale )
  8    rules automatic order(
  9       sale_first_week [2000,1] = 0.12*sale [2000, 1]
 10     )
 11*    order by product, country,year, week
 
----------------------------------------------
| Id  | Operation                          | Name       |
----------------------------------------------
|   0 | SELECT STATEMENT            |            |
|   1 |  SORT ORDER BY                 |            |
|   2 |   SQL MODEL ACYCLIC FAST |            |
|*  3 |    TABLE ACCESS FULL        | SALES_FACT |
----------------------------------------------

CYCLIC
     The execution plan in Listing 9-25 shows the use of  CYCLIC  algorithm to evaluate the rules. The SQL in Listing 9-25 is the copy of Listing 9-23 except for that the clause order by year, week  is removed from
the rule in line 9. Without the  order-by  clause, row evaluation can happen in any order, and so the
CYCLIC algorithm is chosen. 

    在列表9-25的执行计划展示使用CYCLIC算法规则求值。在列表9-25中的SQL是列表9-23的copy除了第9行的rule中去除了子句 order by year, week。没有了order-by子句,行的求值可以以任意顺序发生,因此CYCLIC算法被选择。
Listing 9-25.  Automatic Order and CYCLIC
 1    select product, country, year, week, inventory, sale, receipts
 2    from sales_fact
 3    where country in ('Australia') and product='Xtend Memory'
 4    model return updated rows
 5    partition by (product, country)
 6    dimension by (year, week)
 7    measures ( 0 inventory , sale, receipts)
 8    rules automatic order(
 9         inventory [year, week ]  /*order by year, week*/ =
10                                   nvl(inventory [cv(year), cv(week)-1 ] ,0)
11                                    - sale[cv(year), cv(week) ] +
12                                    + receipts [cv(year), cv(week) ]
13     )
14*    order by product, country,year, week
 
------------------------------------------
| Id  | Operation                   | Name         |
------------------------------------------
|   0 | SELECT STATEMENT    |                   |
|   1 |  SORT ORDER BY         |                  |
|   2 |   SQL MODEL CYCLIC    |                   |
|*  3 |    TABLE ACCESS FULL| SALES_FACT |
------------------------------------------

Sequential
    If the rule specifies sequential order, then the evaluation algorithm of the rules is shown as ORDERED.
Listing 9-26 shows an example. 
    如果规则指定sequential order,则规则求值算法显示的是ORDERER。列表9-26展示了一个例子。
Listing 9-26.  Sequential Order
 1    select product, country, year, week, inventory, sale, receipts
 2    from sales_fact
 3    where country in ('Australia') and product='Xtend Memory'
 4    model return updated rows
 5    partition by (product, country)
 6    dimension by (year, week)
 7    measures ( 0 inventory , sale, receipts)
 8    rules sequential order (
 9         inventory [year, week ] order by year, week =
10                                   nvl(inventory [cv(year), cv(week)-1 ] ,0)
11                                    - sale[cv(year), cv(week) ] +
12                                    + receipts [cv(year), cv(week) ]
13     )
14*    order by product, country,year, week
-------------------------------------------
| Id  | Operation                  | Name       |
------------------------------------------- 
|   0 | SELECT STATEMENT    |            |
|   1 |  SORT ORDER BY         |            |
|   2 |   SQL MODEL ORDERED |            |
|*  3 |    TABLE ACCESS FULL| SALES_FACT |
-------------------------------------------
 
    In a nutshell, the complexity and inter-dependency of the rules plays a critical role in the
algorithm chosen.
ACYCLIC FAST  and ORDERED FAST  algorithms are more scalable. This becomes
important as the amount of data increases.

    简言之,复杂性和规则的相互依赖性在算法选择中扮演了至关重要的角色。 ACYCLIC FAST  和ORDERED FAST 算法较为可扩展。随着数据量的增加这点变得重要。

Predicate Pushing   谓词推进
    Conceptually, the Model clause is a variant of analytical SQL and is typically implemented in a view or
inline view.
Predicates are specified outside the view, and these predicates must be pushed in to the
view for acceptable performance. In fact, predicate pushing is critical to performance of the Model
clause. Unfortunately, not all predicates can be pushed safely into the view due to the unique nature of
the Model clause.
If predicates are not pushed, then the Model clause will execute on the larger set of
rows and can result in poor performance. 
    概念上讲,Model子句是分析SQL的变形体且是通常在视图中或内联视图中 执行 谓词在视图外部指定,为了可接受的性能,这些谓词必须推进到视图中。事实上,谓词推进对Model子句的性能至关重要。不幸的是,不是所有的谓词都能安全的推进到视图中,因为Model子句唯一的天性。 如果谓词没有推进,则Model子句将在大的行集上运行而导致糟糕的性能。
    In Listing 9-27, an inline view is defined from lines 2 to 14 and then predicates on columns Country and Product are added. Step 4 in the execution plan shows that both predicates are pushed into the view, rows are filtered applying these two predicates, and then the Model clause executes on the result set. This is good, as the Model clause is operating on a smaller set of rows than it would otherwise—just 147 rows in this case.
    在列表9-27中,一内联视图在2到14行间定义且在列Country 和Product上的加入谓词。执行计划的第四步展示两个谓词都推进入了视图,符合这两个谓词的行被过滤掉了,接着Model子句运行在这个结果集上。这是好的,因为Model子句运作在小的行集上相比于它原来--本例中仅147行。
Listing 9-27.  Predicate Pushing
  1   select * from (
  2    select product, country, year, week, inventory, sale, receipts
  3    from sales_fact
  4    model return updated rows
  5    partition by (product, country)
  6    dimension by (year, week)
  7    measures ( 0 inventory , sale, receipts)
  8    rules automatic order(
  9         inventory [year, week ] =
 10                                   nvl(inventory [cv(year), cv(week)-1 ] ,0)
 11                                    - sale[cv(year), cv(week) ] +
 12                                    + receipts [cv(year), cv(week) ]
 13     )
 14   ) where country in ('Australia') and product='Xtend Memory'
 15*   order by product, country,year, week
...
select * from table (dbms_xplan.display_cursor('','','ALLSTATS LAST'));
-------------------------------------------------------------------------------
| Id  | Operation                   | Name           | E-Rows |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |                  |            |           |           |              |
|   1 |  SORT ORDER BY          |                  |    147   | 18432 | 18432   |16384  (0)|
|   2 |   VIEW                       |                  |    147   |          |            |              |
|   3 |    SQL MODEL CYCLIC   |                   |    147  |   727K |   727K  |  358K (0)|
|*  4 |     TABLE ACCESS FULL| SALES_FACT |    147  |           |           |              |
-------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   4 - filter(("PRODUCT"='Xtend Memory' AND "COUNTRY"='Australia'))
 
    Listing 9-28 enumerates an example in which the predicates are not pushed into the view. In this
example, predicate  year=2000  is specified, but not pushed into the inline view. The optimizer estimates
show that the Model clause needs to operate on some 111,000 (110K) rows. 
    列表9-28列举了一个谓词没有推进视图的例子。在该例中,指定谓词year=2000 ,但是没有推进如内联视图。优化器评估显示Model子句需要操作大约111,000 (110K) 行。
    Predicates can be pushed into a view only if it’s safe to do so. The SQL in Listing 9-28 uses both the
Year and Week column as dimension columns. Generally, predicates on the partitioning columns can
be pushed in to a view safely , but not all predicates on the dimension column can be pushed.

    谓词能被推进入视图只有当它这样做安全才行。在列表9-28的SQL把Year 和Week两列都用作维度列。一般而言,在分区列上的谓词能安全的推进入视图,但是不是所有在维度列上的谓词能被推进。
Listing 9-28. Predicate not Pushed
  1   select * from (
  2    select product, country, year, week, inventory, sale, receipts
  3    from sales_fact
  4    mod el return updated rows
  5    partition by (product, country)
  6    dimension by (year, week)
  7    measures ( 0 inventory , sale, receipts)
  8    rules automatic order(
  9         inventory [year, week ] =
 10                                   nvl(inventory [cv(year), cv(week)-1 ] ,0)
 11                                    - sale[cv(year), cv(week) ] +
 12                                    + receipts [cv(year), cv(week) ]
 13     )
 14   ) where year=2000
 15*   order by product, country,year, week
-------------------------------------------------------------------------------
| Id  | Operation                      | Name          | E-Rows |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |                  |             |           |          |               |
|   1 |  SORT ORDER BY           |                  |    111K  |  2604K |   733K | 2314K (0) |
|*  2 |   VIEW                         |                  |    111K   |           |          |               |
|   3 |    SQL MODEL CYCLIC    |                  |    111K   |    12M |  1886K |   12M (0) |
|   4 |     TABLE ACCESS FULL | SALES_FACT |    111K   |          |           |               |
-------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("YEAR"=2000)

Materialized Views     物化视图
    Typically, SQL statements using the Model clause access very large tables. Oracle’s query Rewrite
feature and Materialized views can be combined to improve performance of such statements. 
    通常,SQL语句使用Model子句访问非常大的表。Oracle的查询重写特性和物化视图组合能提升这种语句的性能。
    In Listing 9-29, a materialized view  mv_model_inventory  is created with the  enable query rewrite
clause. Subsequent SQL in the listing executes the SQL statement accessing the Sales_fact table with
the Model clause. The execution plan for the statement shows that the query rewrite feature rewrote
the query redirecting access to the materialized view instead of the base table. The rewrite improves
the performance of the SQL statement since the materialized view has pre-evaluated the rules and
stored the results.
    在列表9-29中,用子句enable query rewrite创建了一物化视图mv_model_inventory。列表后面的SQL执行SQL语句用Model子句访问Sales_fact表。语句的执行计划显示查询重写特性重写查询重定位访问物化视图而不是基表。重写提升了SQL语句的性能因为物化视图对规则预先求值且存储了结果。
NOTE   The fast incremental refresh is not available for materialized views involving the Model clause.
注意 快速增量刷新 对于涉及Model子句的物化视图不是有效的。

Listing 9-29.  Materialized View and Query Rewrite
create  materialized view  mv_model_inventory
enable query rewrite as
  select product, country, year, week, inventory, sale, receipts
  from sales_fact
  model return updated rows
  partition by (product, country)
  dimension by (year, week)
  measures ( 0 inventory , sale, receipts)
  rules sequential order(
       inventory [year, week ] order by year, week =
                                 nvl(inventory [cv(year), cv(week)-1 ] ,0)
                                  - sale[cv(year), cv(week) ] +
                                  + receipts [cv(year), cv(week) ]
   )
/
Materialized view created.
 
select * from (
 select product, country, year, week, inventory, sale, receipts
  from sales_fact
  model return updated rows
  partition by (product, country)
  dimension by (year, week)
  measures ( 0 inventory , sale, receipts)
  rules sequential order(
       inventory [year, week ] order by year, week =
                                 nvl(inventory [cv(year), cv(week)-1 ] ,0)
                                  - sale[cv(year), cv(week) ] +
                                  + receipts [cv(year), cv(week) ]
   )
 )
where country in ('Australia') and product='Xtend Memory' 
order by product, country,year, week
/
 
------------------------------------------------------------
| Id  | Operation                                     | Name                   |
------------------------------------------------------------
|   0 | SELECT STATEMENT                       |                            |
|   1 |  SORT ORDER BY                            |                            |
|*  2 |   MAT_VIEW REWRITE ACCESS FULL |  MV_MODEL_INVENTORY|
------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
  2 - filter(("MV_MODEL_INVENTORY"."COUNTRY"='Australia' AND
             "MV_MODEL_INVENTORY"."PRODUCT"='Xtend Memory'))

Parallelism   并行性
     Model-based SQL works seamlessly with Oracle’s parallel execution features. Queries against
partitioned tables benefit greatly from parallelism and Model-based SQL statements. 
    基于Model的SQL与Oracle的并行执行特性无缝集成。查询分区表极大的受益于并行性和基于Model的SQL语句。
    An important concept with parallel query execution and Model SQL is that parallel query
execution needs to respect the partition boundaries. Rules defined in the Model clause-based SQL
statement might access another row. After all, accessing another row is the primary reason to use
Model SQL statements. So, a parallel query slave must receive all rows from a Model data partition so
that the rules can be evaluated.
This distribution of rows to parallel query slaves is taken care of
seamlessly by the database engine. The first set of parallel slaves reads row pieces from the table and
distributes the row pieces to second set of slaves. That distribution is such that one slave receives all
rows of a given model partition. 

    关于并行查询执行和Model SQL是并行查询执行的一个重要概念是需要考虑分区边界。在基于Model SQL语句中定义的规则可以访问其他行。全然,访问其他行是使用Model SQL语句的主要原因。但是一并行查询从属进程必须检索所有来自 Model数据分区的行,才能对规则求值。 并发查询从属进程的行集分布由数据库无缝的管理着。第一组并行从属进程从表中读行片再分配行片给第二组从属进程。分配是一从属进程接收一给定model分区的所有行。
    Listing 9-30 shows an example of Model and parallel queries. Two set of parallel slaves are allocated to execute the statement shown. The first set of slaves is read from the table. The second set of slaves evaluates the Model rule.
    列表9-30展示了Model和并行查询的例子。并行副盘的两集合分配用于执行语句。副盘的第一集合从表读取,副盘的第二集合对Model规则求值。
Listing 9-30.  Model and Parallel Queries
select  /*+ parallel ( sf 4) */ 
  product, country, year, week, inventory, sale, receipts
  from sales_fact sf 
  where country in ('Australia') and product='Xtend Memory' 
  model return updated rows
  partition by (product, country)
  dimension by (year, week)
  measures ( 0 inventory , sale, receipts)
  rules automatic order(
       inventory [year, week ] order by year, week =
                                 nvl(inventory [cv(year), cv(week)-1 ] ,0)
                                  - sale[cv(year), cv(week) ] +
                                  + receipts [cv(year), cv(week) ]
   )
/
-----------------------------------------------...--------------------------
| Id  | Operation                         | Name         |    TQ     |IN-OUT| PQ Distrib |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT           |                 |...          |            |            |
|   1 |  PX COORDINATOR             |                  |             |            |            |
|   2 |   PX SEND QC (RANDOM)     | :TQ10001    |  Q1,01  | P->S     | QC (RAND)  |
|   3 |    BUFFER SORT                 |                 |  Q1,01   | PCWP   |            |
|   4 |     SQL MODEL ACYCLIC      |                 |  Q1,01   | PCWP   |            |
|   5 |      PX RECEIVE                 |                  |  Q1,01   | PCWP   |            |
|   6 |       PX SEND HASH           | :TQ10000     |  Q1,00   | P->P    | HASH       |
|   7 |        PX BLOCK ITERATOR   |                   |  Q1,00  | PCWC   |            |
|*  8 |         TABLE ACCESS FULL | SALES_FACT |  Q1,00  | PCWP    |            |
----------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   8 - access(:Z>=:Z AND :Z<=:Z)
       filter(("PRODUCT"='Xtend Memory' AND "COUNTRY"='Australia'))

Partitioning in Model Clause Execution      Model子句执行中的分区
    Table partitioning can be used to improve the performance of Model SQL statements.  Generally, if the
partitioning column(s) in the Model SQL matches the partitioning keys of the table, partitions are
pruned.
Partition pruning is a technique for performance improvement to limit scanning few partitions. 
    表分区能用于提升Model SQL 语句的执行性能。一般而言,如果Model SQL 中的分区列匹配表的分区键,分区被修剪了。分区修剪 是指限制扫描少部分的分区的一项提升性能的技术。
    In Listing 9-31, the table  sales_fact_part  is list-partitioned by year using the script Listing_9_31_partition.sql (part of the example download for this book). The partition with partition_id=3 contains rows with the value of 2000 for the Year column. Since the Model SQL is using Year as the partitioning column and since a year=2000  predicate is specified, partition pruning lead to scanning partition 3 alone. The execution plan shows that both Pstart and Pstop columns have a value of 3, indicating that the range of partitions to be processed begins and ends with the single partition having id=3. 
    在列表9-31,表sales_fact_part用脚本Listing_9_31_partition.sql(本书样例样例下载的部分) 按year列表分区了。partition_id=3的分区包含Year列值为2000的行集。由于Model SQL用Year作为分区列而且因为指定了谓词year=2000,分区修剪使得只单独扫描分区3。 执行计划显示Pstart 和Pstop 两列都有值3,表明被处理的分区开始和结束的范围只在单个分区id=3(那个分区中)。

Listing 9-31.  Partition Pruning 
select * from (
  select product, country, year, week, inventory, sale, receipts
  from sales_fact_part sf
  model return updated rows
  partition by (year, country )
  dimension by (product, week)
  measures ( 0 inventory , sale, receipts )
  rules automatic order(
       inventory [product, week ] order by product,  week =
                                 nvl(inventory [cv(product),  cv(week)-1 ] ,0)
                                  - sale[cv(product),  cv(week) ] +
                                  + receipts [cv(product), cv(week) ]
   )
 )   where year=2000 and country='Australia' and product='Xtend Memory'
/
--------------------------------------------------...----------------
| Id  | Operation                          | Name                     |... Pstart| Pstop |
---------------------------------------------------------------------
|   0 | SELECT STATEMENT       |                               |              |         |
|   1 |  SQL MODEL ACYCLIC     |                              |              |         |
|   2 |   PARTITION LIST SINGLE|                               |      KEY |   KEY |
|*  3 |    TABLE ACCESS FULL   | SALES_FACT_PART |        3   |     3 |
---------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
   1 - filter("PRODUCT"='Xtend Memory')
   4 - filter("COUNTRY"='Australia')
     In Listing 9-32, columns Product and County are used as partitioning columns, but the table
Sales_fact_part has the Year column as the partitioning key. Step 1 in the execution plan indicates that
predicate  year=2000 was not pushed into the view since the rule can access other partitions (as Year is
a dimension column).
Because the partitioning key is not pushed into the view, partition pruning is
not allowed, and all partitions are scanned. You can see that Pstart and Pstop are 1 and 5, respectively,
in the execution plan.
    在列表9-32中,列Product和Country用做分区列,但是表Sales_fact_part 的分区键是列Year 。执行计划中的步骤1表明谓词year=2000没有推进入视图因为规则能访问其它的分区(因为Year是维度列)。 因为分区键没有推进入视图,分区修剪 不被允许,则扫描所有分区。你可从执行计划中看出Pstart 和Pstop分别是1和5。
Listing 9-32.  No Partition Pruning
  select * from (
  select product, country, year, week, inventory, sale, receipts
  from sales_fact_part sf
  model return updated rows
  partition by (product, country)
  dimension by (year, week)
  measures ( 0 inventory , sale, receipts)
  rules automatic order(
       inventory [year, week ] order by year,  week =
                                 nvl(inventory [cv(year),  cv(week)-1 ] ,0)
                                  - sale[cv(year),  cv(week) ] +
                                  + receipts [cv(year), cv(week) ]
   )
 )   where year=2000 and country='Australia' and product='Xtend Memory'
/
--------------------------------------------------...----------------
| Id  | Operation                          | Name                     |... Pstart| Pstop |
---------------------------------------------------------------------
|   0 | SELECT STATEMENT       |                               |              |         |
|   1 |  SQL MODEL ACYCLIC     |                              |              |         |
|   2 |   PARTITION LIST ALL     |                                 |      1     |   5   |
|*  3 |    TABLE ACCESS FULL   | SALES_FACT_PART |        1  |    5   |
---------------------------------------------------------------------

Indexes    索引
    Choosing indexes to improve the performance of SQL astatements using a Model clause is no different from choosing indexes for any other SQL statements. You use the access and filter predicates to determine the optimal indexing strategy.
    选择索引提升使用Model子句的SQL语句的性能与其他任何SQL语句选择索引没区别。你使用访问和过滤谓词确定优化的索引策略。
    As an example,Listing 9-32's execution plan shows that the filter predicates Product"='Xtend Memory' AND "COUNTRY"='Australia' were appied at step 4. Indexing on the two columns Product and Country will be helpful if there are many executions with these column predicates.
    作为一个例子,列表9-32的执行计划展示过滤谓词Product"='Xtend Memory' AND "COUNTRY"='Australia'在步骤4应用。如果执行中用到了这些谓词则在列Product和Country上的索引将是有帮助的。
    In the Listing 9-33, I added an index to the columns Country and Product. The resulting execution plan shows table access via the index, possibly improving performance.
    在列表9-3中,我在列Country 和Product加了组合索引。生成的执行计划显示表访问通过索引,可能提升性能。
List 9-33 Indexing with SQL Access in Mind     索引用于SQL访问的思考
create index sales_fact_part_i1 on sales_fact_part(country,product);
 
 select * from (
  select product, country, year, week, inventory, sale, receipts
  from sales_fact_part sf
  model return updated rows
  partition by (product, country)
  dimension by (year, week)
  measures ( 0 inventory , sale, receipts)
  rules automatic order(
       inventory [year, week ] order by year,  week =
                                 nvl(inventory [cv(year),  cv(week)-1 ] ,0)
                                  - sale[cv(year),  cv(week) ] +
                                  + receipts [cv(year), cv(week) ]
   )
 )   where year=2000 and country='Australia' and product='Xtend Memory' ;
/

-----------------------------------------------------------------------------------
| Id  | Operation                                             | Name               | Pstart| Pstop |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                             |                    |       |       |
|*  1 |  VIEW                                                |                    |       |       |
|   2 |   SQL MODEL ACYCLIC                            |                    |       |       |
|   3 |    TABLE ACCESS BY GLOBAL INDEX ROWID| SALES_FACT_PART    | ROWID | ROWID |
|*  4 |     INDEX RANGE SCAN                           | SALES_FACT_PART_I1 |       |       |
-----------------------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
   1 - filter("YEAR"=2000)
   4 - access("COUNTRY"='Australia' AND "PRODUCT"='Xtend Memory')

 

1
12
分享到:
评论

相关推荐

Global site tag (gtag.js) - Google Analytics