{section}
{column:width=50}
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - Production
SELECT /*+ gather_plan_statistics */
t1.c1, v.c2
FROM
t1,
(SELECT /*+ no_merge */
c1, COUNT(*) as c2
FROM t2
GROUP BY c1) v
WHERE
t1.c1 = v.c1
;
997 1
998 1
999 1
1000 1
1000 개의 행이 선택되었습니다.
SQL> SELECT * FROM TABLE(dbms_xplan.display_cursor(null,null,'allstats cost last'));
SQL_ID 5ug56utp0uncz, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */ t1.c1, v.c2 FROM t1, (SELECT
/*+ no_merge */ c1, COUNT(*) as c2 FROM t2 GROUP BY c1)
v WHERE t1.c1 = v.c1
Plan hash value: 1333811612
---------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Starts | E-Rows | Cost (%CPU)| A-Rows | A-Time | Buffers | OMem | 1Mem | Used-Mem |
---------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | | 12 (100)| 1000 |00:00:00.03 | 99 | | | |
|* 1 | HASH JOIN | | 1 | 1000 | 12 (17)| 1000 |00:00:00.03 | 99 | 968K| 968K| 1237K (0)|
| 2 | VIEW | | 1 | 1000 | 4 (25)| 1000 |00:00:00.01 | 7 | | | |
| 3 | HASH GROUP BY | | 1 | 1000 | 4 (25)| 1000 |00:00:00.01 | 7 | 879K| 879K| 1263K (0)|
| 4 | TABLE ACCESS FULL | T2 | 1 | 1000 | 3 (0)| 1000 |00:00:00.01 | 7 | | | |
| 5 | INDEX FAST FULL SCAN| T1_N1 | 1 | 10000 | 7 (0)| 10000 |00:00:00.01 | 92 | | | |
---------------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 - access("T1"."C1"="V"."C1")
{column}
{column:width=50}
{column}
{section}
{section}
{column:width=50}
SELECT /*+ gather_plan_statistics */
t1.c1, v.c2
FROM
t1,
(SELECT /*+ merge */
c1, COUNT(*) AS c2
FROM t2
GROUP BY c1) v
WHERE
t1.c1 = v.c1
;
981 1
990 1
993 1
997 1
1000 1
1000 개의 행이 선택되었습니다.
SQL> SELECT * FROM TABLE(dbms_xplan.display_cursor(null,null,'allstats cost last'));
SQL_ID 10db4x15xct6x, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */ t1.c1, v.c2 FROM t1, (SELECT
/*+ merge */ c1, COUNT(*) as c2 FROM t2 GROUP BY c1) v
WHERE t1.c1 = v.c1
Plan hash value: 4227326106
----------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Starts | E-Rows | Cost (%CPU)| A-Rows | A-Time | Buffers | OMem | 1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | | 11 (100)| 1000 |00:00:00.03 | 33 | | | |
| 1 | HASH GROUP BY | | 1 | 1000 | 11 (19)| 1000 |00:00:00.03 | 33 | 792K| 792K| 1266K (0)|
|* 2 | HASH JOIN | | 1 | 1000 | 10 (10)| 1000 |00:00:00.02 | 33 | 1066K| 1066K| 1194K (0)|
| 3 | INDEX FAST FULL SCAN| T2_N1 | 1 | 1000 | 2 (0)| 1000 |00:00:00.01 | 8 | | | |
| 4 | INDEX FAST FULL SCAN| T1_N1 | 1 | 10000 | 7 (0)| 10000 |00:00:00.01 | 25 | | | |
----------------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("T1"."C1"="C1")
{column}
{column:width=50}
{column}
{section}
{section}
{column:width=50}
SELECT
t2.c1, COUNT(*) AS c2
FROM
t1, t2
WHERE
t1.c1 = t2.c1
GROUP BY
t2.c1
;
SQL> SELECT * FROM TABLE(dbms_xplan.display_cursor(null,null,'allstats cost last'));
SQL_ID 2rbvq1tgav575, child number 0
-------------------------------------
SELECT t2.c1, COUNT(*) AS c2 FROM t1, t2 WHERE t1.c1 = t2.c1 GROUP
BY t2.c1
Plan hash value: 4227326106
----------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Starts | E-Rows | Cost (%CPU)| A-Rows | A-Time | Buffers | OMem | 1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | | 11 (100)| 1000 |00:00:00.02 | 33 | | | |
| 1 | HASH GROUP BY | | 1 | 1000 | 11 (19)| 1000 |00:00:00.02 | 33 | 879K| 879K| 1246K (0)|
|* 2 | HASH JOIN | | 1 | 1000 | 10 (10)| 1000 |00:00:00.02 | 33 | 1066K| 1066K| 1212K (0)|
| 3 | INDEX FAST FULL SCAN| T2_N1 | 1 | 1000 | 2 (0)| 1000 |00:00:00.01 | 8 | | | |
| 4 | INDEX FAST FULL SCAN| T1_N1 | 1 | 10000 | 7 (0)| 10000 |00:00:00.01 | 25 | | | |
----------------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("T1"."C1"="T2"."C1")
{column}
{column:width=50}
{column}
{section}