【DB笔试面试619】在Oracle中,举例说明“连接因式分解(Join factorization,JF)”查询转换。...

【DB笔试面试619】在Oracle中,举例说明“连接因式分解(Join factorization,JF)”查询转换。...

♣题目 部分

在Oracle中,举例说明“连接因式分解(Join factorization,JF)”查询转换。


     
♣答案部分



 1LHR@orclasm > SELECT  /*+FULL(A) FULL(B)*/  A.*,B.DNAME FROM SCOTT.EMP A,SCOTT.DEPT B WHERE A.DEPTNO=B.DEPTNO AND A.EMPNO=6
 2  2  UNION ALL
 3  3  SELECT  /*+FULL(A) FULL(B)*/  A.*,B.DNAME FROM SCOTT.EMP A,SCOTT.DEPT B WHERE A.DEPTNO=B.DEPTNO AND A.EMPNO=7;
 4
 5no rows selected
 6
 7
 8Execution Plan
 9----------------------------------------------------------
10Plan hash value: 1245103347
11
12-------------------------------------------------------------------------------------------
13| Id  | Operation            | Name               | Rows  | Bytes | Cost (%CPU)| Time     |
14-------------------------------------------------------------------------------------------
15|   0 | SELECT STATEMENT     |                    |     2 |   244 |     8  (13)| 00:00:01 |
16|*  1 |  HASH JOIN           |                    |     2 |   244 |     8  (13)| 00:00:01 |
17|   2 |   VIEW               | VW_JF_SET$623BBB07 |     2 |   200 |     4   (0)| 00:00:01 |
18|   3 |    UNION-ALL         |                    |       |       |            |          |
19|*  4 |     TABLE ACCESS FULL| EMP                |     1 |    87 |     2   (0)| 00:00:01 |
20|*  5 |     TABLE ACCESS FULL| EMP                |     1 |    87 |     2   (0)| 00:00:01 |
21|   6 |   TABLE ACCESS FULL  | DEPT               |     4 |    88 |     3   (0)| 00:00:01 |
22-------------------------------------------------------------------------------------------
23
24Predicate Information (identified by operation id):
25---------------------------------------------------
26
27   1 - access("ITEM_1"="B"."DEPTNO")
28   4 - filter("A"."EMPNO"=6)
29   5 - filter("A"."EMPNO"=7)
30
31Note
32-----
33   - dynamic sampling used for this statement (level=2)
34
35
36Statistics
37----------------------------------------------------------
38         99  recursive calls
39          7  db block gets
40         32  consistent gets
41          0  physical reads
42       4536  redo size
43        866  bytes sent via SQL*Net to client
44        509  bytes received via SQL*Net from client
45          1  SQL*Net roundtrips to/from client
46          0  sorts (memory)
47          0  sorts (disk)
48          0  rows processed
49
50LHR@orclasm > ALTER SESSION SET "_OPTIMIZER_JOIN_FACTORIZATION"=FALSE; 
51
52Session altered.
53
54LHR@orclasm > SELECT  /*+FULL(A) FULL(B)*/  A.*,B.DNAME FROM SCOTT.EMP A,SCOTT.DEPT B WHERE A.DEPTNO=B.DEPTNO AND A.EMPNO=6
55  2  UNION ALL
56  3  SELECT  /*+FULL(A) FULL(B)*/  A.*,B.DNAME FROM SCOTT.EMP A,SCOTT.DEPT B WHERE A.DEPTNO=B.DEPTNO AND A.EMPNO=7;
57
58no rows selected
59
60
61Execution Plan
62----------------------------------------------------------
63Plan hash value: 2703228680
64
65----------------------------------------------------------------------------
66| Id  | Operation           | Name | Rows  | Bytes | Cost (%CPU)| Time     |
67----------------------------------------------------------------------------
68|   0 | SELECT STATEMENT    |      |     2 |   218 |     8  (50)| 00:00:01 |
69|   1 |  UNION-ALL          |      |       |       |            |          |
70|   2 |   NESTED LOOPS      |      |     1 |   109 |     4   (0)| 00:00:01 |
71|*  3 |    TABLE ACCESS FULL| EMP  |     1 |    87 |     2   (0)| 00:00:01 |
72|*  4 |    TABLE ACCESS FULL| DEPT |    82 |  1804 |     2   (0)| 00:00:01 |
73|   5 |   NESTED LOOPS      |      |     1 |   109 |     4   (0)| 00:00:01 |
74|*  6 |    TABLE ACCESS FULL| EMP  |     1 |    87 |     2   (0)| 00:00:01 |
75|*  7 |    TABLE ACCESS FULL| DEPT |    82 |  1804 |     2   (0)| 00:00:01 |
76----------------------------------------------------------------------------
77
78Predicate Information (identified by operation id):
79---------------------------------------------------
80
81   3 - filter("A"."EMPNO"=6)
82   4 - filter("A"."DEPTNO"="B"."DEPTNO")
83   6 - filter("A"."EMPNO"=7)
84   7 - filter("A"."DEPTNO"="B"."DEPTNO")
85
86
87Statistics
88----------------------------------------------------------
89         93  recursive calls
90          7  db block gets
91         14  consistent gets
92          0  physical reads
93       4536  redo size
94        866  bytes sent via SQL*Net to client
95        509  bytes received via SQL*Net from client
96          1  SQL*Net roundtrips to/from client
97          0  sorts (memory)
98          0  sorts (disk)
99          0  rows processed




上一篇:多文件zip解压


下一篇:hdu 2121 Ice_cream’s world II