您好,登錄后才能下訂單哦!
一.簡單視圖合并:指針對那些不含外連接,以及所帶視圖定義sql語句中不含distinct,group by等聚合函數的目標sql的視圖合并。
create or replace view view_1 as SELECT t2.prod_id FROM sales t2, customers t3 WHERE t2.cust_id = t3.cust_id AND t3.cust_gender = 'M';
視圖合并:
SELECT t1.prod_id, t1.prod_name FROM products t1,view_1 WHERE t1.prod_id = view_1.prod_id 4 AND t1.prod_list_price > 1000; Execution Plan ---------------------------------------------------------- Plan hash value: 3569238377 ----------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | ----------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 213K| 10M| 648(2)| 00:00:08 | | | |* 1 | HASH JOIN | | 213K| 10M| 648(2)| 00:00:08 | | | |* 2 | VIEW | index$_join$_004 | 27750 | 189K| 119(1)| 00:00:02 | | | |* 3 | HASH JOIN | | | | | | | | | 4 | BITMAP CONVERSION TO ROWIDS| | 27750 | 189K| 2(0)| 00:00:01 | | | |* 5 | BITMAP INDEX SINGLE VALUE | CUSTOMERS_GENDER_BIX | | | | | | | | 6 | INDEX FAST FULL SCAN | CUSTOMERS_PK | 27750 | 189K| 145(0)| 00:00:02 | | | |* 7 | HASH JOIN | | 213K| 9160K| 528(2)| 00:00:07 | | | |* 8 | TABLE ACCESS FULL | PRODUCTS | 17 | 595 | 3(0)| 00:00:01 | | | | 9 | PARTITION RANGE ALL | | 918K| 8075K| 523(1)| 00:00:07 | 1 | 28 | | 10 | TABLE ACCESS FULL | SALES | 918K| 8075K| 523(1)| 00:00:07 | 1 | 28 | -----------------------------------------------------------------------------------------------------------------------
禁用視圖合并:
SELECT /*+ no_merge(view_1) */ t1.prod_id, t1.prod_name FROM products t1, view_1 WHERE t1.prod_id = view_1.prod_id AND t1.prod_list_price > 1000 ; 10156 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 2109926904 ------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows| Bytes | Cost (%CPU)| Time| Pstart| Pstop | ------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT || 213K| ×××K| 649 (2)| 00:00:08 ||| |* 1 | HASH JOIN || 213K| ×××K| 649 (2)| 00:00:08 ||| |* 2 | TABLE ACCESS FULL | PRODUCTS| 17 | 595 | 3 (0)| 00:00:01 ||| | 3 | VIEW | VIEW_1| 918K| 11M| 644 (2)| 00:00:08 ||| |* 4 | HASH JOIN || 918K| 14M| 644 (2)| 00:00:08 ||| |* 5 | VIEW | index$_join$_004| 27750 | 189K| 119 (1)| 00:00:02 ||| |* 6 | HASH JOIN |||| |||| | 7 | BITMAP CONVERSION TO ROWIDS|| 27750 | 189K| 2 (0)| 00:00:01 ||| |* 8 | BITMAP INDEX SINGLE VALUE | CUSTOMERS_GENDER_BIX ||| |||| | 9 | INDEX FAST FULL SCAN | CUSTOMERS_PK | 27750 | 189K| 145 (0)| 00:00:02 ||| | 10 | PARTITION RANGE ALL || 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | | 11 | TABLE ACCESS FULL | SALES| 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | ------------------------------------------------------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - access("T1"."PROD_ID"="VIEW_1"."PROD_ID") 2 - filter("T1"."PROD_LIST_PRICE">1000) 4 - access("T2"."CUST_ID"="T3"."CUST_ID") 5 - filter("T3"."CUST_GENDER"='M') 6 - access(ROWID=ROWID) 8 - access("T3"."CUST_GENDER"='M')
一般來說,如果oracle并沒有選擇對帶視圖的目標sql執行合并的話,那么該sql的執行計劃中就會見到“view”關鍵字,并且該關鍵字所對應的Name列的值就是該視圖的名稱.
千萬 不要認為只要執行計劃中出現了VIEW關鍵字就表明oracle一定沒有做視圖合并,這是不一定的,因為還存在著其他的一些特殊情形,在這些情形下,即使oracle做了視圖合并,其對應執行計劃中葉會出現VIEW關鍵字,比如inde_jion后面出現的臨時視圖,對于符合簡單條件視圖合并條件的目標sql。oracle始終會對其進行視圖合并,不管成本。
二:外連接視圖合并:是指針對那些使用了外連接,以及所帶視圖的視圖定義sql語句中不含distinct,group by等聚合函數的目標sql的視圖合并。這里使用外連接的含義指外部查詢的表和視圖之間使用了外連接,或該視圖的視圖定義sql語句中使用了外連接。外連接視圖的限制:當目標視圖和外部查詢的表做外連接時,該目標視圖可以做外連接視圖合并的前提條件是,要么該視圖被作為外連接的驅動表,要么該視圖雖然被作為外連接的被驅動表但它的視圖定義的sql語句中指包含一個表。
SELECT t1.prod_id, t1.prod_name FROM products t1,view_2 3 WHERE t1.prod_id(+) = view_2.prod_id; 594703 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 523667190 ------------------------------------------------------------------------------------------------------------------------ | Id | Operation| Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | ------------------------------------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT| | 918K| 40M| 649 (2)| 00:00:08 | | | |* 1 | HASH JOIN RIGHT OUTER| | 918K| 40M| 649 (2)| 00:00:08 | | | | 2 | TABLE ACCESS FULL| PRODUCTS | 72 | 2160 | 3 (0)| 00:00:01 | | | |* 3 | HASH JOIN| | 918K| 14M| 644 (2)| 00:00:08 | | | |* 4 | VIEW | index$_join$_004 | 27750 | 189K| 119 (1)| 00:00:02 | | | |* 5 | HASH JOIN| | | | | | | | | 6 | BITMAP CONVERSION TO ROWIDS| | 27750 | 189K| 2 (0)| 00:00:01 | | | |* 7 | BITMAP INDEX SINGLE VALUE | CUSTOMERS_GENDER_BIX | | | | | | | | 8 | INDEX FAST FULL SCAN| CUSTOMERS_PK | 27750 | 189K| 145 (0)| 00:00:02 | | | | 9 | PARTITION RANGE ALL| | 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | | 10 | TABLE ACCESS FULL| SALES | 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | ------------------------------------------------------------------------------------------------------------------------
更改驅動表后,沒有進行視圖合并(且視圖定義sql有2個表關聯):
SELECT t1.prod_id, t1.prod_name FROM products t1,view_2 3 WHERE t1.prod_id = view_2.prod_id(+) 4 ; 5 SELECT t1.prod_id, t1.prod_name FROM products t1,view_2 3 WHERE t1.prod_id = view_2.prod_id(+) 4 ; 594703 rows selected Execution Plan ---------------------------------------------------------- Plan hash value: 2735117096 ------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows| Bytes | Cost (%CPU)| Time| Pstart| Pstop | ------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT || 918K| 37M| 649 (2)| 00:00:08 ||| |* 1 | HASH JOIN OUTER || 918K| 37M| 649 (2)| 00:00:08 ||| | 2 | TABLE ACCESS FULL | PRODUCTS| 72 | 2160 | 3 (0)| 00:00:01 ||| | 3 | VIEW | VIEW_2| 918K| 11M| 644 (2)| 00:00:08 ||| |* 4 | HASH JOIN || 918K| 14M| 644 (2)| 00:00:08 ||| |* 5 | VIEW | index$_join$_004| 27750 | 189K| 119 (1)| 00:00:02 ||| |* 6 | HASH JOIN |||| |||| | 7 | BITMAP CONVERSION TO ROWIDS|| 27750 | 189K| 2 (0)| 00:00:01 ||| |* 8 | BITMAP INDEX SINGLE VALUE | CUSTOMERS_GENDER_BIX ||| |||| | 9 | INDEX FAST FULL SCAN | CUSTOMERS_PK | 27750 | 189K| 145 (0)| 00:00:02 ||| | 10 | PARTITION RANGE ALL || 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | | 11 | TABLE ACCESS FULL | SALES| 918K| 8075K| 523 (1)| 00:00:07 | 1 | 28 | -------------------------------------------------------------------------------------------------------------------------
當視圖的定義sql中只有一個表:
可以進行視圖合并:
create or replace view view_3 as SELECT t2.prod_id FROM sales t2 WHERE t2.amount_sold>700 SELECT t1.prod_id, t1.prod_name FROM products t1,view_3 3 WHERE t1.prod_id = view_3.prod_id(+); 39317 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 1313708566 ------------------------------------------------------------------------------------------------- | Id | Operation | Name| Rows| Bytes | Cost (%CPU)| Time| Pstart| Pstop | ------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT || 560K| 20M| 531 (2)| 00:00:07 ||| |* 1 | HASH JOIN OUTER || 560K| 20M| 531 (2)| 00:00:07 ||| | 2 | TABLE ACCESS FULL | PRODUCTS | 72 | 2160 | 3 (0)| 00:00:01 ||| | 3 | PARTITION RANGE ALL|| 560K| 4922K| 526 (2)| 00:00:07 | 1 | 28 | |* 4 | TABLE ACCESS FULL | SALES| 560K| 4922K| 526 (2)| 00:00:07 | 1 | 28 | -------------------------------------------------------------------------------------------------
三.復雜視圖合并:
復雜視圖合并(Complex View Mergin)是針對那些所帶視圖的視圖定義sql語句中中含有group by或distinct的目標sql的視圖合并.
和簡單視圖合并,外連接視圖合并一樣,對這種視圖定義sql語句中含有group by或distinct的復雜視圖做視圖合并也同樣意味著要把其定義sql語句拆開,并把其中的基表和外部查詢中的表合并,這通常意味著上述視圖定義sql語句中的group by或distinct操作會被推遲執行,也就是說,這種情況下通常會先做表連接,再做group by 或distinct操作,而不是像未做復雜視圖合并時那樣在視圖內部做完group by或distinct操作,然后才和外部查詢中的表做表連接。
復雜視圖合并所對應的group by 或distinct操作延遲,并不一定總是能帶來執行效率以及性能上的提升。例如,如果group by或distinct操作能過濾掉絕大部分的數據且表連接并不能有效過濾數據的話,那么先在視圖內部做group by或者distinct操作,然后和外部查詢中的表做表連接的執行效率會更高些,但是如果表連接能過濾絕大部分數據而group by或distinct操作并不能有效過濾數據的話,那么先做表連接,在做group by或distinct的操作的執行效率顯然會更好一些。
正是因為復雜視圖合并并不一定總是能帶來目標sql的執行效率及性能上得提升,所以oracle 10g及以后的版本中,對應復雜視圖的合并,只有當經過復雜視圖合并后等價sql的成本值小于原sql的成本值時,oracle才會對目標sql執行復雜sql的視圖合并。
SQL> set lines 200 pagesize 1000
SELECT t1.cust_id, t1.cust_last_name
FROM customers t1, products t2, view_3 t3
WHERE t1.cust_id = t3.cust_id
AND t2.prod_id = t3.prod_id
AND t3.total > 1000
AND t2.prod_category = 'Hardware'
AND t1.cust_year_of_birth = 1977
7 8 AND t1.cust_marital_status = 'married';
32 rows selected.
Execution Plan
----------------------------------------------------------
Plan hash value: 3286306050
--------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 61 | 5002 | 544 (2)| 00:00:07 | | |
|* 1 | FILTER | | | | | | | |
| 2 | HASH GROUP BY | | 61 | 5002 | 544 (2)| 00:00:07 | | |
|* 3 | HASH JOIN | | 1201 | 98482 | 543 (2)| 00:00:07 | | |
| 4 | TABLE ACCESS BY INDEX ROWID | PRODUCTS | 14 | 462 | 3 (0)| 00:00:01 | | |
|* 5 | INDEX RANGE SCAN | PRODUCTS_PROD_CAT_IX | 14 | | 1 (0)| 00:00:01 | | |
|* 6 | HASH JOIN | | 6007 | 287K| 540 (2)| 00:00:07 | | |
| 7 | TABLE ACCESS BY INDEX ROWID | CUSTOMERS | 46 | 1610 | 13 (0)| 00:00:01 | | |
| 8 | BITMAP CONVERSION TO ROWIDS| | | | | | | |
| 9 | BITMAP AND | | | | | | | |
|* 10 | BITMAP INDEX SINGLE VALUE| CUSTOMERS_YOB_BIX | | | | | | |
|* 11 | BITMAP INDEX SINGLE VALUE| CUSTOMERS_MARITAL_BIX | | | | | | |
| 12 | PARTITION RANGE ALL | | 918K| 12M| 525 (2)| 00:00:07 | 1 | 28 |
| 13 | TABLE ACCESS FULL | SALES | 918K| 12M| 525 (2)| 00:00:07 | 1 | 28 |
--------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(SUM("AMOUNT_SOLD")>1000)
3 - access("T2"."PROD_ID"="PROD_ID")
5 - access("T2"."PROD_CATEGORY"='Hardware')
6 - access("T1"."CUST_ID"="CUST_ID")
10 - access("T1"."CUST_YEAR_OF_BIRTH"=1977)
11 - access("T1"."CUST_MARITAL_STATUS"='married')
Statistics
----------------------------------------------------------
8 recursive calls
0 db block gets
1914 consistent gets
1619 physical reads
0 redo size
1461 bytes sent via SQL*Net to client
546 bytes received via SQL*Net from client
4 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
32 rows processed
SELECT /*+ no_merge(t3) */t1.cust_id, t1.cust_last_name
FROM customers t1, products t2, view_3 t3
WHERE t1.cust_id = t3.cust_id
AND t2.prod_id = t3.prod_id
AND t3.total > 1000
AND t2.prod_category = 'Hardware'
AND t1.cust_year_of_birth = 1977
8 AND t1.cust_marital_status = 'married';
32 rows selected.
Execution Plan
----------------------------------------------------------
Plan hash value: 215761499
---------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 70 | 550 (6)| 00:00:07 | | |
| 1 | NESTED LOOPS | | 1 | 70 | 550 (6)| 00:00:07 | | |
| 2 | NESTED LOOPS | | 1 | 70 | 550 (6)| 00:00:07 | | |
| 3 | NESTED LOOPS | | 1 | 47 | 549 (6)| 00:00:07 | | |
| 4 | VIEW | VIEW_3 | 1 | 26 | 548 (6)| 00:00:07 | | |
|* 5 | FILTER | | | | | | | |
| 6 | HASH GROUP BY | | 1 | 14 | 548 (6)| 00:00:07 | | |
| 7 | PARTITION RANGE ALL | | 918K| 12M| 525 (2)| 00:00:07 | 1 | 28 |
| 8 | TABLE ACCESS FULL | SALES | 918K| 12M| 525 (2)| 00:00:07 | 1 | 28 |
|* 9 | TABLE ACCESS BY INDEX ROWID| PRODUCTS | 1 | 21 | 1 (0)| 00:00:01 | | |
|* 10 | INDEX UNIQUE SCAN | PRODUCTS_PK | 1 | | 0 (0)| 00:00:01 | | |
|* 11 | INDEX UNIQUE SCAN | CUSTOMERS_PK | 1 | | 0 (0)| 00:00:01 | | |
|* 12 | TABLE ACCESS BY INDEX ROWID | CUSTOMERS | 1 | 23 | 1 (0)| 00:00:01 | | |
---------------------------------------------------------------------------------------------------------------
免責聲明:本站發布的內容(圖片、視頻和文字)以原創、轉載和分享為主,文章觀點不代表本網站立場,如果涉及侵權請聯系站長郵箱:is@yisu.com進行舉報,并提供相關證據,一經查實,將立刻刪除涉嫌侵權內容。