I am an Oracle Database Specialist in Singapore.
Please note that this site uses cookies.
28 March, 2015
24 March, 2015
Parallel Execution -- 3 Limiting PX Servers
In my previous posts, I have demonstrated how Oracle "auto"computes the DoP when using the PARALLEL Hint by itself, even when PARALLEL_DEGREE_POLICY is set to MANUAL. This "auto"computed value is CPU_COUNT x PARALLEL_THREADS_PER_CPU.
How do we limit the DoP ?
1. PARALLEL_MAX_SERVERS is an instance-wide limit, not usable at the session level.
2. Resource Manager configuration can be used to limit the number of PX Servers used
3. PARALLEL_DEGREE_LIMIT, unfortunately, is not usable when PARALLEL_DEGREE_POLICY is MANUAL
As expected, the query uses 16 PX Servers (and not the table-level definition of 4). Can we use PARALLEL_DEGREE_LIMIT ?
No, it actually still used 16 PX servers f or the second execution.
What about PARALLEL_MAX_SERVERS ?
Yes, PARALLEL_MAX_SERVERS restricted the next run of the query to 4 PX Servers. However, this parameter limits the total concurrent usage of PX Servers at the instance level. It cannot be applied or derived to the session level.
UPDATE : Another method pointed out to me by Mladen Gogala is to use the Resource Manager to limit the number of PX Servers a session can request.
.
.
.
How do we limit the DoP ?
1. PARALLEL_MAX_SERVERS is an instance-wide limit, not usable at the session level.
2. Resource Manager configuration can be used to limit the number of PX Servers used
3. PARALLEL_DEGREE_LIMIT, unfortunately, is not usable when PARALLEL_DEGREE_POLICY is MANUAL
[oracle@localhost ~]$ sqlplus '/ as sysdba' SQL*Plus: Release 11.2.0.2.0 Production on Tue Mar 24 22:57:18 2015 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SYS>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 4 resource_manager_cpu_allocation integer 4 SYS>show parameter parallel_degree_policy NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ parallel_degree_policy string MANUAL SYS>show parameter parallel_max NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ parallel_max_servers integer 64 SYS> SYS>select * from dba_rsrc_io_calibrate; no rows selected SYS> SYS>connect hemant/hemant Connected. HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE'; DEGREE ---------------------------------------- 4 HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 1 16 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
As expected, the query uses 16 PX Servers (and not the table-level definition of 4). Can we use PARALLEL_DEGREE_LIMIT ?
HEMANT>alter session set parallel_degree_limit=4; Session altered. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 2 32 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
No, it actually still used 16 PX servers f or the second execution.
What about PARALLEL_MAX_SERVERS ?
HEMANT>connect / as sysdba Connected. SYS>alter system set parallel_max_servers=4; System altered. SYS>connect hemant/hemant Connected. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 3 36 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
Yes, PARALLEL_MAX_SERVERS restricted the next run of the query to 4 PX Servers. However, this parameter limits the total concurrent usage of PX Servers at the instance level. It cannot be applied or derived to the session level.
UPDATE : Another method pointed out to me by Mladen Gogala is to use the Resource Manager to limit the number of PX Servers a session can request.
.
.
.
18 March, 2015
Parallel Execution -- 2c PX Servers
Adding to my two previous posts here and here about identifying usage of Parallel Execution -- exactly how many PX servers were used for a query, here is a third method. (the first two are V$PX_PROCESS/V$PX_SESSION and V$SQLSTATS.PX_SERVERS_EXECUTIONS). This method uses V$PQ_SESSTAT.
However, the limitation of V$PQ_SESSTAT is that it can only be queried from the same session as that which ran the Parallel Query. The other two methods can be used by a separate "monitoring" session.
As has been identified earlier, the PARALLEL Hint will use 16 PX Servers (limited by PARALLEL_MAX_SERVERS [see this post] because of the values of CPU_COUNT and PARALLEL_THREADS_PER_CPU (where, in this case, PARALLEL_DEGREE_POLICY is yet MANUAL).
As we can see, the SESSIONS_TOTAL count of Server Threads does not get updated (although the count of Queries Parallelized is updated). This behaviour remains in 12c. (However, there are two additional statistics available in 12c).
.
.
.
However, the limitation of V$PQ_SESSTAT is that it can only be queried from the same session as that which ran the Parallel Query. The other two methods can be used by a separate "monitoring" session.
HEMANT>show parameter parallel_max NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ parallel_max_servers integer 8 HEMANT>connect / as sysdba Connected. SYS>alter system set parallel_max_servers=64; System altered. SYS>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 4 resource_manager_cpu_allocation integer 4 SYS>show parameter parallel_degree_policy NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ parallel_degree_policy string MANUAL SYS>
As has been identified earlier, the PARALLEL Hint will use 16 PX Servers (limited by PARALLEL_MAX_SERVERS [see this post] because of the values of CPU_COUNT and PARALLEL_THREADS_PER_CPU (where, in this case, PARALLEL_DEGREE_POLICY is yet MANUAL).
SYS>alter system flush shared_pool; System altered. SYS>connect hemant/hemant Connected. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select * from v$pq_sesstat; STATISTIC LAST_QUERY SESSION_TOTAL ------------------------------ ---------- ------------- Queries Parallelized 1 1 DML Parallelized 0 0 DDL Parallelized 0 0 DFO Trees 1 1 Server Threads 16 0 Allocation Height 16 0 Allocation Width 1 0 Local Msgs Sent 464 464 Distr Msgs Sent 0 0 Local Msgs Recv'd 464 464 Distr Msgs Recv'd 0 0 11 rows selected. HEMANT> HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select * from v$pq_sesstat; STATISTIC LAST_QUERY SESSION_TOTAL ------------------------------ ---------- ------------- Queries Parallelized 1 2 DML Parallelized 0 0 DDL Parallelized 0 0 DFO Trees 1 2 Server Threads 16 0 Allocation Height 16 0 Allocation Width 1 0 Local Msgs Sent 464 928 Distr Msgs Sent 0 0 Local Msgs Recv'd 464 928 Distr Msgs Recv'd 0 0 11 rows selected. HEMANT>
As we can see, the SESSIONS_TOTAL count of Server Threads does not get updated (although the count of Queries Parallelized is updated). This behaviour remains in 12c. (However, there are two additional statistics available in 12c).
.
.
.
13 March, 2015
Parallel Execution -- 2b PX Servers
Continuing my previous post, here I demonstrate using V$SQLSTATS.PX_SERVERS_EXECUTIONS and a couple of issues around it.
I have restarted the database.
[Note : To understand why the executions took 16 PX Servers inspite of the degree on table being 1, see this post]
So we see that PX_SERVERS_EXECUTIONS shows cumulative statistics. Let's try a slight twist.
Because I set PARALLEL_MAX_SERVERS to 8, my query on Large_Table could take only 8 PX Servers at the next execution. V$SQLSTATS.PX_SERVERS_EXECUTIONS now shows a cumulative count of 40 for 3 executions. There is no way to determine how many PX Servers were used in each of the 3 executions, because the history of executions is not maintained.
(In my controlled experiment, we know, by deduction, that the 3rd execution took 8 PX Servers simply because we know already that the first 2 executions took a cumulative count of 32 PX Servers -- by deducting 32 from 40 to get 8 for the 3rd execution)
What happens if the SQL is invalidated ?
The ALTER TABLE, being a DDL, had invalidated the query on Large_Table. So, V$SQLSTATS also got reset. Therefore, EXECUTIONS reset to 1 and PX_SERVES_EXECUTIONS got reset to 8.
.
.
.
I have restarted the database.
[oracle@localhost ~]$ sqlplus hemant/hemant SQL*Plus: Release 11.2.0.2.0 Production on Fri Mar 13 22:49:20 2015 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options HEMANT>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 4 resource_manager_cpu_allocation integer 4 HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE'; DEGREE ---------------------------------------- 1 HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 1 16 select /*+ PARALLEL */ count(*) from Large_Table HEMANT> HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 2 32 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
[Note : To understand why the executions took 16 PX Servers inspite of the degree on table being 1, see this post]
So we see that PX_SERVERS_EXECUTIONS shows cumulative statistics. Let's try a slight twist.
HEMANT>connect / as sysdba Connected. SYS>alter system set parallel_max_servers=8; System altered. SYS>connect hemant/hemant Connected. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 3 40 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
Because I set PARALLEL_MAX_SERVERS to 8, my query on Large_Table could take only 8 PX Servers at the next execution. V$SQLSTATS.PX_SERVERS_EXECUTIONS now shows a cumulative count of 40 for 3 executions. There is no way to determine how many PX Servers were used in each of the 3 executions, because the history of executions is not maintained.
(In my controlled experiment, we know, by deduction, that the 3rd execution took 8 PX Servers simply because we know already that the first 2 executions took a cumulative count of 32 PX Servers -- by deducting 32 from 40 to get 8 for the 3rd execution)
What happens if the SQL is invalidated ?
HEMANT>alter table large_table parallel 4; Table altered. HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select executions, px_servers_executions, sql_fulltext 2 from v$sqlstats 3 where sql_id = '8b0ybuspqu0mm'; EXECUTIONS PX_SERVERS_EXECUTIONS SQL_FULLTEXT ---------- --------------------- -------------------------------------------------------------------------------- 1 8 select /*+ PARALLEL */ count(*) from Large_Table HEMANT>
The ALTER TABLE, being a DDL, had invalidated the query on Large_Table. So, V$SQLSTATS also got reset. Therefore, EXECUTIONS reset to 1 and PX_SERVES_EXECUTIONS got reset to 8.
.
.
.
03 March, 2015
Parallel Execution -- 2 PX Servers
I've posted a couple of examples (here and here) of Parallel Execution servers for Parallel Query.
How do we identify usage of Parallel Execution ?
I will update this post (and, possibly, subsequent post(s)) with a few methods.
The first one (as I've shown in my previous posts) is to look at the column PX_SERVERS_EXECUTIONS in either V$SQLSTATS or V$SQL. This can identify the number of PX Servers used for an SQL (Query or DML). However, there is a caveat when the SQL undergoes multiple execution -- the statistic on PX_SERVERS_EXECUTIONS may be cumulative (i.e. additive) across all the executions of the SQL. UPDATE 13-Mar-15 : See the new post here.
Another method is to look at the V$PX_PROCESS and V$PX_SESSION views.
Let me demonstrate this second method using the same SQL query from my previous blog post.
The query by the SYS user is from a different session while the "select /*+ PARALLEL */ count(*) from Large_Table;" is being executed by HEMANT. This query is on V$PX_SESSION and shows only when the Parallel Query sessions are active -- i.e. running HEMANT's parallel count(*) query. (If I query V$PX_SESSION after the parallel count(*) completes, I won't get the information).
The above output demonstrates
(a) that there were no PX servers before I began the parallel count(*) query and there were 16 at the end -- 16 PX servers had been started and had not yet shutdown by the time I queried V$PX_PROCESS (They will shutdown after a while ** note below).
(b) that my parallel count(*) query (executed by SID 197 which is the QueryCo-ordinator -- represented by QCSID) DID request and use 16 PX server sessions (as evidenced in the output from the query on V$PX_SESSION). Thus, what I claimed on the basis of PX_SERVERS_EXECUTION in my previous post is correct.
** Note : A few minutes later, I can see that the PX Servers have shutdown.
Later, I will demonstrate how to join V$PX_PROCESS and V$PX_SESSION.
I will also demonstrate how you manage the number of PX Servers.
.
.
.
How do we identify usage of Parallel Execution ?
I will update this post (and, possibly, subsequent post(s)) with a few methods.
The first one (as I've shown in my previous posts) is to look at the column PX_SERVERS_EXECUTIONS in either V$SQLSTATS or V$SQL. This can identify the number of PX Servers used for an SQL (Query or DML). However, there is a caveat when the SQL undergoes multiple execution -- the statistic on PX_SERVERS_EXECUTIONS may be cumulative (i.e. additive) across all the executions of the SQL. UPDATE 13-Mar-15 : See the new post here.
Another method is to look at the V$PX_PROCESS and V$PX_SESSION views.
Let me demonstrate this second method using the same SQL query from my previous blog post.
[oracle@localhost ~]$ sqlplus hemant/hemant SQL*Plus: Release 11.2.0.2.0 Production on Tue Mar 3 23:34:37 2015 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options HEMANT>select distinct sid from v$mystat; SID ---------- 197 HEMANT>select count(*) from v$px_process; COUNT(*) ---------- 0 HEMANT>select count(*) from v$px_session; COUNT(*) ---------- 0 HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE'; DEGREE ---------------------------------------- 1 HEMANT>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 4 resource_manager_cpu_allocation integer 4 HEMANT>set serveroutput off HEMANT>select /*+ PARALLEL */ count(*) from Large_Table; COUNT(*) ---------- 4802944 HEMANT>select count(*) from v$px_process; COUNT(*) ---------- 16 SYS>select qcsid, req_degree, degree, count(*) 2 from v$px_session 3 group by qcsid, req_degree, degree 4 / QCSID REQ_DEGREE DEGREE COUNT(*) ---------- ---------- ---------- ---------- 197 1 197 16 16 16 SYS>
The query by the SYS user is from a different session while the "select /*+ PARALLEL */ count(*) from Large_Table;" is being executed by HEMANT. This query is on V$PX_SESSION and shows only when the Parallel Query sessions are active -- i.e. running HEMANT's parallel count(*) query. (If I query V$PX_SESSION after the parallel count(*) completes, I won't get the information).
The above output demonstrates
(a) that there were no PX servers before I began the parallel count(*) query and there were 16 at the end -- 16 PX servers had been started and had not yet shutdown by the time I queried V$PX_PROCESS (They will shutdown after a while ** note below).
(b) that my parallel count(*) query (executed by SID 197 which is the QueryCo-ordinator -- represented by QCSID) DID request and use 16 PX server sessions (as evidenced in the output from the query on V$PX_SESSION). Thus, what I claimed on the basis of PX_SERVERS_EXECUTION in my previous post is correct.
** Note : A few minutes later, I can see that the PX Servers have shutdown.
HEMANT>select count(*) from v$px_process 2 / COUNT(*) ---------- 0 HEMANT>
Later, I will demonstrate how to join V$PX_PROCESS and V$PX_SESSION.
I will also demonstrate how you manage the number of PX Servers.
.
.
.
02 March, 2015
Parallel Execution -- 1b The PARALLEL Hint and AutoDoP (contd)
Continuing the previous thread, having restarted the database again, with the same CPU_COUNT and missing I/O Calibration statistics ....
The question this time is : What if the table level DoP is specifically 1 ?
Aaha ! Again ! The same SQL statement, the same SQL_ID, the same Execution Plan (Plan Hash Value) and Oracle chose to use 8 PX Servers for the query ! Again, ignoring the table level DoP (of 1)
So, once again, we see that Oracle actually computes a DoP that looks like it is CPU_COUNT x PARALLEL_THREADS_PER_CPU. Let's verify this.
YES SIR ! Oracle chose to use 16 PX Servers this time. So that does look like CPU_COUNT x PARALLEL_THREADS_PER_CPU. Have you also noticed the COST ? The COST has also dropped to half. So, the COST is also computed based on the number of PX Servers that it expects to be able to grab and use.
.
.
.
The question this time is : What if the table level DoP is specifically 1 ?
[oracle@localhost ~]$ sqlplus '/ as sysdba' SQL*Plus: Release 11.2.0.2.0 Production on Mon Mar 2 23:22:28 2015 Copyright (c) 1982, 2010, Oracle. All rights reserved. Connected to: Oracle Database 11g Enterprise Edition Release 11.2.0.2.0 - Production With the Partitioning, OLAP, Data Mining and Real Application Testing options SYS>show parameter cpu NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ cpu_count integer 4 parallel_threads_per_cpu integer 2 resource_manager_cpu_allocation integer 4 SYS>show parameter parallel NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ fast_start_parallel_rollback string LOW parallel_adaptive_multi_user boolean FALSE parallel_automatic_tuning boolean FALSE parallel_degree_limit string CPU parallel_degree_policy string MANUAL parallel_execution_message_size integer 16384 parallel_force_local boolean FALSE parallel_instance_group string parallel_io_cap_enabled boolean FALSE parallel_max_servers integer 135 parallel_min_percent integer 0 parallel_min_servers integer 0 parallel_min_time_threshold string AUTO parallel_server boolean FALSE parallel_server_instances integer 1 parallel_servers_target integer 64 parallel_threads_per_cpu integer 2 recovery_parallelism integer 0 SYS>
SYS>select * from dba_rsrc_io_calibrate;
no rows selected
SYS>
SYS>connect hemant/hemant
Connected.
HEMANT>set serveroutput off
HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE';
DEGREE
----------------------------------------
4
HEMANT>alter table large_table parallel 1;
Table altered.
HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE';
DEGREE
----------------------------------------
1
HEMANT>select /*+ PARALLEL */ count(*) from LARGE_TABLE;
COUNT(*)
----------
4802944
HEMANT>select * from table(dbms_xplan.display_cursor);
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------
SQL_ID 47m7qyrj6uzqn, child number 0
-------------------------------------
select /*+ PARALLEL */ count(*) from LARGE_TABLE
Plan hash value: 2085386270
-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | 2622 (100)| | | | |
| 1 | SORT AGGREGATE | | 1 | | | | | |
| 2 | PX COORDINATOR | | | | | | | |
| 3 | PX SEND QC (RANDOM) | :TQ10000 | 1 | | | Q1,00 | P->S | QC (RAND) |
| 4 | SORT AGGREGATE | | 1 | | | Q1,00 | PCWP | |
| 5 | PX BLOCK ITERATOR | | 4802K| 2622 (1)| 00:00:32 | Q1,00 | PCWC | |
|* 6 | TABLE ACCESS FULL| LARGE_TABLE | 4802K| 2622 (1)| 00:00:32 | Q1,00 | PCWP | |
-----------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
6 - access(:Z>=:Z AND :Z<=:Z)
Note
-----
- automatic DOP: skipped because of IO calibrate statistics are missing
27 rows selected.
HEMANT>select px_servers_executions from v$sqlstats where sql_id='47m7qyrj6uzqn';
PX_SERVERS_EXECUTIONS
---------------------
8
HEMANT>
Aaha ! Again ! The same SQL statement, the same SQL_ID, the same Execution Plan (Plan Hash Value) and Oracle chose to use 8 PX Servers for the query ! Again, ignoring the table level DoP (of 1)
So, once again, we see that Oracle actually computes a DoP that looks like it is CPU_COUNT x PARALLEL_THREADS_PER_CPU. Let's verify this.
HEMANT>connect / as sysdba
Connected.
SYS>alter system set parallel_threads_per_cpu=4;
System altered.
SYS>alter system flush shared_pool;
System altered.
SYS>connect hemant/hemant
Connected.
HEMANT>select degree from user_tables where table_name = 'LARGE_TABLE';
DEGREE
----------------------------------------
1
HEMANT>set serveroutput off
HEMANT>select /*+ PARALLEL */ count(*) from Large_Table;
COUNT(*)
----------
4802944
HEMANT>select * from table(dbms_xplan.display_cursor);
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------
SQL_ID 8b0ybuspqu0mm, child number 0
-------------------------------------
select /*+ PARALLEL */ count(*) from Large_Table
Plan hash value: 2085386270
-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | 1311 (100)| | | | |
| 1 | SORT AGGREGATE | | 1 | | | | | |
| 2 | PX COORDINATOR | | | | | | | |
| 3 | PX SEND QC (RANDOM) | :TQ10000 | 1 | | | Q1,00 | P->S | QC (RAND) |
| 4 | SORT AGGREGATE | | 1 | | | Q1,00 | PCWP | |
| 5 | PX BLOCK ITERATOR | | 4802K| 1311 (1)| 00:00:16 | Q1,00 | PCWC | |
|* 6 | TABLE ACCESS FULL| LARGE_TABLE | 4802K| 1311 (1)| 00:00:16 | Q1,00 | PCWP | |
-----------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
6 - access(:Z>=:Z AND :Z<=:Z)
Note
-----
- automatic DOP: skipped because of IO calibrate statistics are missing
27 rows selected.
HEMANT>select px_servers_executions from v$sqlstats where sql_id='8b0ybuspqu0mm';
PX_SERVERS_EXECUTIONS
---------------------
16
HEMANT>
YES SIR ! Oracle chose to use 16 PX Servers this time. So that does look like CPU_COUNT x PARALLEL_THREADS_PER_CPU. Have you also noticed the COST ? The COST has also dropped to half. So, the COST is also computed based on the number of PX Servers that it expects to be able to grab and use.
.
.
.
Subscribe to:
Posts (Atom)